plpgsql functions can return RECORD, per Neil Conway.
This commit is contained in:
parent
1903221517
commit
470a1048ec
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/plpgsql.sgml,v 1.5 2002/08/30 00:28:40 tgl Exp $
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/plpgsql.sgml,v 1.6 2002/09/01 16:28:05 tgl Exp $
|
||||
-->
|
||||
|
||||
<chapter id="plpgsql">
|
||||
@ -538,8 +538,6 @@ END;
|
||||
|
||||
<para>
|
||||
Note that <literal>RECORD</> is not a true data type, only a placeholder.
|
||||
Thus, for example, one cannot declare a function returning
|
||||
<literal>RECORD</>.
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.59 2002/08/30 00:28:40 tgl Exp $
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.60 2002/09/01 16:28:05 tgl Exp $
|
||||
-->
|
||||
|
||||
<chapter id="xfunc">
|
||||
@ -2119,6 +2119,27 @@ SELECT * FROM vw_getfoo;
|
||||
</programlisting>
|
||||
are all valid statements.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
In some cases it is useful to define table functions that can return
|
||||
different column sets depending on how they are invoked. To support this,
|
||||
the table function can be declared as returning the pseudo-type
|
||||
<type>record</>. When such a function is used in a query, the expected
|
||||
row structure must be specified in the query itself, so that the system
|
||||
can know how to parse and plan the query. Consider this example:
|
||||
<programlisting>
|
||||
SELECT *
|
||||
FROM dblink('dbname=template1', 'select proname, prosrc from pg_proc')
|
||||
AS t1(proname name, prosrc text)
|
||||
WHERE proname LIKE 'bytea%';
|
||||
</programlisting>
|
||||
The <literal>dblink</> function executes a remote query (see
|
||||
<literal>contrib/dblink</>). It is declared to return <type>record</>
|
||||
since it might be used for any kind of query. The actual column set
|
||||
must be specified in the calling query so that the parser knows, for
|
||||
example, what <literal>*</> should expand to.
|
||||
</para>
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="xfunc-plhandler">
|
||||
|
@ -4,7 +4,7 @@
|
||||
* procedural language
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $Header: /cvsroot/pgsql/src/pl/plpgsql/src/gram.y,v 1.36 2002/08/30 00:28:41 tgl Exp $
|
||||
* $Header: /cvsroot/pgsql/src/pl/plpgsql/src/gram.y,v 1.37 2002/09/01 16:28:06 tgl Exp $
|
||||
*
|
||||
* This software is copyrighted by Jan Wieck - Hamburg.
|
||||
*
|
||||
@ -1159,7 +1159,6 @@ stmt_return : K_RETURN lno
|
||||
}
|
||||
;
|
||||
|
||||
/* FIXME: this syntax needs work, RETURN NEXT breaks stmt_return */
|
||||
stmt_return_next: K_RETURN_NEXT lno
|
||||
{
|
||||
PLpgSQL_stmt_return_next *new;
|
||||
|
@ -3,7 +3,7 @@
|
||||
* procedural language
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $Header: /cvsroot/pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.49 2002/08/30 00:28:41 tgl Exp $
|
||||
* $Header: /cvsroot/pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.50 2002/09/01 16:28:06 tgl Exp $
|
||||
*
|
||||
* This software is copyrighted by Jan Wieck - Hamburg.
|
||||
*
|
||||
@ -211,11 +211,11 @@ plpgsql_compile(Oid fn_oid, int functype)
|
||||
procStruct->prorettype);
|
||||
typeStruct = (Form_pg_type) GETSTRUCT(typeTup);
|
||||
|
||||
/* Disallow pseudotype result, except VOID */
|
||||
/* XXX someday allow RECORD? */
|
||||
/* Disallow pseudotype result, except VOID or RECORD */
|
||||
if (typeStruct->typtype == 'p')
|
||||
{
|
||||
if (procStruct->prorettype == VOIDOID)
|
||||
if (procStruct->prorettype == VOIDOID ||
|
||||
procStruct->prorettype == RECORDOID)
|
||||
/* okay */;
|
||||
else if (procStruct->prorettype == TRIGGEROID ||
|
||||
procStruct->prorettype == OPAQUEOID)
|
||||
@ -227,7 +227,8 @@ plpgsql_compile(Oid fn_oid, int functype)
|
||||
format_type_be(procStruct->prorettype));
|
||||
}
|
||||
|
||||
if (typeStruct->typrelid != InvalidOid)
|
||||
if (typeStruct->typrelid != InvalidOid ||
|
||||
procStruct->prorettype == RECORDOID)
|
||||
function->fn_retistuple = true;
|
||||
else
|
||||
{
|
||||
@ -486,8 +487,7 @@ plpgsql_compile(Oid fn_oid, int functype)
|
||||
}
|
||||
|
||||
/*
|
||||
* Create the magic found variable indicating if the last FOR or
|
||||
* SELECT statement returned data
|
||||
* Create the magic FOUND variable.
|
||||
*/
|
||||
var = malloc(sizeof(PLpgSQL_var));
|
||||
memset(var, 0, sizeof(PLpgSQL_var));
|
||||
|
@ -3,7 +3,7 @@
|
||||
* procedural language
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $Header: /cvsroot/pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.61 2002/08/30 23:59:46 tgl Exp $
|
||||
* $Header: /cvsroot/pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.62 2002/09/01 16:28:06 tgl Exp $
|
||||
*
|
||||
* This software is copyrighted by Jan Wieck - Hamburg.
|
||||
*
|
||||
@ -1588,9 +1588,9 @@ static int
|
||||
exec_stmt_return_next(PLpgSQL_execstate *estate,
|
||||
PLpgSQL_stmt_return_next *stmt)
|
||||
{
|
||||
TupleDesc tupdesc;
|
||||
int natts;
|
||||
HeapTuple tuple;
|
||||
TupleDesc tupdesc;
|
||||
int natts;
|
||||
HeapTuple tuple;
|
||||
bool free_tuple = false;
|
||||
|
||||
if (!estate->retisset)
|
||||
|
@ -1680,3 +1680,56 @@ select * from test_ret_set_scalar(1,10);
|
||||
11
|
||||
(10 rows)
|
||||
|
||||
create function test_ret_set_rec_dyn(int) returns setof record as '
|
||||
DECLARE
|
||||
retval RECORD;
|
||||
BEGIN
|
||||
IF $1 > 10 THEN
|
||||
SELECT INTO retval 5, 10, 15;
|
||||
RETURN NEXT retval;
|
||||
RETURN NEXT retval;
|
||||
ELSE
|
||||
SELECT INTO retval 50, 5::numeric, ''xxx''::text;
|
||||
RETURN NEXT retval;
|
||||
RETURN NEXT retval;
|
||||
END IF;
|
||||
RETURN;
|
||||
END;' language 'plpgsql';
|
||||
SELECT * FROM test_ret_set_rec_dyn(1500) AS (a int, b int, c int);
|
||||
a | b | c
|
||||
---+----+----
|
||||
5 | 10 | 15
|
||||
5 | 10 | 15
|
||||
(2 rows)
|
||||
|
||||
SELECT * FROM test_ret_set_rec_dyn(5) AS (a int, b numeric, c text);
|
||||
a | b | c
|
||||
----+---+-----
|
||||
50 | 5 | xxx
|
||||
50 | 5 | xxx
|
||||
(2 rows)
|
||||
|
||||
create function test_ret_rec_dyn(int) returns record as '
|
||||
DECLARE
|
||||
retval RECORD;
|
||||
BEGIN
|
||||
IF $1 > 10 THEN
|
||||
SELECT INTO retval 5, 10, 15;
|
||||
RETURN retval;
|
||||
ELSE
|
||||
SELECT INTO retval 50, 5::numeric, ''xxx''::text;
|
||||
RETURN retval;
|
||||
END IF;
|
||||
END;' language 'plpgsql';
|
||||
SELECT * FROM test_ret_rec_dyn(1500) AS (a int, b int, c int);
|
||||
a | b | c
|
||||
---+----+----
|
||||
5 | 10 | 15
|
||||
(1 row)
|
||||
|
||||
SELECT * FROM test_ret_rec_dyn(5) AS (a int, b numeric, c text);
|
||||
a | b | c
|
||||
----+---+-----
|
||||
50 | 5 | xxx
|
||||
(1 row)
|
||||
|
||||
|
@ -1524,3 +1524,38 @@ BEGIN
|
||||
END;' language 'plpgsql';
|
||||
|
||||
select * from test_ret_set_scalar(1,10);
|
||||
|
||||
create function test_ret_set_rec_dyn(int) returns setof record as '
|
||||
DECLARE
|
||||
retval RECORD;
|
||||
BEGIN
|
||||
IF $1 > 10 THEN
|
||||
SELECT INTO retval 5, 10, 15;
|
||||
RETURN NEXT retval;
|
||||
RETURN NEXT retval;
|
||||
ELSE
|
||||
SELECT INTO retval 50, 5::numeric, ''xxx''::text;
|
||||
RETURN NEXT retval;
|
||||
RETURN NEXT retval;
|
||||
END IF;
|
||||
RETURN;
|
||||
END;' language 'plpgsql';
|
||||
|
||||
SELECT * FROM test_ret_set_rec_dyn(1500) AS (a int, b int, c int);
|
||||
SELECT * FROM test_ret_set_rec_dyn(5) AS (a int, b numeric, c text);
|
||||
|
||||
create function test_ret_rec_dyn(int) returns record as '
|
||||
DECLARE
|
||||
retval RECORD;
|
||||
BEGIN
|
||||
IF $1 > 10 THEN
|
||||
SELECT INTO retval 5, 10, 15;
|
||||
RETURN retval;
|
||||
ELSE
|
||||
SELECT INTO retval 50, 5::numeric, ''xxx''::text;
|
||||
RETURN retval;
|
||||
END IF;
|
||||
END;' language 'plpgsql';
|
||||
|
||||
SELECT * FROM test_ret_rec_dyn(1500) AS (a int, b int, c int);
|
||||
SELECT * FROM test_ret_rec_dyn(5) AS (a int, b numeric, c text);
|
||||
|
Loading…
Reference in New Issue
Block a user