diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index 24bcf52a4f..70a0c4e6dc 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -1,4 +1,4 @@ - + <application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language @@ -135,7 +135,9 @@ PL/pgSQL functions can also be declared to return a set, or table, of any data type they can return a single instance of. Such a function generates its output by executing - RETURN NEXT for each desired element of the result set. + RETURN NEXT for each desired element of the result + set, or by using RETURN QUERY to output the result of + evaluating a query. @@ -1349,52 +1351,69 @@ RETURN expression; - <command>RETURN NEXT</> + <command>RETURN NEXT</> and <command>RETURN QUERY</command> + + RETURN NEXT + in PL/PgSQL + + + RETURN QUERY + in PL/PgSQL + RETURN NEXT expression; +RETURN QUERY query; When a PL/pgSQL function is declared to return SETOF sometype, the procedure to follow is slightly different. In that case, the individual - items to return are specified in RETURN NEXT - commands, and then a final RETURN command - with no argument is used to indicate that the function has - finished executing. RETURN NEXT can be used - with both scalar and composite data types; with a composite result - type, an entire table of results will be returned. + items to return are specified by a sequence of RETURN + NEXT or RETURN QUERY commands, and + then a final RETURN command with no argument + is used to indicate that the function has finished executing. + RETURN NEXT can be used with both scalar and + composite data types; with a composite result type, an entire + table of results will be returned. + RETURN QUERY appends the results of executing + a query to the function's result set. RETURN + NEXT and RETURN QUERY can be freely + intermixed in a single set-returning function, in which case + their results will be concatenated. - RETURN NEXT does not actually return from the - function — it simply saves away the value of the expression. - Execution then continues with the next statement in - the PL/pgSQL function. As successive - RETURN NEXT commands are executed, the result - set is built up. A final RETURN, which should - have no argument, causes control to exit the function (or you can - just let control reach the end of the function). + RETURN NEXT and RETURN + QUERY do not actually return from the function — + they simply append zero or more rows to the function's result + set. Execution then continues with the next statement in the + PL/pgSQL function. As successive + RETURN NEXT or RETURN + QUERY commands are executed, the result set is built + up. A final RETURN, which should have no + argument, causes control to exit the function (or you can just + let control reach the end of the function). If you declared the function with output parameters, write just RETURN NEXT with no expression. On each - execution, the current values - of the output parameter variable(s) will be saved for eventual return - as a row of the result. - Note that you must declare the function as returning - SETOF record when there are - multiple output parameters, or - SETOF sometype when there is - just one output parameter of type sometype, in - order to create a set-returning function with output parameters. + execution, the current values of the output parameter + variable(s) will be saved for eventual return as a row of the + result. Note that you must declare the function as returning + SETOF record when there are multiple output + parameters, or SETOF sometype + when there is just one output parameter of type + sometype, in order to create a set-returning + function with output parameters. - Functions that use RETURN NEXT should be - called in the following fashion: + Functions that use RETURN NEXT or + RETURN QUERY should be called in the + following fashion: SELECT * FROM some_func(); @@ -1407,7 +1426,7 @@ SELECT * FROM some_func(); The current implementation of RETURN NEXT - for PL/pgSQL stores the entire result set + and RETURN QUERY stores the entire result set before returning from the function, as discussed above. That means that if a PL/pgSQL function produces a very large result set, performance might be poor: data will be diff --git a/src/pl/plpgsql/src/gram.y b/src/pl/plpgsql/src/gram.y index 795d3c4c4b..b0bc0ea304 100644 --- a/src/pl/plpgsql/src/gram.y +++ b/src/pl/plpgsql/src/gram.y @@ -9,7 +9,7 @@ * * * 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); static PLpgSQL_stmt_fetch *read_fetch_direction(void); static PLpgSQL_stmt *make_return_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 read_into_target(PLpgSQL_rec **rec, PLpgSQL_row **row, bool *strict); @@ -187,6 +188,7 @@ static void check_labels(const char *start_label, %token K_NULL %token K_OPEN %token K_OR +%token K_QUERY %token K_PERFORM %token K_ROW_COUNT %token K_RAISE @@ -1171,6 +1173,10 @@ stmt_return : K_RETURN lno { $$ = make_return_next_stmt($2); } + else if (tok == K_QUERY) + { + $$ = make_return_query_stmt($2); + } else { plpgsql_push_back_token(tok); @@ -2104,7 +2110,8 @@ make_return_stmt(int lineno) if (plpgsql_curr_compile->fn_retset) { 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) { @@ -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 check_assignable(PLpgSQL_datum *datum) { diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c index 9527fdc61d..dd415047f3 100644 --- a/src/pl/plpgsql/src/pl_exec.c +++ b/src/pl/plpgsql/src/pl_exec.c @@ -8,7 +8,7 @@ * * * 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, PLpgSQL_stmt_return *stmt); static int exec_stmt_return_next(PLpgSQL_execstate *estate, 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, PLpgSQL_stmt_raise *stmt); static int exec_stmt_execsql(PLpgSQL_execstate *estate, @@ -1244,6 +1246,10 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt) rc = exec_stmt_return_next(estate, (PLpgSQL_stmt_return_next *) stmt); break; + case PLPGSQL_STMT_RETURN_QUERY: + rc = exec_stmt_return_query(estate, (PLpgSQL_stmt_return_query *) stmt); + break; + case PLPGSQL_STMT_RAISE: rc = exec_stmt_raise(estate, (PLpgSQL_stmt_raise *) stmt); break; @@ -2137,6 +2143,59 @@ exec_stmt_return_next(PLpgSQL_execstate *estate, 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 exec_init_tuple_store(PLpgSQL_execstate *estate) { diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c index 894284fc19..55c8d2eeac 100644 --- a/src/pl/plpgsql/src/pl_funcs.c +++ b/src/pl/plpgsql/src/pl_funcs.c @@ -8,7 +8,7 @@ * * * 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) return "RETURN"; case PLPGSQL_STMT_RETURN_NEXT: return "RETURN NEXT"; + case PLPGSQL_STMT_RETURN_QUERY: + return "RETURN QUERY"; case PLPGSQL_STMT_RAISE: return "RAISE"; case PLPGSQL_STMT_EXECSQL: @@ -484,6 +486,7 @@ static void dump_fors(PLpgSQL_stmt_fors *stmt); static void dump_exit(PLpgSQL_stmt_exit *stmt); static void dump_return(PLpgSQL_stmt_return *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_execsql(PLpgSQL_stmt_execsql *stmt); static void dump_dynexecute(PLpgSQL_stmt_dynexecute *stmt); @@ -542,6 +545,9 @@ dump_stmt(PLpgSQL_stmt *stmt) case PLPGSQL_STMT_RETURN_NEXT: dump_return_next((PLpgSQL_stmt_return_next *) stmt); break; + case PLPGSQL_STMT_RETURN_QUERY: + dump_return_query((PLpgSQL_stmt_return_query *) stmt); + break; case PLPGSQL_STMT_RAISE: dump_raise((PLpgSQL_stmt_raise *) stmt); break; @@ -878,6 +884,15 @@ dump_return_next(PLpgSQL_stmt_return_next *stmt) 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 dump_raise(PLpgSQL_stmt_raise *stmt) { diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h index 6ffb8b4195..4a61379fb5 100644 --- a/src/pl/plpgsql/src/plpgsql.h +++ b/src/pl/plpgsql/src/plpgsql.h @@ -8,7 +8,7 @@ * * * 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 PLPGSQL_STMT_EXIT, PLPGSQL_STMT_RETURN, PLPGSQL_STMT_RETURN_NEXT, + PLPGSQL_STMT_RETURN_QUERY, PLPGSQL_STMT_RAISE, PLPGSQL_STMT_EXECSQL, PLPGSQL_STMT_DYNEXECUTE, @@ -493,6 +494,13 @@ typedef struct int retvarno; } PLpgSQL_stmt_return_next; +typedef struct +{ /* RETURN QUERY statement */ + int cmd_type; + int lineno; + PLpgSQL_expr *query; +} PLpgSQL_stmt_return_query; + typedef struct { /* RAISE statement */ int cmd_type; diff --git a/src/pl/plpgsql/src/scan.l b/src/pl/plpgsql/src/scan.l index 0d71dd6436..b322a4045e 100644 --- a/src/pl/plpgsql/src/scan.l +++ b/src/pl/plpgsql/src/scan.l @@ -9,7 +9,7 @@ * * * 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 $ * *------------------------------------------------------------------------- */ @@ -124,8 +124,8 @@ declare { return K_DECLARE; } default { return K_DEFAULT; } diagnostics { return K_DIAGNOSTICS; } else { return K_ELSE; } -elseif { return K_ELSIF; } -elsif { return K_ELSIF; } +elseif { return K_ELSIF; } +elsif { return K_ELSIF; } end { return K_END; } exception { return K_EXCEPTION; } execute { return K_EXECUTE; } @@ -151,6 +151,7 @@ null { return K_NULL; } open { return K_OPEN; } or { return K_OR; } perform { return K_PERFORM; } +query { return K_QUERY; } raise { return K_RAISE; } rename { return K_RENAME; } result_oid { return K_RESULT_OID; } diff --git a/src/test/regress/expected/plpgsql.out b/src/test/regress/expected/plpgsql.out index a8bf045842..78466426f1 100644 --- a/src/test/regress/expected/plpgsql.out +++ b/src/test/regress/expected/plpgsql.out @@ -3079,3 +3079,52 @@ NOTICE: innerblock.param1 = 2 (1 row) 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) + diff --git a/src/test/regress/sql/plpgsql.sql b/src/test/regress/sql/plpgsql.sql index d1c715e8d4..3c7459b2b7 100644 --- a/src/test/regress/sql/plpgsql.sql +++ b/src/test/regress/sql/plpgsql.sql @@ -2557,3 +2557,27 @@ $$ language plpgsql; select pl_qual_names(42); 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