
Until now, our Serializable mode has in fact been what's called Snapshot Isolation, which allows some anomalies that could not occur in any serialized ordering of the transactions. This patch fixes that using a method called Serializable Snapshot Isolation, based on research papers by Michael J. Cahill (see README-SSI for full references). In Serializable Snapshot Isolation, transactions run like they do in Snapshot Isolation, but a predicate lock manager observes the reads and writes performed and aborts transactions if it detects that an anomaly might occur. This method produces some false positives, ie. it sometimes aborts transactions even though there is no anomaly. To track reads we implement predicate locking, see storage/lmgr/predicate.c. Whenever a tuple is read, a predicate lock is acquired on the tuple. Shared memory is finite, so when a transaction takes many tuple-level locks on a page, the locks are promoted to a single page-level lock, and further to a single relation level lock if necessary. To lock key values with no matching tuple, a sequential scan always takes a relation-level lock, and an index scan acquires a page-level lock that covers the search key, whether or not there are any matching keys at the moment. A predicate lock doesn't conflict with any regular locks or with another predicate locks in the normal sense. They're only used by the predicate lock manager to detect the danger of anomalies. Only serializable transactions participate in predicate locking, so there should be no extra overhead for for other transactions. Predicate locks can't be released at commit, but must be remembered until all the transactions that overlapped with it have completed. That means that we need to remember an unbounded amount of predicate locks, so we apply a lossy but conservative method of tracking locks for committed transactions. If we run short of shared memory, we overflow to a new "pg_serial" SLRU pool. We don't currently allow Serializable transactions in Hot Standby mode. That would be hard, because even read-only transactions can cause anomalies that wouldn't otherwise occur. Serializable isolation mode now means the new fully serializable level. Repeatable Read gives you the old Snapshot Isolation level that we have always had. Kevin Grittner and Dan Ports, reviewed by Jeff Davis, Heikki Linnakangas and Anssi Kääriäinen
203 lines
7.1 KiB
Plaintext
203 lines
7.1 KiB
Plaintext
<!-- doc/src/sgml/ref/set_transaction.sgml -->
|
|
<refentry id="SQL-SET-TRANSACTION">
|
|
<refmeta>
|
|
<refentrytitle>SET TRANSACTION</refentrytitle>
|
|
<manvolnum>7</manvolnum>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>SET TRANSACTION</refname>
|
|
<refpurpose>set the characteristics of the current transaction</refpurpose>
|
|
</refnamediv>
|
|
|
|
<indexterm zone="sql-set-transaction">
|
|
<primary>SET TRANSACTION</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>transaction isolation level</primary>
|
|
<secondary>setting</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>read-only transaction</primary>
|
|
<secondary>setting</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>deferrable transaction</primary>
|
|
<secondary>setting</secondary>
|
|
</indexterm>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
SET TRANSACTION <replaceable class="parameter">transaction_mode</replaceable> [, ...]
|
|
SET SESSION CHARACTERISTICS AS TRANSACTION <replaceable class="parameter">transaction_mode</replaceable> [, ...]
|
|
|
|
<phrase>where <replaceable class="parameter">transaction_mode</replaceable> is one of:</phrase>
|
|
|
|
ISOLATION LEVEL { SERIALIZABLE | REPEATABLE READ | READ COMMITTED | READ UNCOMMITTED }
|
|
READ WRITE | READ ONLY
|
|
[ NOT ] DEFERRABLE
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1>
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
The <command>SET TRANSACTION</command> command sets the
|
|
characteristics of the current transaction. It has no effect on any
|
|
subsequent transactions. <command>SET SESSION
|
|
CHARACTERISTICS</command> sets the default transaction
|
|
characteristics for subsequent transactions of a session. These
|
|
defaults can be overridden by <command>SET TRANSACTION</command>
|
|
for an individual transaction.
|
|
</para>
|
|
|
|
<para>
|
|
The available transaction characteristics are the transaction
|
|
isolation level, the transaction access mode (read/write or
|
|
read-only), and the deferrable mode.
|
|
</para>
|
|
|
|
<para>
|
|
The isolation level of a transaction determines what data the
|
|
transaction can see when other transactions are running concurrently:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><literal>READ COMMITTED</literal></term>
|
|
<listitem>
|
|
<para>
|
|
A statement can only see rows committed before it began. This
|
|
is the default.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>REPEATABLE READ</literal></term>
|
|
<listitem>
|
|
<para>
|
|
All statements of the current transaction can only see rows committed
|
|
before the first query or data-modification statement was executed in
|
|
this transaction.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SERIALIZABLE</literal></term>
|
|
<listitem>
|
|
<para>
|
|
All statements of the current transaction can only see rows committed
|
|
before the first query or data-modification statement was executed in
|
|
this transaction. If a pattern of reads and writes among concurrent
|
|
serializable transactions would create a situation which could not
|
|
have occurred for any serial (one-at-a-time) execution of those
|
|
transactions, one of them will be rolled back with a
|
|
<literal>serialization_failure</literal> <literal>SQLSTATE</literal>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
|
|
The SQL standard defines one additional level, <literal>READ
|
|
UNCOMMITTED</literal>.
|
|
In <productname>PostgreSQL</productname> <literal>READ
|
|
UNCOMMITTED</literal> is treated as <literal>READ COMMITTED</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
The transaction isolation level cannot be changed after the first query or
|
|
data-modification statement (<command>SELECT</command>,
|
|
<command>INSERT</command>, <command>DELETE</command>,
|
|
<command>UPDATE</command>, <command>FETCH</command>, or
|
|
<command>COPY</command>) of a transaction has been executed. See
|
|
<xref linkend="mvcc"> for more information about transaction
|
|
isolation and concurrency control.
|
|
</para>
|
|
|
|
<para>
|
|
The transaction access mode determines whether the transaction is
|
|
read/write or read-only. Read/write is the default. When a
|
|
transaction is read-only, the following SQL commands are
|
|
disallowed: <literal>INSERT</literal>, <literal>UPDATE</literal>,
|
|
<literal>DELETE</literal>, and <literal>COPY FROM</literal> if the
|
|
table they would write to is not a temporary table; all
|
|
<literal>CREATE</literal>, <literal>ALTER</literal>, and
|
|
<literal>DROP</literal> commands; <literal>COMMENT</literal>,
|
|
<literal>GRANT</literal>, <literal>REVOKE</literal>,
|
|
<literal>TRUNCATE</literal>; and <literal>EXPLAIN ANALYZE</literal>
|
|
and <literal>EXECUTE</literal> if the command they would execute is
|
|
among those listed. This is a high-level notion of read-only that
|
|
does not prevent all writes to disk.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
If <command>SET TRANSACTION</command> is executed without a prior
|
|
<command>START TRANSACTION</command> or <command>BEGIN</command>,
|
|
it will appear to have no effect, since the transaction will immediately
|
|
end.
|
|
</para>
|
|
|
|
<para>
|
|
It is possible to dispense with <command>SET TRANSACTION</command>
|
|
by instead specifying the desired <replaceable
|
|
class="parameter">transaction_modes</replaceable> in
|
|
<command>BEGIN</command> or <command>START TRANSACTION</command>.
|
|
</para>
|
|
|
|
<para>
|
|
The session default transaction modes can also be set by setting the
|
|
configuration parameters <xref linkend="guc-default-transaction-isolation">,
|
|
<xref linkend="guc-default-transaction-read-only">, and
|
|
<xref linkend="guc-default-transaction-deferrable">.
|
|
(In fact <command>SET SESSION CHARACTERISTICS</command> is just a
|
|
verbose equivalent for setting these variables with <command>SET</>.)
|
|
This means the defaults can be set in the configuration file, via
|
|
<command>ALTER DATABASE</>, etc. Consult <xref linkend="runtime-config">
|
|
for more information.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1 id="R1-SQL-SET-TRANSACTION-3">
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
Both commands are defined in the <acronym>SQL</acronym> standard.
|
|
<literal>SERIALIZABLE</literal> is the default transaction
|
|
isolation level in the standard. In
|
|
<productname>PostgreSQL</productname> the default is ordinarily
|
|
<literal>READ COMMITTED</literal>, but you can change it as
|
|
mentioned above.
|
|
</para>
|
|
|
|
<para>
|
|
In the SQL standard, there is one other transaction characteristic
|
|
that can be set with these commands: the size of the diagnostics
|
|
area. This concept is specific to embedded SQL, and therefore is
|
|
not implemented in the <productname>PostgreSQL</productname> server.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>DEFERRABLE</literal>
|
|
<replaceable class="parameter">transaction_mode</replaceable>
|
|
is a <productname>PostgreSQL</productname> language extension.
|
|
</para>
|
|
|
|
<para>
|
|
The SQL standard requires commas between successive <replaceable
|
|
class="parameter">transaction_modes</replaceable>, but for historical
|
|
reasons <productname>PostgreSQL</productname> allows the commas to be
|
|
omitted.
|
|
</para>
|
|
</refsect1>
|
|
</refentry>
|