Blog Post

Listing members of a group in SQL Server.

,

In SQL we are used to the GROUP BY and the type of result it produces. In real life, we are often asked for other types of grouping. One of these is to produce a list of the members of each set  This is easier to show by example.

Adams (Ms. Frances B., Ms. Carla J., Mr. Jay, Mr. Ben, Jay G, Edward, Wyatt, Fernando S...)
Alan (Mr. Stanley A., Kelvin, Xavier, Cheryl L, Kari A, Alisha M, Jamie S, Bob A, Megh...)
Alberts (Ms. Amy E., Amy E, Amy)
Alderson (Mr. Gregory F., Greg )
Alexander (Mr. J. Phillip L., Ms. Michelle, Ms. Mary, Sean P, Sean, Isabella, Natalie A, Al...)
Allen (Ms. Phyllis A., Mr. Marvin N., Mr. Michael, Michael, Michael, Wyatt C, Fernando ...)
Alonso (Francis J, Andy, Alfredo T, Jessie J, Daisy, Audrey J, Beth R, Latasha A, Janet ...)
Alvarez (Francis, Max M, Andy, Jessie, Daisy P, Audrey L, Beth M, Latasha, Cheryl A, Jane...)
Anand (Dustin, Karla, Shawna P, Yolanda, Kurt L, Tommy, Cedric P, Terrence J, Niñia L, ...)
Andersen (Dustin L, Gregory, Kenneth, Warren, Kelvin C, Karla R, Shawna C, Yolanda, Bonnie...)
Anderson (Ms. Mae N., Nancy A, Wyatt M, Jeremy J, Miguel, Blake, Edward L, Seth D, Xavier,...)
Arthur (Mr. John, Jarrod R, Adriana J, Kaitlin, Tammy L, Carla, Regina A, Jermaine H, Ca...)
Arun (Harold, Erick C, Summer G, Evelyn, Ruth S, Toni, Mayra, Lydia A, Barry, Cesar J,...)
Ashe (Melvin, Reginald, Geoffrey E, Michele A, Tasha W, Maurice, Brad, Ebony E, Deanna...)
Ashton (Mr. Chris, Chris)
Bailey (Mr. James B., Natalie J, Alexandra J, Sydney, Katherine L, Amanda M, Stephanie M...)
Baker (Mary R, Bryan, Beverly, Dan, Edward, Wyatt A, Fernando R, Jeremy, Miguel M, Blak...)
Barnes (Isabella J, Natalie, Alexandra P, Sydney, Amanda N, Stephanie J, Hailey, Maria J...)

This has always been possible in SQL Server, though it has usually involved a certain trickery.  The question comes up so often as to how to do it that I thought I ought to show a simple query that uses the Adventureworks database. I've added a simple device to truncate each row after a certain number of characters and add an ellipsis.  This was really just to print out the sample output, but you may find it useful.  Generally, you should be able to perform an ungrouping as easily as you do a grouping, but, in this case, it is a bit more complicated!.

USE AdventureWorks
SELECT Lastname+' ('
            
+ LEFT(LEFT(listOfFirstNames, LEN(listOfFirstNames)-1),80)
            +
CASE WHEN LEN(listOfFirstNames)>80 THEN '...'
    
ELSE '' END +')' AS names
FROM --use a derived table as we need to perform three functions on the
    -- listofforenames column
    
(
    
SELECT lastname,
        (
        
SELECT REPLACE(REPLACE(COALESCE(Title+' ','')+COALESCE(firstname+' ','')
                            +
COALESCE(' '+Middlename,'')+', ','  ',' '),' ,',',')
            
FROM person.contact AS forename
            
WHERE forename.lastname LIKE surname.lastname
                    
FOR XML PATH(''), TYPE).value('.', 'varchar(max)') AS listOfFirstNames
        
FROM Person.Contact AS surname
        
GROUP BY lastname
        )
list
ORDER BY lastname ASC
/* thanks to Wayne Sheffield for the  .value('.', 'varchar(max)') trick
   though it is most unlikely that a name will include a < or a >. Still
   it is nice to make the example as generic as possible! */

For the ins and outs of these techniques see Concatenating Row Values in Transact-SQL by Anith Sen

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating