8
0
Files
Skriptentwickung/current/[DD_ECM]-Database/[FNDD_GET_GROUP_FOR_USER].sql

104 lines
7.6 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.
USE [DD_ECM]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- [FNDD_GET_GROUP_FOR_USER]
-- =================================================================
-- Gets groups in which a given user is member of
--
-- Returns: Table
-- =================================================================
-- Copyright (c) 2026 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: 13.01.2026 / MK
-- Version Date / Editor: 13.01.2026 / MK
-- Version Number: 1.0.0.0
-- =================================================================
-- History:
-- 13.01.2026 / MK - First Version
CREATE OR ALTER FUNCTION [dbo].[FNDD_GET_GROUP_FOR_USER] (
@pUSER_GUID BIGINT, -- GUID from TBDD_USERS. GUID - or - USER_NAME is required!
@pUSER_NAME NVARCHAR(50), -- USERNAME FROM TBDD_USERS. GUID - or - USER_NAME is required!
@pIS_ACTIVE BIT, -- NULL = active or inactive groups, 0 = inactive groups, 1 = active groups
@pIS_INTERNAL BIT -- NULL = internal or custom groups, 0 = custom groups, 1 = internal groups
)
RETURNS @RESULT TABLE ( [GUID] [int] NOT NULL,
[NAME] [varchar](50) NULL,
[ECM_FK_ID] [int] NOT NULL,
[AD_SYNC] [bit] NOT NULL,
[INTERNAL] [bit] NOT NULL,
[ACTIVE] [bit] NOT NULL,
[COMMENT] [varchar](200) NULL,
[ADDED_WHO] [varchar](50) NULL,
[ADDED_WHEN] [datetime] NULL,
[CHANGED_WHO] [varchar](50) NULL,
[CHANGED_WHEN] [datetime] NULL)
AS
BEGIN
--=========================================-- Parameter copies (avoid sniffing) --========================================--
DECLARE @USER_GUID BIGINT = @pUSER_GUID,
@USER_NAME NVARCHAR(50) = LTRIM(RTRIM(@pUSER_NAME)),
@IS_ACTIVE BIT = @pIS_ACTIVE,
@IS_INTERNAL BIT = @pIS_INTERNAL;
----------------------------------------------------------------------------------------------------------------------------
--=============================================-- Get missing informations --=============================================--
IF ((@USER_GUID IS NULL) OR (@USER_GUID = 0)) BEGIN
SELECT @USER_GUID = [GUID]
FROM [dbo].[TBDD_USER] (NOLOCK)
WHERE UPPER([USERNAME]) = UPPER(@USER_NAME);
END;
----------------------------------------------------------------------------------------------------------------------------
--=============================================-- Get user allocated groups --============================================--
IF (@USER_GUID > 0) BEGIN
INSERT INTO @RESULT
([GUID],
[NAME],
[ECM_FK_ID],
[AD_SYNC],
[INTERNAL],
[ACTIVE],
[COMMENT],
[ADDED_WHO],
[ADDED_WHEN],
[CHANGED_WHO],
[CHANGED_WHEN])
SELECT TOP (100) PERCENT
[GUID],
[NAME],
[ECM_FK_ID],
[AD_SYNC],
[INTERNAL],
[ACTIVE],
[COMMENT],
[ADDED_WHO],
[ADDED_WHEN],
[CHANGED_WHO],
[CHANGED_WHEN]
FROM [dbo].[TBDD_GROUPS] (NOLOCK)
WHERE [GUID] IN (SELECT [GROUP_ID] FROM [dbo].[TBDD_GROUPS_USER] (NOLOCK) WHERE [USER_ID] = @USER_GUID)
AND ([ACTIVE] = CASE WHEN @IS_ACTIVE IS NULL THEN 0 ELSE @IS_ACTIVE END
OR [ACTIVE] = CASE WHEN @IS_ACTIVE IS NULL THEN 1 ELSE @IS_ACTIVE END)
AND ([INTERNAL] = CASE WHEN @IS_INTERNAL IS NULL THEN 0 ELSE @IS_INTERNAL END
OR [INTERNAL] = CASE WHEN @IS_INTERNAL IS NULL THEN 1 ELSE @IS_INTERNAL END);
END;
----------------------------------------------------------------------------------------------------------------------------
RETURN;
END;
-- Test mit
-- SELECT * FROM [FNDD_GET_GROUP_FOR_USER](1,NULL,NULL,NULL)