Documentation Home
MySQL 9.1 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 40.3Mb
PDF (A4) - 40.4Mb
Man Pages (TGZ) - 259.3Kb
Man Pages (Zip) - 366.3Kb
Info (Gzip) - 4.0Mb
Info (Zip) - 4.0Mb


MySQL 9.1 Reference Manual  /  ...  /  Replication and Transactions

19.5.1.36 Replication and Transactions

Mixing transactional and nontransactional statements within the same transaction.  In MySQL 9.1 (and later), transactions that update both transactional tables and tables which are nontransactional or noncomposable are deprecated, and causes a deprecation warning to be written to both the client and the error log. In MySQL 9.1 only the InnoDB and BLACKHOLE storage engines are transactional and composable; NDBCLUSTER is transactional but not composable. This means that the only combinations of storage engines that do not raise the deprecation warning are those listed here:

  • InnoDB and BLACKHOLE

  • MyISAM and Merge

  • performance_schema and any other storage engine

  • TempTable and any other storage engine

In general, you should avoid transactions that update both transactional and nontransactional tables in a replication environment. You should also avoid using any statement that accesses both transactional (or temporary) and nontransactional tables and writes to any of them.

The server uses these rules for binary logging:

  • If the initial statements in a transaction are nontransactional, they are written to the binary log immediately. The remaining statements in the transaction are cached and not written to the binary log until the transaction is committed. (If the transaction is rolled back, the cached statements are written to the binary log only if they make nontransactional changes that cannot be rolled back. Otherwise, they are discarded.)

  • For statement-based logging, logging of nontransactional statements is affected by the binlog_direct_non_transactional_updates system variable. When this variable is OFF (the default), logging is as just described. When this variable is ON, logging occurs immediately for nontransactional statements occurring anywhere in the transaction (not just initial nontransactional statements). Other statements are kept in the transaction cache and logged when the transaction commits. binlog_direct_non_transactional_updates has no effect for row-format or mixed-format binary logging.

Transactional, nontransactional, and mixed statements.  To apply those rules, the server considers a statement nontransactional if it changes only nontransactional tables, and transactional if it changes only transactional tables. A statement that references both nontransactional and transactional tables and updates any of the tables involved is considered a mixed statement. Mixed statements, like transactional statements, are cached and logged when the transaction commits.

A mixed statement that updates a transactional table is considered unsafe if the statement also performs either of the following actions:

  • Updates or reads a temporary table

  • Reads a nontransactional table and the transaction isolation level is less than REPEATABLE_READ

A mixed statement following the update of a transactional table within a transaction is considered unsafe if it performs either of the following actions:

For more information, see Section 19.2.1.3, “Determination of Safe and Unsafe Statements in Binary Logging”.

Note

A mixed statement is unrelated to mixed binary logging format.

In situations where transactions mix updates to transactional and nontransactional tables, the order of statements in the binary log is correct, and all needed statements are written to the binary log even in case of a ROLLBACK. However, when a second connection updates the nontransactional table before the first connection transaction is complete, statements can be logged out of order because the second connection update is written immediately after it is performed, regardless of the state of the transaction being performed by the first connection.

Using different storage engines on source and replica.  It is possible to replicate transactional tables on the source using nontransactional tables on the replica. For example, you can replicate an InnoDB source table as a MyISAM replica table. However, if you do this, there are problems if the replica is stopped in the middle of a BEGIN ... COMMIT block because the replica restarts at the beginning of the BEGIN block.

It is also safe to replicate transactions from MyISAM tables on the source to transactional tables, such as tables that use the InnoDB storage engine, on the replica. In such cases, an AUTOCOMMIT=1 statement issued on the source is replicated, thus enforcing AUTOCOMMIT mode on the replica.

When the storage engine type of the replica is nontransactional, transactions on the source that mix updates of transactional and nontransactional tables should be avoided because they can cause inconsistency of the data between the source transactional table and the replica nontransactional table. That is, such transactions can lead to source storage engine-specific behavior with the possible effect of replication going out of synchrony. MySQL does not issue a warning about this, so extra care should be taken when replicating transactional tables from the source to nontransactional tables on the replicas.

Changing the binary logging format within transactions.  The binlog_format and binlog_checksum system variables are read-only as long as a transaction is in progress.

Every transaction (including autocommit transactions) is recorded in the binary log as though it starts with a BEGIN statement, and ends with either a COMMIT or a ROLLBACK statement. This is even true for statements affecting tables that use a nontransactional storage engine (such as MyISAM).

Note

For restrictions that apply specifically to XA transactions, see Section 15.3.8.3, “Restrictions on XA Transactions”.