8
0

PRDD_SYNC_USER_OR_GROUP: First commit

This commit is contained in:
2026-02-25 16:45:19 +01:00
parent 0897b19701
commit 1bd99e6ec8
6 changed files with 600 additions and 0 deletions

View File

@@ -0,0 +1,457 @@
USE [DD_ECM]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- [PRDD_SYNC_USER_OR_GROUP]
-- =================================================================
-- Syncs a user or group with a external system and / or
-- sets it representation
--
-- 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: 23.12.2025 / MK
-- Version Date / Editor: 23.12.2025 / MK
-- Version Number: 1.0.0.0
-- =================================================================
-- History:
-- 23.12.2025 / MK - First Version
CREATE OR ALTER PROCEDURE [dbo].[PRDD_SYNC_USER_OR_GROUP](
@pOBJECT_TYPE NVARCHAR(10) = 'ALL', -- 'ALL', 'User' or 'Group'
@pOBJECT_NAME NVARCHAR(100) = NULL, -- Name of User or Group (IF @pOBJECT_TYPE <> ALL)
@pSYNC_EXT_SYSTEM BIT = 0, -- 1 = Sync with windream User Ids
@pCLEAN_EXT_SYSTEM BIT = 0, -- 1 = Remove old referencies
@pSYNC_INT_REPRESENTATION BIT = 0, -- 1 = Sync with user and group representation
@pCLEAN_INT_REPRESENTATION BIT = 0, -- 1 = Remove old referencies, but only if there are made by this procedure!
@pDEBUG BIT = 0 -- 1 = Display table objects
)
AS
BEGIN
--================================================-- Set session options --===============================================--
SET NOCOUNT ON;
EXEC sys.sp_set_session_context @key = 'SkipTrigger', @value = 1;
----------------------------------------------------------------------------------------------------------------------------
--=========================================-- Parameter copies (avoid sniffing) --========================================--
DECLARE @OBJECT_TYPE NVARCHAR(10) = LTRIM(RTRIM(UPPER(@pOBJECT_TYPE))),
@OBJECT_NAME NVARCHAR(100) = LTRIM(RTRIM(ISNULL(@pOBJECT_NAME, N''))),
@SYNC_EXT_SYSTEM BIT = ISNULL(@pSYNC_EXT_SYSTEM,0),
@CLEAN_EXT_SYSTEM BIT = ISNULL(@pCLEAN_EXT_SYSTEM,0),
@SYNC_INT_REPRESENTATION BIT = ISNULL(@pSYNC_INT_REPRESENTATION,0),
@CLEAN_INT_REPRESENTATION BIT = ISNULL(@pCLEAN_INT_REPRESENTATION,0),
@DEBUG BIT = ISNULL(@pDEBUG,0);
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Declare runtime variables --========================================--
DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID);
DECLARE @ROW_COUNT1 INT = 0,
@ROW_COUNT2 INT = 0,
@ID BIGINT = 0,
@USER_ID BIGINT = 0,
@GROUP_ID BIGINT = 0,
@EXT_SYSTEM_USER_ID INT = NULL,
@EXT_SYSTEM_GROUP_ID INT = NULL,
@ProductVersion SQL_VARIANT,
@ProductMainVersion INT,
@ProductLevel SQL_VARIANT,
@ProductEdition SQL_VARIANT,
@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) = '';
DECLARE @vTB_OBJECTS TABLE ([ID] BIGINT,
[OBJECT_TYPE] NVARCHAR(10),
[OBJECT_NAME] NVARCHAR(100));
DECLARE @vTB_REPRESENTATIONS TABLE ([ID] BIGINT,
[OBJECT_TYPE] NVARCHAR(10),
[GROUP_ID] BIGINT);
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Output parameters --================================================--
PRINT '====================================================================================================';
PRINT @RETURN_STATUS_TEXT;
PRINT '';
PRINT 'PARAMETER01 - @OBJECT_TYPE: ' + CONVERT(NVARCHAR(50),ISNULL(@OBJECT_TYPE,'<NO-VALUE>'));
PRINT 'PARAMETER02 - @OBJECT_NAME: ' + CONVERT(NVARCHAR(50),ISNULL(NULLIF(@OBJECT_NAME,N''),'<NO-VALUE>'));
PRINT 'PARAMETER03 - @SYNC_EXT_SYSTEM: ' + CONVERT(NVARCHAR(50),ISNULL(@SYNC_EXT_SYSTEM,'<NO-VALUE>'));
PRINT 'PARAMETER04 - @CLEAN_EXT_SYSTEM: ' + CONVERT(NVARCHAR(50),ISNULL(@CLEAN_EXT_SYSTEM,'<NO-VALUE>'));
PRINT 'PARAMETER05 - @SYNC_INT_REPRESENTATION: ' + CONVERT(NVARCHAR(50),ISNULL(@SYNC_INT_REPRESENTATION,'<NO-VALUE>'));
PRINT 'PARAMETER06 - @CLEAN_INT_REPRESENTATION: ' + CONVERT(NVARCHAR(50),ISNULL(@CLEAN_INT_REPRESENTATION,'<NO-VALUE>'));
PRINT 'PARAMETER07 - @DEBUG: ' + CONVERT(NVARCHAR(50),ISNULL(@DEBUG,'<NO-VALUE>'));
PRINT '';
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Get server infos --==================================================--
SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition');
SET @ProductMainVersion = ISNULL(LEFT(convert(NVARCHAR(100),@ProductVersion), CHARINDEX('.', convert(NVARCHAR(100),@ProductVersion)) - 1),0);
PRINT 'Informations about this Server:';
PRINT '@MySessionID: ' + CONVERT(NVARCHAR(100),@@SPID);
PRINT '@ProductVersion: ' + CONVERT(NVARCHAR(100),@ProductVersion);
PRINT '@ProductMainVersion: ' + CONVERT(NVARCHAR(100),@ProductMainVersion);
PRINT '@ProductLevel: ' + CONVERT(NVARCHAR(100),@ProductLevel);
PRINT '@ProductEdition: ' + CONVERT(NVARCHAR(100),@ProductEdition);
-----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Validate parameters --=============================================--
IF (@OBJECT_TYPE NOT IN ('ALL','USER','GROUP')) BEGIN
SET @RETURN_STATUS = 50001;
SET @RETURN_STATUS_TEXT = 'ERROR: Parameter @OBJECT_TYPE needs to be "ALL", "USER" OR "GROUP"!';
RAISERROR(@RETURN_STATUS_TEXT,16,1);
RETURN @RETURN_STATUS;
END;
IF ((@OBJECT_TYPE <> 'ALL') AND (@OBJECT_NAME = N'')) BEGIN
SET @RETURN_STATUS = 50002;
SET @RETURN_STATUS_TEXT = 'ERROR: Parameter @OBJECT_NAME is required, when @OBJECT_TYPE isnt "ALL"!';
RAISERROR(@RETURN_STATUS_TEXT,16,1);
RETURN @RETURN_STATUS;
END;
IF (@SYNC_EXT_SYSTEM = 0) AND (@CLEAN_EXT_SYSTEM = 0) AND (@SYNC_INT_REPRESENTATION = 0) AND (@CLEAN_INT_REPRESENTATION = 0) BEGIN
SET @RETURN_STATUS = 50003;
SET @RETURN_STATUS_TEXT = 'ERROR: Parameter @SYNC_EXT_SYSTEM, @CLEAN_EXT_SYSTEM, @SYNC_INT_REPRESENTATION or @CLEAN_INT_REPRESENTATION needs to be 1!';
RAISERROR(@RETURN_STATUS_TEXT,16,1);
RETURN @RETURN_STATUS;
END;
-----------------------------------------------------------------------------------------------------------------------------
--===============================================--Get objects to process --===============================================--
IF (@OBJECT_TYPE IN ('ALL','USER')) BEGIN
IF (@OBJECT_NAME <> N'') BEGIN -- Get data for a specific user
INSERT INTO @vTB_OBJECTS([ID], [OBJECT_TYPE], [OBJECT_NAME])
SELECT [GUID],'USER', [USERNAME]
FROM [dbo].[TBDD_USER] WITH (NOLOCK)
WHERE [DELETED] = 0 AND [ACTIVE] = 1
AND [USERNAME] = @OBJECT_NAME;
END; ELSE BEGIN -- Get data for all active users
INSERT INTO @vTB_OBJECTS([ID], [OBJECT_TYPE], [OBJECT_NAME])
SELECT [GUID],'USER', [USERNAME]
FROM [dbo].[TBDD_USER] WITH (NOLOCK)
WHERE [DELETED] = 0 AND [ACTIVE] = 1;
END;
END;
IF (@OBJECT_TYPE IN ('ALL','GROUP')) BEGIN
IF (@OBJECT_NAME <> N'') BEGIN -- Get data for a specific group
INSERT INTO @vTB_OBJECTS([ID], [OBJECT_TYPE], [OBJECT_NAME])
SELECT [GUID],'GROUP', [NAME]
FROM [dbo].[TBDD_GROUPS] WITH (NOLOCK)
WHERE [INTERNAL] <> 1 AND [ACTIVE] = 1
AND [NAME] = @OBJECT_NAME;
END; ELSE BEGIN -- Get data for all active groups
INSERT INTO @vTB_OBJECTS([ID], [OBJECT_TYPE], [OBJECT_NAME])
SELECT [GUID],'GROUP', [NAME]
FROM [dbo].[TBDD_GROUPS] WITH (NOLOCK)
WHERE [INTERNAL] <> 1 AND [ACTIVE] = 1;
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
--==========================================--Get group IDs for representation --==========================================--
IF ((@SYNC_INT_REPRESENTATION = 1) OR (@CLEAN_INT_REPRESENTATION = 1)) BEGIN
INSERT INTO @vTB_REPRESENTATIONS ([ID], [OBJECT_TYPE],[GROUP_ID])
SELECT [GU].[USER_ID], 'USER', [GU].[GROUP_ID]
FROM [dbo].[TBDD_GROUPS_USER] AS [GU] WITH (NOLOCK)
INNER JOIN [dbo].[TBDD_GROUPS] AS [G] WITH (NOLOCK) ON [GU].[GROUP_ID] = [G].[GUID]
WHERE [G].[ACTIVE] = 1 AND [G].[INTERNAL] <> 1
AND [GU].[USER_ID] in (SELECT DISTINCT [ID] FROM @vTB_OBJECTS WHERE [OBJECT_TYPE] = 'USER');
END;
-----------------------------------------------------------------------------------------------------------------------------
--==================================================-- Show work data --==================================================--
IF (@DEBUG = 1) BEGIN
SELECT TOP (100) PERCENT
[ID], [OBJECT_TYPE], [OBJECT_NAME]
FROM @vTB_OBJECTS
ORDER BY [OBJECT_TYPE] DESC, [ID] ASC;
SELECT TOP (100) PERCENT
[ID], [OBJECT_TYPE], [GROUP_ID]
FROM @vTB_REPRESENTATIONS
ORDER BY [OBJECT_TYPE] DESC, [ID] ASC;
END;
-----------------------------------------------------------------------------------------------------------------------------
--==================================================-- Main Processing --==================================================--
SET @ROW_COUNT1 = (SELECT count (*) FROM @vTB_OBJECTS);
IF (@ROW_COUNT1 > 0) BEGIN
PRINT '';
PRINT 'INFO: Found: ' + convert(nvarchar(15),@ROW_COUNT1) + ' objects (users/groups) to process!';
DECLARE CURSOR_OBJECT_PROCESSING CURSOR
LOCAL FAST_FORWARD FOR
SELECT TOP (100) PERCENT
[ID], [OBJECT_TYPE], [OBJECT_NAME]
FROM @vTB_OBJECTS
ORDER BY [OBJECT_TYPE] DESC, [ID] ASC;
OPEN CURSOR_OBJECT_PROCESSING
FETCH NEXT FROM CURSOR_OBJECT_PROCESSING INTO @ID, @OBJECT_TYPE, @OBJECT_NAME;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT '';
PRINT 'Processing: ' + @OBJECT_NAME
IF (@OBJECT_TYPE = 'USER') BEGIN
IF ((@SYNC_EXT_SYSTEM = 1) OR (@CLEAN_EXT_SYSTEM = 1)) BEGIN
SET @EXT_SYSTEM_USER_ID = (SELECT [dwUserID]
FROM [windreamDB].[dbo].[UserInfo] WITH (NOLOCK)
WHERE UPPER(szUserName) = UPPER(@OBJECT_NAME));
IF ((@SYNC_EXT_SYSTEM = 1) AND (@EXT_SYSTEM_USER_ID IS NOT NULL)) BEGIN
BEGIN TRY
UPDATE [dbo].[TBDD_USER]
SET [USERID_FK_INT_ECM] = @EXT_SYSTEM_USER_ID,
[CHANGED_WHO] = @MY_PROCEDURE_NAME,
[CHANGED_WHEN] = GETDATE()
WHERE [GUID] = @ID;
PRINT 'INFO: User: ' + @OBJECT_NAME + ' has be updateded with external system ID: ' + convert(nvarchar(25),@EXT_SYSTEM_USER_ID);
END TRY BEGIN CATCH
PRINT 'ERROR: User: ' + @OBJECT_NAME + ' cannot be updateded with external system ID!'
SET @RETURN_STATUS_TEXT = 'ERROR: ' + ERROR_MESSAGE();
RAISERROR(@RETURN_STATUS_TEXT,16,1);
END CATCH;
END; ELSE IF ((@CLEAN_EXT_SYSTEM = 1) AND (@EXT_SYSTEM_USER_ID IS NULL)) BEGIN
BEGIN TRY
UPDATE [dbo].[TBDD_USER]
SET [USERID_FK_INT_ECM] = 0,
[CHANGED_WHO] = @MY_PROCEDURE_NAME,
[CHANGED_WHEN] = GETDATE()
WHERE [GUID] = @ID;
PRINT 'INFO: User: ' + @OBJECT_NAME + ' has be removed the external system ID';
END TRY BEGIN CATCH
PRINT 'ERROR: User: ' + @OBJECT_NAME + ' cannot removed the external system ID!'
SET @RETURN_STATUS_TEXT = 'ERROR: ' + ERROR_MESSAGE();
RAISERROR(@RETURN_STATUS_TEXT,16,1);
END CATCH;
END;
END;
END; ELSE IF (@OBJECT_TYPE = 'GROUP') BEGIN
IF ((@SYNC_EXT_SYSTEM = 1) OR (@CLEAN_EXT_SYSTEM = 1)) BEGIN
SET @EXT_SYSTEM_GROUP_ID = (SELECT [dwGroupID]
FROM [windreamDB].[dbo].[GroupInfo] WITH (NOLOCK)
WHERE UPPER(szGroupName) = UPPER(@OBJECT_NAME));
IF ((@SYNC_EXT_SYSTEM = 1) AND (@EXT_SYSTEM_GROUP_ID IS NOT NULL)) BEGIN
BEGIN TRY
UPDATE [dbo].[TBDD_GROUPS]
SET [ECM_FK_ID] = @EXT_SYSTEM_GROUP_ID,
[CHANGED_WHO] = @MY_PROCEDURE_NAME,
[CHANGED_WHEN] = GETDATE()
WHERE [GUID] = @ID;
PRINT 'INFO: Group: ' + @OBJECT_NAME + ' has be updateded with external system ID: ' + convert(nvarchar(25),@EXT_SYSTEM_GROUP_ID);
END TRY BEGIN CATCH
PRINT 'ERROR: Group: ' + @OBJECT_NAME + ' cannot be updateded with external system ID!'
SET @RETURN_STATUS_TEXT = 'ERROR: ' + ERROR_MESSAGE();
RAISERROR(@RETURN_STATUS_TEXT,16,1);
END CATCH;
END; ELSE IF ((@CLEAN_EXT_SYSTEM = 1) AND (@EXT_SYSTEM_GROUP_ID IS NULL)) BEGIN
BEGIN TRY
UPDATE [dbo].[TBDD_GROUPS]
SET [ECM_FK_ID] = 0,
[CHANGED_WHO] = @MY_PROCEDURE_NAME,
[CHANGED_WHEN] = GETDATE()
WHERE [GUID] = @ID;
PRINT 'INFO: Group: ' + @OBJECT_NAME + ' has be removed the external system ID';
END TRY BEGIN CATCH
PRINT 'ERROR: Group: ' + @OBJECT_NAME + ' cannot removed the external system ID!'
SET @RETURN_STATUS_TEXT = 'ERROR: ' + ERROR_MESSAGE();
RAISERROR(@RETURN_STATUS_TEXT,16,1);
END CATCH;
END;
END;
END;
--===========================================-- Handle IDs for representation --===========================================--
IF ((@SYNC_INT_REPRESENTATION = 1) OR (@CLEAN_INT_REPRESENTATION = 1)) BEGIN
SET @ROW_COUNT2 = (SELECT count (*) FROM @vTB_REPRESENTATIONS WHERE [ID] = @ID AND [OBJECT_TYPE] = 'USER');
IF (@ROW_COUNT2 > 0) BEGIN
--==================================================-- Show work data --==================================================--
IF (@DEBUG = 1) BEGIN
SELECT DISTINCT
[ID] as 'USER_ID', [OBJECT_TYPE], [GROUP_ID]
FROM @vTB_REPRESENTATIONS
WHERE [ID] = @ID AND [OBJECT_TYPE] = 'USER'
ORDER BY [ID] ASC;
END;
-----------------------------------------------------------------------------------------------------------------------------
PRINT '';
PRINT 'INFO: Found: ' + convert(nvarchar(15),@ROW_COUNT2) + ' objects (users/groups) to process (Representation)!';
DECLARE CURSOR_REPRESENTATIONS_PROCESSING CURSOR
LOCAL FAST_FORWARD FOR
SELECT DISTINCT
[ID] as 'USER_ID', [OBJECT_TYPE], [GROUP_ID]
FROM @vTB_REPRESENTATIONS
WHERE [ID] = @ID AND [OBJECT_TYPE] = 'USER'
ORDER BY [ID] ASC;
OPEN CURSOR_REPRESENTATIONS_PROCESSING
FETCH NEXT FROM CURSOR_REPRESENTATIONS_PROCESSING INTO @USER_ID, @OBJECT_TYPE, @GROUP_ID;
WHILE @@FETCH_STATUS = 0
BEGIN
IF (@SYNC_INT_REPRESENTATION = 1) BEGIN -- Create new allocations
IF NOT EXISTS (SELECT 1 FROM [dbo].[TBDD_USER_REPRESENTATION] WITH (NOLOCK)
WHERE [USER_ID] = @USER_ID AND [REPR_GROUP] = @GROUP_ID) BEGIN
BEGIN TRY
INSERT INTO [dbo].[TBDD_USER_REPRESENTATION]([USER_ID],[REPR_USER],[REPR_GROUP],[RIGHT_GROUP],[ADDED_WHO], [ADDED_WHEN])
VALUES (@USER_ID, NULL, @GROUP_ID, NULL, @MY_PROCEDURE_NAME, GetDate())
PRINT 'INFO: User: ' + @OBJECT_NAME + ' has be inserted with representation of group ID: ' + convert(nvarchar(25),@GROUP_ID);
END TRY BEGIN CATCH
PRINT 'ERROR: User: ' + @OBJECT_NAME + ' cannot be inserted with representation of group ID!'
SET @RETURN_STATUS_TEXT = 'ERROR: ' + ERROR_MESSAGE();
RAISERROR(@RETURN_STATUS_TEXT,16,1);
END CATCH;
END;
END;
IF (@CLEAN_INT_REPRESENTATION = 1) BEGIN -- Delete old allocations
IF EXISTS (SELECT 1
FROM [dbo].[TBDD_USER_REPRESENTATION] WITH (NOLOCK)
WHERE [USER_ID] = @USER_ID
AND NOT EXISTS (
SELECT 1
FROM @vTB_REPRESENTATIONS AS [R]
WHERE [R].[ID] = @USER_ID AND [R].[OBJECT_TYPE] = 'USER' AND [R].[GROUP_ID] = @GROUP_ID
)
AND ( [ADDED_WHO] = @MY_PROCEDURE_NAME OR [CHANGED_WHO] = @MY_PROCEDURE_NAME )
) BEGIN
BEGIN TRY
DELETE FROM [dbo].[TBDD_USER_REPRESENTATION]
WHERE [USER_ID] = @USER_ID
AND NOT EXISTS (
SELECT 1
FROM @vTB_REPRESENTATIONS AS [R]
WHERE [R].[ID] = @USER_ID AND [R].[OBJECT_TYPE] = 'USER' AND [R].[GROUP_ID] = @GROUP_ID
)
AND ( [ADDED_WHO] = @MY_PROCEDURE_NAME OR [CHANGED_WHO] = @MY_PROCEDURE_NAME );
PRINT 'INFO: User: ' + @OBJECT_NAME + ' has be deleted with representation of group ID: ' + convert(nvarchar(25),@GROUP_ID);
END TRY BEGIN CATCH
PRINT 'ERROR: User: ' + @OBJECT_NAME + ' cannot be deleted with representation of group ID!'
SET @RETURN_STATUS_TEXT = 'ERROR: ' + ERROR_MESSAGE();
RAISERROR(@RETURN_STATUS_TEXT,16,1);
END CATCH;
END;
END;
FETCH NEXT FROM CURSOR_REPRESENTATIONS_PROCESSING INTO @USER_ID, @OBJECT_TYPE, @GROUP_ID;
END
CLOSE CURSOR_REPRESENTATIONS_PROCESSING;
DEALLOCATE CURSOR_REPRESENTATIONS_PROCESSING;
END; ELSE BEGIN
PRINT '';
PRINT 'WARN: Found no objects (users/groups) to process (Representation)!';
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
FETCH NEXT FROM CURSOR_OBJECT_PROCESSING INTO @ID, @OBJECT_TYPE, @OBJECT_NAME;
END
CLOSE CURSOR_OBJECT_PROCESSING;
DEALLOCATE CURSOR_OBJECT_PROCESSING;
END; ELSE BEGIN
PRINT '';
PRINT 'WARN: Found no objects (users/groups) to process!';
END;
-----------------------------------------------------------------------------------------------------------------------------
--================================================-- Set session options --===============================================--
EXEC sys.sp_set_session_context @key = 'SkipTrigger', @value = NULL;
----------------------------------------------------------------------------------------------------------------------------
--======================================================-- 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 '====================================================================================================';
-----------------------------------------------------------------------------------------------------------------------------------
RETURN @RETURN_STATUS;
END;
/***
EXEC sp_recompile '[PRDD_SYNC_USER_OR_GROUP]'
GO
-- TEST:
EXEC [dbo].[PRDD_SYNC_USER_OR_GROUP]
@pOBJECT_TYPE = 'ALL',
@pOBJECT_NAME = NULL,
@pSYNC_EXT_SYSTEM = 1,
@pCLEAN_EXT_SYSTEM = 1,
@pSYNC_INT_REPRESENTATION = 1,
@pCLEAN_INT_REPRESENTATION = 1,
@pDEBUG = 1
***/

