1SET TRANSACTION(7)       PostgreSQL 14.3 Documentation      SET TRANSACTION(7)
2
3
4

NAME

6       SET_TRANSACTION - set the characteristics of the current transaction
7

SYNOPSIS

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

DESCRIPTION

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, FETCH,
56       or COPY) of a transaction has been executed. See Chapter 13 for more
57       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, and COPY FROM if the table they would write to is not a
63       temporary table; all CREATE, ALTER, and DROP commands; COMMENT, GRANT,
64       REVOKE, TRUNCATE; and EXPLAIN ANALYZE and EXECUTE if the command they
65       would execute is among those listed. This is a high-level notion of
66       read-only that does not prevent all writes to disk.
67
68       The DEFERRABLE transaction property has no effect unless the
69       transaction is also SERIALIZABLE and READ ONLY. When all three of these
70       properties are selected for a transaction, the transaction may block
71       when first acquiring its snapshot, after which it is able to run
72       without the normal overhead of a SERIALIZABLE transaction and without
73       any risk of contributing to or being canceled by a serialization
74       failure. This mode is well suited for long-running reports or backups.
75
76       The SET TRANSACTION SNAPSHOT command allows a new transaction to run
77       with the same snapshot as an existing transaction. The pre-existing
78       transaction must have exported its snapshot with the pg_export_snapshot
79       function (see Section 9.27.5). That function returns a snapshot
80       identifier, which must be given to SET TRANSACTION SNAPSHOT to specify
81       which snapshot is to be imported. The identifier must be written as a
82       string literal in this command, for example '000003A1-1'.  SET
83       TRANSACTION SNAPSHOT can only be executed at the start of a
84       transaction, before the first query or data-modification statement
85       (SELECT, INSERT, DELETE, UPDATE, FETCH, or COPY) of the transaction.
86       Furthermore, the transaction must already be set to SERIALIZABLE or
87       REPEATABLE READ isolation level (otherwise, the snapshot would be
88       discarded immediately, since READ COMMITTED mode takes a new snapshot
89       for each command). If the importing transaction uses SERIALIZABLE
90       isolation level, then the transaction that exported the snapshot must
91       also use that isolation level. Also, a non-read-only serializable
92       transaction cannot import a snapshot from a read-only transaction.
93

NOTES

95       If SET TRANSACTION is executed without a prior START TRANSACTION or
96       BEGIN, it emits a warning and otherwise has no effect.
97
98       It is possible to dispense with SET TRANSACTION by instead specifying
99       the desired transaction_modes in BEGIN or START TRANSACTION. But that
100       option is not available for SET TRANSACTION SNAPSHOT.
101
102       The session default transaction modes can also be set or examined via
103       the configuration parameters default_transaction_isolation,
104       default_transaction_read_only, and default_transaction_deferrable. (In
105       fact SET SESSION CHARACTERISTICS is just a verbose equivalent for
106       setting these variables with SET.) This means the defaults can be set
107       in the configuration file, via ALTER DATABASE, etc. Consult Chapter 20
108       for more information.
109
110       The current transaction's modes can similarly be set or examined via
111       the configuration parameters transaction_isolation,
112       transaction_read_only, and transaction_deferrable. Setting one of these
113       parameters acts the same as the corresponding SET TRANSACTION option,
114       with the same restrictions on when it can be done. However, these
115       parameters cannot be set in the configuration file, or from any source
116       other than live SQL.
117

EXAMPLES

119       To begin a new transaction with the same snapshot as an already
120       existing transaction, first export the snapshot from the existing
121       transaction. That will return the snapshot identifier, for example:
122
123           BEGIN TRANSACTION ISOLATION LEVEL REPEATABLE READ;
124           SELECT pg_export_snapshot();
125            pg_export_snapshot
126           ---------------------
127            00000003-0000001B-1
128           (1 row)
129
130       Then give the snapshot identifier in a SET TRANSACTION SNAPSHOT command
131       at the beginning of the newly opened transaction:
132
133           BEGIN TRANSACTION ISOLATION LEVEL REPEATABLE READ;
134           SET TRANSACTION SNAPSHOT '00000003-0000001B-1';
135

COMPATIBILITY

137       These commands are defined in the SQL standard, except for the
138       DEFERRABLE transaction mode and the SET TRANSACTION SNAPSHOT form,
139       which are PostgreSQL extensions.
140
141       SERIALIZABLE is the default transaction isolation level in the
142       standard. In PostgreSQL the default is ordinarily READ COMMITTED, but
143       you can change it as mentioned above.
144
145       In the SQL standard, there is one other transaction characteristic that
146       can be set with these commands: the size of the diagnostics area. This
147       concept is specific to embedded SQL, and therefore is not implemented
148       in the PostgreSQL server.
149
150       The SQL standard requires commas between successive transaction_modes,
151       but for historical reasons PostgreSQL allows the commas to be omitted.
152
153
154
155PostgreSQL 14.3                      2022                   SET TRANSACTION(7)
Impressum