<!--
-$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.69 2005/05/26 04:08:31 momjian Exp $
+$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.70 2005/06/07 02:47:15 neilc Exp $
-->
<chapter id="plpgsql">
<command>EXECUTE</command> statement is provided:
<synopsis>
-EXECUTE <replaceable class="command">command-string</replaceable>;
+EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replaceable>target</replaceable> ];
</synopsis>
where <replaceable>command-string</replaceable> is an expression
- yielding a string (of type
- <type>text</type>) containing the command
- to be executed. This string is fed literally to the SQL engine.
+ yielding a string (of type <type>text</type>) containing the
+ command to be executed and <replaceable>target</replaceable> is a
+ record variable, row variable, or a comma-separated list of
+ simple variables and record/row fields.
</para>
<para>
</para>
<para>
- The results from <command>SELECT</command> commands are discarded
- by <command>EXECUTE</command>, and <command>SELECT INTO</command>
- is not currently supported within <command>EXECUTE</command>.
- So there is no way to extract a result from a dynamically-created
- <command>SELECT</command> using the plain <command>EXECUTE</command>
- command. There are two other ways to do it, however: one is to use the
- <command>FOR-IN-EXECUTE</>
- loop form described in <xref linkend="plpgsql-records-iterating">,
- and the other is to use a cursor with <command>OPEN-FOR-EXECUTE</>, as
- described in <xref linkend="plpgsql-cursor-opening">.
+ The <literal>INTO</literal> clause specifies where the results of
+ a <command>SELECT</command> command should be assigned. If a row
+ or variable list is provided, it must exactly match the structure
+ of the results produced by the <command>SELECT</command> (when a
+ record variable is used, it will configure itself to match the
+ result's structure automatically). If multiple rows are returned,
+ only the first will be assigned to the <literal>INTO</literal>
+ variable. If no rows are returned, NULL is assigned to the
+ <literal>INTO</literal> variable. If no <literal>INTO</literal>
+ clause is specified, the results of a <command>SELECT</command>
+ command are discarded.
+ </para>
+
+ <para>
+ <command>SELECT INTO</command> is not currently supported within
+ <command>EXECUTE</command>.
</para>
<para>
command, which has the form:
<synopsis>
-GET DIAGNOSTICS <replaceable>variable</replaceable> = <replaceable>item</replaceable> <optional> , ... </optional> ;
+GET DIAGNOSTICS <replaceable>variable</replaceable> = <replaceable>item</replaceable> <optional> , ... </optional>;
</synopsis>
This command allows retrieval of system status indicators. Each
Another way is to use the cursor declaration syntax,
which in general is:
<synopsis>
-<replaceable>name</replaceable> CURSOR <optional> ( <replaceable>arguments</replaceable> ) </optional> FOR <replaceable>query</replaceable> ;
+<replaceable>name</replaceable> CURSOR <optional> ( <replaceable>arguments</replaceable> ) </optional> FOR <replaceable>query</replaceable>;
</synopsis>
(<literal>FOR</> may be replaced by <literal>IS</> for
<productname>Oracle</productname> compatibility.)
<title><command>OPEN FOR</command> <replaceable>query</replaceable></title>
<synopsis>
-OPEN <replaceable>unbound_cursor</replaceable> FOR <replaceable>query</replaceable> ;
+OPEN <replaceable>unbound_cursor</replaceable> FOR <replaceable>query</replaceable>;
</synopsis>
<para>
func_body text;
func_cmd text;
BEGIN
- func_body := 'BEGIN' ;
+ func_body := 'BEGIN';
-- Notice how we scan through the results of a query in a FOR loop
-- using the FOR <record> construct.
* procedural language
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.72 2005/05/26 04:08:31 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.73 2005/06/07 02:47:16 neilc Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
}
;
-stmt_dynexecute : K_EXECUTE lno expr_until_semi
+stmt_dynexecute : K_EXECUTE lno
{
PLpgSQL_stmt_dynexecute *new;
+ PLpgSQL_expr *expr;
+ int endtoken;
+
+ expr = read_sql_construct(K_INTO, ';', "INTO|;", "SELECT ",
+ true, true, &endtoken);
new = palloc(sizeof(PLpgSQL_stmt_dynexecute));
new->cmd_type = PLPGSQL_STMT_DYNEXECUTE;
new->lineno = $2;
- new->query = $3;
+ new->query = expr;
+
+ new->rec = NULL;
+ new->row = NULL;
+
+ /*
+ * If we saw "INTO", look for an additional
+ * row or record var.
+ */
+ if (endtoken == K_INTO)
+ {
+ switch (yylex())
+ {
+ case T_ROW:
+ check_assignable((PLpgSQL_datum *) yylval.row);
+ new->row = yylval.row;
+ break;
+
+ case T_RECORD:
+ check_assignable((PLpgSQL_datum *) yylval.row);
+ new->rec = yylval.rec;
+ break;
+
+ case T_SCALAR:
+ new->row = read_into_scalar_list(yytext, yylval.scalar);
+ break;
+
+ default:
+ plpgsql_error_lineno = $2;
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("syntax error at \"%s\"",
+ yytext),
+ errdetail("Expected record or row variable.")));
+ }
+ if (yylex() != ';')
+ yyerror("syntax error");
+ }
$$ = (PLpgSQL_stmt *)new;
}
;
+
stmt_open : K_OPEN lno cursor_varptr
{
PLpgSQL_stmt_open *new;
* procedural language
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.141 2005/05/26 04:08:31 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.142 2005/06/07 02:47:17 neilc Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
Oid restype;
char *querystr;
int exec_res;
+ PLpgSQL_rec *rec = NULL;
+ PLpgSQL_row *row = NULL;
+
+ if (stmt->rec != NULL)
+ rec = (PLpgSQL_rec *) (estate->datums[stmt->rec->recno]);
+ else if (stmt->row != NULL)
+ row = (PLpgSQL_row *) (estate->datums[stmt->row->rowno]);
/*
* First we evaluate the string expression after the EXECUTE keyword.
/*
* Call SPI_execute() without preparing a saved plan. The returncode can
* be any standard OK. Note that while a SELECT is allowed, its
- * results will be discarded.
+ * results will be discarded unless an INTO clause is specified.
*/
exec_res = SPI_execute(querystr, estate->readonly_func, 0);
+
+ /* Assign to INTO variable */
+ if (rec || row)
+ {
+ if (exec_res != SPI_OK_SELECT)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("EXECUTE ... INTO is only for SELECT")));
+ else
+ {
+ if (SPI_processed == 0)
+ exec_move_row(estate, rec, row, NULL, SPI_tuptable->tupdesc);
+ else
+ exec_move_row(estate, rec, row,
+ SPI_tuptable->vals[0], SPI_tuptable->tupdesc);
+ }
+ }
+
switch (exec_res)
{
case SPI_OK_SELECT:
* procedural language
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.60 2005/05/26 04:08:31 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.61 2005/06/07 02:47:18 neilc Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
{ /* Dynamic SQL string to execute */
int cmd_type;
int lineno;
+ PLpgSQL_rec *rec; /* INTO record or row variable */
+ PLpgSQL_row *row;
PLpgSQL_expr *query;
} PLpgSQL_stmt_dynexecute;
CONTEXT: PL/pgSQL function "missing_return_expr"
drop function void_return_expr();
drop function missing_return_expr();
+--
+-- EXECUTE ... INTO test
+--
+create table eifoo (i integer, y integer);
+create type eitype as (i integer, y integer);
+create or replace function execute_into_test(varchar) returns record as $$
+declare
+ _r record;
+ _rt eifoo%rowtype;
+ _v eitype;
+ i int;
+ j int;
+ k int;
+begin
+ execute 'insert into '||$1||' values(10,15)';
+ execute 'select (row).* from (select row(10,1)::eifoo) s' into _r;
+ raise notice '% %', _r.i, _r.y;
+ execute 'select * from '||$1||' limit 1' into _rt;
+ raise notice '% %', _rt.i, _rt.y;
+ execute 'select *, 20 from '||$1||' limit 1' into i, j, k;
+ raise notice '% % %', i, j, k;
+ execute 'select 1,2' into _v;
+ return _v;
+end; $$ language plpgsql;
+select execute_into_test('eifoo');
+NOTICE: 10 1
+NOTICE: 10 15
+NOTICE: 10 15 20
+ execute_into_test
+-------------------
+ (1,2)
+(1 row)
+
+drop table eifoo cascade;
+drop type eitype cascade;
drop function void_return_expr();
drop function missing_return_expr();
+
+--
+-- EXECUTE ... INTO test
+--
+
+create table eifoo (i integer, y integer);
+create type eitype as (i integer, y integer);
+
+create or replace function execute_into_test(varchar) returns record as $$
+declare
+ _r record;
+ _rt eifoo%rowtype;
+ _v eitype;
+ i int;
+ j int;
+ k int;
+begin
+ execute 'insert into '||$1||' values(10,15)';
+ execute 'select (row).* from (select row(10,1)::eifoo) s' into _r;
+ raise notice '% %', _r.i, _r.y;
+ execute 'select * from '||$1||' limit 1' into _rt;
+ raise notice '% %', _rt.i, _rt.y;
+ execute 'select *, 20 from '||$1||' limit 1' into i, j, k;
+ raise notice '% % %', i, j, k;
+ execute 'select 1,2' into _v;
+ return _v;
+end; $$ language plpgsql;
+
+select execute_into_test('eifoo');
+
+drop table eifoo cascade;
+drop type eitype cascade;