New T-SQL Functions in SQL Server 2017

SQL Server 2017 brings us some new T-SQL functions. They are very simple to use, and can also help us to simplify our T-SQL code. I’ll be talking about them in this article.

String_AGG

This new function solves an old and very interesting problem: How can we concatenate the contents of a column from several records in a single string value, in a particular order?

There are several points where you migh need this. For example, when some people have several e-mail addresses, or several phone numbers, and we would like to print a report with all these emails and phone numbers listed.

This was  difficult to do up to now,  though it was possible to achieve this with some XML tricks.

Let’s try an example. This script below creates a table and insert some records.

drop tableif exists names

create table names
( [name] varchar(50) )

go
 
insert into names values (‘joao’),(‘jose’),(‘maria’),(‘joaquim’)
go

 

This query below uses some tricks with XML to concatenate the names in a single comma-separated string:

select stuff((select ‘,’ + [name] as [text()]
       from names for xml path()),1,1,)
 
string concatenation

The new STRING_AGG function gives us the same result:

select string_agg([name],‘,’)
       from names

The AdventureWorks database has another interesting example where this function can be used. The tables ‘Person.Person’ and ‘Person.EmailAddress’ are related and each people can have several email addresses. It’s an usual need to list the people with their email addresses in a single record.

This query below should achieve this,  but there is a catch:

select lastname,string_agg(emailaddress,‘, ‘) email
       from person.person, person.EmailAddress
       where person.BusinessEntityID=EmailAddress.BusinessEntityID
       group by lastname

 

The result will be the following error:

string size limit

 

The size limit of the string_agg function results depends on the datatype that is passed to it. Usually, the data type will be varchar, as in the example above, and because the datatype of the column is 8000 bytes, the size limit for the aggregated column will be 8000 bytes.

We saw this error message even though we have no  record over 8000 bytes, but the records combined together exceeded 8000 bytes. 

The solution is to change the datatype of the field. We can use the ‘Cast’ function for this:

select lastname,string_agg(cast(emailaddress as varchar(max)),‘, ‘) email
       from person.person, person.EmailAddress
       where person.BusinessEntityID=EmailAddress.BusinessEntityID
       group by lastname

 

Trim

This new function has been requested for a lot of SQL Server DBAs for a long time.

Removing the empty spaces in a string always demanded the use of two functions, like this:

SELECT RTRIM(LTRIM( ‘     test    ‘)) AS Result;

This new function simplifies this task:

SELECT TRIM( ‘     test    ‘) AS Result;

 

Concat_WS

Concat_WS function is similar to the Concat function that exists since SQL Server 2012, with the ‘WS’ as a plus. ‘WS’ in this case means ‘With Separator’, meaning this new function is able to add a separator between each string value it concatenates.

The NULL value behavior with both functions is the same: NULL values are ignored, not even adding the separator.

This isn’t SQL Server’s default behavior in a concatenation. By default, concatenating a NULL value with a string value yields a null value. Despite what a lot of people believe, NULL doesn’t mean an empty value, NULL means an unknown value. That’s why any value concatenated with NULL yields NULL: the result is also unknown.

SQL Server has a session configuration called CONCAT_NULL_YIELDS_NULL, but this configuration is deprecated. You can see more about this here 

Both functions, CONCAT and CONCAT_WS, ignores the default behavior and the CONCAT_NULL_YIELDS_NULL configuration, ignoring NULL values during the concatenation.

This is very useful to simplify the queries when we need to concatenate fields that aren’t always filled, such as address fields, that sometimes have all the fields filled and sometimes haven’t.

The first example below use a comma as a separator, the 2nd uses a carriage-return (char(13)) :

SELECT CONCAT_WS(‘,’,‘1 Microsoft Way’, NULL, NULL, ‘Redmond’, ‘WA’, 98052) AS Address;

select Concat_WS(char(13),addressline1,addressline2,city,PostalCode)
       as [Address],AddressId
       from person.Address

This function can be useful to produce reports, concatenating some fields, however it’s not useful for exporting data, because when we export data we need some kind of separator, such as a semi-colon (“;”) even when a field is NULL, but this function doesn’t add the separator when a field is NULL.

Translate

Translate does the work of several replace functions, simplifying some queries.

The function is called ‘Translate’ because its main objective: transform one kind of information in another by doing a bunch of replaces.

For example: GeoJson and WKT are two different formats for coordinates. In GeoJson a coordinate is represented using the format ‘[137.4, 72.3]’ while in WKT a point is represented using the format ‘(137.4 72.3)’.

We would need several ‘Replace’s to transform GeoJson format in WKT format and the reverse. The ‘Translate’ function can do this easily.

Using ‘Replace’ function the transformation would be like this:

select replace(replace(replace(‘[137.4, 72.3]’,‘[‘,‘(‘),‘,’,‘ ‘),‘]’,‘)’) as Point

Using the ‘Translate’ function the transformations becomes way simpler:

SELECT TRANSLATE(‘[137.4, 72.3]’ , ‘[,]’, ‘( )’) AS Point,
       TRANSLATE(‘(137.4 72.3)’ , ‘( )’, ‘[,]’) AS Coordinates

Instead of several ‘Replaces’, the ‘Translate’ syntax allows us to specify all the characters in the source string we would like to replace and all the new characters.