aboutsummaryrefslogtreecommitdiff
diff options
context:
space:
mode:
authorTom Lane <tgl@sss.pgh.pa.us>2008-04-06 23:43:29 +0000
committerTom Lane <tgl@sss.pgh.pa.us>2008-04-06 23:43:29 +0000
commit347dd6a1cf4ea78e37982ade15496b454c54cf4c (patch)
treeee44f4a10b60477856fc22217ff6c0eb560cd8bd
parent2604359251d34177a14ef58250d8b4a51d83103b (diff)
downloadpostgresql-347dd6a1cf4ea78e37982ade15496b454c54cf4c.tar.gz
postgresql-347dd6a1cf4ea78e37982ade15496b454c54cf4c.zip
Make plpgsql support FOR over a query specified by a cursor declaration,
for improved compatibility with Oracle. Pavel Stehule, with some fixes by me.
-rw-r--r--doc/src/sgml/plpgsql.sgml273
-rw-r--r--src/pl/plpgsql/src/gram.y233
-rw-r--r--src/pl/plpgsql/src/pl_comp.c57
-rw-r--r--src/pl/plpgsql/src/pl_exec.c667
-rw-r--r--src/pl/plpgsql/src/pl_funcs.c31
-rw-r--r--src/pl/plpgsql/src/plpgsql.h38
-rw-r--r--src/test/regress/expected/plpgsql.out116
-rw-r--r--src/test/regress/sql/plpgsql.sql74
8 files changed, 934 insertions, 555 deletions
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml
index 512cb7657ce..8eac671fabf 100644
--- a/doc/src/sgml/plpgsql.sgml
+++ b/doc/src/sgml/plpgsql.sgml
@@ -1,6 +1,6 @@
-<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.126 2008/04/01 03:51:09 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.127 2008/04/06 23:43:29 tgl Exp $ -->
-<chapter id="plpgsql">
+<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
<indexterm zone="plpgsql">
@@ -195,7 +195,7 @@ END <optional> <replaceable>label</replaceable> </optional>;
<para>
A <replaceable>label</replaceable> is only needed if you want to
- identify the block for use
+ identify the block for use
in an <literal>EXIT</> statement, or to qualify the names of the
variables declared in the block. If a label is given after
<literal>END</>, it must match the label at the block's beginning.
@@ -285,10 +285,12 @@ $$ LANGUAGE plpgsql;
<para>
All variables used in a block must be declared in the
- declarations section of the block.
- (The only exception is that the loop variable of a <literal>FOR</> loop
+ declarations section of the block.
+ (The only exceptions are that the loop variable of a <literal>FOR</> loop
iterating over a range of integer values is automatically declared as an
- integer variable.)
+ integer variable, and likewise the loop variable of a <literal>FOR</> loop
+ iterating over a cursor's result is automatically declared as a
+ record variable.)
</para>
<para>
@@ -317,7 +319,7 @@ arow RECORD;
The <literal>DEFAULT</> clause, if given, specifies the initial value assigned
to the variable when the block is entered. If the <literal>DEFAULT</> clause
is not given then the variable is initialized to the
- <acronym>SQL</acronym> null value.
+ <acronym>SQL</acronym> null value.
The <literal>CONSTANT</> option prevents the variable from being assigned to,
so that its value remains constant for the duration of the block.
If <literal>NOT NULL</>
@@ -750,7 +752,7 @@ PREPARE <replaceable>statement_name</>(integer, integer) AS SELECT $1 &lt; $2;
data type, or the variable has a specific size/precision
(like <type>char(20)</type>), the result value will be implicitly
converted by the <application>PL/pgSQL</application> interpreter using
- the result type's output-function and
+ the result type's output-function and
the variable type's input-function. Note that this could potentially
result in run-time errors generated by the input function, if the
string form of the result value is not acceptable to the input function.
@@ -1049,7 +1051,7 @@ EXECUTE <replaceable class="command">command-string</replaceable> <optional> INT
If the <literal>STRICT</> option is given, an error is reported
unless the query produces exactly one row.
</para>
-
+
<para>
The command string can use parameter values, which are referenced
in the command as <literal>$1</>, <literal>$2</>, etc.
@@ -1082,8 +1084,8 @@ EXECUTE 'SELECT count(*) FROM '
<para>
An <command>EXECUTE</> with a simple constant command string and some
<literal>USING</> parameters, as in the first example above, is
- functionally equivalent to just writing the command directly in
- <application>PL/pgSQL</application> and allowing replacement of
+ functionally equivalent to just writing the command directly in
+ <application>PL/pgSQL</application> and allowing replacement of
<application>PL/pgSQL</application> variables to happen automatically.
The important difference is that <command>EXECUTE</> will re-plan
the command on each execution, generating a plan that is specific
@@ -1198,7 +1200,7 @@ EXECUTE 'UPDATE tbl SET '
not deliver unintended results. For example the <literal>WHERE</> clause
<programlisting>
'WHERE key = ' || quote_nullable(keyvalue)
-</programlisting>
+</programlisting>
will never succeed if <literal>keyvalue</> is null, because the
result of using the equality operator <literal>=</> with a null operand
is always null. If you wish null to work like an ordinary key value,
@@ -1281,50 +1283,51 @@ GET DIAGNOSTICS integer_var = ROW_COUNT;
<itemizedlist>
<listitem>
<para>
- A <command>SELECT INTO</command> statement sets
- <literal>FOUND</literal> true if a row is assigned, false if no
- row is returned.
+ A <command>SELECT INTO</command> statement sets
+ <literal>FOUND</literal> true if a row is assigned, false if no
+ row is returned.
</para>
</listitem>
<listitem>
<para>
- A <command>PERFORM</> statement sets <literal>FOUND</literal>
- true if it produces (and discards) one or more rows, false if
- no row is produced.
+ A <command>PERFORM</> statement sets <literal>FOUND</literal>
+ true if it produces (and discards) one or more rows, false if
+ no row is produced.
</para>
</listitem>
<listitem>
<para>
- <command>UPDATE</>, <command>INSERT</>, and <command>DELETE</>
- statements set <literal>FOUND</literal> true if at least one
- row is affected, false if no row is affected.
+ <command>UPDATE</>, <command>INSERT</>, and <command>DELETE</>
+ statements set <literal>FOUND</literal> true if at least one
+ row is affected, false if no row is affected.
</para>
</listitem>
<listitem>
<para>
- A <command>FETCH</> statement sets <literal>FOUND</literal>
- true if it returns a row, false if no row is returned.
+ A <command>FETCH</> statement sets <literal>FOUND</literal>
+ true if it returns a row, false if no row is returned.
</para>
</listitem>
<listitem>
<para>
- A <command>MOVE</> statement sets <literal>FOUND</literal>
- true if it successfully repositions the cursor, false otherwise.
+ A <command>MOVE</> statement sets <literal>FOUND</literal>
+ true if it successfully repositions the cursor, false otherwise.
</para>
</listitem>
<listitem>
<para>
- A <command>FOR</> statement sets <literal>FOUND</literal> true
- if it iterates one or more times, else false. This applies to
- all three variants of the <command>FOR</> statement (integer
- <command>FOR</> loops, record-set <command>FOR</> loops, and
- dynamic record-set <command>FOR</>
- loops). <literal>FOUND</literal> is set this way when the
- <command>FOR</> loop exits; inside the execution of the loop,
- <literal>FOUND</literal> is not modified by the
- <command>FOR</> statement, although it might be changed by the
- execution of other statements within the loop body.
+ A <command>FOR</> statement sets <literal>FOUND</literal> true
+ if it iterates one or more times, else false. This applies to
+ all four variants of the <command>FOR</> statement (integer
+ <command>FOR</> loops, record-set <command>FOR</> loops,
+ dynamic record-set <command>FOR</> loops, and cursor
+ <command>FOR</> loops).
+ <literal>FOUND</literal> is set this way when the
+ <command>FOR</> loop exits; inside the execution of the loop,
+ <literal>FOUND</literal> is not modified by the
+ <command>FOR</> statement, although it might be changed by the
+ execution of other statements within the loop body.
</para>
</listitem>
</itemizedlist>
@@ -1391,7 +1394,7 @@ NULL;
important) part of <application>PL/pgSQL</>. With
<application>PL/pgSQL</>'s control structures,
you can manipulate <productname>PostgreSQL</> data in a very
- flexible and powerful way.
+ flexible and powerful way.
</para>
<sect2 id="plpgsql-statements-returning">
@@ -1649,7 +1652,7 @@ END IF;
</programlisting>
<programlisting>
-IF v_count &gt; 0 THEN
+IF v_count &gt; 0 THEN
INSERT INTO users_count (count) VALUES (v_count);
RETURN 't';
ELSE
@@ -1721,7 +1724,7 @@ END IF;
<programlisting>
IF number = 0 THEN
result := 'zero';
-ELSIF number &gt; 0 THEN
+ELSIF number &gt; 0 THEN
result := 'positive';
ELSIF number &lt; 0 THEN
result := 'negative';
@@ -1879,7 +1882,7 @@ LOOP
-- some computations
EXIT WHEN count &gt; 100;
CONTINUE WHEN count &lt; 50;
- -- some computations for count IN [50 .. 100]
+ -- some computations for count IN [50 .. 100]
END LOOP;
</programlisting>
</para>
@@ -1935,16 +1938,16 @@ END LOOP <optional> <replaceable>label</replaceable> </optional>;
<para>
This form of <literal>FOR</> creates a loop that iterates over a range
- of integer values. The variable
+ of integer values. The variable
<replaceable>name</replaceable> is automatically defined as type
<type>integer</> and exists only inside the loop (any existing
definition of the variable name is ignored within the loop).
The two expressions giving
the lower and upper bound of the range are evaluated once when entering
- the loop. If the <literal>BY</> clause isn't specified the iteration
- step is 1, otherwise it's the value specified in the <literal>BY</>
+ the loop. If the <literal>BY</> clause isn't specified the iteration
+ step is 1, otherwise it's the value specified in the <literal>BY</>
clause, which again is evaluated once on loop entry.
- If <literal>REVERSE</> is specified then the step value is
+ If <literal>REVERSE</> is specified then the step value is
subtracted, rather than added, after each iteration.
</para>
@@ -2045,7 +2048,7 @@ $$ LANGUAGE plpgsql;
rows:
<synopsis>
<optional> &lt;&lt;<replaceable>label</replaceable>&gt;&gt; </optional>
-FOR <replaceable>target</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional> LOOP
+FOR <replaceable>target</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional> LOOP
<replaceable>statements</replaceable>
END LOOP <optional> <replaceable>label</replaceable> </optional>;
</synopsis>
@@ -2057,6 +2060,12 @@ END LOOP <optional> <replaceable>label</replaceable> </optional>;
As with <command>EXECUTE</command>, parameter values can be inserted
into the dynamic command via <literal>USING</>.
</para>
+
+ <para>
+ Another way to specify the query whose results should be iterated
+ through is to declare it as a cursor. This is described in
+ <xref linkend="plpgsql-cursor-for-loop">.
+ </para>
</sect2>
<sect2 id="plpgsql-error-trapping">
@@ -2293,6 +2302,14 @@ DECLARE
cursor variables while the third uses a bound cursor variable.
</para>
+ <note>
+ <para>
+ Bound cursors can also be used without explicitly opening them,
+ via the <command>FOR</> statement described in
+ <xref linkend="plpgsql-cursor-for-loop">.
+ </para>
+ </note>
+
<sect3>
<title><command>OPEN FOR</command> <replaceable>query</replaceable></title>
@@ -2640,7 +2657,7 @@ END;
BEGIN;
SELECT reffunc2();
- reffunc2
+ reffunc2
--------------------
&lt;unnamed cursor 1&gt;
(1 row)
@@ -2676,6 +2693,36 @@ COMMIT;
</para>
</sect3>
</sect2>
+
+ <sect2 id="plpgsql-cursor-for-loop">
+ <title>Looping Through a Cursor's Result</title>
+
+ <para>
+ There is a variant of the <command>FOR</> statement that allows
+ iterating through the rows returned by a cursor. The syntax is:
+
+<synopsis>
+<optional> &lt;&lt;<replaceable>label</replaceable>&gt;&gt; </optional>
+FOR <replaceable>recordvar</replaceable> IN <replaceable>bound_cursor</replaceable> <optional> ( <replaceable>argument_values</replaceable> ) </optional> LOOP
+ <replaceable>statements</replaceable>
+END LOOP <optional> <replaceable>label</replaceable> </optional>;
+</synopsis>
+
+ The cursor variable must have been bound to some query when it was
+ declared, and it <emphasis>cannot</> be open already. The
+ <command>FOR</> statement automatically opens the cursor, and it closes
+ the cursor again when the loop exits. A list of actual argument value
+ expressions must appear if and only if the cursor was declared to take
+ arguments. These values will be substituted in the query, in just
+ the same way as during an <command>OPEN</>.
+ The variable <replaceable>recordvar</replaceable> is automatically
+ defined as type <type>record</> and exists only inside the loop (any
+ existing definition of the variable name is ignored within the loop).
+ Each row returned by the cursor is successively assigned to this
+ record variable and the loop body is executed.
+ </para>
+ </sect2>
+
</sect1>
<sect1 id="plpgsql-errors-and-messages">
@@ -2716,8 +2763,8 @@ RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="pa
<para>
Inside the format string, <literal>%</literal> is replaced by the
next optional argument's string representation. Write
- <literal>%%</literal> to emit a literal <literal>%</literal>.
- Arguments can be simple variables or expressions,
+ <literal>%%</literal> to emit a literal <literal>%</literal>.
+ Arguments can be simple variables or expressions,
but the format must be a simple string literal.
</para>
@@ -2772,7 +2819,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<para>
When a <application>PL/pgSQL</application> function is called as a
- trigger, several special variables are created automatically in the
+ trigger, several special variables are created automatically in the
top-level block. They are:
<variablelist>
@@ -2812,7 +2859,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<term><varname>TG_WHEN</varname></term>
<listitem>
<para>
- Data type <type>text</type>; a string of either
+ Data type <type>text</type>; a string of either
<literal>BEFORE</literal> or <literal>AFTER</literal>
depending on the trigger's definition.
</para>
@@ -2857,7 +2904,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<listitem>
<para>
Data type <type>name</type>; the name of the table that caused the trigger
- invocation. This is now deprecated, and could disappear in a future
+ invocation. This is now deprecated, and could disappear in a future
release. Use <literal>TG_TABLE_NAME</> instead.
</para>
</listitem>
@@ -2867,7 +2914,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<term><varname>TG_TABLE_NAME</varname></term>
<listitem>
<para>
- Data type <type>name</type>; the name of the table that
+ Data type <type>name</type>; the name of the table that
caused the trigger invocation.
</para>
</listitem>
@@ -2877,7 +2924,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<term><varname>TG_TABLE_SCHEMA</varname></term>
<listitem>
<para>
- Data type <type>name</type>; the name of the schema of the
+ Data type <type>name</type>; the name of the schema of the
table that caused the trigger invocation.
</para>
</listitem>
@@ -2918,7 +2965,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
trigger manager to skip the rest of the operation for this row
(i.e., subsequent triggers are not fired, and the
<command>INSERT</>/<command>UPDATE</>/<command>DELETE</> does not occur
- for this row). If a nonnull
+ for this row). If a nonnull
value is returned then the operation proceeds with that row value.
Returning a row value different from the original value
of <varname>NEW</> alters the row that will be inserted or updated
@@ -2998,8 +3045,8 @@ CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
<para>
This example trigger ensures that any insert, update or delete of a row
- in the <literal>emp</literal> table is recorded (i.e., audited) in the <literal>emp_audit</literal> table.
- The current time and user name are stamped into the row, together with
+ in the <literal>emp</literal> table is recorded (i.e., audited) in the <literal>emp_audit</literal> table.
+ The current time and user name are stamped into the row, together with
the type of operation performed on it.
</para>
@@ -3009,7 +3056,7 @@ CREATE TABLE emp (
salary integer
);
-CREATE TABLE emp_audit(
+CREATE TABLE emp_audit(
operation char(1) NOT NULL,
stamp timestamp NOT NULL,
userid text NOT NULL,
@@ -3045,8 +3092,8 @@ AFTER INSERT OR UPDATE OR DELETE ON emp
<para>
One use of triggers is to maintain a summary table
- of another table. The resulting summary can be used in place of the
- original table for certain queries &mdash; often with vastly reduced run
+ of another table. The resulting summary can be used in place of the
+ original table for certain queries &mdash; often with vastly reduced run
times.
This technique is commonly used in Data Warehousing, where the tables
of measured or observed data (called fact tables) might be extremely large.
@@ -3061,7 +3108,7 @@ AFTER INSERT OR UPDATE OR DELETE ON emp
<para>
The schema detailed here is partly based on the <emphasis>Grocery Store
- </emphasis> example from <emphasis>The Data Warehouse Toolkit</emphasis>
+ </emphasis> example from <emphasis>The Data Warehouse Toolkit</emphasis>
by Ralph Kimball.
</para>
@@ -3122,7 +3169,7 @@ CREATE OR REPLACE FUNCTION maint_sales_summary_bytime() RETURNS TRIGGER AS $main
ELSIF (TG_OP = 'UPDATE') THEN
-- forbid updates that change the time_key -
- -- (probably not too onerous, as DELETE + INSERT is how most
+ -- (probably not too onerous, as DELETE + INSERT is how most
-- changes will be made).
IF ( OLD.time_key != NEW.time_key) THEN
RAISE EXCEPTION 'Update of time_key : % -&gt; % not allowed', OLD.time_key, NEW.time_key;
@@ -3152,15 +3199,15 @@ CREATE OR REPLACE FUNCTION maint_sales_summary_bytime() RETURNS TRIGGER AS $main
amount_cost = amount_cost + delta_amount_cost
WHERE time_key = delta_time_key;
- EXIT insert_update WHEN found;
+ EXIT insert_update WHEN found;
BEGIN
INSERT INTO sales_summary_bytime (
- time_key,
- amount_sold,
- units_sold,
+ time_key,
+ amount_sold,
+ units_sold,
amount_cost)
- VALUES (
+ VALUES (
delta_time_key,
delta_amount_sold,
delta_units_sold,
@@ -3357,7 +3404,7 @@ CONTEXT: SQL statement in PL/PgSQL function "logfunc2" near line 5
The <application>PL/pgSQL</> interpreter parses the function's source
text and produces an internal binary instruction tree the first time the
function is called (within each session). The instruction tree
- fully translates the
+ fully translates the
<application>PL/pgSQL</> statement structure, but individual
<acronym>SQL</acronym> expressions and <acronym>SQL</acronym> commands
used in the function are not translated immediately.
@@ -3410,7 +3457,7 @@ $$ LANGUAGE plpgsql;
start a new database session so that <function>populate()</function>
will be compiled afresh, before it will work again. You can avoid
this problem by using <command>CREATE OR REPLACE FUNCTION</command>
- when updating the definition of
+ when updating the definition of
<function>my_function</function>, since when a function is
<quote>replaced</quote>, its OID is not changed.
</para>
@@ -3527,10 +3574,10 @@ $$ LANGUAGE plpgsql;
</para>
<para>
- In the case of <function>logfunc2</function>, the
+ In the case of <function>logfunc2</function>, the
<productname>PostgreSQL</productname> main parser does not know
- what type <literal>'now'</literal> should become and therefore
- it returns a data value of type <type>text</type> containing the string
+ what type <literal>'now'</literal> should become and therefore
+ it returns a data value of type <type>text</type> containing the string
<literal>now</literal>. During the ensuing assignment
to the local variable <varname>curtime</varname>, the
<application>PL/pgSQL</application> interpreter casts this
@@ -3710,11 +3757,11 @@ a_output := a_output || $$ AND name LIKE 'foobar'$$
<xref linkend="plpgsql-porting-ex2">.
For example:
<programlisting>
-a_output := a_output || '' if v_'' ||
- referrer_keys.kind || '' like ''''''''''
- || referrer_keys.key_string || ''''''''''
- then return '''''' || referrer_keys.referrer_type
- || ''''''; end if;'';
+a_output := a_output || '' if v_'' ||
+ referrer_keys.kind || '' like ''''''''''
+ || referrer_keys.key_string || ''''''''''
+ then return '''''' || referrer_keys.referrer_type
+ || ''''''; end if;'';
</programlisting>
The value of <literal>a_output</literal> would then be:
<programlisting>
@@ -3726,8 +3773,8 @@ if v_... like ''...'' then return ''...''; end if;
<programlisting>
a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
|| referrer_keys.key_string || $$'
- then return '$$ || referrer_keys.referrer_type
- || $$'; end if;$$;
+ then return '$$ || referrer_keys.referrer_type
+ || $$'; end if;$$;
</programlisting>
where we assume we only need to put single quote marks into
<literal>a_output</literal>, because it will be re-quoted before use.
@@ -3798,14 +3845,6 @@ a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
<listitem>
<para>
- No need for cursors in <application>PL/pgSQL</>, just put the
- query in the <literal>FOR</literal> statement. (See <xref
- linkend="plpgsql-porting-ex2">.)
- </para>
- </listitem>
-
- <listitem>
- <para>
In <productname>PostgreSQL</> the function body must be written as
a string literal. Therefore you need to use dollar quoting or escape
single quotes in the function body. (See <xref
@@ -3823,7 +3862,7 @@ a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
<listitem>
<para>
Since there are no packages, there are no package-level variables
- either. This is somewhat annoying. You can keep per-session state
+ either. This is somewhat annoying. You can keep per-session state
in temporary tables instead.
</para>
</listitem>
@@ -3840,6 +3879,23 @@ a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
</para>
</listitem>
+ <listitem>
+ <para>
+ <command>FOR</> loops over queries (other than cursors) also work
+ differently: the target variable(s) must have been declared,
+ whereas <application>PL/SQL</> always declares them implicitly.
+ An advantage of this is that the variable values are still accessible
+ after the loop exits.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ There are various notational differences for the use of cursor
+ variables.
+ </para>
+ </listitem>
+
</itemizedlist>
</para>
@@ -3939,36 +3995,34 @@ $$ LANGUAGE plpgsql;
The following procedure grabs rows from a
<command>SELECT</command> statement and builds a large function
with the results in <literal>IF</literal> statements, for the
- sake of efficiency. Notice particularly the differences in the
- cursor and the <literal>FOR</literal> loop.
+ sake of efficiency.
</para>
<para>
This is the Oracle version:
<programlisting>
CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc IS
- CURSOR referrer_keys IS
- SELECT * FROM cs_referrer_keys
+ CURSOR referrer_keys IS
+ SELECT * FROM cs_referrer_keys
ORDER BY try_order;
-
- func_cmd VARCHAR(4000);
-BEGIN
+ func_cmd VARCHAR(4000);
+BEGIN
func_cmd := 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host IN VARCHAR,
- v_domain IN VARCHAR, v_url IN VARCHAR) RETURN VARCHAR IS BEGIN';
+ v_domain IN VARCHAR, v_url IN VARCHAR) RETURN VARCHAR IS BEGIN';
- FOR referrer_key IN referrer_keys LOOP
+ FOR referrer_key IN referrer_keys LOOP
func_cmd := func_cmd ||
' IF v_' || referrer_key.kind
|| ' LIKE ''' || referrer_key.key_string
|| ''' THEN RETURN ''' || referrer_key.referrer_type
- || '''; END IF;';
- END LOOP;
+ || '''; END IF;';
+ END LOOP;
- func_cmd := func_cmd || ' RETURN NULL; END;';
+ func_cmd := func_cmd || ' RETURN NULL; END;';
- EXECUTE IMMEDIATE func_cmd;
-END;
-/
+ EXECUTE IMMEDIATE func_cmd;
+END;
+/
show errors;
</programlisting>
</para>
@@ -3978,29 +4032,28 @@ show errors;
<programlisting>
CREATE OR REPLACE FUNCTION cs_update_referrer_type_proc() RETURNS void AS $func$
DECLARE
- referrer_key RECORD; -- declare a generic record to be used in a FOR
+ CURSOR referrer_keys IS
+ SELECT * FROM cs_referrer_keys
+ ORDER BY try_order;
func_body text;
func_cmd text;
-BEGIN
+BEGIN
func_body := 'BEGIN';
- -- Notice how we scan through the results of a query in a FOR loop
- -- using the FOR &lt;record&gt; construct.
-
- FOR referrer_key IN SELECT * FROM cs_referrer_keys ORDER BY try_order LOOP
+ FOR referrer_key IN referrer_keys LOOP
func_body := func_body ||
' IF v_' || referrer_key.kind
|| ' LIKE ' || quote_literal(referrer_key.key_string)
|| ' THEN RETURN ' || quote_literal(referrer_key.referrer_type)
|| '; END IF;' ;
- END LOOP;
+ END LOOP;
func_body := func_body || ' RETURN NULL; END;';
func_cmd :=
'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host varchar,
v_domain varchar,
- v_url varchar)
+ v_url varchar)
RETURNS varchar AS '
|| quote_literal(func_body)
|| ' LANGUAGE plpgsql;' ;
@@ -4364,7 +4417,7 @@ $$ LANGUAGE plpgsql STRICT IMMUTABLE;
--
-- instr functions that mimic Oracle's counterpart
-- Syntax: instr(string1, string2, [n], [m]) where [] denotes optional parameters.
---
+--
-- Searches string1 beginning at the nth character for the mth occurrence
-- of string2. If n is negative, search backwards. If m is not passed,
-- assume 1 (search starts at first character).
diff --git a/src/pl/plpgsql/src/gram.y b/src/pl/plpgsql/src/gram.y
index f8b7dd4291c..495b625a450 100644
--- a/src/pl/plpgsql/src/gram.y
+++ b/src/pl/plpgsql/src/gram.y
@@ -9,7 +9,7 @@
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.109 2008/04/01 03:51:09 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.110 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@@ -50,6 +50,8 @@ static void plpgsql_sql_error_callback(void *arg);
static char *check_label(const char *yytxt);
static void check_labels(const char *start_label,
const char *end_label);
+static PLpgSQL_expr *read_cursor_args(PLpgSQL_var *cursor,
+ int until, const char *expected);
%}
@@ -861,21 +863,15 @@ stmt_for : opt_block_label K_FOR for_control loop_body
new->body = $4.stmts;
$$ = (PLpgSQL_stmt *) new;
}
- else if ($3->cmd_type == PLPGSQL_STMT_FORS)
- {
- PLpgSQL_stmt_fors *new;
-
- new = (PLpgSQL_stmt_fors *) $3;
- new->label = $1;
- new->body = $4.stmts;
- $$ = (PLpgSQL_stmt *) new;
- }
else
{
- PLpgSQL_stmt_dynfors *new;
+ PLpgSQL_stmt_forq *new;
- Assert($3->cmd_type == PLPGSQL_STMT_DYNFORS);
- new = (PLpgSQL_stmt_dynfors *) $3;
+ Assert($3->cmd_type == PLPGSQL_STMT_FORS ||
+ $3->cmd_type == PLPGSQL_STMT_FORC ||
+ $3->cmd_type == PLPGSQL_STMT_DYNFORS);
+ /* forq is the common supertype of all three */
+ new = (PLpgSQL_stmt_forq *) $3;
new->label = $1;
new->body = $4.stmts;
$$ = (PLpgSQL_stmt *) new;
@@ -892,9 +888,9 @@ for_control :
{
int tok = yylex();
- /* Simple case: EXECUTE is a dynamic FOR loop */
if (tok == K_EXECUTE)
{
+ /* EXECUTE means it's a dynamic FOR loop */
PLpgSQL_stmt_dynfors *new;
PLpgSQL_expr *expr;
int term;
@@ -942,6 +938,47 @@ for_control :
$$ = (PLpgSQL_stmt *) new;
}
+ else if (tok == T_SCALAR &&
+ yylval.scalar->dtype == PLPGSQL_DTYPE_VAR &&
+ ((PLpgSQL_var *) yylval.scalar)->datatype->typoid == REFCURSOROID)
+ {
+ /* It's FOR var IN cursor */
+ PLpgSQL_stmt_forc *new;
+ PLpgSQL_var *cursor = (PLpgSQL_var *) yylval.scalar;
+ char *varname;
+
+ new = (PLpgSQL_stmt_forc *) palloc0(sizeof(PLpgSQL_stmt_forc));
+ new->cmd_type = PLPGSQL_STMT_FORC;
+ new->lineno = $1;
+
+ new->curvar = cursor->varno;
+
+ /* Should have had a single variable name */
+ plpgsql_error_lineno = $2.lineno;
+ if ($2.scalar && $2.row)
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("cursor FOR loop must have just one target variable")));
+
+ /* create loop's private RECORD variable */
+ plpgsql_convert_ident($2.name, &varname, 1);
+ new->rec = plpgsql_build_record(varname,
+ $2.lineno,
+ true);
+
+ /* can't use an unbound cursor this way */
+ if (cursor->cursor_explicit_expr == NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("cursor FOR loop must use a bound cursor variable")));
+
+ /* collect cursor's parameters if any */
+ new->argquery = read_cursor_args(cursor,
+ K_LOOP,
+ "LOOP");
+
+ $$ = (PLpgSQL_stmt *) new;
+ }
else
{
PLpgSQL_expr *expr1;
@@ -1412,81 +1449,8 @@ stmt_open : K_OPEN lno cursor_variable
}
else
{
- if ($3->cursor_explicit_argrow >= 0)
- {
- char *cp;
-
- tok = yylex();
- if (tok != '(')
- {
- plpgsql_error_lineno = plpgsql_scanner_lineno();
- ereport(ERROR,
- (errcode(ERRCODE_SYNTAX_ERROR),
- errmsg("cursor \"%s\" has arguments",
- $3->refname)));
- }
-
- /*
- * Push back the '(', else read_sql_stmt
- * will complain about unbalanced parens.
- */
- plpgsql_push_back_token(tok);
-
- new->argquery = read_sql_stmt("SELECT ");
-
- /*
- * Now remove the leading and trailing parens,
- * because we want "select 1, 2", not
- * "select (1, 2)".
- */
- cp = new->argquery->query;
-
- if (strncmp(cp, "SELECT", 6) != 0)
- {
- plpgsql_error_lineno = plpgsql_scanner_lineno();
- /* internal error */
- elog(ERROR, "expected \"SELECT (\", got \"%s\"",
- new->argquery->query);
- }
- cp += 6;
- while (*cp == ' ') /* could be more than 1 space here */
- cp++;
- if (*cp != '(')
- {
- plpgsql_error_lineno = plpgsql_scanner_lineno();
- /* internal error */
- elog(ERROR, "expected \"SELECT (\", got \"%s\"",
- new->argquery->query);
- }
- *cp = ' ';
-
- cp += strlen(cp) - 1;
-
- if (*cp != ')')
- yyerror("expected \")\"");
- *cp = '\0';
- }
- else
- {
- tok = yylex();
- if (tok == '(')
- {
- plpgsql_error_lineno = plpgsql_scanner_lineno();
- ereport(ERROR,
- (errcode(ERRCODE_SYNTAX_ERROR),
- errmsg("cursor \"%s\" has no arguments",
- $3->refname)));
- }
-
- if (tok != ';')
- {
- plpgsql_error_lineno = plpgsql_scanner_lineno();
- ereport(ERROR,
- (errcode(ERRCODE_SYNTAX_ERROR),
- errmsg("syntax error at \"%s\"",
- yytext)));
- }
- }
+ /* predefined cursor query, so read args */
+ new->argquery = read_cursor_args($3, ';', ";");
}
$$ = (PLpgSQL_stmt *)new;
@@ -2578,6 +2542,97 @@ check_labels(const char *start_label, const char *end_label)
}
}
+/*
+ * Read the arguments (if any) for a cursor, followed by the until token
+ *
+ * If cursor has no args, just swallow the until token and return NULL.
+ * If it does have args, we expect to see "( expr [, expr ...] )" followed
+ * by the until token. Consume all that and return a SELECT query that
+ * evaluates the expression(s) (without the outer parens).
+ */
+static PLpgSQL_expr *
+read_cursor_args(PLpgSQL_var *cursor, int until, const char *expected)
+{
+ PLpgSQL_expr *expr;
+ int tok;
+ char *cp;
+
+ tok = yylex();
+ if (cursor->cursor_explicit_argrow < 0)
+ {
+ /* No arguments expected */
+ if (tok == '(')
+ {
+ plpgsql_error_lineno = plpgsql_scanner_lineno();
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("cursor \"%s\" has no arguments",
+ cursor->refname)));
+ }
+
+ if (tok != until)
+ {
+ plpgsql_error_lineno = plpgsql_scanner_lineno();
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("syntax error at \"%s\"",
+ yytext)));
+ }
+
+ return NULL;
+ }
+
+ /* Else better provide arguments */
+ if (tok != '(')
+ {
+ plpgsql_error_lineno = plpgsql_scanner_lineno();
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("cursor \"%s\" has arguments",
+ cursor->refname)));
+ }
+
+ /*
+ * Push back the '(', else plpgsql_read_expression
+ * will complain about unbalanced parens.
+ */
+ plpgsql_push_back_token(tok);
+
+ expr = plpgsql_read_expression(until, expected);
+
+ /*
+ * Now remove the leading and trailing parens,
+ * because we want "SELECT 1, 2", not "SELECT (1, 2)".
+ */
+ cp = expr->query;
+
+ if (strncmp(cp, "SELECT", 6) != 0)
+ {
+ plpgsql_error_lineno = plpgsql_scanner_lineno();
+ /* internal error */
+ elog(ERROR, "expected \"SELECT (\", got \"%s\"", expr->query);
+ }
+ cp += 6;
+ while (*cp == ' ') /* could be more than 1 space here */
+ cp++;
+ if (*cp != '(')
+ {
+ plpgsql_error_lineno = plpgsql_scanner_lineno();
+ /* internal error */
+ elog(ERROR, "expected \"SELECT (\", got \"%s\"", expr->query);
+ }
+ *cp = ' ';
+
+ cp += strlen(cp) - 1;
+
+ if (*cp != ')')
+ yyerror("expected \")\"");
+ *cp = '\0';
+
+ return expr;
+}
+
+
/* Needed to avoid conflict between different prefix settings: */
#undef yylex
diff --git a/src/pl/plpgsql/src/pl_comp.c b/src/pl/plpgsql/src/pl_comp.c
index c124d071542..ea19a375db7 100644
--- a/src/pl/plpgsql/src/pl_comp.c
+++ b/src/pl/plpgsql/src/pl_comp.c
@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.123 2008/03/27 03:57:34 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.124 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@@ -575,25 +575,11 @@ do_compile(FunctionCallInfo fcinfo,
errhint("You probably want to use TG_NARGS and TG_ARGV instead.")));
/* Add the record for referencing NEW */
- rec = palloc0(sizeof(PLpgSQL_rec));
- rec->dtype = PLPGSQL_DTYPE_REC;
- rec->refname = pstrdup("new");
- rec->tup = NULL;
- rec->tupdesc = NULL;
- rec->freetup = false;
- plpgsql_adddatum((PLpgSQL_datum *) rec);
- plpgsql_ns_additem(PLPGSQL_NSTYPE_REC, rec->recno, rec->refname);
+ rec = plpgsql_build_record("new", 0, true);
function->new_varno = rec->recno;
/* Add the record for referencing OLD */
- rec = palloc0(sizeof(PLpgSQL_rec));
- rec->dtype = PLPGSQL_DTYPE_REC;
- rec->refname = pstrdup("old");
- rec->tup = NULL;
- rec->tupdesc = NULL;
- rec->freetup = false;
- plpgsql_adddatum((PLpgSQL_datum *) rec);
- plpgsql_ns_additem(PLPGSQL_NSTYPE_REC, rec->recno, rec->refname);
+ rec = plpgsql_build_record("old", 0, true);
function->old_varno = rec->recno;
/* Add the variable tg_name */
@@ -1481,21 +1467,10 @@ plpgsql_build_variable(const char *refname, int lineno, PLpgSQL_type *dtype,
}
case PLPGSQL_TTYPE_REC:
{
- /*
- * "record" type -- build a variable-contents record variable
- */
+ /* "record" type -- build a record variable */
PLpgSQL_rec *rec;
- rec = palloc0(sizeof(PLpgSQL_rec));
- rec->dtype = PLPGSQL_DTYPE_REC;
- rec->refname = pstrdup(refname);
- rec->lineno = lineno;
-
- plpgsql_adddatum((PLpgSQL_datum *) rec);
- if (add2namespace)
- plpgsql_ns_additem(PLPGSQL_NSTYPE_REC,
- rec->recno,
- refname);
+ rec = plpgsql_build_record(refname, lineno, add2namespace);
result = (PLpgSQL_variable *) rec;
break;
}
@@ -1516,6 +1491,28 @@ plpgsql_build_variable(const char *refname, int lineno, PLpgSQL_type *dtype,
}
/*
+ * Build empty named record variable, and optionally add it to namespace
+ */
+PLpgSQL_rec *
+plpgsql_build_record(const char *refname, int lineno, bool add2namespace)
+{
+ PLpgSQL_rec *rec;
+
+ rec = palloc0(sizeof(PLpgSQL_rec));
+ rec->dtype = PLPGSQL_DTYPE_REC;
+ rec->refname = pstrdup(refname);
+ rec->lineno = lineno;
+ rec->tup = NULL;
+ rec->tupdesc = NULL;
+ rec->freetup = false;
+ plpgsql_adddatum((PLpgSQL_datum *) rec);
+ if (add2namespace)
+ plpgsql_ns_additem(PLPGSQL_NSTYPE_REC, rec->recno, rec->refname);
+
+ return rec;
+}
+
+/*
* Build a row-variable data structure given the pg_class OID.
*/
static PLpgSQL_row *
diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c
index e331b732d35..64ce1d1202d 100644
--- a/src/pl/plpgsql/src/pl_exec.c
+++ b/src/pl/plpgsql/src/pl_exec.c
@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.208 2008/04/01 03:51:09 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.209 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@@ -103,6 +103,8 @@ 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_forc(PLpgSQL_execstate *estate,
+ PLpgSQL_stmt_forc *stmt);
static int exec_stmt_open(PLpgSQL_execstate *estate,
PLpgSQL_stmt_open *stmt);
static int exec_stmt_fetch(PLpgSQL_execstate *estate,
@@ -165,6 +167,10 @@ static Datum exec_eval_expr(PLpgSQL_execstate *estate,
Oid *rettype);
static int exec_run_select(PLpgSQL_execstate *estate,
PLpgSQL_expr *expr, long maxtuples, Portal *portalP);
+static int exec_for_query(PLpgSQL_execstate *estate, PLpgSQL_stmt_forq *stmt,
+ Portal portal, bool prefetch_ok);
+static void eval_expr_params(PLpgSQL_execstate *estate,
+ PLpgSQL_expr *expr, Datum **p_values, char **p_nulls);
static void exec_move_row(PLpgSQL_execstate *estate,
PLpgSQL_rec *rec,
PLpgSQL_row *row,
@@ -187,6 +193,7 @@ static bool compatible_tupdesc(TupleDesc td1, TupleDesc td2);
static void exec_set_found(PLpgSQL_execstate *estate, bool state);
static void plpgsql_create_econtext(PLpgSQL_execstate *estate);
static void free_var(PLpgSQL_var *var);
+static void assign_text_var(PLpgSQL_var *var, const char *str);
static PreparedParamsData *exec_eval_using_params(PLpgSQL_execstate *estate,
List *params);
static void free_params_data(PreparedParamsData *ppd);
@@ -1084,15 +1091,12 @@ exec_stmt_block(PLpgSQL_execstate *estate, PLpgSQL_stmt_block *block)
state_var = (PLpgSQL_var *)
estate->datums[block->exceptions->sqlstate_varno];
- state_var->value = CStringGetTextDatum(unpack_sql_state(edata->sqlerrcode));
- state_var->freeval = true;
- state_var->isnull = false;
-
errm_var = (PLpgSQL_var *)
estate->datums[block->exceptions->sqlerrm_varno];
- errm_var->value = CStringGetTextDatum(edata->message);
- errm_var->freeval = true;
- errm_var->isnull = false;
+
+ assign_text_var(state_var,
+ unpack_sql_state(edata->sqlerrcode));
+ assign_text_var(errm_var, edata->message);
estate->err_text = NULL;
@@ -1100,8 +1104,10 @@ exec_stmt_block(PLpgSQL_execstate *estate, PLpgSQL_stmt_block *block)
free_var(state_var);
state_var->value = (Datum) 0;
+ state_var->isnull = true;
free_var(errm_var);
errm_var->value = (Datum) 0;
+ errm_var->isnull = true;
break;
}
}
@@ -1246,6 +1252,10 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
rc = exec_stmt_fors(estate, (PLpgSQL_stmt_fors *) stmt);
break;
+ case PLPGSQL_STMT_FORC:
+ rc = exec_stmt_forc(estate, (PLpgSQL_stmt_forc *) stmt);
+ break;
+
case PLPGSQL_STMT_EXIT:
rc = exec_stmt_exit(estate, (PLpgSQL_stmt_exit *) stmt);
break;
@@ -1724,145 +1734,149 @@ exec_stmt_fori(PLpgSQL_execstate *estate, PLpgSQL_stmt_fori *stmt)
static int
exec_stmt_fors(PLpgSQL_execstate *estate, PLpgSQL_stmt_fors *stmt)
{
- PLpgSQL_rec *rec = NULL;
- PLpgSQL_row *row = NULL;
- SPITupleTable *tuptab;
Portal portal;
- bool found = false;
- int rc = PLPGSQL_RC_OK;
- int i;
- int n;
-
- /*
- * 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");
+ int rc;
/*
- * Open the implicit cursor for the statement and fetch the initial 10
- * rows.
+ * Open the implicit cursor for the statement using exec_run_select
*/
exec_run_select(estate, stmt->query, 0, &portal);
- SPI_cursor_fetch(portal, true, 10);
- tuptab = SPI_tuptable;
- n = SPI_processed;
-
/*
- * If the query didn't return any rows, set the target to NULL and return
- * with FOUND = false.
+ * Execute the loop
*/
- if (n == 0)
- exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
- else
- found = true; /* processed at least one tuple */
+ rc = exec_for_query(estate, (PLpgSQL_stmt_forq *) stmt, portal, true);
/*
- * Now do the loop
+ * Close the implicit cursor
*/
- while (n > 0)
- {
- for (i = 0; i < n; i++)
- {
- /*
- * Assign the tuple to the target
- */
- exec_move_row(estate, rec, row, tuptab->vals[i], tuptab->tupdesc);
+ SPI_cursor_close(portal);
- /*
- * Execute the statements
- */
- rc = exec_stmts(estate, stmt->body);
- if (rc != PLPGSQL_RC_OK)
- {
- if (rc == PLPGSQL_RC_EXIT)
- {
- if (estate->exitlabel == NULL)
- /* unlabelled exit, finish the current loop */
- rc = PLPGSQL_RC_OK;
- else if (stmt->label != NULL &&
- strcmp(stmt->label, estate->exitlabel) == 0)
- {
- /* labelled exit, matches the current stmt's label */
- estate->exitlabel = NULL;
- rc = PLPGSQL_RC_OK;
- }
+ return rc;
+}
- /*
- * otherwise, we processed a labelled exit that does not
- * match the current statement's label, if any: return
- * RC_EXIT so that the EXIT continues to recurse upward.
- */
- }
- else if (rc == PLPGSQL_RC_CONTINUE)
- {
- if (estate->exitlabel == NULL)
- {
- /* anonymous continue, so re-run the current loop */
- rc = PLPGSQL_RC_OK;
- continue;
- }
- else if (stmt->label != NULL &&
- strcmp(stmt->label, estate->exitlabel) == 0)
- {
- /* label matches named continue, so re-run loop */
- rc = PLPGSQL_RC_OK;
- estate->exitlabel = NULL;
- continue;
- }
- /*
- * otherwise, we processed a named continue that does not
- * match the current statement's label, if any: return
- * RC_CONTINUE so that the CONTINUE will propagate up the
- * stack.
- */
- }
+/* ----------
+ * exec_stmt_forc Execute a loop for each row from a cursor.
+ * ----------
+ */
+static int
+exec_stmt_forc(PLpgSQL_execstate *estate, PLpgSQL_stmt_forc *stmt)
+{
+ PLpgSQL_var *curvar;
+ char *curname = NULL;
+ PLpgSQL_expr *query;
+ Portal portal;
+ int rc;
+ Datum *values;
+ char *nulls;
- /*
- * We're aborting the loop, so cleanup and set FOUND. (This
- * code should match the code after the loop.)
- */
- SPI_freetuptable(tuptab);
- SPI_cursor_close(portal);
- exec_set_found(estate, found);
+ /* ----------
+ * Get the cursor variable and if it has an assigned name, check
+ * that it's not in use currently.
+ * ----------
+ */
+ curvar = (PLpgSQL_var *) (estate->datums[stmt->curvar]);
+ if (!curvar->isnull)
+ {
+ curname = TextDatumGetCString(curvar->value);
+ if (SPI_cursor_find(curname) != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_CURSOR),
+ errmsg("cursor \"%s\" already in use", curname)));
+ }
- return rc;
- }
- }
+ /* ----------
+ * Open the cursor just like an OPEN command
+ *
+ * Note: parser should already have checked that statement supplies
+ * args iff cursor needs them, but we check again to be safe.
+ * ----------
+ */
+ if (stmt->argquery != NULL)
+ {
+ /* ----------
+ * OPEN CURSOR with args. We fake a SELECT ... INTO ...
+ * statement to evaluate the args and put 'em into the
+ * internal row.
+ * ----------
+ */
+ PLpgSQL_stmt_execsql set_args;
- SPI_freetuptable(tuptab);
+ if (curvar->cursor_explicit_argrow < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("arguments given for cursor without arguments")));
- /*
- * Fetch the next 50 tuples
- */
- SPI_cursor_fetch(portal, true, 50);
- n = SPI_processed;
- tuptab = SPI_tuptable;
+ memset(&set_args, 0, sizeof(set_args));
+ 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]);
+
+ if (exec_stmt_execsql(estate, &set_args) != PLPGSQL_RC_OK)
+ elog(ERROR, "open cursor failed during argument processing");
+ }
+ else
+ {
+ if (curvar->cursor_explicit_argrow >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("arguments required for cursor")));
}
+ query = curvar->cursor_explicit_expr;
+ Assert(query);
+
+ if (query->plan == NULL)
+ exec_prepare_plan(estate, query, curvar->cursor_options);
+
/*
- * Release last group of tuples
+ * Now build up the values and nulls arguments for SPI_execute_plan()
*/
- SPI_freetuptable(tuptab);
+ eval_expr_params(estate, query, &values, &nulls);
/*
- * Close the implicit cursor
+ * Open the cursor
*/
- SPI_cursor_close(portal);
+ portal = SPI_cursor_open(curname, query->plan, values, nulls,
+ estate->readonly_func);
+ if (portal == NULL)
+ elog(ERROR, "could not open cursor: %s",
+ SPI_result_code_string(SPI_result));
/*
- * Set the FOUND variable to indicate the result of executing the loop
- * (namely, whether we looped one or more times). This must be set here so
- * that it does not interfere with the value of the FOUND variable inside
- * the loop processing itself.
+ * If cursor variable was NULL, store the generated portal name in it
*/
- exec_set_found(estate, found);
+ if (curname == NULL)
+ assign_text_var(curvar, portal->name);
+
+ /*
+ * Execute the loop. We can't prefetch because the cursor is accessible
+ * to the user, for instance via UPDATE WHERE CURRENT OF within the loop.
+ */
+ rc = exec_for_query(estate, (PLpgSQL_stmt_forq *) stmt, portal, false);
+
+ /* ----------
+ * Close portal, and restore cursor variable if it was initially NULL.
+ * ----------
+ */
+ SPI_cursor_close(portal);
+
+ if (curname == NULL)
+ {
+ free_var(curvar);
+ curvar->value = (Datum) 0;
+ curvar->isnull = true;
+ }
+
+ pfree(values);
+ pfree(nulls);
+ if (curname)
+ pfree(curname);
return rc;
}
@@ -2470,7 +2484,6 @@ static int
exec_stmt_execsql(PLpgSQL_execstate *estate,
PLpgSQL_stmt_execsql *stmt)
{
- int i;
Datum *values;
char *nulls;
long tcount;
@@ -2511,22 +2524,7 @@ exec_stmt_execsql(PLpgSQL_execstate *estate,
/*
* Now build up the values and nulls arguments for SPI_execute_plan()
*/
- values = (Datum *) palloc(expr->nparams * sizeof(Datum));
- nulls = (char *) palloc(expr->nparams * sizeof(char));
-
- for (i = 0; i < expr->nparams; i++)
- {
- PLpgSQL_datum *datum = estate->datums[expr->params[i]];
- Oid paramtypeid;
- bool paramisnull;
-
- exec_eval_datum(estate, datum, expr->plan_argtypes[i],
- &paramtypeid, &values[i], &paramisnull);
- if (paramisnull)
- nulls[i] = 'n';
- else
- nulls[i] = ' ';
- }
+ eval_expr_params(estate, expr, &values, &nulls);
/*
* If we have INTO, then we only need one row back ... but if we have INTO
@@ -2846,22 +2844,8 @@ exec_stmt_dynfors(PLpgSQL_execstate *estate, PLpgSQL_stmt_dynfors *stmt)
bool isnull;
Oid restype;
char *querystr;
- PLpgSQL_rec *rec = NULL;
- PLpgSQL_row *row = NULL;
- SPITupleTable *tuptab;
- int n;
Portal portal;
- bool found = 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");
+ int rc;
/*
* Evaluate the string expression after the EXECUTE keyword. It's result
@@ -2910,124 +2894,16 @@ exec_stmt_dynfors(PLpgSQL_execstate *estate, PLpgSQL_stmt_dynfors *stmt)
pfree(querystr);
/*
- * Fetch the initial 10 tuples
- */
- SPI_cursor_fetch(portal, true, 10);
- tuptab = SPI_tuptable;
- n = SPI_processed;
-
- /*
- * If the query didn't return any rows, set the target to NULL and return
- * with FOUND = false.
- */
- if (n == 0)
- exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
- else
- found = true; /* processed at least one tuple */
-
- /*
- * Now do the loop
- */
- while (n > 0)
- {
- int i;
-
- for (i = 0; i < n; i++)
- {
- int rc;
-
- /*
- * Assign the tuple to the target
- */
- exec_move_row(estate, rec, row, tuptab->vals[i], tuptab->tupdesc);
-
- /*
- * Execute the statements
- */
- rc = exec_stmts(estate, stmt->body);
-
- if (rc != PLPGSQL_RC_OK)
- {
- if (rc == PLPGSQL_RC_EXIT)
- {
- if (estate->exitlabel == NULL)
- /* unlabelled exit, finish the current loop */
- rc = PLPGSQL_RC_OK;
- else if (stmt->label != NULL &&
- strcmp(stmt->label, estate->exitlabel) == 0)
- {
- /* labelled exit, matches the current stmt's label */
- estate->exitlabel = NULL;
- rc = PLPGSQL_RC_OK;
- }
-
- /*
- * otherwise, we processed a labelled exit that does not
- * match the current statement's label, if any: return
- * RC_EXIT so that the EXIT continues to recurse upward.
- */
- }
- else if (rc == PLPGSQL_RC_CONTINUE)
- {
- if (estate->exitlabel == NULL)
- /* unlabelled continue, continue the current loop */
- continue;
- else if (stmt->label != NULL &&
- strcmp(stmt->label, estate->exitlabel) == 0)
- {
- /* labelled continue, matches the current stmt's label */
- estate->exitlabel = NULL;
- continue;
- }
-
- /*
- * otherwise, we process a labelled continue that does not
- * match the current statement's label, so propagate
- * RC_CONTINUE upward in the stack.
- */
- }
-
- /*
- * We're aborting the loop, so cleanup and set FOUND. (This
- * code should match the code after the loop.)
- */
- SPI_freetuptable(tuptab);
- SPI_cursor_close(portal);
- exec_set_found(estate, found);
-
- return rc;
- }
- }
-
- SPI_freetuptable(tuptab);
-
- /*
- * Fetch the next 50 tuples
- */
- SPI_cursor_fetch(portal, true, 50);
- n = SPI_processed;
- tuptab = SPI_tuptable;
- }
-
- /*
- * Release last group of tuples
+ * Execute the loop
*/
- SPI_freetuptable(tuptab);
+ rc = exec_for_query(estate, (PLpgSQL_stmt_forq *) stmt, portal, true);
/*
* Close the implicit cursor
*/
SPI_cursor_close(portal);
- /*
- * Set the FOUND variable to indicate the result of executing the loop
- * (namely, whether we looped one or more times). This must be set here so
- * that it does not interfere with the value of the FOUND variable inside
- * the loop processing itself.
- */
- exec_set_found(estate, found);
-
- return PLPGSQL_RC_OK;
+ return rc;
}
@@ -3038,16 +2914,14 @@ exec_stmt_dynfors(PLpgSQL_execstate *estate, PLpgSQL_stmt_dynfors *stmt)
static int
exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt)
{
- PLpgSQL_var *curvar = NULL;
+ PLpgSQL_var *curvar;
char *curname = NULL;
- PLpgSQL_expr *query = NULL;
+ PLpgSQL_expr *query;
Portal portal;
- int i;
Datum *values;
char *nulls;
bool isnull;
-
/* ----------
* Get the cursor variable and if it has an assigned name, check
* that it's not in use currently.
@@ -3124,14 +2998,11 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt)
pfree(querystr);
SPI_freeplan(curplan);
- /* ----------
- * Store the eventually assigned cursor name in the cursor variable
- * ----------
+ /*
+ * If cursor variable was NULL, store the generated portal name in it
*/
- free_var(curvar);
- curvar->value = CStringGetTextDatum(portal->name);
- curvar->isnull = false;
- curvar->freeval = true;
+ if (curname == NULL)
+ assign_text_var(curvar, portal->name);
return PLPGSQL_RC_OK;
}
@@ -3184,32 +3055,13 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt)
exec_prepare_plan(estate, query, curvar->cursor_options);
}
- /* ----------
- * Here we go if we have a saved plan where we have to put
- * values into, either from an explicit cursor or from a
- * refcursor opened with OPEN ... FOR SELECT ...;
- * ----------
+ /*
+ * Now build up the values and nulls arguments for SPI_execute_plan()
*/
- values = (Datum *) palloc(query->nparams * sizeof(Datum));
- nulls = (char *) palloc(query->nparams * sizeof(char));
+ eval_expr_params(estate, query, &values, &nulls);
- for (i = 0; i < query->nparams; i++)
- {
- PLpgSQL_datum *datum = estate->datums[query->params[i]];
- Oid paramtypeid;
- bool paramisnull;
-
- exec_eval_datum(estate, datum, query->plan_argtypes[i],
- &paramtypeid, &values[i], &paramisnull);
- if (paramisnull)
- nulls[i] = 'n';
- else
- nulls[i] = ' ';
- }
-
- /* ----------
+ /*
* Open the cursor
- * ----------
*/
portal = SPI_cursor_open(curname, query->plan, values, nulls,
estate->readonly_func);
@@ -3217,20 +3069,17 @@ exec_stmt_open(PLpgSQL_execstate *estate, PLpgSQL_stmt_open *stmt)
elog(ERROR, "could not open cursor: %s",
SPI_result_code_string(SPI_result));
+ /*
+ * If cursor variable was NULL, store the generated portal name in it
+ */
+ if (curname == NULL)
+ assign_text_var(curvar, portal->name);
+
pfree(values);
pfree(nulls);
if (curname)
pfree(curname);
- /* ----------
- * Store the eventually assigned portal name in the cursor variable
- * ----------
- */
- free_var(curvar);
- curvar->value = CStringGetTextDatum(portal->name);
- curvar->isnull = false;
- curvar->freeval = true;
-
return PLPGSQL_RC_OK;
}
@@ -4082,7 +3931,6 @@ static int
exec_run_select(PLpgSQL_execstate *estate,
PLpgSQL_expr *expr, long maxtuples, Portal *portalP)
{
- int i;
Datum *values;
char *nulls;
int rc;
@@ -4096,22 +3944,7 @@ exec_run_select(PLpgSQL_execstate *estate,
/*
* Now build up the values and nulls arguments for SPI_execute_plan()
*/
- values = (Datum *) palloc(expr->nparams * sizeof(Datum));
- nulls = (char *) palloc(expr->nparams * sizeof(char));
-
- for (i = 0; i < expr->nparams; i++)
- {
- PLpgSQL_datum *datum = estate->datums[expr->params[i]];
- Oid paramtypeid;
- bool paramisnull;
-
- exec_eval_datum(estate, datum, expr->plan_argtypes[i],
- &paramtypeid, &values[i], &paramisnull);
- if (paramisnull)
- nulls[i] = 'n';
- else
- nulls[i] = ' ';
- }
+ eval_expr_params(estate, expr, &values, &nulls);
/*
* If a portal was requested, put the query into the portal
@@ -4151,6 +3984,154 @@ exec_run_select(PLpgSQL_execstate *estate,
}
+/*
+ * exec_for_query --- execute body of FOR loop for each row from a portal
+ *
+ * Used by exec_stmt_fors, exec_stmt_forc and exec_stmt_dynfors
+ */
+static int
+exec_for_query(PLpgSQL_execstate *estate, PLpgSQL_stmt_forq *stmt,
+ Portal portal, bool prefetch_ok)
+{
+ PLpgSQL_rec *rec = NULL;
+ PLpgSQL_row *row = NULL;
+ SPITupleTable *tuptab;
+ bool found = false;
+ int rc = PLPGSQL_RC_OK;
+ int n;
+
+ /*
+ * 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");
+
+ /*
+ * Fetch the initial tuple(s). If prefetching is allowed then we grab
+ * a few more rows to avoid multiple trips through executor startup
+ * overhead.
+ */
+ SPI_cursor_fetch(portal, true, prefetch_ok ? 10 : 1);
+ tuptab = SPI_tuptable;
+ n = SPI_processed;
+
+ /*
+ * If the query didn't return any rows, set the target to NULL and
+ * fall through with found = false.
+ */
+ if (n <= 0)
+ exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
+ else
+ found = true; /* processed at least one tuple */
+
+ /*
+ * Now do the loop
+ */
+ while (n > 0)
+ {
+ int i;
+
+ for (i = 0; i < n; i++)
+ {
+ /*
+ * Assign the tuple to the target
+ */
+ exec_move_row(estate, rec, row, tuptab->vals[i], tuptab->tupdesc);
+
+ /*
+ * Execute the statements
+ */
+ rc = exec_stmts(estate, stmt->body);
+
+ if (rc != PLPGSQL_RC_OK)
+ {
+ if (rc == PLPGSQL_RC_EXIT)
+ {
+ if (estate->exitlabel == NULL)
+ {
+ /* unlabelled exit, so exit the current loop */
+ rc = PLPGSQL_RC_OK;
+ }
+ else if (stmt->label != NULL &&
+ strcmp(stmt->label, estate->exitlabel) == 0)
+ {
+ /* label matches this loop, so exit loop */
+ estate->exitlabel = NULL;
+ rc = PLPGSQL_RC_OK;
+ }
+
+ /*
+ * otherwise, we processed a labelled exit that does not
+ * match the current statement's label, if any; return
+ * RC_EXIT so that the EXIT continues to recurse upward.
+ */
+ }
+ else if (rc == PLPGSQL_RC_CONTINUE)
+ {
+ if (estate->exitlabel == NULL)
+ {
+ /* unlabelled continue, so re-run the current loop */
+ rc = PLPGSQL_RC_OK;
+ continue;
+ }
+ else if (stmt->label != NULL &&
+ strcmp(stmt->label, estate->exitlabel) == 0)
+ {
+ /* label matches this loop, so re-run loop */
+ estate->exitlabel = NULL;
+ rc = PLPGSQL_RC_OK;
+ continue;
+ }
+
+ /*
+ * otherwise, we process a labelled continue that does not
+ * match the current statement's label, if any; return
+ * RC_CONTINUE so that the CONTINUE will propagate up the
+ * stack.
+ */
+ }
+
+ /*
+ * We're aborting the loop. Need a goto to get out of two
+ * levels of loop...
+ */
+ goto loop_exit;
+ }
+ }
+
+ SPI_freetuptable(tuptab);
+
+ /*
+ * Fetch more tuples. If prefetching is allowed, grab 50 at a time.
+ */
+ SPI_cursor_fetch(portal, true, prefetch_ok ? 50 : 1);
+ tuptab = SPI_tuptable;
+ n = SPI_processed;
+ }
+
+loop_exit:
+
+ /*
+ * Release last group of tuples (if any)
+ */
+ SPI_freetuptable(tuptab);
+
+ /*
+ * Set the FOUND variable to indicate the result of executing the loop
+ * (namely, whether we looped one or more times). This must be set last so
+ * that it does not interfere with the value of the FOUND variable inside
+ * the loop processing itself.
+ */
+ exec_set_found(estate, found);
+
+ return rc;
+}
+
+
/* ----------
* exec_eval_simple_expr - Evaluate a simple expression returning
* a Datum by directly calling ExecEvalExpr().
@@ -4317,6 +4298,36 @@ exec_eval_simple_expr(PLpgSQL_execstate *estate,
}
+/*
+ * Build up the values and nulls arguments for SPI_execute_plan()
+ */
+static void
+eval_expr_params(PLpgSQL_execstate *estate,
+ PLpgSQL_expr *expr, Datum **p_values, char **p_nulls)
+{
+ Datum *values;
+ char *nulls;
+ int i;
+
+ *p_values = values = (Datum *) palloc(expr->nparams * sizeof(Datum));
+ *p_nulls = nulls = (char *) palloc(expr->nparams * sizeof(char));
+
+ for (i = 0; i < expr->nparams; i++)
+ {
+ PLpgSQL_datum *datum = estate->datums[expr->params[i]];
+ Oid paramtypeid;
+ bool paramisnull;
+
+ exec_eval_datum(estate, datum, expr->plan_argtypes[i],
+ &paramtypeid, &values[i], &paramisnull);
+ if (paramisnull)
+ nulls[i] = 'n';
+ else
+ nulls[i] = ' ';
+ }
+}
+
+
/* ----------
* exec_move_row Move one tuple's values into a record or row
* ----------
@@ -5110,6 +5121,18 @@ free_var(PLpgSQL_var *var)
}
/*
+ * free old value of a text variable and assign new value from C string
+ */
+static void
+assign_text_var(PLpgSQL_var *var, const char *str)
+{
+ free_var(var);
+ var->value = CStringGetTextDatum(str);
+ var->isnull = false;
+ var->freeval = true;
+}
+
+/*
* exec_eval_using_params --- evaluate params of USING clause
*/
static PreparedParamsData *
diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c
index be57154e402..1a68c9339f2 100644
--- a/src/pl/plpgsql/src/pl_funcs.c
+++ b/src/pl/plpgsql/src/pl_funcs.c
@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.68 2008/04/01 03:51:09 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.69 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@@ -482,6 +482,8 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
return _("FOR with integer loop variable");
case PLPGSQL_STMT_FORS:
return _("FOR over SELECT rows");
+ case PLPGSQL_STMT_FORC:
+ return _("FOR over cursor");
case PLPGSQL_STMT_EXIT:
return "EXIT";
case PLPGSQL_STMT_RETURN:
@@ -528,6 +530,7 @@ 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_forc(PLpgSQL_stmt_forc *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);
@@ -581,6 +584,9 @@ dump_stmt(PLpgSQL_stmt *stmt)
case PLPGSQL_STMT_FORS:
dump_fors((PLpgSQL_stmt_fors *) stmt);
break;
+ case PLPGSQL_STMT_FORC:
+ dump_forc((PLpgSQL_stmt_forc *) stmt);
+ break;
case PLPGSQL_STMT_EXIT:
dump_exit((PLpgSQL_stmt_exit *) stmt);
break;
@@ -776,6 +782,29 @@ dump_fors(PLpgSQL_stmt_fors *stmt)
}
static void
+dump_forc(PLpgSQL_stmt_forc *stmt)
+{
+ dump_ind();
+ printf("FORC %s ", stmt->rec->refname);
+ printf("curvar=%d\n", stmt->curvar);
+
+ dump_indent += 2;
+ if (stmt->argquery != NULL)
+ {
+ dump_ind();
+ printf(" arguments = ");
+ dump_expr(stmt->argquery);
+ printf("\n");
+ }
+ dump_indent -= 2;
+
+ dump_stmts(stmt->body);
+
+ dump_ind();
+ printf(" ENDFORC\n");
+}
+
+static void
dump_open(PLpgSQL_stmt_open *stmt)
{
dump_ind();
diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h
index 66588b343f8..a50d5721f43 100644
--- a/src/pl/plpgsql/src/plpgsql.h
+++ b/src/pl/plpgsql/src/plpgsql.h
@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.96 2008/04/01 03:51:09 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.97 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@@ -80,6 +80,7 @@ enum
PLPGSQL_STMT_WHILE,
PLPGSQL_STMT_FORI,
PLPGSQL_STMT_FORS,
+ PLPGSQL_STMT_FORC,
PLPGSQL_STMT_EXIT,
PLPGSQL_STMT_RETURN,
PLPGSQL_STMT_RETURN_NEXT,
@@ -409,6 +410,21 @@ typedef struct
} PLpgSQL_stmt_fori;
+/*
+ * PLpgSQL_stmt_forq represents a FOR statement running over a SQL query.
+ * It is the common supertype of PLpgSQL_stmt_fors, PLpgSQL_stmt_forc
+ * and PLpgSQL_dynfors.
+ */
+typedef struct
+{
+ int cmd_type;
+ int lineno;
+ char *label;
+ PLpgSQL_rec *rec;
+ PLpgSQL_row *row;
+ List *body; /* List of statements */
+} PLpgSQL_stmt_forq;
+
typedef struct
{ /* FOR statement running over SELECT */
int cmd_type;
@@ -416,10 +432,23 @@ typedef struct
char *label;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
- PLpgSQL_expr *query;
List *body; /* List of statements */
+ /* end of fields that must match PLpgSQL_stmt_forq */
+ PLpgSQL_expr *query;
} PLpgSQL_stmt_fors;
+typedef struct
+{ /* FOR statement running over cursor */
+ int cmd_type;
+ int lineno;
+ char *label;
+ PLpgSQL_rec *rec;
+ PLpgSQL_row *row;
+ List *body; /* List of statements */
+ /* end of fields that must match PLpgSQL_stmt_forq */
+ int curvar;
+ PLpgSQL_expr *argquery; /* cursor arguments if any */
+} PLpgSQL_stmt_forc;
typedef struct
{ /* FOR statement running over EXECUTE */
@@ -428,8 +457,9 @@ typedef struct
char *label;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
- PLpgSQL_expr *query;
List *body; /* List of statements */
+ /* end of fields that must match PLpgSQL_stmt_forq */
+ PLpgSQL_expr *query;
List *params; /* USING expressions */
} PLpgSQL_stmt_dynfors;
@@ -738,6 +768,8 @@ extern PLpgSQL_type *plpgsql_build_datatype(Oid typeOid, int32 typmod);
extern PLpgSQL_variable *plpgsql_build_variable(const char *refname, int lineno,
PLpgSQL_type *dtype,
bool add2namespace);
+extern PLpgSQL_rec *plpgsql_build_record(const char *refname, int lineno,
+ bool add2namespace);
extern PLpgSQL_condition *plpgsql_parse_err_condition(char *condname);
extern void plpgsql_adddatum(PLpgSQL_datum *new);
extern int plpgsql_add_initdatums(int **varnos);
diff --git a/src/test/regress/expected/plpgsql.out b/src/test/regress/expected/plpgsql.out
index bcf974483ea..018c8c2b50f 100644
--- a/src/test/regress/expected/plpgsql.out
+++ b/src/test/regress/expected/plpgsql.out
@@ -3151,3 +3151,119 @@ NOTICE: 6
26
(1 row)
+-- test FOR-over-cursor
+create or replace function forc01() returns void as $$
+declare
+ c cursor(r1 integer, r2 integer)
+ for select * from generate_series(r1,r2) i;
+ c2 cursor
+ for select * from generate_series(41,43) i;
+begin
+ for r in c(5,7) loop
+ raise notice '% from %', r.i, c;
+ end loop;
+ -- again, to test if cursor was closed properly
+ for r in c(9,10) loop
+ raise notice '% from %', r.i, c;
+ end loop;
+ -- and test a parameterless cursor
+ for r in c2 loop
+ raise notice '% from %', r.i, c2;
+ end loop;
+ -- and try it with a hand-assigned name
+ raise notice 'after loop, c2 = %', c2;
+ c2 := 'special_name';
+ for r in c2 loop
+ raise notice '% from %', r.i, c2;
+ end loop;
+ raise notice 'after loop, c2 = %', c2;
+ -- and try it with a generated name
+ -- (which we can't show in the output because it's variable)
+ c2 := null;
+ for r in c2 loop
+ raise notice '%', r.i;
+ end loop;
+ raise notice 'after loop, c2 = %', c2;
+ return;
+end;
+$$ language plpgsql;
+select forc01();
+NOTICE: 5 from c
+NOTICE: 6 from c
+NOTICE: 7 from c
+NOTICE: 9 from c
+NOTICE: 10 from c
+NOTICE: 41 from c2
+NOTICE: 42 from c2
+NOTICE: 43 from c2
+NOTICE: after loop, c2 = c2
+NOTICE: 41 from special_name
+NOTICE: 42 from special_name
+NOTICE: 43 from special_name
+NOTICE: after loop, c2 = special_name
+NOTICE: 41
+NOTICE: 42
+NOTICE: 43
+NOTICE: after loop, c2 = <NULL>
+ forc01
+--------
+
+(1 row)
+
+-- try updating the cursor's current row
+create temp table forc_test as
+ select n as i, n as j from generate_series(1,10) n;
+create or replace function forc01() returns void as $$
+declare
+ c cursor for select * from forc_test;
+begin
+ for r in c loop
+ raise notice '%, %', r.i, r.j;
+ update forc_test set i = i * 100, j = r.j * 2 where current of c;
+ end loop;
+end;
+$$ language plpgsql;
+select forc01();
+NOTICE: 1, 1
+NOTICE: 2, 2
+NOTICE: 3, 3
+NOTICE: 4, 4
+NOTICE: 5, 5
+NOTICE: 6, 6
+NOTICE: 7, 7
+NOTICE: 8, 8
+NOTICE: 9, 9
+NOTICE: 10, 10
+ forc01
+--------
+
+(1 row)
+
+select * from forc_test;
+ i | j
+------+----
+ 100 | 2
+ 200 | 4
+ 300 | 6
+ 400 | 8
+ 500 | 10
+ 600 | 12
+ 700 | 14
+ 800 | 16
+ 900 | 18
+ 1000 | 20
+(10 rows)
+
+drop function forc01();
+-- fail because cursor has no query bound to it
+create or replace function forc_bad() returns void as $$
+declare
+ c refcursor;
+begin
+ for r in c loop
+ raise notice '%', r.i;
+ end loop;
+end;
+$$ language plpgsql;
+ERROR: cursor FOR loop must use a bound cursor variable
+CONTEXT: compile of PL/pgSQL function "forc_bad" near line 4
diff --git a/src/test/regress/sql/plpgsql.sql b/src/test/regress/sql/plpgsql.sql
index 2a93ffc611e..066ccbeba63 100644
--- a/src/test/regress/sql/plpgsql.sql
+++ b/src/test/regress/sql/plpgsql.sql
@@ -2595,3 +2595,77 @@ end
$$ language plpgsql;
select exc_using(5, 'foobar');
+
+-- test FOR-over-cursor
+
+create or replace function forc01() returns void as $$
+declare
+ c cursor(r1 integer, r2 integer)
+ for select * from generate_series(r1,r2) i;
+ c2 cursor
+ for select * from generate_series(41,43) i;
+begin
+ for r in c(5,7) loop
+ raise notice '% from %', r.i, c;
+ end loop;
+ -- again, to test if cursor was closed properly
+ for r in c(9,10) loop
+ raise notice '% from %', r.i, c;
+ end loop;
+ -- and test a parameterless cursor
+ for r in c2 loop
+ raise notice '% from %', r.i, c2;
+ end loop;
+ -- and try it with a hand-assigned name
+ raise notice 'after loop, c2 = %', c2;
+ c2 := 'special_name';
+ for r in c2 loop
+ raise notice '% from %', r.i, c2;
+ end loop;
+ raise notice 'after loop, c2 = %', c2;
+ -- and try it with a generated name
+ -- (which we can't show in the output because it's variable)
+ c2 := null;
+ for r in c2 loop
+ raise notice '%', r.i;
+ end loop;
+ raise notice 'after loop, c2 = %', c2;
+ return;
+end;
+$$ language plpgsql;
+
+select forc01();
+
+-- try updating the cursor's current row
+
+create temp table forc_test as
+ select n as i, n as j from generate_series(1,10) n;
+
+create or replace function forc01() returns void as $$
+declare
+ c cursor for select * from forc_test;
+begin
+ for r in c loop
+ raise notice '%, %', r.i, r.j;
+ update forc_test set i = i * 100, j = r.j * 2 where current of c;
+ end loop;
+end;
+$$ language plpgsql;
+
+select forc01();
+
+select * from forc_test;
+
+drop function forc01();
+
+-- fail because cursor has no query bound to it
+
+create or replace function forc_bad() returns void as $$
+declare
+ c refcursor;
+begin
+ for r in c loop
+ raise notice '%', r.i;
+ end loop;
+end;
+$$ language plpgsql;