Skip to content

Commit c19d22c

Browse files
authored
Merge pull request #11 from RoelantVos/load_window_addition
Load window addition
2 parents 6fc108a + 7a099f7 commit c19d22c

File tree

9 files changed

+174
-11
lines changed

9 files changed

+174
-11
lines changed

.gitignore

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -242,3 +242,11 @@ ModelManifest.xml
242242
.fake/
243243

244244
.vscode
245+
020_DIRECT_Framework/Direct_Framework/Direct_Framework.jfm
246+
*.jfm
247+
*.jfm
248+
*.jfm
249+
020_DIRECT_Framework/Direct_Framework/Direct_Framework.jfm
250+
*.jfm
251+
*.jfm
252+
020_DIRECT_Framework/Direct_Framework/Direct_Framework.jfm
0 Bytes
Binary file not shown.

020_DIRECT_Framework/Direct_Framework/Direct_Framework.sqlproj

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -141,6 +141,8 @@
141141
<Build Include="Functions\omd.GetBatchIdByName.sql" />
142142
<Build Include="Functions\omd.GetFailedBatchIdList.sql" />
143143
<Build Include="Functions\omd.GetPreviousBatchInstanceDetails.sql" />
144+
<Build Include="Stored Procedures\omd.CreateLoadWindow.sql" />
145+
<Build Include="Functions\GetModuleAreaByModuleId.sql" />
144146
</ItemGroup>
145147
<ItemGroup>
146148
<PostDeploy Include="Scripts\Script.PostDeployment.sql" />
Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,26 @@
1+
CREATE FUNCTION omd.GetModuleAreaByModuleId
2+
(
3+
@ModuleId INT -- The identifier of the Module (PK).
4+
)
5+
RETURNS VARCHAR(255) AS
6+
7+
-- =============================================
8+
-- Function: Get Module Area (by Id)
9+
-- Description: Takes the module id as input and returns the area code as registered in the framework
10+
-- =============================================
11+
12+
BEGIN
13+
-- Declare ouput variable
14+
15+
DECLARE @ModuleArea VARCHAR(255) =
16+
(
17+
SELECT module.AREA_CODE
18+
FROM omd.MODULE module
19+
WHERE MODULE_ID = @ModuleId
20+
)
21+
22+
SET @ModuleArea = COALESCE(@ModuleArea,'N/A')
23+
24+
-- Return the result of the function
25+
RETURN @ModuleArea
26+
END

020_DIRECT_Framework/Direct_Framework/Functions/omd.GetLoadWindowDateTimes.sql

Lines changed: 4 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
CREATE FUNCTION [omd].[GetLoadWindowDateTimes] ( @module_code VARCHAR(255), @start_or_end tinyint)
1+
CREATE FUNCTION [omd].[GetLoadWindowDateTimes] ( @ModuleId INT, @start_or_end tinyint)
22
RETURNS DATETIME2(7) AS
33
BEGIN
44
DECLARE @result DATETIME2(7)
@@ -15,7 +15,7 @@ BEGIN
1515
ROW_NUMBER() OVER (PARTITION BY MODULE_ID ORDER BY INSERT_DATETIME DESC) AS ROW_NR
1616
FROM omd.SOURCE_CONTROL sct
1717
JOIN omd.MODULE_INSTANCE modinst ON sct.MODULE_INSTANCE_ID = modinst.MODULE_INSTANCE_ID
18-
WHERE MODULE_ID = (SELECT MODULE_ID FROM omd.MODULE WHERE MODULE_CODE=@module_code)
18+
WHERE MODULE_ID = @ModuleId
1919
) ranksub
2020
WHERE ROW_NR=1
2121
END
@@ -31,10 +31,9 @@ BEGIN
3131
ROW_NUMBER() OVER (PARTITION BY MODULE_ID ORDER BY INSERT_DATETIME DESC) AS ROW_NR
3232
FROM omd.SOURCE_CONTROL sct
3333
JOIN omd.MODULE_INSTANCE modinst ON sct.MODULE_INSTANCE_ID = modinst.MODULE_INSTANCE_ID
34-
WHERE MODULE_ID = (SELECT MODULE_ID FROM omd.MODULE WHERE MODULE_CODE = @module_code)
34+
WHERE MODULE_ID = @ModuleId
3535
) ranksub
3636
WHERE ROW_NR=1
3737
END
3838
return @result
39-
END
40-
39+
END

020_DIRECT_Framework/Direct_Framework/Stored Procedures/omd.CreateBatchInstance.sql

Lines changed: 2 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,4 @@
1-
2-
/*
1+
/*
32
Process: Create Batch Instance
43
Input:
54
- Batch Code
@@ -16,7 +15,7 @@ Usage:
1615
*/
1716

