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

@@ -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));