SQL SERVER – Group by Rows and Columns using XML PATH – Efficient Concating Trick

I hardly get hard time to come up with the title of the blog post. This was one of the blog post even though simple, I believe I have not come up with appropriate title: Group by Rows and Columns using XML PATH – Efficient Concatenating Trick. Anyway, here is the question I received.

“I have a table of students and the courses they are enrolled with the name of the professor besides it. I would like to group the result with course and instructor name.

For example, here is my table:

SQL SERVER - Group by Rows and Columns using XML PATH - Efficient Concating Trick xmlpath1

How can I generate result as following?

SQL SERVER - Group by Rows and Columns using XML PATH - Efficient Concating Trick xmlpath2

Now you can see how easy the question is but so hard to come up with either solution or the title of this blog post. We can use XML PATH and come up with the solution where we combine two or more columns together and display desired result.

Here is the quick script which does the task, ask, I have used temporary tables so you can just take this script and quickly run on your machine and see how it returns results.

Let me know if there are any better ways to do the same.

-- Create table
CREATE TABLE #TestTable (StudentName VARCHAR(100), Course VARCHAR(100), 
Instructor VARCHAR(100), RoomNo VARCHAR(100))
GO
-- Populate table
INSERT INTO #TestTable (StudentName, Course, Instructor, RoomNo)
SELECT 'Mark', 'Algebra', 'Dr. James', '101'
UNION ALL
SELECT 'Mark', 'Maths', 'Dr. Jones', '201'
UNION ALL
SELECT 'Joe', 'Algebra', 'Dr. James', '101'
UNION ALL
SELECT 'Joe', 'Science', 'Dr. Ross', '301'
UNION ALL
SELECT 'Joe', 'Geography', 'Dr. Lisa', '401'
UNION ALL
SELECT 'Jenny', 'Algebra', 'Dr. James', '101'
GO
-- Check orginal data
SELECT *
FROM #TestTable
GO
-- Group by Data using column and XML PATH
SELECT
StudentName,
STUFF((
SELECT ', ' + Course + ' by ' + CAST(Instructor AS VARCHAR(MAX)) + 
' in Room No ' + CAST(RoomNo AS VARCHAR(MAX))
FROM #TestTable
WHERE (StudentName = StudentCourses.StudentName)
FOR XML PATH (''))
,1,2,'') AS NameValues
FROM #TestTable StudentCourses
GROUP BY StudentName
GO
-- Clean up
DROP TABLE #TestTable
GO

Reference: Pinal Dave (https://blog.sqlauthority.com)

SQL Scripts, SQL Server, SQL String, SQL XML
Previous Post
SQLAuthority Contests – Get 50 Amazon Gift Cards – Experience NuoDB Starlings 1.0.2
Next Post
SQL SERVER – Weekly Series – Memory Lane – #023

Related Posts

Leave a Reply