Support RETURN QUERY EXECUTE in plpgsql.
Pavel Stehule
This commit is contained in:
parent
511b798c46
commit
47391591ba
@ -1,4 +1,4 @@
|
|||||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.127 2008/04/06 23:43:29 tgl Exp $ -->
|
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.128 2008/05/03 00:11:36 tgl 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>
|
||||||
@ -1467,6 +1467,7 @@ RETURN <replaceable>expression</replaceable>;
|
|||||||
<synopsis>
|
<synopsis>
|
||||||
RETURN NEXT <replaceable>expression</replaceable>;
|
RETURN NEXT <replaceable>expression</replaceable>;
|
||||||
RETURN QUERY <replaceable>query</replaceable>;
|
RETURN QUERY <replaceable>query</replaceable>;
|
||||||
|
RETURN QUERY EXECUTE <replaceable class="command">command-string</replaceable> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional>;
|
||||||
</synopsis>
|
</synopsis>
|
||||||
|
|
||||||
<para>
|
<para>
|
||||||
@ -1500,6 +1501,14 @@ RETURN QUERY <replaceable>query</replaceable>;
|
|||||||
let control reach the end of the function).
|
let control reach the end of the function).
|
||||||
</para>
|
</para>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
<command>RETURN QUERY</command> has a variant
|
||||||
|
<command>RETURN QUERY EXECUTE</command>, which specifies the
|
||||||
|
query to be executed dynamically. Parameter expressions can
|
||||||
|
be inserted into the computed query string via <literal>USING</>,
|
||||||
|
in just the same way as in the <command>EXECUTE</> command.
|
||||||
|
</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
|
||||||
@ -1544,7 +1553,6 @@ SELECT * FROM getallfoo();
|
|||||||
Note that functions using <command>RETURN NEXT</command> or
|
Note that functions using <command>RETURN NEXT</command> or
|
||||||
<command>RETURN QUERY</command> must be called as a table source in
|
<command>RETURN QUERY</command> must be called as a table source in
|
||||||
a <literal>FROM</literal> clause.
|
a <literal>FROM</literal> clause.
|
||||||
|
|
||||||
</para>
|
</para>
|
||||||
|
|
||||||
<note>
|
<note>
|
||||||
|
@ -9,7 +9,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.110 2008/04/06 23:43:29 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.111 2008/05/03 00:11:36 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -2239,6 +2239,7 @@ static PLpgSQL_stmt *
|
|||||||
make_return_query_stmt(int lineno)
|
make_return_query_stmt(int lineno)
|
||||||
{
|
{
|
||||||
PLpgSQL_stmt_return_query *new;
|
PLpgSQL_stmt_return_query *new;
|
||||||
|
int tok;
|
||||||
|
|
||||||
if (!plpgsql_curr_compile->fn_retset)
|
if (!plpgsql_curr_compile->fn_retset)
|
||||||
yyerror("cannot use RETURN QUERY in a non-SETOF function");
|
yyerror("cannot use RETURN QUERY in a non-SETOF function");
|
||||||
@ -2246,7 +2247,32 @@ make_return_query_stmt(int lineno)
|
|||||||
new = palloc0(sizeof(PLpgSQL_stmt_return_query));
|
new = palloc0(sizeof(PLpgSQL_stmt_return_query));
|
||||||
new->cmd_type = PLPGSQL_STMT_RETURN_QUERY;
|
new->cmd_type = PLPGSQL_STMT_RETURN_QUERY;
|
||||||
new->lineno = lineno;
|
new->lineno = lineno;
|
||||||
new->query = read_sql_stmt("");
|
|
||||||
|
/* check for RETURN QUERY EXECUTE */
|
||||||
|
if ((tok = yylex()) != K_EXECUTE)
|
||||||
|
{
|
||||||
|
/* ordinary static query */
|
||||||
|
plpgsql_push_back_token(tok);
|
||||||
|
new->query = read_sql_stmt("");
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
/* dynamic SQL */
|
||||||
|
int term;
|
||||||
|
|
||||||
|
new->dynquery = read_sql_expression2(';', K_USING, "; or USING",
|
||||||
|
&term);
|
||||||
|
if (term == K_USING)
|
||||||
|
{
|
||||||
|
do
|
||||||
|
{
|
||||||
|
PLpgSQL_expr *expr;
|
||||||
|
|
||||||
|
expr = read_sql_expression2(',', ';', ", or ;", &term);
|
||||||
|
new->params = lappend(new->params, expr);
|
||||||
|
} while (term == ',');
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
return (PLpgSQL_stmt *) new;
|
return (PLpgSQL_stmt *) new;
|
||||||
}
|
}
|
||||||
|
@ -8,7 +8,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.210 2008/04/17 21:37:28 alvherre Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.211 2008/05/03 00:11:36 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -197,6 +197,8 @@ static void assign_text_var(PLpgSQL_var *var, const char *str);
|
|||||||
static PreparedParamsData *exec_eval_using_params(PLpgSQL_execstate *estate,
|
static PreparedParamsData *exec_eval_using_params(PLpgSQL_execstate *estate,
|
||||||
List *params);
|
List *params);
|
||||||
static void free_params_data(PreparedParamsData *ppd);
|
static void free_params_data(PreparedParamsData *ppd);
|
||||||
|
static Portal exec_dynquery_with_params(PLpgSQL_execstate *estate,
|
||||||
|
PLpgSQL_expr *query, List *params);
|
||||||
|
|
||||||
|
|
||||||
/* ----------
|
/* ----------
|
||||||
@ -1968,7 +1970,7 @@ exec_stmt_return(PLpgSQL_execstate *estate, PLpgSQL_stmt_return *stmt)
|
|||||||
PLpgSQL_row *row = (PLpgSQL_row *) retvar;
|
PLpgSQL_row *row = (PLpgSQL_row *) retvar;
|
||||||
|
|
||||||
Assert(row->rowtupdesc);
|
Assert(row->rowtupdesc);
|
||||||
estate->retval =
|
estate->retval =
|
||||||
PointerGetDatum(make_tuple_from_row(estate, row,
|
PointerGetDatum(make_tuple_from_row(estate, row,
|
||||||
row->rowtupdesc));
|
row->rowtupdesc));
|
||||||
if (DatumGetPointer(estate->retval) == NULL) /* should not happen */
|
if (DatumGetPointer(estate->retval) == NULL) /* should not happen */
|
||||||
@ -2189,7 +2191,18 @@ exec_stmt_return_query(PLpgSQL_execstate *estate,
|
|||||||
if (estate->tuple_store == NULL)
|
if (estate->tuple_store == NULL)
|
||||||
exec_init_tuple_store(estate);
|
exec_init_tuple_store(estate);
|
||||||
|
|
||||||
exec_run_select(estate, stmt->query, 0, &portal);
|
if (stmt->query != NULL)
|
||||||
|
{
|
||||||
|
/* static query */
|
||||||
|
exec_run_select(estate, stmt->query, 0, &portal);
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
/* RETURN QUERY EXECUTE */
|
||||||
|
Assert(stmt->dynquery != NULL);
|
||||||
|
portal = exec_dynquery_with_params(estate, stmt->dynquery,
|
||||||
|
stmt->params);
|
||||||
|
}
|
||||||
|
|
||||||
if (!compatible_tupdesc(estate->rettupdesc, portal->tupDesc))
|
if (!compatible_tupdesc(estate->rettupdesc, portal->tupDesc))
|
||||||
ereport(ERROR,
|
ereport(ERROR,
|
||||||
@ -2841,58 +2854,10 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate,
|
|||||||
static int
|
static int
|
||||||
exec_stmt_dynfors(PLpgSQL_execstate *estate, PLpgSQL_stmt_dynfors *stmt)
|
exec_stmt_dynfors(PLpgSQL_execstate *estate, PLpgSQL_stmt_dynfors *stmt)
|
||||||
{
|
{
|
||||||
Datum query;
|
|
||||||
bool isnull;
|
|
||||||
Oid restype;
|
|
||||||
char *querystr;
|
|
||||||
Portal portal;
|
Portal portal;
|
||||||
int rc;
|
int rc;
|
||||||
|
|
||||||
/*
|
portal = exec_dynquery_with_params(estate, stmt->query, stmt->params);
|
||||||
* Evaluate the string expression after the EXECUTE keyword. It's result
|
|
||||||
* is the querystring we have to execute.
|
|
||||||
*/
|
|
||||||
query = exec_eval_expr(estate, stmt->query, &isnull, &restype);
|
|
||||||
if (isnull)
|
|
||||||
ereport(ERROR,
|
|
||||||
(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
|
|
||||||
errmsg("cannot EXECUTE a null querystring")));
|
|
||||||
|
|
||||||
/* Get the C-String representation */
|
|
||||||
querystr = convert_value_to_string(query, restype);
|
|
||||||
|
|
||||||
exec_eval_cleanup(estate);
|
|
||||||
|
|
||||||
/*
|
|
||||||
* Open an implicit cursor for the query. We use SPI_cursor_open_with_args
|
|
||||||
* even when there are no params, because this avoids making and freeing
|
|
||||||
* one copy of the plan.
|
|
||||||
*/
|
|
||||||
if (stmt->params)
|
|
||||||
{
|
|
||||||
PreparedParamsData *ppd;
|
|
||||||
|
|
||||||
ppd = exec_eval_using_params(estate, stmt->params);
|
|
||||||
portal = SPI_cursor_open_with_args(NULL,
|
|
||||||
querystr,
|
|
||||||
ppd->nargs, ppd->types,
|
|
||||||
ppd->values, ppd->nulls,
|
|
||||||
estate->readonly_func, 0);
|
|
||||||
free_params_data(ppd);
|
|
||||||
}
|
|
||||||
else
|
|
||||||
{
|
|
||||||
portal = SPI_cursor_open_with_args(NULL,
|
|
||||||
querystr,
|
|
||||||
0, NULL,
|
|
||||||
NULL, NULL,
|
|
||||||
estate->readonly_func, 0);
|
|
||||||
}
|
|
||||||
|
|
||||||
if (portal == NULL)
|
|
||||||
elog(ERROR, "could not open implicit cursor for query \"%s\": %s",
|
|
||||||
querystr, SPI_result_code_string(SPI_result));
|
|
||||||
pfree(querystr);
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* Execute the loop
|
* Execute the loop
|
||||||
@ -5208,3 +5173,65 @@ free_params_data(PreparedParamsData *ppd)
|
|||||||
|
|
||||||
pfree(ppd);
|
pfree(ppd);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Open portal for dynamic query
|
||||||
|
*/
|
||||||
|
static Portal
|
||||||
|
exec_dynquery_with_params(PLpgSQL_execstate *estate, PLpgSQL_expr *dynquery,
|
||||||
|
List *params)
|
||||||
|
{
|
||||||
|
Portal portal;
|
||||||
|
Datum query;
|
||||||
|
bool isnull;
|
||||||
|
Oid restype;
|
||||||
|
char *querystr;
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Evaluate the string expression after the EXECUTE keyword. Its result
|
||||||
|
* is the querystring we have to execute.
|
||||||
|
*/
|
||||||
|
query = exec_eval_expr(estate, dynquery, &isnull, &restype);
|
||||||
|
if (isnull)
|
||||||
|
ereport(ERROR,
|
||||||
|
(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
|
||||||
|
errmsg("cannot EXECUTE a null querystring")));
|
||||||
|
|
||||||
|
/* Get the C-String representation */
|
||||||
|
querystr = convert_value_to_string(query, restype);
|
||||||
|
|
||||||
|
exec_eval_cleanup(estate);
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Open an implicit cursor for the query. We use SPI_cursor_open_with_args
|
||||||
|
* even when there are no params, because this avoids making and freeing
|
||||||
|
* one copy of the plan.
|
||||||
|
*/
|
||||||
|
if (params)
|
||||||
|
{
|
||||||
|
PreparedParamsData *ppd;
|
||||||
|
|
||||||
|
ppd = exec_eval_using_params(estate, params);
|
||||||
|
portal = SPI_cursor_open_with_args(NULL,
|
||||||
|
querystr,
|
||||||
|
ppd->nargs, ppd->types,
|
||||||
|
ppd->values, ppd->nulls,
|
||||||
|
estate->readonly_func, 0);
|
||||||
|
free_params_data(ppd);
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
portal = SPI_cursor_open_with_args(NULL,
|
||||||
|
querystr,
|
||||||
|
0, NULL,
|
||||||
|
NULL, NULL,
|
||||||
|
estate->readonly_func, 0);
|
||||||
|
}
|
||||||
|
|
||||||
|
if (portal == NULL)
|
||||||
|
elog(ERROR, "could not open implicit cursor for query \"%s\": %s",
|
||||||
|
querystr, SPI_result_code_string(SPI_result));
|
||||||
|
pfree(querystr);
|
||||||
|
|
||||||
|
return portal;
|
||||||
|
}
|
||||||
|
@ -8,7 +8,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.69 2008/04/06 23:43:29 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.70 2008/05/03 00:11:36 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -963,9 +963,37 @@ static void
|
|||||||
dump_return_query(PLpgSQL_stmt_return_query *stmt)
|
dump_return_query(PLpgSQL_stmt_return_query *stmt)
|
||||||
{
|
{
|
||||||
dump_ind();
|
dump_ind();
|
||||||
printf("RETURN QUERY ");
|
if (stmt->query)
|
||||||
dump_expr(stmt->query);
|
{
|
||||||
printf("\n");
|
printf("RETURN QUERY ");
|
||||||
|
dump_expr(stmt->query);
|
||||||
|
printf("\n");
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
printf("RETURN QUERY EXECUTE ");
|
||||||
|
dump_expr(stmt->dynquery);
|
||||||
|
printf("\n");
|
||||||
|
if (stmt->params != NIL)
|
||||||
|
{
|
||||||
|
ListCell *lc;
|
||||||
|
int i;
|
||||||
|
|
||||||
|
dump_indent += 2;
|
||||||
|
dump_ind();
|
||||||
|
printf(" USING\n");
|
||||||
|
dump_indent += 2;
|
||||||
|
i = 1;
|
||||||
|
foreach(lc, stmt->params)
|
||||||
|
{
|
||||||
|
dump_ind();
|
||||||
|
printf(" parameter $%d: ", i++);
|
||||||
|
dump_expr((PLpgSQL_expr *) lfirst(lc));
|
||||||
|
printf("\n");
|
||||||
|
}
|
||||||
|
dump_indent -= 4;
|
||||||
|
}
|
||||||
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
static void
|
static void
|
||||||
|
@ -8,7 +8,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.97 2008/04/06 23:43:29 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.98 2008/05/03 00:11:36 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -529,7 +529,9 @@ typedef struct
|
|||||||
{ /* RETURN QUERY statement */
|
{ /* RETURN QUERY statement */
|
||||||
int cmd_type;
|
int cmd_type;
|
||||||
int lineno;
|
int lineno;
|
||||||
PLpgSQL_expr *query;
|
PLpgSQL_expr *query; /* if static query */
|
||||||
|
PLpgSQL_expr *dynquery; /* if dynamic query (RETURN QUERY EXECUTE) */
|
||||||
|
List *params; /* USING arguments for dynamic query */
|
||||||
} PLpgSQL_stmt_return_query;
|
} PLpgSQL_stmt_return_query;
|
||||||
|
|
||||||
typedef struct
|
typedef struct
|
||||||
|
@ -3267,3 +3267,21 @@ end;
|
|||||||
$$ language plpgsql;
|
$$ language plpgsql;
|
||||||
ERROR: cursor FOR loop must use a bound cursor variable
|
ERROR: cursor FOR loop must use a bound cursor variable
|
||||||
CONTEXT: compile of PL/pgSQL function "forc_bad" near line 4
|
CONTEXT: compile of PL/pgSQL function "forc_bad" near line 4
|
||||||
|
-- return query execute
|
||||||
|
create or replace function return_dquery()
|
||||||
|
returns setof int as $$
|
||||||
|
begin
|
||||||
|
return query execute 'select * from (values(10),(20)) f';
|
||||||
|
return query execute 'select * from (values($1),($2)) f' using 40,50;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql;
|
||||||
|
select * from return_dquery();
|
||||||
|
return_dquery
|
||||||
|
---------------
|
||||||
|
10
|
||||||
|
20
|
||||||
|
40
|
||||||
|
50
|
||||||
|
(4 rows)
|
||||||
|
|
||||||
|
drop function return_dquery();
|
||||||
|
@ -2669,3 +2669,17 @@ begin
|
|||||||
end loop;
|
end loop;
|
||||||
end;
|
end;
|
||||||
$$ language plpgsql;
|
$$ language plpgsql;
|
||||||
|
|
||||||
|
-- return query execute
|
||||||
|
|
||||||
|
create or replace function return_dquery()
|
||||||
|
returns setof int as $$
|
||||||
|
begin
|
||||||
|
return query execute 'select * from (values(10),(20)) f';
|
||||||
|
return query execute 'select * from (values($1),($2)) f' using 40,50;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql;
|
||||||
|
|
||||||
|
select * from return_dquery();
|
||||||
|
|
||||||
|
drop function return_dquery();
|
||||||
|
Loading…
x
Reference in New Issue
Block a user