9.3 9.4 9.5 9.6 10 11 12 13
阿里云PostgreSQL 问题报告 纠错本页面

9.24. 集合返回函数

本节描述那些可能返回多于一行的函数。目前这个类中被使用最广泛的是级数生成函数, 如表 9-55表 9-56所述。其他更特殊的集合返回函数在本手册的其他地方描述。 组合多集合返回函数的方法可见第 7.2.1.4 节

表 9-55. 级数生成函数

函数参数类型返回类型描述
generate_series(start, stop)intbigint或者numericsetof intsetof bigint或者setof numeric (与参数类型相同) 产生一系列值,从startstop,步长为 1
generate_series(start, stop, step)intbigint或者numericsetof intsetof bigint或者setof numeric (与参数类型相同) 产生一系列值,从startstop,步长为step
generate_series(start, stop, step interval)timestamptimestamp with time zonesetof timestampsetof timestamp with time zone(和参数类型相同) 产生一系列值,从startstop,步长为step

step为正时,如果start大于stop则返回零行。相反,当step为负时,如果start小于stop则返回零行。对于NULL输入也会返回零行。step为零是一个错误。下面是一些例子:

SELECT * FROM generate_series(2,4);
 generate_series
-----------------
               2
               3
               4
(3 rows)

SELECT * FROM generate_series(5,1,-2);
 generate_series
-----------------
               5
               3
               1
(3 rows)

SELECT * FROM generate_series(4,3);
 generate_series
-----------------
(0 rows)

SELECT generate_series(1.1, 4, 1.3);
 generate_series 
-----------------
             1.1
             2.4
             3.7
(3 rows)

-- 这个例子依赖于日期+整数操作符
SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
   dates
------------
 2004-02-05
 2004-02-12
 2004-02-19
(3 rows)

SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
                              '2008-03-04 12:00', '10 hours');
   generate_series   
---------------------
 2008-03-01 00:00:00
 2008-03-01 10:00:00
 2008-03-01 20:00:00
 2008-03-02 06:00:00
 2008-03-02 16:00:00
 2008-03-03 02:00:00
 2008-03-03 12:00:00
 2008-03-03 22:00:00
 2008-03-04 08:00:00
(9 rows)

表 9-56. 下标生成函数

函数返回类型描述
generate_subscripts(array anyarray, dim int)setof int 生成一个级数组成给定数组的下标。
generate_subscripts(array anyarray, dim int, reverse boolean)setof int 生成一个级数组成给定数组的下标。当reverse为真,级数以逆序返回。

generate_subscripts是一个快捷函数,它为给定数组的指定维度生成一组合法的下标。对于不具有请求维度的数组返回零行,对于 NULL 数组也返回零行(但是会对 NULL 数组元素返回合法的下标)。下面是一些例子:

-- 基本使用
SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
 s 
---
 1
 2
 3
 4
(4 rows)

-- 表示一个数组,下标和被下标的值需要一个子查询
SELECT * FROM arrays;
         a          
--------------------
 {-1,-2}
 {100,200,300}
(2 rows)

SELECT a AS array, s AS subscript, a[s] AS value
FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
     array     | subscript | value
---------------+-----------+-------
 {-1,-2}       |         1 |    -1
 {-1,-2}       |         2 |    -2
 {100,200,300} |         1 |   100
 {100,200,300} |         2 |   200
 {100,200,300} |         3 |   300
(5 rows)

-- 平面化一个 2D 数组
CREATE OR REPLACE FUNCTION unnest2(anyarray)
RETURNS SETOF anyelement AS $$
select $1[i][j]
   from generate_subscripts($1,1) g1(i),
        generate_subscripts($1,2) g2(j);
$$ LANGUAGE sql IMMUTABLE;
CREATE FUNCTION
SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
 unnest2 
---------
       1
       2
       3
       4
(4 rows)

When a function in the FROM clause is suffixed by WITH ORDINALITY, a bigint column is appended to the output which starts from 1 and increments by 1 for each row of the function's output. This is most useful in the case of set returning functions such as unnest().

-- set returning function WITH ORDINALITY
SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
       ls        | n
-----------------+----
 pg_serial       |  1
 pg_twophase     |  2
 postmaster.opts |  3
 pg_notify       |  4
 postgresql.conf |  5
 pg_tblspc       |  6
 logfile         |  7
 base            |  8
 postmaster.pid  |  9
 pg_ident.conf   | 10
 global          | 11
 pg_clog         | 12
 pg_snapshots    | 13
 pg_multixact    | 14
 PG_VERSION      | 15
 pg_xlog         | 16
 pg_hba.conf     | 17
 pg_stat_tmp     | 18
 pg_subtrans     | 19
(19 rows)

<
/BODY >