Sophie

Sophie

distrib > Mageia > 7 > x86_64 > by-pkgid > 9b6cc37ce608401d44f6535a0c7cb777 > files > 593

postgresql11-docs-11.5-1.mga7.noarch.rpm

<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>43.8. Transaction Management</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="plpgsql-cursors.html" title="43.7. Cursors" /><link rel="next" href="plpgsql-errors-and-messages.html" title="43.9. Errors and Messages" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">43.8. Transaction Management</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="plpgsql-cursors.html" title="43.7. Cursors">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="plpgsql.html" title="Chapter 43. PL/pgSQL - SQL Procedural Language">Up</a></td><th width="60%" align="center">Chapter 43. <span xmlns="http://www.w3.org/1999/xhtml" class="application">PL/pgSQL</span> - <acronym xmlns="http://www.w3.org/1999/xhtml" class="acronym">SQL</acronym> Procedural Language</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 11.5 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="plpgsql-errors-and-messages.html" title="43.9. Errors and Messages">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="PLPGSQL-TRANSACTIONS"><div class="titlepage"><div><div><h2 class="title" style="clear: both">43.8. Transaction Management</h2></div></div></div><p>
    In procedures invoked by the <code class="command">CALL</code> command
    as well as in anonymous code blocks (<code class="command">DO</code> command),
    it is possible to end transactions using the
    commands <code class="command">COMMIT</code> and <code class="command">ROLLBACK</code>.  A new
    transaction is started automatically after a transaction is ended using
    these commands, so there is no separate <code class="command">START
    TRANSACTION</code> command.  (Note that <code class="command">BEGIN</code> and
    <code class="command">END</code> have different meanings in PL/pgSQL.)
   </p><p>
    Here is a simple example:
</p><pre class="programlisting">
CREATE PROCEDURE transaction_test1()
LANGUAGE plpgsql
AS $$
BEGIN
    FOR i IN 0..9 LOOP
        INSERT INTO test1 (a) VALUES (i);
        IF i % 2 = 0 THEN
            COMMIT;
        ELSE
            ROLLBACK;
        END IF;
    END LOOP;
END
$$;

CALL transaction_test1();
</pre><p>
   </p><p>
    Transaction control is only possible in <code class="command">CALL</code> or
    <code class="command">DO</code> invocations from the top level or nested
    <code class="command">CALL</code> or <code class="command">DO</code> invocations without any
    other intervening command.  For example, if the call stack is
    <code class="command">CALL proc1()</code> → <code class="command">CALL proc2()</code>
    → <code class="command">CALL proc3()</code>, then the second and third
    procedures can perform transaction control actions.  But if the call stack
    is <code class="command">CALL proc1()</code> → <code class="command">SELECT
    func2()</code> → <code class="command">CALL proc3()</code>, then the last
    procedure cannot do transaction control, because of the
    <code class="command">SELECT</code> in between.
   </p><p>
    Special considerations apply to cursor loops.  Consider this example:
</p><pre class="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();
</pre><p>
    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 <code class="command">COMMIT</code> or
    <code class="command">ROLLBACK</code>.  That means that the cursor is fully
    evaluated at the first <code class="command">COMMIT</code> or
    <code class="command">ROLLBACK</code> rather than row by row.  The cursor is still
    removed automatically after the loop, so this is mostly invisible to the
    user.
   </p><p>
    Transaction commands are not allowed in cursor loops driven by commands
    that are not read-only (for example <code class="command">UPDATE
    ... RETURNING</code>).
   </p><p>
    A transaction cannot be ended inside a block with exception handlers.
   </p></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="plpgsql-cursors.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="plpgsql.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="plpgsql-errors-and-messages.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">43.7. Cursors </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 43.9. Errors and Messages</td></tr></table></div></body></html>