|
- <?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.9. Explicit Subtransactions in PL/Tcl</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 V1.79.1" /><link rel="prev" href="pltcl-error-handling.html" title="43.8. Error Handling in PL/Tcl" /><link rel="next" href="pltcl-transactions.html" title="43.10. Transaction Management" /></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.9. Explicit Subtransactions in PL/Tcl</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="pltcl-error-handling.html" title="43.8. Error Handling in PL/Tcl">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="pltcl.html" title="Chapter 43. PL/Tcl - Tcl Procedural Language">Up</a></td><th width="60%" align="center">Chapter 43. PL/Tcl - Tcl Procedural Language</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="pltcl-transactions.html" title="43.10. Transaction Management">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="PLTCL-SUBTRANSACTIONS"><div class="titlepage"><div><div><h2 class="title" style="clear: both">43.9. Explicit Subtransactions in PL/Tcl</h2></div></div></div><a id="id-1.8.9.13.2" class="indexterm"></a><p>
- Recovering from errors caused by database access as described in
- <a class="xref" href="pltcl-error-handling.html" title="43.8. Error Handling in PL/Tcl">Section 43.8</a> can lead to an undesirable
- situation where some operations succeed before one of them fails,
- and after recovering from that error the data is left in an
- inconsistent state. PL/Tcl offers a solution to this problem in
- the form of explicit subtransactions.
- </p><p>
- Consider a function that implements a transfer between two accounts:
- </p><pre class="programlisting">
- CREATE FUNCTION transfer_funds() RETURNS void AS $$
- if [catch {
- spi_exec "UPDATE accounts SET balance = balance - 100 WHERE account_name = 'joe'"
- spi_exec "UPDATE accounts SET balance = balance + 100 WHERE account_name = 'mary'"
- } errormsg] {
- set result [format "error transferring funds: %s" $errormsg]
- } else {
- set result "funds transferred successfully"
- }
- spi_exec "INSERT INTO operations (result) VALUES ('[quote $result]')"
- $$ LANGUAGE pltcl;
- </pre><p>
- If the second <code class="command">UPDATE</code> statement results in an
- exception being raised, this function will log the failure, but
- the result of the first <code class="command">UPDATE</code> will
- nevertheless be committed. In other words, the funds will be
- withdrawn from Joe's account, but will not be transferred to
- Mary's account. This happens because each <code class="function">spi_exec</code>
- is a separate subtransaction, and only one of those subtransactions
- got rolled back.
- </p><p>
- To handle such cases, you can wrap multiple database operations in an
- explicit subtransaction, which will succeed or roll back as a whole.
- PL/Tcl provides a <code class="function">subtransaction</code> command to manage
- this. We can rewrite our function as:
- </p><pre class="programlisting">
- CREATE FUNCTION transfer_funds2() RETURNS void AS $$
- if [catch {
- subtransaction {
- spi_exec "UPDATE accounts SET balance = balance - 100 WHERE account_name = 'joe'"
- spi_exec "UPDATE accounts SET balance = balance + 100 WHERE account_name = 'mary'"
- }
- } errormsg] {
- set result [format "error transferring funds: %s" $errormsg]
- } else {
- set result "funds transferred successfully"
- }
- spi_exec "INSERT INTO operations (result) VALUES ('[quote $result]')"
- $$ LANGUAGE pltcl;
- </pre><p>
- Note that use of <code class="function">catch</code> is still required for this
- purpose. Otherwise the error would propagate to the top level of the
- function, preventing the desired insertion into
- the <code class="structname">operations</code> table.
- The <code class="function">subtransaction</code> command does not trap errors, it
- only assures that all database operations executed inside its scope will
- be rolled back together when an error is reported.
- </p><p>
- A rollback of an explicit subtransaction occurs on any error reported
- by the contained Tcl code, not only errors originating from database
- access. Thus a regular Tcl exception raised inside
- a <code class="function">subtransaction</code> command will also cause the
- subtransaction to be rolled back. However, non-error exits out of the
- contained Tcl code (for instance, due to <code class="function">return</code>) do
- not cause a rollback.
- </p></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="pltcl-error-handling.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="pltcl.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="pltcl-transactions.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">43.8. Error Handling in PL/Tcl </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 43.10. Transaction Management</td></tr></table></div></body></html>
|