Archive
Posts Tagged ‘FOR XML PATH’
Combine multiple ROWS to CSV String… and vice-versa
September 16, 2010
16 comments
There are times when you want to combine values from multiple rows of a single column into a CSV (Comma Separates Value) String.
Like combining multiple orders of each customer into one single row, or multiple Cities against each State as shown below.
It was a bit difficult to do in SQL Server 2000 and requires to create a customized function or a script.
But with SQL Server’s 2005 version, the new “PATH” mode with “FOR XML” provides us a way to get the desired output. Its a bit tricky but will do the needful, that’s why I’ve also added this post for my reference as well.
CREATE TABLE #tempCityState (State VARCHAR(5), City VARCHAR(50)) INSERT INTO #tempCityState SELECT 'CO', 'Denver' UNION SELECT 'CO', 'Teluride' UNION SELECT 'CO', 'Vail' UNION SELECT 'CO', 'Aspen' UNION SELECT 'CA', 'Los Angeles' UNION SELECT 'CA', 'Hanford' UNION SELECT 'CA', 'Fremont' UNION SELECT 'WA', 'Seattle' UNION SELECT 'WA', 'Redmond' UNION SELECT 'WA', 'Bellvue' SELECT * FROM #tempCityState
State City
CA Hanford
CA Fremont
CA Los Angeles
CO Denver
CO Aspen
CO Vail
CO Teluride
WA Seattle
WA Redmond
WA Bellvue
Using the “FOR XML PATH” syntax:
SELECT DISTINCT State, (SELECT SUBSTRING((SELECT ',' + City FROM #tempCityState WHERE State = t.State FOR XML PATH('')),2,200000)) AS Cities INTO #tempCityStateCSV FROM #tempCityState t -- OR -- SELECT DISTINCT State, (SELECT STUFF((SELECT ',' + City FROM #tempCityState WHERE State = t.State FOR XML PATH('')),1,1,'')) AS Cities FROM #tempCityState t SELECT * FROM #tempCityStateCSV
State Cities
CA Hanford,Fremont,Los Angeles
CO Denver,Aspen,Vail,Teluride
WA Seattle,Redmond,Bellvue
Now, converting it back to multiple rows:
SELECT A.[State], Split.a.value('.', 'VARCHAR(100)') AS City FROM (SELECT [State], CAST ('<M>' + REPLACE([Cities], ',', '</M><M>') + '</M>' AS XML) AS String FROM #tempCityStateCSV) AS A CROSS APPLY String.nodes ('/M') AS Split(a) ORDER BY 1,2
State City CA Fremont CA Hanford CA Los Angeles CO Aspen CO Denver CO Teluride CO Vail WA Bellvue WA Redmond WA Seattle
Categories: SQL Tips
CSV String, FOR XML PATH, ROWS to CSV, XML