View File

@@ -0,0 +1,31 @@
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER TRIGGER [dbo].[TBDD_GROUPS_AFT_INS] ON [dbo].[TBDD_GROUPS]
FOR INSERT
AS
BEGIN
IF SESSION_CONTEXT(N'SkipTrigger') = 1 BEGIN
RETURN; -- Trigger überspringen
END;
DECLARE @GRPNAME NVARCHAR(50);
SELECT @GRPNAME = NAME FROM inserted;
EXEC [dbo].[PRDD_SYNC_USER_OR_GROUP]
@pOBJECT_TYPE = 'Group',
@pOBJECT_NAME = @GRPNAME,
@pSYNC_EXT_SYSTEM = 1,
@pCLEAN_EXT_SYSTEM = 1,
@pSYNC_INT_REPRESENTATION = 0,
@pCLEAN_INT_REPRESENTATION = 0,
@pDEBUG = 0;
END;
GO
ALTER TABLE [dbo].[TBDD_GROUPS] ENABLE TRIGGER [TBDD_GROUPS_AFT_INS]
GO

View File

@@ -0,0 +1,33 @@
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER TRIGGER [dbo].[TBDD_GROUPS_AFT_UPD] ON [dbo].[TBDD_GROUPS]
FOR UPDATE
AS
BEGIN
IF SESSION_CONTEXT(N'SkipTrigger') = 1 BEGIN
RETURN; -- Trigger überspringen
END;
DECLARE @GRPNAME NVARCHAR(50);
SELECT @GRPNAME = NAME FROM inserted;
EXEC [dbo].[PRDD_SYNC_USER_OR_GROUP]
@pOBJECT_TYPE = 'Group',
@pOBJECT_NAME = @GRPNAME,
@pSYNC_EXT_SYSTEM = 1,
@pCLEAN_EXT_SYSTEM = 1,
@pSYNC_INT_REPRESENTATION = 0,
@pCLEAN_INT_REPRESENTATION = 0,
@pDEBUG = 0;
UPDATE TBDD_GROUPS SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_GROUPS.GUID = INSERTED.GUID
END;
GO
ALTER TABLE [dbo].[TBDD_GROUPS] ENABLE TRIGGER [TBDD_GROUPS_AFT_UPD]
GO

