New built-in function STRING_AGG() with option “WITHIN GROUP” – SQL Server 2017
In one of my [previous post] I discussed about a new function STRING_SPLIT() introduced in SQL Server 2016, which splits a Sentence or CSV String to multiple values or rows.
Now with the latest CTP 1.x version of SQL Server vNext (I’m calling it “SQL Server 2017”) a new function is introduced to just do its reverse, i.e. Concatenate string values or expressions separated by any character.
The STRING_AGG() aggregate function takes all expressions from rows and concatenates them into a single string in a single row.
It implicitly converts all expressions to String type and then concatenates with the separator defined.
–> In the example below I’ll populate a table with States and Cities in separate rows, and then try to Concatenate Cities belonging to same States:
USE tempdb GO CREATE TABLE #tempCityState ( [State] VARCHAR(5), [Cities] VARCHAR(50) ) GO INSERT INTO #tempCityState SELECT 'CA', 'Hanford' UNION ALL SELECT 'CA', 'Fremont' UNION ALL SELECT 'CA', 'Los Anggeles' UNION ALL SELECT 'CO', 'Denver' UNION ALL SELECT 'CO', 'Aspen' UNION ALL SELECT 'CO', 'Vail' UNION ALL SELECT 'CO', 'Teluride' UNION ALL SELECT 'WA', 'Seattle' UNION ALL SELECT 'WA', 'Redmond' UNION ALL SELECT 'WA', 'Bellvue' GO SELECT * FROM #tempCityState
State Cities
CA Hanford
CA Fremont
CA Los Anggeles
CO Denver
CO Aspen
CO Vail
CO Teluride
WA Seattle
WA Redmond
WA Bellvue
–> To comma separate values under a single row you just need to apply the STRING_AGG() function:
SELECT STRING_AGG(Cities, ', ') as AllCities FROM #tempCityState -- Use "WITHIN GROUP (ORDER BY ...)" clause to concatenate them in an Order: SELECT STRING_AGG(Cities, ', ') WITHIN GROUP (ORDER BY Cities) as AllCitiesSorted FROM #tempCityState
–> Now to Concatenate them by States, you just need to group them by the State, like any other aggregate function:
SELECT State, STRING_AGG(Cities, ', ') as CitiesByStates FROM #tempCityState GROUP BY State -- Use "WITHIN GROUP (ORDER BY ...)" clause to concatenate them in an Order: State, STRING_AGG(Cities, ', ') WITHIN GROUP (ORDER BY Cities) as CitiesByStatesSorted FROM #tempCityState GROUP BY State
You can check more about STRING_AGG() on MSDN.
-
January 20, 2017 at 7:00 amNew built-in function CONCAT_WS() in SQL Server vNext (2018) | SQL with Manoj