STRING_AGG (Transact-SQL)

 

Updated: December 21, 2016

THIS TOPIC APPLIES TO:yesSQL Server (starting with vNext)noAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Concatenates the values of string expressions and places separator values between them. The separator is not added at the end of string.

Topic link icon Transact-SQL Syntax Conventions

STRING_AGG ( expression, separator [ <order_clause> ] )

<order_clause> ::=   
    WITHIN GROUP ( ORDER BY <order_by_expression_list> [ ASC | DESC ] )   

separator
Is an expression of NVARCHAR or VARCHAR type that is used as separator for concatenated strings. It can be literal or variable.

expression
Is an expression of any type. Expressions are converted to NVARCHAR or VARCHAR types during concatenation. Non-string types are converted to NVARCHAR type.

<order_clause>
Optionally specify order of concatenated results using WITHIN GROUP clause:

WITHIN GROUP ( ORDER BY <order_by_expression_list> [ ASC | DESC ] )

<order_by_expression_list>
Applies to: SQL Server vNext CTP 1.1.
A list of non-constant expressions that can be used for sorting results. Only one order_by_expression is allowed per query. The default sort order is ascending.

Return type is depends on first argument (expression). If input argument is string type (NVARCHAR, VARCHAR), result type will be same as input type. The following table lists automatic conversions:

Input expression typeResult
NVARCHAR(MAX)NVARCHAR(MAX)
VARCHAR(MAX)VARCHAR(MAX)
NVARCHAR(1…4000)NVARCHAR(4000)
VARCHAR(1…8000)VARCHAR(8000)
int, bigint, smallint, tinyint, numeric, float, real, bit, decimal, smallmoney, money, datetime, datetime2,NVARCHAR(4000)

STRING_AGG aggregate takes all expressions from rows and concatenates them into a single string. Expression values are implicitly converted to string types and then concatenated. The implicit conversion to strings follows the existing rules for data type conversions. For more information about data type conversions, see CAST and CONVERT (Transact-SQL).

If the input expression is type VARCHAR, the separator cannot be type NVARCHAR.

Null values are ignored and the corresponding separator is not added. To return a place holder for null values, use the ISNULL function as demonstrated in example B.

STRING_AGG is available in any compatibility level.

A. Generate list of names separated in new lines

The following example produces a list of names in a single result cell, separated with carriage returns.

SELECT STRING_AGG (FirstName, CHAR(13)) AS csv 
FROM Person.Person; 

Here is the result set.

csv
Syed
Catherine
Kim
Kim
Kim
Hazem
...

NULL values found in name cells are not returned in result.

System_CAPS_ICON_note.jpg Note


If using the Management Studio Query Editor, the Results to Grid option cannot implement the carriage return. Switch to Results to Text to see the result set properly.

B. Generate list of names separated with comma without NULL values

The following example replaces null values with 'N/A' and returns the names separated by commas in a single result cell.

SELECT STRING_AGG ( ISNULL(FirstName,'N/A'), ',') AS csv 
FROM Person.Person; 

Here is the result set.

Csv
John,N/A,Mike,Peter,N/A,N/A,Alice,Bob

C. Generate comma-separated values

SELECT 
STRING_AGG(CONCAT(FirstName, ' ', LastName, ' (', ModifiedDate, ')'), CHAR(13)) 
  AS names 
FROM Person.Person; 

Here is the result set.

names
Ken Sánchez (Feb 8 2003 12:00AM)
Terri Duffy (Feb 24 2002 12:00AM)
Roberto Tamburello (Dec 5 2001 12:00AM)
Rob Walters (Dec 29 2001 12:00AM)
...
System_CAPS_ICON_note.jpg Note


If using the Management Studio Query Editor, the Results to Grid option cannot implement the carriage return. Switch to Results to Text to see the result set properly.

D. Return news articles with related tags

Article and their tags are separated into different tables. Developer wants to return one row per each article with all associated tags. Using following query:

SELECT a.articleId, title, STRING_AGG (tag, ',') as tags 
FROM dbo.Article AS a       
LEFT JOIN dbo.ArticleTag AS t 
    ON a.ArticleId = t.ArticleId 
GROUP BY a.articleId, title;

Here is the result set.

articleIdtitletags
172Polls indicate close election resultspolitics,polls,city council
176New highway expected to reduce congestionNULL
177Dogs continue to be more popular than catspolls,animals

E. Generate list of emails per towns

The following query finds the email addresses of employees and groups them by towns:

SELECT town, STRING_AGG (email, ';') AS emails 
FROM dbo.Employee 
GROUP BY town; 

Here is the result set.

townemails
Seattlesyed0@adventure-works.com;catherine0@adventure-works.com;kim2@adventure-works.com
LAsam1@adventure-works.com;hazem0@adventure-works.com

Emails returned in the emails column can be directly used to send emails to group of people working in some particular towns.

F. Generate a sorted list of emails per towns

Applies to: SQL Server vNext CTP 1.1.
Similar to previous example, the following query finds the email addresses of employees, groups them by town, and sorts the emails alphabetically:

SELECT town, 
    STRING_AGG (email, ';') WITHIN GROUP (ORDER BY email ASC) AS emails 
FROM dbo.Employee 
GROUP BY town; 

Here is the result set.

townemails
Seattlecatherine0@adventure-works.com;kim2@adventure-works.com;syed0@adventure-works.com
LAhazem0@adventure-works.com;sam1@adventure-works.com

String Functions (Transact-SQL)

Show: