1SET TRANSACTION(7) PostgreSQL 16.1 Documentation SET TRANSACTION(7)
2
3
4
6 SET_TRANSACTION - set the characteristics of the current transaction
7
9 SET TRANSACTION transaction_mode [, ...]
10 SET TRANSACTION SNAPSHOT snapshot_id
11 SET SESSION CHARACTERISTICS AS TRANSACTION transaction_mode [, ...]
12
13 where transaction_mode is one of:
14
15 ISOLATION LEVEL { SERIALIZABLE | REPEATABLE READ | READ COMMITTED | READ UNCOMMITTED }
16 READ WRITE | READ ONLY
17 [ NOT ] DEFERRABLE
18
20 The SET TRANSACTION command sets the characteristics of the current
21 transaction. It has no effect on any subsequent transactions. SET
22 SESSION CHARACTERISTICS sets the default transaction characteristics
23 for subsequent transactions of a session. These defaults can be
24 overridden by SET TRANSACTION for an individual transaction.
25
26 The available transaction characteristics are the transaction isolation
27 level, the transaction access mode (read/write or read-only), and the
28 deferrable mode. In addition, a snapshot can be selected, though only
29 for the current transaction, not as a session default.
30
31 The isolation level of a transaction determines what data the
32 transaction can see when other transactions are running concurrently:
33
34 READ COMMITTED
35 A statement can only see rows committed before it began. This is
36 the default.
37
38 REPEATABLE READ
39 All statements of the current transaction can only see rows
40 committed before the first query or data-modification statement was
41 executed in this transaction.
42
43 SERIALIZABLE
44 All statements of the current transaction can only see rows
45 committed before the first query or data-modification statement was
46 executed in this transaction. If a pattern of reads and writes
47 among concurrent serializable transactions would create a situation
48 which could not have occurred for any serial (one-at-a-time)
49 execution of those transactions, one of them will be rolled back
50 with a serialization_failure error.
51 The SQL standard defines one additional level, READ UNCOMMITTED. In
52 PostgreSQL READ UNCOMMITTED is treated as READ COMMITTED.
53
54 The transaction isolation level cannot be changed after the first query
55 or data-modification statement (SELECT, INSERT, DELETE, UPDATE, MERGE,
56 FETCH, or COPY) of a transaction has been executed. See Chapter 13 for
57 more information about transaction isolation and concurrency control.
58
59 The transaction access mode determines whether the transaction is
60 read/write or read-only. Read/write is the default. When a transaction
61 is read-only, the following SQL commands are disallowed: INSERT,
62 UPDATE, DELETE, MERGE, and COPY FROM if the table they would write to
63 is not a temporary table; all CREATE, ALTER, and DROP commands;
64 COMMENT, GRANT, REVOKE, TRUNCATE; and EXPLAIN ANALYZE and EXECUTE if
65 the command they would execute is among those listed. This is a
66 high-level notion of read-only that does not prevent all writes to
67 disk.
68
69 The DEFERRABLE transaction property has no effect unless the
70 transaction is also SERIALIZABLE and READ ONLY. When all three of these
71 properties are selected for a transaction, the transaction may block
72 when first acquiring its snapshot, after which it is able to run
73 without the normal overhead of a SERIALIZABLE transaction and without
74 any risk of contributing to or being canceled by a serialization
75 failure. This mode is well suited for long-running reports or backups.
76
77 The SET TRANSACTION SNAPSHOT command allows a new transaction to run
78 with the same snapshot as an existing transaction. The pre-existing
79 transaction must have exported its snapshot with the pg_export_snapshot
80 function (see Section 9.27.5). That function returns a snapshot
81 identifier, which must be given to SET TRANSACTION SNAPSHOT to specify
82 which snapshot is to be imported. The identifier must be written as a
83 string literal in this command, for example '00000003-0000001B-1'. SET
84 TRANSACTION SNAPSHOT can only be executed at the start of a
85 transaction, before the first query or data-modification statement
86 (SELECT, INSERT, DELETE, UPDATE, MERGE, FETCH, or COPY) of the
87 transaction. Furthermore, the transaction must already be set to
88 SERIALIZABLE or REPEATABLE READ isolation level (otherwise, the
89 snapshot would be discarded immediately, since READ COMMITTED mode
90 takes a new snapshot for each command). If the importing transaction
91 uses SERIALIZABLE isolation level, then the transaction that exported
92 the snapshot must also use that isolation level. Also, a non-read-only
93 serializable transaction cannot import a snapshot from a read-only
94 transaction.
95
97 If SET TRANSACTION is executed without a prior START TRANSACTION or
98 BEGIN, it emits a warning and otherwise has no effect.
99
100 It is possible to dispense with SET TRANSACTION by instead specifying
101 the desired transaction_modes in BEGIN or START TRANSACTION. But that
102 option is not available for SET TRANSACTION SNAPSHOT.
103
104 The session default transaction modes can also be set or examined via
105 the configuration parameters default_transaction_isolation,
106 default_transaction_read_only, and default_transaction_deferrable. (In
107 fact SET SESSION CHARACTERISTICS is just a verbose equivalent for
108 setting these variables with SET.) This means the defaults can be set
109 in the configuration file, via ALTER DATABASE, etc. Consult Chapter 20
110 for more information.
111
112 The current transaction's modes can similarly be set or examined via
113 the configuration parameters transaction_isolation,
114 transaction_read_only, and transaction_deferrable. Setting one of these
115 parameters acts the same as the corresponding SET TRANSACTION option,
116 with the same restrictions on when it can be done. However, these
117 parameters cannot be set in the configuration file, or from any source
118 other than live SQL.
119
121 To begin a new transaction with the same snapshot as an already
122 existing transaction, first export the snapshot from the existing
123 transaction. That will return the snapshot identifier, for example:
124
125 BEGIN TRANSACTION ISOLATION LEVEL REPEATABLE READ;
126 SELECT pg_export_snapshot();
127 pg_export_snapshot
128 ---------------------
129 00000003-0000001B-1
130 (1 row)
131
132 Then give the snapshot identifier in a SET TRANSACTION SNAPSHOT command
133 at the beginning of the newly opened transaction:
134
135 BEGIN TRANSACTION ISOLATION LEVEL REPEATABLE READ;
136 SET TRANSACTION SNAPSHOT '00000003-0000001B-1';
137
139 These commands are defined in the SQL standard, except for the
140 DEFERRABLE transaction mode and the SET TRANSACTION SNAPSHOT form,
141 which are PostgreSQL extensions.
142
143 SERIALIZABLE is the default transaction isolation level in the
144 standard. In PostgreSQL the default is ordinarily READ COMMITTED, but
145 you can change it as mentioned above.
146
147 In the SQL standard, there is one other transaction characteristic that
148 can be set with these commands: the size of the diagnostics area. This
149 concept is specific to embedded SQL, and therefore is not implemented
150 in the PostgreSQL server.
151
152 The SQL standard requires commas between successive transaction_modes,
153 but for historical reasons PostgreSQL allows the commas to be omitted.
154
155
156
157PostgreSQL 16.1 2023 SET TRANSACTION(7)