本節描述可能回傳多個列的函數。 此類別中最廣泛使用的函數是序列生成函數,如表 9.67和表 9.68中詳述。 其他更專業的集合回傳函數在本手冊的其他地方進行描述。 有關組合多個集合回傳函數的方法,請參閱第 7.2.1.4 節。
表 9.67. 序列生成函數
函數 描述 |
---|
產生從 |
產生從 |
當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) -- this example relies on the date-plus-integer operator: 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) -- this example assumes that TimeZone is set to UTC; note the DST transition: SELECT * FROM generate_series('2001-10-22 00:00 -04:00'::timestamptz, '2001-11-01 00:00 -05:00'::timestamptz, '1 day'::interval, 'America/New_York'); generate_series ------------------------ 2001-10-22 04:00:00+00 2001-10-23 04:00:00+00 2001-10-24 04:00:00+00 2001-10-25 04:00:00+00 2001-10-26 04:00:00+00 2001-10-27 04:00:00+00 2001-10-28 04:00:00+00 2001-10-29 05:00:00+00 2001-10-30 05:00:00+00 2001-10-31 05:00:00+00 2001-11-01 05:00:00+00 (11 rows)
表 9.68. 下標生成函數
generate_subscripts
是一個方便的函數,它產生給定陣列的指定維度的有效下標集合。 對於沒有請求維度的陣列,或任何輸入為NULL
,則回傳零列。 以下是一些範例
-- basic usage: SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s; s --- 1 2 3 4 (4 rows) -- presenting an array, the subscript and the subscripted -- value requires a subquery: 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) -- unnest a 2D array: 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)
當FROM
子句中的函數加上後綴WITH ORDINALITY
時,一個bigint
列會附加到函數的輸出列,該列從 1 開始,並且對於函數的每個輸出列遞增 1。 這在集合回傳函數(例如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_xact | 12 pg_snapshots | 13 pg_multixact | 14 PG_VERSION | 15 pg_wal | 16 pg_hba.conf | 17 pg_stat_tmp | 18 pg_subtrans | 19 (19 rows)
如果您在文件中發現任何不正確、與您使用特定功能的經驗不符或需要進一步澄清的地方,請使用此表格來回報文件問題。