Home Forums SQL Server 2008 T-SQL (SS2K8) Determine unique combinations of permissions assigned to users RE: Determine unique combinations of permissions assigned to users

  • 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