1817
CREATE PROCEDURE [omd].[CreateBatchInstance]
19-
@BatchCode VARCHAR(255), -- The name of the module, as identified in the BATCH_CODE attribute in the BATCH table.
18+
@BatchCode VARCHAR(255), -- The name of the Batch, as identified in the BATCH_CODE attribute in the BATCH table.
2019
@Debug VARCHAR(1) = 'N',
2120
@ExecutionRuntimeId VARCHAR(255) = 'N/A',
2221
@BatchInstanceId INT = NULL OUTPUT
Lines changed: 127 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,127 @@
1+
CREATE PROCEDURE [omd].[CreateLoadWindow]
2+
@ModuleInstanceId INT, -- The currently running Module Instance Id
3+
@Debug VARCHAR(1) = 'N',
4+
@LoadWindowStartDateTime DATETIME2(7) = NULL OUTPUT,
5+
@LoadWindowEndDateTime DATETIME2(7) = NULL OUTPUT
6+
AS
7+
BEGIN
8+
9+
/*
10+
Process: Create Load Window
11+
Input:
12+
- Module Instance Id
13+
- Debug flag Y/N
14+
Returns:
15+
- Load Window Start Date/Time
16+
- Load Window End Date/Time
17+
Usage:
18+
DECLARE
19+
@LoadWindowStartDateTime datetime2(7),
20+
@LoadWindowEndDateTime datetime2(7)
21+
22+
EXEC [omd].[CreateLoadWindow]
23+
@ModuleInstanceId = '',
24+
@Debug = N'Y',
25+
@LoadWindowStartDateTime = @LoadWindowStartDateTime OUTPUT,
26+
@LoadWindowEndDateTime = @LoadWindowEndDateTime OUTPUT
27+
28+
SELECT @LoadWindowStartDateTime as N'@LoadWindowStartDateTime',
29+
@LoadWindowEndDateTime as N'@LoadWindowEndDateTime'
30+
*/
31+
32+
-- Local variables (Module Id and source Data Object)
33+
DECLARE @ModuleId INT = [omd].[GetModuleIdByModuleInstanceId](@ModuleInstanceId);
34+
DECLARE @TableCode VARCHAR(255);
35+
SELECT @TableCode = DATA_OBJECT_SOURCE FROM omd.MODULE WHERE MODULE_ID = @ModuleId;
36+
37+
IF @Debug = 'Y'
38+
BEGIN
39+
PRINT 'For Module Instance Id '+CONVERT(VARCHAR(10),@ModuleInstanceId)+' the following Module Id was found in omd.MODULE: '+CONVERT(VARCHAR(10),@ModuleId)+'.';
40+
PRINT 'For Module Id '+CONVERT(VARCHAR(10),@ModuleId)+' the Source Data Object is '+@TableCode+'.';
41+
END
42+
43+
DECLARE @PreviousModuleInstanceOutcome VARCHAR(MAX);
44+
DECLARE @SqlStatement VARCHAR(MAX);
45+
46+
-- Exception handling
47+
IF @ModuleId = NULL OR @ModuleId = 0
48+
THROW 50000,'The Module Id could not be retrieved based on the Module Instance Id.',1
49+
50+
51+
52+
SELECT @PreviousModuleInstanceOutcome =
53+
COALESCE
54+
(
55+
(
56+
SELECT TOP 1
57+
NEXT_RUN_INDICATOR
58+
FROM omd.MODULE_INSTANCE main
59+
WHERE
60+
main.MODULE_ID = @ModuleId
61+
AND main.MODULE_INSTANCE_ID != @ModuleInstanceId
62+
ORDER BY main.MODULE_INSTANCE_ID DESC
63+
)
64+
, 'S') -- If there is no Module Instance Id, the process will resolve to succeeded.
65+
66+
IF @Debug = 'Y'
67+
PRINT 'The previous Module Instance Id was evaluated as: '+@PreviousModuleInstanceOutcome+'.';
68+
69+
-- If the most recent run prior to the active Instance Id (now) is not failed, continue.
70+
IF @PreviousModuleInstanceOutcome = 'R'
71+
BEGIN
72+
IF @Debug = 'Y'
73+
PRINT 'The previous Module Instance was a failure, so no new load window is set until this is resolved - end of procedure.';
74+
GOTO EndOfProcedure
75+
END
76+
ELSE
77+
BEGIN
78+
BEGIN TRY
79+
80+
SET @SqlStatement = '
81+
INSERT INTO omd.[SOURCE_CONTROL]
82+
(
83+
[MODULE_INSTANCE_ID]
84+
,[INSERT_DATETIME]
85+
,[INTERVAL_START_DATETIME]
86+
,[INTERVAL_END_DATETIME]
87+
,[INTERVAL_START_IDENTIFIER]
88+
,[INTERVAL_END_IDENTIFIER]
89+
)
90+
VALUES
91+
(
92+
'+CONVERT(VARCHAR(10),@ModuleInstanceId)+'
93+
,SYSDATETIME()
94+
,(
95+
SELECT CONVERT(varchar,ISNULL(MAX(INTERVAL_END_DATETIME),''1900-01-01''),121) AS INTERVAL_START_DATETIME
96+
FROM omd.SOURCE_CONTROL A
97+
JOIN omd.MODULE_INSTANCE B ON (A.MODULE_INSTANCE_ID=B.MODULE_INSTANCE_ID)
98+
WHERE B.MODULE_ID = '+CONVERT(VARCHAR(10),@ModuleId)+'
99+
) -- Maps to INTERVAL_START_DATETIME which is the last datetime of the previous window.
100+
, (
101+
SELECT COALESCE(MAX(LOAD_DATETIME),''1900-01-01'')
102+
FROM '+@TableCode+' sdo
103+
JOIN omd.MODULE_INSTANCE modinst ON sdo.ETL_INSERT_RUN_ID=modinst.MODULE_INSTANCE_ID
104+
WHERE modinst.EXECUTION_STATUS_CODE=''S''
105+
) -- Maps to INTERVAL_END_DATETIME
106+
,NULL --INTERVAL_START_IDENTIFIER
107+
,NULL --INTERVAL_END_IDENTIFIER
108+
)'
109+
110+
IF @Debug='Y'
111+
PRINT 'Load Window SQL statement is: '+@SqlStatement;
112+
113+
EXEC (@SqlStatement);
114+
115+
-- Retrieve values for return
116+
SELECT @LoadWindowStartDateTime = [omd].[GetLoadWindowDateTimes](@ModuleId,1);
117+
SELECT @LoadWindowEndDateTime = [omd].[GetLoadWindowDateTimes](@ModuleId,2);
118+
119+
END TRY
120+
BEGIN CATCH
121+
THROW
122+
END CATCH
123+
END
124+
125+
EndOfProcedure:
126+
-- End label
127+
END

