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
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
|
<!-- 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>
<para>
The <literal>DEFERRABLE</literal> transaction property has no effect
unless the transaction is also <literal>SERIALIZABLE</literal> and
<literal>READ ONLY</literal>. When all of these properties are set on a
transaction, the transaction may block when first acquiring its snapshot,
after which it is able to run without the normal overhead of a
<literal>SERIALIZABLE</literal> transaction and without any risk of
contributing to or being canceled by a serialization failure. This mode
is well suited for long-running reports or backups.
</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>
|