diff options
Diffstat (limited to 'doc/src')
-rw-r--r-- | doc/src/sgml/plperl.sgml | 54 | ||||
-rw-r--r-- | doc/src/sgml/plpgsql.sgml | 91 | ||||
-rw-r--r-- | doc/src/sgml/plpython.sgml | 41 | ||||
-rw-r--r-- | doc/src/sgml/pltcl.sgml | 41 | ||||
-rw-r--r-- | doc/src/sgml/ref/call.sgml | 7 | ||||
-rw-r--r-- | doc/src/sgml/ref/create_procedure.sgml | 7 | ||||
-rw-r--r-- | doc/src/sgml/ref/do.sgml | 7 | ||||
-rw-r--r-- | doc/src/sgml/spi.sgml | 177 |
8 files changed, 381 insertions, 44 deletions
diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml index 100162dead5..cff7a847dee 100644 --- a/doc/src/sgml/plperl.sgml +++ b/doc/src/sgml/plperl.sgml @@ -661,6 +661,60 @@ SELECT release_hosts_query(); </para> </listitem> </varlistentry> + + <varlistentry> + <term> + <literal><function>spi_commit()</function></literal> + <indexterm> + <primary>spi_commit</primary> + <secondary>in PL/Perl</secondary> + </indexterm> + </term> + <term> + <literal><function>spi_rollback()</function></literal> + <indexterm> + <primary>spi_rollback</primary> + <secondary>in PL/Perl</secondary> + </indexterm> + </term> + <listitem> + <para> + Commit or roll back the current transaction. This can only be called + in a procedure or anonymous code block (<command>DO</command> command) + called from the top level. (Note that it is not possible to run the + SQL commands <command>COMMIT</command> or <command>ROLLBACK</command> + via <function>spi_exec_query</function> or similar. It has to be done + using these functions.) After a transaction is ended, a new + transaction is automatically started, so there is no separate function + for that. + </para> + + <para> + Here is an example: +<programlisting> +CREATE PROCEDURE transaction_test1() +LANGUAGE plperl +AS $$ +foreach my $i (0..9) { + spi_exec_query("INSERT INTO test1 (a) VALUES ($i)"); + if ($i % 2 == 0) { + spi_commit(); + } else { + spi_rollback(); + } +} +$$; + +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> </sect2> diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index ddd054c6cc5..90a3c00dfe8 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -3449,6 +3449,48 @@ END LOOP <optional> <replaceable>label</replaceable> </optional>; </sect1> + <sect1 id="plpgsql-transactions"> + <title>Transaction Management</title> + + <para> + In procedures invoked by the <command>CALL</command> command from the top + level as well as in anonymous code blocks (<command>DO</command> command) + called from the top level, it is possible to end transactions using the + commands <command>COMMIT</command> and <command>ROLLBACK</command>. A new + transaction is started automatically after a transaction is ended using + these commands, so there is no separate <command>START + TRANSACTION</command> command. (Note that <command>BEGIN</command> and + <command>END</command> have different meanings in PL/pgSQL.) + </para> + + <para> + Here is a simple example: +<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(); +</programlisting> + </para> + + <para> + A transaction cannot be ended inside a loop over a query result, nor + inside a block with exception handlers. + </para> + </sect1> + <sect1 id="plpgsql-errors-and-messages"> <title>Errors and Messages</title> @@ -5432,14 +5474,13 @@ SELECT * FROM cs_parse_url('http://foobar.com/query.cgi?baz'); <programlisting> CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS a_running_job_count INTEGER; - PRAGMA AUTONOMOUS_TRANSACTION; -- <co id="co.plpgsql-porting-pragma"/> BEGIN - LOCK TABLE cs_jobs IN EXCLUSIVE MODE; -- <co id="co.plpgsql-porting-locktable"/> + LOCK TABLE cs_jobs IN EXCLUSIVE MODE; SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL; IF a_running_job_count > 0 THEN - COMMIT; -- free lock <co id="co.plpgsql-porting-commit"/> + COMMIT; -- free lock raise_application_error(-20000, 'Unable to create a new job: a job is currently running.'); END IF; @@ -5460,44 +5501,10 @@ show errors </para> <para> - Procedures like this can easily be converted into <productname>PostgreSQL</productname> - functions returning <type>void</type>. This procedure in - particular is interesting because it can teach us some things: - - <calloutlist> - <callout arearefs="co.plpgsql-porting-pragma"> - <para> - There is no <literal>PRAGMA</literal> statement in <productname>PostgreSQL</productname>. - </para> - </callout> - - <callout arearefs="co.plpgsql-porting-locktable"> - <para> - If you do a <command>LOCK TABLE</command> in <application>PL/pgSQL</application>, - the lock will not be released until the calling transaction is - finished. - </para> - </callout> - - <callout arearefs="co.plpgsql-porting-commit"> - <para> - You cannot issue <command>COMMIT</command> in a - <application>PL/pgSQL</application> function. The function is - running within some outer transaction and so <command>COMMIT</command> - would imply terminating the function's execution. However, in - this particular case it is not necessary anyway, because the lock - obtained by the <command>LOCK TABLE</command> will be released when - we raise an error. - </para> - </callout> - </calloutlist> - </para> - - <para> This is how we could port this procedure to <application>PL/pgSQL</application>: <programlisting> -CREATE OR REPLACE FUNCTION cs_create_job(v_job_id integer) RETURNS void AS $$ +CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id integer) AS $$ DECLARE a_running_job_count integer; BEGIN @@ -5506,6 +5513,7 @@ BEGIN SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL; IF a_running_job_count > 0 THEN + COMMIT; -- free lock RAISE EXCEPTION 'Unable to create a new job: a job is currently running'; -- <co id="co.plpgsql-porting-raise"/> END IF; @@ -5518,6 +5526,7 @@ BEGIN WHEN unique_violation THEN -- <co id="co.plpgsql-porting-exception"/> -- don't worry if it already exists END; + COMMIT; END; $$ LANGUAGE plpgsql; </programlisting> @@ -5541,12 +5550,6 @@ $$ LANGUAGE plpgsql; </para> </callout> </calloutlist> - - The main functional difference between this procedure and the - Oracle equivalent is that the exclusive lock on the <literal>cs_jobs</literal> - table will be held until the calling transaction completes. Also, if - the caller later aborts (for example due to an error), the effects of - this procedure will be rolled back. </para> </example> </sect2> diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml index 0dbeee1fa2e..ba79beb7437 100644 --- a/doc/src/sgml/plpython.sgml +++ b/doc/src/sgml/plpython.sgml @@ -1370,6 +1370,47 @@ $$ LANGUAGE plpythonu; </sect2> </sect1> + <sect1 id="plpython-transactions"> + <title>Transaction Management</title> + + <para> + In a procedure called from the top level or an anonymous code block + (<command>DO</command> command) called from the top level it is possible to + control transactions. To commit the current transaction, call + <literal>plpy.commit()</literal>. To roll back the current transaction, + call <literal>plpy.rollback()</literal>. (Note that it is not possible to + run the SQL commands <command>COMMIT</command> or + <command>ROLLBACK</command> via <function>plpy.execute</function> or + similar. It has to be done using these functions.) After a transaction is + ended, a new transaction is automatically started, so there is no separate + function for that. + </para> + + <para> + Here is an example: +<programlisting> +CREATE PROCEDURE transaction_test1() +LANGUAGE plpythonu +AS $$ +for i in range(0, 10): + plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i) + if i % 2 == 0: + plpy.commit() + else: + plpy.rollback() +$$; + +CALL transaction_test1(); +</programlisting> + </para> + + <para> + Transactions cannot be ended when a cursor created by + <literal>plpy.cursor</literal> is open or when an explicit subtransaction + is active. + </para> + </sect1> + <sect1 id="plpython-util"> <title>Utility Functions</title> <para> diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml index 8018783b0a0..a834ab8862b 100644 --- a/doc/src/sgml/pltcl.sgml +++ b/doc/src/sgml/pltcl.sgml @@ -1002,6 +1002,47 @@ $$ LANGUAGE pltcl; </para> </sect1> + <sect1 id="pltcl-transactions"> + <title>Transaction Management</title> + + <para> + In a procedure called from the top level or an anonymous code block + (<command>DO</command> command) called from the top level it is possible + to control transactions. To commit the current transaction, call the + <literal>commit</literal> command. To roll back the current transaction, + call the <literal>rollback</literal> command. (Note that it is not + possible to run the SQL commands <command>COMMIT</command> or + <command>ROLLBACK</command> via <function>spi_exec</function> or similar. + It has to be done using these functions.) After a transaction is ended, + a new transaction is automatically started, so there is no separate + command for that. + </para> + + <para> + Here is an example: +<programlisting> +CREATE PROCEDURE transaction_test1() +LANGUAGE pltcl +AS $$ +for {set i 0} {$i < 10} {incr i} { + spi_exec "INSERT INTO test1 (a) VALUES ($i)" + if {$i % 2 == 0} { + commit + } else { + rollback + } +} +$$; + +CALL transaction_test1(); +</programlisting> + </para> + + <para> + Transactions cannot be ended when an explicit subtransaction is active. + </para> + </sect1> + <sect1 id="pltcl-config"> <title>PL/Tcl Configuration</title> diff --git a/doc/src/sgml/ref/call.sgml b/doc/src/sgml/ref/call.sgml index 2741d8d15ec..03da4518ee2 100644 --- a/doc/src/sgml/ref/call.sgml +++ b/doc/src/sgml/ref/call.sgml @@ -70,6 +70,13 @@ CALL <replaceable class="parameter">name</replaceable> ( [ <replaceable class="p <para> To call a function (not a procedure), use <command>SELECT</command> instead. </para> + + <para> + If <command>CALL</command> is executed in a transaction block, then the + called procedure cannot execute transaction control statements. + Transaction control statements are only allowed if <command>CALL</command> + is executed in its own transaction. + </para> </refsect1> <refsect1> diff --git a/doc/src/sgml/ref/create_procedure.sgml b/doc/src/sgml/ref/create_procedure.sgml index d712043824a..bbf8b03d04e 100644 --- a/doc/src/sgml/ref/create_procedure.sgml +++ b/doc/src/sgml/ref/create_procedure.sgml @@ -229,6 +229,13 @@ CREATE [ OR REPLACE ] PROCEDURE </para> <para> + If a <literal>SET</literal> clause is attached to a procedure, then + that procedure cannot execute transaction control statements (for + example, <command>COMMIT</command> and <command>ROLLBACK</command>, + depending on the language). + </para> + + <para> See <xref linkend="sql-set"/> and <xref linkend="runtime-config"/> for more information about allowed parameter names and values. diff --git a/doc/src/sgml/ref/do.sgml b/doc/src/sgml/ref/do.sgml index 061218b135a..b9a6f9a6fd6 100644 --- a/doc/src/sgml/ref/do.sgml +++ b/doc/src/sgml/ref/do.sgml @@ -91,6 +91,13 @@ DO [ LANGUAGE <replaceable class="parameter">lang_name</replaceable> ] <replacea This is the same privilege requirement as for creating a function in the language. </para> + + <para> + If <command>DO</command> is executed in a transaction block, then the + procedure code cannot execute transaction control statements. Transaction + control statements are only allowed if <command>DO</command> is executed in + its own transaction. + </para> </refsect1> <refsect1 id="sql-do-examples"> diff --git a/doc/src/sgml/spi.sgml b/doc/src/sgml/spi.sgml index 350f0863e92..10448922b1d 100644 --- a/doc/src/sgml/spi.sgml +++ b/doc/src/sgml/spi.sgml @@ -64,6 +64,7 @@ <refentry id="spi-spi-connect"> <indexterm><primary>SPI_connect</primary></indexterm> + <indexterm><primary>SPI_connect_ext</primary></indexterm> <refmeta> <refentrytitle>SPI_connect</refentrytitle> @@ -72,6 +73,7 @@ <refnamediv> <refname>SPI_connect</refname> + <refname>SPI_connect_ext</refname> <refpurpose>connect a procedure to the SPI manager</refpurpose> </refnamediv> @@ -79,6 +81,10 @@ <synopsis> int SPI_connect(void) </synopsis> + + <synopsis> +int SPI_connect_ext(int <parameter>options</parameter>) +</synopsis> </refsynopsisdiv> <refsect1> @@ -90,6 +96,31 @@ int SPI_connect(void) function if you want to execute commands through SPI. Some utility SPI functions can be called from unconnected procedures. </para> + + <para> + <function>SPI_connect_ext</function> does the same but has an argument that + allows passing option flags. Currently, the following option values are + available: + <variablelist> + <varlistentry> + <term><symbol>SPI_OPT_NONATOMIC</symbol></term> + <listitem> + <para> + Sets the SPI connection to be <firstterm>nonatomic</firstterm>, which + means that transaction control calls <function>SPI_commit</function>, + <function>SPI_rollback</function>, and + <function>SPI_start_transaction</function> are allowed. Otherwise, + calling these functions will result in an immediate error. + </para> + </listitem> + </varlistentry> + </variablelist> + </para> + + <para> + <literal>SPI_connect()</literal> is equivalent to + <literal>SPI_connect_ext(0)</literal>. + </para> </refsect1> <refsect1> @@ -4325,6 +4356,152 @@ int SPI_freeplan(SPIPlanPtr <parameter>plan</parameter>) </sect1> + <sect1 id="spi-transaction"> + <title>Transaction Management</title> + + <para> + It is not possible to run transaction control commands such + as <command>COMMIT</command> and <command>ROLLBACK</command> through SPI + functions such as <function>SPI_execute</function>. There are, however, + separate interface functions that allow transaction control through SPI. + </para> + + <para> + It is not generally safe and sensible to start and end transactions in + arbitrary user-defined SQL-callable functions without taking into account + the context in which they are called. For example, a transaction boundary + in the middle of a function that is part of a complex SQL expression that + is part of some SQL command will probably result in obscure internal errors + or crashes. The interface functions presented here are primarily intended + to be used by procedural language implementations to support transaction + management in procedures that are invoked by the <command>CALL</command> + command, taking the context of the <command>CALL</command> invocation into + account. SPI procedures implemented in C can implement the same logic, but + the details of that are beyond the scope of this documentation. + </para> + +<!-- *********************************************** --> + +<refentry id="spi-spi-commit"> + <indexterm><primary>SPI_commit</primary></indexterm> + + <refmeta> + <refentrytitle>SPI_commit</refentrytitle> + <manvolnum>3</manvolnum> + </refmeta> + + <refnamediv> + <refname>SPI_commit</refname> + <refpurpose>commit the current transaction</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +void SPI_commit(void) +</synopsis> + </refsynopsisdiv> + + <refsect1> + <title>Description</title> + + <para> + <function>SPI_commit</function> commits the current transaction. It is + approximately equivalent to running the SQL + command <command>COMMIT</command>. After a transaction is committed, a new + transaction has to be started + using <function>SPI_start_transaction</function> before further database + actions can be executed. + </para> + + <para> + This function can only be executed if the SPI connection has been set as + nonatomic in the call to <function>SPI_connect_ext</function>. + </para> + </refsect1> +</refentry> + +<!-- *********************************************** --> + +<refentry id="spi-spi-rollback"> + <indexterm><primary>SPI_rollback</primary></indexterm> + + <refmeta> + <refentrytitle>SPI_rollback</refentrytitle> + <manvolnum>3</manvolnum> + </refmeta> + + <refnamediv> + <refname>SPI_rollback</refname> + <refpurpose>abort the current transaction</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +void SPI_rollback(void) +</synopsis> + </refsynopsisdiv> + + <refsect1> + <title>Description</title> + + <para> + <function>SPI_rollback</function> rolls back the current transaction. It + is approximately equivalent to running the SQL + command <command>ROLLBACK</command>. After a transaction is rolled back, a + new transaction has to be started + using <function>SPI_start_transaction</function> before further database + actions can be executed. + </para> + + <para> + This function can only be executed if the SPI connection has been set as + nonatomic in the call to <function>SPI_connect_ext</function>. + </para> + </refsect1> +</refentry> + +<!-- *********************************************** --> + +<refentry id="spi-spi-start-transaction"> + <indexterm><primary>SPI_start_transaction</primary></indexterm> + + <refmeta> + <refentrytitle>SPI_start_transaction</refentrytitle> + <manvolnum>3</manvolnum> + </refmeta> + + <refnamediv> + <refname>SPI_start_transaction</refname> + <refpurpose>start a new transaction</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +void SPI_start_transaction(void) +</synopsis> + </refsynopsisdiv> + + <refsect1> + <title>Description</title> + + <para> + <function>SPI_start_transaction</function> starts a new transaction. It + can only be called after <function>SPI_commit</function> + or <function>SPI_rollback</function>, as there is no transaction active at + that point. Normally, when an SPI procedure is called, there is already a + transaction active, so attempting to start another one before closing out + the current one will result in an error. + </para> + + <para> + This function can only be executed if the SPI connection has been set as + nonatomic in the call to <function>SPI_connect_ext</function>. + </para> + </refsect1> +</refentry> + + </sect1> + <sect1 id="spi-visibility"> <title>Visibility of Data Changes</title> |