Blog Post

Cool Stuff in Snowflake – Part 2: LISTAGG

,

I’m starting a little series on some of the nice features/capabilities in Snowflake (the cloud data warehouse). In each part, I’ll highlight something that I think it’s interesting enough to share. It might be some SQL function that I’d really like to be in SQL Server, it might be something else.

This blog post talks about the LISTAGG function. The goal of the function is to concatenate values from a column into a delimited list. Let’s take a look at an example. I have a simple table with one column and 250 rows, containing a list of the top 250 movies from IMDB. If I want one single row with all the movie titles concatenated, I can issue the following SQL statement:

select LISTAGG(MOVIES,', ') from STAGE.TEST

If you want to group by another column, you can add the WITHIN GROUP clause. For example, return a list of concatenated employee names per department.

Since SQL Server 2017, you have the STRING_AGG function, which has almost the exact same syntax as its Snowflake counterpart. There are two minor differences:

  • Snowflake has an optional DISTINCT
  • SQL Server has a default ascending sorting. If you want another sorting, you can specify one in the WITHIN GROUP clause. In Snowflake, there is no guaranteed sorting unless you specify it (again in the WITHIN GROUP clause).

If you are working on a version of SQL Server before 2017, you’ll appreciate the simplicity of the LISTAGG/STRINGAGG function, since you have to resort to some hacks to get the job done. My favorite article which lists a lot of potential solutions is Concatenating Row Values in Transact-SQL. My favorite method is the “black-box XML” method (I still had to look up the syntax every time). It’s ugly, but quite fast. The STUFF function is used to remove the trailing comma.

SELECT
     e1.DepartmentID
    ,Employees = 
       STUFF(
       (  SELECT EmployeeName + ',' 
          FROM dbo.Employees e2
          WHERE e2.DepartmentID = e1.DepartmentID
          ORDER BY EmployeeName
          FOR XML PATH(''), TYPE).value('.', 'VARCHAR(MAX)')
       ),1,1,'')
FROM dbo.Employees e1
GROUP BY DepartmentID;

Yep, using LISTAGG is much easier. The previous example can be rewritten as:

SELECT
     DepartmentID
    ,LISTAGG(DISTINCT EmployeeName) WITHIN GROUP (ORDER BY EmployeeName) AS Employees
FROM dbo.Employees
GROUP BY DepartmentID;

Other parts in this series:

Original post (opens in new tab)
View comments in original post (opens in new tab)

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating