Add generate_subscripts, a series-generation function which generates an

array's subscripts.

Pavel Stehule, some editorialization by me.
This commit is contained in:
Alvaro Herrera 2008-04-28 14:48:58 +00:00
parent a1d479f518
commit 1fcb977a13
7 changed files with 253 additions and 6 deletions

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/array.sgml,v 1.65 2008/04/27 04:33:27 alvherre Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/array.sgml,v 1.66 2008/04/28 14:48:57 alvherre Exp $ -->
<sect1 id="arrays">
<title>Arrays</title>
@ -542,6 +542,21 @@ SELECT * FROM sal_emp WHERE 10000 = ALL (pay_by_quarter);
</para>
<para>
Alternatively, the <function>generate_subscripts</> function can be used.
For example:
<programlisting>
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;
</programlisting>
This function is described in <xref linkend="functions-srf-subscripts">.
</para>
<tip>
<para>
Arrays are not sets; searching for specific array elements

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.433 2008/04/17 20:56:41 momjian Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.434 2008/04/28 14:48:57 alvherre Exp $ -->
<chapter id="functions">
<title>Functions and Operators</title>
@ -10613,7 +10613,8 @@ AND
<para>
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 <xref linkend="functions-srf-series">.
as detailed in <xref linkend="functions-srf-series"> and
<xref linkend="functions-srf-subscripts">.
</para>
<table id="functions-srf-series">
@ -10691,6 +10692,99 @@ select current_date + s.a as dates from generate_series(0,14,7) as s(a);
(3 rows)
</programlisting>
</para>
<table id="functions-srf-subscripts">
<indexterm>
<primary>generate_subscripts</primary>
</indexterm>
<title>Subscripts Generating Functions</title>
<tgroup cols="3">
<thead>
<row>
<entry>Function</entry>
<entry>Return Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal><function>generate_subscripts</function>(<parameter>array annyarray</parameter>, <parameter>dim int</parameter>)</literal></entry>
<entry><type>setof int</type></entry>
<entry>
Generate a series comprising the given array's subscripts.
</entry>
</row>
<row>
<entry><literal><function>generate_subscripts</function>(<parameter>array annyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</literal></entry>
<entry><type>setof int</type></entry>
<entry>
Generate a series comprising the given array's subscripts. When
<parameter>reverse</parameter> is true, the series is returned in
reverse order.
</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
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:
<programlisting>
-- 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)
</programlisting>
</para>
</sect1>
<sect1 id="functions-info">

View File

@ -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 <ctype.h>
#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);
}

View File

@ -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");

View File

@ -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,

View File

@ -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);

View File

@ -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);