PostgreSQL listagg within group (order by) 聚合兼容用法 string_agg ( order by) - 行列变换,CSV构造…

1 minute read

背景

listagg — Rows to Delimited Strings

The listagg function transforms values from a group of rows into a list of values that are delimited by a configurable separator. Listagg is typically used to denormalize rows into a string of comma-separated values (CSV) or other comparable formats suitable for human reading.

Listagg does not apply any escaping: it is not generally possible to tell whether an occurrence of the separator in the result is an actual separator, or just part of a value. The safe use of listagg for electronic data interfaces is therefore limited to cases in which an unambiguous separator can be selected, e.g. when aggregating numbers, dates, or strings that are known to not contain the separator.

When implementing electronic data interfaces, arrays and document types (JSON, XML) are advantageous as they offer type safety, or at least proper escaping.

PostgreSQL string_agg

string_agg 代替listagg,实现同样功能。

建表

postgres=# create table tbl1 (gid int, val text, ts timestamp default clock_timestamp());  
CREATE TABLE  

写入测试数据

postgres=# insert into tbl1 values (1,'a'),(1,'b'),(1,null),(2,'test'),(2,'a""b"c'),(3,'fw');  
INSERT 0 6  

数据

postgres=# select * from tbl1;  
 gid |  val   |             ts               
-----+--------+----------------------------  
   1 | a      | 2018-10-29 21:00:24.593859  
   1 | b      | 2018-10-29 21:00:24.593994  
   1 |        | 2018-10-29 21:00:24.593997  
   2 | test   | 2018-10-29 21:00:24.593998  
   2 | a""b"c | 2018-10-29 21:00:24.594  
   3 | fw     | 2018-10-29 21:00:24.594001  
(6 rows)  

逆向聚合,双引号作为quote字符,转义文本内的双引号,空值使用NULL表示。

postgres=# select gid, string_agg(coalesce('"'||replace(val,'"','\"')||'"','NULL'),',' order by ts desc) from tbl1 group by gid;  
 gid |     string_agg       
-----+--------------------  
   1 | NULL,"b","a"  
   2 | "a\"\"b\"c","test"  
   3 | "fw"  
(3 rows)  

正向聚合,双引号作为quote字符,转义文本内的双引号,空值使用NULL表示。

postgres=# select gid, string_agg(coalesce('"'||replace(val,'"','\"')||'"','NULL'),',' order by ts) from tbl1 group by gid;  
 gid |     string_agg       
-----+--------------------  
   1 | "a","b",NULL  
   2 | "test","a\"\"b\"c"  
   3 | "fw"  
(3 rows)  

正向聚合,不使用QUOTE,直接去除NULL值

postgres=# select gid, string_agg(val,',' order by ts) from tbl1 group by gid;  
 gid | string_agg    
-----+-------------  
   1 | a,b  
   2 | test,a""b"c  
   3 | fw  
(3 rows)  

参考

《PostgreSQL 聚合表达式 FILTER , order , within group, over window 用法》

《PostgreSQL aggregate function 3 : Aggregate Functions for Ordered-Set》

https://modern-sql.com/feature/listagg

https://www.postgresql.org/docs/11/static/functions-aggregate.html

https://wiki.postgresql.org/wiki/PostgreSQL_vs_SQL_Standard

Flag Counter

digoal’s 大量PostgreSQL文章入口