SQL SERVER 2017: STRING_AGG



STRING_AGG is a function released in SQL Server 2017.   The Oracle equivalent LIST_AGG has been available since 11gR2.  In the meantime, SQL Server users have resorted to black magic in order to get string values from separate rows.

STRING_AGG is very welcome but there are some gotchas to be aware of.  Below is a simple example that works just like you think it would.


SELECT STRING_AGG(FIrst_Name, ', ') WITHIN GROUP (ORDER BY First_Name) LIST
FROM 
           (SELECT DISTINCT   First_name FROM [dbo].[Employee]
    WHERE First_Name like 'A%' OR First_Name like 'B%') A
ORDER BY LIST;

You can run the query on any database you have string values and you will get something like this:

A David, Aaren, Aaron, Abdul, Bob, Brian...

If you want to split by the first letter of the name, do not make the mistake of using an over clause.  You will get an error stating STRING_AGG is not a window function.

The function 'STRING_AGG' is not a valid windowing function, and cannot be used with the OVER clause.

Instead, use the GROUP BY on the SUBSTRING function like so:

SELECT STRING_AGG( cast( FIrst_Name as varchar(max)), ', ') WITHIN GROUP (ORDER BY First_Name) LIST
FROM 
           (SELECT DISTINCT   First_name FROM [dbo].[Employee]
    WHERE First_Name like 'A%' OR First_Name like 'B%') A
GROUP BY SUBSTRING(First_Name, 1, 1)
ORDER BY LIST;


Notice in both cases I have limited the query to only names beginning with A or B.  The reason why is because the STRING_AGG function limits the size of the return value to the max size of the data type being aggregated.  So the following query:

SELECT STRING_AGG(FIrst_Name, ', ') WITHIN GROUP (ORDER BY First_Name) LIST
FROM   [dbo].[EmployeeTest]
GROUP BY SUBSTRING(First_Name, 1, 1)
ORDER BY LIST;

Results in this error:

STRING_AGG aggregation result exceeded the limit of 8000 bytes. Use LOB types to avoid result truncation.

A simple change and you will get the results you expect:

SELECT STRING_AGG(cast(FIrst_Name as varchar(max)), ', ') WITHIN GROUP (ORDER BY First_Name) LIST
FROM   [dbo].[EmployeeTest]   
GROUP BY SUBSTRING(First_Name, 1, 1)
ORDER BY LIST;

Finally, if you are using the 2017 version of SQL Server Mangement Studio to access an older database, the function is recognized by Intellisense.  However, if you try to use it, you will get the following error:

'STRING_AGG' is not a recognized built-in function name.

Popular posts from this blog

Power BI Report Server: "An Error Has Occurred" or Power BI Report Server: "My Power BI Report is Coming up Blank" or Power BI Report Server: "401 and 403” Errors From Nowhere

Dynamic Label Positions With SSRS