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

605 lines
65 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_EXPORT_NUMBER]
-- =================================================================
-- Writes log messages 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_SET_EXPORT_NUMBER] (
@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;
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')),
@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 virtual table for preprocessing steps
DECLARE @vTBDEX_RUN_NUMBER_RANGE as TABLE (
[GUID] BIGINT NOT NULL,
[PROFILE_ID] BIGINT NOT NULL,
[ACTIVE] BIT NOT NULL,
[EXPORT_NUMBER_SCHEMA] NVARCHAR(50) NULL,
[EXPORT_NUMBER_COUNTER] BIGINT NULL,
[EXPORT_NUMBER] NVARCHAR(25) NULL,
[NEXT_EXPORT_NUMBER_COUNTER] BIGINT NULL,
[NEXT_EXPORT_NUMBER] NVARCHAR(25) NULL)
-- declare runtime vars
DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID);
DECLARE @ACTIVE_FLAG BIT = 1,
@INACTIVE_FLAG BIT = 0,
@ACTIVE BIT = NULL,
@ROW_COUNT1 SMALLINT = 0,
@ROW_COUNT2 SMALLINT = 0,
@ROW_COUNT3 SMALLINT = 0,
@DATE_TODAY DATE = CONVERT(date, getdate()),
@TRANSACTION_NAME1 NVARCHAR(25) = 'LOCK_PRDEX_SET_EXPORT_NUMBER',
@ACCESS_TRYS_COUNTER TINYINT = 0,
@ACCESS_TRYS_MAX_COUNT TINYINT = 20,
@RETRY_DELAY_MAX_SECONDS TINYINT = 30,
@RETRY_DELAY_JITTER_SECONDS TINYINT = 0,
@RETRY_DELAY_CURRENT_SECONDS TINYINT = 0,
@RETRY_DELAY_TIME TIME(3) = '00:00:00.000',
@EXPORT_NUMBER_COUNTER BIGINT = NULL,
@EXPORT_NUMBER NVARCHAR(25) = NULL,
@NEXT_EXPORT_NUMBER_COUNTER BIGINT = NULL,
@NEXT_EXPORT_NUMBER NVARCHAR(25) = NULL,
@GUID1 BIGINT = NULL,
@GUID2 BIGINT = NULL,
@GUID3 BIGINT = NULL,
@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,
@EXPORT_NUMBER_INSERT_FLAG BIT = 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) = '';
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 registered --============================================--
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 = 50025;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('Insufficient data lines in [TBDEX_TMP_PROCESS] 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 exact one line in [TBDEX_TMP_PROCESS], thats how it should be!','');
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;
-----------------------------------------------------------------------------------------------------------------------------------
--=========================================-- Double check if process is registered --============================================--
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_COUNT2 < 1) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50026;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('Insufficient data lines in [TBDEX_TMP_PROCESS_REFERENCES] found! ','@ROW_COUNT2: ',@ROW_COUNT2);
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Found one or more lines in [TBDEX_TMP_PROCESS_REFERENCES], thats how it should be!','');
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;
-----------------------------------------------------------------------------------------------------------------------------------
--=================================================-- Lock table to avoid chaos --===============================================--
WHILE (@ACCESS_TRYS_COUNTER < @ACCESS_TRYS_MAX_COUNT) BEGIN
BEGIN TRY
BEGIN TRANSACTION @TRANSACTION_NAME1;
SELECT TOP 1 @GUID1 = [GUID]
FROM [TBDEX_RUN_NUMBER_RANGE] WITH (UPDLOCK, HOLDLOCK, ROWLOCK) -- LOCK ROW
WHERE [PROFILE_ID] = @PROFILE_ID
AND [ACTIVE] in (@ACTIVE_FLAG,@INACTIVE_FLAG)
AND [EXPORT_NUMBER_SCHEMA] = @EXPORT_NUMBER_SCHEMA
AND (([VALID_FROM] IS NULL AND [VALID_TO] IS NULL)
OR (@DATE_TODAY BETWEEN [VALID_FROM] AND [VALID_TO]))
ORDER BY [GUID] DESC; -- take the newest line if there are multiple
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Number range in [TBDEX_RUN_NUMBER_RANGE] has been locked! ','@GUID1: ',@GUID1);
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;
-----------------------------------------------------------------------------------------------------------------------------------
BREAK; -- Exit WHILE Loop
END TRY BEGIN CATCH
IF (@@TRANCOUNT > 0) BEGIN
ROLLBACK TRANSACTION @TRANSACTION_NAME1;
END;
IF (ERROR_NUMBER() = 1205) BEGIN -- Deadlock
SET @ACCESS_TRYS_COUNTER += 1;
SET @RETRY_DELAY_JITTER_SECONDS = CONVERT(TINYINT,ABS(CHECKSUM(NEWID())) % 3);
SET @RETRY_DELAY_CURRENT_SECONDS = CASE
WHEN ((@ACCESS_TRYS_COUNTER * 2) + @RETRY_DELAY_JITTER_SECONDS) > @RETRY_DELAY_MAX_SECONDS THEN @RETRY_DELAY_MAX_SECONDS
ELSE ((@ACCESS_TRYS_COUNTER * 2) + @RETRY_DELAY_JITTER_SECONDS)
END;
SET @RETRY_DELAY_TIME = TIMEFROMPARTS(0,0,@RETRY_DELAY_CURRENT_SECONDS,0,3);
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50027;
SET @RETURN_STATUS_TEXT = concat('Number range in [TBDEX_RUN_NUMBER_RANGE] cannot be locked! ','Will retry in ',@RETRY_DELAY_CURRENT_SECONDS,' seconds...',
'(Try nr: ',@ACCESS_TRYS_COUNTER,' out of ',@ACCESS_TRYS_MAX_COUNT,')');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT 'WARN: ' + @RETURN_STATUS_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO','WARN')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'WARN', @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;
-----------------------------------------------------------------------------------------------------------------------------------
WAITFOR DELAY @RETRY_DELAY_TIME;
END; ELSE BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50028;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('Number range in [TBDEX_RUN_NUMBER_RANGE] cannot be locked!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END;
END CATCH
END;
IF (@GUID1 IS NULL) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50027;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('Number range in [TBDEX_RUN_NUMBER_RANGE] cannot be locked after maximum retries!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------------
--=================================================-- Loop for every unique key --===============================================--
DECLARE CURSOR_SET_EXPORT_NUMBER CURSOR
LOCAL FAST_FORWARD FOR
SELECT
[GUID] as 'GUID2', [REFERENCE1], [REFERENCE2], [REFERENCE3], [REFERENCE4], [REFERENCE5],
[EXTERNAL_REFERENCE1], [EXTERNAL_REFERENCE2], [EXTERNAL_REFERENCE3], [EXTERNAL_REFERENCE4], [EXTERNAL_REFERENCE5]
FROM [dbo].[TBDEX_TMP_PROCESS_REFERENCES] WITH (SNAPSHOT)
WHERE [PROFILE_ID] = @PROFILE_ID
AND [BATCH_ID] = @BATCH_ID
AND [EXPORT_NUMBER_COUNTER] IS NULL
AND [EXPORT_NUMBER] IS NULL
ORDER BY [GUID] ASC;
OPEN CURSOR_SET_EXPORT_NUMBER
FETCH NEXT FROM CURSOR_SET_EXPORT_NUMBER INTO @GUID2,@REFERENCE1,@REFERENCE2,@REFERENCE3,@REFERENCE4,@REFERENCE5,@EXTERNAL_REFERENCE1,@EXTERNAL_REFERENCE2,@EXTERNAL_REFERENCE3,@EXTERNAL_REFERENCE4,@EXTERNAL_REFERENCE5;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT '';
--===============================================-- Get next free export number --==============================================--
INSERT INTO @vTBDEX_RUN_NUMBER_RANGE([GUID],[PROFILE_ID],[ACTIVE],[EXPORT_NUMBER_SCHEMA],[EXPORT_NUMBER_COUNTER],[EXPORT_NUMBER],
[NEXT_EXPORT_NUMBER_COUNTER],[NEXT_EXPORT_NUMBER])
SELECT [GUID],[PROFILE_ID],[ACTIVE],[EXPORT_NUMBER_SCHEMA],[EXPORT_NUMBER_COUNTER],[EXPORT_NUMBER],
[NEXT_EXPORT_NUMBER_COUNTER],[NEXT_EXPORT_NUMBER]
FROM [dbo].[FNDEX_GET_NEXT_EXPORT_NUMBER](@PROFILE_ID,@TEST_MODE,@ASYNC_MODE,@BATCH_ID,@BATCH_CREATOR,@LANGUAGE,@LOG_LEVEL,
@FORCE,@PROFILE_NAME,@MANDANTOR,@EXPORT_TYPE,@EXPORT_NUMBER_SCHEMA,@DEFAULT_DATA_SEPARATOR,
@REFERENCE1,@REFERENCE2,@REFERENCE3,@REFERENCE4,@REFERENCE5,
@EXTERNAL_REFERENCE1,@EXTERNAL_REFERENCE2,@EXTERNAL_REFERENCE3,@EXTERNAL_REFERENCE4,@EXTERNAL_REFERENCE5)
-----------------------------------------------------------------------------------------------------------------------------------
--=================================================-- We need one active line --=================================================--
SET @ROW_COUNT3 = ISNULL((SELECT COUNT(*) FROM @vTBDEX_RUN_NUMBER_RANGE),0);
IF (@ROW_COUNT3 = 0) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50019;
SET @RETURN_STATUS_TEXT = concat('No valid number range found in table [TBDEX_RUN_NUMBER_RANGE]! ','Will create it!');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT 'WARN: ' + @RETURN_STATUS_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--=================================================-- create new number range --=================================================--
SET @EXPORT_NUMBER_INSERT_FLAG = 1;
INSERT INTO [TBDEX_RUN_NUMBER_RANGE]([PROFILE_ID],[ACTIVE],[EXPORT_NUMBER_SCHEMA],[EXPORT_NUMBER_COUNTER],[EXPORT_NUMBER],[ADDED_WHO], [ADDED_WHEN])
VALUES(@PROFILE_ID, 1, @EXPORT_NUMBER_SCHEMA, 0, 0, @BATCH_CREATOR, GetDate());
INSERT INTO @vTBDEX_RUN_NUMBER_RANGE([GUID],[PROFILE_ID],[ACTIVE],[EXPORT_NUMBER_SCHEMA],[EXPORT_NUMBER_COUNTER],[EXPORT_NUMBER],
[NEXT_EXPORT_NUMBER_COUNTER],[NEXT_EXPORT_NUMBER])
SELECT [GUID],[PROFILE_ID],[ACTIVE],[EXPORT_NUMBER_SCHEMA],[EXPORT_NUMBER_COUNTER],[EXPORT_NUMBER],
[NEXT_EXPORT_NUMBER_COUNTER],[NEXT_EXPORT_NUMBER]
FROM [dbo].[FNDEX_GET_NEXT_EXPORT_NUMBER](@PROFILE_ID,@TEST_MODE,@ASYNC_MODE,@BATCH_ID,@BATCH_CREATOR,@LANGUAGE,@LOG_LEVEL,
@FORCE,@PROFILE_NAME,@MANDANTOR,@EXPORT_TYPE,@EXPORT_NUMBER_SCHEMA,@DEFAULT_DATA_SEPARATOR,
@REFERENCE1,@REFERENCE2,@REFERENCE3,@REFERENCE4,@REFERENCE5,
@EXTERNAL_REFERENCE1,@EXTERNAL_REFERENCE2,@EXTERNAL_REFERENCE3,@EXTERNAL_REFERENCE4,@EXTERNAL_REFERENCE5)
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Found a valid existing number range in [TBDEX_RUN_NUMBER_RANGE]!','');
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;
-----------------------------------------------------------------------------------------------------------------------------------
--=================================================-- We need one active line --=================================================--
SET @ROW_COUNT3 = ISNULL((SELECT COUNT(*) FROM @vTBDEX_RUN_NUMBER_RANGE),0);
IF ((@ROW_COUNT3 = 0) AND (@EXPORT_NUMBER_INSERT_FLAG = 1)) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50020;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('No valid number range found in table [TBDEX_RUN_NUMBER_RANGE]! ','Creating did not work!');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------------
--=================================================-- Allocate runtime values --=================================================--
SELECT @GUID3 = [GUID],
@ACTIVE = [ACTIVE],
@EXPORT_NUMBER_COUNTER = [EXPORT_NUMBER_COUNTER],
@EXPORT_NUMBER = [EXPORT_NUMBER],
@NEXT_EXPORT_NUMBER_COUNTER = [NEXT_EXPORT_NUMBER_COUNTER],
@NEXT_EXPORT_NUMBER = [NEXT_EXPORT_NUMBER]
FROM @vTBDEX_RUN_NUMBER_RANGE;
PRINT 'Number range config:';
PRINT concat('@GUID: ',@GUID3);
PRINT concat('@ACTIVE: ',@ACTIVE);
PRINT concat('@EXPORT_NUMBER_COUNTER: ',@EXPORT_NUMBER_COUNTER);
PRINT concat('@EXPORT_NUMBER: ',@EXPORT_NUMBER);
PRINT concat('@NEXT_EXPORT_NUMBER_COUNTER: ',@NEXT_EXPORT_NUMBER_COUNTER);
PRINT concat('@NEXT_EXPORT_NUMBER: ',@NEXT_EXPORT_NUMBER);
-----------------------------------------------------------------------------------------------------------------------------------
IF (@ACTIVE <> @ACTIVE_FLAG) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50021;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('The found number range is inactive, cannot proceed!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Active number range found OR has been created!','');
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;
-----------------------------------------------------------------------------------------------------------------------------------
UPDATE [TBDEX_TMP_PROCESS_REFERENCES]
SET [EXPORT_NUMBER_COUNTER] = @NEXT_EXPORT_NUMBER_COUNTER,
[EXPORT_NUMBER] = @NEXT_EXPORT_NUMBER
WHERE [GUID] = @GUID2;
UPDATE [TBDEX_RUN_NUMBER_RANGE]
SET [EXPORT_NUMBER_COUNTER] = @NEXT_EXPORT_NUMBER_COUNTER,
[EXPORT_NUMBER] = @NEXT_EXPORT_NUMBER,
[CHANGED_WHO] = @BATCH_CREATOR,
[CHANGED_WHEN] = GETDATE()
WHERE [GUID] = @GUID3
AND [PROFILE_ID] = @PROFILE_ID
AND [EXPORT_NUMBER_SCHEMA] = @EXPORT_NUMBER_SCHEMA
AND [ACTIVE] = @ACTIVE_FLAG;
-----------------------------------------------------------------------------------------------------------------------------------
DELETE FROM @vTBDEX_RUN_NUMBER_RANGE
-----------------------------------------------------------------------------------------------------------------------------------
IF (@@TRANCOUNT > 0) BEGIN
COMMIT TRANSACTION @TRANSACTION_NAME1; -- release lock per processed row
END;
-----------------------------------------------------------------------------------------------------------------------------------
FETCH NEXT FROM CURSOR_SET_EXPORT_NUMBER INTO @GUID2,@REFERENCE1,@REFERENCE2,@REFERENCE3,@REFERENCE4,@REFERENCE5,@EXTERNAL_REFERENCE1,@EXTERNAL_REFERENCE2,@EXTERNAL_REFERENCE3,@EXTERNAL_REFERENCE4,@EXTERNAL_REFERENCE5;
IF (@@FETCH_STATUS = 0) BEGIN
SET @ACCESS_TRYS_COUNTER = 0;
SET @GUID1 = NULL;
WHILE (@ACCESS_TRYS_COUNTER < @ACCESS_TRYS_MAX_COUNT) BEGIN
BEGIN TRY
BEGIN TRANSACTION @TRANSACTION_NAME1;
SELECT TOP 1 @GUID1 = [GUID]
FROM [TBDEX_RUN_NUMBER_RANGE] WITH (UPDLOCK, HOLDLOCK, ROWLOCK)
WHERE [PROFILE_ID] = @PROFILE_ID
AND [ACTIVE] in (@ACTIVE_FLAG,@INACTIVE_FLAG)
AND [EXPORT_NUMBER_SCHEMA] = @EXPORT_NUMBER_SCHEMA
AND (([VALID_FROM] IS NULL AND [VALID_TO] IS NULL)
OR (@DATE_TODAY BETWEEN [VALID_FROM] AND [VALID_TO]))
ORDER BY [GUID] DESC;
IF (@GUID1 IS NULL) BEGIN
SET @RETURN_STATUS = 50027;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('Number range in [TBDEX_RUN_NUMBER_RANGE] cannot be locked after maximum retries!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
END;
BREAK;
END TRY BEGIN CATCH
IF (@@TRANCOUNT > 0) BEGIN
ROLLBACK TRANSACTION @TRANSACTION_NAME1;
END;
IF (ERROR_NUMBER() = 1205) BEGIN
SET @ACCESS_TRYS_COUNTER += 1;
SET @RETRY_DELAY_JITTER_SECONDS = CONVERT(TINYINT,ABS(CHECKSUM(NEWID())) % 3);
SET @RETRY_DELAY_CURRENT_SECONDS = CASE
WHEN ((@ACCESS_TRYS_COUNTER * 2) + @RETRY_DELAY_JITTER_SECONDS) > @RETRY_DELAY_MAX_SECONDS THEN @RETRY_DELAY_MAX_SECONDS
ELSE ((@ACCESS_TRYS_COUNTER * 2) + @RETRY_DELAY_JITTER_SECONDS)
END;
SET @RETRY_DELAY_TIME = TIMEFROMPARTS(0,0,@RETRY_DELAY_CURRENT_SECONDS,0,3);
WAITFOR DELAY @RETRY_DELAY_TIME;
END; ELSE BEGIN
SET @RETURN_STATUS = 50028;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('Number range in [TBDEX_RUN_NUMBER_RANGE] cannot be locked!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
END;
END CATCH
END;
IF (@GUID1 IS NULL) BEGIN
SET @RETURN_STATUS = 50027;
SET @RETURN_STATUS_TEXT = concat('','');
SET @RETURN_ERROR_TEXT = concat('Number range in [TBDEX_RUN_NUMBER_RANGE] cannot be locked after maximum retries!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
END;
END;
END
CLOSE CURSOR_SET_EXPORT_NUMBER;
DEALLOCATE CURSOR_SET_EXPORT_NUMBER;
-----------------------------------------------------------------------------------------------------------------------------------
IF (@@TRANCOUNT > 0) BEGIN
COMMIT TRANSACTION @TRANSACTION_NAME1;
END;
-----------------------------------------------------------------------------------------------------------------------------------
-- write new value
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- 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; -- unlock table
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;