757 lines
85 KiB
Transact-SQL
757 lines
85 KiB
Transact-SQL
SET ANSI_NULLS ON
|
||
GO
|
||
SET QUOTED_IDENTIFIER ON
|
||
GO
|
||
|
||
-- [PRDEX_CLEAN_UP]
|
||
-- =================================================================
|
||
-- Cleans up temp and result (archive) tables in the DEX module
|
||
--
|
||
-- 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_CLEAN_UP](
|
||
@pPROFILE_ID BIGINT = 0, -- Give GUID from [TBDEX_PROFILE], or 0 for all profiles
|
||
@pBATCH_ID NVARCHAR(25) = NULL, -- OPTIONAL: Set the batch ID
|
||
@pCLEAR_TEMP_TABLES BIT = 1, -- Give 1 = Enable temp table deletion (DEFAULT); 0 = Disable temp table deletion
|
||
@pCLEAR_LOGS_OLDER_THEN_DAYS SMALLINT = NULL, -- Give a int value bigger then Null/0 to delete old line(s) in the log table
|
||
@pCLEAR_RESULTS_OLDER_THEN_DAYS SMALLINT = NULL, -- Give a int value bigger then Null/0 to delete old line(s) in the result and result reference tables
|
||
@pLOG_LEVEL NVARCHAR(25) = NULL -- Optional: Set @LOG_LEVEL,'WARN' or 'ERROR' to overwrite profile setting. Failsafe is 'INFO'
|
||
)
|
||
AS
|
||
BEGIN TRY
|
||
|
||
SET NOCOUNT ON;
|
||
SET XACT_ABORT ON;
|
||
|
||
-- declare new vars because of parameter sniffing
|
||
DECLARE @PROFILE_ID BIGINT = ISNULL(@pPROFILE_ID,0),
|
||
@BATCH_ID NVARCHAR(25) = ISNULL(@pBATCH_ID,0),
|
||
@CLEAR_TEMP_TABLES BIT = ISNULL(@pCLEAR_TEMP_TABLES,1),
|
||
@CLEAR_LOGS_OLDER_THEN_DAYS SMALLINT = ISNULL(@pCLEAR_LOGS_OLDER_THEN_DAYS,0),
|
||
@CLEAR_RESULTS_OLDER_THEN_DAYS SMALLINT = ISNULL(@pCLEAR_RESULTS_OLDER_THEN_DAYS,0),
|
||
@LOG_LEVEL NVARCHAR(25) = UPPER(ISNULL(@pLOG_LEVEL,'INFO'));
|
||
|
||
DECLARE @vTBDEX_PROFILE as TABLE (
|
||
[GUID] [bigint] IDENTITY(1,1) NOT NULL,
|
||
[PROFILE_ID] [bigint] NOT NULL,
|
||
[PROFILE_NAME] [nvarchar](50) NOT NULL);
|
||
|
||
DECLARE @vTBDEX_RUN_LOG as TABLE (
|
||
[GUID] [bigint] NOT NULL);
|
||
|
||
DECLARE @vTBDEX_OUT as TABLE (
|
||
[GUID] [bigint] NOT NULL);
|
||
|
||
-- declare runtime vars
|
||
DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID);
|
||
DECLARE @ACTIVE_FLAG BIT = 1,
|
||
@INACTIVE_FLAG BIT = 0,
|
||
@DELETE_BATCH_SIZE INT = 5000,
|
||
@PROFILE_COUNT INT = 0,
|
||
@LINE_COUNT INT = 0,
|
||
@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,'<NO-VALUE>'));
|
||
PRINT 'PARAMETER02 - @CLEAR_TEMP_TABLES: ' + CONVERT(NVARCHAR(50),ISNULL(@CLEAR_TEMP_TABLES,'<NO-VALUE>'));
|
||
PRINT 'PARAMETER03 - @CLEAR_LOGS_OLDER_THEN_DAYS: ' + CONVERT(NVARCHAR(50),ISNULL(@CLEAR_LOGS_OLDER_THEN_DAYS,'<NO-VALUE>'));
|
||
PRINT 'PARAMETER04 - @CLEAR_RESULTS_OLDER_THEN_DAYS: ' + CONVERT(NVARCHAR(50),ISNULL(@CLEAR_RESULTS_OLDER_THEN_DAYS,'<NO-VALUE>'));
|
||
PRINT 'PARAMETER05 - @LOG_LEVEL: ' + CONVERT(NVARCHAR(50),ISNULL(@LOG_LEVEL,'<NO-VALUE>'));
|
||
PRINT '';
|
||
|
||
--=================================================-- Get PROFILE configuration --==================================================--
|
||
IF (@PROFILE_ID = 0) BEGIN
|
||
INSERT INTO @vTBDEX_PROFILE([PROFILE_ID],[PROFILE_NAME])
|
||
SELECT [GUID] as [PROFILE_ID],[PROFILE_NAME]
|
||
FROM [VWDEX_PROFILE]
|
||
WHERE [ACTIVE] = @ACTIVE_FLAG;
|
||
|
||
END; ELSE IF (@PROFILE_ID > 0) BEGIN
|
||
INSERT INTO @vTBDEX_PROFILE([PROFILE_ID],[PROFILE_NAME])
|
||
SELECT [GUID] as [PROFILE_ID],[PROFILE_NAME]
|
||
FROM [VWDEX_PROFILE]
|
||
WHERE [ACTIVE] = @ACTIVE_FLAG AND [GUID] = @PROFILE_ID;
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===================================================-- FailSafe settings --====================================================--
|
||
IF (@LOG_LEVEL NOT IN ('INFO','WARN','ERROR')) BEGIN
|
||
SET @LOG_LEVEL = 'INFO';
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===================================================-- 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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
|
||
--=================================================-- Set PROFILE configuration --==================================================--
|
||
SET @PROFILE_COUNT = (SELECT COUNT(*) FROM @vTBDEX_PROFILE);
|
||
IF (@PROFILE_COUNT > 0) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Found ',convert(varchar,@PROFILE_COUNT),' active Profile(s), which will be temporaly deactivated!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
UPDATE [VWDEX_PROFILE]
|
||
SET [ACTIVE] = @INACTIVE_FLAG
|
||
WHERE [ACTIVE] = @ACTIVE_FLAG
|
||
AND [GUID] IN (SELECT [PROFILE_ID] FROM @vTBDEX_PROFILE);
|
||
|
||
END; ELSE BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Found no active Profile(s)!','');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
--==================================================-- Do it for all profiles --=================================================--
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@PROFILE_ID = 0) BEGIN
|
||
|
||
--====================================================-- CLEAR_TEMP_TABLES --====================================================--
|
||
|
||
IF (@CLEAR_TEMP_TABLES = @ACTIVE_FLAG) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing temp tables for all profiles is engaging!','');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
BEGIN TRANSACTION;
|
||
|
||
IF (LEN(@BATCH_ID) >= 4) BEGIN
|
||
|
||
DELETE FROM [TBDEX_IN] WHERE [PROFILE_ID] > @INACTIVE_FLAG AND [BATCH_ID] = @BATCH_ID;
|
||
DELETE FROM [TBDEX_TMP_QUERY] WHERE [PROFILE_ID] > @INACTIVE_FLAG AND [BATCH_ID] = @BATCH_ID;
|
||
DELETE FROM [TBDEX_TMP_PROCESS] WHERE [PROFILE_ID] > @INACTIVE_FLAG AND [BATCH_ID] = @BATCH_ID;
|
||
DELETE FROM [TBDEX_TMP_PROCESS_REFERENCES] WHERE [PROFILE_ID] > @INACTIVE_FLAG AND [BATCH_ID] = @BATCH_ID;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
WHILE (1=1) BEGIN
|
||
DELETE TOP (@DELETE_BATCH_SIZE) FROM [TBDEX_IN] WHERE [PROFILE_ID] > @INACTIVE_FLAG;
|
||
IF (@@ROWCOUNT = 0) BREAK;
|
||
END;
|
||
|
||
WHILE (1=1) BEGIN
|
||
DELETE TOP (@DELETE_BATCH_SIZE) FROM [TBDEX_TMP_QUERY] WHERE [PROFILE_ID] > @INACTIVE_FLAG;
|
||
IF (@@ROWCOUNT = 0) BREAK;
|
||
END;
|
||
|
||
WHILE (1=1) BEGIN
|
||
DELETE TOP (@DELETE_BATCH_SIZE) FROM [TBDEX_TMP_PROCESS] WHERE [PROFILE_ID] > @INACTIVE_FLAG;
|
||
IF (@@ROWCOUNT = 0) BREAK;
|
||
END;
|
||
|
||
WHILE (1=1) BEGIN
|
||
DELETE TOP (@DELETE_BATCH_SIZE) FROM [TBDEX_TMP_PROCESS_REFERENCES] WHERE [PROFILE_ID] > @INACTIVE_FLAG;
|
||
IF (@@ROWCOUNT = 0) BREAK;
|
||
END;
|
||
|
||
END;
|
||
|
||
IF (@@TRANCOUNT > 0) BEGIN
|
||
COMMIT TRANSACTION;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing temp tables for all profiles is disabled!','');
|
||
SET @RETURN_ERROR_TEXT = concat('','');
|
||
|
||
PRINT 'INFO: ' + @RETURN_STATUS_TEXT;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===================================================-- Log result to table --===================================================--
|
||
IF (@LOG_LEVEL in ('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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--================================================-- CLEAR_LOGS_OLDER_THEN_DAYS --===============================================--
|
||
IF (@CLEAR_LOGS_OLDER_THEN_DAYS > 0) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing log table for all profiles is engaging!','');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
BEGIN TRANSACTION;
|
||
|
||
INSERT INTO @vTBDEX_RUN_LOG([GUID])
|
||
SELECT [GUID]
|
||
FROM [TBDEX_RUN_LOG]
|
||
WHERE [PROFILE_ID] > 0
|
||
AND DATEDIFF(day,[ADDED_WHEN],GetDate()) >= @CLEAR_LOGS_OLDER_THEN_DAYS;
|
||
|
||
SET @LINE_COUNT = (SELECT COUNT(*) FROM @vTBDEX_RUN_LOG);
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Found: ',CONVERT(NVARCHAR(50),@LINE_COUNT),' line(s) for deletion!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@LINE_COUNT > 0) BEGIN
|
||
DELETE FROM [TBDEX_RUN_LOG] WHERE [GUID] IN (SELECT [GUID] FROM @vTBDEX_RUN_LOG);
|
||
END;
|
||
|
||
IF (@@TRANCOUNT > 0) BEGIN
|
||
COMMIT TRANSACTION;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing log table for all profiles is disabled!','');
|
||
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;
|
||
|
||
--===============================================-- CLEAR_RESULTS_OLDER_THEN_DAYS --=============================================--
|
||
|
||
IF (@CLEAR_RESULTS_OLDER_THEN_DAYS > 0) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing result tables for all profiles is engaging!','');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
BEGIN TRANSACTION;
|
||
|
||
INSERT INTO @vTBDEX_OUT([GUID])
|
||
SELECT [GUID] FROM [TBDEX_OUT] WHERE [PROFILE_ID] > 0 AND DATEDIFF(day,[ADDED_WHEN],GetDate()) >= @CLEAR_RESULTS_OLDER_THEN_DAYS;
|
||
|
||
SET @LINE_COUNT = (SELECT COUNT(*) FROM @vTBDEX_OUT);
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Found: ',CONVERT(NVARCHAR(50),@LINE_COUNT),' line(s) for deletion!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@LINE_COUNT > 0) BEGIN
|
||
DELETE FROM [TBDEX_OUT_REFERENCES] WHERE [OUT_ID] IN (SELECT [GUID] FROM @vTBDEX_OUT);
|
||
DELETE FROM [TBDEX_OUT] WHERE [GUID] IN (SELECT [GUID] FROM @vTBDEX_OUT);
|
||
END;
|
||
|
||
IF (@@TRANCOUNT > 0) BEGIN
|
||
COMMIT TRANSACTION;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing result tables for all profiles is disabled!','');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
--===============================================-- Do it for a specific profile --==============================================--
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END; ELSE IF (@PROFILE_ID > 0) BEGIN
|
||
|
||
IF (@CLEAR_TEMP_TABLES = 1) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing temp tables for PROFILE_ID: ',CONVERT(NVARCHAR(50),@PROFILE_ID),' is engaging!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
BEGIN TRANSACTION;
|
||
|
||
IF (LEN(@BATCH_ID) >= 4) BEGIN
|
||
|
||
DELETE FROM [TBDEX_IN] WHERE [PROFILE_ID] = @PROFILE_ID AND [BATCH_ID] = @BATCH_ID;
|
||
DELETE FROM [TBDEX_TMP_QUERY] WHERE [PROFILE_ID] = @PROFILE_ID AND [BATCH_ID] = @BATCH_ID;
|
||
DELETE FROM [TBDEX_TMP_PROCESS] WHERE [PROFILE_ID] = @PROFILE_ID AND [BATCH_ID] = @BATCH_ID;
|
||
DELETE FROM [TBDEX_TMP_PROCESS_REFERENCES] WHERE [PROFILE_ID] = @PROFILE_ID AND [BATCH_ID] = @BATCH_ID;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
WHILE (1=1) BEGIN
|
||
DELETE TOP (@DELETE_BATCH_SIZE) FROM [TBDEX_IN] WHERE [PROFILE_ID] = @PROFILE_ID;
|
||
IF (@@ROWCOUNT = 0) BREAK;
|
||
END;
|
||
|
||
WHILE (1=1) BEGIN
|
||
DELETE TOP (@DELETE_BATCH_SIZE) FROM [TBDEX_TMP_QUERY] WHERE [PROFILE_ID] = @PROFILE_ID;
|
||
IF (@@ROWCOUNT = 0) BREAK;
|
||
END;
|
||
|
||
WHILE (1=1) BEGIN
|
||
DELETE TOP (@DELETE_BATCH_SIZE) FROM [TBDEX_TMP_PROCESS] WHERE [PROFILE_ID] = @PROFILE_ID;
|
||
IF (@@ROWCOUNT = 0) BREAK;
|
||
END;
|
||
|
||
WHILE (1=1) BEGIN
|
||
DELETE TOP (@DELETE_BATCH_SIZE) FROM [TBDEX_TMP_PROCESS_REFERENCES] WHERE [PROFILE_ID] = @PROFILE_ID;
|
||
IF (@@ROWCOUNT = 0) BREAK;
|
||
END;
|
||
|
||
END;
|
||
|
||
IF (@@TRANCOUNT > 0) BEGIN
|
||
COMMIT TRANSACTION;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing temp tables for PROFILE_ID: ',CONVERT(NVARCHAR(50),@PROFILE_ID),' is disabled!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
|
||
--================================================-- CLEAR_LOGS_OLDER_THEN_DAYS --===============================================--
|
||
IF (@CLEAR_LOGS_OLDER_THEN_DAYS > 0) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing log table for PROFILE_ID: ',CONVERT(NVARCHAR(50),@PROFILE_ID),' is engaging!');
|
||
SET @RETURN_ERROR_TEXT = concat('','');
|
||
|
||
PRINT 'INFO: ' + @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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
BEGIN TRANSACTION;
|
||
|
||
INSERT INTO @vTBDEX_RUN_LOG([GUID])
|
||
SELECT [GUID] FROM [TBDEX_RUN_LOG]
|
||
WHERE [PROFILE_ID] = @PROFILE_ID AND DATEDIFF(day,[ADDED_WHEN],GetDate()) >= @CLEAR_LOGS_OLDER_THEN_DAYS;
|
||
|
||
SET @LINE_COUNT = ISNULL((SELECT COUNT(*) FROM @vTBDEX_RUN_LOG),0);
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Found: ',CONVERT(NVARCHAR(50),@LINE_COUNT),' line(s) for deletion!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@LINE_COUNT > 0) BEGIN
|
||
DELETE FROM [TBDEX_RUN_LOG] WHERE [GUID] IN (SELECT [GUID] FROM @vTBDEX_RUN_LOG);
|
||
END;
|
||
|
||
IF (@@TRANCOUNT > 0) BEGIN
|
||
COMMIT TRANSACTION;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing log table for PROFILE_ID: ',CONVERT(NVARCHAR(50),@PROFILE_ID),' is disabled!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
|
||
--===============================================-- CLEAR_RESULTS_OLDER_THEN_DAYS --=============================================--
|
||
|
||
IF (@CLEAR_RESULTS_OLDER_THEN_DAYS > 0) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing result tables for PROFILE_ID: ',CONVERT(NVARCHAR(50),@PROFILE_ID),' is engaging!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
BEGIN TRANSACTION;
|
||
|
||
INSERT INTO @vTBDEX_OUT([GUID])
|
||
SELECT [GUID]
|
||
FROM [TBDEX_OUT]
|
||
WHERE [PROFILE_ID] = @PROFILE_ID
|
||
AND DATEDIFF(day,[ADDED_WHEN],GetDate()) >= @CLEAR_RESULTS_OLDER_THEN_DAYS;
|
||
|
||
SET @LINE_COUNT = (SELECT COUNT(*) FROM @vTBDEX_OUT);
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Found: ',CONVERT(NVARCHAR(50),@LINE_COUNT),' line(s) for deletion!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@LINE_COUNT > 0) BEGIN
|
||
DELETE FROM [TBDEX_OUT_REFERENCES] WHERE [OUT_ID] IN (SELECT [GUID] FROM @vTBDEX_OUT);
|
||
DELETE FROM [TBDEX_OUT] WHERE [GUID] IN (SELECT [GUID] FROM @vTBDEX_OUT);
|
||
END;
|
||
|
||
IF (@@TRANCOUNT > 0) BEGIN
|
||
COMMIT TRANSACTION;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Clearing result tables for PROFILE_ID: ',CONVERT(NVARCHAR(50),@PROFILE_ID),' is disabled!');
|
||
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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=================================================-- Get PROFILE configuration --==================================================--
|
||
IF (@PROFILE_COUNT > 0) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Found ',convert(varchar,@PROFILE_COUNT),' inactive Profile(s), which will be reactivated!');
|
||
SET @RETURN_ERROR_TEXT = concat('','');
|
||
|
||
PRINT 'INFO: ' + @RETURN_STATUS_TEXT;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
UPDATE [VWDEX_PROFILE]
|
||
SET [ACTIVE] = @ACTIVE_FLAG
|
||
WHERE [ACTIVE] = @INACTIVE_FLAG
|
||
AND [GUID] IN (SELECT [PROFILE_ID] FROM @vTBDEX_PROFILE);
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===================================================-- 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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--======================================================-- 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;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=================================================-- Get PROFILE configuration --==================================================--
|
||
IF (@PROFILE_COUNT > 0) BEGIN
|
||
|
||
--======================================================-- Output result --======================================================--
|
||
SET @RETURN_STATUS = 0;
|
||
SET @RETURN_STATUS_TEXT = concat('Found ',convert(varchar,@PROFILE_COUNT),' inactive Profile(s), which will be reactivated!');
|
||
SET @RETURN_ERROR_TEXT = concat('','');
|
||
|
||
PRINT 'INFO: ' + @RETURN_STATUS_TEXT;
|
||
-----------------------------------------------------------------------------------------------------------------------------------
|
||
|
||
UPDATE [VWDEX_PROFILE]
|
||
SET [ACTIVE] = @ACTIVE_FLAG
|
||
WHERE [ACTIVE] = @INACTIVE_FLAG
|
||
AND [GUID] IN (SELECT [PROFILE_ID] FROM @vTBDEX_PROFILE);
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===================================================-- 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; |