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

284 lines
33 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_REGISTER_PROCESS]
-- =================================================================
-- Writes log mesages to table [TBDEX_RUN_LOG]
--
-- 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_REGISTER_PROCESS](
@pPROFILE_ID BIGINT,
@pTEST_MODE BIT,
@pASYNC_MODE BIT,
@pBATCH_ID NVARCHAR(25),
@pBATCH_CREATOR NVARCHAR(50),
@pLANGUAGE NVARCHAR(10),
@pLOG_LEVEL NVARCHAR(25),
@pFORCE BIT,
@pPROFILE_NAME NVARCHAR(50),
@pMANDANTOR NVARCHAR(50),
@pEXPORT_TYPE NVARCHAR(50),
@pEXPORT_NUMBER_SCHEMA NVARCHAR(25),
@pDEFAULT_DATA_SEPARATOR NVARCHAR(10)
)
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(ISNULL(@pLOG_LEVEL,'INFO')),
@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;
-- 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,
@ROW_COUNT2 SMALLINT = 0,
@DATE_TODAY DATE = CONVERT(date, getdate()),
@GUID BIGINT = NULL,
@EXPORT_NUMBER_COUNTER BIGINT = NULL,
@EXPORT_NUMBER NVARCHAR(25) = NULL,
@NEXT_EXPORT_NUMBER_COUNTER BIGINT = NULL,
@NEXT_EXPORT_NUMBER NVARCHAR(25) = NULL,
@EXPORT_NUMBER_INSERT_FLAG BIT = 0,
@REFERENCE1 NVARCHAR(150) = NULL,
@REFERENCE2 NVARCHAR(150) = NULL,
@REFERENCE3 NVARCHAR(150) = NULL,
@REFERENCE4 NVARCHAR(150) = NULL,
@REFERENCE5 NVARCHAR(150) = NULL,
@EXTERNAL_REFERENCE1 NVARCHAR(2000) = NULL,
@EXTERNAL_REFERENCE2 NVARCHAR(2000) = NULL,
@EXTERNAL_REFERENCE3 NVARCHAR(2000) = NULL,
@EXTERNAL_REFERENCE4 NVARCHAR(2000) = NULL,
@EXTERNAL_REFERENCE5 NVARCHAR(2000) = 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: ' + ISNULL(CONVERT(NVARCHAR(200),@PROFILE_ID),'<NO-VALUE>');
PRINT 'PARAMETER02 - @TEST_MODE: ' + ISNULL(CONVERT(NVARCHAR(200),@TEST_MODE),'<NO-VALUE>');
PRINT 'PARAMETER03 - @ASYNC_MODE: ' + ISNULL(CONVERT(NVARCHAR(200),@ASYNC_MODE),'<NO-VALUE>');
PRINT 'PARAMETER04 - @BATCH_ID: ' + ISNULL(CONVERT(NVARCHAR(200),@BATCH_ID),'<NO-VALUE>');
PRINT 'PARAMETER05 - @BATCH_CREATOR: ' + ISNULL(CONVERT(NVARCHAR(200),@BATCH_CREATOR),'<NO-VALUE>');
PRINT 'PARAMETER06 - @LANGUAGE: ' + ISNULL(CONVERT(NVARCHAR(200),@LANGUAGE),'<NO-VALUE>');
PRINT 'PARAMETER07 - @LOG_LEVEL: ' + ISNULL(CONVERT(NVARCHAR(200),@LOG_LEVEL),'<NO-VALUE>');
PRINT 'PARAMETER08 - @FORCE: ' + ISNULL(CONVERT(NVARCHAR(200),@FORCE),'<NO-VALUE>');
PRINT 'PARAMETER09 - @PROFILE_NAME: ' + ISNULL(CONVERT(NVARCHAR(200),@PROFILE_NAME),'<NO-VALUE>');
PRINT 'PARAMETER10 - @MANDANTOR: ' + ISNULL(CONVERT(NVARCHAR(200),@MANDANTOR),'<NO-VALUE>');
PRINT 'PARAMETER11 - @EXPORT_TYPE: ' + ISNULL(CONVERT(NVARCHAR(200),@EXPORT_TYPE),'<NO-VALUE>');
PRINT 'PARAMETER12 - @EXPORT_NUMBER_SCHEMA: ' + ISNULL(CONVERT(NVARCHAR(200),@EXPORT_NUMBER_SCHEMA),'<NO-VALUE>');
PRINT 'PARAMETER13 - @DEFAULT_DATA_SEPARATOR: ' + ISNULL(CONVERT(NVARCHAR(200),@DEFAULT_DATA_SEPARATOR),'<NO-VALUE>');
PRINT '';
--=========================================-- Double check if process is registerd --============================================--
SET @ROW_COUNT1 = ISNULL((SELECT COUNT(*) FROM [TBDEX_TMP_PROCESS] WITH (SNAPSHOT) WHERE [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID),0);
SET @ROW_COUNT2 = ISNULL((SELECT COUNT(*) FROM [TBDEX_TMP_PROCESS_REFERENCES] WITH (SNAPSHOT) WHERE [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID),0);
IF ((@ROW_COUNT1 <> 0) AND (@ROW_COUNT2 <> 0)) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50008;
SET @RETURN_STATUS_TEXT = concat('Process already registerd in table [TBDEX_TMP_PROCESS]!','');
SET @RETURN_ERROR_TEXT = concat('Duplicate process detected!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('No row found in [TBDEX_TMP_PROCESS], thats how it should be, before the Insert!','');
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;
-----------------------------------------------------------------------------------------------------------------------------------
--====================================================-- Register process --====================================================--
INSERT INTO [dbo].[TBDEX_TMP_PROCESS]([PROFILE_ID],[BATCH_ID],[ADDED_WHO], [ADDED_WHEN])
SELECT @PROFILE_ID, @BATCH_ID, @BATCH_CREATOR, GetDate()
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Check result --=======================================================--
SET @ROW_COUNT1 = ISNULL((SELECT COUNT(*)
FROM [TBDEX_TMP_PROCESS] WITH (SNAPSHOT)
WHERE [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID),0);
-----------------------------------------------------------------------------------------------------------------------------------
IF (@ROW_COUNT1 <> 1) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50029;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('There should be exact one line in [TBDEX_TMP_PROCESS], after the Insert!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Inserted: ',@ROW_COUNT1,' row(s) into [TBDEX_TMP_PROCESS]!');
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;
-----------------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------------
--=========================================-- Double check if process is registerd --============================================--
SET @ROW_COUNT1 = ISNULL((SELECT COUNT(*) FROM [TBDEX_TMP_PROCESS] WITH (SNAPSHOT) WHERE [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID),0);
SET @ROW_COUNT2 = ISNULL((SELECT COUNT(*) FROM [TBDEX_TMP_PROCESS_REFERENCES] WITH (SNAPSHOT) WHERE [PROFILE_ID]=@PROFILE_ID AND [BATCH_ID]=@BATCH_ID),0);
IF ((@ROW_COUNT1 = 0) AND (@ROW_COUNT2 <> 0)) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50024;
SET @RETURN_STATUS_TEXT = concat('Process already registerd in table [TBDEX_TMP_PROCESS_REFERENCES]!','');
SET @RETURN_ERROR_TEXT = concat('Duplicate process detected!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('No row found in [TBDEX_TMP_PROCESS_REFERENCES], thats how it should be, before the Insert!','');
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;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- 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(char(13),'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