Commit b2b9b4d5 authored by Neil Conway's avatar Neil Conway

Implement RETURN QUERY for PL/PgSQL. This provides some convenient syntax

sugar for PL/PgSQL set-returning functions that want to return the result
of evaluating a query; it should also be more efficient than repeated
RETURN NEXT statements. Based on an earlier patch from Pavel Stehule.
parent 507b53c8
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.115 2007/07/16 17:01:10 tgl Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.116 2007/07/25 04:19:08 neilc Exp $ -->
<chapter id="plpgsql"> <chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title> <title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
...@@ -135,7 +135,9 @@ ...@@ -135,7 +135,9 @@
<application>PL/pgSQL</> functions can also be declared to return <application>PL/pgSQL</> functions can also be declared to return
a <quote>set</>, or table, of any data type they can return a single a <quote>set</>, or table, of any data type they can return a single
instance of. Such a function generates its output by executing instance of. Such a function generates its output by executing
<literal>RETURN NEXT</> for each desired element of the result set. <command>RETURN NEXT</> for each desired element of the result
set, or by using <command>RETURN QUERY</> to output the result of
evaluating a query.
</para> </para>
<para> <para>
...@@ -1349,52 +1351,69 @@ RETURN <replaceable>expression</replaceable>; ...@@ -1349,52 +1351,69 @@ RETURN <replaceable>expression</replaceable>;
</sect3> </sect3>
<sect3> <sect3>
<title><command>RETURN NEXT</></title> <title><command>RETURN NEXT</> and <command>RETURN QUERY</command></title>
<indexterm>
<primary>RETURN NEXT</primary>
<secondary>in PL/PgSQL</secondary>
</indexterm>
<indexterm>
<primary>RETURN QUERY</primary>
<secondary>in PL/PgSQL</secondary>
</indexterm>
<synopsis> <synopsis>
RETURN NEXT <replaceable>expression</replaceable>; RETURN NEXT <replaceable>expression</replaceable>;
RETURN QUERY <replaceable>query</replaceable>;
</synopsis> </synopsis>
<para> <para>
When a <application>PL/pgSQL</> function is declared to return When a <application>PL/pgSQL</> function is declared to return
<literal>SETOF <replaceable>sometype</></literal>, the procedure <literal>SETOF <replaceable>sometype</></literal>, the procedure
to follow is slightly different. In that case, the individual to follow is slightly different. In that case, the individual
items to return are specified in <command>RETURN NEXT</command> items to return are specified by a sequence of <command>RETURN
commands, and then a final <command>RETURN</command> command NEXT</command> or <command>RETURN QUERY</command> commands, and
with no argument is used to indicate that the function has then a final <command>RETURN</command> command with no argument
finished executing. <command>RETURN NEXT</command> can be used is used to indicate that the function has finished executing.
with both scalar and composite data types; with a composite result <command>RETURN NEXT</command> can be used with both scalar and
type, an entire <quote>table</quote> of results will be returned. composite data types; with a composite result type, an entire
</para> <quote>table</quote> of results will be returned.
<command>RETURN QUERY</command> appends the results of executing
<para> a query to the function's result set. <command>RETURN
<command>RETURN NEXT</command> does not actually return from the NEXT</command> and <command>RETURN QUERY</command> can be freely
function &mdash; it simply saves away the value of the expression. intermixed in a single set-returning function, in which case
Execution then continues with the next statement in their results will be concatenated.
the <application>PL/pgSQL</> function. As successive </para>
<command>RETURN NEXT</command> commands are executed, the result
set is built up. A final <command>RETURN</command>, which should <para>
have no argument, causes control to exit the function (or you can <command>RETURN NEXT</command> and <command>RETURN
just let control reach the end of the function). QUERY</command> do not actually return from the function &mdash;
they simply append zero or more rows to the function's result
set. Execution then continues with the next statement in the
<application>PL/pgSQL</> function. As successive
<command>RETURN NEXT</command> or <command>RETURN
QUERY</command> commands are executed, the result set is built
up. A final <command>RETURN</command>, which should have no
argument, causes control to exit the function (or you can just
let control reach the end of the function).
</para> </para>
<para> <para>
If you declared the function with output parameters, write just If you declared the function with output parameters, write just
<command>RETURN NEXT</command> with no expression. On each <command>RETURN NEXT</command> with no expression. On each
execution, the current values execution, the current values of the output parameter
of the output parameter variable(s) will be saved for eventual return variable(s) will be saved for eventual return as a row of the
as a row of the result. result. Note that you must declare the function as returning
Note that you must declare the function as returning <literal>SETOF record</literal> when there are multiple output
<literal>SETOF record</literal> when there are parameters, or <literal>SETOF <replaceable>sometype</></literal>
multiple output parameters, or when there is just one output parameter of type
<literal>SETOF <replaceable>sometype</></literal> when there is <replaceable>sometype</>, in order to create a set-returning
just one output parameter of type <replaceable>sometype</>, in function with output parameters.
order to create a set-returning function with output parameters.
</para> </para>
<para> <para>
Functions that use <command>RETURN NEXT</command> should be Functions that use <command>RETURN NEXT</command> or
called in the following fashion: <command>RETURN QUERY</command> should be called in the
following fashion:
<programlisting> <programlisting>
SELECT * FROM some_func(); SELECT * FROM some_func();
...@@ -1407,7 +1426,7 @@ SELECT * FROM some_func(); ...@@ -1407,7 +1426,7 @@ SELECT * FROM some_func();
<note> <note>
<para> <para>
The current implementation of <command>RETURN NEXT</command> The current implementation of <command>RETURN NEXT</command>
for <application>PL/pgSQL</> stores the entire result set and <command>RETURN QUERY</command> stores the entire result set
before returning from the function, as discussed above. That before returning from the function, as discussed above. That
means that if a <application>PL/pgSQL</> function produces a means that if a <application>PL/pgSQL</> function produces a
very large result set, performance might be poor: data will be very large result set, performance might be poor: data will be
......
...@@ -9,7 +9,7 @@ ...@@ -9,7 +9,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.104 2007/07/16 17:01:10 tgl Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.105 2007/07/25 04:19:08 neilc Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -32,6 +32,7 @@ static PLpgSQL_stmt *make_execsql_stmt(const char *sqlstart, int lineno); ...@@ -32,6 +32,7 @@ static PLpgSQL_stmt *make_execsql_stmt(const char *sqlstart, int lineno);
static PLpgSQL_stmt_fetch *read_fetch_direction(void); static PLpgSQL_stmt_fetch *read_fetch_direction(void);
static PLpgSQL_stmt *make_return_stmt(int lineno); static PLpgSQL_stmt *make_return_stmt(int lineno);
static PLpgSQL_stmt *make_return_next_stmt(int lineno); static PLpgSQL_stmt *make_return_next_stmt(int lineno);
static PLpgSQL_stmt *make_return_query_stmt(int lineno);
static void check_assignable(PLpgSQL_datum *datum); static void check_assignable(PLpgSQL_datum *datum);
static void read_into_target(PLpgSQL_rec **rec, PLpgSQL_row **row, static void read_into_target(PLpgSQL_rec **rec, PLpgSQL_row **row,
bool *strict); bool *strict);
...@@ -187,6 +188,7 @@ static void check_labels(const char *start_label, ...@@ -187,6 +188,7 @@ static void check_labels(const char *start_label,
%token K_NULL %token K_NULL
%token K_OPEN %token K_OPEN
%token K_OR %token K_OR
%token K_QUERY
%token K_PERFORM %token K_PERFORM
%token K_ROW_COUNT %token K_ROW_COUNT
%token K_RAISE %token K_RAISE
...@@ -1171,6 +1173,10 @@ stmt_return : K_RETURN lno ...@@ -1171,6 +1173,10 @@ stmt_return : K_RETURN lno
{ {
$$ = make_return_next_stmt($2); $$ = make_return_next_stmt($2);
} }
else if (tok == K_QUERY)
{
$$ = make_return_query_stmt($2);
}
else else
{ {
plpgsql_push_back_token(tok); plpgsql_push_back_token(tok);
...@@ -2104,7 +2110,8 @@ make_return_stmt(int lineno) ...@@ -2104,7 +2110,8 @@ make_return_stmt(int lineno)
if (plpgsql_curr_compile->fn_retset) if (plpgsql_curr_compile->fn_retset)
{ {
if (yylex() != ';') if (yylex() != ';')
yyerror("RETURN cannot have a parameter in function returning set; use RETURN NEXT"); yyerror("RETURN cannot have a parameter in function "
"returning set; use RETURN NEXT or RETURN QUERY");
} }
else if (plpgsql_curr_compile->out_param_varno >= 0) else if (plpgsql_curr_compile->out_param_varno >= 0)
{ {
...@@ -2200,6 +2207,23 @@ make_return_next_stmt(int lineno) ...@@ -2200,6 +2207,23 @@ make_return_next_stmt(int lineno)
} }
static PLpgSQL_stmt *
make_return_query_stmt(int lineno)
{
PLpgSQL_stmt_return_query *new;
if (!plpgsql_curr_compile->fn_retset)
yyerror("cannot use RETURN QUERY in a non-SETOF function");
new = palloc0(sizeof(PLpgSQL_stmt_return_query));
new->cmd_type = PLPGSQL_STMT_RETURN_QUERY;
new->lineno = lineno;
new->query = read_sql_construct(';', 0, ")", "", false, true, NULL);
return (PLpgSQL_stmt *) new;
}
static void static void
check_assignable(PLpgSQL_datum *datum) check_assignable(PLpgSQL_datum *datum)
{ {
......
...@@ -8,7 +8,7 @@ ...@@ -8,7 +8,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.198 2007/07/15 02:15:04 tgl Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.199 2007/07/25 04:19:08 neilc Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -105,6 +105,8 @@ static int exec_stmt_return(PLpgSQL_execstate *estate, ...@@ -105,6 +105,8 @@ static int exec_stmt_return(PLpgSQL_execstate *estate,
PLpgSQL_stmt_return *stmt); PLpgSQL_stmt_return *stmt);
static int exec_stmt_return_next(PLpgSQL_execstate *estate, static int exec_stmt_return_next(PLpgSQL_execstate *estate,
PLpgSQL_stmt_return_next *stmt); PLpgSQL_stmt_return_next *stmt);
static int exec_stmt_return_query(PLpgSQL_execstate *estate,
PLpgSQL_stmt_return_query *stmt);
static int exec_stmt_raise(PLpgSQL_execstate *estate, static int exec_stmt_raise(PLpgSQL_execstate *estate,
PLpgSQL_stmt_raise *stmt); PLpgSQL_stmt_raise *stmt);
static int exec_stmt_execsql(PLpgSQL_execstate *estate, static int exec_stmt_execsql(PLpgSQL_execstate *estate,
...@@ -1244,6 +1246,10 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt) ...@@ -1244,6 +1246,10 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
rc = exec_stmt_return_next(estate, (PLpgSQL_stmt_return_next *) stmt); rc = exec_stmt_return_next(estate, (PLpgSQL_stmt_return_next *) stmt);
break; break;
case PLPGSQL_STMT_RETURN_QUERY:
rc = exec_stmt_return_query(estate, (PLpgSQL_stmt_return_query *) stmt);
break;
case PLPGSQL_STMT_RAISE: case PLPGSQL_STMT_RAISE:
rc = exec_stmt_raise(estate, (PLpgSQL_stmt_raise *) stmt); rc = exec_stmt_raise(estate, (PLpgSQL_stmt_raise *) stmt);
break; break;
...@@ -2137,6 +2143,59 @@ exec_stmt_return_next(PLpgSQL_execstate *estate, ...@@ -2137,6 +2143,59 @@ exec_stmt_return_next(PLpgSQL_execstate *estate,
return PLPGSQL_RC_OK; return PLPGSQL_RC_OK;
} }
/* ----------
* exec_stmt_return_query Evaluate a query and add it to the
* list of tuples returned by the current
* SRF.
* ----------
*/
static int
exec_stmt_return_query(PLpgSQL_execstate *estate,
PLpgSQL_stmt_return_query *stmt)
{
Portal portal;
if (!estate->retisset)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cannot use RETURN QUERY in a non-SETOF function")));
if (estate->tuple_store == NULL)
exec_init_tuple_store(estate);
exec_run_select(estate, stmt->query, 0, &portal);
if (!compatible_tupdesc(estate->rettupdesc, portal->tupDesc))
ereport(ERROR,
(errcode(ERRCODE_DATATYPE_MISMATCH),
errmsg("structure of query does not match function result type")));
while (true)
{
MemoryContext old_cxt;
int i;
SPI_cursor_fetch(portal, true, 50);
if (SPI_processed == 0)
break;
old_cxt = MemoryContextSwitchTo(estate->tuple_store_cxt);
for (i = 0; i < SPI_processed; i++)
{
HeapTuple tuple = SPI_tuptable->vals[i];
tuplestore_puttuple(estate->tuple_store, tuple);
}
MemoryContextSwitchTo(old_cxt);
SPI_freetuptable(SPI_tuptable);
}
SPI_freetuptable(SPI_tuptable);
SPI_cursor_close(portal);
return PLPGSQL_RC_OK;
}
static void static void
exec_init_tuple_store(PLpgSQL_execstate *estate) exec_init_tuple_store(PLpgSQL_execstate *estate)
{ {
......
...@@ -8,7 +8,7 @@ ...@@ -8,7 +8,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.62 2007/07/20 16:23:34 petere Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.63 2007/07/25 04:19:08 neilc Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -443,6 +443,8 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt) ...@@ -443,6 +443,8 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
return "RETURN"; return "RETURN";
case PLPGSQL_STMT_RETURN_NEXT: case PLPGSQL_STMT_RETURN_NEXT:
return "RETURN NEXT"; return "RETURN NEXT";
case PLPGSQL_STMT_RETURN_QUERY:
return "RETURN QUERY";
case PLPGSQL_STMT_RAISE: case PLPGSQL_STMT_RAISE:
return "RAISE"; return "RAISE";
case PLPGSQL_STMT_EXECSQL: case PLPGSQL_STMT_EXECSQL:
...@@ -484,6 +486,7 @@ static void dump_fors(PLpgSQL_stmt_fors *stmt); ...@@ -484,6 +486,7 @@ static void dump_fors(PLpgSQL_stmt_fors *stmt);
static void dump_exit(PLpgSQL_stmt_exit *stmt); static void dump_exit(PLpgSQL_stmt_exit *stmt);
static void dump_return(PLpgSQL_stmt_return *stmt); static void dump_return(PLpgSQL_stmt_return *stmt);
static void dump_return_next(PLpgSQL_stmt_return_next *stmt); static void dump_return_next(PLpgSQL_stmt_return_next *stmt);
static void dump_return_query(PLpgSQL_stmt_return_query *stmt);
static void dump_raise(PLpgSQL_stmt_raise *stmt); static void dump_raise(PLpgSQL_stmt_raise *stmt);
static void dump_execsql(PLpgSQL_stmt_execsql *stmt); static void dump_execsql(PLpgSQL_stmt_execsql *stmt);
static void dump_dynexecute(PLpgSQL_stmt_dynexecute *stmt); static void dump_dynexecute(PLpgSQL_stmt_dynexecute *stmt);
...@@ -542,6 +545,9 @@ dump_stmt(PLpgSQL_stmt *stmt) ...@@ -542,6 +545,9 @@ dump_stmt(PLpgSQL_stmt *stmt)
case PLPGSQL_STMT_RETURN_NEXT: case PLPGSQL_STMT_RETURN_NEXT:
dump_return_next((PLpgSQL_stmt_return_next *) stmt); dump_return_next((PLpgSQL_stmt_return_next *) stmt);
break; break;
case PLPGSQL_STMT_RETURN_QUERY:
dump_return_query((PLpgSQL_stmt_return_query *) stmt);
break;
case PLPGSQL_STMT_RAISE: case PLPGSQL_STMT_RAISE:
dump_raise((PLpgSQL_stmt_raise *) stmt); dump_raise((PLpgSQL_stmt_raise *) stmt);
break; break;
...@@ -878,6 +884,15 @@ dump_return_next(PLpgSQL_stmt_return_next *stmt) ...@@ -878,6 +884,15 @@ dump_return_next(PLpgSQL_stmt_return_next *stmt)
printf("\n"); printf("\n");
} }
static void
dump_return_query(PLpgSQL_stmt_return_query *stmt)
{
dump_ind();
printf("RETURN QUERY ");
dump_expr(stmt->query);
printf("\n");
}
static void static void
dump_raise(PLpgSQL_stmt_raise *stmt) dump_raise(PLpgSQL_stmt_raise *stmt)
{ {
......
...@@ -8,7 +8,7 @@ ...@@ -8,7 +8,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.90 2007/07/16 17:01:11 tgl Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.91 2007/07/25 04:19:09 neilc Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -83,6 +83,7 @@ enum ...@@ -83,6 +83,7 @@ enum
PLPGSQL_STMT_EXIT, PLPGSQL_STMT_EXIT,
PLPGSQL_STMT_RETURN, PLPGSQL_STMT_RETURN,
PLPGSQL_STMT_RETURN_NEXT, PLPGSQL_STMT_RETURN_NEXT,
PLPGSQL_STMT_RETURN_QUERY,
PLPGSQL_STMT_RAISE, PLPGSQL_STMT_RAISE,
PLPGSQL_STMT_EXECSQL, PLPGSQL_STMT_EXECSQL,
PLPGSQL_STMT_DYNEXECUTE, PLPGSQL_STMT_DYNEXECUTE,
...@@ -493,6 +494,13 @@ typedef struct ...@@ -493,6 +494,13 @@ typedef struct
int retvarno; int retvarno;
} PLpgSQL_stmt_return_next; } PLpgSQL_stmt_return_next;
typedef struct
{ /* RETURN QUERY statement */
int cmd_type;
int lineno;
PLpgSQL_expr *query;
} PLpgSQL_stmt_return_query;
typedef struct typedef struct
{ /* RAISE statement */ { /* RAISE statement */
int cmd_type; int cmd_type;
......
...@@ -9,7 +9,7 @@ ...@@ -9,7 +9,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.57 2007/04/29 01:21:09 neilc Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.58 2007/07/25 04:19:09 neilc Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -151,6 +151,7 @@ null { return K_NULL; } ...@@ -151,6 +151,7 @@ null { return K_NULL; }
open { return K_OPEN; } open { return K_OPEN; }
or { return K_OR; } or { return K_OR; }
perform { return K_PERFORM; } perform { return K_PERFORM; }
query { return K_QUERY; }
raise { return K_RAISE; } raise { return K_RAISE; }
rename { return K_RENAME; } rename { return K_RENAME; }
result_oid { return K_RESULT_OID; } result_oid { return K_RESULT_OID; }
......
...@@ -3079,3 +3079,52 @@ NOTICE: innerblock.param1 = 2 ...@@ -3079,3 +3079,52 @@ NOTICE: innerblock.param1 = 2
(1 row) (1 row)
drop function pl_qual_names(int); drop function pl_qual_names(int);
-- tests for RETURN QUERY
create function ret_query1(out int, out int) returns setof record as $$
begin
$1 := -1;
$2 := -2;
return next;
return query select x + 1, x * 10 from generate_series(0, 10) s (x);
return next;
end;
$$ language plpgsql;
select * from ret_query1();
column1 | column2
---------+---------
-1 | -2
1 | 0
2 | 10
3 | 20
4 | 30
5 | 40
6 | 50
7 | 60
8 | 70
9 | 80
10 | 90
11 | 100
-1 | -2
(13 rows)
create type record_type as (x text, y int, z boolean);
create or replace function ret_query2(lim int) returns setof record_type as $$
begin
return query select md5(s.x::text), s.x, s.x > 0
from generate_series(-8, lim) s (x) where s.x % 2 = 0;
end;
$$ language plpgsql;
select * from ret_query2(8);
x | y | z
----------------------------------+----+---
a8d2ec85eaf98407310b72eb73dda247 | -8 | f
596a3d04481816330f07e4f97510c28f | -6 | f
0267aaf632e87a63288a08331f22c7c3 | -4 | f
5d7b9adcbe1c629ec722529dd12e5129 | -2 | f
cfcd208495d565ef66e7dff9f98764da | 0 | f
c81e728d9d4c2f636f067f89cc14862c | 2 | t
a87ff679a2f3e71d9181a67b7542122c | 4 | t
1679091c5a880faf6fb5e6087eb1b2dc | 6 | t
c9f0f895fb98ab9159f51fd0297e236d | 8 | t
(9 rows)
...@@ -2557,3 +2557,27 @@ $$ language plpgsql; ...@@ -2557,3 +2557,27 @@ $$ language plpgsql;
select pl_qual_names(42); select pl_qual_names(42);
drop function pl_qual_names(int); drop function pl_qual_names(int);
-- tests for RETURN QUERY
create function ret_query1(out int, out int) returns setof record as $$
begin
$1 := -1;
$2 := -2;
return next;
return query select x + 1, x * 10 from generate_series(0, 10) s (x);
return next;
end;
$$ language plpgsql;
select * from ret_query1();
create type record_type as (x text, y int, z boolean);
create or replace function ret_query2(lim int) returns setof record_type as $$
begin
return query select md5(s.x::text), s.x, s.x > 0
from generate_series(-8, lim) s (x) where s.x % 2 = 0;
end;
$$ language plpgsql;
select * from ret_query2(8);
\ No newline at end of file
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment