aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/set_transaction.sgml
blob: cbe41d7175fa3beb1e7575df5a02132e94d84196 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/ref/set_transaction.sgml,v 1.17 2003/09/11 21:42:20 momjian Exp $ -->
<refentry id="SQL-SET-TRANSACTION">
 <refmeta>
  <refentrytitle id="SQL-SET-TRANSACTION-TITLE">SET TRANSACTION</refentrytitle>
  <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>

 <refsynopsisdiv>
<synopsis>
SET TRANSACTION
    [ ISOLATION LEVEL { READ COMMITTED | SERIALIZABLE } ] [ READ WRITE | READ ONLY ]
SET SESSION CHARACTERISTICS AS TRANSACTION
    [ ISOLATION LEVEL { READ COMMITTED | SERIALIZABLE } ] [ READ WRITE | READ ONLY ]
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   The <command>SET TRANSACTION</command> command sets the transaction
   characteristics of the current transaction. It has no effect on any
   subsequent transactions.  <command>SET SESSION
   CHARACTERISTICS</command> sets the default transaction
   characteristics for each transaction of a session.  <command>SET
   TRANSACTION</command> can override it for an individual
   transaction.
  </para>

  <para>
   The available transaction characteristics are the transaction
   isolation level and the transaction access mode (read/write or
   read-only).
  </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>SERIALIZABLE</literal></term>
     <listitem>
      <para>
       The current transaction can only see rows committed before
       first query or data-modification statement was executed in this transaction.
      </para>
      <tip>
       <para>
        Intuitively, serializable means that two concurrent
        transactions will leave the database in the same state as if
        the two has been executed strictly after one another in either
        order.
       </para>
      </tip>
     </listitem>
    </varlistentry>
   </variablelist>

   The transaction isolation level cannot be set after the first query
   or data-modification statement (<command>SELECT</command>,
   <command>INSERT</command>, <command>DELETE</command>,
   <command>UPDATE</command>, <command>FETCH</command>,
   <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 TO</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 writes to disk.
  </para>
 </refsect1>

 <refsect1>
  <title>Notes</title>

  <para>
   The session default transaction isolation level can also be set
   with the command
<programlisting>
SET default_transaction_isolation = '<replaceable>value</replaceable>'
</programlisting>
   and in the configuration file.  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
   described above.  <productname>PostgreSQL</productname> does not
   provide the isolation levels <literal>READ UNCOMMITTED</literal>
   and <literal>REPEATABLE READ</literal>. Because of multiversion
   concurrency control, the <literal>SERIALIZABLE</literal> level is
   not truly serializable. See <xref linkend="mvcc"> for details.
  </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 only for use in embedded SQL.
  </para>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->