PostgreSQL 8.4.22 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 9. Functions and Operators | Fast Forward | Next |
This section describes functions that possibly return more than one row. Currently the only functions in this class are series generating functions, as detailed in Table 9-45 and Table 9-46.
Table 9-45. Series Generating Functions
Function | Argument Type | Return Type | Description |
---|---|---|---|
generate_series (start, stop) |
int or bigint | setof int or setof bigint (same as argument type) | Generate a series of values, from start to stop with a step size of one |
generate_series (start, stop,
step) |
int or bigint | setof int or setof bigint (same as argument type) | Generate a series of values, from start to stop with a step size of step |
generate_series (start, stop,
step interval) |
timestamp or timestamp with time zone | setof timestamp or setof timestamp with time zone (same as argument type) | Generate a series of values, from start to stop with a step size of step |
When step is positive, zero rows are returned if start is greater than stop. Conversely, when step is negative, zero rows are returned if start is less than stop. Zero rows are also returned for NULL inputs. It is an error for step to be zero. Some examples follow:
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) -- 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)
Table 9-46. Subscript Generating Functions
Function | Return Type | Description |
---|---|---|
generate_subscripts (array anyarray, dim int) |
setof int | Generate a series comprising the given array's subscripts. |
generate_subscripts (array anyarray, dim int, reverse
boolean) |
setof int | Generate a series comprising the given array's subscripts. When reverse is true, the series is returned in reverse order. |
generate_subscripts
is a
convenience function that generates the set of valid subscripts
for the specified dimension of the given array. Zero rows are
returned for arrays that do not have the requested dimension, or
for NULL arrays (but valid subscripts are returned for NULL array
elements). Some examples follow:
-- 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} (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} | 1 | 100 {100,200} | 2 | 200 (4 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 postgres=# select * from unnest2(array[[1,2],[3,4]]); unnest2 --------- 1 2 3 4 (4 rows)