Determine unique combinations of permissions assigned to users

  • I need to determine the unique combinations of group permissions assigned to users. Currently, permissions are assigned to a user. I'm working on changing our model to assign permissions to a role, and assigning a role to a user.

    I believe I need to generate a query to PIVOT/Select DISTINCT with Row_Number/UNPIVOT the data, but I haven't been able to structure the query.

    We have nearly 15000 users and over 1000 groups, so I can't manually type the PIVOT/UNPIVOT column names. On the plus side, I don't care what the intermediate columns names will be as they'll only be used in this statement.

    I'm starting with:

    NameGroupName

    TomAdmin

    TomAccounting

    TomSupport

    TomLegal

    DickAccounting

    DickLegal

    HarrySupport

    MarySupport

    NULLRestricted

    and need to finish with this

    RoleNumGroupName

    1Admin

    1Accounting

    1Support

    1Legal

    2Accounting

    2Legal

    3Support

    Notice the Support group only shows up once even though two people belong to that group, and the Restricted group does not appear because no one is currently assigned.

    I've created some sample tables to play with if anyone is interested in helping.:w00t:

    CREATE TABLE [dbo].[groups](

    [GroupID] [int] IDENTITY(1,1) NOT NULL,

    [GroupName] [varchar](50) NULL

    ) ON [PRIMARY]

    GO

    CREATE TABLE [dbo].[person](

    [PersonID] [int] IDENTITY(1,1) NOT NULL,

    [NAME] [varchar](10) NULL

    ) ON [PRIMARY]

    GO

    CREATE TABLE [dbo].[PersonGroups](

    [PersonID] [int] NULL,

    [GroupID] [int] NULL

    ) ON [PRIMARY]

    GO

    SET IDENTITY_INSERT [dbo].[groups] ON;

    BEGIN TRANSACTION;

    INSERT INTO [dbo].[groups]([GroupID], [GroupName])

    SELECT 1, N'Admin' UNION ALL

    SELECT 2, N'Accounting' UNION ALL

    SELECT 3, N'Support' UNION ALL

    SELECT 4, N'Legal' UNION ALL

    SELECT 5, N'Restricted'

    COMMIT;

    RAISERROR (N'[dbo].[groups]: Insert Batch: 1.....Done!', 10, 1) WITH NOWAIT;

    GO

    SET IDENTITY_INSERT [dbo].[groups] OFF;

    SET IDENTITY_INSERT [dbo].[person] ON;

    BEGIN TRANSACTION;

    INSERT INTO [dbo].[person]([PersonID], [NAME])

    SELECT 1, N'Tom' UNION ALL

    SELECT 2, N'Dick' UNION ALL

    SELECT 3, N'Harry' UNION ALL

    SELECT 4, N'Mary'

    COMMIT;

    RAISERROR (N'[dbo].[person]: Insert Batch: 1.....Done!', 10, 1) WITH NOWAIT;

    GO

    SET IDENTITY_INSERT [dbo].[person] OFF;

    BEGIN TRANSACTION;

    INSERT INTO [dbo].[PersonGroups]([PersonID], [GroupID])

    SELECT 1, 1 UNION ALL

    SELECT 1, 2 UNION ALL

    SELECT 1, 3 UNION ALL

    SELECT 1, 4 UNION ALL

    SELECT 2, 2 UNION ALL

    SELECT 2, 4 UNION ALL

    SELECT 3, 3 UNION ALL

    SELECT 4, 3

    COMMIT;

    RAISERROR (N'[dbo].[PersonGroups]: Insert Batch: 1.....Done!', 10, 1) WITH NOWAIT;

    GO

    Wes
    (A solid design is always preferable to a creative workaround)

  • If dynamic pivot will solve your case, here it is: http://sqlwithmanoj.wordpress.com/2011/01/25/dynamic-pivot/[/url]

    But I think you should rethink your concept.

    -- users with object-level permissions in current db

    sp_helprotect NULL, NULL, NULL, 'o'

    -- users with server-level permissions in current db

    sp_helprotect NULL, NULL, NULL, 's'

    -- Object-level permissions for all databases

    IF OBJECT_ID('tempdb..#p','U') is not null DROP TABLE #P

    create table #p

    (DBname nvarchar(500), Owner sysname, Object sysname, Grantee sysname, Grantor sysname,

    ProtectType varchar(100), Action varchar(100), [Column] varchar(100)

    )

    EXEC sp_msforeachdb '

    INSERT INTO #p(Owner, Object, Grantee, Grantor, ProtectType, Action, [Column]) exec ?.dbo.sp_helprotect NULL, NULL, NULL, ''o''

    UPDATE #p SET DBName=''?'' WHERE DBName IS NULL

    '

    select * from #p

    -- Roles granted

    IF OBJECT_ID('tempdb..#g','U') is not null DROP TABLE #G

    CREATE TABLE #g

    (DBName varchar(100), UserName nvarchar(500), GroupName nvarchar(500), LoginName nvarchar(500),

    DefDBName nvarchar(500),

    DefSchemaName nvarchar(500),

    UserID int, SID image

    )

    exec sp_msforeachdb

    '

    insert into #g(UserName, GroupName, LoginName,

    DefDBName,

    DefSchemaName,

    UserID, SID) EXEC sp_helpuser

    UPDATE #g SET DBName=''?'' WHERE DBName IS NULL

    '

    SELECT * FROM #G

    It's straightforward to select distinct from those.

    HTH,

    Vedran

    _____________________________________________________
    Microsoft Certified Master: SQL Server 2008
    XDetails Addin - for SQL Developers
    blog.sqlxdetails.com - Transaction log myths
  • No need to use dynamic SQL or a PIVOT for this.

    ;WITH GroupsGrouped AS (

    SELECT DISTINCT Groups=STUFF((

    SELECT ',' + CAST(GroupID AS VARCHAR(5))

    FROM PersonGroups b

    WHERE a.PersonID = b.PersonID

    ORDER BY GroupID

    FOR XML PATH('')), 1, 1, '')

    FROM personGroups a

    GROUP BY PersonID)

    SELECT RoleID, GroupName

    FROM (

    SELECT RoleID=ROW_NUMBER() OVER (ORDER BY (SELECT NULL))

    ,Groups

    FROM GroupsGrouped) a

    CROSS APPLY dbo.DelimitedSplit8K(Groups, ',') b

    INNER JOIN Groups c ON c.GroupID = b.Item

    The trick is to create a delimited string (I chose comma for my delimiter) of each combination of groups for a user. You can then apply a ROW_NUMBER() to get the RoleID and unravel the whole thing using a delimited string splitter (DelimitedSplit8K), like the one popularized here by Jeff Moden: http://www.sqlservercentral.com/articles/Tally+Table/72993/


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • @dwain.c

    Excellent, that is just what I needed.

    After working with it for a bit this morning, I've determined I need to assign the groups string in a checksum rather than a row_number. Now I don't need to worry about row_number assigments changing erratically when new group combinations are used. The checksum values won't be affected by permissions changes.

    Thanks again.

    Wes

    Wes
    (A solid design is always preferable to a creative workaround)

  • whenriksen (10/16/2012)


    @dwain.c

    Excellent, that is just what I needed.

    After working with it for a bit this morning, I've determined I need to assign the groups string in a checksum rather than a row_number. Now I don't need to worry about row_number assigments changing erratically when new group combinations are used. The checksum values won't be affected by permissions changes.

    Thanks again.

    Wes

    Happy to hear that my suggestion seems to have gotten you on the right track.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply