SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- [PRDEX_WRITE_OUTPUT] -- ================================================================= -- Inserts data to the Output tables -- -- Returns: INTEGER; 0 = ok; 0 <> nicht ok -- ================================================================= -- Copyright (c) 2025 by Digital Data GmbH -- -- Digital Data GmbH • Ludwig-Rinn-Strasse 16 • D-35452 Heuchelheim -- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works -- ================================================================= -- Creation Date / Author: 01.08.2025 / MK -- Version Date / Editor: 01.08.2025 / MK -- Version Number: 1.0.0.0 -- ================================================================= -- History: -- 01.08.2025 / MK - First Version CREATE OR ALTER PROCEDURE [dbo].[PRDEX_WRITE_OUTPUT] @pPROFILE_ID BIGINT, @pTEST_MODE BIT, @pASYNC_MODE BIT, @pBATCH_ID NVARCHAR(25), @pBATCH_CREATOR NVARCHAR(50), @pLANGUAGE NVARCHAR(10), @pLOG_LEVEL NVARCHAR(25), @pSTART_QUERY NVARCHAR(MAX), @pSTART_QUERY_VAR1 NVARCHAR(50), @pSTART_QUERY_VAR2 NVARCHAR(50), @pSTART_QUERY_VAR3 NVARCHAR(50), @pSTART_QUERY_VAR4 NVARCHAR(50), @pSTART_QUERY_VAR5 NVARCHAR(50), @pMAIN_QUERY NVARCHAR(MAX), @pMAIN_QUERY_VAR1 NVARCHAR(50), @pMAIN_QUERY_VAR2 NVARCHAR(50), @pMAIN_QUERY_VAR3 NVARCHAR(50), @pMAIN_QUERY_VAR4 NVARCHAR(50), @pMAIN_QUERY_VAR5 NVARCHAR(50), @pEND_QUERY NVARCHAR(MAX), @pEND_QUERY_VAR1 NVARCHAR(50), @pEND_QUERY_VAR2 NVARCHAR(50), @pEND_QUERY_VAR3 NVARCHAR(50), @pEND_QUERY_VAR4 NVARCHAR(50), @pEND_QUERY_VAR5 NVARCHAR(50), @pFORCE BIT, @pPROFILE_NAME NVARCHAR(50), @pMANDANTOR NVARCHAR(50), @pEXPORT_TYPE NVARCHAR(50), @pEXPORT_NUMBER_SCHEMA NVARCHAR(25), @pDEFAULT_DATA_SEPARATOR NVARCHAR(10), @pTBDEX_TMP_TABLE_SCHEMA SYSNAME, @pTBDEX_TMP_TABLE_NAME SYSNAME, @pTBDEX_TMP_TABLE_SCHEMA_AND_NAME NVARCHAR(150), @pTBDEX_TMP_TABLE_DROP_QUERY NVARCHAR(MAX), @pTBDEX_TMP_TABLE_COLUMNS NVARCHAR(MAX), @pTBDEX_TMP_TABLE_CREATE_QUERY NVARCHAR(MAX), @pTBDEX_TMP_TABLE_INSERT_QUERY NVARCHAR(MAX) AS BEGIN TRY SET NOCOUNT ON; -- declare new vars because of parameter sniffing DECLARE @PROFILE_ID BIGINT = @pPROFILE_ID, @TEST_MODE BIT = @pTEST_MODE, @ASYNC_MODE BIT = @pASYNC_MODE, @BATCH_ID NVARCHAR(25) = @pBATCH_ID, @BATCH_CREATOR NVARCHAR(128) = ISNULL(@pBATCH_CREATOR,OBJECT_NAME(@@PROCID)), @LANGUAGE NVARCHAR(10) = @pLANGUAGE, @LOG_LEVEL NVARCHAR(25) = UPPER(@pLOG_LEVEL), @START_QUERY NVARCHAR(MAX) = @pSTART_QUERY, @START_QUERY_VAR1 NVARCHAR(50) = @pSTART_QUERY_VAR1, @START_QUERY_VAR2 NVARCHAR(50) = @pSTART_QUERY_VAR2, @START_QUERY_VAR3 NVARCHAR(50) = @pSTART_QUERY_VAR3, @START_QUERY_VAR4 NVARCHAR(50) = @pSTART_QUERY_VAR4, @START_QUERY_VAR5 NVARCHAR(50) = @pSTART_QUERY_VAR5, @MAIN_QUERY NVARCHAR(MAX) = @pMAIN_QUERY, @MAIN_QUERY_VAR1 NVARCHAR(50) = @pMAIN_QUERY_VAR1, @MAIN_QUERY_VAR2 NVARCHAR(50) = @pMAIN_QUERY_VAR2, @MAIN_QUERY_VAR3 NVARCHAR(50) = @pMAIN_QUERY_VAR3, @MAIN_QUERY_VAR4 NVARCHAR(50) = @pMAIN_QUERY_VAR4, @MAIN_QUERY_VAR5 NVARCHAR(50) = @pMAIN_QUERY_VAR5, @END_QUERY NVARCHAR(MAX) = @pEND_QUERY, @END_QUERY_VAR1 NVARCHAR(50) = @pEND_QUERY_VAR1, @END_QUERY_VAR2 NVARCHAR(50) = @pEND_QUERY_VAR2, @END_QUERY_VAR3 NVARCHAR(50) = @pEND_QUERY_VAR3, @END_QUERY_VAR4 NVARCHAR(50) = @pEND_QUERY_VAR4, @END_QUERY_VAR5 NVARCHAR(50) = @pEND_QUERY_VAR5, @FORCE BIT = @pFORCE, @PROFILE_NAME NVARCHAR(50) = @pPROFILE_NAME, @MANDANTOR NVARCHAR(50) = @pMANDANTOR, @EXPORT_TYPE NVARCHAR(50) = @pEXPORT_TYPE, @EXPORT_NUMBER_SCHEMA NVARCHAR(25) = @pEXPORT_NUMBER_SCHEMA, @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, @TBDEX_TMP_TABLE_SCHEMA_AND_NAME NVARCHAR(150) = @pTBDEX_TMP_TABLE_SCHEMA_AND_NAME, @TBDEX_TMP_TABLE_COLUMNS NVARCHAR(MAX) = @pTBDEX_TMP_TABLE_COLUMNS, @TBDEX_TMP_TABLE_DROP_QUERY NVARCHAR(MAX) = @pTBDEX_TMP_TABLE_DROP_QUERY, @TBDEX_TMP_TABLE_CREATE_QUERY NVARCHAR(MAX) = @pTBDEX_TMP_TABLE_CREATE_QUERY, @TBDEX_TMP_TABLE_INSERT_QUERY NVARCHAR(MAX) = @pTBDEX_TMP_TABLE_INSERT_QUERY; DECLARE @vTBDEX_OUT_SOURCE TABLE ( [PROFILE_ID] BIGINT, [BATCH_ID] NVARCHAR(25), [CONTENT] NVARCHAR(MAX), [REFERENCE1] NVARCHAR(150), [REFERENCE2] NVARCHAR(150), [REFERENCE3] NVARCHAR(150), [REFERENCE4] NVARCHAR(150), [REFERENCE5] NVARCHAR(150), [EXTERNAL_REFERENCE1] NVARCHAR(2000), [EXTERNAL_REFERENCE2] NVARCHAR(2000), [EXTERNAL_REFERENCE3] NVARCHAR(2000), [EXTERNAL_REFERENCE4] NVARCHAR(2000), [EXTERNAL_REFERENCE5] NVARCHAR(2000) ); DECLARE @vTBDEX_OUT_INSERTED TABLE ( [OUT_ID] BIGINT, [PROFILE_ID] BIGINT, [BATCH_ID] NVARCHAR(25), [REFERENCE1] NVARCHAR(150), [REFERENCE2] NVARCHAR(150), [REFERENCE3] NVARCHAR(150), [REFERENCE4] NVARCHAR(150), [REFERENCE5] NVARCHAR(150), [EXTERNAL_REFERENCE1] NVARCHAR(2000), [EXTERNAL_REFERENCE2] NVARCHAR(2000), [EXTERNAL_REFERENCE3] NVARCHAR(2000), [EXTERNAL_REFERENCE4] NVARCHAR(2000), [EXTERNAL_REFERENCE5] NVARCHAR(2000) ); -- declare runtime vars DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID); DECLARE @ACTIVE_FLAG BIT = 1, @INACTIVE_FLAG BIT = 0, @ROW_COUNT1 INT = 0, @QUERY_KEYWORD NVARCHAR(50) = 'QUERY', @QUERY_SET_OUTPUT NVARCHAR(MAX) = NULL, @PLACEHOLDER_NAME NVARCHAR(50) = NULL, @PLACEHOLDER NVARCHAR(MAX) = NULL, @PLACEHOLDER_TYPE NVARCHAR(10) = 'CONST', @REFERENCE1 NVARCHAR(150) = NULL, @REFERENCE2 NVARCHAR(150) = NULL, @REFERENCE3 NVARCHAR(150) = NULL, @REFERENCE4 NVARCHAR(150) = NULL, @REFERENCE5 NVARCHAR(150) = NULL, @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) = ''; PRINT '===================================================================================================='; PRINT @RETURN_STATUS_TEXT; PRINT ''; PRINT 'PARAMETER01 - @PROFILE_ID: ' + CONVERT(NVARCHAR(50),ISNULL(@PROFILE_ID,'')); PRINT 'PARAMETER02 - @TEST_MODE: ' + CONVERT(NVARCHAR(50),ISNULL(@TEST_MODE,'')); PRINT 'PARAMETER03 - @ASYNC_MODE: ' + CONVERT(NVARCHAR(50),ISNULL(@ASYNC_MODE,'')); PRINT 'PARAMETER04 - @BATCH_ID: ' + CONVERT(NVARCHAR(50),ISNULL(@BATCH_ID,'')); PRINT 'PARAMETER05 - @BATCH_CREATOR: ' + CONVERT(NVARCHAR(50),ISNULL(@BATCH_CREATOR,'')); PRINT 'PARAMETER06 - @LANGUAGE: ' + CONVERT(NVARCHAR(50),ISNULL(@LANGUAGE,'')); PRINT 'PARAMETER07 - @LOG_LEVEL: ' + CONVERT(NVARCHAR(50),ISNULL(@LOG_LEVEL,'')); PRINT 'PARAMETER08 - @START_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY,'')); PRINT 'PARAMETER09 - @START_QUERY_VAR1: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR1,'')); PRINT 'PARAMETER10 - @START_QUERY_VAR2: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR2,'')); PRINT 'PARAMETER11 - @START_QUERY_VAR3: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR3,'')); PRINT 'PARAMETER12 - @START_QUERY_VAR4: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR4,'')); PRINT 'PARAMETER13 - @START_QUERY_VAR5: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR5,'')); PRINT 'PARAMETER14 - @MAIN_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY,'')); PRINT 'PARAMETER15 - @MAIN_QUERY_VAR1: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR1,'')); PRINT 'PARAMETER16 - @MAIN_QUERY_VAR2: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR2,'')); PRINT 'PARAMETER17 - @MAIN_QUERY_VAR3: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR3,'')); PRINT 'PARAMETER18 - @MAIN_QUERY_VAR4: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR4,'')); PRINT 'PARAMETER19 - @MAIN_QUERY_VAR5: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR5,'')); PRINT 'PARAMETER20 - @END_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY,'')); PRINT 'PARAMETER21 - @END_QUERY_VAR1: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR1,'')); PRINT 'PARAMETER22 - @END_QUERY_VAR2: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR2,'')); PRINT 'PARAMETER23 - @END_QUERY_VAR3: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR3,'')); PRINT 'PARAMETER24 - @END_QUERY_VAR4: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR4,'')); PRINT 'PARAMETER25 - @END_QUERY_VAR5: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR5,'')); PRINT 'PARAMETER26 - @FORCE: ' + CONVERT(NVARCHAR(50),ISNULL(@FORCE,'')); PRINT 'PARAMETER27 - @PROFILE_NAME: ' + CONVERT(NVARCHAR(50),ISNULL(@PROFILE_NAME,'')); PRINT 'PARAMETER28 - @MANDANTOR: ' + CONVERT(NVARCHAR(50),ISNULL(@MANDANTOR,'')); PRINT 'PARAMETER29 - @EXPORT_TYPE: ' + CONVERT(NVARCHAR(50),ISNULL(@EXPORT_TYPE,'')); PRINT 'PARAMETER30 - @DEFAULT_DATA_SEPARATOR: ' + CONVERT(NVARCHAR(50),ISNULL(@DEFAULT_DATA_SEPARATOR,'')); PRINT 'PARAMETER31 - @TBDEX_TMP_TABLE_SCHEMA: ' + CONVERT(NVARCHAR(50),ISNULL(@TBDEX_TMP_TABLE_SCHEMA,'')); PRINT 'PARAMETER32 - @TBDEX_TMP_TABLE_NAME: ' + CONVERT(NVARCHAR(50),ISNULL(@TBDEX_TMP_TABLE_NAME,'')); PRINT 'PARAMETER33 - @TBDEX_TMP_TABLE_SCHEMA_AND_NAME: ' + CONVERT(NVARCHAR(50),ISNULL(@TBDEX_TMP_TABLE_SCHEMA_AND_NAME,'')); PRINT 'PARAMETER34 - @TBDEX_TMP_TABLE_COLUMNS: ' + CONVERT(NVARCHAR(50),ISNULL(@TBDEX_TMP_TABLE_COLUMNS,'')); PRINT 'PARAMETER35 - @TBDEX_TMP_TABLE_DROP_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@TBDEX_TMP_TABLE_DROP_QUERY,'')); PRINT 'PARAMETER36 - @TBDEX_TMP_TABLE_CREATE_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@TBDEX_TMP_TABLE_CREATE_QUERY,'')); PRINT 'PARAMETER37 - @TBDEX_TMP_TABLE_INSERT_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@TBDEX_TMP_TABLE_INSERT_QUERY,'')); PRINT ''; --===================================================-- Log result to table --===================================================-- IF (@LOG_LEVEL in ('INFO')) BEGIN EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @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; ----------------------------------------------------------------------------------------------------------------------------------- --====================================================-- Get end sql query --====================================================-- IF (((UPPER(@END_QUERY) LIKE 'SELECT%') OR (UPPER(@END_QUERY) LIKE '%SELECT%')) AND (UPPER(@END_QUERY) LIKE '%FROM%')) BEGIN SET @QUERY_SET_OUTPUT = LTRIM(RTRIM(@END_QUERY)); END; ELSE IF ((SELECT count(*) FROM [TBDEX_CFG_RESOURCES] WHERE [PROFILE_ID] IN (0,@PROFILE_ID) AND [ACTIVE] = @ACTIVE_FLAG AND LTRIM(RTRIM([PLACEHOLDER_NAME])) = @END_QUERY AND LTRIM(RTRIM([PLACEHOLDER_TYPE])) = @QUERY_KEYWORD) >= 1) BEGIN SET @QUERY_SET_OUTPUT = (SELECT TOP 1 LTRIM(RTRIM([PLACEHOLDER])) FROM [TBDEX_CFG_RESOURCES] WHERE [PROFILE_ID] IN (@PROFILE_ID,0) AND [ACTIVE] = @ACTIVE_FLAG AND LTRIM(RTRIM([PLACEHOLDER_NAME])) = @END_QUERY AND LTRIM(RTRIM([PLACEHOLDER_TYPE])) = @QUERY_KEYWORD ORDER BY [PROFILE_ID] ASC,[GUID] DESC); END; ----------------------------------------------------------------------------------------------------------------------------------- --=================================================-- Check first sql query --===================================================-- IF (LEN(@QUERY_SET_OUTPUT) < 15) BEGIN --====================================================-- exception / error --====================================================-- SET @RETURN_STATUS = 50001; SET @RETURN_STATUS_TEXT = concat('Wrong call or configuraton!',''); SET @RETURN_ERROR_TEXT = concat('Found no valid querys (query needs to be 15 chars or more)!',''); THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1; ----------------------------------------------------------------------------------------------------------------------------------- END; ELSE BEGIN --======================================================-- Output result --======================================================-- SET @RETURN_STATUS = 0; SET @RETURN_STATUS_TEXT = concat('Found "QUERY_SET_OUTPUT" query: ',char(13),@QUERY_SET_OUTPUT); SET @RETURN_ERROR_TEXT = concat('',''); PRINT 'INFO: ' + @RETURN_STATUS_TEXT; ----------------------------------------------------------------------------------------------------------------------------------- --===================================================-- Log result to table --===================================================-- IF (@LOG_LEVEL in ('INFO')) BEGIN EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @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; ----------------------------------------------------------------------------------------------------------------------------------- END; ----------------------------------------------------------------------------------------------------------------------------------- --==============================================-- Get data separator for cols --===============================================-- IF (LEN(@DEFAULT_DATA_SEPARATOR) > 0) BEGIN SET @TBDEX_TMP_TABLE_COLUMNS = REPLACE(@TBDEX_TMP_TABLE_COLUMNS,',',@DEFAULT_DATA_SEPARATOR) --======================================================-- Output result --======================================================-- SET @RETURN_STATUS = 0; SET @RETURN_STATUS_TEXT = concat('The @TBDEX_TMP_TABLE_COLUMNS variable has been modified by the @DEFAULT_DATA_SEPARATOR variable: ',@TBDEX_TMP_TABLE_COLUMNS); SET @RETURN_ERROR_TEXT = concat('',''); PRINT 'INFO: ' + @RETURN_STATUS_TEXT; ----------------------------------------------------------------------------------------------------------------------------------- --===================================================-- Log result to table --===================================================-- IF (@LOG_LEVEL in ('INFO')) BEGIN EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @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; ----------------------------------------------------------------------------------------------------------------------------------- END; ELSE BEGIN --======================================================-- Output result --======================================================-- SET @RETURN_STATUS = 0; SET @RETURN_STATUS_TEXT = concat('The @TBDEX_TMP_TABLE_COLUMNS variable has NOT been modified by the @DEFAULT_DATA_SEPARATOR variable: ',@TBDEX_TMP_TABLE_COLUMNS); SET @RETURN_ERROR_TEXT = concat('',''); PRINT 'INFO: ' + @RETURN_STATUS_TEXT; ----------------------------------------------------------------------------------------------------------------------------------- --===================================================-- Log result to table --===================================================-- IF (@LOG_LEVEL in ('INFO')) BEGIN EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @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; ----------------------------------------------------------------------------------------------------------------------------------- END; ----------------------------------------------------------------------------------------------------------------------------------- --==================================================-- Handle placeholders --==================================================-- PRINT 'Replacing placeholders...'; SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%PROFILE_ID%',ISNULL(@PROFILE_ID,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%TEST_MODE%',ISNULL(@TEST_MODE,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%ASYNC_MODE%',ISNULL(@ASYNC_MODE,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%BATCH_ID%',ISNULL(@BATCH_ID,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%BATCH_CREATOR%',ISNULL(@BATCH_CREATOR,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%LANGUAGE%',ISNULL(@LANGUAGE,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%LOG_LEVEL%',ISNULL(@LOG_LEVEL,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%START_QUERY%',ISNULL(@START_QUERY,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%START_QUERY_VAR1%',ISNULL(@START_QUERY_VAR1,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%START_QUERY_VAR2%',ISNULL(@START_QUERY_VAR2,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%START_QUERY_VAR3%',ISNULL(@START_QUERY_VAR3,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%START_QUERY_VAR4%',ISNULL(@START_QUERY_VAR4,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%START_QUERY_VAR5%',ISNULL(@START_QUERY_VAR5,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%MAIN_QUERY%',ISNULL(@MAIN_QUERY,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%MAIN_QUERY_VAR1%',ISNULL(@MAIN_QUERY_VAR1,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%MAIN_QUERY_VAR2%',ISNULL(@MAIN_QUERY_VAR2,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%MAIN_QUERY_VAR3%',ISNULL(@MAIN_QUERY_VAR3,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%MAIN_QUERY_VAR4%',ISNULL(@MAIN_QUERY_VAR4,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%MAIN_QUERY_VAR5%',ISNULL(@MAIN_QUERY_VAR5,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%END_QUERY%',ISNULL(@END_QUERY,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%END_QUERY_VAR1%',ISNULL(@END_QUERY_VAR1,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%END_QUERY_VAR2%',ISNULL(@END_QUERY_VAR2,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%END_QUERY_VAR3%',ISNULL(@END_QUERY_VAR3,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%END_QUERY_VAR4%',ISNULL(@END_QUERY_VAR4,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%END_QUERY_VAR5%',ISNULL(@END_QUERY_VAR5,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%FORCE%',ISNULL(@FORCE,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%MY_PROCEDURE_NAME%',ISNULL(@MY_PROCEDURE_NAME,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%PROFILE_NAME%',ISNULL(@PROFILE_NAME,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%MANDANTOR%',ISNULL(@MANDANTOR,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%EXPORT_TYPE%',ISNULL(@EXPORT_TYPE,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%DEFAULT_DATA_SEPARATOR%',ISNULL(@DEFAULT_DATA_SEPARATOR,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%REFERENCE1%',ISNULL(@REFERENCE1,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%REFERENCE2%',ISNULL(@REFERENCE2,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%REFERENCE3%',ISNULL(@REFERENCE3,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%REFERENCE4%',ISNULL(@REFERENCE4,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%REFERENCE5%',ISNULL(@REFERENCE5,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%TBDEX_TMP_TABLE_SCHEMA%',ISNULL(@TBDEX_TMP_TABLE_SCHEMA,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%TBDEX_TMP_TABLE_NAME%',ISNULL(@TBDEX_TMP_TABLE_NAME,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%TBDEX_TMP_TABLE_COLUMNS%',ISNULL(@TBDEX_TMP_TABLE_COLUMNS,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%TBDEX_TMP_TABLE_DROP_QUERY%',ISNULL(@TBDEX_TMP_TABLE_DROP_QUERY,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%TBDEX_TMP_TABLE_CREATE_QUERY%',ISNULL(@TBDEX_TMP_TABLE_CREATE_QUERY,'')); SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,'%TBDEX_TMP_TABLE_INSERT_QUERY%',ISNULL(@TBDEX_TMP_TABLE_INSERT_QUERY,'')); DECLARE CURSOR_PLACEHOLDER CURSOR LOCAL FAST_FORWARD FOR SELECT [PLACEHOLDER_NAME] as 'Placeholder_Name', [PLACEHOLDER] as 'Placeholder' FROM [TBDEX_CFG_RESOURCES] 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 BEGIN SET @QUERY_SET_OUTPUT = REPLACE(@QUERY_SET_OUTPUT,concat('%',@PLACEHOLDER_NAME,'%'),ISNULL(@PLACEHOLDER,'')); FETCH NEXT FROM CURSOR_PLACEHOLDER INTO @PLACEHOLDER_NAME,@PLACEHOLDER; END CLOSE CURSOR_PLACEHOLDER; DEALLOCATE CURSOR_PLACEHOLDER; ----------------------------------------------------------------------------------------------------------------------------------- --======================================================-- Output result --======================================================-- SET @RETURN_STATUS = 0; SET @RETURN_STATUS_TEXT = concat('Prepared "@QUERY_SET_OUTPUT" (length: ',LEN(@QUERY_SET_OUTPUT),', preview: ',LEFT(@QUERY_SET_OUTPUT,500),')'); SET @RETURN_ERROR_TEXT = concat('',''); PRINT 'INFO: ' + @RETURN_STATUS_TEXT; ----------------------------------------------------------------------------------------------------------------------------------- --===================================================-- Log result to table --===================================================-- IF (@LOG_LEVEL in ('INFO')) BEGIN EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @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; ----------------------------------------------------------------------------------------------------------------------------------- --======================================================-- Safety checks --======================================================-- EXEC [PRDEX_TEST_DYNAMIC_SQL] @pQUERY = @QUERY_SET_OUTPUT, @pRETURN_STATUS = 50054, @pQUERY_NAME = N'@QUERY_SET_OUTPUT'; ----------------------------------------------------------------------------------------------------------------------------------- --==================================================-- 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; ----------------------------------------------------------------------------------------------------------------------------------- BEGIN TRANSACTION; MERGE [TBDEX_OUT] AS [T] USING ( SELECT [SRC].[PROFILE_ID], [SRC].[BATCH_ID], [SRC].[CONTENT], [SRC].[REFERENCE1], [SRC].[REFERENCE2], [SRC].[REFERENCE3], [SRC].[REFERENCE4], [SRC].[REFERENCE5], [SRC].[EXTERNAL_REFERENCE1], [SRC].[EXTERNAL_REFERENCE2], [SRC].[EXTERNAL_REFERENCE3], [SRC].[EXTERNAL_REFERENCE4], [SRC].[EXTERNAL_REFERENCE5] FROM @vTBDEX_OUT_SOURCE AS [SRC] ) AS [S] ON 1 = 0 WHEN NOT MATCHED THEN INSERT ([PROFILE_ID],[BATCH_ID],[CONTENT],[ADDED_WHO],[ADDED_WHEN]) VALUES ([S].[PROFILE_ID],[S].[BATCH_ID],[S].[CONTENT],@BATCH_CREATOR,GETDATE()) OUTPUT INSERTED.[GUID], [S].[PROFILE_ID], [S].[BATCH_ID], [S].[REFERENCE1], [S].[REFERENCE2], [S].[REFERENCE3], [S].[REFERENCE4], [S].[REFERENCE5], [S].[EXTERNAL_REFERENCE1], [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]); 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] WHERE [MAP].[EXPORT_NUMBER] IS NULL ) BEGIN SET @RETURN_STATUS = 50058; SET @RETURN_STATUS_TEXT = concat('Missing EXPORT_NUMBER mapping for output references!',''); SET @RETURN_ERROR_TEXT = concat('Could not resolve [TBDEX_TMP_PROCESS_REFERENCES].[EXPORT_NUMBER] for at least one output row.',''); THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1; END; 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], @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]; COMMIT TRANSACTION; ----------------------------------------------------------------------------------------------------------------------------------- --======================================================-- Output result --======================================================-- SET @RETURN_STATUS = 0; SET @RETURN_STATUS_TEXT = concat('END PROCEDURE [',@MY_PROCEDURE_NAME,'] @ ',CONVERT(NVARCHAR(50),GETDATE(),120)); SET @RETURN_ERROR_TEXT = concat('',''); PRINT ''; PRINT @RETURN_STATUS_TEXT; PRINT '===================================================================================================='; ----------------------------------------------------------------------------------------------------------------------------------- --===================================================-- Log result to table --===================================================-- IF (@LOG_LEVEL in ('INFO')) BEGIN EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @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; ----------------------------------------------------------------------------------------------------------------------------------- RETURN @RETURN_STATUS; END TRY BEGIN CATCH --====================================================-- exception / error --====================================================-- IF (@@TRANCOUNT > 0) BEGIN 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)); SET @RETURN_ERROR_TEXT = concat('ERROR MESSAGE: ',CONVERT(NVARCHAR(500),ERROR_MESSAGE())); PRINT 'ERROR IN PROCEDURE: [' + @MY_PROCEDURE_NAME + ']' + char(13) + @RETURN_ERROR_TEXT; PRINT @RETURN_STATUS_TEXT; PRINT '===================================================================================================='; ----------------------------------------------------------------------------------------------------------------------------------- --===================================================-- 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; ----------------------------------------------------------------------------------------------------------------------------------- RETURN @RETURN_STATUS; END CATCH; GO