1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-30 11:03:19 +03:00

Allow committing inside cursor loop

Previously, committing or aborting inside a cursor loop was prohibited
because that would close and remove the cursor.  To allow that,
automatically convert such cursors to holdable cursors so they survive
commits or rollbacks.  Portals now have a new state "auto-held", which
means they have been converted automatically from pinned.  An auto-held
portal is kept on transaction commit or rollback, but is still removed
when returning to the main loop on error.

This supports all languages that have cursor loop constructs: PL/pgSQL,
PL/Python, PL/Perl.

Reviewed-by: Ildus Kurbangaliev <i.kurbangaliev@postgrespro.ru>
This commit is contained in:
Peter Eisentraut
2018-03-28 18:57:10 -04:00
parent a2894cce54
commit 056a5a3f63
15 changed files with 534 additions and 87 deletions

View File

@ -722,11 +722,6 @@ $$;
CALL transaction_test1();
</programlisting>
</para>
<para>
Transactions cannot be ended when a cursor created by
<function>spi_query</function> is open.
</para>
</listitem>
</varlistentry>
</variablelist>

View File

@ -3510,8 +3510,41 @@ CALL transaction_test1();
</para>
<para>
A transaction cannot be ended inside a loop over a query result, nor
inside a block with exception handlers.
Special considerations apply to cursor loops. Consider this example:
<programlisting>
CREATE PROCEDURE transaction_test2()
LANGUAGE plpgsql
AS $$
DECLARE
r RECORD;
BEGIN
FOR r IN SELECT * FROM test2 ORDER BY x LOOP
INSERT INTO test1 (a) VALUES (r.x);
COMMIT;
END LOOP;
END;
$$;
CALL transaction_test2();
</programlisting>
Normally, cursors are automatically closed at transaction commit.
However, a cursor created as part of a loop like this is automatically
converted to a holdable cursor by the first <command>COMMIT</command> or
<command>ROLLBACK</command>. That means that the cursor is fully
evaluated at the first <command>COMMIT</command> or
<command>ROLLBACK</command> rather than row by row. The cursor is still
removed automatically after the loop, so this is mostly invisible to the
user.
</para>
<para>
Transaction commands are not allowed in cursor loops driven by commands
that are not read-only (for example <command>UPDATE
... RETURNING</command>).
</para>
<para>
A transaction cannot be ended inside a block with exception handlers.
</para>
</sect1>

View File

@ -1416,9 +1416,7 @@ CALL transaction_test1();
</para>
<para>
Transactions cannot be ended when a cursor created by
<literal>plpy.cursor</literal> is open or when an explicit subtransaction
is active.
Transactions cannot be ended when an explicit subtransaction is active.
</para>
</sect1>