8
0
Files
Skriptentwickung/current/[DD_ECM]-Database/DEX_SQL/[PRDEX_SET_QUERY].sql
2026-02-24 16:43:48 +01:00

419 lines
54 KiB
Transact-SQL
Raw Blame History

This file contains invisible Unicode characters
This file contains invisible Unicode characters that are indistinguishable to humans but may be processed differently by a computer. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- [PRDEX_SET_QUERY]
-- =================================================================
-- Prepares querys, resolves placeholders and runtime vars
--
-- 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_SET_QUERY](
@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),
@pREFERENCE1 NVARCHAR(150),
@pREFERENCE2 NVARCHAR(150),
@pREFERENCE3 NVARCHAR(150),
@pREFERENCE4 NVARCHAR(150),
@pREFERENCE5 NVARCHAR(150),
@pEXTERNAL_REFERENCE1 NVARCHAR(2000),
@pEXTERNAL_REFERENCE2 NVARCHAR(2000),
@pEXTERNAL_REFERENCE3 NVARCHAR(2000),
@pEXTERNAL_REFERENCE4 NVARCHAR(2000),
@pEXTERNAL_REFERENCE5 NVARCHAR(2000)
)
AS
BEGIN TRY
SET NOCOUNT ON;
SET XACT_ABORT 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(ISNULL(@pLOG_LEVEL,'INFO')),
@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(500) = @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(10) = @pDEFAULT_DATA_SEPARATOR,
@REFERENCE1 NVARCHAR(150) = @pREFERENCE1,
@REFERENCE2 NVARCHAR(150) = @pREFERENCE2,
@REFERENCE3 NVARCHAR(150) = @pREFERENCE3,
@REFERENCE4 NVARCHAR(150) = @pREFERENCE4,
@REFERENCE5 NVARCHAR(150) = @pREFERENCE5,
@EXTERNAL_REFERENCE1 NVARCHAR(2000) = @pEXTERNAL_REFERENCE1,
@EXTERNAL_REFERENCE2 NVARCHAR(2000) = @pEXTERNAL_REFERENCE2,
@EXTERNAL_REFERENCE3 NVARCHAR(2000) = @pEXTERNAL_REFERENCE3,
@EXTERNAL_REFERENCE4 NVARCHAR(2000) = @pEXTERNAL_REFERENCE4,
@EXTERNAL_REFERENCE5 NVARCHAR(2000) = @pEXTERNAL_REFERENCE5;
-- declare runtime vars
DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID);
DECLARE @ACTIVE_FLAG BIT = 1,
@INACTIVE_FLAG BIT = 0,
@ROW_COUNT1 SMALLINT = 0,
@QUERY_KEYWORD NVARCHAR(50) = 'QUERY',
@TBDEX_TMP_QUERY_GUID BIGINT = 0,
@TBDEX_TMP_QUERY_QUERY NVARCHAR(MAX) = NULL,
@PLACEHOLDER_NAME NVARCHAR(50) = NULL,
@PLACEHOLDER NVARCHAR(MAX) = 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,'<NO-VALUE>'));
PRINT 'PARAMETER02 - @TEST_MODE: ' + CONVERT(NVARCHAR(50),ISNULL(@TEST_MODE,'<NO-VALUE>'));
PRINT 'PARAMETER03 - @ASYNC_MODE: ' + CONVERT(NVARCHAR(50),ISNULL(@ASYNC_MODE,'<NO-VALUE>'));
PRINT 'PARAMETER04 - @BATCH_ID: ' + CONVERT(NVARCHAR(50),ISNULL(@BATCH_ID,'<NO-VALUE>'));
PRINT 'PARAMETER05 - @BATCH_CREATOR: ' + CONVERT(NVARCHAR(50),ISNULL(@BATCH_CREATOR,'<NO-VALUE>'));
PRINT 'PARAMETER06 - @LANGUAGE: ' + CONVERT(NVARCHAR(50),ISNULL(@LANGUAGE,'<NO-VALUE>'));
PRINT 'PARAMETER07 - @LOG_LEVEL: ' + CONVERT(NVARCHAR(50),ISNULL(@LOG_LEVEL,'<NO-VALUE>'));
PRINT 'PARAMETER08 - @START_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY,'<NO-VALUE>'));
PRINT 'PARAMETER09 - @START_QUERY_VAR1: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR1,'<NO-VALUE>'));
PRINT 'PARAMETER10 - @START_QUERY_VAR2: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR2,'<NO-VALUE>'));
PRINT 'PARAMETER11 - @START_QUERY_VAR3: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR3,'<NO-VALUE>'));
PRINT 'PARAMETER12 - @START_QUERY_VAR4: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR4,'<NO-VALUE>'));
PRINT 'PARAMETER13 - @START_QUERY_VAR5: ' + CONVERT(NVARCHAR(50),ISNULL(@START_QUERY_VAR5,'<NO-VALUE>'));
PRINT 'PARAMETER14 - @MAIN_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY,'<NO-VALUE>'));
PRINT 'PARAMETER15 - @MAIN_QUERY_VAR1: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR1,'<NO-VALUE>'));
PRINT 'PARAMETER16 - @MAIN_QUERY_VAR2: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR2,'<NO-VALUE>'));
PRINT 'PARAMETER17 - @MAIN_QUERY_VAR3: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR3,'<NO-VALUE>'));
PRINT 'PARAMETER18 - @MAIN_QUERY_VAR4: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR4,'<NO-VALUE>'));
PRINT 'PARAMETER19 - @MAIN_QUERY_VAR5: ' + CONVERT(NVARCHAR(50),ISNULL(@MAIN_QUERY_VAR5,'<NO-VALUE>'));
PRINT 'PARAMETER20 - @END_QUERY: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY,'<NO-VALUE>'));
PRINT 'PARAMETER21 - @END_QUERY_VAR1: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR1,'<NO-VALUE>'));
PRINT 'PARAMETER22 - @END_QUERY_VAR2: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR2,'<NO-VALUE>'));
PRINT 'PARAMETER23 - @END_QUERY_VAR3: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR3,'<NO-VALUE>'));
PRINT 'PARAMETER24 - @END_QUERY_VAR4: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR4,'<NO-VALUE>'));
PRINT 'PARAMETER25 - @END_QUERY_VAR5: ' + CONVERT(NVARCHAR(50),ISNULL(@END_QUERY_VAR5,'<NO-VALUE>'));
PRINT 'PARAMETER26 - @FORCE: ' + CONVERT(NVARCHAR(50),ISNULL(@FORCE,'<NO-VALUE>'));
PRINT 'PARAMETER27 - @PROFILE_NAME: ' + CONVERT(NVARCHAR(50),ISNULL(@PROFILE_NAME,'<NO-VALUE>'));
PRINT 'PARAMETER28 - @MANDANTOR: ' + CONVERT(NVARCHAR(50),ISNULL(@MANDANTOR,'<NO-VALUE>'));
PRINT 'PARAMETER29 - @EXPORT_TYPE: ' + CONVERT(NVARCHAR(50),ISNULL(@EXPORT_TYPE,'<NO-VALUE>'));
PRINT 'PARAMETER30 - @DEFAULT_DATA_SEPARATOR: ' + CONVERT(NVARCHAR(50),ISNULL(@DEFAULT_DATA_SEPARATOR,'<NO-VALUE>'));
PRINT 'PARAMETER31 - @REFERENCE1: ' + CONVERT(NVARCHAR(50),ISNULL(@REFERENCE1,'<NO-VALUE>'));
PRINT 'PARAMETER32 - @REFERENCE2: ' + CONVERT(NVARCHAR(50),ISNULL(@REFERENCE2,'<NO-VALUE>'));
PRINT 'PARAMETER33 - @REFERENCE3: ' + CONVERT(NVARCHAR(50),ISNULL(@REFERENCE3,'<NO-VALUE>'));
PRINT 'PARAMETER34 - @REFERENCE4: ' + CONVERT(NVARCHAR(50),ISNULL(@REFERENCE4,'<NO-VALUE>'));
PRINT 'PARAMETER35 - @REFERENCE5: ' + CONVERT(NVARCHAR(50),ISNULL(@REFERENCE5,'<NO-VALUE>'));
PRINT 'PARAMETER36 - @EXTERNAL_REFERENCE1: ' + CONVERT(NVARCHAR(50),ISNULL(@EXTERNAL_REFERENCE1,'<NO-VALUE>'));
PRINT 'PARAMETER37 - @EXTERNAL_REFERENCE2: ' + CONVERT(NVARCHAR(50),ISNULL(@EXTERNAL_REFERENCE2,'<NO-VALUE>'));
PRINT 'PARAMETER38 - @EXTERNAL_REFERENCE3: ' + CONVERT(NVARCHAR(50),ISNULL(@EXTERNAL_REFERENCE3,'<NO-VALUE>'));
PRINT 'PARAMETER39 - @EXTERNAL_REFERENCE4: ' + CONVERT(NVARCHAR(50),ISNULL(@EXTERNAL_REFERENCE4,'<NO-VALUE>'));
PRINT 'PARAMETER40 - @EXTERNAL_REFERENCE5: ' + CONVERT(NVARCHAR(50),ISNULL(@EXTERNAL_REFERENCE5,'<NO-VALUE>'));
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 main sql query --====================================================--
IF (((UPPER(@MAIN_QUERY) LIKE 'SELECT%') OR (UPPER(@MAIN_QUERY) LIKE '%SELECT%')) AND (UPPER(@MAIN_QUERY) LIKE '%FROM%')) BEGIN
INSERT INTO [TBDEX_TMP_QUERY]([PROFILE_ID],[BATCH_ID],[QUERY], [COMMENT], [ADDED_WHO], [ADDED_WHEN])
SELECT @PROFILE_ID, @BATCH_ID, LTRIM(RTRIM(@MAIN_QUERY)),'AdHoc-Query',@MY_PROCEDURE_NAME,getdate();
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])) = @MAIN_QUERY AND LTRIM(RTRIM([PLACEHOLDER_TYPE])) = @QUERY_KEYWORD) >= 1) BEGIN
INSERT INTO [TBDEX_TMP_QUERY]([PROFILE_ID],[BATCH_ID],[QUERY], [COMMENT], [ADDED_WHO], [ADDED_WHEN])
SELECT @PROFILE_ID, @BATCH_ID, LTRIM(RTRIM([PLACEHOLDER])),'Setup-Query',@MY_PROCEDURE_NAME,getdate()
FROM [TBDEX_CFG_RESOURCES]
WHERE [PROFILE_ID] IN (0,@PROFILE_ID) AND [ACTIVE] = @ACTIVE_FLAG AND LTRIM(RTRIM([PLACEHOLDER_NAME])) = @MAIN_QUERY AND LTRIM(RTRIM([PLACEHOLDER_TYPE])) = @QUERY_KEYWORD
ORDER BY [SEQUENCE],[GUID] ASC;
END;
-----------------------------------------------------------------------------------------------------------------------------------
--==================================================-- Count main sql querys --==================================================--
SET @ROW_COUNT1 = 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]=@MY_PROCEDURE_NAME),0);
IF (@ROW_COUNT1 = 0) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50005;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('Insufficient data lines in [TBDEX_TMP_QUERY] found! ','@ROW_COUNT1: ',@ROW_COUNT1);
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Found: ',@ROW_COUNT1,' in the TBDEX_TMP_QUERY table');
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 '';
PRINT 'Replacing placeholders...';
BEGIN TRANSACTION;
DECLARE CURSOR_REPLACE_PLACEHOLDER_IN_QUERY CURSOR
LOCAL FAST_FORWARD FOR
SELECT [GUID] as 'TBDEX_TMP_QUERY_GUID',
[QUERY] as 'TBDEX_TMP_QUERY_QUERY'
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] in (@BATCH_CREATOR,@MY_PROCEDURE_NAME)
ORDER BY [GUID] ASC;
OPEN CURSOR_REPLACE_PLACEHOLDER_IN_QUERY
FETCH NEXT FROM CURSOR_REPLACE_PLACEHOLDER_IN_QUERY INTO @TBDEX_TMP_QUERY_GUID,@TBDEX_TMP_QUERY_QUERY;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%PROFILE_ID%',ISNULL(@PROFILE_ID,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%TEST_MODE%',ISNULL(@TEST_MODE,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%ASYNC_MODE%',ISNULL(@ASYNC_MODE,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%BATCH_ID%',ISNULL(@BATCH_ID,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%BATCH_CREATOR%',ISNULL(@BATCH_CREATOR,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%LANGUAGE%',ISNULL(@LANGUAGE,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%LOG_LEVEL%',ISNULL(@LOG_LEVEL,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%START_QUERY%',ISNULL(@START_QUERY,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%START_QUERY_VAR1%',ISNULL(@START_QUERY_VAR1,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%START_QUERY_VAR2%',ISNULL(@START_QUERY_VAR2,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%START_QUERY_VAR3%',ISNULL(@START_QUERY_VAR3,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%START_QUERY_VAR4%',ISNULL(@START_QUERY_VAR4,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%START_QUERY_VAR5%',ISNULL(@START_QUERY_VAR5,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%MAIN_QUERY%',ISNULL(@MAIN_QUERY,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%MAIN_QUERY_VAR1%',ISNULL(@MAIN_QUERY_VAR1,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%MAIN_QUERY_VAR2%',ISNULL(@MAIN_QUERY_VAR2,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%MAIN_QUERY_VAR3%',ISNULL(@MAIN_QUERY_VAR3,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%MAIN_QUERY_VAR4%',ISNULL(@MAIN_QUERY_VAR4,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%MAIN_QUERY_VAR5%',ISNULL(@MAIN_QUERY_VAR5,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%END_QUERY%',ISNULL(@END_QUERY,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%END_QUERY_VAR1%',ISNULL(@END_QUERY_VAR1,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%END_QUERY_VAR2%',ISNULL(@END_QUERY_VAR2,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%END_QUERY_VAR3%',ISNULL(@END_QUERY_VAR3,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%END_QUERY_VAR4%',ISNULL(@END_QUERY_VAR4,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%END_QUERY_VAR5%',ISNULL(@END_QUERY_VAR5,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%FORCE%',ISNULL(@FORCE,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%MY_PROCEDURE_NAME%',ISNULL(@MY_PROCEDURE_NAME,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%PROFILE_NAME%',ISNULL(@PROFILE_NAME,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%MANDANTOR%',ISNULL(@MANDANTOR,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%EXPORT_TYPE%',ISNULL(@EXPORT_TYPE,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%EXPORT_NUMBER_SCHEMA%',ISNULL(@EXPORT_NUMBER_SCHEMA,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%REFERENCE1%',ISNULL(@REFERENCE1,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%REFERENCE2%',ISNULL(@REFERENCE2,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%REFERENCE3%',ISNULL(@REFERENCE3,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%REFERENCE4%',ISNULL(@REFERENCE4,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%REFERENCE5%',ISNULL(@REFERENCE5,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%EXTERNAL_REFERENCE1%',ISNULL(@EXTERNAL_REFERENCE1,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%EXTERNAL_REFERENCE2%',ISNULL(@EXTERNAL_REFERENCE2,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%EXTERNAL_REFERENCE3%',ISNULL(@EXTERNAL_REFERENCE3,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%EXTERNAL_REFERENCE4%',ISNULL(@EXTERNAL_REFERENCE4,''));
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,'%EXTERNAL_REFERENCE5%',ISNULL(@EXTERNAL_REFERENCE5,''));
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])) = 'CONST'
ORDER BY [SEQUENCE] ASC;
OPEN CURSOR_PLACEHOLDER
FETCH NEXT FROM CURSOR_PLACEHOLDER INTO @PLACEHOLDER_NAME,@PLACEHOLDER;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @TBDEX_TMP_QUERY_QUERY = REPLACE(@TBDEX_TMP_QUERY_QUERY,concat('%',@PLACEHOLDER_NAME,'%'),ISNULL(@PLACEHOLDER,''));
FETCH NEXT FROM CURSOR_PLACEHOLDER INTO @PLACEHOLDER_NAME,@PLACEHOLDER;
END
CLOSE CURSOR_PLACEHOLDER;
DEALLOCATE CURSOR_PLACEHOLDER;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Safety checks --======================================================--
EXEC [PRDEX_TEST_DYNAMIC_SQL] @pQUERY = @TBDEX_TMP_QUERY_QUERY,
@pRETURN_STATUS = 50052,
@pQUERY_NAME = N'@TBDEX_TMP_QUERY_QUERY';
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('The complete resolved "@TBDEX_TMP_QUERY_QUERY" query: ',char(13),@TBDEX_TMP_QUERY_QUERY);
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;
-----------------------------------------------------------------------------------------------------------------------------------
--===============================================-- After replacing palaceholder --==============================================--
UPDATE [TBDEX_TMP_QUERY]
SET [QUERY] = @TBDEX_TMP_QUERY_QUERY
WHERE [GUID] = @TBDEX_TMP_QUERY_GUID AND [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID AND [QUERY] IS NOT NULL AND [ADDED_WHO]=@BATCH_CREATOR
-----------------------------------------------------------------------------------------------------------------------------------
FETCH NEXT FROM CURSOR_REPLACE_PLACEHOLDER_IN_QUERY INTO @TBDEX_TMP_QUERY_GUID,@TBDEX_TMP_QUERY_QUERY;
END
CLOSE CURSOR_REPLACE_PLACEHOLDER_IN_QUERY;
DEALLOCATE CURSOR_REPLACE_PLACEHOLDER_IN_QUERY;
IF (@@TRANCOUNT > 0) BEGIN
COMMIT TRANSACTION;
END;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- 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;