View File

@@ -0,0 +1,31 @@
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER TRIGGER [dbo].[TBDD_USER_AFT_INS] ON [dbo].[TBDD_USER]
FOR INSERT
AS
BEGIN
IF SESSION_CONTEXT(N'SkipTrigger') = 1 BEGIN
RETURN; -- Trigger überspringen
END;
DECLARE @USRNAME NVARCHAR(50);
SELECT @USRNAME = USERNAME FROM inserted;
EXEC [dbo].[PRDD_SYNC_USER_OR_GROUP]
@pOBJECT_TYPE = 'User',
@pOBJECT_NAME = @USRNAME,
@pSYNC_EXT_SYSTEM = 1,
@pCLEAN_EXT_SYSTEM = 1,
@pSYNC_INT_REPRESENTATION = 0,
@pCLEAN_INT_REPRESENTATION = 0,
@pDEBUG = 0;
END
GO
ALTER TABLE [dbo].[TBDD_USER] ENABLE TRIGGER [TBDD_USER_AFT_INS]
GO

View File

@@ -0,0 +1,32 @@
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER TRIGGER [dbo].[TBDD_USER_AFT_UPD] ON [dbo].[TBDD_USER]
FOR UPDATE
AS
BEGIN
IF SESSION_CONTEXT(N'SkipTrigger') = 1 BEGIN
RETURN; -- Trigger überspringen
END;
DECLARE @USRNAME NVARCHAR(50);
SELECT @USRNAME = USERNAME FROM inserted;
EXEC [dbo].[PRDD_SYNC_USER_OR_GROUP]
@pOBJECT_TYPE = 'User',
@pOBJECT_NAME = @USRNAME,
@pSYNC_EXT_SYSTEM = 1,
@pCLEAN_EXT_SYSTEM = 1,
@pSYNC_INT_REPRESENTATION = 0,
@pCLEAN_INT_REPRESENTATION = 0,
@pDEBUG = 0;
UPDATE TBDD_USER SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_USER.GUID = INSERTED.GUID
END
GO
ALTER TABLE [dbo].[TBDD_USER] ENABLE TRIGGER [TBDD_USER_AFT_UPD]
GO

View File

@@ -0,0 +1,16 @@
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER TRIGGER [dbo].[TBDD_USER_REPRESENTATION_AFT_UPD] ON [dbo].[TBDD_USER_REPRESENTATION]
FOR UPDATE
AS
BEGIN
IF SESSION_CONTEXT(N'SkipTrigger') = 1 BEGIN
RETURN; -- Trigger überspringen
END;
UPDATE TBDD_USER_REPRESENTATION SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_USER_REPRESENTATION.GUID = INSERTED.GUID
END