Commit 3d1e01ca authored by Tom Lane's avatar Tom Lane

Support INSERT/UPDATE/DELETE RETURNING in plpgsql, with rowcount checking

as per yesterday's proposal.  Also make things a tad more orthogonal by
adding the recent STRICT addition to EXECUTE INTO.
Jonah Harris and Tom Lane
parent 29fa0513
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.98 2006/08/12 20:05:54 tgl Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.99 2006/08/14 21:14:41 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>
...@@ -228,17 +228,6 @@ $$ LANGUAGE plpgsql; ...@@ -228,17 +228,6 @@ $$ LANGUAGE plpgsql;
<type>void</> if it has no useful return value. <type>void</> if it has no useful return value.
</para> </para>
<note>
<para>
<application>PL/pgSQL</> does not currently have full support for
domain types: it treats a domain the same as the underlying scalar
type. This means that constraints associated with the domain will
not be enforced. This is not an issue for function arguments, but
it is a hazard if you declare a <application>PL/pgSQL</> function
as returning a domain type.
</para>
</note>
<para> <para>
<application>PL/pgSQL</> functions can also be declared with output <application>PL/pgSQL</> functions can also be declared with output
parameters in place of an explicit specification of the return type. parameters in place of an explicit specification of the return type.
...@@ -1024,21 +1013,17 @@ $$ LANGUAGE plpgsql; ...@@ -1024,21 +1013,17 @@ $$ LANGUAGE plpgsql;
types that are explicitly understood by types that are explicitly understood by
<application>PL/pgSQL</application>. <application>PL/pgSQL</application>.
Anything not recognized as one of these statement types is presumed Anything not recognized as one of these statement types is presumed
to be an SQL command and is sent to the main database engine to execute to be an SQL command and is sent to the main database engine to execute,
(after substitution of any <application>PL/pgSQL</application> variables as described in <xref linkend="plpgsql-statements-sql-noresult">
used in the statement). Thus, and <xref linkend="plpgsql-statements-sql-onerow">.
for example, the SQL commands <command>INSERT</>, <command>UPDATE</>, and
<command>DELETE</> may be considered to be statements of
<application>PL/pgSQL</application>, but they are not specifically
listed here.
</para> </para>
<sect2 id="plpgsql-statements-assignment"> <sect2 id="plpgsql-statements-assignment">
<title>Assignment</title> <title>Assignment</title>
<para> <para>
An assignment of a value to a variable or row/record field is An assignment of a value to a <application>PL/pgSQL</application>
written as: variable or row/record field is written as:
<synopsis> <synopsis>
<replaceable>identifier</replaceable> := <replaceable>expression</replaceable>; <replaceable>identifier</replaceable> := <replaceable>expression</replaceable>;
</synopsis> </synopsis>
...@@ -1067,65 +1052,177 @@ tax := subtotal * 0.06; ...@@ -1067,65 +1052,177 @@ tax := subtotal * 0.06;
</para> </para>
</sect2> </sect2>
<sect2 id="plpgsql-select-into"> <sect2 id="plpgsql-statements-sql-noresult">
<title><command>SELECT INTO</command></title> <title>Executing a Query With No Result</title>
<para>
For any SQL query that does not return rows, for example
<command>INSERT</> without a <literal>RETURNING</> clause, you can
execute the query within a <application>PL/pgSQL</application> function
just by writing the query.
</para>
<para>
Any <application>PL/pgSQL</application> variable name appearing
in the query text is replaced by a parameter symbol, and then the
current value of the variable is provided as the parameter value
at runtime. This allows the same textual query to do different
things in different calls of the function.
</para>
<note>
<para>
This two-step process allows
<application>PL/pgSQL</application> to plan the query just once
and re-use the plan on subsequent executions. As an example,
if you write
<programlisting>
DECLARE
key TEXT;
delta INTEGER;
BEGIN
...
UPDATE mytab SET val = val + delta WHERE id = key;
</programlisting>
the query text seen by the main SQL engine will look like
<programlisting>
UPDATE mytab SET val = val + $1 WHERE id = $2;
</programlisting>
Although you don't normally have to think about this, it's helpful
to know it when you need to make sense of syntax-error messages.
</para>
</note>
<caution>
<para>
<application>PL/pgSQL</application> will substitute for any identifier
matching one of the function's declared variables; it is not bright
enough to know whether that's what you meant! Thus, it is a bad idea
to use a variable name that is the same as any table or column name
that you need to reference in queries within the function. Sometimes
you can work around this by using qualified names in the query:
<application>PL/pgSQL</application> will not substitute in a
qualified name <replaceable>foo</>.<replaceable>bar</>, even if
<replaceable>foo</> or <replaceable>bar</> is a declared variable
name.
</para>
</caution>
<para>
Sometimes it is useful to evaluate an expression or <command>SELECT</>
query but discard the result, for example when calling a function
that has side-effects but no useful result value. To do
this in <application>PL/pgSQL</application>, use the
<command>PERFORM</command> statement:
<synopsis>
PERFORM <replaceable>query</replaceable>;
</synopsis>
This executes <replaceable>query</replaceable> and discards the
result. Write the <replaceable>query</replaceable> the same
way you would write an SQL <command>SELECT</> command, but replace the
initial keyword <command>SELECT</> with <command>PERFORM</command>.
<application>PL/pgSQL</application> variables will be
substituted into the query as usual. Also, the special variable
<literal>FOUND</literal> is set to true if the query produced at
least one row, or false if it produced no rows.
</para>
<note>
<para>
One might expect that writing <command>SELECT</command> directly
would accomplish this result, but at
present the only accepted way to do it is
<command>PERFORM</command>. A SQL command that can return rows,
such as <command>SELECT</command>, will be rejected as an error
unless it has an <literal>INTO</> clause as discussed in the
next section.
</para>
</note>
<para>
An example:
<programlisting>
PERFORM create_mv('cs_session_page_requests_mv', my_query);
</programlisting>
</para>
</sect2>
<sect2 id="plpgsql-statements-sql-onerow">
<title>Executing a Query with a Single-Row Result</title>
<indexterm zone="plpgsql-select-into"> <indexterm zone="plpgsql-statements-sql-onerow">
<primary>SELECT INTO</primary> <primary>SELECT INTO</primary>
<secondary>in PL/pgSQL</secondary> <secondary>in PL/pgSQL</secondary>
</indexterm> </indexterm>
<indexterm zone="plpgsql-statements-sql-onerow">
<primary>RETURNING INTO</primary>
<secondary>in PL/pgSQL</secondary>
</indexterm>
<para> <para>
The result of a <command>SELECT</command> command yielding multiple The result of a SQL command yielding a single row (possibly of multiple
columns (but only one row) can be assigned to a record variable, row-type columns) can be assigned to a record variable, row-type variable, or list
variable, or list of scalar variables. This is done by: of scalar variables. This is done by writing the base SQL command and
adding an <literal>INTO</> clause. For example,
<synopsis> <synopsis>
SELECT INTO <optional>STRICT</optional> <replaceable>target</replaceable> <replaceable>select_expressions</replaceable> FROM ...; SELECT <replaceable>select_expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable> FROM ...;
INSERT ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
UPDATE ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
DELETE ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
</synopsis> </synopsis>
where <replaceable>target</replaceable> can be a record variable, a row where <replaceable>target</replaceable> can be a record variable, a row
variable, or a comma-separated list of simple variables and variable, or a comma-separated list of simple variables and
record/row fields. The <replaceable>select_expressions</replaceable> record/row fields.
and the remainder of the command are the same as in regular SQL. <application>PL/pgSQL</application> variables will be
substituted into the rest of the query as usual.
This works for <command>SELECT</>,
<command>INSERT</>/<command>UPDATE</>/<command>DELETE</> with
<literal>RETURNING</>, and utility commands that return rowset
results (such as <command>EXPLAIN</>).
Except for the <literal>INTO</> clause, the SQL command is the same
as it would be written outside <application>PL/pgSQL</application>.
</para> </para>
<tip>
<para> <para>
Note that this is quite different from Note that this interpretation of <command>SELECT</> with <literal>INTO</>
<productname>PostgreSQL</>'s normal interpretation of is quite different from <productname>PostgreSQL</>'s regular
<command>SELECT INTO</command>, where the <literal>INTO</> target <command>SELECT INTO</command> command, wherein the <literal>INTO</>
is a newly created table. If you want to create a table from a target is a newly created table. If you want to create a table from a
<command>SELECT</> result inside a <command>SELECT</> result inside a
<application>PL/pgSQL</application> function, use the syntax <application>PL/pgSQL</application> function, use the syntax
<command>CREATE TABLE ... AS SELECT</command>. <command>CREATE TABLE ... AS SELECT</command>.
</para> </para>
</tip>
<para> <para>
If a row or a variable list is used as target, the selected values If a row or a variable list is used as target, the query's result columns
must exactly match the structure of the target, or a run-time error must exactly match the structure of the target as to number and data
types, or a run-time error
occurs. When a record variable is the target, it automatically occurs. When a record variable is the target, it automatically
configures itself to the row type of the query result columns. configures itself to the row type of the query result columns.
</para> </para>
<para> <para>
Except for the <literal>INTO</> clause, the <command>SELECT</> The <literal>INTO</> clause can appear almost anywhere in the SQL
statement is the same as a normal SQL <command>SELECT</> command command. Customarily it is written either just before or just after
and can use its full power. the list of <replaceable>select_expressions</replaceable> in a
<command>SELECT</> command, or at the end of the command for other
command types. It is recommended that you follow this convention
in case the <application>PL/pgSQL</application> parser becomes
stricter in future versions.
</para> </para>
<para> <para>
The <literal>INTO</> clause can appear almost anywhere in the If <literal>STRICT</literal> is not specified, then
<command>SELECT</command> statement. Customarily it is written
either just after <literal>SELECT</> as shown above, or
just before <literal>FROM</> &mdash; that is, either just before
or just after the list of <replaceable>select_expressions</replaceable>.
</para>
<para>
If <literal>STRICT</literal> is not specified then
<replaceable>target</replaceable> will be set to the first row <replaceable>target</replaceable> will be set to the first row
returned by the query, or if the query returned no rows, returned by the query, or to nulls if the query returned no rows.
null values are assigned. (Note that <quote>the first row</> is not (Note that <quote>the first row</> is not
well-defined unless you've used <literal>ORDER BY</>.) Any result rows well-defined unless you've used <literal>ORDER BY</>.) Any result rows
after the first row are discarded. after the first row are discarded.
You can check the special <literal>FOUND</literal> variable (see You can check the special <literal>FOUND</literal> variable (see
...@@ -1133,21 +1230,21 @@ SELECT INTO <optional>STRICT</optional> <replaceable>target</replaceable> <repla ...@@ -1133,21 +1230,21 @@ SELECT INTO <optional>STRICT</optional> <replaceable>target</replaceable> <repla
determine whether a row was returned: determine whether a row was returned:
<programlisting> <programlisting>
SELECT INTO myrec * FROM emp WHERE empname = myname; SELECT * INTO myrec FROM emp WHERE empname = myname;
IF NOT FOUND THEN IF NOT FOUND THEN
RAISE EXCEPTION 'employee % not found', myname; RAISE EXCEPTION 'employee % not found', myname;
END IF; END IF;
</programlisting> </programlisting>
If the <literal>STRICT</literal> option is specified, the query must If the <literal>STRICT</literal> option is specified, the query must
return exactly one row or a run-time error will be thrown, either return exactly one row or a run-time error will be reported, either
<literal>NO_DATA_FOUND</> (no rows) or <literal>TOO_MANY_ROWS</> <literal>NO_DATA_FOUND</> (no rows) or <literal>TOO_MANY_ROWS</>
(more than one row). You can use an exception block if you wish (more than one row). You can use an exception block if you wish
to catch the error, for example: to catch the error, for example:
<programlisting> <programlisting>
BEGIN; BEGIN;
SELECT INTO STRICT myrec * FROM emp WHERE empname = myname; SELECT * INTO STRICT myrec FROM emp WHERE empname = myname;
EXCEPTION EXCEPTION
WHEN NO_DATA_FOUND THEN WHEN NO_DATA_FOUND THEN
RAISE EXCEPTION 'employee % not found', myname; RAISE EXCEPTION 'employee % not found', myname;
...@@ -1155,58 +1252,31 @@ BEGIN; ...@@ -1155,58 +1252,31 @@ BEGIN;
RAISE EXCEPTION 'employee % not unique', myname; RAISE EXCEPTION 'employee % not unique', myname;
END; END;
</programlisting> </programlisting>
Successful execution of <command>SELECT INTO STRICT</command> Successful execution of a command with <literal>STRICT</>
always sets <literal>FOUND</literal> to true. always sets <literal>FOUND</literal> to true.
</para> </para>
<note>
<para> <para>
<command>SELECT INTO STRICT</command> matches the behavior of For <command>INSERT</>/<command>UPDATE</>/<command>DELETE</> with
Oracle PL/SQL's <command>SELECT INTO</command> statement. <literal>RETURNING</>, <application>PL/pgSQL</application> reports
</para> an error for more than one returned row, even when
</note> <literal>STRICT</literal> is not specified. This is because there
is no option such as <literal>ORDER BY</> with which to determine
</sect2> which affected row would be returned.
<sect2 id="plpgsql-statements-perform">
<title>Executing an Expression or Query With No Result</title>
<para>
Sometimes one wishes to evaluate an expression or query but
discard the result (typically because one is calling a function
that has useful side-effects but no useful result value). To do
this in <application>PL/pgSQL</application>, use the
<command>PERFORM</command> statement:
<synopsis>
PERFORM <replaceable>query</replaceable>;
</synopsis>
This executes <replaceable>query</replaceable> and discards the
result. Write the <replaceable>query</replaceable> the same
way as you would in an SQL <command>SELECT</> command, but replace the
initial keyword <command>SELECT</> with <command>PERFORM</command>.
<application>PL/pgSQL</application> variables will be
substituted into the query as usual. Also, the special variable
<literal>FOUND</literal> is set to true if the query produced at
least one row or false if it produced no rows.
</para> </para>
<note> <note>
<para> <para>
One might expect that <command>SELECT</command> with no The <literal>STRICT</> option matches the behavior of
<literal>INTO</> clause would accomplish this result, but at Oracle PL/SQL's <command>SELECT INTO</command> and related statements.
present the only accepted way to do it is
<command>PERFORM</command>.
</para> </para>
</note> </note>
<para> <para>
An example: To handle cases where you need to process multiple result rows
<programlisting> from a SQL query, see <xref linkend="plpgsql-records-iterating">.
PERFORM create_mv('cs_session_page_requests_mv', my_query);
</programlisting>
</para> </para>
</sect2> </sect2>
<sect2 id="plpgsql-statements-null"> <sect2 id="plpgsql-statements-null">
...@@ -1268,7 +1338,7 @@ NULL; ...@@ -1268,7 +1338,7 @@ NULL;
<command>EXECUTE</command> statement is provided: <command>EXECUTE</command> statement is provided:
<synopsis> <synopsis>
EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replaceable>target</replaceable> ]; EXECUTE <replaceable class="command">command-string</replaceable> <optional> INTO <optional>STRICT</optional> <replaceable>target</replaceable> </optional>;
</synopsis> </synopsis>
where <replaceable>command-string</replaceable> is an expression where <replaceable>command-string</replaceable> is an expression
...@@ -1280,8 +1350,8 @@ EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replac ...@@ -1280,8 +1350,8 @@ EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replac
<para> <para>
Note in particular that no substitution of <application>PL/pgSQL</> Note in particular that no substitution of <application>PL/pgSQL</>
variables is done on the command string. The values of variables must variables is done on the computed command string. The values of
be inserted in the command string as it is constructed. variables must be inserted in the command string as it is constructed.
</para> </para>
<para> <para>
...@@ -1295,16 +1365,20 @@ EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replac ...@@ -1295,16 +1365,20 @@ EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replac
<para> <para>
The <literal>INTO</literal> clause specifies where the results of The <literal>INTO</literal> clause specifies where the results of
a <command>SELECT</command> command should be assigned. If a row a SQL command returning rows should be assigned. If a row
or variable list is provided, it must exactly match the structure or variable list is provided, it must exactly match the structure
of the results produced by the <command>SELECT</command> (when a of the query's results (when a
record variable is used, it will configure itself to match the record variable is used, it will configure itself to match the
result's structure automatically). If multiple rows are returned, result structure automatically). If multiple rows are returned,
only the first will be assigned to the <literal>INTO</literal> only the first will be assigned to the <literal>INTO</literal>
variable. If no rows are returned, NULL is assigned to the variable. If no rows are returned, NULL is assigned to the
<literal>INTO</literal> variable. If no <literal>INTO</literal> <literal>INTO</literal> variable. If no <literal>INTO</literal>
clause is specified, the results of a <command>SELECT</command> clause is specified, the query results are discarded.
command are discarded. </para>
<para>
If the <literal>STRICT</> option is given, an error is reported
unless the query produces exactly one row.
</para> </para>
<para> <para>
...@@ -2070,8 +2144,8 @@ $$ LANGUAGE plpgsql; ...@@ -2070,8 +2144,8 @@ $$ LANGUAGE plpgsql;
<para> <para>
The <replaceable>query</replaceable> used in this type of <literal>FOR</> The <replaceable>query</replaceable> used in this type of <literal>FOR</>
statement can be any query that returns rows to the caller: statement can be any SQL command that returns rows to the caller:
<command>SELECT</> (without <literal>INTO</>) is the most common case, <command>SELECT</> is the most common case,
but you can also use <command>INSERT</>, <command>UPDATE</>, or but you can also use <command>INSERT</>, <command>UPDATE</>, or
<command>DELETE</> with a <literal>RETURNING</> clause. Some utility <command>DELETE</> with a <literal>RETURNING</> clause. Some utility
commands such as <command>EXPLAIN</> will work too. commands such as <command>EXPLAIN</> will work too.
...@@ -3158,17 +3232,19 @@ SELECT * FROM sales_summary_bytime; ...@@ -3158,17 +3232,19 @@ SELECT * FROM sales_summary_bytime;
<listitem> <listitem>
<para> <para>
You cannot use parameter names that are the same as columns You can overload function names in <productname>PostgreSQL</>. This is
that are referenced in the function. Oracle allows you to do this often used to work around the lack of default parameters.
if you qualify the parameter name using
<literal>function_name.paramater_name</>.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
You can overload function names in <productname>PostgreSQL</>. This is You cannot use parameter names that are the same as columns
often used to work around the lack of default parameters. that are referenced in the function. Oracle allows you to do this
if you qualify the parameter name using
<literal>function_name.parameter_name</>.
In <application>PL/pgSQL</>, you can instead avoid a conflict by
qualifying the column or table name.
</para> </para>
</listitem> </listitem>
...@@ -3684,7 +3760,7 @@ $$ LANGUAGE plpgsql; ...@@ -3684,7 +3760,7 @@ $$ LANGUAGE plpgsql;
<function>quote_ident</function> as described in <xref <function>quote_ident</function> as described in <xref
linkend="plpgsql-statements-executing-dyn">. Constructs of the linkend="plpgsql-statements-executing-dyn">. Constructs of the
type <literal>EXECUTE 'SELECT * FROM $1';</literal> will not work type <literal>EXECUTE 'SELECT * FROM $1';</literal> will not work
unless you use these functions. reliably unless you use these functions.
</para> </para>
</sect3> </sect3>
......
...@@ -9,7 +9,7 @@ ...@@ -9,7 +9,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.94 2006/08/14 00:46:53 tgl Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.95 2006/08/14 21:14:41 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -28,11 +28,13 @@ static PLpgSQL_expr *read_sql_construct(int until, ...@@ -28,11 +28,13 @@ static PLpgSQL_expr *read_sql_construct(int until,
int *endtoken); int *endtoken);
static PLpgSQL_expr *read_sql_stmt(const char *sqlstart); static PLpgSQL_expr *read_sql_stmt(const char *sqlstart);
static PLpgSQL_type *read_datatype(int tok); static PLpgSQL_type *read_datatype(int tok);
static PLpgSQL_stmt *make_select_stmt(int lineno); static PLpgSQL_stmt *make_execsql_stmt(const char *sqlstart, int lineno);
static PLpgSQL_stmt *make_fetch_stmt(int lineno, int curvar); static PLpgSQL_stmt *make_fetch_stmt(int lineno, int curvar);
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 void check_assignable(PLpgSQL_datum *datum); static void check_assignable(PLpgSQL_datum *datum);
static void read_into_target(PLpgSQL_rec **rec, PLpgSQL_row **row,
bool *strict);
static PLpgSQL_row *read_into_scalar_list(const char *initial_name, static PLpgSQL_row *read_into_scalar_list(const char *initial_name,
PLpgSQL_datum *initial_datum); PLpgSQL_datum *initial_datum);
static PLpgSQL_row *make_scalar_list1(const char *initial_name, static PLpgSQL_row *make_scalar_list1(const char *initial_name,
...@@ -120,9 +122,8 @@ static void check_labels(const char *start_label, ...@@ -120,9 +122,8 @@ static void check_labels(const char *start_label,
%type <loop_body> loop_body %type <loop_body> loop_body
%type <stmt> proc_stmt pl_block %type <stmt> proc_stmt pl_block
%type <stmt> stmt_assign stmt_if stmt_loop stmt_while stmt_exit %type <stmt> stmt_assign stmt_if stmt_loop stmt_while stmt_exit
%type <stmt> stmt_return stmt_raise stmt_execsql %type <stmt> stmt_return stmt_raise stmt_execsql stmt_execsql_insert
%type <stmt> stmt_for stmt_select stmt_perform %type <stmt> stmt_dynexecute stmt_for stmt_perform stmt_getdiag
%type <stmt> stmt_dynexecute stmt_getdiag
%type <stmt> stmt_open stmt_fetch stmt_close stmt_null %type <stmt> stmt_open stmt_fetch stmt_close stmt_null
%type <list> proc_exceptions %type <list> proc_exceptions
...@@ -169,6 +170,7 @@ static void check_labels(const char *start_label, ...@@ -169,6 +170,7 @@ static void check_labels(const char *start_label,
%token K_IF %token K_IF
%token K_IN %token K_IN
%token K_INFO %token K_INFO
%token K_INSERT
%token K_INTO %token K_INTO
%token K_IS %token K_IS
%token K_LOG %token K_LOG
...@@ -186,7 +188,6 @@ static void check_labels(const char *start_label, ...@@ -186,7 +188,6 @@ static void check_labels(const char *start_label,
%token K_RESULT_OID %token K_RESULT_OID
%token K_RETURN %token K_RETURN
%token K_REVERSE %token K_REVERSE
%token K_SELECT
%token K_STRICT %token K_STRICT
%token K_THEN %token K_THEN
%token K_TO %token K_TO
...@@ -591,8 +592,6 @@ proc_stmt : pl_block ';' ...@@ -591,8 +592,6 @@ proc_stmt : pl_block ';'
{ $$ = $1; } { $$ = $1; }
| stmt_for | stmt_for
{ $$ = $1; } { $$ = $1; }
| stmt_select
{ $$ = $1; }
| stmt_exit | stmt_exit
{ $$ = $1; } { $$ = $1; }
| stmt_return | stmt_return
...@@ -601,6 +600,8 @@ proc_stmt : pl_block ';' ...@@ -601,6 +600,8 @@ proc_stmt : pl_block ';'
{ $$ = $1; } { $$ = $1; }
| stmt_execsql | stmt_execsql
{ $$ = $1; } { $$ = $1; }
| stmt_execsql_insert
{ $$ = $1; }
| stmt_dynexecute | stmt_dynexecute
{ $$ = $1; } { $$ = $1; }
| stmt_perform | stmt_perform
...@@ -1127,12 +1128,6 @@ for_variable : T_SCALAR ...@@ -1127,12 +1128,6 @@ for_variable : T_SCALAR
} }
; ;
stmt_select : K_SELECT lno
{
$$ = make_select_stmt($2);
}
;
stmt_exit : exit_type lno opt_label opt_exitcond stmt_exit : exit_type lno opt_label opt_exitcond
{ {
PLpgSQL_stmt_exit *new; PLpgSQL_stmt_exit *new;
...@@ -1259,14 +1254,28 @@ loop_body : proc_sect K_END K_LOOP opt_label ';' ...@@ -1259,14 +1254,28 @@ loop_body : proc_sect K_END K_LOOP opt_label ';'
stmt_execsql : execsql_start lno stmt_execsql : execsql_start lno
{ {
PLpgSQL_stmt_execsql *new; $$ = make_execsql_stmt($1, $2);
}
;
new = palloc(sizeof(PLpgSQL_stmt_execsql)); /* this matches any otherwise-unrecognized starting keyword */
new->cmd_type = PLPGSQL_STMT_EXECSQL; execsql_start : T_WORD
new->lineno = $2; { $$ = pstrdup(yytext); }
new->sqlstmt = read_sql_stmt($1); | T_ERROR
{ $$ = pstrdup(yytext); }
;
$$ = (PLpgSQL_stmt *)new; stmt_execsql_insert : K_INSERT lno K_INTO
{
/*
* We have to special-case INSERT so that its INTO
* won't be treated as an INTO-variables clause.
*
* Fortunately, this is the only valid use of INTO
* in a pl/pgsql SQL command, and INTO is already
* a fully reserved word in the main grammar.
*/
$$ = make_execsql_stmt("INSERT INTO", $2);
} }
; ;
...@@ -1276,46 +1285,24 @@ stmt_dynexecute : K_EXECUTE lno ...@@ -1276,46 +1285,24 @@ stmt_dynexecute : K_EXECUTE lno
PLpgSQL_expr *expr; PLpgSQL_expr *expr;
int endtoken; int endtoken;
expr = read_sql_construct(K_INTO, ';', "INTO|;", "SELECT ", expr = read_sql_construct(K_INTO, ';', "INTO|;",
"SELECT ",
true, true, &endtoken); true, true, &endtoken);
new = palloc(sizeof(PLpgSQL_stmt_dynexecute)); new = palloc(sizeof(PLpgSQL_stmt_dynexecute));
new->cmd_type = PLPGSQL_STMT_DYNEXECUTE; new->cmd_type = PLPGSQL_STMT_DYNEXECUTE;
new->lineno = $2; new->lineno = $2;
new->query = expr; new->query = expr;
new->into = false;
new->strict = false;
new->rec = NULL; new->rec = NULL;
new->row = NULL; new->row = NULL;
/* /* If we found "INTO", collect the argument */
* If we saw "INTO", look for a following row
* var, record var, or list of scalars.
*/
if (endtoken == K_INTO) if (endtoken == K_INTO)
{ {
switch (yylex()) new->into = true;
{ read_into_target(&new->rec, &new->row, &new->strict);
case T_ROW:
new->row = yylval.row;
check_assignable((PLpgSQL_datum *) new->row);
break;
case T_RECORD:
new->rec = yylval.rec;
check_assignable((PLpgSQL_datum *) new->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 variable, row variable, "
"or list of scalar variables.")));
}
if (yylex() != ';') if (yylex() != ';')
yyerror("syntax error"); yyerror("syntax error");
} }
...@@ -1502,12 +1489,6 @@ cursor_variable : T_SCALAR ...@@ -1502,12 +1489,6 @@ cursor_variable : T_SCALAR
} }
; ;
execsql_start : T_WORD
{ $$ = pstrdup(yytext); }
| T_ERROR
{ $$ = pstrdup(yytext); }
;
exception_sect : exception_sect :
{ $$ = NULL; } { $$ = NULL; }
| K_EXCEPTION lno | K_EXCEPTION lno
...@@ -1892,12 +1873,13 @@ read_datatype(int tok) ...@@ -1892,12 +1873,13 @@ read_datatype(int tok)
} }
static PLpgSQL_stmt * static PLpgSQL_stmt *
make_select_stmt(int lineno) make_execsql_stmt(const char *sqlstart, int lineno)
{ {
PLpgSQL_dstring ds; PLpgSQL_dstring ds;
int nparams = 0; int nparams = 0;
int params[MAX_EXPR_PARAMS]; int params[MAX_EXPR_PARAMS];
char buf[32]; char buf[32];
PLpgSQL_stmt_execsql *execsql;
PLpgSQL_expr *expr; PLpgSQL_expr *expr;
PLpgSQL_row *row = NULL; PLpgSQL_row *row = NULL;
PLpgSQL_rec *rec = NULL; PLpgSQL_rec *rec = NULL;
...@@ -1906,12 +1888,11 @@ make_select_stmt(int lineno) ...@@ -1906,12 +1888,11 @@ make_select_stmt(int lineno)
bool have_strict = false; bool have_strict = false;
plpgsql_dstring_init(&ds); plpgsql_dstring_init(&ds);
plpgsql_dstring_append(&ds, "SELECT "); plpgsql_dstring_append(&ds, sqlstart);
while (1) for (;;)
{ {
tok = yylex(); tok = yylex();
if (tok == ';') if (tok == ';')
break; break;
if (tok == 0) if (tok == 0)
...@@ -1930,37 +1911,8 @@ make_select_stmt(int lineno) ...@@ -1930,37 +1911,8 @@ make_select_stmt(int lineno)
(errcode(ERRCODE_SYNTAX_ERROR), (errcode(ERRCODE_SYNTAX_ERROR),
errmsg("INTO specified more than once"))); errmsg("INTO specified more than once")));
} }
tok = yylex();
if (tok == K_STRICT)
{
have_strict = true;
tok = yylex();
}
switch (tok)
{
case T_ROW:
row = yylval.row;
check_assignable((PLpgSQL_datum *) row);
have_into = true; have_into = true;
break; read_into_target(&rec, &row, &have_strict);
case T_RECORD:
rec = yylval.rec;
check_assignable((PLpgSQL_datum *) rec);
have_into = true;
break;
case T_SCALAR:
row = read_into_scalar_list(yytext, yylval.scalar);
have_into = true;
break;
default:
/* Treat the INTO as non-special */
plpgsql_dstring_append(&ds, " INTO ");
plpgsql_push_back_token(tok);
break;
}
continue; continue;
} }
...@@ -2007,31 +1959,16 @@ make_select_stmt(int lineno) ...@@ -2007,31 +1959,16 @@ make_select_stmt(int lineno)
check_sql_expr(expr->query); check_sql_expr(expr->query);
if (have_into)
{
PLpgSQL_stmt_select *select;
select = palloc0(sizeof(PLpgSQL_stmt_select));
select->cmd_type = PLPGSQL_STMT_SELECT;
select->lineno = lineno;
select->rec = rec;
select->row = row;
select->query = expr;
select->strict = have_strict;
return (PLpgSQL_stmt *)select;
}
else
{
PLpgSQL_stmt_execsql *execsql;
execsql = palloc(sizeof(PLpgSQL_stmt_execsql)); execsql = palloc(sizeof(PLpgSQL_stmt_execsql));
execsql->cmd_type = PLPGSQL_STMT_EXECSQL; execsql->cmd_type = PLPGSQL_STMT_EXECSQL;
execsql->lineno = lineno; execsql->lineno = lineno;
execsql->sqlstmt = expr; execsql->sqlstmt = expr;
execsql->into = have_into;
execsql->strict = have_strict;
execsql->rec = rec;
execsql->row = row;
return (PLpgSQL_stmt *)execsql; return (PLpgSQL_stmt *) execsql;
}
} }
...@@ -2039,38 +1976,12 @@ static PLpgSQL_stmt * ...@@ -2039,38 +1976,12 @@ static PLpgSQL_stmt *
make_fetch_stmt(int lineno, int curvar) make_fetch_stmt(int lineno, int curvar)
{ {
int tok; int tok;
PLpgSQL_row *row = NULL; PLpgSQL_rec *rec;
PLpgSQL_rec *rec = NULL; PLpgSQL_row *row;
PLpgSQL_stmt_fetch *fetch; PLpgSQL_stmt_fetch *fetch;
/* We have already parsed everything through the INTO keyword */ /* We have already parsed everything through the INTO keyword */
read_into_target(&rec, &row, NULL);
tok = yylex();
switch (tok)
{
case T_ROW:
row = yylval.row;
check_assignable((PLpgSQL_datum *) row);
break;
case T_RECORD:
rec = yylval.rec;
check_assignable((PLpgSQL_datum *) rec);
break;
case T_SCALAR:
row = read_into_scalar_list(yytext, yylval.scalar);
break;
default:
plpgsql_error_lineno = plpgsql_scanner_lineno();
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("syntax error at \"%s\"", yytext),
errdetail("Expected record variable, row variable, "
"or list of scalar variables.")));
}
tok = yylex(); tok = yylex();
if (tok != ';') if (tok != ';')
yyerror("syntax error"); yyerror("syntax error");
...@@ -2232,6 +2143,54 @@ check_assignable(PLpgSQL_datum *datum) ...@@ -2232,6 +2143,54 @@ check_assignable(PLpgSQL_datum *datum)
} }
} }
/*
* Read the argument of an INTO clause. On entry, we have just read the
* INTO keyword.
*/
static void
read_into_target(PLpgSQL_rec **rec, PLpgSQL_row **row, bool *strict)
{
int tok;
/* Set default results */
*rec = NULL;
*row = NULL;
if (strict)
*strict = false;
tok = yylex();
if (strict && tok == K_STRICT)
{
*strict = true;
tok = yylex();
}
switch (tok)
{
case T_ROW:
*row = yylval.row;
check_assignable((PLpgSQL_datum *) *row);
break;
case T_RECORD:
*rec = yylval.rec;
check_assignable((PLpgSQL_datum *) *rec);
break;
case T_SCALAR:
*row = read_into_scalar_list(yytext, yylval.scalar);
break;
default:
plpgsql_error_lineno = plpgsql_scanner_lineno();
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("syntax error at \"%s\"", yytext),
errdetail("Expected record variable, row variable, "
"or list of scalar variables following INTO.")));
}
}
/* /*
* Given the first datum and name in the INTO list, continue to read * Given the first datum and name in the INTO list, continue to read
* comma-separated scalar variables until we run out. Then construct * comma-separated scalar variables until we run out. Then construct
......
...@@ -8,7 +8,7 @@ ...@@ -8,7 +8,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.174 2006/07/13 16:49:20 momjian Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.175 2006/08/14 21:14:41 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -74,8 +74,6 @@ static int exec_stmt_fori(PLpgSQL_execstate *estate, ...@@ -74,8 +74,6 @@ static int exec_stmt_fori(PLpgSQL_execstate *estate,
PLpgSQL_stmt_fori *stmt); PLpgSQL_stmt_fori *stmt);
static int exec_stmt_fors(PLpgSQL_execstate *estate, static int exec_stmt_fors(PLpgSQL_execstate *estate,
PLpgSQL_stmt_fors *stmt); PLpgSQL_stmt_fors *stmt);
static int exec_stmt_select(PLpgSQL_execstate *estate,
PLpgSQL_stmt_select *stmt);
static int exec_stmt_open(PLpgSQL_execstate *estate, static int exec_stmt_open(PLpgSQL_execstate *estate,
PLpgSQL_stmt_open *stmt); PLpgSQL_stmt_open *stmt);
static int exec_stmt_fetch(PLpgSQL_execstate *estate, static int exec_stmt_fetch(PLpgSQL_execstate *estate,
...@@ -1079,10 +1077,6 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt) ...@@ -1079,10 +1077,6 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
rc = exec_stmt_fors(estate, (PLpgSQL_stmt_fors *) stmt); rc = exec_stmt_fors(estate, (PLpgSQL_stmt_fors *) stmt);
break; break;
case PLPGSQL_STMT_SELECT:
rc = exec_stmt_select(estate, (PLpgSQL_stmt_select *) stmt);
break;
case PLPGSQL_STMT_EXIT: case PLPGSQL_STMT_EXIT:
rc = exec_stmt_exit(estate, (PLpgSQL_stmt_exit *) stmt); rc = exec_stmt_exit(estate, (PLpgSQL_stmt_exit *) stmt);
break; break;
...@@ -1673,81 +1667,6 @@ exec_stmt_fors(PLpgSQL_execstate *estate, PLpgSQL_stmt_fors *stmt) ...@@ -1673,81 +1667,6 @@ exec_stmt_fors(PLpgSQL_execstate *estate, PLpgSQL_stmt_fors *stmt)
} }
/* ----------
* exec_stmt_select Run a query and assign the first
* row to a record or rowtype.
* ----------
*/
static int
exec_stmt_select(PLpgSQL_execstate *estate, PLpgSQL_stmt_select *stmt)
{
PLpgSQL_rec *rec = NULL;
PLpgSQL_row *row = NULL;
SPITupleTable *tuptab;
uint32 n;
/*
* Initialize the global found variable to false
*/
exec_set_found(estate, false);
/*
* Determine if we assign to a record or a row
*/
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]);
else
elog(ERROR, "unsupported target");
/*
* Run the query
*
* Retrieving two rows can be slower than a single row, e.g.
* a sequential scan where the scan has to be completed to
* check for a second row. For this reason, we only retrieve
* the second row if checking STRICT.
*/
exec_run_select(estate, stmt->query, stmt->strict ? 2 : 1, NULL);
tuptab = estate->eval_tuptable;
n = estate->eval_processed;
/*
* If SELECT ... INTO specified STRICT, and the query didn't
* find exactly one row, throw an error. If STRICT was not specified,
* then allow the query to find any number of rows.
*/
if (n == 0)
{
if (stmt->strict)
ereport(ERROR,
(errcode(ERRCODE_NO_DATA_FOUND),
errmsg("query returned no rows")));
/* set the target to NULL(s) */
exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
exec_eval_cleanup(estate);
return PLPGSQL_RC_OK;
}
if (n > 1 && stmt->strict)
ereport(ERROR,
(errcode(ERRCODE_TOO_MANY_ROWS),
errmsg("query returned more than one row")));
/*
* Put the first result into the target and set found to true
*/
exec_move_row(estate, rec, row, tuptab->vals[0], tuptab->tupdesc);
exec_set_found(estate, true);
exec_eval_cleanup(estate);
return PLPGSQL_RC_OK;
}
/* ---------- /* ----------
* exec_stmt_exit Implements EXIT and CONTINUE * exec_stmt_exit Implements EXIT and CONTINUE
* *
...@@ -2296,8 +2215,7 @@ exec_prepare_plan(PLpgSQL_execstate *estate, ...@@ -2296,8 +2215,7 @@ exec_prepare_plan(PLpgSQL_execstate *estate,
/* ---------- /* ----------
* exec_stmt_execsql Execute an SQL statement not * exec_stmt_execsql Execute an SQL statement (possibly with INTO).
* returning any data.
* ---------- * ----------
*/ */
static int static int
...@@ -2307,14 +2225,41 @@ exec_stmt_execsql(PLpgSQL_execstate *estate, ...@@ -2307,14 +2225,41 @@ exec_stmt_execsql(PLpgSQL_execstate *estate,
int i; int i;
Datum *values; Datum *values;
char *nulls; char *nulls;
long tcount;
int rc; int rc;
PLpgSQL_expr *expr = stmt->sqlstmt; PLpgSQL_expr *expr = stmt->sqlstmt;
/* /*
* On the first call for this expression generate the plan * On the first call for this statement generate the plan, and
* detect whether the statement is INSERT/UPDATE/DELETE
*/ */
if (expr->plan == NULL) if (expr->plan == NULL)
{
_SPI_plan *spi_plan;
ListCell *l;
exec_prepare_plan(estate, expr); exec_prepare_plan(estate, expr);
stmt->mod_stmt = false;
spi_plan = (_SPI_plan *) expr->plan;
foreach(l, spi_plan->qtlist)
{
ListCell *l2;
foreach(l2, (List *) lfirst(l))
{
Query *q = (Query *) lfirst(l2);
Assert(IsA(q, Query));
if (q->canSetTag)
{
if (q->commandType == CMD_INSERT ||
q->commandType == CMD_UPDATE ||
q->commandType == CMD_DELETE)
stmt->mod_stmt = true;
}
}
}
}
/* /*
* Now build up the values and nulls arguments for SPI_execute_plan() * Now build up the values and nulls arguments for SPI_execute_plan()
...@@ -2336,49 +2281,134 @@ exec_stmt_execsql(PLpgSQL_execstate *estate, ...@@ -2336,49 +2281,134 @@ exec_stmt_execsql(PLpgSQL_execstate *estate,
nulls[i] = ' '; nulls[i] = ' ';
} }
/*
* If we have INTO, then we only need one row back ... but if we have
* INTO STRICT, ask for two rows, so that we can verify the statement
* returns only one. INSERT/UPDATE/DELETE are always treated strictly.
* Without INTO, just run the statement to completion (tcount = 0).
*
* We could just ask for two rows always when using INTO, but there
* are some cases where demanding the extra row costs significant time,
* eg by forcing completion of a sequential scan. So don't do it unless
* we need to enforce strictness.
*/
if (stmt->into)
{
if (stmt->strict || stmt->mod_stmt)
tcount = 2;
else
tcount = 1;
}
else
tcount = 0;
/* /*
* Execute the plan * Execute the plan
*/ */
rc = SPI_execute_plan(expr->plan, values, nulls, rc = SPI_execute_plan(expr->plan, values, nulls,
estate->readonly_func, 0); estate->readonly_func, tcount);
/*
* Check for error, and set FOUND if appropriate (for historical reasons
* we set FOUND only for certain query types). Also Assert that we
* identified the statement type the same as SPI did.
*/
switch (rc) switch (rc)
{ {
case SPI_OK_UTILITY: case SPI_OK_SELECT:
case SPI_OK_SELINTO: Assert(!stmt->mod_stmt);
exec_set_found(estate, (SPI_processed != 0));
break; break;
case SPI_OK_INSERT: case SPI_OK_INSERT:
case SPI_OK_DELETE:
case SPI_OK_UPDATE: case SPI_OK_UPDATE:
case SPI_OK_DELETE:
Assert(stmt->mod_stmt);
exec_set_found(estate, (SPI_processed != 0));
break;
case SPI_OK_SELINTO:
Assert(!stmt->mod_stmt);
break;
case SPI_OK_UTILITY:
Assert(!stmt->mod_stmt);
/* /*
* If the INSERT, DELETE, or UPDATE query affected at least one * spi.c currently does not update SPI_processed for utility
* tuple, set the magic 'FOUND' variable to true. This conforms * commands. Not clear if this should be considered a bug;
* with the behavior of PL/SQL. * for the moment, work around it here.
*/ */
exec_set_found(estate, (SPI_processed != 0)); if (SPI_tuptable)
SPI_processed = (SPI_tuptable->alloced - SPI_tuptable->free);
break; break;
case SPI_OK_SELECT:
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("SELECT query has no destination for result data"),
errhint("If you want to discard the results, use PERFORM instead.")));
default: default:
elog(ERROR, "SPI_execute_plan failed executing query \"%s\": %s", elog(ERROR, "SPI_execute_plan failed executing query \"%s\": %s",
expr->query, SPI_result_code_string(rc)); expr->query, SPI_result_code_string(rc));
} }
/* All variants should save result info for GET DIAGNOSTICS */
estate->eval_processed = SPI_processed;
estate->eval_lastoid = SPI_lastoid;
/* Process INTO if present */
if (stmt->into)
{
SPITupleTable *tuptab = SPI_tuptable;
uint32 n = SPI_processed;
PLpgSQL_rec *rec = NULL;
PLpgSQL_row *row = NULL;
/* If the statement did not return a tuple table, complain */
if (tuptab == NULL)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("INTO used with a command that cannot return data")));
/* Determine if we assign to a record or a row */
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]);
else
elog(ERROR, "unsupported target");
/* /*
* Release any result tuples from SPI_execute_plan (probably shouldn't be * If SELECT ... INTO specified STRICT, and the query didn't
* any) * find exactly one row, throw an error. If STRICT was not specified,
* then allow the query to find any number of rows.
*/ */
SPI_freetuptable(SPI_tuptable); if (n == 0)
{
if (stmt->strict)
ereport(ERROR,
(errcode(ERRCODE_NO_DATA_FOUND),
errmsg("query returned no rows")));
/* set the target to NULL(s) */
exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
}
else
{
if (n > 1 && (stmt->strict || stmt->mod_stmt))
ereport(ERROR,
(errcode(ERRCODE_TOO_MANY_ROWS),
errmsg("query returned more than one row")));
/* Put the first result row into the target */
exec_move_row(estate, rec, row, tuptab->vals[0], tuptab->tupdesc);
}
/* Save result info for GET DIAGNOSTICS */ /* Clean up */
estate->eval_processed = SPI_processed; SPI_freetuptable(SPI_tuptable);
estate->eval_lastoid = SPI_lastoid; }
else
{
/* If the statement returned a tuple table, complain */
if (SPI_tuptable != NULL)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("query has no destination for result data"),
(rc == SPI_OK_SELECT) ? errhint("If you want to discard the results of a SELECT, use PERFORM instead.") : 0));
}
pfree(values); pfree(values);
pfree(nulls); pfree(nulls);
...@@ -2388,8 +2418,8 @@ exec_stmt_execsql(PLpgSQL_execstate *estate, ...@@ -2388,8 +2418,8 @@ exec_stmt_execsql(PLpgSQL_execstate *estate,
/* ---------- /* ----------
* exec_stmt_dynexecute Execute a dynamic SQL query not * exec_stmt_dynexecute Execute a dynamic SQL query
* returning any data. * (possibly with INTO).
* ---------- * ----------
*/ */
static int static int
...@@ -2401,17 +2431,10 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate, ...@@ -2401,17 +2431,10 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate,
Oid restype; Oid restype;
char *querystr; char *querystr;
int exec_res; 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. It's * First we evaluate the string expression after the EXECUTE keyword.
* result is the querystring we have to execute. * Its result is the querystring we have to execute.
*/ */
query = exec_eval_expr(estate, stmt->query, &isnull, &restype); query = exec_eval_expr(estate, stmt->query, &isnull, &restype);
if (isnull) if (isnull)
...@@ -2425,36 +2448,26 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate, ...@@ -2425,36 +2448,26 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate,
exec_eval_cleanup(estate); exec_eval_cleanup(estate);
/* /*
* Call SPI_execute() without preparing a saved plan. The returncode can * Call SPI_execute() without preparing a saved plan.
* be any standard OK. Note that while a SELECT is allowed, its results
* will be discarded unless an INTO clause is specified.
*/ */
exec_res = SPI_execute(querystr, estate->readonly_func, 0); 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) switch (exec_res)
{ {
case SPI_OK_SELECT: case SPI_OK_SELECT:
case SPI_OK_INSERT: case SPI_OK_INSERT:
case SPI_OK_UPDATE: case SPI_OK_UPDATE:
case SPI_OK_DELETE: case SPI_OK_DELETE:
break;
case SPI_OK_UTILITY: case SPI_OK_UTILITY:
/*
* spi.c currently does not update SPI_processed for utility
* commands. Not clear if this should be considered a bug;
* for the moment, work around it here.
*/
if (SPI_tuptable)
SPI_processed = (SPI_tuptable->alloced - SPI_tuptable->free);
break; break;
case 0: case 0:
...@@ -2511,14 +2524,69 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate, ...@@ -2511,14 +2524,69 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate,
break; break;
} }
/* Release any result from SPI_execute, as well as the querystring */
SPI_freetuptable(SPI_tuptable);
pfree(querystr);
/* Save result info for GET DIAGNOSTICS */ /* Save result info for GET DIAGNOSTICS */
estate->eval_processed = SPI_processed; estate->eval_processed = SPI_processed;
estate->eval_lastoid = SPI_lastoid; estate->eval_lastoid = SPI_lastoid;
/* Process INTO if present */
if (stmt->into)
{
SPITupleTable *tuptab = SPI_tuptable;
uint32 n = SPI_processed;
PLpgSQL_rec *rec = NULL;
PLpgSQL_row *row = NULL;
/* If the statement did not return a tuple table, complain */
if (tuptab == NULL)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("INTO used with a command that cannot return data")));
/* Determine if we assign to a record or a row */
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]);
else
elog(ERROR, "unsupported target");
/*
* If SELECT ... INTO specified STRICT, and the query didn't
* find exactly one row, throw an error. If STRICT was not specified,
* then allow the query to find any number of rows.
*/
if (n == 0)
{
if (stmt->strict)
ereport(ERROR,
(errcode(ERRCODE_NO_DATA_FOUND),
errmsg("query returned no rows")));
/* set the target to NULL(s) */
exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
}
else
{
if (n > 1 && stmt->strict)
ereport(ERROR,
(errcode(ERRCODE_TOO_MANY_ROWS),
errmsg("query returned more than one row")));
/* Put the first result row into the target */
exec_move_row(estate, rec, row, tuptab->vals[0], tuptab->tupdesc);
}
}
else
{
/*
* It might be a good idea to raise an error if the query returned
* tuples that are being ignored, but historically we have not done
* that.
*/
}
/* Release any result from SPI_execute, as well as the querystring */
SPI_freetuptable(SPI_tuptable);
pfree(querystr);
return PLPGSQL_RC_OK; return PLPGSQL_RC_OK;
} }
...@@ -2823,12 +2891,12 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt) ...@@ -2823,12 +2891,12 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt)
if (stmt->argquery != NULL) if (stmt->argquery != NULL)
{ {
/* ---------- /* ----------
* Er - OPEN CURSOR (args). We fake a SELECT ... INTO ... * OPEN CURSOR with args. We fake a SELECT ... INTO ...
* statement to evaluate the args and put 'em into the * statement to evaluate the args and put 'em into the
* internal row. * internal row.
* ---------- * ----------
*/ */
PLpgSQL_stmt_select set_args; PLpgSQL_stmt_execsql set_args;
if (curvar->cursor_explicit_argrow < 0) if (curvar->cursor_explicit_argrow < 0)
ereport(ERROR, ereport(ERROR,
...@@ -2836,13 +2904,15 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt) ...@@ -2836,13 +2904,15 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt)
errmsg("arguments given for cursor without arguments"))); errmsg("arguments given for cursor without arguments")));
memset(&set_args, 0, sizeof(set_args)); memset(&set_args, 0, sizeof(set_args));
set_args.cmd_type = PLPGSQL_STMT_SELECT; set_args.cmd_type = PLPGSQL_STMT_EXECSQL;
set_args.lineno = stmt->lineno; set_args.lineno = stmt->lineno;
set_args.sqlstmt = stmt->argquery;
set_args.into = true;
/* XXX historically this has not been STRICT */
set_args.row = (PLpgSQL_row *) set_args.row = (PLpgSQL_row *)
(estate->datums[curvar->cursor_explicit_argrow]); (estate->datums[curvar->cursor_explicit_argrow]);
set_args.query = stmt->argquery;
if (exec_stmt_select(estate, &set_args) != PLPGSQL_RC_OK) if (exec_stmt_execsql(estate, &set_args) != PLPGSQL_RC_OK)
elog(ERROR, "open cursor failed during argument processing"); elog(ERROR, "open cursor failed during argument processing");
} }
else else
......
...@@ -8,7 +8,7 @@ ...@@ -8,7 +8,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.53 2006/06/12 16:45:30 momjian Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.54 2006/08/14 21:14:41 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -439,8 +439,6 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt) ...@@ -439,8 +439,6 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
return "for with integer loopvar"; return "for with integer loopvar";
case PLPGSQL_STMT_FORS: case PLPGSQL_STMT_FORS:
return "for over select rows"; return "for over select rows";
case PLPGSQL_STMT_SELECT:
return "select into variables";
case PLPGSQL_STMT_EXIT: case PLPGSQL_STMT_EXIT:
return "exit"; return "exit";
case PLPGSQL_STMT_RETURN: case PLPGSQL_STMT_RETURN:
...@@ -485,7 +483,6 @@ static void dump_loop(PLpgSQL_stmt_loop *stmt); ...@@ -485,7 +483,6 @@ static void dump_loop(PLpgSQL_stmt_loop *stmt);
static void dump_while(PLpgSQL_stmt_while *stmt); static void dump_while(PLpgSQL_stmt_while *stmt);
static void dump_fori(PLpgSQL_stmt_fori *stmt); static void dump_fori(PLpgSQL_stmt_fori *stmt);
static void dump_fors(PLpgSQL_stmt_fors *stmt); static void dump_fors(PLpgSQL_stmt_fors *stmt);
static void dump_select(PLpgSQL_stmt_select *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);
...@@ -537,9 +534,6 @@ dump_stmt(PLpgSQL_stmt *stmt) ...@@ -537,9 +534,6 @@ dump_stmt(PLpgSQL_stmt *stmt)
case PLPGSQL_STMT_FORS: case PLPGSQL_STMT_FORS:
dump_fors((PLpgSQL_stmt_fors *) stmt); dump_fors((PLpgSQL_stmt_fors *) stmt);
break; break;
case PLPGSQL_STMT_SELECT:
dump_select((PLpgSQL_stmt_select *) stmt);
break;
case PLPGSQL_STMT_EXIT: case PLPGSQL_STMT_EXIT:
dump_exit((PLpgSQL_stmt_exit *) stmt); dump_exit((PLpgSQL_stmt_exit *) stmt);
break; break;
...@@ -731,29 +725,6 @@ dump_fors(PLpgSQL_stmt_fors *stmt) ...@@ -731,29 +725,6 @@ dump_fors(PLpgSQL_stmt_fors *stmt)
printf(" ENDFORS\n"); printf(" ENDFORS\n");
} }
static void
dump_select(PLpgSQL_stmt_select *stmt)
{
dump_ind();
printf("SELECT ");
dump_expr(stmt->query);
printf("\n");
dump_indent += 2;
if (stmt->rec != NULL)
{
dump_ind();
printf(" target = %d %s\n", stmt->rec->recno, stmt->rec->refname);
}
if (stmt->row != NULL)
{
dump_ind();
printf(" target = %d %s\n", stmt->row->rowno, stmt->row->refname);
}
dump_indent -= 2;
}
static void static void
dump_open(PLpgSQL_stmt_open *stmt) dump_open(PLpgSQL_stmt_open *stmt)
{ {
...@@ -891,6 +862,23 @@ dump_execsql(PLpgSQL_stmt_execsql *stmt) ...@@ -891,6 +862,23 @@ dump_execsql(PLpgSQL_stmt_execsql *stmt)
printf("EXECSQL "); printf("EXECSQL ");
dump_expr(stmt->sqlstmt); dump_expr(stmt->sqlstmt);
printf("\n"); printf("\n");
dump_indent += 2;
if (stmt->rec != NULL)
{
dump_ind();
printf(" INTO%s target = %d %s\n",
stmt->strict ? " STRICT" : "",
stmt->rec->recno, stmt->rec->refname);
}
if (stmt->row != NULL)
{
dump_ind();
printf(" INTO%s target = %d %s\n",
stmt->strict ? " STRICT" : "",
stmt->row->rowno, stmt->row->refname);
}
dump_indent -= 2;
} }
static void static void
...@@ -905,12 +893,16 @@ dump_dynexecute(PLpgSQL_stmt_dynexecute *stmt) ...@@ -905,12 +893,16 @@ dump_dynexecute(PLpgSQL_stmt_dynexecute *stmt)
if (stmt->rec != NULL) if (stmt->rec != NULL)
{ {
dump_ind(); dump_ind();
printf(" target = %d %s\n", stmt->rec->recno, stmt->rec->refname); printf(" INTO%s target = %d %s\n",
stmt->strict ? " STRICT" : "",
stmt->rec->recno, stmt->rec->refname);
} }
else if (stmt->row != NULL) if (stmt->row != NULL)
{ {
dump_ind(); dump_ind();
printf(" target = %d %s\n", stmt->row->rowno, stmt->row->refname); printf(" INTO%s target = %d %s\n",
stmt->strict ? " STRICT" : "",
stmt->row->rowno, stmt->row->refname);
} }
dump_indent -= 2; dump_indent -= 2;
} }
......
...@@ -8,7 +8,7 @@ ...@@ -8,7 +8,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.78 2006/08/08 19:15:09 tgl Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.79 2006/08/14 21:14:41 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -80,7 +80,6 @@ enum ...@@ -80,7 +80,6 @@ enum
PLPGSQL_STMT_WHILE, PLPGSQL_STMT_WHILE,
PLPGSQL_STMT_FORI, PLPGSQL_STMT_FORI,
PLPGSQL_STMT_FORS, PLPGSQL_STMT_FORS,
PLPGSQL_STMT_SELECT,
PLPGSQL_STMT_EXIT, PLPGSQL_STMT_EXIT,
PLPGSQL_STMT_RETURN, PLPGSQL_STMT_RETURN,
PLPGSQL_STMT_RETURN_NEXT, PLPGSQL_STMT_RETURN_NEXT,
...@@ -428,17 +427,6 @@ typedef struct ...@@ -428,17 +427,6 @@ typedef struct
} PLpgSQL_stmt_dynfors; } PLpgSQL_stmt_dynfors;
typedef struct
{ /* SELECT ... INTO statement */
int cmd_type;
int lineno;
bool strict;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
PLpgSQL_expr *query;
} PLpgSQL_stmt_select;
typedef struct typedef struct
{ /* OPEN a curvar */ { /* OPEN a curvar */
int cmd_type; int cmd_type;
...@@ -510,6 +498,12 @@ typedef struct ...@@ -510,6 +498,12 @@ typedef struct
int cmd_type; int cmd_type;
int lineno; int lineno;
PLpgSQL_expr *sqlstmt; PLpgSQL_expr *sqlstmt;
bool mod_stmt; /* is the stmt INSERT/UPDATE/DELETE? */
/* note: mod_stmt is set when we plan the query */
bool into; /* INTO supplied? */
bool strict; /* INTO STRICT flag */
PLpgSQL_rec *rec; /* INTO target, if record */
PLpgSQL_row *row; /* INTO target, if row */
} PLpgSQL_stmt_execsql; } PLpgSQL_stmt_execsql;
...@@ -517,9 +511,11 @@ typedef struct ...@@ -517,9 +511,11 @@ typedef struct
{ /* Dynamic SQL string to execute */ { /* Dynamic SQL string to execute */
int cmd_type; int cmd_type;
int lineno; int lineno;
PLpgSQL_rec *rec; /* INTO record or row variable */ PLpgSQL_expr *query; /* string expression */
PLpgSQL_row *row; bool into; /* INTO supplied? */
PLpgSQL_expr *query; bool strict; /* INTO STRICT flag */
PLpgSQL_rec *rec; /* INTO target, if record */
PLpgSQL_row *row; /* INTO target, if row */
} PLpgSQL_stmt_dynexecute; } PLpgSQL_stmt_dynexecute;
......
...@@ -9,7 +9,7 @@ ...@@ -9,7 +9,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.53 2006/08/14 00:46:53 tgl Exp $ * $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.54 2006/08/14 21:14:42 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -137,6 +137,7 @@ get { return K_GET; } ...@@ -137,6 +137,7 @@ get { return K_GET; }
if { return K_IF; } if { return K_IF; }
in { return K_IN; } in { return K_IN; }
info { return K_INFO; } info { return K_INFO; }
insert { return K_INSERT; }
into { return K_INTO; } into { return K_INTO; }
is { return K_IS; } is { return K_IS; }
log { return K_LOG; } log { return K_LOG; }
...@@ -154,7 +155,6 @@ result_oid { return K_RESULT_OID; } ...@@ -154,7 +155,6 @@ result_oid { return K_RESULT_OID; }
return { return K_RETURN; } return { return K_RETURN; }
reverse { return K_REVERSE; } reverse { return K_REVERSE; }
row_count { return K_ROW_COUNT; } row_count { return K_ROW_COUNT; }
select { return K_SELECT; }
strict { return K_STRICT; } strict { return K_STRICT; }
then { return K_THEN; } then { return K_THEN; }
to { return K_TO; } to { return K_TO; }
......
...@@ -2048,6 +2048,7 @@ select * from foo; ...@@ -2048,6 +2048,7 @@ select * from foo;
20 20
(2 rows) (2 rows)
drop table foo;
-- Test for pass-by-ref values being stored in proper context -- Test for pass-by-ref values being stored in proper context
create function test_variable_storage() returns text as $$ create function test_variable_storage() returns text as $$
declare x text; declare x text;
...@@ -2794,3 +2795,142 @@ select multi_datum_use(42); ...@@ -2794,3 +2795,142 @@ select multi_datum_use(42);
t t
(1 row) (1 row)
--
-- Test STRICT limiter in both planned and EXECUTE invocations.
-- Note that a data-modifying query is quasi strict (disallow multi rows)
-- by default in the planned case, but not in EXECUTE.
--
create temp table foo (f1 int, f2 int);
insert into foo values (1,2), (3,4);
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
insert into foo values(5,6) returning * into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 5, x.f2 = 6
footest
---------
(1 row)
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail due to implicit strict
insert into foo values(7,8),(9,10) returning * into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
ERROR: query returned more than one row
CONTEXT: PL/pgSQL function "footest" line 4 at SQL statement
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
execute 'insert into foo values(5,6) returning *' into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 5, x.f2 = 6
footest
---------
(1 row)
create or replace function footest() returns void as $$
declare x record;
begin
-- this should work since EXECUTE isn't as picky
execute 'insert into foo values(7,8),(9,10) returning *' into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 7, x.f2 = 8
footest
---------
(1 row)
select * from foo;
f1 | f2
----+----
1 | 2
3 | 4
5 | 6
5 | 6
7 | 8
9 | 10
(6 rows)
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
select * from foo where f1 = 3 into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 3, x.f2 = 4
footest
---------
(1 row)
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, no rows
select * from foo where f1 = 0 into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
ERROR: query returned no rows
CONTEXT: PL/pgSQL function "footest" line 4 at SQL statement
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, too many rows
select * from foo where f1 > 3 into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
ERROR: query returned more than one row
CONTEXT: PL/pgSQL function "footest" line 4 at SQL statement
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
execute 'select * from foo where f1 = 3' into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 3, x.f2 = 4
footest
---------
(1 row)
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, no rows
execute 'select * from foo where f1 = 0' into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
ERROR: query returned no rows
CONTEXT: PL/pgSQL function "footest" line 4 at execute statement
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, too many rows
execute 'select * from foo where f1 > 3' into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
ERROR: query returned more than one row
CONTEXT: PL/pgSQL function "footest" line 4 at execute statement
drop function footest();
...@@ -1777,6 +1777,8 @@ reset statement_timeout; ...@@ -1777,6 +1777,8 @@ reset statement_timeout;
select * from foo; select * from foo;
drop table foo;
-- Test for pass-by-ref values being stored in proper context -- Test for pass-by-ref values being stored in proper context
create function test_variable_storage() returns text as $$ create function test_variable_storage() returns text as $$
declare x text; declare x text;
...@@ -2324,3 +2326,117 @@ begin ...@@ -2324,3 +2326,117 @@ begin
end$$ language plpgsql; end$$ language plpgsql;
select multi_datum_use(42); select multi_datum_use(42);
--
-- Test STRICT limiter in both planned and EXECUTE invocations.
-- Note that a data-modifying query is quasi strict (disallow multi rows)
-- by default in the planned case, but not in EXECUTE.
--
create temp table foo (f1 int, f2 int);
insert into foo values (1,2), (3,4);
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
insert into foo values(5,6) returning * into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail due to implicit strict
insert into foo values(7,8),(9,10) returning * into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
execute 'insert into foo values(5,6) returning *' into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
create or replace function footest() returns void as $$
declare x record;
begin
-- this should work since EXECUTE isn't as picky
execute 'insert into foo values(7,8),(9,10) returning *' into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
select * from foo;
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
select * from foo where f1 = 3 into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, no rows
select * from foo where f1 = 0 into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, too many rows
select * from foo where f1 > 3 into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
execute 'select * from foo where f1 = 3' into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, no rows
execute 'select * from foo where f1 = 0' into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, too many rows
execute 'select * from foo where f1 > 3' into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
drop function footest();
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