SET [GLOBAL | SESSION] TRANSACTION
transaction_characteristic [, transaction_characteristic] ...
transaction_characteristic: {
ISOLATION LEVEL level
| access_mode
}
level: {
REPEATABLE READ
| READ COMMITTED
| READ UNCOMMITTED
| SERIALIZABLE
}
access_mode: {
READ WRITE
| READ ONLY
}
This statement specifies
transaction
characteristics. It takes a list of one or more characteristic
values separated by commas. Each characteristic value sets the
transaction isolation
level or access mode. The isolation level is used for
operations on InnoDB
tables. The
access mode specifies whether transactions operate in read/write
or read-only mode.
In addition, SET TRANSACTION
can
include an optional GLOBAL
or
SESSION
keyword to indicate the scope of the
statement.
To set the transaction isolation level, use an
ISOLATION LEVEL
clause. It is not
permitted to specify multiple level
ISOLATION LEVEL
clauses in the same SET
TRANSACTION
statement.
The default isolation level is
REPEATABLE READ
. Other
permitted values are READ
COMMITTED
, READ
UNCOMMITTED
, and
SERIALIZABLE
. For information
about these isolation levels, see
Section 14.7.2.1, “Transaction Isolation Levels”.
To set the transaction access mode, use a READ
WRITE
or READ ONLY
clause. It is
not permitted to specify multiple access-mode clauses in the
same SET TRANSACTION
statement.
By default, a transaction takes place in read/write mode, with
both reads and writes permitted to tables used in the
transaction. This mode may be specified explicitly using
SET TRANSACTION
with an access
mode of READ WRITE
.
If the transaction access mode is set to READ
ONLY
, changes to tables are prohibited. This may
enable storage engines to make performance improvements that are
possible when writes are not permitted.
In read-only mode, it remains possible to change tables created
with the TEMPORARY
keyword using DML
statements. Changes made with DDL statements are not permitted,
just as with permanent tables.
The READ WRITE
and READ
ONLY
access modes also may be specified for an
individual transaction using the
START
TRANSACTION
statement.
You can set transaction characteristics globally, for the current session, or for the next transaction only:
With the
GLOBAL
keyword:The statement applies globally for all subsequent sessions.
Existing sessions are unaffected.
With the
SESSION
keyword:The statement applies to all subsequent transactions performed within the current session.
The statement is permitted within transactions, but does not affect the current ongoing transaction.
If executed between transactions, the statement overrides any preceding statement that sets the next-transaction value of the named characteristics.
Without any
SESSION
orGLOBAL
keyword:The statement applies only to the next single transaction performed within the session.
Subsequent transactions revert to using the session value of the named characteristics.
The statement is not permitted within transactions:
mysql> START TRANSACTION; Query OK, 0 rows affected (0.02 sec) mysql> SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; ERROR 1568 (25001): Transaction characteristics can't be changed while a transaction is in progress
A change to global transaction characteristics requires the
SUPER
privilege. Any session is
free to change its session characteristics (even in the middle
of a transaction), or the characteristics for its next
transaction (prior to the start of that transaction).
To set the global isolation level at server startup, use the
--transaction-isolation=
option on the command line or in an option file. Values of
level
level
for this option use dashes
rather than spaces, so the permissible values are
READ-UNCOMMITTED
,
READ-COMMITTED
,
REPEATABLE-READ
, or
SERIALIZABLE
.
Similarly, to set the global transaction access mode at server
startup, use the
--transaction-read-only
option.
The default is OFF
(read/write mode) but the
value can be set to ON
for a mode of read
only.
For example, to set the isolation level to
REPEATABLE READ
and the
access mode to READ WRITE
, use these lines in
the [mysqld]
section of an option file:
[mysqld]
transaction-isolation = REPEATABLE-READ
transaction-read-only = OFF
At runtime, characteristics at the global, session, and
next-transaction scope levels can be set indirectly using the
SET TRANSACTION
statement, as
described previously. They can also be set directly using the
SET
statement to assign values to the
transaction_isolation
and
transaction_read_only
system
variables:
SET TRANSACTION
permits optionalGLOBAL
andSESSION
keywords for setting transaction characteristics at different scope levels.The
SET
statement for assigning values to thetransaction_isolation
andtransaction_read_only
system variables has syntaxes for setting these variables at different scope levels.
The following tables show the characteristic scope level set by
each SET TRANSACTION
and
variable-assignment syntax.
Table 13.6 SET TRANSACTION Syntax for Transaction Characteristics
Syntax | Affected Characteristic Scope |
---|---|
SET GLOBAL TRANSACTION
|
Global |
SET SESSION TRANSACTION
|
Session |
SET TRANSACTION
|
Next transaction only |
Table 13.7 SET Syntax for Transaction Characteristics
Syntax | Affected Characteristic Scope |
---|---|
SET GLOBAL |
Global |
SET @@GLOBAL. |
Global |
SET SESSION |
Session |
SET @@SESSION. |
Session |
SET |
Session |
SET @@ |
Next transaction only |
It is possible to check the global and session values of transaction characteristics at runtime:
SELECT @@GLOBAL.transaction_isolation, @@GLOBAL.transaction_read_only;
SELECT @@SESSION.transaction_isolation, @@SESSION.transaction_read_only;
Prior to MySQL 5.7.20, use
tx_isolation
and
tx_read_only
rather than
transaction_isolation
and
transaction_read_only
.