8
0

First release version of [PRDD_MOVE_USER_LOGIN_OUT_TO_ARCHIVE]

This commit is contained in:
2025-09-30 16:53:57 +02:00
parent d46305e91e
commit 88aff8d464

View File

@@ -5,7 +5,8 @@ GO
-- [PRDD_MOVE_USER_LOGIN_OUT_TO_ARCHIVE]
-- =================================================================
-- Reads the table [TBDD_USER_LOGIN_OUT] for used licenses
-- Reads the table [TBDD_USER_LOGIN_OUT] for used licenses and
-- moves old values anonymized to [TBDD_USER_LOGIN_OUT_HISTORY]
--
-- Returns: An integer value
-- =================================================================
@@ -14,88 +15,453 @@ GO
-- Digital Data GmbH • Ludwig-Rinn-Strasse 16 • D-35452 Heuchelheim
-- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works
-- =================================================================
-- Creation Date / Author: 16.09.2025 / MK
-- Version Date / Editor: 16.09.2025 / MK
-- Creation Date / Author: 30.09.2025 / MK
-- Version Date / Editor: 30.09.2025 / MK
-- Version Number: 1.0.0.0
-- =================================================================
-- History:
-- 16.09.2025 / MS - First Version
-- 30.09.2025 / MS - First Version
CREATE OR ALTER PROCEDURE [dbo].[PRDD_MOVE_USER_LOGIN_OUT_TO_ARCHIVE](
@pCLIENT_ID INTEGER, -- Give the mandator ID from [TBDD_CLIENT] or 0, for all mandators.
@pMODULE_ID INTEGER, -- Give the module ID from [TBDD_MODULES] the get the module name.
@pLOOKBACK_IN_DAYS SMALLINT -- Give the timespan you want to monitor in the past.
-- By giving 0, function will check sql table [TBDD_CATALOG] for global variables: <MODULE_NAME>_LICENSE_LOOKBACK_IN_DAYS.
-- Failsafe value is 90 days.
@pCLIENT_ID INTEGER, -- Give the mandator ID from [TBDD_CLIENT] or 0, for all mandators.
@pMODULE_ID INTEGER, -- Give the module ID from [TBDD_MODULES] the get the module name or 0, for all modules.
@pARCHIVE_OLDER_THEN_IN_DAYS SMALLINT, -- Give the timespan you want to monitor in the past.
-- By giving 0, function will check sql table [TBDD_CATALOG] for global variables: <MODULE_NAME>_LICENSE_ARCHIVE_OLDER_THEN_IN_DAYS.
-- Failsafe value is 90 days.
@pTEST_MODE BIT = 0 -- Give 0, to insert, update and delete data or 1 to insert, update but NOT delete.
)
RETURNS INTEGER
AS
BEGIN
BEGIN TRY
SET NOCOUNT ON;
-- declare new vars because of parameter sniffing
DECLARE @CLIENT_ID INTEGER = @pCLIENT_ID,
@MODULE_ID INTEGER = @pMODULE_ID,
@LOOKBACK_IN_DAYS SMALLINT = @pLOOKBACK_I[F[DF_TBDD_USER_LOGIN_OUT_STATISTICS_ADDED_WHO]K_TBDD_USER_LOGIN_OUT_HISTORY_TBDD_CLIENT][FK_TBDD_USER_LOGIN_OUT_STATISTICS_TBDD_MODULES]N[FK_TBDD_USER_LOGIN_OUT_STATISTICS_TBDD_CLIENT]_DAYS;
@ARCHIVE_OLDER_THEN_IN_DAYS SMALLINT = @pARCHIVE_OLDER_THEN_IN_DAYS,
@TEST_MODE BIT = ISNULL(@pTEST_MODE,1);
-- declare temp tables
DECLARE @vTBDD_CLIENT TABLE([GUID] [INT] NOT NULL,
[CLIENT_NAME] [NVARCHAR](50) NOT NULL,
[SHORTNAME] [NVARCHAR](30) NULL);
DECLARE @vTBDD_MODULES TABLE([GUID] [INT] NOT NULL,
[NAME] [NVARCHAR](50) NOT NULL,
[SHORT_NAME] [NVARCHAR](20) NULL);
DECLARE @vTBDD_USER_LOGIN_OUT TABLE([GUID] [BIGINT] IDENTITY(1,1) NOT NULL,
[CLIENT_ID] [INT] NOT NULL,
[MODULE_ID] [INT] NOT NULL,
[LOGIN_DATE] [DATE] NOT NULL,
[LOGIN_COUNT] [INT] NOT NULL);
-- declare runtime vars
DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID);
DECLARE @USED_LICENSE_COUNT INTEGER = 0,
@MODULE_NAME NVARCHAR(50) = NULL,
@CLIENT_GUID INTEGER = 0,
@CLIENT_NAME NVARCHAR(100) = NULL,
@CLIENT_SHORT_NAME NVARCHAR(50) = NULL,
@MODULE_GUID INTEGER = 0,
@MODULE_NAME NVARCHAR(100) = NULL,
@MODULE_SHORT_NAME NVARCHAR(50) = NULL,
@CATALOG_TITLE_TERM NVARCHAR(50) = '_LICENSE_LOOKBACK_IN_DAYS';
@LOGIN_DATE DATE = NULL,
@LOGIN_COUNT INTEGER = 0,
@COMMENT NVARCHAR(500) = NULL,
@CATALOG_TITLE_TERM NVARCHAR(50) = '_LICENSE_ARCHIVE_OLDER_THEN_IN_DAYS',
@RETURN_STATUS NVARCHAR(50) = 0,
@RETURN_STATUS_TEXT NVARCHAR(MAX) = 'START [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120),
@RETURN_ERROR_TEXT NVARCHAR(MAX) = '';
--=================================================-- Get module name --===================================================--
SELECT @MODULE_NAME = [NAME],
@MODULE_SHORT_NAME = [SHORT_NAME]
FROM [TBDD_MODULES] (NOLOCK)
WHERE [GUID] = @MODULE_ID AND [ACTIVE] = 1;
-----------------------------------------------------------------------------------------------------------------------------
PRINT '====================================================================================================';
PRINT 'PROCEDURE - ' + @return_status_text;
PRINT 'PARAMETER01 - @CLIENT_ID: ' + CONVERT(NVARCHAR(50),@CLIENT_ID);
PRINT 'PARAMETER02 - @MODULE_ID: ' + CONVERT(NVARCHAR(50),@MODULE_ID);
PRINT 'PARAMETER03 - @ARCHIVE_OLDER_THEN_IN_DAYS: ' + CONVERT(NVARCHAR(50),@ARCHIVE_OLDER_THEN_IN_DAYS);
PRINT 'PARAMETER04 - @TEST_MODE: ' + CONVERT(NVARCHAR(50),@TEST_MODE);
--===============================================-- check if tables exist --===============================================--
IF NOT (EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] (NOLOCK) WHERE [TABLE_NAME] = 'TBDD_CLIENT')) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50001;
SET @RETURN_STATUS_TEXT = concat('Missing table!','');
SET @RETURN_ERROR_TEXT = concat('Table [TBDD_CLIENT] is missing or unavailable!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE IF NOT (EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] (NOLOCk) WHERE [TABLE_NAME] = 'TBDD_MODULES')) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50002;
SET @RETURN_STATUS_TEXT = concat('Missing table!','');
SET @RETURN_ERROR_TEXT = concat('Table [TBDD_MODULES] is missing or unavailable!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE IF NOT (EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] (NOLOCk) WHERE [TABLE_NAME] = 'TBDD_USER_LOGIN_OUT')) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50003;
SET @RETURN_STATUS_TEXT = concat('Missing table!','');
SET @RETURN_ERROR_TEXT = concat('Table [TBDD_USER_LOGIN_OUT] is missing or unavailable!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE IF NOT (EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] (NOLOCk) WHERE [TABLE_NAME] = 'TBDD_USER_LOGIN_OUT_HISTORY')) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50004;
SET @RETURN_STATUS_TEXT = concat('Missing table!','');
SET @RETURN_ERROR_TEXT = concat('Table [TBDD_USER_LOGIN_OUT_HISTORY] is missing or unavailable!','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('All necessary tables have been found','');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT concat(char(13),'INFO: ',@RETURN_STATUS_TEXT,'; ',@RETURN_ERROR_TEXT);
-----------------------------------------------------------------------------------------------------------------------------------
--===========================================-- Exit because of missing data --============================================--
IF (LEN(@MODULE_NAME) = 0) AND (LEN(@MODULE_SHORT_NAME) = 0) BEGIN
RETURN ISNULL(@USED_LICENSE_COUNT,0);
END;
-----------------------------------------------------------------------------------------------------------------------------
--===================================-- Determ how long in the past we need to check --===================================--
IF (@LOOKBACK_IN_DAYS = 0) BEGIN
--=====================================================-- Get client name --=====================================================--
IF (@CLIENT_ID > 0) BEGIN
SELECT TOP (1) @LOOKBACK_IN_DAYS = CONVERT(INTEGER,[CAT_STRING])
INSERT INTO @vTBDD_CLIENT ([GUID], [CLIENT_NAME], [SHORTNAME])
SELECT @CLIENT_ID, [CLIENT_NAME], [SHORTNAME]
FROM [TBDD_CLIENT] (NOLOCK)
WHERE [GUID] = @CLIENT_ID AND [ACTIVE] = 1;
SELECT @CLIENT_NAME = [CLIENT_NAME],
@CLIENT_SHORT_NAME = [SHORTNAME]
FROM @vTBDD_CLIENT;
IF (LEN(@CLIENT_NAME) = 0) AND (LEN(@CLIENT_SHORT_NAME) = 0) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50005;
SET @RETURN_STATUS_TEXT = concat('Cannot retrieve @CLIENT_NAME and @CLIENT_SHORT_NAME!','');
SET @RETURN_ERROR_TEXT = concat('Check table [TBDD_CLIENT] for the CLIENT_ID: ',@CLIENT_ID);
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Found client with name: ',@CLIENT_NAME,' and ',@CLIENT_SHORT_NAME,' in the [TBDD_CLIENT] table');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT concat(char(13),'INFO: ',@RETURN_STATUS_TEXT,'; ',@RETURN_ERROR_TEXT);
-----------------------------------------------------------------------------------------------------------------------------------
END;
END; ELSE BEGIN
--==================================================-- Collect mandator data --==================================================--
INSERT INTO @vTBDD_CLIENT ([GUID], [CLIENT_NAME], [SHORTNAME])
SELECT TOP 100 PERCENT [GUID], [CLIENT_NAME], [SHORTNAME] FROM [TBDD_CLIENT] (NOLOCK) WHERE [ACTIVE] = 1 ORDER BY [GUID] ASC;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Processing all active clients (',(SELECT COUNT(*) FROM @vTBDD_CLIENT),')');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT concat(char(13),'INFO: ',@RETURN_STATUS_TEXT,'; ',@RETURN_ERROR_TEXT);
-----------------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------
--=====================================================-- Get module name --=====================================================--
IF (@MODULE_ID > 0) BEGIN
INSERT INTO @vTBDD_MODULES ([GUID], [NAME], [SHORT_NAME])
SELECT @MODULE_ID, [NAME], [SHORT_NAME]
FROM [TBDD_MODULES] (NOLOCK)
WHERE [GUID] = @MODULE_ID AND [ACTIVE] = 1;
SELECT @MODULE_NAME = [NAME],
@MODULE_SHORT_NAME = [SHORT_NAME]
FROM @vTBDD_MODULES;
IF (LEN(@MODULE_NAME) = 0) AND (LEN(@MODULE_SHORT_NAME) = 0) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50006;
SET @RETURN_STATUS_TEXT = concat('Cannot retrieve @MODULE_NAME and @MODULE_SHORT_NAME!','');
SET @RETURN_ERROR_TEXT = concat('Check table [TBDD_MODULES] for the MODULE_ID: ',@MODULE_ID);
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Found module with name: ',@MODULE_NAME,' and ',@MODULE_SHORT_NAME,' in the [TBDD_MODULES] table');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT concat(char(13),'INFO: ',@RETURN_STATUS_TEXT,'; ',@RETURN_ERROR_TEXT);
-----------------------------------------------------------------------------------------------------------------------------------
END;
END; ELSE BEGIN
--===================================================-- Collect module data --===================================================--
INSERT INTO @vTBDD_MODULES ([GUID], [NAME], [SHORT_NAME])
SELECT TOP 100 PERCENT [GUID], [NAME], [SHORT_NAME] FROM [TBDD_MODULES] (NOLOCK) WHERE [ACTIVE] = 1 ORDER BY [GUID] ASC;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Processing all active modules (',(SELECT COUNT(*) FROM @vTBDD_MODULES),')');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT concat(char(13),'INFO: ',@RETURN_STATUS_TEXT,'; ',@RETURN_ERROR_TEXT);
-----------------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================-- Determ how long in the past we need to check --======================================--
IF (@ARCHIVE_OLDER_THEN_IN_DAYS = 0) BEGIN
SELECT TOP (1) @ARCHIVE_OLDER_THEN_IN_DAYS = CONVERT(INTEGER,[CAT_STRING])
FROM [TBDD_CATALOG] (NOLOCK)
WHERE [CAT_TITLE] IN (CONCAT(@MODULE_NAME,@CATALOG_TITLE_TERM),CONCAT(@MODULE_SHORT_NAME,@CATALOG_TITLE_TERM));
IF ((@LOOKBACK_IN_DAYS is null) or (@LOOKBACK_IN_DAYS = 0)) BEGIN -- Failsafe is 90 days
SET @LOOKBACK_IN_DAYS = 90;
IF ((@ARCHIVE_OLDER_THEN_IN_DAYS is null) or (@ARCHIVE_OLDER_THEN_IN_DAYS = 0)) BEGIN -- Failsafe is 90 days
SET @ARCHIVE_OLDER_THEN_IN_DAYS = 90;
END;
END;
PRINT concat(char(13),'INFO: @ARCHIVE_OLDER_THEN_IN_DAYS: ',@ARCHIVE_OLDER_THEN_IN_DAYS);
-----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Collect login data --================================================--
INSERT INTO @vTBDD_USER_LOGIN_OUT([CLIENT_ID], [MODULE_ID], [LOGIN_DATE], [LOGIN_COUNT])
SELECT [ULIO].[CLIENT_ID] as 'CLIENT_ID',
[M].[GUID] as 'MODULE_ID',
CONVERT(DATE,[ULIO].[LOGIN]) as 'LOGIN_DATE',
COUNT([ULIO].[MODULE]) as 'LOGIN_COUNT'
FROM [TBDD_USER_LOGIN_OUT] as [ULIO] -- !no (NOLOCK)! --
LEFT JOIN [TBDD_MODULES] as [M] (NOLOCK) ON [ULIO].[MODULE] = [M].[NAME]
OR [ULIO].[MODULE] = [M].[SHORT_NAME]
WHERE (CONVERT(date,[ULIO].[LOGIN]) >= DATEADD(DAY, (ISNULL(@ARCHIVE_OLDER_THEN_IN_DAYS,0)*(-1)), GETDATE()))
AND (
(@CLIENT_ID <> 0 AND [ULIO].[CLIENT_ID] = @CLIENT_ID)
OR (@CLIENT_ID = 0 AND [ULIO].[CLIENT_ID] IN (SELECT [GUID] FROM @vTBDD_CLIENT))
)
AND (
(@MODULE_ID <> 0 AND [M].[GUID] = @MODULE_ID)
OR (@MODULE_ID = 0 AND [M].[GUID] IN (SELECT [GUID] FROM @vTBDD_MODULES))
)
AND [M].[ACTIVE] = 1
GROUP BY [ULIO].[CLIENT_ID], [M].[GUID], CONVERT(date,[ULIO].[LOGIN]), [ULIO].[MODULE]
ORDER BY CONVERT(date,[ULIO].[LOGIN]) DESC, [ULIO].[CLIENT_ID] ASC, [ULIO].[MODULE] ASC;
-----------------------------------------------------------------------------------------------------------------------------
--===================================================-- preparing part --==================================================--
PRINT concat(char(13),'INFO: Query complete...');
SET @USED_LICENSE_COUNT = ISNULL((SELECT COUNT(*) FROM @vTBDD_USER_LOGIN_OUT),0);
IF (@TEST_MODE <> 1) BEGIN
PRINT concat(char(13),'INFO: Test mode is disabled! ','Will delete source data from [TBDD_USER_LOGIN_OUT]...');
SET @COMMENT = NULL;
END; ELSE BEGIN
SET @COMMENT = '!!##TEST-RUN##!!!';
PRINT concat(char(13),'INFO: Test mode is enabled! ','Will NOT delete source data from [TBDD_USER_LOGIN_OUT]...');
END;
-----------------------------------------------------------------------------------------------------------------------------
--=====================================================-- main part --=====================================================--
IF (@CLIENT_ID = 0) BEGIN
IF (@USED_LICENSE_COUNT > 0) BEGIN
SET @USED_LICENSE_COUNT = (SELECT COUNT(DISTINCT [USER_ID])
FROM [TBDD_USER_LOGIN_OUT] (NOLOCK)
WHERE LEN([MACHINE_NAME]) > 0
AND [CLIENT_ID] IS NOT NULL
AND [MODULE] IN (@MODULE_NAME,@MODULE_SHORT_NAME)
AND CONVERT(DATE,[LOGIN]) BETWEEN DATEADD(DAY, (@LOOKBACK_IN_DAYS*(-1)), GETDATE()) AND GETDATE());
PRINT concat(char(13),'Found: ',@USED_LICENSE_COUNT,' lines to write in the archive!');
--===================================================-- loop clients --====================================================--
DECLARE CURSOR_vTBDD_CLIENT CURSOR
LOCAL FAST_FORWARD FOR
SELECT [GUID] as 'CLIENT_GUID',
[CLIENT_NAME] as 'CLIENT_NAME',
[SHORTNAME] as 'CLIENT_SHORT_NAME'
FROM @vTBDD_CLIENT
ORDER BY [GUID] ASC;
OPEN CURSOR_vTBDD_CLIENT
FETCH NEXT FROM CURSOR_vTBDD_CLIENT INTO @CLIENT_GUID, @CLIENT_NAME, @CLIENT_SHORT_NAME;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT concat(char(13),'Processing @CLIENT_GUID: ',@CLIENT_GUID,', @CLIENT_NAME: ',@CLIENT_NAME,', @CLIENT_SHORT_NAME: ',@CLIENT_SHORT_NAME);
--===================================================-- loop modules --====================================================--
DECLARE CURSOR_vTBDD_MODULES CURSOR
LOCAL FAST_FORWARD FOR
SELECT [GUID] as 'MODULE_GUID',
[NAME] as 'MODULE_NAME',
[SHORT_NAME] as 'MODULE_SHORT_NAME'
FROM @vTBDD_MODULES
ORDER BY [GUID] ASC;
OPEN CURSOR_vTBDD_MODULES
FETCH NEXT FROM CURSOR_vTBDD_MODULES INTO @MODULE_GUID, @MODULE_NAME, @MODULE_SHORT_NAME;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT concat(char(13),'Processing @MODULE_GUID: ',@MODULE_GUID,', @MODULE_NAME: ',@MODULE_NAME,', @MODULE_SHORT_NAME: ',@MODULE_SHORT_NAME);
--================================================-- loop login entrys --==================================================--
DECLARE CURSOR_vTBDD_USER_LOGIN_OUT CURSOR
LOCAL FAST_FORWARD FOR
SELECT [CLIENT_ID] as 'CLIENT_GUID',
[MODULE_ID] as 'MODULE_GUID',
[LOGIN_DATE] as 'LOGIN_DATE',
[LOGIN_COUNT] as 'LOGIN_COUNT'
FROM @vTBDD_USER_LOGIN_OUT
WHERE [CLIENT_ID] = @CLIENT_GUID
AND [MODULE_ID] = @MODULE_GUID
ORDER BY [GUID] DESC;
OPEN CURSOR_vTBDD_USER_LOGIN_OUT
FETCH NEXT FROM CURSOR_vTBDD_USER_LOGIN_OUT INTO @CLIENT_GUID, @MODULE_GUID, @LOGIN_DATE, @LOGIN_COUNT;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT concat(char(13),'Processing @LOGIN_DATE: ',@LOGIN_DATE,', @LOGIN_COUNT: ',@LOGIN_COUNT,', @CLIENT_GUID: ',@CLIENT_GUID,', @MODULE_GUID: ',@MODULE_GUID);
BEGIN TRY
IF ((SELECT COUNT(*) FROM [TBDD_USER_LOGIN_OUT_HISTORY] WHERE [CLIENT_ID] = @CLIENT_GUID AND [MODULE_ID] = @MODULE_GUID AND [LOGIN_DATE] = @LOGIN_DATE) > 0) BEGIN --!no (NOLOCK)!--
IF ((SELECT COUNT(*) FROM [TBDD_USER_LOGIN_OUT_HISTORY] WHERE [CLIENT_ID] = @CLIENT_GUID AND [MODULE_ID] = @MODULE_GUID AND [LOGIN_DATE] = @LOGIN_DATE AND [LOGIN_COUNT] < @LOGIN_COUNT) > 0) BEGIN
PRINT concat('Entry already exists, [LOGIN_COUNT] missmatch,',' updating [TBDD_USER_LOGIN_OUT_HISTORY]...','');
UPDATE [TBDD_USER_LOGIN_OUT_HISTORY]
SET [LOGIN_COUNT] = ([LOGIN_COUNT] + @LOGIN_COUNT),
[COMMENT] = @COMMENT,
[CHANGED_WHO] = @MY_PROCEDURE_NAME,
[CHANGED_WHEN] = GETDATE();
END; ELSE BEGIN
PRINT concat('Entry already existis, [LOGIN_COUNT] matches,',' DONT updating [TBDD_USER_LOGIN_OUT_HISTORY]...','');
END;
END; ELSE BEGIN
PRINT concat('Insert into [TBDD_USER_LOGIN_OUT_HISTORY]...','');
INSERT INTO [TBDD_USER_LOGIN_OUT_HISTORY]([CLIENT_ID],[MODULE_ID],[LOGIN_DATE],[LOGIN_COUNT],[COMMENT],[ADDED_WHO],[ADDED_WHEN])
VALUES (@CLIENT_GUID, @MODULE_GUID, @LOGIN_DATE, @LOGIN_COUNT, @COMMENT, @MY_PROCEDURE_NAME, GETDATE());
END;
IF (@TEST_MODE <> 1) BEGIN
PRINT concat('Operation successful! ',char(13),'Delete source data from [TBDD_USER_LOGIN_OUT]!');
DELETE FROM [TBDD_USER_LOGIN_OUT]
WHERE [CLIENT_ID] = @CLIENT_GUID
AND [MODULE] in (@MODULE_NAME,@MODULE_SHORT_NAME)
AND CONVERT(date,[LOGIN]) = @LOGIN_DATE;
END; ELSE BEGIN
PRINT concat('Operation successful! ',char(13),'Will not delete source data from [TBDD_USER_LOGIN_OUT], because of test mode!');
END;
END TRY BEGIN CATCH
PRINT concat(char(13),'An error occurred! Will not delete source data from [TBDD_USER_LOGIN_OUT]','');
END CATCH;
FETCH NEXT FROM CURSOR_vTBDD_USER_LOGIN_OUT INTO @CLIENT_GUID, @MODULE_GUID, @LOGIN_DATE, @LOGIN_COUNT;
END
CLOSE CURSOR_vTBDD_USER_LOGIN_OUT;
DEALLOCATE CURSOR_vTBDD_USER_LOGIN_OUT;
-----------------------------------------------------------------------------------------------------------------------------
FETCH NEXT FROM CURSOR_vTBDD_MODULES INTO @MODULE_GUID, @MODULE_NAME, @MODULE_SHORT_NAME;
END
CLOSE CURSOR_vTBDD_MODULES;
DEALLOCATE CURSOR_vTBDD_MODULES;
-----------------------------------------------------------------------------------------------------------------------------
FETCH NEXT FROM CURSOR_vTBDD_CLIENT INTO @CLIENT_GUID, @CLIENT_NAME, @CLIENT_SHORT_NAME;
END
CLOSE CURSOR_vTBDD_CLIENT;
DEALLOCATE CURSOR_vTBDD_CLIENT;
-----------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
SET @USED_LICENSE_COUNT = (SELECT COUNT(DISTINCT [USER_ID])
FROM [TBDD_USER_LOGIN_OUT] (NOLOCK)
WHERE LEN([MACHINE_NAME]) > 0
AND [CLIENT_ID] = @CLIENT_ID
AND [MODULE] IN (@MODULE_NAME,@MODULE_SHORT_NAME)
AND CONVERT(DATE,[LOGIN]) BETWEEN DATEADD(DAY, (@LOOKBACK_IN_DAYS*(-1)), GETDATE()) AND GETDATE());
PRINT concat(char(13),'Found no lines to write in the archive!');
END;
-----------------------------------------------------------------------------------------------------------------------------
--===============================================-- Returning final count --===============================================--
RETURN ISNULL(@USED_LICENSE_COUNT,0);
-----------------------------------------------------------------------------------------------------------------------------
--======================================================-- 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('','');
END
GO
PRINT concat(char(13),@RETURN_STATUS_TEXT);
PRINT '====================================================================================================';
-----------------------------------------------------------------------------------------------------------------------------------
RETURN @RETURN_STATUS;
END TRY BEGIN CATCH
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = CASE WHEN @RETURN_STATUS > 50000 THEN @RETURN_STATUS ELSE 50000 END;
SET @RETURN_STATUS_TEXT = concat('END [',@MY_PROCEDURE_NAME,'] @ ',CONVERT(NVARCHAR(50),GETDATE(),120));
SET @RETURN_ERROR_TEXT = concat('ERROR MESSAGE: ',CONVERT(NVARCHAR(500),ERROR_MESSAGE()));
PRINT concat(char(13),'ERROR IN PROCEDURE: [',@MY_PROCEDURE_NAME,']',char(13),@RETURN_ERROR_TEXT);
PRINT concat(char(13),'PROCEDURE - ',@RETURN_STATUS_TEXT);
PRINT '====================================================================================================';
-----------------------------------------------------------------------------------------------------------------------------------
RETURN @RETURN_STATUS;
END CATCH;
-- ##### TEST #####:
--USE [DD_ECM]
--GO
--DECLARE @return_value int
--EXEC @return_value = [dbo].[PRDD_MOVE_USER_LOGIN_OUT_TO_ARCHIVE]
-- @pCLIENT_ID = 0,
-- @pMODULE_ID = 0,
-- @pARCHIVE_OLDER_THEN_IN_DAYS = 90,
-- @pTEST_MODE = 0
--SELECT 'Return Value' = @return_value
--GO
--SELECT * FROM [DD_ECM].[dbo].[TBDD_USER_LOGIN_OUT]
--SELECT * FROM [DD_ECM].[dbo].[TBDD_USER_LOGIN_OUT_HISTORY]
---- DELETE FROM [DD_ECM].[dbo].[TBDD_USER_LOGIN_OUT_HISTORY]