020_DIRECT_Framework/Direct_Framework/Stored Procedures/omd.CreateModuleInstance.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -16,7 +16,7 @@ Usage:
1616
*/
1717

1818
CREATE PROCEDURE omd.CreateModuleInstance
19-
@ModuleCode VARCHAR(255), -- The name of the module, as identified in the MODULE_CODE attribute in the MODULE table.
19+
@ModuleCode VARCHAR(255), -- The name of the Module, as identified in the MODULE_CODE attribute in the MODULE table.
2020
@Debug VARCHAR(1) = 'N',
2121
@ExecutionRuntimeId VARCHAR(255) = 'N/A',
2222
@BatchInstanceId INT = 0, -- The Batch Instance Id, if the Module is run from a Batch.

020_DIRECT_Framework/Direct_Framework/Stored Procedures/omd.UpdateModuleInstance.sql

Lines changed: 4 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -16,6 +16,8 @@ Usage:
1616
CREATE PROCEDURE [omd].[UpdateModuleInstance]
1717
@ModuleInstanceId INT,
1818
@EventCode VARCHAR(10) = 'None',
19+
@RowCountSelect INT = 0,
20+
@RowCountInsert INT = 0,
1921
@Debug VARCHAR(1) = 'Y'
2022
AS
2123

@@ -56,9 +58,9 @@ BEGIN
5658
BEGIN
5759
BEGIN TRY
5860
IF @Debug='Y'
59-
PRINT 'Setting Module Instance '+CONVERT(VARCHAR(10),@ModuleInstanceId)+' to '+@EventCode+'.';
61+
PRINT 'Setting Module Instance '+CONVERT(VARCHAR(10),@ModuleInstanceId)+' to '+@EventCode+' and row count '+CONVERT(VARCHAR(10),@RowCountInsert)+'.';
6062

61-
UPDATE omd.MODULE_INSTANCE SET EXECUTION_STATUS_CODE = 'S', NEXT_RUN_INDICATOR = 'P', END_DATETIME=GETDATE() WHERE MODULE_INSTANCE_ID = @ModuleInstanceId
63+
UPDATE omd.MODULE_INSTANCE SET EXECUTION_STATUS_CODE = 'S', NEXT_RUN_INDICATOR = 'P', END_DATETIME=GETDATE(), ROWS_INPUT = @RowCountSelect, ROWS_INSERTED = @RowCountInsert WHERE MODULE_INSTANCE_ID = @ModuleInstanceId
6264
END TRY
6365
BEGIN CATCH
6466
THROW

0 commit comments

Comments
 (0)