8
0

DEX: Work in progress

This commit is contained in:
2026-02-25 16:36:19 +01:00
parent 7a97a7fe55
commit 143070e179
14 changed files with 275 additions and 122 deletions

View File

@@ -51,7 +51,7 @@ BEGIN TRY
@TEST_MODE BIT = @pTEST_MODE,
@ASYNC_MODE BIT = @pASYNC_MODE,
@BATCH_ID NVARCHAR(25) = @pBATCH_ID,
@BATCH_CREATOR NVARCHAR(25) = @pBATCH_CREATOR,
@BATCH_CREATOR NVARCHAR(128) = @pBATCH_CREATOR,
@LANGUAGE NVARCHAR(10) = @pLANGUAGE,
@LOG_LEVEL NVARCHAR(25) = UPPER(ISNULL(@pLOG_LEVEL,'INFO')),
@START_QUERY NVARCHAR(MAX) = @pSTART_QUERY,

View File

@@ -75,6 +75,7 @@ AS
BEGIN TRY
SET NOCOUNT ON;
SET XACT_ABORT ON;
-- declare new vars because of parameter sniffing
DECLARE @PROFILE_ID BIGINT = @pPROFILE_ID,
@@ -164,10 +165,29 @@ BEGIN TRY
@TBDEX_TMP_QUERY_COMMENT NVARCHAR(150) = NULL,
@TBDEX_TMP_QUERY_ADDED_WHO NVARCHAR(50) = NULL,
@TBDEX_TMP_QUERY_ADDED_WHEN DATETIME = NULL,
@PLACEHOLDER_ROW_COUNT INT = 0,
@PLACEHOLDER_ROW_INDEX INT = 0,
@RETURN_STATUS INT = 0,
@RETURN_STATUS_TEXT NVARCHAR(MAX) = concat('START PROCEDURE [',@MY_PROCEDURE_NAME,'] @ ',CONVERT(varchar(50),GETDATE(),120)),
@RETURN_ERROR_TEXT NVARCHAR(MAX) = '';
DECLARE @vTBDEX_TMP_QUERY_SOURCE TABLE (
[ROW_ID] INT IDENTITY(1,1) NOT NULL,
[GUID] BIGINT,
[PROFILE_ID] SMALLINT,
[BATCH_ID] NVARCHAR(25),
[QUERY] NVARCHAR(MAX),
[COMMENT] NVARCHAR(150),
[ADDED_WHO] NVARCHAR(50),
[ADDED_WHEN] DATETIME
);
DECLARE @vTBDEX_CFG_RESOURCES_CONST TABLE (
[ROW_ID] INT IDENTITY(1,1) NOT NULL,
[PLACEHOLDER_NAME] NVARCHAR(50) NOT NULL,
[PLACEHOLDER] NVARCHAR(MAX) NULL
);
PRINT '====================================================================================================';
PRINT @RETURN_STATUS_TEXT;
PRINT '';
@@ -222,8 +242,22 @@ BEGIN TRY
--==================================================-- Count main sql querys --==================================================--
SET @ROW_COUNT1 = ISNULL((SELECT COUNT(*) FROM [TBDEX_TMP_PROCESS_REFERENCES] WITH (SNAPSHOT)
WHERE [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID AND [ADDED_WHO]=@BATCH_CREATOR),0);
SET @ROW_COUNT2 = ISNULL((SELECT COUNT(*) FROM [TBDEX_TMP_QUERY] WITH (SNAPSHOT)
WHERE [GUID] > 0 AND [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID AND [QUERY] IS NOT NULL AND [ADDED_WHO]=@BATCH_CREATOR),0);
INSERT INTO @vTBDEX_TMP_QUERY_SOURCE([GUID],[PROFILE_ID],[BATCH_ID],[QUERY],[COMMENT],[ADDED_WHO],[ADDED_WHEN])
SELECT [GUID],[PROFILE_ID],[BATCH_ID],[QUERY],[COMMENT],[ADDED_WHO],[ADDED_WHEN]
FROM [TBDEX_TMP_QUERY] WITH (SNAPSHOT)
WHERE [GUID] > 0 AND [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID AND [QUERY] IS NOT NULL AND [ADDED_WHO]=@BATCH_CREATOR
ORDER BY [GUID] ASC;
INSERT INTO @vTBDEX_CFG_RESOURCES_CONST([PLACEHOLDER_NAME],[PLACEHOLDER])
SELECT [PLACEHOLDER_NAME],[PLACEHOLDER]
FROM [dbo].[VWDEX_RESOURCES]
WHERE [PROFILE_ID] IN (0,@PROFILE_ID) AND [ACTIVE] = @ACTIVE_FLAG AND LTRIM(RTRIM([PLACEHOLDER_TYPE])) = @PLACEHOLDER_TYPE
ORDER BY [SEQUENCE] ASC;
SET @PLACEHOLDER_ROW_COUNT = ISNULL((SELECT COUNT(*) FROM @vTBDEX_CFG_RESOURCES_CONST),0);
SET @ROW_COUNT2 = ISNULL((SELECT COUNT(*) FROM @vTBDEX_TMP_QUERY_SOURCE),0);
SET @ROW_COUNT_SUM1 = (@ROW_COUNT1 + @ROW_COUNT2);
IF (@ROW_COUNT_SUM1 < 2) BEGIN
@@ -321,22 +355,21 @@ BEGIN TRY
-----------------------------------------------------------------------------------------------------------------------------------
SET @ROW_COUNTER2 = 0;
DECLARE CURSOR_TBDEX_TMP_QUERY CURSOR
LOCAL FAST_FORWARD FOR
SELECT [GUID] as 'TBDEX_TMP_QUERY_GUID', [PROFILE_ID] as 'TBDEX_TMP_QUERY_PROFILE_ID', [BATCH_ID] as 'TBDEX_TMP_QUERY_BATCH_ID',
[QUERY] as 'TBDEX_TMP_QUERY_QUERY', [COMMENT] as 'TBDEX_TMP_QUERY_COMMENT', [ADDED_WHO] as 'TBDEX_TMP_QUERY_ADDED_WHO',
[ADDED_WHEN] as 'TBDEX_TMP_QUERY_ADDED_WHEN'
FROM [TBDEX_TMP_QUERY] WITH (SNAPSHOT)
WHERE [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID
ORDER BY [GUID] ASC;
OPEN CURSOR_TBDEX_TMP_QUERY
FETCH NEXT FROM CURSOR_TBDEX_TMP_QUERY INTO @TBDEX_TMP_QUERY_GUID,@TBDEX_TMP_QUERY_PROFILE_ID,@TBDEX_TMP_QUERY_BATCH_ID,@TBDEX_TMP_QUERY_QUERY,@TBDEX_TMP_QUERY_COMMENT,@TBDEX_TMP_QUERY_ADDED_WHO,@TBDEX_TMP_QUERY_ADDED_WHEN;
WHILE @@FETCH_STATUS = 0
WHILE (@ROW_COUNTER2 < @ROW_COUNT2)
BEGIN
SET @ROW_COUNTER2 += 1; -- Increase loop counter
SET @ROW_COUNTER2 += 1;
SELECT @TBDEX_TMP_QUERY_GUID = [GUID],
@TBDEX_TMP_QUERY_PROFILE_ID = [PROFILE_ID],
@TBDEX_TMP_QUERY_BATCH_ID = [BATCH_ID],
@TBDEX_TMP_QUERY_QUERY = [QUERY],
@TBDEX_TMP_QUERY_COMMENT = [COMMENT],
@TBDEX_TMP_QUERY_ADDED_WHO = [ADDED_WHO],
@TBDEX_TMP_QUERY_ADDED_WHEN = [ADDED_WHEN]
FROM @vTBDEX_TMP_QUERY_SOURCE
WHERE [ROW_ID] = @ROW_COUNTER2;
IF ((@ROW_COUNTER2 = 1) OR (@ROW_COUNTER2 = @ROW_COUNT2) OR (@ROW_COUNTER2 % 100 = 0)) BEGIN
PRINT concat('This is cursor (CURSOR_TBDEX_TMP_QUERY), loop nr: ',@ROW_COUNTER2);
END;
@@ -399,24 +432,17 @@ BEGIN TRY
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%REFERENCE4%',ISNULL(@TBDEX_IN_REFERENCE4,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%REFERENCE5%',ISNULL(@TBDEX_IN_REFERENCE5,''));
DECLARE CURSOR_PLACEHOLDER CURSOR
LOCAL FAST_FORWARD FOR
SELECT [PLACEHOLDER_NAME] as 'Placeholder_Name', [PLACEHOLDER] as 'Placeholder'
FROM [TBDEX_CFG_RESOURCES] (NOLOCK)
WHERE [PROFILE_ID] IN (0,@PROFILE_ID) AND [ACTIVE] = @ACTIVE_FLAG AND LTRIM(RTRIM([PLACEHOLDER_TYPE])) = @PLACEHOLDER_TYPE
ORDER BY [SEQUENCE] ASC;
OPEN CURSOR_PLACEHOLDER
FETCH NEXT FROM CURSOR_PLACEHOLDER INTO @PLACEHOLDER_NAME,@PLACEHOLDER;
WHILE @@FETCH_STATUS = 0
SET @PLACEHOLDER_ROW_INDEX = 1;
WHILE (@PLACEHOLDER_ROW_INDEX <= @PLACEHOLDER_ROW_COUNT)
BEGIN
SELECT @PLACEHOLDER_NAME = [PLACEHOLDER_NAME],
@PLACEHOLDER = [PLACEHOLDER]
FROM @vTBDEX_CFG_RESOURCES_CONST
WHERE [ROW_ID] = @PLACEHOLDER_ROW_INDEX;
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,concat('%',@PLACEHOLDER_NAME,'%'),ISNULL(@PLACEHOLDER,''));
FETCH NEXT FROM CURSOR_PLACEHOLDER INTO @PLACEHOLDER_NAME,@PLACEHOLDER;
SET @PLACEHOLDER_ROW_INDEX += 1;
END
CLOSE CURSOR_PLACEHOLDER;
DEALLOCATE CURSOR_PLACEHOLDER;
-----------------------------------------------------------------------------------------------------------------------------------
--=================================================-- Check first sql query --===================================================--
@@ -516,10 +542,7 @@ BEGIN TRY
END;
-----------------------------------------------------------------------------------------------------------------------------------
FETCH NEXT FROM CURSOR_TBDEX_TMP_QUERY INTO @TBDEX_TMP_QUERY_GUID,@TBDEX_TMP_QUERY_PROFILE_ID,@TBDEX_TMP_QUERY_BATCH_ID,@TBDEX_TMP_QUERY_QUERY,@TBDEX_TMP_QUERY_COMMENT,@TBDEX_TMP_QUERY_ADDED_WHO,@TBDEX_TMP_QUERY_ADDED_WHEN;
END
CLOSE CURSOR_TBDEX_TMP_QUERY;
DEALLOCATE CURSOR_TBDEX_TMP_QUERY;
-----------------------------------------------------------------------------------------------------------------------------------
FETCH NEXT FROM CURSOR_TBDEX_TMP_PROCESS_REFERENCES INTO @TBDEX_IN_GUID,@TBDEX_IN_PROFILE_ID,@TBDEX_IN_BATCH_ID,@TBDEX_IN_REFERENCE1,@TBDEX_IN_REFERENCE2,@TBDEX_IN_REFERENCE3,@TBDEX_IN_REFERENCE4,@TBDEX_IN_REFERENCE5,@TBDEX_IN_EXTERNAL_REFERENCE1,@TBDEX_IN_EXTERNAL_REFERENCE2,@TBDEX_IN_EXTERNAL_REFERENCE3,@TBDEX_IN_EXTERNAL_REFERENCE4,@TBDEX_IN_EXTERNAL_REFERENCE5,@TBDEX_IN_COMMENT,@TBDEX_IN_ADDED_WHO,@TBDEX_IN_ADDED_WHEN;
@@ -556,18 +579,6 @@ END TRY BEGIN CATCH
ROLLBACK TRANSACTION;
END;
PRINT 'ERROR: ' + @RETURN_ERROR_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO','WARN','ERROR')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'ERROR', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = CASE WHEN @RETURN_STATUS > 50000 THEN @RETURN_STATUS ELSE 50000 END;
SET @RETURN_STATUS_TEXT = concat('END PROCEDURE [',@MY_PROCEDURE_NAME,'] @ ',CONVERT(NVARCHAR(50),GETDATE(),120));

View File

@@ -95,7 +95,7 @@ BEGIN TRY
@FORCE BIT = @pFORCE,
@PROFILE_NAME NVARCHAR(50) = @pPROFILE_NAME,
@MANDANTOR NVARCHAR(50) = @pMANDANTOR,
@EXPORT_TYPE NVARCHAR(10) = @pEXPORT_TYPE,
@EXPORT_TYPE NVARCHAR(50) = @pEXPORT_TYPE,
@DEFAULT_DATA_SEPARATOR NVARCHAR(50) = @pDEFAULT_DATA_SEPARATOR,
@TBDEX_TMP_TABLE_SCHEMA SYSNAME = @pTBDEX_TMP_TABLE_SCHEMA,
@TBDEX_TMP_TABLE_NAME SYSNAME = @pTBDEX_TMP_TABLE_NAME,

View File

@@ -60,6 +60,7 @@ AS
BEGIN TRY
SET NOCOUNT ON;
SET XACT_ABORT ON;
-- declare new vars because of parameter sniffing
DECLARE @PROFILE_ID BIGINT = @pPROFILE_ID,
@@ -90,7 +91,7 @@ BEGIN TRY
@FORCE BIT = @pFORCE,
@PROFILE_NAME NVARCHAR(50) = @pPROFILE_NAME,
@MANDANTOR NVARCHAR(50) = @pMANDANTOR,
@EXPORT_TYPE NVARCHAR(10) = @pEXPORT_TYPE,
@EXPORT_TYPE NVARCHAR(50) = @pEXPORT_TYPE,
@DEFAULT_DATA_SEPARATOR NVARCHAR(50) = @pDEFAULT_DATA_SEPARATOR,
@TBDEX_TMP_TABLE_SCHEMA NVARCHAR(150) = @pTBDEX_TMP_TABLE_SCHEMA,
@TBDEX_TMP_TABLE_NAME NVARCHAR(150) = @pTBDEX_TMP_TABLE_NAME,

View File

@@ -37,20 +37,107 @@ BEGIN TRY
DECLARE @QUERY NVARCHAR(MAX) = ISNULL(@pQUERY,N''),
@RETURN_STATUS INT = ISNULL(@pRETURN_STATUS,50000),
@QUERY_NAME NVARCHAR(100) = ISNULL(@pQUERY_NAME,N'@QUERY'),
@QUERY_SCAN NVARCHAR(MAX) = N'',
@QUERY_SCAN_NORM NVARCHAR(MAX) = N'',
@COMMENT_START INT = 0,
@COMMENT_END INT = 0,
@SCAN_POS INT = 1,
@TOKEN_START INT = 0,
@TOKEN_END INT = 0,
@QUOTE_START INT = 0,
@QUOTE_END INT = 0,
@TOKEN NVARCHAR(200) = N'',
@HAS_UNRESOLVED_PLACEHOLDER BIT = 0,
@HAS_RESTRICTED_SQL BIT = 0,
@RETURN_ERROR_TEXT NVARCHAR(MAX) = N'';
----------------------------------------------------------------------------------------------------------------------------
--=========================================-- validate query content --====================================================--
SET @HAS_UNRESOLVED_PLACEHOLDER = CASE WHEN PATINDEX('%[%][A-Z_][A-Z0-9_][A-Z0-9_][A-Z0-9_][%]%',UPPER(@QUERY)) > 0 THEN 1 ELSE 0 END;
SET @QUERY_SCAN = UPPER(@QUERY);
SET @COMMENT_START = CHARINDEX('/*',@QUERY_SCAN);
WHILE (@COMMENT_START > 0)
BEGIN
SET @COMMENT_END = CHARINDEX('*/',@QUERY_SCAN,@COMMENT_START + 2);
IF (@COMMENT_END = 0)
BREAK;
SET @QUERY_SCAN = STUFF(@QUERY_SCAN,@COMMENT_START,(@COMMENT_END - @COMMENT_START + 2),REPLICATE(' ',(@COMMENT_END - @COMMENT_START + 2)));
SET @COMMENT_START = CHARINDEX('/*',@QUERY_SCAN,@COMMENT_START + 1);
END;
SET @COMMENT_START = CHARINDEX('--',@QUERY_SCAN);
WHILE (@COMMENT_START > 0)
BEGIN
SET @COMMENT_END = CHARINDEX(CHAR(10),@QUERY_SCAN,@COMMENT_START + 2);
IF (@COMMENT_END = 0)
SET @COMMENT_END = LEN(@QUERY_SCAN) + 1;
SET @QUERY_SCAN = STUFF(@QUERY_SCAN,@COMMENT_START,(@COMMENT_END - @COMMENT_START),REPLICATE(' ',(@COMMENT_END - @COMMENT_START)));
SET @COMMENT_START = CHARINDEX('--',@QUERY_SCAN,@COMMENT_START + 1);
END;
SET @QUERY_SCAN_NORM = REPLACE(REPLACE(REPLACE(@QUERY_SCAN,CHAR(9),' '),CHAR(10),' '),CHAR(13),' ');
WHILE (CHARINDEX(' ',@QUERY_SCAN_NORM) > 0)
BEGIN
SET @QUERY_SCAN_NORM = REPLACE(@QUERY_SCAN_NORM,' ',' ');
END;
SET @QUOTE_START = CHARINDEX('''',@QUERY_SCAN);
WHILE (@QUOTE_START > 0)
BEGIN
SET @QUOTE_END = CHARINDEX('''',@QUERY_SCAN,@QUOTE_START + 1);
IF (@QUOTE_END = 0)
BREAK;
SET @QUERY_SCAN = STUFF(@QUERY_SCAN,@QUOTE_START,(@QUOTE_END - @QUOTE_START + 1),REPLICATE(' ',(@QUOTE_END - @QUOTE_START + 1)));
SET @QUOTE_START = CHARINDEX('''',@QUERY_SCAN,@QUOTE_START + 1);
END;
WHILE (1 = 1)
BEGIN
SET @TOKEN_START = CHARINDEX('%',@QUERY_SCAN,@SCAN_POS);
IF (@TOKEN_START = 0)
BREAK;
SET @TOKEN_END = CHARINDEX('%',@QUERY_SCAN,@TOKEN_START + 1);
IF (@TOKEN_END = 0)
BREAK;
SET @TOKEN = SUBSTRING(@QUERY_SCAN,@TOKEN_START + 1,@TOKEN_END - @TOKEN_START - 1);
IF (LEN(@TOKEN) > 0)
AND (LEFT(@TOKEN,1) LIKE '[A-Z_]')
AND (@TOKEN NOT LIKE '%[^A-Z0-9_]%')
BEGIN
SET @HAS_UNRESOLVED_PLACEHOLDER = 1;
BREAK;
END;
SET @SCAN_POS = @TOKEN_END + 1;
END;
SET @HAS_RESTRICTED_SQL = CASE WHEN
(PATINDEX('%;--%',UPPER(@QUERY)) > 0) OR
(PATINDEX('%XP_CMDSHELL%',UPPER(@QUERY)) > 0) OR
(PATINDEX('%SP_CONFIGURE%',UPPER(@QUERY)) > 0) OR
(PATINDEX('%ALTER LOGIN%',UPPER(@QUERY)) > 0) OR
(PATINDEX('%CREATE LOGIN%',UPPER(@QUERY)) > 0) OR
(PATINDEX('%DROP DATABASE%',UPPER(@QUERY)) > 0)
(CHARINDEX(';--',@QUERY_SCAN_NORM) > 0) OR
(CHARINDEX('; --',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%XP_CMDSHELL%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%SP_OA%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%OPENROWSET%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%OPENDATASOURCE%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%BULK INSERT%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%SP_CONFIGURE%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%RECONFIGURE%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%ALTER SERVER%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%ALTER LOGIN%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%CREATE LOGIN%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%DROP LOGIN%',@QUERY_SCAN_NORM) > 0) OR
(PATINDEX('%DROP DATABASE%',@QUERY_SCAN_NORM) > 0)
THEN 1 ELSE 0 END;
----------------------------------------------------------------------------------------------------------------------------

View File

@@ -44,6 +44,8 @@ AS
BEGIN TRY
SET XACT_ABORT ON;
BEGIN TRANSACTION
DECLARE @JOB_NAME VARCHAR(50),
@@ -298,7 +300,7 @@ BEGIN TRY
EXECUTE sp_executesql @FILE_CONTENT_Head_Query, N'@FILE_DATA_SEPARATOR varchar(1)', @FILE_DATA_SEPARATOR = @FILE_DATA_SEPARATOR;
-- Get File Head and replace word wrap / line breaks
SET @FILE_CONTENT_HEAD = (SELECT * FROM @FILE_CONTENT_HEAD_RESULT)
SET @FILE_CONTENT_HEAD = (SELECT TOP 1 [ResultText] FROM @FILE_CONTENT_HEAD_RESULT)
SET @FILE_CONTENT_HEAD = REPLACE(@FILE_CONTENT_HEAD,CHAR(13) + CHAR(10),'')
PRINT '@FILE_CONTENT_Head: ' + @FILE_CONTENT_Head

View File

@@ -65,6 +65,7 @@ AS
BEGIN TRY
SET NOCOUNT ON;
SET XACT_ABORT ON;
-- declare new vars because of parameter sniffing
DECLARE @PROFILE_ID BIGINT = @pPROFILE_ID,
@@ -119,7 +120,8 @@ BEGIN TRY
[EXTERNAL_REFERENCE2] NVARCHAR(2000),
[EXTERNAL_REFERENCE3] NVARCHAR(2000),
[EXTERNAL_REFERENCE4] NVARCHAR(2000),
[EXTERNAL_REFERENCE5] NVARCHAR(2000)
[EXTERNAL_REFERENCE5] NVARCHAR(2000),
[MATCH_KEY] VARBINARY(32)
);
DECLARE @vTBDEX_OUT_INSERTED TABLE (
@@ -135,7 +137,14 @@ BEGIN TRY
[EXTERNAL_REFERENCE2] NVARCHAR(2000),
[EXTERNAL_REFERENCE3] NVARCHAR(2000),
[EXTERNAL_REFERENCE4] NVARCHAR(2000),
[EXTERNAL_REFERENCE5] NVARCHAR(2000)
[EXTERNAL_REFERENCE5] NVARCHAR(2000),
[MATCH_KEY] VARBINARY(32)
);
DECLARE @vTBDEX_OUT_MAP TABLE (
[MATCH_KEY] VARBINARY(32) NOT NULL,
[EXPORT_NUMBER] NVARCHAR(25) NULL,
[ROW_NUM] INT NOT NULL
);
-- declare runtime vars
@@ -400,6 +409,16 @@ BEGIN TRY
--==================================================-- run insert statement --===================================================--
INSERT INTO @vTBDEX_OUT_SOURCE ([PROFILE_ID],[BATCH_ID],[CONTENT],[REFERENCE1],[REFERENCE2],[REFERENCE3],[REFERENCE4],[REFERENCE5],[EXTERNAL_REFERENCE1],[EXTERNAL_REFERENCE2],[EXTERNAL_REFERENCE3],[EXTERNAL_REFERENCE4],[EXTERNAL_REFERENCE5])
EXEC sp_executesql @QUERY_SET_OUTPUT;
UPDATE [SRC]
SET [MATCH_KEY] = HASHBYTES(
'SHA2_256',
CONCAT(
ISNULL([SRC].[REFERENCE1],N''),N'|',ISNULL([SRC].[REFERENCE2],N''),N'|',ISNULL([SRC].[REFERENCE3],N''),N'|',ISNULL([SRC].[REFERENCE4],N''),N'|',ISNULL([SRC].[REFERENCE5],N''),N'|',
ISNULL([SRC].[EXTERNAL_REFERENCE1],N''),N'|',ISNULL([SRC].[EXTERNAL_REFERENCE2],N''),N'|',ISNULL([SRC].[EXTERNAL_REFERENCE3],N''),N'|',ISNULL([SRC].[EXTERNAL_REFERENCE4],N''),N'|',ISNULL([SRC].[EXTERNAL_REFERENCE5],N'')
)
)
FROM @vTBDEX_OUT_SOURCE AS [SRC];
-----------------------------------------------------------------------------------------------------------------------------------
BEGIN TRANSACTION;
@@ -437,30 +456,40 @@ BEGIN TRY
[S].[EXTERNAL_REFERENCE2],
[S].[EXTERNAL_REFERENCE3],
[S].[EXTERNAL_REFERENCE4],
[S].[EXTERNAL_REFERENCE5]
INTO @vTBDEX_OUT_INSERTED ([OUT_ID],[PROFILE_ID],[BATCH_ID],[REFERENCE1],[REFERENCE2],[REFERENCE3],[REFERENCE4],[REFERENCE5],[EXTERNAL_REFERENCE1],[EXTERNAL_REFERENCE2],[EXTERNAL_REFERENCE3],[EXTERNAL_REFERENCE4],[EXTERNAL_REFERENCE5]);
[S].[EXTERNAL_REFERENCE5],
[S].[MATCH_KEY]
INTO @vTBDEX_OUT_INSERTED ([OUT_ID],[PROFILE_ID],[BATCH_ID],[REFERENCE1],[REFERENCE2],[REFERENCE3],[REFERENCE4],[REFERENCE5],[EXTERNAL_REFERENCE1],[EXTERNAL_REFERENCE2],[EXTERNAL_REFERENCE3],[EXTERNAL_REFERENCE4],[EXTERNAL_REFERENCE5],[MATCH_KEY]);
INSERT INTO @vTBDEX_OUT_MAP ([MATCH_KEY],[EXPORT_NUMBER],[ROW_NUM])
SELECT HASHBYTES(
'SHA2_256',
CONCAT(
ISNULL([TPR].[REFERENCE1],N''),N'|',ISNULL([TPR].[REFERENCE2],N''),N'|',ISNULL([TPR].[REFERENCE3],N''),N'|',ISNULL([TPR].[REFERENCE4],N''),N'|',ISNULL([TPR].[REFERENCE5],N''),N'|',
ISNULL([TPR].[EXTERNAL_REFERENCE1],N''),N'|',ISNULL([TPR].[EXTERNAL_REFERENCE2],N''),N'|',ISNULL([TPR].[EXTERNAL_REFERENCE3],N''),N'|',ISNULL([TPR].[EXTERNAL_REFERENCE4],N''),N'|',ISNULL([TPR].[EXTERNAL_REFERENCE5],N'')
)
) AS [MATCH_KEY],
[TPR].[EXPORT_NUMBER],
ROW_NUMBER() OVER (
PARTITION BY HASHBYTES(
'SHA2_256',
CONCAT(
ISNULL([TPR].[REFERENCE1],N''),N'|',ISNULL([TPR].[REFERENCE2],N''),N'|',ISNULL([TPR].[REFERENCE3],N''),N'|',ISNULL([TPR].[REFERENCE4],N''),N'|',ISNULL([TPR].[REFERENCE5],N''),N'|',
ISNULL([TPR].[EXTERNAL_REFERENCE1],N''),N'|',ISNULL([TPR].[EXTERNAL_REFERENCE2],N''),N'|',ISNULL([TPR].[EXTERNAL_REFERENCE3],N''),N'|',ISNULL([TPR].[EXTERNAL_REFERENCE4],N''),N'|',ISNULL([TPR].[EXTERNAL_REFERENCE5],N'')
)
)
ORDER BY [TPR].[GUID] DESC
) AS [ROW_NUM]
FROM [TBDEX_TMP_PROCESS_REFERENCES] AS [TPR] WITH (SNAPSHOT)
WHERE [TPR].[PROFILE_ID] = @PROFILE_ID
AND [TPR].[BATCH_ID] = @BATCH_ID
AND [TPR].[ADDED_WHO] IN (@BATCH_CREATOR,@MY_PROCEDURE_NAME);
IF EXISTS (
SELECT 1
FROM @vTBDEX_OUT_INSERTED AS [OI]
OUTER APPLY (
SELECT TOP 1 [TPR].[EXPORT_NUMBER]
FROM [TBDEX_TMP_PROCESS_REFERENCES] AS [TPR] WITH (SNAPSHOT)
WHERE [TPR].[PROFILE_ID] = [OI].[PROFILE_ID]
AND [TPR].[BATCH_ID] = [OI].[BATCH_ID]
AND ISNULL([TPR].[REFERENCE1],'') = ISNULL([OI].[REFERENCE1],'')
AND ISNULL([TPR].[REFERENCE2],'') = ISNULL([OI].[REFERENCE2],'')
AND ISNULL([TPR].[REFERENCE3],'') = ISNULL([OI].[REFERENCE3],'')
AND ISNULL([TPR].[REFERENCE4],'') = ISNULL([OI].[REFERENCE4],'')
AND ISNULL([TPR].[REFERENCE5],'') = ISNULL([OI].[REFERENCE5],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE1],'') = ISNULL([OI].[EXTERNAL_REFERENCE1],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE2],'') = ISNULL([OI].[EXTERNAL_REFERENCE2],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE3],'') = ISNULL([OI].[EXTERNAL_REFERENCE3],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE4],'') = ISNULL([OI].[EXTERNAL_REFERENCE4],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE5],'') = ISNULL([OI].[EXTERNAL_REFERENCE5],'')
AND [TPR].[ADDED_WHO] IN (@BATCH_CREATOR,@MY_PROCEDURE_NAME)
ORDER BY [TPR].[GUID] DESC
) AS [MAP]
LEFT JOIN @vTBDEX_OUT_MAP AS [MAP]
ON [MAP].[MATCH_KEY] = [OI].[MATCH_KEY]
AND [MAP].[ROW_NUM] = 1
WHERE [MAP].[EXPORT_NUMBER] IS NULL
) BEGIN
@@ -471,40 +500,42 @@ BEGIN TRY
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
END;
;WITH [REF_SRC] AS (
SELECT [OI].[OUT_ID],
ISNULL([OI].[REFERENCE1],'' ) AS [REFERENCE1],
[OI].[REFERENCE2],
[OI].[REFERENCE3],
[OI].[REFERENCE4],
[OI].[REFERENCE5],
LEFT([OI].[EXTERNAL_REFERENCE1],255) AS [EXTERNAL_REFERENCE1],
LEFT([OI].[EXTERNAL_REFERENCE2],255) AS [EXTERNAL_REFERENCE2],
LEFT([OI].[EXTERNAL_REFERENCE3],255) AS [EXTERNAL_REFERENCE3],
LEFT([OI].[EXTERNAL_REFERENCE4],255) AS [EXTERNAL_REFERENCE4],
LEFT([OI].[EXTERNAL_REFERENCE5],255) AS [EXTERNAL_REFERENCE5],
[MAP].[EXPORT_NUMBER],
ROW_NUMBER() OVER (PARTITION BY [OI].[OUT_ID],[MAP].[EXPORT_NUMBER] ORDER BY [OI].[OUT_ID]) AS [ROW_NUM]
FROM @vTBDEX_OUT_INSERTED AS [OI]
INNER JOIN @vTBDEX_OUT_MAP AS [MAP]
ON [MAP].[MATCH_KEY] = [OI].[MATCH_KEY]
AND [MAP].[ROW_NUM] = 1
)
INSERT INTO [TBDEX_OUT_REFERENCES] ([OUT_ID],[REFERENCE1],[REFERENCE2],[REFERENCE3],[REFERENCE4],[REFERENCE5],[EXTERNAL_REFERENCE1],[EXTERNAL_REFERENCE2],[EXTERNAL_REFERENCE3],[EXTERNAL_REFERENCE4],[EXTERNAL_REFERENCE5],[EXPORT_NUMBER],[ADDED_WHO],[ADDED_WHEN])
SELECT [OI].[OUT_ID],
ISNULL([OI].[REFERENCE1],''),
[OI].[REFERENCE2],
[OI].[REFERENCE3],
[OI].[REFERENCE4],
[OI].[REFERENCE5],
LEFT([OI].[EXTERNAL_REFERENCE1],255),
LEFT([OI].[EXTERNAL_REFERENCE2],255),
LEFT([OI].[EXTERNAL_REFERENCE3],255),
LEFT([OI].[EXTERNAL_REFERENCE4],255),
LEFT([OI].[EXTERNAL_REFERENCE5],255),
[MAP].[EXPORT_NUMBER],
SELECT [OUT_ID],
[REFERENCE1],
[REFERENCE2],
[REFERENCE3],
[REFERENCE4],
[REFERENCE5],
[EXTERNAL_REFERENCE1],
[EXTERNAL_REFERENCE2],
[EXTERNAL_REFERENCE3],
[EXTERNAL_REFERENCE4],
[EXTERNAL_REFERENCE5],
[EXPORT_NUMBER],
@BATCH_CREATOR,
GETDATE()
FROM @vTBDEX_OUT_INSERTED AS [OI]
CROSS APPLY (
SELECT TOP 1 [TPR].[EXPORT_NUMBER]
FROM [TBDEX_TMP_PROCESS_REFERENCES] AS [TPR] WITH (SNAPSHOT)
WHERE [TPR].[PROFILE_ID] = [OI].[PROFILE_ID]
AND [TPR].[BATCH_ID] = [OI].[BATCH_ID]
AND ISNULL([TPR].[REFERENCE1],'') = ISNULL([OI].[REFERENCE1],'')
AND ISNULL([TPR].[REFERENCE2],'') = ISNULL([OI].[REFERENCE2],'')
AND ISNULL([TPR].[REFERENCE3],'') = ISNULL([OI].[REFERENCE3],'')
AND ISNULL([TPR].[REFERENCE4],'') = ISNULL([OI].[REFERENCE4],'')
AND ISNULL([TPR].[REFERENCE5],'') = ISNULL([OI].[REFERENCE5],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE1],'') = ISNULL([OI].[EXTERNAL_REFERENCE1],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE2],'') = ISNULL([OI].[EXTERNAL_REFERENCE2],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE3],'') = ISNULL([OI].[EXTERNAL_REFERENCE3],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE4],'') = ISNULL([OI].[EXTERNAL_REFERENCE4],'')
AND ISNULL([TPR].[EXTERNAL_REFERENCE5],'') = ISNULL([OI].[EXTERNAL_REFERENCE5],'')
AND [TPR].[ADDED_WHO] IN (@BATCH_CREATOR,@MY_PROCEDURE_NAME)
ORDER BY [TPR].[GUID] DESC
) AS [MAP];
FROM [REF_SRC]
WHERE [ROW_NUM] = 1;
COMMIT TRANSACTION;
-----------------------------------------------------------------------------------------------------------------------------------
@@ -537,18 +568,6 @@ END TRY BEGIN CATCH
ROLLBACK TRANSACTION;
END;
PRINT 'ERROR: ' + @RETURN_ERROR_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO','WARN','ERROR')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'ERROR', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = CASE WHEN @RETURN_STATUS > 50000 THEN @RETURN_STATUS ELSE 50000 END;
SET @RETURN_STATUS_TEXT = concat('END PROCEDURE [',@MY_PROCEDURE_NAME,'] @ ',CONVERT(NVARCHAR(50),GETDATE(),120));

View File

@@ -15,7 +15,9 @@ EXEC @return_value = [dbo].[PRDEX_START_PROFILE_EXECUTION]
SELECT 'Return Value' = @return_value
GO
SELECT * FROM [DD_ECM].[dbo].[TBDEX_RUN_LOG]
SELECT [GUID],[PROFILE_ID],[BATCH_ID],[LOG_LEVEL],[REFERENCE1],[REFERENCE2],[REFERENCE3],[REFERENCE4],[REFERENCE5],
[RETURN_CODE],[MESSAGE1],[MESSAGE2],[MESSAGE3],[MESSAGE4],[MESSAGE5],[COMMENT],[ADDED_WHO],[ADDED_WHEN]
FROM [DD_ECM].[dbo].[TBDEX_RUN_LOG]
-- =========================================
-- Validation: OUT <-> OUT_REFERENCES mapping

View File

@@ -44,6 +44,16 @@ GO
ALTER TABLE [dbo].[TBDEX_OUT] CHECK CONSTRAINT [FK_TBDEX_OUT_TBDEX_CONFIG_PROFILE]
GO
CREATE NONCLUSTERED INDEX [IX_TBDEX_OUT_PROFILE_BATCH_ADDED] ON [dbo].[TBDEX_OUT]
(
[PROFILE_ID] ASC,
[BATCH_ID] ASC,
[ADDED_WHEN] DESC
)
WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = ON, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)
ON [PRIMARY]
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Link PROFILE_ID' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'TBDEX_OUT', @level2type=N'CONSTRAINT',@level2name=N'FK_TBDEX_OUT_TBDEX_CONFIG_PROFILE'
GO

View File

@@ -46,6 +46,24 @@ GO
ALTER TABLE [dbo].[TBDEX_OUT_REFERENCES] CHECK CONSTRAINT [FK_TBDEX_OUT_REFERENCES_TBDEX_OUT]
GO
CREATE UNIQUE NONCLUSTERED INDEX [UX_TBDEX_OUT_REFERENCES_OUT_ID_EXPORT_NUMBER] ON [dbo].[TBDEX_OUT_REFERENCES]
(
[OUT_ID] ASC,
[EXPORT_NUMBER] ASC
)
WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = ON, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)
ON [PRIMARY]
GO
CREATE NONCLUSTERED INDEX [IX_TBDEX_OUT_REFERENCES_OUT_ID] ON [dbo].[TBDEX_OUT_REFERENCES]
(
[OUT_ID] ASC,
[GUID] DESC
)
WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = ON, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)
ON [PRIMARY]
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Link OUT_ID' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'TBDEX_OUT_REFERENCES', @level2type=N'CONSTRAINT',@level2name=N'FK_TBDEX_OUT_REFERENCES_TBDEX_OUT'
GO

View File

@@ -45,4 +45,7 @@ GO
ALTER TABLE [dbo].[TBDEX_TMP_PROCESS_REFERENCES] ADD INDEX [IX_TBDEX_TMP_PROCESS_REFERENCES_PROFILE_BATCH] NONCLUSTERED ([PROFILE_ID],[BATCH_ID]);
GO
ALTER TABLE [dbo].[TBDEX_TMP_PROCESS_REFERENCES] ADD INDEX [IX_TBDEX_TMP_PROCESS_REFERENCES_PROFILE_BATCH_EXPORT] NONCLUSTERED ([PROFILE_ID],[BATCH_ID],[EXPORT_NUMBER]);
GO