Listing members of a group in SQL Server.

Phil Factor, 2010-10-11

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

Share

Share

Rate

Related content

Database Mirroring FAQ: Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup?

Question: Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup? This question was sent to me via email. My reply follows. Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup? Databases to be mirrored are currently running on 2005 SQL instances but will be upgraded to 2008 SQL in the near future.

Robert Davis

2009-02-23

1,567 reads

Networking – Part 4

You may want to read Part 1 , Part 2 , and Part 3 before continuing. This time around I’d like to talk about social networking. We’ll start with social networking. Facebook, MySpace, and Twitter are all good examples of using technology to let…

Andy Warren

2009-02-17

1,530 reads

Speaking at Community Events – More Thoughts

Last week I posted Speaking at Community Events – Time to Raise the Bar?, a first cut at talking about to what degree we should require experience for speakers at events like SQLSaturday as well as when it might be appropriate to add additional focus/limitations on the presentations that are accepted. I’ve got a few more thoughts on the topic this week, and I look forward to your comments.

Andy Warren

2009-02-13

360 reads