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
This commit is contained in:
parent
29fa051316
commit
3d1e01caa4
@ -1,4 +1,4 @@
|
||||
<!-- $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">
|
||||
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
|
||||
@ -228,17 +228,6 @@ $$ LANGUAGE plpgsql;
|
||||
<type>void</> if it has no useful return value.
|
||||
</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>
|
||||
<application>PL/pgSQL</> functions can also be declared with output
|
||||
parameters in place of an explicit specification of the return type.
|
||||
@ -1024,21 +1013,17 @@ $$ LANGUAGE plpgsql;
|
||||
types that are explicitly understood by
|
||||
<application>PL/pgSQL</application>.
|
||||
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
|
||||
(after substitution of any <application>PL/pgSQL</application> variables
|
||||
used in the statement). Thus,
|
||||
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.
|
||||
to be an SQL command and is sent to the main database engine to execute,
|
||||
as described in <xref linkend="plpgsql-statements-sql-noresult">
|
||||
and <xref linkend="plpgsql-statements-sql-onerow">.
|
||||
</para>
|
||||
|
||||
<sect2 id="plpgsql-statements-assignment">
|
||||
<title>Assignment</title>
|
||||
|
||||
<para>
|
||||
An assignment of a value to a variable or row/record field is
|
||||
written as:
|
||||
An assignment of a value to a <application>PL/pgSQL</application>
|
||||
variable or row/record field is written as:
|
||||
<synopsis>
|
||||
<replaceable>identifier</replaceable> := <replaceable>expression</replaceable>;
|
||||
</synopsis>
|
||||
@ -1067,114 +1052,66 @@ tax := subtotal * 0.06;
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
<sect2 id="plpgsql-select-into">
|
||||
<title><command>SELECT INTO</command></title>
|
||||
|
||||
<indexterm zone="plpgsql-select-into">
|
||||
<primary>SELECT INTO</primary>
|
||||
<secondary>in PL/pgSQL</secondary>
|
||||
</indexterm>
|
||||
<sect2 id="plpgsql-statements-sql-noresult">
|
||||
<title>Executing a Query With No Result</title>
|
||||
|
||||
<para>
|
||||
The result of a <command>SELECT</command> command yielding multiple
|
||||
columns (but only one row) can be assigned to a record variable, row-type
|
||||
variable, or list of scalar variables. This is done by:
|
||||
|
||||
<synopsis>
|
||||
SELECT INTO <optional>STRICT</optional> <replaceable>target</replaceable> <replaceable>select_expressions</replaceable> FROM ...;
|
||||
</synopsis>
|
||||
|
||||
where <replaceable>target</replaceable> can be a record variable, a row
|
||||
variable, or a comma-separated list of simple variables and
|
||||
record/row fields. The <replaceable>select_expressions</replaceable>
|
||||
and the remainder of the command are the same as in regular SQL.
|
||||
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>
|
||||
Note that this is quite different from
|
||||
<productname>PostgreSQL</>'s normal interpretation of
|
||||
<command>SELECT INTO</command>, where the <literal>INTO</> target
|
||||
is a newly created table. If you want to create a table from a
|
||||
<command>SELECT</> result inside a
|
||||
<application>PL/pgSQL</application> function, use the syntax
|
||||
<command>CREATE TABLE ... AS SELECT</command>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If a row or a variable list is used as target, the selected values
|
||||
must exactly match the structure of the target, or a run-time error
|
||||
occurs. When a record variable is the target, it automatically
|
||||
configures itself to the row type of the query result columns.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Except for the <literal>INTO</> clause, the <command>SELECT</>
|
||||
statement is the same as a normal SQL <command>SELECT</> command
|
||||
and can use its full power.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The <literal>INTO</> clause can appear almost anywhere in the
|
||||
<command>SELECT</command> statement. Customarily it is written
|
||||
either just after <literal>SELECT</> as shown above, or
|
||||
just before <literal>FROM</> — 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
|
||||
returned by the query, or if the query returned no rows,
|
||||
null values are assigned. (Note that <quote>the first row</> is not
|
||||
well-defined unless you've used <literal>ORDER BY</>.) Any result rows
|
||||
after the first row are discarded.
|
||||
You can check the special <literal>FOUND</literal> variable (see
|
||||
<xref linkend="plpgsql-statements-diagnostics">) to
|
||||
determine whether a row was returned:
|
||||
|
||||
<programlisting>
|
||||
SELECT INTO myrec * FROM emp WHERE empname = myname;
|
||||
IF NOT FOUND THEN
|
||||
RAISE EXCEPTION 'employee % not found', myname;
|
||||
END IF;
|
||||
</programlisting>
|
||||
|
||||
If the <literal>STRICT</literal> option is specified, the query must
|
||||
return exactly one row or a run-time error will be thrown, either
|
||||
<literal>NO_DATA_FOUND</> (no rows) or <literal>TOO_MANY_ROWS</>
|
||||
(more than one row). You can use an exception block if you wish
|
||||
to catch the error, for example:
|
||||
|
||||
<programlisting>
|
||||
BEGIN;
|
||||
SELECT INTO STRICT myrec * FROM emp WHERE empname = myname;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
RAISE EXCEPTION 'employee % not found', myname;
|
||||
WHEN TOO_MANY_ROWS THEN
|
||||
RAISE EXCEPTION 'employee % not unique', myname;
|
||||
END;
|
||||
</programlisting>
|
||||
Successful execution of <command>SELECT INTO STRICT</command>
|
||||
always sets <literal>FOUND</literal> to true.
|
||||
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>
|
||||
<command>SELECT INTO STRICT</command> matches the behavior of
|
||||
Oracle PL/SQL's <command>SELECT INTO</command> statement.
|
||||
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>
|
||||
|
||||
</sect2>
|
||||
|
||||
<sect2 id="plpgsql-statements-perform">
|
||||
<title>Executing an Expression or Query With No Result</title>
|
||||
<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 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
|
||||
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:
|
||||
|
||||
@ -1184,20 +1121,23 @@ PERFORM <replaceable>query</replaceable>;
|
||||
|
||||
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
|
||||
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.
|
||||
least one row, or false if it produced no rows.
|
||||
</para>
|
||||
|
||||
<note>
|
||||
<para>
|
||||
One might expect that <command>SELECT</command> with no
|
||||
<literal>INTO</> clause would accomplish this result, but at
|
||||
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>.
|
||||
<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>
|
||||
|
||||
@ -1209,6 +1149,136 @@ PERFORM create_mv('cs_session_page_requests_mv', my_query);
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
<sect2 id="plpgsql-statements-sql-onerow">
|
||||
<title>Executing a Query with a Single-Row Result</title>
|
||||
|
||||
<indexterm zone="plpgsql-statements-sql-onerow">
|
||||
<primary>SELECT INTO</primary>
|
||||
<secondary>in PL/pgSQL</secondary>
|
||||
</indexterm>
|
||||
|
||||
<indexterm zone="plpgsql-statements-sql-onerow">
|
||||
<primary>RETURNING INTO</primary>
|
||||
<secondary>in PL/pgSQL</secondary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The result of a SQL command yielding a single row (possibly of multiple
|
||||
columns) can be assigned to a record variable, row-type variable, or list
|
||||
of scalar variables. This is done by writing the base SQL command and
|
||||
adding an <literal>INTO</> clause. For example,
|
||||
|
||||
<synopsis>
|
||||
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>
|
||||
|
||||
where <replaceable>target</replaceable> can be a record variable, a row
|
||||
variable, or a comma-separated list of simple variables and
|
||||
record/row fields.
|
||||
<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>
|
||||
|
||||
<tip>
|
||||
<para>
|
||||
Note that this interpretation of <command>SELECT</> with <literal>INTO</>
|
||||
is quite different from <productname>PostgreSQL</>'s regular
|
||||
<command>SELECT INTO</command> command, wherein the <literal>INTO</>
|
||||
target is a newly created table. If you want to create a table from a
|
||||
<command>SELECT</> result inside a
|
||||
<application>PL/pgSQL</application> function, use the syntax
|
||||
<command>CREATE TABLE ... AS SELECT</command>.
|
||||
</para>
|
||||
</tip>
|
||||
|
||||
<para>
|
||||
If a row or a variable list is used as target, the query's result columns
|
||||
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
|
||||
configures itself to the row type of the query result columns.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The <literal>INTO</> clause can appear almost anywhere in the SQL
|
||||
command. Customarily it is written either just before or just after
|
||||
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>
|
||||
If <literal>STRICT</literal> is not specified, then
|
||||
<replaceable>target</replaceable> will be set to the first row
|
||||
returned by the query, or to nulls if the query returned no rows.
|
||||
(Note that <quote>the first row</> is not
|
||||
well-defined unless you've used <literal>ORDER BY</>.) Any result rows
|
||||
after the first row are discarded.
|
||||
You can check the special <literal>FOUND</literal> variable (see
|
||||
<xref linkend="plpgsql-statements-diagnostics">) to
|
||||
determine whether a row was returned:
|
||||
|
||||
<programlisting>
|
||||
SELECT * INTO myrec FROM emp WHERE empname = myname;
|
||||
IF NOT FOUND THEN
|
||||
RAISE EXCEPTION 'employee % not found', myname;
|
||||
END IF;
|
||||
</programlisting>
|
||||
|
||||
If the <literal>STRICT</literal> option is specified, the query must
|
||||
return exactly one row or a run-time error will be reported, either
|
||||
<literal>NO_DATA_FOUND</> (no rows) or <literal>TOO_MANY_ROWS</>
|
||||
(more than one row). You can use an exception block if you wish
|
||||
to catch the error, for example:
|
||||
|
||||
<programlisting>
|
||||
BEGIN;
|
||||
SELECT * INTO STRICT myrec FROM emp WHERE empname = myname;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
RAISE EXCEPTION 'employee % not found', myname;
|
||||
WHEN TOO_MANY_ROWS THEN
|
||||
RAISE EXCEPTION 'employee % not unique', myname;
|
||||
END;
|
||||
</programlisting>
|
||||
Successful execution of a command with <literal>STRICT</>
|
||||
always sets <literal>FOUND</literal> to true.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
For <command>INSERT</>/<command>UPDATE</>/<command>DELETE</> with
|
||||
<literal>RETURNING</>, <application>PL/pgSQL</application> reports
|
||||
an error for more than one returned row, even when
|
||||
<literal>STRICT</literal> is not specified. This is because there
|
||||
is no option such as <literal>ORDER BY</> with which to determine
|
||||
which affected row would be returned.
|
||||
</para>
|
||||
|
||||
<note>
|
||||
<para>
|
||||
The <literal>STRICT</> option matches the behavior of
|
||||
Oracle PL/SQL's <command>SELECT INTO</command> and related statements.
|
||||
</para>
|
||||
</note>
|
||||
|
||||
<para>
|
||||
To handle cases where you need to process multiple result rows
|
||||
from a SQL query, see <xref linkend="plpgsql-records-iterating">.
|
||||
</para>
|
||||
|
||||
</sect2>
|
||||
|
||||
<sect2 id="plpgsql-statements-null">
|
||||
<title>Doing Nothing At All</title>
|
||||
|
||||
@ -1268,7 +1338,7 @@ NULL;
|
||||
<command>EXECUTE</command> statement is provided:
|
||||
|
||||
<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>
|
||||
|
||||
where <replaceable>command-string</replaceable> is an expression
|
||||
@ -1280,8 +1350,8 @@ EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replac
|
||||
|
||||
<para>
|
||||
Note in particular that no substitution of <application>PL/pgSQL</>
|
||||
variables is done on the command string. The values of variables must
|
||||
be inserted in the command string as it is constructed.
|
||||
variables is done on the computed command string. The values of
|
||||
variables must be inserted in the command string as it is constructed.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@ -1295,16 +1365,20 @@ EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replac
|
||||
|
||||
<para>
|
||||
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
|
||||
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
|
||||
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>
|
||||
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.
|
||||
clause is specified, the query results are discarded.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If the <literal>STRICT</> option is given, an error is reported
|
||||
unless the query produces exactly one row.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@ -2070,8 +2144,8 @@ $$ LANGUAGE plpgsql;
|
||||
|
||||
<para>
|
||||
The <replaceable>query</replaceable> used in this type of <literal>FOR</>
|
||||
statement can be any query that returns rows to the caller:
|
||||
<command>SELECT</> (without <literal>INTO</>) is the most common case,
|
||||
statement can be any SQL command that returns rows to the caller:
|
||||
<command>SELECT</> is the most common case,
|
||||
but you can also use <command>INSERT</>, <command>UPDATE</>, or
|
||||
<command>DELETE</> with a <literal>RETURNING</> clause. Some utility
|
||||
commands such as <command>EXPLAIN</> will work too.
|
||||
@ -3158,17 +3232,19 @@ SELECT * FROM sales_summary_bytime;
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
You cannot use parameter names that are the same as columns
|
||||
that are referenced in the function. Oracle allows you to do this
|
||||
if you qualify the parameter name using
|
||||
<literal>function_name.paramater_name</>.
|
||||
You can overload function names in <productname>PostgreSQL</>. This is
|
||||
often used to work around the lack of default parameters.
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
You can overload function names in <productname>PostgreSQL</>. This is
|
||||
often used to work around the lack of default parameters.
|
||||
You cannot use parameter names that are the same as columns
|
||||
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>
|
||||
</listitem>
|
||||
|
||||
@ -3684,7 +3760,7 @@ $$ LANGUAGE plpgsql;
|
||||
<function>quote_ident</function> as described in <xref
|
||||
linkend="plpgsql-statements-executing-dyn">. Constructs of the
|
||||
type <literal>EXECUTE 'SELECT * FROM $1';</literal> will not work
|
||||
unless you use these functions.
|
||||
reliably unless you use these functions.
|
||||
</para>
|
||||
</sect3>
|
||||
|
||||
|
@ -9,7 +9,7 @@
|
||||
*
|
||||
*
|
||||
* 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,
|
||||
int *endtoken);
|
||||
static PLpgSQL_expr *read_sql_stmt(const char *sqlstart);
|
||||
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_return_stmt(int lineno);
|
||||
static PLpgSQL_stmt *make_return_next_stmt(int lineno);
|
||||
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,
|
||||
PLpgSQL_datum *initial_datum);
|
||||
static PLpgSQL_row *make_scalar_list1(const char *initial_name,
|
||||
@ -120,9 +122,8 @@ static void check_labels(const char *start_label,
|
||||
%type <loop_body> loop_body
|
||||
%type <stmt> proc_stmt pl_block
|
||||
%type <stmt> stmt_assign stmt_if stmt_loop stmt_while stmt_exit
|
||||
%type <stmt> stmt_return stmt_raise stmt_execsql
|
||||
%type <stmt> stmt_for stmt_select stmt_perform
|
||||
%type <stmt> stmt_dynexecute stmt_getdiag
|
||||
%type <stmt> stmt_return stmt_raise stmt_execsql stmt_execsql_insert
|
||||
%type <stmt> stmt_dynexecute stmt_for stmt_perform stmt_getdiag
|
||||
%type <stmt> stmt_open stmt_fetch stmt_close stmt_null
|
||||
|
||||
%type <list> proc_exceptions
|
||||
@ -169,6 +170,7 @@ static void check_labels(const char *start_label,
|
||||
%token K_IF
|
||||
%token K_IN
|
||||
%token K_INFO
|
||||
%token K_INSERT
|
||||
%token K_INTO
|
||||
%token K_IS
|
||||
%token K_LOG
|
||||
@ -186,7 +188,6 @@ static void check_labels(const char *start_label,
|
||||
%token K_RESULT_OID
|
||||
%token K_RETURN
|
||||
%token K_REVERSE
|
||||
%token K_SELECT
|
||||
%token K_STRICT
|
||||
%token K_THEN
|
||||
%token K_TO
|
||||
@ -591,8 +592,6 @@ proc_stmt : pl_block ';'
|
||||
{ $$ = $1; }
|
||||
| stmt_for
|
||||
{ $$ = $1; }
|
||||
| stmt_select
|
||||
{ $$ = $1; }
|
||||
| stmt_exit
|
||||
{ $$ = $1; }
|
||||
| stmt_return
|
||||
@ -601,6 +600,8 @@ proc_stmt : pl_block ';'
|
||||
{ $$ = $1; }
|
||||
| stmt_execsql
|
||||
{ $$ = $1; }
|
||||
| stmt_execsql_insert
|
||||
{ $$ = $1; }
|
||||
| stmt_dynexecute
|
||||
{ $$ = $1; }
|
||||
| stmt_perform
|
||||
@ -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
|
||||
{
|
||||
PLpgSQL_stmt_exit *new;
|
||||
@ -1259,14 +1254,28 @@ loop_body : proc_sect K_END K_LOOP opt_label ';'
|
||||
|
||||
stmt_execsql : execsql_start lno
|
||||
{
|
||||
PLpgSQL_stmt_execsql *new;
|
||||
$$ = make_execsql_stmt($1, $2);
|
||||
}
|
||||
;
|
||||
|
||||
new = palloc(sizeof(PLpgSQL_stmt_execsql));
|
||||
new->cmd_type = PLPGSQL_STMT_EXECSQL;
|
||||
new->lineno = $2;
|
||||
new->sqlstmt = read_sql_stmt($1);
|
||||
/* this matches any otherwise-unrecognized starting keyword */
|
||||
execsql_start : T_WORD
|
||||
{ $$ = pstrdup(yytext); }
|
||||
| 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
|
||||
PLpgSQL_expr *expr;
|
||||
int endtoken;
|
||||
|
||||
expr = read_sql_construct(K_INTO, ';', "INTO|;", "SELECT ",
|
||||
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 = expr;
|
||||
new->lineno = $2;
|
||||
new->query = expr;
|
||||
new->into = false;
|
||||
new->strict = false;
|
||||
new->rec = NULL;
|
||||
new->row = NULL;
|
||||
|
||||
/*
|
||||
* If we saw "INTO", look for a following row
|
||||
* var, record var, or list of scalars.
|
||||
*/
|
||||
/* If we found "INTO", collect the argument */
|
||||
if (endtoken == K_INTO)
|
||||
{
|
||||
switch (yylex())
|
||||
{
|
||||
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.")));
|
||||
}
|
||||
new->into = true;
|
||||
read_into_target(&new->rec, &new->row, &new->strict);
|
||||
if (yylex() != ';')
|
||||
yyerror("syntax error");
|
||||
}
|
||||
@ -1502,12 +1489,6 @@ cursor_variable : T_SCALAR
|
||||
}
|
||||
;
|
||||
|
||||
execsql_start : T_WORD
|
||||
{ $$ = pstrdup(yytext); }
|
||||
| T_ERROR
|
||||
{ $$ = pstrdup(yytext); }
|
||||
;
|
||||
|
||||
exception_sect :
|
||||
{ $$ = NULL; }
|
||||
| K_EXCEPTION lno
|
||||
@ -1892,12 +1873,13 @@ read_datatype(int tok)
|
||||
}
|
||||
|
||||
static PLpgSQL_stmt *
|
||||
make_select_stmt(int lineno)
|
||||
make_execsql_stmt(const char *sqlstart, int lineno)
|
||||
{
|
||||
PLpgSQL_dstring ds;
|
||||
int nparams = 0;
|
||||
int params[MAX_EXPR_PARAMS];
|
||||
char buf[32];
|
||||
PLpgSQL_stmt_execsql *execsql;
|
||||
PLpgSQL_expr *expr;
|
||||
PLpgSQL_row *row = NULL;
|
||||
PLpgSQL_rec *rec = NULL;
|
||||
@ -1906,12 +1888,11 @@ make_select_stmt(int lineno)
|
||||
bool have_strict = false;
|
||||
|
||||
plpgsql_dstring_init(&ds);
|
||||
plpgsql_dstring_append(&ds, "SELECT ");
|
||||
plpgsql_dstring_append(&ds, sqlstart);
|
||||
|
||||
while (1)
|
||||
for (;;)
|
||||
{
|
||||
tok = yylex();
|
||||
|
||||
if (tok == ';')
|
||||
break;
|
||||
if (tok == 0)
|
||||
@ -1930,37 +1911,8 @@ make_select_stmt(int lineno)
|
||||
(errcode(ERRCODE_SYNTAX_ERROR),
|
||||
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;
|
||||
break;
|
||||
|
||||
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;
|
||||
}
|
||||
have_into = true;
|
||||
read_into_target(&rec, &row, &have_strict);
|
||||
continue;
|
||||
}
|
||||
|
||||
@ -2007,31 +1959,16 @@ make_select_stmt(int lineno)
|
||||
|
||||
check_sql_expr(expr->query);
|
||||
|
||||
if (have_into)
|
||||
{
|
||||
PLpgSQL_stmt_select *select;
|
||||
execsql = palloc(sizeof(PLpgSQL_stmt_execsql));
|
||||
execsql->cmd_type = PLPGSQL_STMT_EXECSQL;
|
||||
execsql->lineno = lineno;
|
||||
execsql->sqlstmt = expr;
|
||||
execsql->into = have_into;
|
||||
execsql->strict = have_strict;
|
||||
execsql->rec = rec;
|
||||
execsql->row = row;
|
||||
|
||||
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->cmd_type = PLPGSQL_STMT_EXECSQL;
|
||||
execsql->lineno = lineno;
|
||||
execsql->sqlstmt = expr;
|
||||
|
||||
return (PLpgSQL_stmt *)execsql;
|
||||
}
|
||||
return (PLpgSQL_stmt *) execsql;
|
||||
}
|
||||
|
||||
|
||||
@ -2039,38 +1976,12 @@ static PLpgSQL_stmt *
|
||||
make_fetch_stmt(int lineno, int curvar)
|
||||
{
|
||||
int tok;
|
||||
PLpgSQL_row *row = NULL;
|
||||
PLpgSQL_rec *rec = NULL;
|
||||
PLpgSQL_rec *rec;
|
||||
PLpgSQL_row *row;
|
||||
PLpgSQL_stmt_fetch *fetch;
|
||||
|
||||
/* We have already parsed everything through the INTO keyword */
|
||||
|
||||
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.")));
|
||||
}
|
||||
|
||||
read_into_target(&rec, &row, NULL);
|
||||
tok = yylex();
|
||||
if (tok != ';')
|
||||
yyerror("syntax error");
|
||||
@ -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
|
||||
* comma-separated scalar variables until we run out. Then construct
|
||||
|
@ -8,7 +8,7 @@
|
||||
*
|
||||
*
|
||||
* 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,
|
||||
PLpgSQL_stmt_fori *stmt);
|
||||
static int exec_stmt_fors(PLpgSQL_execstate *estate,
|
||||
PLpgSQL_stmt_fors *stmt);
|
||||
static int exec_stmt_select(PLpgSQL_execstate *estate,
|
||||
PLpgSQL_stmt_select *stmt);
|
||||
static int exec_stmt_open(PLpgSQL_execstate *estate,
|
||||
PLpgSQL_stmt_open *stmt);
|
||||
static int exec_stmt_fetch(PLpgSQL_execstate *estate,
|
||||
@ -1079,10 +1077,6 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
|
||||
rc = exec_stmt_fors(estate, (PLpgSQL_stmt_fors *) stmt);
|
||||
break;
|
||||
|
||||
case PLPGSQL_STMT_SELECT:
|
||||
rc = exec_stmt_select(estate, (PLpgSQL_stmt_select *) stmt);
|
||||
break;
|
||||
|
||||
case PLPGSQL_STMT_EXIT:
|
||||
rc = exec_stmt_exit(estate, (PLpgSQL_stmt_exit *) stmt);
|
||||
break;
|
||||
@ -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
|
||||
*
|
||||
@ -2296,8 +2215,7 @@ exec_prepare_plan(PLpgSQL_execstate *estate,
|
||||
|
||||
|
||||
/* ----------
|
||||
* exec_stmt_execsql Execute an SQL statement not
|
||||
* returning any data.
|
||||
* exec_stmt_execsql Execute an SQL statement (possibly with INTO).
|
||||
* ----------
|
||||
*/
|
||||
static int
|
||||
@ -2307,14 +2225,41 @@ exec_stmt_execsql(PLpgSQL_execstate *estate,
|
||||
int i;
|
||||
Datum *values;
|
||||
char *nulls;
|
||||
long tcount;
|
||||
int rc;
|
||||
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)
|
||||
{
|
||||
_SPI_plan *spi_plan;
|
||||
ListCell *l;
|
||||
|
||||
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()
|
||||
@ -2336,50 +2281,135 @@ exec_stmt_execsql(PLpgSQL_execstate *estate,
|
||||
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
|
||||
*/
|
||||
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)
|
||||
{
|
||||
case SPI_OK_UTILITY:
|
||||
case SPI_OK_SELINTO:
|
||||
break;
|
||||
|
||||
case SPI_OK_INSERT:
|
||||
case SPI_OK_DELETE:
|
||||
case SPI_OK_UPDATE:
|
||||
|
||||
/*
|
||||
* If the INSERT, DELETE, or UPDATE query affected at least one
|
||||
* tuple, set the magic 'FOUND' variable to true. This conforms
|
||||
* with the behavior of PL/SQL.
|
||||
*/
|
||||
case SPI_OK_SELECT:
|
||||
Assert(!stmt->mod_stmt);
|
||||
exec_set_found(estate, (SPI_processed != 0));
|
||||
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.")));
|
||||
case SPI_OK_INSERT:
|
||||
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);
|
||||
/*
|
||||
* 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;
|
||||
|
||||
default:
|
||||
elog(ERROR, "SPI_execute_plan failed executing query \"%s\": %s",
|
||||
expr->query, SPI_result_code_string(rc));
|
||||
}
|
||||
|
||||
/*
|
||||
* Release any result tuples from SPI_execute_plan (probably shouldn't be
|
||||
* any)
|
||||
*/
|
||||
SPI_freetuptable(SPI_tuptable);
|
||||
|
||||
/* Save result info for GET DIAGNOSTICS */
|
||||
/* 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");
|
||||
|
||||
/*
|
||||
* 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 || 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);
|
||||
}
|
||||
|
||||
/* Clean up */
|
||||
SPI_freetuptable(SPI_tuptable);
|
||||
}
|
||||
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(nulls);
|
||||
|
||||
@ -2388,8 +2418,8 @@ exec_stmt_execsql(PLpgSQL_execstate *estate,
|
||||
|
||||
|
||||
/* ----------
|
||||
* exec_stmt_dynexecute Execute a dynamic SQL query not
|
||||
* returning any data.
|
||||
* exec_stmt_dynexecute Execute a dynamic SQL query
|
||||
* (possibly with INTO).
|
||||
* ----------
|
||||
*/
|
||||
static int
|
||||
@ -2401,17 +2431,10 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate,
|
||||
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. It's
|
||||
* result is the querystring we have to execute.
|
||||
* First we evaluate the string expression after the EXECUTE keyword.
|
||||
* Its result is the querystring we have to execute.
|
||||
*/
|
||||
query = exec_eval_expr(estate, stmt->query, &isnull, &restype);
|
||||
if (isnull)
|
||||
@ -2425,36 +2448,26 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate,
|
||||
exec_eval_cleanup(estate);
|
||||
|
||||
/*
|
||||
* 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 unless an INTO clause is specified.
|
||||
* Call SPI_execute() without preparing a saved plan.
|
||||
*/
|
||||
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:
|
||||
case SPI_OK_INSERT:
|
||||
case SPI_OK_UPDATE:
|
||||
case SPI_OK_DELETE:
|
||||
break;
|
||||
|
||||
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;
|
||||
|
||||
case 0:
|
||||
@ -2511,14 +2524,69 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate,
|
||||
break;
|
||||
}
|
||||
|
||||
/* Release any result from SPI_execute, as well as the querystring */
|
||||
SPI_freetuptable(SPI_tuptable);
|
||||
pfree(querystr);
|
||||
|
||||
/* 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");
|
||||
|
||||
/*
|
||||
* 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;
|
||||
}
|
||||
|
||||
@ -2823,12 +2891,12 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt)
|
||||
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
|
||||
* internal row.
|
||||
* ----------
|
||||
*/
|
||||
PLpgSQL_stmt_select set_args;
|
||||
PLpgSQL_stmt_execsql set_args;
|
||||
|
||||
if (curvar->cursor_explicit_argrow < 0)
|
||||
ereport(ERROR,
|
||||
@ -2836,13 +2904,15 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt)
|
||||
errmsg("arguments given for cursor without arguments")));
|
||||
|
||||
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.sqlstmt = stmt->argquery;
|
||||
set_args.into = true;
|
||||
/* XXX historically this has not been STRICT */
|
||||
set_args.row = (PLpgSQL_row *)
|
||||
(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");
|
||||
}
|
||||
else
|
||||
|
@ -8,7 +8,7 @@
|
||||
*
|
||||
*
|
||||
* 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)
|
||||
return "for with integer loopvar";
|
||||
case PLPGSQL_STMT_FORS:
|
||||
return "for over select rows";
|
||||
case PLPGSQL_STMT_SELECT:
|
||||
return "select into variables";
|
||||
case PLPGSQL_STMT_EXIT:
|
||||
return "exit";
|
||||
case PLPGSQL_STMT_RETURN:
|
||||
@ -485,7 +483,6 @@ static void dump_loop(PLpgSQL_stmt_loop *stmt);
|
||||
static void dump_while(PLpgSQL_stmt_while *stmt);
|
||||
static void dump_fori(PLpgSQL_stmt_fori *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_return(PLpgSQL_stmt_return *stmt);
|
||||
static void dump_return_next(PLpgSQL_stmt_return_next *stmt);
|
||||
@ -537,9 +534,6 @@ dump_stmt(PLpgSQL_stmt *stmt)
|
||||
case PLPGSQL_STMT_FORS:
|
||||
dump_fors((PLpgSQL_stmt_fors *) stmt);
|
||||
break;
|
||||
case PLPGSQL_STMT_SELECT:
|
||||
dump_select((PLpgSQL_stmt_select *) stmt);
|
||||
break;
|
||||
case PLPGSQL_STMT_EXIT:
|
||||
dump_exit((PLpgSQL_stmt_exit *) stmt);
|
||||
break;
|
||||
@ -731,29 +725,6 @@ dump_fors(PLpgSQL_stmt_fors *stmt)
|
||||
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
|
||||
dump_open(PLpgSQL_stmt_open *stmt)
|
||||
{
|
||||
@ -891,6 +862,23 @@ dump_execsql(PLpgSQL_stmt_execsql *stmt)
|
||||
printf("EXECSQL ");
|
||||
dump_expr(stmt->sqlstmt);
|
||||
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
|
||||
@ -905,12 +893,16 @@ dump_dynexecute(PLpgSQL_stmt_dynexecute *stmt)
|
||||
if (stmt->rec != NULL)
|
||||
{
|
||||
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();
|
||||
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;
|
||||
}
|
||||
|
@ -8,7 +8,7 @@
|
||||
*
|
||||
*
|
||||
* 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
|
||||
PLPGSQL_STMT_WHILE,
|
||||
PLPGSQL_STMT_FORI,
|
||||
PLPGSQL_STMT_FORS,
|
||||
PLPGSQL_STMT_SELECT,
|
||||
PLPGSQL_STMT_EXIT,
|
||||
PLPGSQL_STMT_RETURN,
|
||||
PLPGSQL_STMT_RETURN_NEXT,
|
||||
@ -428,17 +427,6 @@ typedef struct
|
||||
} 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
|
||||
{ /* OPEN a curvar */
|
||||
int cmd_type;
|
||||
@ -510,6 +498,12 @@ typedef struct
|
||||
int cmd_type;
|
||||
int lineno;
|
||||
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;
|
||||
|
||||
|
||||
@ -517,9 +511,11 @@ typedef struct
|
||||
{ /* 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_expr *query; /* string expression */
|
||||
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_dynexecute;
|
||||
|
||||
|
||||
|
@ -9,7 +9,7 @@
|
||||
*
|
||||
*
|
||||
* 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; }
|
||||
if { return K_IF; }
|
||||
in { return K_IN; }
|
||||
info { return K_INFO; }
|
||||
insert { return K_INSERT; }
|
||||
into { return K_INTO; }
|
||||
is { return K_IS; }
|
||||
log { return K_LOG; }
|
||||
@ -154,7 +155,6 @@ result_oid { return K_RESULT_OID; }
|
||||
return { return K_RETURN; }
|
||||
reverse { return K_REVERSE; }
|
||||
row_count { return K_ROW_COUNT; }
|
||||
select { return K_SELECT; }
|
||||
strict { return K_STRICT; }
|
||||
then { return K_THEN; }
|
||||
to { return K_TO; }
|
||||
|
@ -2048,6 +2048,7 @@ select * from foo;
|
||||
20
|
||||
(2 rows)
|
||||
|
||||
drop table foo;
|
||||
-- Test for pass-by-ref values being stored in proper context
|
||||
create function test_variable_storage() returns text as $$
|
||||
declare x text;
|
||||
@ -2794,3 +2795,142 @@ select multi_datum_use(42);
|
||||
t
|
||||
(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;
|
||||
|
||||
select * from foo;
|
||||
|
||||
drop table foo;
|
||||
|
||||
-- Test for pass-by-ref values being stored in proper context
|
||||
create function test_variable_storage() returns text as $$
|
||||
declare x text;
|
||||
@ -2324,3 +2326,117 @@ begin
|
||||
end$$ language plpgsql;
|
||||
|
||||
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();
|
||||
|
Loading…
Reference in New Issue
Block a user