MySQL :: MySQL 8.4 Reference Manual :: 15.3.7 SET TRANSACTION Statement (original) (raw)

15.3.7 SET TRANSACTION Statement

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 specifiestransaction 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 orSESSION keyword to indicate the scope of the statement.

Transaction Access Mode

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 usingSET 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 theSTART TRANSACTION statement.

Transaction Characteristic Scope

You can set transaction characteristics globally, for the current session, or for the next transaction only:

A change to global transaction characteristics requires theCONNECTION_ADMIN privilege (or the deprecated 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=level option on the command line or in an option file. Values of_level_ for this option use dashes rather than spaces, so the permissible values areREAD-UNCOMMITTED,READ-COMMITTED,REPEATABLE-READ, orSERIALIZABLE.

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 toREPEATABLE 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 theSET TRANSACTION statement, as described previously. They can also be set directly using theSET statement to assign values to thetransaction_isolation andtransaction_read_only system variables:

The following tables show the characteristic scope level set by each SET TRANSACTION and variable-assignment syntax.

Table 15.9 SET TRANSACTION Syntax for Transaction Characteristics

Syntax Affected Characteristic Scope
SET GLOBAL TRANSACTION_transaction_characteristic_ Global
SET SESSION TRANSACTION_transaction_characteristic_ Session
SET TRANSACTION_transaction_characteristic_ Next transaction only

Table 15.10 SET Syntax for Transaction Characteristics

Syntax Affected Characteristic Scope
SET GLOBAL var_name =value Global
SET @@GLOBAL.var_name =value Global
SET PERSIST var_name =value Global
SET @@PERSIST.var_name =value Global
SET PERSIST_ONLY var_name =value No runtime effect
SET @@PERSIST_ONLY.var_name =value No runtime effect
SET SESSION var_name =value Session
SET @@SESSION.var_name =value Session
SET var_name =value Session
SET @@var_name =value 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;