From 1fcb977a13d70f8746ec86488fd9afc0569e7784 Mon Sep 17 00:00:00 2001 From: Alvaro Herrera Date: Mon, 28 Apr 2008 14:48:58 +0000 Subject: [PATCH] Add generate_subscripts, a series-generation function which generates an array's subscripts. Pavel Stehule, some editorialization by me. --- doc/src/sgml/array.sgml | 17 ++++- doc/src/sgml/func.sgml | 98 +++++++++++++++++++++++++++- src/backend/utils/adt/arrayfuncs.c | 86 +++++++++++++++++++++++- src/include/catalog/pg_proc.h | 7 +- src/include/utils/array.h | 4 +- src/test/regress/expected/arrays.out | 30 +++++++++ src/test/regress/sql/arrays.sql | 17 +++++ 7 files changed, 253 insertions(+), 6 deletions(-) diff --git a/doc/src/sgml/array.sgml b/doc/src/sgml/array.sgml index 87df7e556a..b0d6e19abf 100644 --- a/doc/src/sgml/array.sgml +++ b/doc/src/sgml/array.sgml @@ -1,4 +1,4 @@ - + Arrays @@ -542,6 +542,21 @@ SELECT * FROM sal_emp WHERE 10000 = ALL (pay_by_quarter); + + Alternatively, the generate_subscripts function can be used. + For example: + + +SELECT * FROM + (SELECT pay_by_quarter, + generate_subscripts(pay_by_quarter, 1) AS s + FROM sal_emp) AS foo + WHERE pay_by_quarter[s] = 10000; + + + This function is described in . + + Arrays are not sets; searching for specific array elements diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 7e120bc862..d017179867 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -1,4 +1,4 @@ - + Functions and Operators @@ -10613,7 +10613,8 @@ AND 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 . + as detailed in and + . @@ -10691,6 +10692,99 @@ select current_date + s.a as dates from generate_series(0,14,7) as s(a); (3 rows) + +
+ + + generate_subscripts + + + Subscripts Generating Functions + + + + Function + Return Type + Description + + + + + + generate_subscripts(array annyarray, dim int) + setof int + + Generate a series comprising the given array's subscripts. + + + + + generate_subscripts(array annyarray, 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. + + + + + +
+ + + 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) + + +
diff --git a/src/backend/utils/adt/arrayfuncs.c b/src/backend/utils/adt/arrayfuncs.c index b9e9aa8fd7..68676bd28c 100644 --- a/src/backend/utils/adt/arrayfuncs.c +++ b/src/backend/utils/adt/arrayfuncs.c @@ -8,7 +8,7 @@ * * * IDENTIFICATION - * $PostgreSQL: pgsql/src/backend/utils/adt/arrayfuncs.c,v 1.143 2008/04/11 22:52:05 tgl Exp $ + * $PostgreSQL: pgsql/src/backend/utils/adt/arrayfuncs.c,v 1.144 2008/04/28 14:48:57 alvherre Exp $ * *------------------------------------------------------------------------- */ @@ -17,6 +17,7 @@ #include #include "access/tupmacs.h" +#include "funcapi.h" #include "libpq/pqformat.h" #include "parser/parse_coerce.h" #include "utils/array.h" @@ -4231,3 +4232,86 @@ array_smaller(PG_FUNCTION_ARGS) PG_RETURN_ARRAYTYPE_P(result); } + + +typedef struct generate_subscripts_fctx +{ + int4 lower; + int4 upper; + bool reverse; +} generate_subscripts_fctx; + +/* + * generate_subscripts(array anyarray, dim int [, reverse bool]) + * Returns all subscripts of the array for any dimension + */ +Datum +generate_subscripts(PG_FUNCTION_ARGS) +{ + FuncCallContext *funcctx; + MemoryContext oldcontext; + generate_subscripts_fctx *fctx; + + /* stuff done only on the first call of the function */ + if (SRF_IS_FIRSTCALL()) + { + ArrayType *v = PG_GETARG_ARRAYTYPE_P(0); + int reqdim = PG_GETARG_INT32(1); + int *lb, + *dimv; + + /* create a function context for cross-call persistence */ + funcctx = SRF_FIRSTCALL_INIT(); + + /* Sanity check: does it look like an array at all? */ + if (ARR_NDIM(v) <= 0 || ARR_NDIM(v) > MAXDIM) + SRF_RETURN_DONE(funcctx); + + /* Sanity check: was the requested dim valid */ + if (reqdim <= 0 || reqdim > ARR_NDIM(v)) + SRF_RETURN_DONE(funcctx); + + /* + * switch to memory context appropriate for multiple function calls + */ + oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); + fctx = (generate_subscripts_fctx *) palloc(sizeof(generate_subscripts_fctx)); + + lb = ARR_LBOUND(v); + dimv = ARR_DIMS(v); + + fctx->lower = lb[reqdim - 1]; + fctx->upper = dimv[reqdim - 1] + lb[reqdim - 1] - 1; + fctx->reverse = (PG_NARGS() < 3) ? false : PG_GETARG_BOOL(2); + + funcctx->user_fctx = fctx; + + MemoryContextSwitchTo(oldcontext); + } + + funcctx = SRF_PERCALL_SETUP(); + + fctx = funcctx->user_fctx; + + if (fctx->lower <= fctx->upper) + { + if (!fctx->reverse) + SRF_RETURN_NEXT(funcctx, Int32GetDatum(fctx->lower++)); + else + SRF_RETURN_NEXT(funcctx, Int32GetDatum(fctx->upper--)); + } + else + /* done when there are no more elements left */ + SRF_RETURN_DONE(funcctx); +} + +/* + * generate_subscripts_nodir + * Implements the 2-argument version of generate_subscripts + */ +Datum +generate_subscripts_nodir(PG_FUNCTION_ARGS) +{ + /* just call the other one -- it can handle both cases */ + return generate_subscripts(fcinfo); +} diff --git a/src/include/catalog/pg_proc.h b/src/include/catalog/pg_proc.h index 90b5503413..2f0809bca3 100644 --- a/src/include/catalog/pg_proc.h +++ b/src/include/catalog/pg_proc.h @@ -7,7 +7,7 @@ * Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group * Portions Copyright (c) 1994, Regents of the University of California * - * $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.492 2008/04/17 20:56:41 momjian Exp $ + * $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.493 2008/04/28 14:48:57 alvherre Exp $ * * NOTES * The script catalog/genbki.sh reads this file and generates .bki @@ -1010,6 +1010,11 @@ DATA(insert OID = 515 ( array_larger PGNSP PGUID 12 1 0 f f t f i 2 2277 "22 DESCR("larger of two"); DATA(insert OID = 516 ( array_smaller PGNSP PGUID 12 1 0 f f t f i 2 2277 "2277 2277" _null_ _null_ _null_ array_smaller - _null_ _null_ )); DESCR("smaller of two"); +DATA(insert OID = 1191 ( generate_subscripts PGNSP PGUID 12 1 1000 f f t t v 3 23 "2277 23 16" _null_ _null_ _null_ generate_subscripts - _null_ _null_ )); +DESCR("array subscripts generator"); +DATA(insert OID = 1192 ( generate_subscripts PGNSP PGUID 12 1 1000 f f t t v 2 23 "2277 23" _null_ _null_ _null_ generate_subscripts_nodir - _null_ _null_ )); +DESCR("array subscripts generator"); + DATA(insert OID = 760 ( smgrin PGNSP PGUID 12 1 0 f f t f s 1 210 "2275" _null_ _null_ _null_ smgrin - _null_ _null_ )); DESCR("I/O"); diff --git a/src/include/utils/array.h b/src/include/utils/array.h index 9f253879f9..f8595d908b 100644 --- a/src/include/utils/array.h +++ b/src/include/utils/array.h @@ -49,7 +49,7 @@ * Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group * Portions Copyright (c) 1994, Regents of the University of California * - * $PostgreSQL: pgsql/src/include/utils/array.h,v 1.66 2008/01/01 19:45:59 momjian Exp $ + * $PostgreSQL: pgsql/src/include/utils/array.h,v 1.67 2008/04/28 14:48:57 alvherre Exp $ * *------------------------------------------------------------------------- */ @@ -200,6 +200,8 @@ extern Datum array_lower(PG_FUNCTION_ARGS); extern Datum array_upper(PG_FUNCTION_ARGS); extern Datum array_larger(PG_FUNCTION_ARGS); extern Datum array_smaller(PG_FUNCTION_ARGS); +extern Datum generate_subscripts(PG_FUNCTION_ARGS); +extern Datum generate_subscripts_nodir(PG_FUNCTION_ARGS); extern Datum array_ref(ArrayType *array, int nSubscripts, int *indx, int arraytyplen, int elmlen, bool elmbyval, char elmalign, diff --git a/src/test/regress/expected/arrays.out b/src/test/regress/expected/arrays.out index c82cd3919b..9ab372d15a 100644 --- a/src/test/regress/expected/arrays.out +++ b/src/test/regress/expected/arrays.out @@ -903,3 +903,33 @@ select c2[2].f2 from comptable; drop type _comptype; drop table comptable; drop type comptype; +create or replace function unnest1(anyarray) +returns setof anyelement as $$ +select $1[s] from generate_subscripts($1,1) g(s); +$$ language sql immutable; +create or replace function unnest2(anyarray) +returns setof anyelement as $$ +select $1[s1][s2] from generate_subscripts($1,1) g1(s1), + generate_subscripts($1,2) g2(s2); +$$ language sql immutable; +select * from unnest1(array[1,2,3]); + unnest1 +--------- + 1 + 2 + 3 +(3 rows) + +select * from unnest2(array[[1,2,3],[4,5,6]]); + unnest2 +--------- + 1 + 2 + 3 + 4 + 5 + 6 +(6 rows) + +drop function unnest1(anyarray); +drop function unnest2(anyarray); diff --git a/src/test/regress/sql/arrays.sql b/src/test/regress/sql/arrays.sql index 192648a39b..6590cad36c 100644 --- a/src/test/regress/sql/arrays.sql +++ b/src/test/regress/sql/arrays.sql @@ -340,3 +340,20 @@ select c2[2].f2 from comptable; drop type _comptype; drop table comptable; drop type comptype; + +create or replace function unnest1(anyarray) +returns setof anyelement as $$ +select $1[s] from generate_subscripts($1,1) g(s); +$$ language sql immutable; + +create or replace function unnest2(anyarray) +returns setof anyelement as $$ +select $1[s1][s2] from generate_subscripts($1,1) g1(s1), + generate_subscripts($1,2) g2(s2); +$$ language sql immutable; + +select * from unnest1(array[1,2,3]); +select * from unnest2(array[[1,2,3],[4,5,6]]); + +drop function unnest1(anyarray); +drop function unnest2(anyarray);