Generating a Distinct Delimited List Using XML

  • How's this for data? 🙂

    CREATE TABLE #Role

    (

    RoleName VARCHAR(100)

    );

    GO

    INSERT INTO #Role

    (

    RoleName

    )

    VALUES ('Accounting'), ('Approver'), ('Developer'), ('International Sales Manager'), ('Marketing'), ('System Administrator'),

    ('Technical Customer'), ('Technical Director'), ('Training');

    GO

    CREATE TABLE #UserRole

    (

    UserID INT NOT NULL,

    RoleName VARCHAR(100) NOT NULL,

    ProjectID INT NOT NULL,

    RoleAssignedDate DATETIME NOT NULL,

    PRIMARY KEY

    (

    UserID,

    RoleName,

    ProjectID,

    RoleAssignedDate

    )

    );

    GO

    CREATE TABLE #Numbers

    (

    Num INT NOT NULL PRIMARY KEY

    );

    GO

    WITH DIGITS

    AS

    (

    SELECT 0 AS Num

    UNION ALL

    SELECT Num + 1

    FROM DIGITS

    WHERE Num < 10

    )

    INSERT INTO #Numbers

    (

    Num

    )

    SELECT Num

    FROM DIGITS;

    GO

    WITH NUMBERS

    AS

    (

    SELECT HundredThousand.Num * 100000 + TenThousand.Num * 10000 +

    Thousand.Num * 1000 + Hundred.Num * 100 +

    Ten.Num + One.Num AS Num

    FROM #Numbers HundredThousand

    CROSS JOIN #Numbers TenThousand

    CROSS JOIN #Numbers Thousand

    CROSS JOIN #Numbers Hundred

    CROSS JOIN #Numbers Ten

    CROSS JOIN #Numbers One

    ),

    RANDOMDATA

    AS

    (

    SELECT Num AS UserID,

    RoleName,

    ABS(CHECKSUM(NEWID()) % 8000) + 1000 AS ProjectID,

    DATEADD(DAY, -ABS(CHECKSUM(NEWID()) % 1000), GETDATE()) AS RoleAssignedDate,

    NEWID() AS SortOrder

    FROM NUMBERS

    CROSS JOIN #Role

    )

    INSERT INTO #UserRole

    (

    UserID,

    RoleName,

    ProjectID,

    RoleAssignedDate

    )

    SELECT TOP(1000000) UserID,

    RoleName,

    ProjectID,

    RoleAssignedDate

    FROM RANDOMDATA

    ORDER BY SortOrder;

    GO

  • I did something similar the other month to demonstrate the use of XML data, and how to remove the dreaded cursors from the code, granted it was written on an intitally small set and there was not requirement for Ordering the data in the output list.

    The main difference was that I prefixed the list with a Comma, this mean that I could simply do a substring(XMLString,2,4000), the code looked like this

    Select Distinct

    EmployeeID

    ,Substring(Replace

    (Replace((Select ','+SkillData

    From #tmp

    where EmployeeID=a.EmployeeID

    FOR XML RAW),'<Row Data="',''),'"/>',''),2,4000) Data

    from #tmp a

    The XML data before the Replace is run looked like

    <row Data=",UU"/><row Data=",WW"/><row Data=",XX"/><row Data=",ZZ"/>

    After the replace you had a string that looked like this ",UU,WW,XX,ZZ"

    The downside is the distinct has on large data sets it could have an impact.

    Having said that I do like the look of some of the pure T-SQL scripts.

    _________________________________________________________________________
    SSC Guide to Posting and Best Practices

  • I did the test and combined Mike's test data with (most of) the suggestions:

    *** Peso ***********************************************************************

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 0 ms.

    UserID Roles

    ----------- -------------------------------------------------------------------------------------------------------------------------------------

    1 Technical Director,Technical Customer

    2 R&D,Approver

    4 International Sales Manager,Marketing,System Administrator,Technical Customer

    ...

    1111018 International Sales Manager,Technical Director

    1111019 Approver,Marketing

    1111020 Approver

    (210092 row(s) affected)

    Table '#UserRole___________________________________________________________________________________________________________0000000007DC'. Scan count 210093, logical reads 641750, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 7719 ms, elapsed time = 7917 ms.

    *** Puja Shah ******************************************************************

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 0 ms.

    UserID Roles

    ----------- -------------------------------------------------------------------------------------------------------------------------------------

    1 Technical Director, Technical Customer

    2 R&D, Approver

    4 International Sales Manager, Marketing, System Administrator, Technical Customer

    ...

    1111018 International Sales Manager, Technical Director

    1111019 Approver, Marketing

    1111020 Approver

    (210092 row(s) affected)

    Table '#UserRole___________________________________________________________________________________________________________0000000007DC'. Scan count 210095, logical reads 641749, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1210296, logical reads 3993980, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 1509437 ms, elapsed time = 772965 ms.

    *** Kailash Mishra *************************************************************

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 0 ms.

    UserID

    ----------- -------------------------------------------------------------------------------------------------------------------------------------

    1 Technical Customer,Technical Director

    2 Approver,R&D

    4 International Sales Manager,Marketing,System Administrator,Technical Customer

    ...

    1111018 International Sales Manager,Technical Director

    1111019 Approver,Marketing

    1111020 Approver

    (210092 row(s) affected)

    Table '#UserRole___________________________________________________________________________________________________________0000000007DC'. Scan count 210095, logical reads 641749, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1210312, logical reads 4167863, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 103482 ms, elapsed time = 54131 ms.

    *** R.P.Rozema ****************************************************************

    SQL Server parse and compile time:

    CPU time = 0 ms, elapsed time = 13 ms.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 0 ms.

    UserID Roles

    ----------- -------------------------------------------------------------------------------------------------------------------------------------

    1 Technical Director, Technical Customer

    2 R&D, Approver

    4 International Sales Manager, Marketing, System Administrator, Technical Customer

    ...

    1111018 International Sales Manager, Technical Director

    1111019 Approver, Marketing

    1111020 Approver

    (210092 row(s) affected)

    Table '#UserRole___________________________________________________________________________________________________________0000000007DC'. Scan count 210093, logical reads 641750, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 20672 ms, elapsed time = 21298 ms.

    *** Brian Barkauskas 1st ****************************************************************

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 0 ms.

    UserID RoleName

    ----------- -------------------------------------------------------------------------------------------------------------------------------------

    8 Marketing, Technical Director, Training, Accounting, Approver

    9 Accounting, R&D, Developer

    10 Accounting, R&D, Technical Customer, System Administrator, Training

    ...

    1111014 Approver, Technical Director, Training, System Administrator

    1111015 Developer, Training

    1111016 Marketing, R&D

    (210092 row(s) affected)

    Table '#UserRole___________________________________________________________________________________________________________0000000007DC'. Scan count 974634, logical reads 2944527, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1210315, logical reads 4196120, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 96921 ms, elapsed time = 51262 ms.

    *** Brian Barkauskas 2nd ****************************************************************

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 0 ms.

    UserID RoleName

    ----------- -------------------------------------------------------------------------------------------------------------------------------------

    1 Technical Director, Technical Customer

    2 R&D, Approver

    4 International Sales Manager, Marketing, System Administrator, Technical Customer

    ...

    1111018 International Sales Manager, Technical Director

    1111019 Approver, Marketing

    1111020 Approver

    (210092 row(s) affected)

    Table '#UserRole___________________________________________________________________________________________________________0000000007DC'. Scan count 210093, logical reads 641750, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 8000 ms, elapsed time = 8233 ms.

    Soooooooo... Granted, Brian's 2nd is faster than my suggestion. However, that 2nd suggestion is nearly identical to Peso's suggestion, so you can hardly claim credit for that.

    Plus, as you can not see due to the forum code translating the & amp ; in the output back into &, I've added 'R&D' as a role. Mine is the only suggestion that correctly returns 'R&D' instead of 'R& amp ;D' (without the spaces).

    To see what the difference is I also tried changing the case row_number() when 1 then '' else ',' end construct into the stuff( ..., 1, 2, '')-construction in my suggestion and found out that the stuff construction is indeed faster: about 0.013ms per row. Resulting in a gain of roughly 3 seconds for these 200K rows. So it is better to use stuff() on the result to replace the first ',' in the resulting string than to use case row_number to suppress the ',' on only the first role name.

    In conclusion: When you can guarantee the role name will never contain any of &, < or >, use this:

    -- Peso

    PRINT '*** Peso ***********************************************************************'

    SELECT b.UserID,

    STUFF(f.Roles, 1, 1, '') AS Roles

    FROM (

    SELECT UserID

    FROM #UserRole

    GROUP BY UserID

    ) AS b

    CROSS APPLY (

    SELECT TOP(100) PERCENT

    ',' + w.RoleName

    FROM #UserRole AS w

    WHERE w.UserID = b.UserID

    GROUP BY w.RoleName

    ORDER BY MIN(RoleAssignedDate)

    FOR XML PATH('')

    ) AS f(Roles)

    ORDER BY b.UserID

    If however your role name can contain any of the characters &, < or >, use this -at the cost of almost doubling the required cpu time from 8250 ms to 17203 ms for these 210092 rows- :

    PRINT '*** Peso & R.P.Rozema ****************************************************************'

    SELECT b.UserID,

    STUFF(f.Roles.value('.','nvarchar(max)'), 1, 1, '') AS Roles

    FROM (

    SELECT UserID

    FROM #UserRole

    GROUP BY UserID

    ) AS b

    CROSS APPLY (

    SELECT ',' + w.RoleName as [text()]

    FROM #UserRole AS w

    WHERE w.UserID = b.UserID

    GROUP BY w.RoleName

    ORDER BY MIN(RoleAssignedDate)

    FOR XML PATH(''), type

    ) AS f(Roles)

    ORDER BY b.UserID

    Or cheat and do the translation of the xml escaped characters yourself too, reducing the loss of performance a little to 13985 ms cpu time on the same data set:

    PRINT '*** Peso & R.P.Rozema ****************************************************************'

    SELECT b.UserID,

    replace(replace(replace(STUFF(f.Roles, 1, 1, ''), '&', '&'), '&lt', '<'), '&gt', '>') AS Roles

    FROM (

    SELECT UserID

    FROM #UserRole

    GROUP BY UserID

    ) AS b

    CROSS APPLY (

    SELECT ',' + w.RoleName as [text()]

    FROM #UserRole AS w

    WHERE w.UserID = b.UserID

    GROUP BY w.RoleName

    ORDER BY MIN(RoleAssignedDate)

    FOR XML PATH('')

    ) AS f(Roles)

    ORDER BY b.UserID



    Posting Data Etiquette - Jeff Moden[/url]
    Posting Performance Based Questions - Gail Shaw[/url]
    Hidden RBAR - Jeff Moden[/url]
    Cross Tabs and Pivots - Jeff Moden[/url]
    Catch-all queries - Gail Shaw[/url]


    If you don't have time to do it right, when will you have time to do it over?

  • I didn't get a chance to run any tests against the data (it was a little late when I posted that), but one thing worth considering is whether or not a specific indexing strategy/index changes can improve the results. I slapped a clustered PK on the sample data, but not necessarily the most efficient for any given query.

    Thanks

    Mike C

  • I found Brian's 2nd solution easier to understand....I dig the STUFF...never used that before.

  • Bradley Deem (6/29/2010)


    I recommend using a CLR for this. Microsoft has a great example here http://msdn.microsoft.com/en-us/library/ms131056.aspx. I'm curious what the performance differences are. Admittedly, I have not compared the two because I've never had the CLR function not perform adequately.

    You can then use this as an aggregate, for example.

    SELECT dbo.List(myColumn)

    FROM myTable

    GROUP BY SomeOtherColumn

    What version of SQLSERVER are you running with CLR? Any issues with the server crashing? Could the server crash if the CLR has an unhandled exception?

    I see the power of CLR, but the boss and I are scared for the database.

    Thanks

    Chris

  • Mike C (6/29/2010)


    How's this for data? 🙂

    CREATE TABLE #Role

    (

    RoleName VARCHAR(100)

    );

    GO

    INSERT INTO #Role

    (

    RoleName

    )

    VALUES ('Accounting'), ('Approver'), ('Developer'), ('International Sales Manager'), ('Marketing'), ('System Administrator'),

    ('Technical Customer'), ('Technical Director'), ('Training');

    GO

    CREATE TABLE #UserRole

    (

    UserID INT NOT NULL,

    RoleName VARCHAR(100) NOT NULL,

    ProjectID INT NOT NULL,

    RoleAssignedDate DATETIME NOT NULL,

    PRIMARY KEY

    (

    UserID,

    RoleName,

    ProjectID,

    RoleAssignedDate

    )

    );

    GO

    CREATE TABLE #Numbers

    (

    Num INT NOT NULL PRIMARY KEY

    );

    GO

    WITH DIGITS

    AS

    (

    SELECT 0 AS Num

    UNION ALL

    SELECT Num + 1

    FROM DIGITS

    WHERE Num < 10

    )

    INSERT INTO #Numbers

    (

    Num

    )

    SELECT Num

    FROM DIGITS;

    GO

    WITH NUMBERS

    AS

    (

    SELECT HundredThousand.Num * 100000 + TenThousand.Num * 10000 +

    Thousand.Num * 1000 + Hundred.Num * 100 +

    Ten.Num + One.Num AS Num

    FROM #Numbers HundredThousand

    CROSS JOIN #Numbers TenThousand

    CROSS JOIN #Numbers Thousand

    CROSS JOIN #Numbers Hundred

    CROSS JOIN #Numbers Ten

    CROSS JOIN #Numbers One

    ),

    RANDOMDATA

    AS

    (

    SELECT Num AS UserID,

    RoleName,

    ABS(CHECKSUM(NEWID()) % 8000) + 1000 AS ProjectID,

    DATEADD(DAY, -ABS(CHECKSUM(NEWID()) % 1000), GETDATE()) AS RoleAssignedDate,

    NEWID() AS SortOrder

    FROM NUMBERS

    CROSS JOIN #Role

    )

    INSERT INTO #UserRole

    (

    UserID,

    RoleName,

    ProjectID,

    RoleAssignedDate

    )

    SELECT TOP(1000000) UserID,

    RoleName,

    ProjectID,

    RoleAssignedDate

    FROM RANDOMDATA

    ORDER BY SortOrder;

    GO

    Nice to see someone else ramp it up for a change. Nicely done Michael. 😀

    The next thing we need to teach is that returning results to the screen is a performance testing error known as "The Great Equalizer". :hehe:

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • chris.fauvel (6/30/2010)


    Bradley Deem (6/29/2010)


    I recommend using a CLR for this. Microsoft has a great example here http://msdn.microsoft.com/en-us/library/ms131056.aspx. I'm curious what the performance differences are. Admittedly, I have not compared the two because I've never had the CLR function not perform adequately.

    You can then use this as an aggregate, for example.

    SELECT dbo.List(myColumn)

    FROM myTable

    GROUP BY SomeOtherColumn

    What version of SQLSERVER are you running with CLR? Any issues with the server crashing? Could the server crash if the CLR has an unhandled exception?

    I see the power of CLR, but the boss and I are scared for the database.

    Thanks

    Chris

    CLR is just like any other feature. Spend some time researching the in and outs so you will be fine. In regards to your questions, this CLR function was implemented into 2005 and we recently upgraded to 2008 without any problems (in regards to the CLR). If your CLR throws an unhandled exception it will be returned to SQL; it will not crash your server. Of course, there are caveats, you could always build a CLR that could bring down a server, but I would find it hard to believe you'd knowingly put such volatile code in a CLR untested for production.

    On a side note, one of the changes to CLR in 2008 is removing the restriction of 8000 byte max. This means you could return a list of elements of size varchar(max).

  • Bradley Deem (6/30/2010)


    chris.fauvel (6/30/2010)


    Bradley Deem (6/29/2010)


    I recommend using a CLR for this. Microsoft has a great example here http://msdn.microsoft.com/en-us/library/ms131056.aspx. I'm curious what the performance differences are. Admittedly, I have not compared the two because I've never had the CLR function not perform adequately.

    You can then use this as an aggregate, for example.

    SELECT dbo.List(myColumn)

    FROM myTable

    GROUP BY SomeOtherColumn

    What version of SQLSERVER are you running with CLR? Any issues with the server crashing? Could the server crash if the CLR has an unhandled exception?

    I see the power of CLR, but the boss and I are scared for the database.

    Thanks

    Chris

    CLR is just like any other feature. Spend some time researching the in and outs so you will be fine. In regards to your questions, this CLR function was implemented into 2005 and we recently upgraded to 2008 without any problems (in regards to the CLR). If your CLR throws an unhandled exception it will be returned to SQL; it will not crash your server. Of course, there are caveats, you could always build a CLR that could bring down a server, but I would find it hard to believe you'd knowingly put such volatile code in a CLR untested for production.

    On a side note, one of the changes to CLR in 2008 is removing the restriction of 8000 byte max. This means you could return a list of elements of size varchar(max).

    Unfortunately we are still at 2005, we have plans to go to 2008, but there is SOOOOO MUCH regression testing that it would preclude enhancements to the apps for several months. 🙁 ugh

  • Jeff Moden (6/30/2010)


    Nice to see someone else ramp it up for a change. Nicely done Michael. 😀

    The next thing we need to teach is that returning results to the screen is a performance testing error known as "The Great Equalizer". :hehe:

    As usual you're 2 steps ahead of me Jeff 🙂

    The only thing I wanted to add is that a performance test should be run multiple times to get a good read, they need to be sure to clean buffers and drop cache, and the difference between 2 and 4 ms in performance tuning terms is literally a rounding error 🙂

    Mike C

  • chris.fauvel (6/30/2010)


    Bradley Deem (6/29/2010)


    I recommend using a CLR for this. Microsoft has a great example here http://msdn.microsoft.com/en-us/library/ms131056.aspx. I'm curious what the performance differences are. Admittedly, I have not compared the two because I've never had the CLR function not perform adequately.

    You can then use this as an aggregate, for example.

    SELECT dbo.List(myColumn)

    FROM myTable

    GROUP BY SomeOtherColumn

    What version of SQLSERVER are you running with CLR? Any issues with the server crashing? Could the server crash if the CLR has an unhandled exception?

    I see the power of CLR, but the boss and I are scared for the database.

    Thanks

    Chris

    For this task you could build a SQL CLR assembly using the strictest permission set (SAFE), which indicates all managed code and no access to any external resources. It's highly unlikely you could write an assembly that would corrupt the memory space with SAFE permissions, but even if you could it would be limited to just the managed memory space and wouldn't bring down the server.

    There are some things to know about using SQL CLR:

    * SQL Server caches SQL CLR assemblies after it loads them the first time, for efficiency. In the case of memory pressure, SQL CLR assemblies are one of the first things to get unloaded. If you are on a machine with a lot of memory pressure SQL Server will need to reload your assemblies every time, adding overhead and cutting into any efficiency gains from using SQL CLR.

    * When you're doing string concatenation operations like this you probably want to use an efficient .NET StringBuilder object to maximize efficiency. Normal string concatenation is notoriously slow because strings are immutable (a copy of the string is made everytime it is modified).

    * SQL Server can't accurately cost a SQL CLR assembly in a query plan since it has no idea what you're doing in there.

    * In some cases SQL CLR can prevent parallelization in query plans. When you pass in LOB (varchar(max), etc.) parameters to it, for instance. That may not be an issue in this case, but is something to be aware of.

    * You need to explicitly handle NULLs on the .NET side when you use SQL CLR. One of the biggest mistakes I've seen is SQL CLR code that pretends NULLs don't exist. That usually results in hard-to-troubleshoot exceptions from the .NET side.

    If you keep these things in mind, you shouldn't have any problems with SQL CLR. This particular exercise would actually make a very nice introduction to SQL CLR.

    Mike C

  • Hi all,

    Thank you very much. I liked your suggestions & different but better solutions.

    Regards,

    Puja

Viewing 12 posts - 16 through 26 (of 26 total)

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