15.1.1 Atomic Data Definition Statement Support (original) (raw)

15.1.1 Atomic Data Definition Statement Support

MySQL 8.4 supports atomic Data Definition Language (DDL) statements. This feature is referred to as atomic DDL. An atomic DDL statement combines the data dictionary updates, storage engine operations, and binary log writes associated with a DDL operation into a single, atomic operation. The operation is either committed, with applicable changes persisted to the data dictionary, storage engine, and binary log, or is rolled back, even if the server halts during the operation.

Note

Atomic DDL is not transactional DDL. DDL statements, atomic or otherwise, implicitly end any transaction that is active in the current session, as if you had done a COMMIT before executing the statement. This means that DDL statements cannot be performed within another transaction, within transaction control statements such asSTART TRANSACTION ... COMMIT, or combined with other statements within the same transaction.

Atomic DDL is made possible by the MySQL data dictionary, which provides centralized, transactional metadata storage.

The atomic DDL feature is described under the following topics in this section:

Supported DDL Statements

The atomic DDL feature supports both table and non-table DDL statements. Table-related DDL operations require storage engine support, whereas non-table DDL operations do not. Currently, only the InnoDB storage engine supports atomic DDL.

The following statements are not supported by the atomic DDL feature:

Atomic DDL Characteristics

The characteristics of atomic DDL statements include the following:

DDL Statement Behavior

This section describes some important aspects of DDL statement behavior when using a storage engine that support atomic DDL, such as InnoDB.

Storage Engine Support

Currently, only the InnoDB storage engine supports atomic DDL. Storage engines that do not support atomic DDL are exempted from DDL atomicity. DDL operations involving exempted storage engines remain capable of introducing inconsistencies that can occur when operations are interrupted or only partially completed.

To support redo and rollback of DDL operations,InnoDB writes DDL logs to themysql.innodb_ddl_log table, which is a hidden data dictionary table that resides in themysql.ibd data dictionary tablespace.

To view DDL logs that are written to themysql.innodb_ddl_log table during a DDL operation, enable theinnodb_print_ddl_logs configuration option. For more information, seeViewing DDL Logs.

Note

The redo logs for changes to themysql.innodb_ddl_log table are flushed to disk immediately regardless of theinnodb_flush_log_at_trx_commit setting. Flushing the redo logs immediately avoids situations where data files are modified by DDL operations but the redo logs for changes to themysql.innodb_ddl_log table resulting from those operations are not persisted to disk. Such a situation could cause errors during rollback or recovery.

The InnoDB storage engine executes DDL operations in phases. DDL operations such asALTER TABLE may perform the_Prepare_ and Perform phases multiple times prior to the Commit phase.

  1. Prepare: Create the required objects and write the DDL logs to themysql.innodb_ddl_log table. The DDL logs define how to roll forward and roll back the DDL operation.
  2. Perform: Perform the DDL operation. For example, perform a create routine for a CREATE TABLE operation.
  3. Commit: Update the data dictionary and commit the data dictionary transaction.
  4. Post-DDL: Replay and remove DDL logs from the mysql.innodb_ddl_log table. To ensure that rollback can be performed safely without introducing inconsistencies, file operations such as renaming or removing data files are performed in this final phase. This phase also removes dynamic metadata from themysql.innodb_dynamic_metadata data dictionary table for DROP TABLE, TRUNCATE TABLE, and other DDL operations that rebuild the table.

DDL logs are replayed and removed from themysql.innodb_ddl_log table during the_Post-DDL_ phase, regardless of whether the DDL operation is committed or rolled back. DDL logs should only remain in the mysql.innodb_ddl_log table if the server is halted during a DDL operation. In this case, the DDL logs are replayed and removed after recovery.

In a recovery situation, a DDL operation may be committed or rolled back when the server is restarted. If the data dictionary transaction that was performed during the_Commit_ phase of a DDL operation is present in the redo log and binary log, the operation is considered successful and is rolled forward. Otherwise, the incomplete data dictionary transaction is rolled back whenInnoDB replays data dictionary redo logs, and the DDL operation is rolled back.

Viewing DDL Logs

To view DDL logs that are written to themysql.innodb_ddl_log data dictionary table during atomic DDL operations that involve theInnoDB storage engine, enableinnodb_print_ddl_logs to have MySQL write the DDL logs to stderr. Depending on the host operating system and MySQL configuration,stderr may be the error log, terminal, or console window. SeeSection 7.4.2.2, “Default Error Log Destination Configuration”.

InnoDB writes DDL logs to themysql.innodb_ddl_log table to support redo and rollback of DDL operations. Themysql.innodb_ddl_log table is a hidden data dictionary table that resides in themysql.ibd data dictionary tablespace. Like other hidden data dictionary tables, themysql.innodb_ddl_log table cannot be accessed directly in non-debug versions of MySQL. (SeeSection 16.1, “Data Dictionary Schema”.) The structure of themysql.innodb_ddl_log table corresponds to this definition:

CREATE TABLE mysql.innodb_ddl_log (
  id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
  thread_id BIGINT UNSIGNED NOT NULL,
  type INT UNSIGNED NOT NULL,
  space_id INT UNSIGNED,
  page_no INT UNSIGNED,
  index_id BIGINT UNSIGNED,
  table_id BIGINT UNSIGNED,
  old_file_path VARCHAR(512) COLLATE utf8mb4_bin,
  new_file_path VARCHAR(512) COLLATE utf8mb4_bin,
  KEY(thread_id)
);

This example demonstrates enablinginnodb_print_ddl_logs to view DDL logs written to strderr for aCREATE TABLE operation.

mysql> SET GLOBAL innodb_print_ddl_logs=1;
mysql> CREATE TABLE t1 (c1 INT) ENGINE = InnoDB;
[Note] [000000] InnoDB: DDL log insert : [DDL record: DELETE SPACE, id=18, thread_id=7,
space_id=5, old_file_path=./test/t1.ibd]
[Note] [000000] InnoDB: DDL log delete : by id 18
[Note] [000000] InnoDB: DDL log insert : [DDL record: REMOVE CACHE, id=19, thread_id=7,
table_id=1058, new_file_path=test/t1]
[Note] [000000] InnoDB: DDL log delete : by id 19
[Note] [000000] InnoDB: DDL log insert : [DDL record: FREE, id=20, thread_id=7,
space_id=5, index_id=132, page_no=4]
[Note] [000000] InnoDB: DDL log delete : by id 20
[Note] [000000] InnoDB: DDL log post ddl : begin for thread id : 7
[Note] [000000] InnoDB: DDL log post ddl : end for thread id : 7