mirror of
https://github.com/postgres/postgres.git
synced 2025-05-31 03:21:24 +03:00
In each of the supplied procedural languages (PL/pgSQL, PL/Perl, PL/Python, PL/Tcl), add language-specific commit and rollback functions/commands to control transactions in procedures in that language. Add similar underlying functions to SPI. Some additional cleanup so that transaction commit or abort doesn't blow away data structures still used by the procedure call. Add execution context tracking to CALL and DO statements so that transaction control commands can only be issued in top-level procedure and block calls, not function calls or other procedure or block calls. - SPI Add a new function SPI_connect_ext() that is like SPI_connect() but allows passing option flags. The only option flag right now is SPI_OPT_NONATOMIC. A nonatomic SPI connection can execute transaction control commands, otherwise it's not allowed. This is meant to be passed down from CALL and DO statements which themselves know in which context they are called. A nonatomic SPI connection uses different memory management. A normal SPI connection allocates its memory in TopTransactionContext. For nonatomic connections we use PortalContext instead. As the comment in SPI_connect_ext() (previously SPI_connect()) indicates, one could potentially use PortalContext in all cases, but it seems safest to leave the existing uses alone, because this stuff is complicated enough already. SPI also gets new functions SPI_start_transaction(), SPI_commit(), and SPI_rollback(), which can be used by PLs to implement their transaction control logic. - portalmem.c Some adjustments were made in the code that cleans up portals at transaction abort. The portal code could already handle a command *committing* a transaction and continuing (e.g., VACUUM), but it was not quite prepared for a command *aborting* a transaction and continuing. In AtAbort_Portals(), remove the code that marks an active portal as failed. As the comment there already predicted, this doesn't work if the running command wants to keep running after transaction abort. And it's actually not necessary, because pquery.c is careful to run all portal code in a PG_TRY block and explicitly runs MarkPortalFailed() if there is an exception. So the code in AtAbort_Portals() is never used anyway. In AtAbort_Portals() and AtCleanup_Portals(), we need to be careful not to clean up active portals too much. This mirrors similar code in PreCommit_Portals(). - PL/Perl Gets new functions spi_commit() and spi_rollback() - PL/pgSQL Gets new commands COMMIT and ROLLBACK. Update the PL/SQL porting example in the documentation to reflect that transactions are now possible in procedures. - PL/Python Gets new functions plpy.commit and plpy.rollback. - PL/Tcl Gets new commands commit and rollback. Reviewed-by: Andrew Dunstan <andrew.dunstan@2ndquadrant.com>
136 lines
3.6 KiB
Plaintext
136 lines
3.6 KiB
Plaintext
<!--
|
|
doc/src/sgml/ref/do.sgml
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="sql-do">
|
|
<indexterm zone="sql-do">
|
|
<primary>DO</primary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="sql-do">
|
|
<primary>anonymous code blocks</primary>
|
|
</indexterm>
|
|
|
|
<refmeta>
|
|
<refentrytitle>DO</refentrytitle>
|
|
<manvolnum>7</manvolnum>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>DO</refname>
|
|
<refpurpose>execute an anonymous code block</refpurpose>
|
|
</refnamediv>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
DO [ LANGUAGE <replaceable class="parameter">lang_name</replaceable> ] <replaceable class="parameter">code</replaceable>
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1>
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>DO</command> executes an anonymous code block, or in other
|
|
words a transient anonymous function in a procedural language.
|
|
</para>
|
|
|
|
<para>
|
|
The code block is treated as though it were the body of a function
|
|
with no parameters, returning <type>void</type>. It is parsed and
|
|
executed a single time.
|
|
</para>
|
|
|
|
<para>
|
|
The optional <literal>LANGUAGE</literal> clause can be written either
|
|
before or after the code block.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">code</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The procedural language code to be executed. This must be specified
|
|
as a string literal, just as in <command>CREATE FUNCTION</command>.
|
|
Use of a dollar-quoted literal is recommended.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">lang_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name of the procedural language the code is written in.
|
|
If omitted, the default is <literal>plpgsql</literal>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
The procedural language to be used must already have been installed
|
|
into the current database by means of <command>CREATE LANGUAGE</command>.
|
|
<literal>plpgsql</literal> is installed by default, but other languages are not.
|
|
</para>
|
|
|
|
<para>
|
|
The user must have <literal>USAGE</literal> privilege for the procedural
|
|
language, or must be a superuser if the language is untrusted.
|
|
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">
|
|
<title id="sql-do-examples-title">Examples</title>
|
|
<para>
|
|
Grant all privileges on all views in schema <literal>public</literal> to
|
|
role <literal>webuser</literal>:
|
|
<programlisting>
|
|
DO $$DECLARE r record;
|
|
BEGIN
|
|
FOR r IN SELECT table_schema, table_name FROM information_schema.tables
|
|
WHERE table_type = 'VIEW' AND table_schema = 'public'
|
|
LOOP
|
|
EXECUTE 'GRANT ALL ON ' || quote_ident(r.table_schema) || '.' || quote_ident(r.table_name) || ' TO webuser';
|
|
END LOOP;
|
|
END$$;
|
|
</programlisting></para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
There is no <command>DO</command> statement in the SQL standard.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>See Also</title>
|
|
|
|
<simplelist type="inline">
|
|
<member><xref linkend="sql-createlanguage"/></member>
|
|
</simplelist>
|
|
</refsect1>
|
|
</refentry>
|