17.6.1.6 AUTO_INCREMENT Handling in InnoDB (original) (raw)

17.6.1.6 AUTO_INCREMENT Handling in InnoDB

InnoDB provides a configurable locking mechanism that can significantly improve scalability and performance of SQL statements that add rows to tables withAUTO_INCREMENT columns. To use theAUTO_INCREMENT mechanism with anInnoDB table, anAUTO_INCREMENT column must be defined as the first or only column of some index such that it is possible to perform the equivalent of an indexed SELECT MAX(_`aicol`_) lookup on the table to obtain the maximum column value. The index is not required to be a PRIMARY KEY orUNIQUE, but to avoid duplicate values in theAUTO_INCREMENT column, those index types are recommended.

This section describes the AUTO_INCREMENT lock modes, usage implications of differentAUTO_INCREMENT lock mode settings, and howInnoDB initializes theAUTO_INCREMENT counter.

InnoDB AUTO_INCREMENT Lock Modes

This section describes the AUTO_INCREMENT lock modes used to generate auto-increment values, and how each lock mode affects replication. The auto-increment lock mode is configured at startup using theinnodb_autoinc_lock_mode variable.

The following terms are used in describinginnodb_autoinc_lock_mode settings:

INSERT INTO t1 (c1,c2) VALUES (1,'a'), (NULL,'b'), (5,'c'), (NULL,'d');  

Another type of “mixed-mode insert” isINSERT ... ON DUPLICATE KEY UPDATE, which in the worst case is in effect an INSERT followed by a UPDATE, where the allocated value for theAUTO_INCREMENT column may or may not be used during the update phase.

There are three possible settings for theinnodb_autoinc_lock_mode variable. The settings are 0, 1, or 2, for“traditional”, “consecutive”, or“interleaved” lock mode, respectively. Interleaved lock mode (innodb_autoinc_lock_mode=2) is the default.

The default setting of interleaved lock mode in MySQL 8.4 reflects the change from statement-based replication to row based replication as the default replication type. Statement-based replication requires the consecutive auto-increment lock mode to ensure that auto-increment values are assigned in a predictable and repeatable order for a given sequence of SQL statements, whereas row-based replication is not sensitive to the execution order of SQL statements.

CREATE TABLE t1 (  
  c1 INT(11) NOT NULL AUTO_INCREMENT,  
  c2 VARCHAR(10) DEFAULT NULL,  
  PRIMARY KEY (c1)  
) ENGINE=InnoDB;  

Suppose that there are two transactions running, each inserting rows into a table with anAUTO_INCREMENT column. One transaction is using anINSERT ... SELECT statement that inserts 1000 rows, and another is using a simpleINSERT statement that inserts one row:

Tx1: INSERT INTO t1 (c2) SELECT 1000 rows from another table ...  
Tx2: INSERT INTO t1 (c2) VALUES ('xxx');  

InnoDB cannot tell in advance how many rows are retrieved from theSELECT in theINSERT statement in Tx1, and it assigns the auto-increment values one at a time as the statement proceeds. With a table-level lock, held to the end of the statement, only oneINSERT statement referring to table t1 can execute at a time, and the generation of auto-increment numbers by different statements is not interleaved. The auto-increment values generated by the Tx1INSERT ... SELECT statement are consecutive, and the (single) auto-increment value used by theINSERT statement in Tx2 is either smaller or larger than all those used for Tx1, depending on which statement executes first.
As long as the SQL statements execute in the same order when replayed from the binary log (when using statement-based replication, or in recovery scenarios), the results are the same as they were when Tx1 and Tx2 first ran. Thus, table-level locks held until the end of a statement makeINSERT statements using auto-increment safe for use with statement-based replication. However, those table-level locks limit concurrency and scalability when multiple transactions are executing insert statements at the same time.
In the preceding example, if there were no table-level lock, the value of the auto-increment column used for theINSERT in Tx2 depends on precisely when the statement executes. If theINSERT of Tx2 executes while the INSERT of Tx1 is running (rather than before it starts or after it completes), the specific auto-increment values assigned by the twoINSERT statements are nondeterministic, and may vary from run to run.
Under theconsecutive lock mode, InnoDB can avoid using table-level AUTO-INC locks for“simple insert” statements where the number of rows is known in advance, and still preserve deterministic execution and safety for statement-based replication.
If you are not using the binary log to replay SQL statements as part of recovery or replication, theinterleaved lock mode can be used to eliminate all use of table-levelAUTO-INC locks for even greater concurrency and performance, at the cost of permitting gaps in auto-increment numbers assigned by a statement and potentially having the numbers assigned by concurrently executing statements interleaved.

InnoDB AUTO_INCREMENT Lock Mode Usage Implications
mysql> CREATE TABLE t1 (  
    -> c1 INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,  
    -> c2 CHAR(1)  
    -> ) ENGINE = INNODB;  

Now, consider the following “mixed-mode insert” statement:

mysql> INSERT INTO t1 (c1,c2) VALUES (1,'a'), (NULL,'b'), (5,'c'), (NULL,'d');  

Withinnodb_autoinc_lock_mode set to 0 (“traditional”), the four new rows are:

mysql> SELECT c1, c2 FROM t1 ORDER BY c2;  
+-----+------+  
| c1  | c2   |  
+-----+------+  
|   1 | a    |  
| 101 | b    |  
|   5 | c    |  
| 102 | d    |  
+-----+------+  

The next available auto-increment value is 103 because the auto-increment values are allocated one at a time, not all at once at the beginning of statement execution. This result is true whether or not there are concurrently executing“INSERT-like” statements (of any type).
Withinnodb_autoinc_lock_mode set to 1 (“consecutive”), the four new rows are also:

mysql> SELECT c1, c2 FROM t1 ORDER BY c2;  
+-----+------+  
| c1  | c2   |  
+-----+------+  
|   1 | a    |  
| 101 | b    |  
|   5 | c    |  
| 102 | d    |  
+-----+------+  

However, in this case, the next available auto-increment value is 105, not 103 because four auto-increment values are allocated at the time the statement is processed, but only two are used. This result is true whether or not there are concurrently executing“INSERT-like” statements (of any type).
Withinnodb_autoinc_lock_mode set to 2 (“interleaved”), the four new rows are:

mysql> SELECT c1, c2 FROM t1 ORDER BY c2;  
+-----+------+  
| c1  | c2   |  
+-----+------+  
|   1 | a    |  
|   x | b    |  
|   5 | c    |  
|   y | d    |  
+-----+------+  

The values of x and_y_ are unique and larger than any previously generated rows. However, the specific values of_x_ and_y_ depend on the number of auto-increment values generated by concurrently executing statements.
Finally, consider the following statement, issued when the most-recently generated sequence number is 100:

mysql> INSERT INTO t1 (c1,c2) VALUES (1,'a'), (NULL,'b'), (101,'c'), (NULL,'d');  

With anyinnodb_autoinc_lock_mode setting, this statement generates a duplicate-key error 23000 (Can't write; duplicate key in table) because 101 is allocated for the row(NULL, 'b') and insertion of the row(101, 'c') fails.

mysql> CREATE TABLE t1 (  
    -> c1 INT NOT NULL AUTO_INCREMENT,  
    -> PRIMARY KEY (c1)  
    ->  ) ENGINE = InnoDB;  
mysql> INSERT INTO t1 VALUES(0), (0), (3);  
mysql> SELECT c1 FROM t1;  
+----+  
| c1 |  
+----+  
|  1 |  
|  2 |  
|  3 |  
+----+  
mysql> UPDATE t1 SET c1 = 4 WHERE c1 = 1;  
mysql> SELECT c1 FROM t1;  
+----+  
| c1 |  
+----+  
|  2 |  
|  3 |  
|  4 |  
+----+  
mysql> INSERT INTO t1 VALUES(0);  
mysql> SELECT c1 FROM t1;  
+----+  
| c1 |  
+----+  
|  2 |  
|  3 |  
|  4 |  
|  5 |  
+----+  
InnoDB AUTO_INCREMENT Counter Initialization

This section describes how InnoDB initializesAUTO_INCREMENT counters.

If you specify an AUTO_INCREMENT column for an InnoDB table, the in-memory table object contains a special counter called the auto-increment counter that is used when assigning new values for the column.

The current maximum auto-increment counter value is written to the redo log each time it changes and saved to the data dictionary on each checkpoint; this makes the current maximum auto-increment counter value persistent across server restarts.

On a server restart following a normal shutdown,InnoDB initializes the in-memory auto-increment counter using the current maximum auto-increment value stored in the data dictionary.

On a server restart during crash recovery,InnoDB initializes the in-memory auto-increment counter using the current maximum auto-increment value stored in the data dictionary and scans the redo log for auto-increment counter values written since the last checkpoint. If a redo-logged value is greater than the in-memory counter value, the redo-logged value is applied. However, in the case of an unexpected server exit, reuse of a previously allocated auto-increment value cannot be guaranteed. Each time the current maximum auto-increment value is changed due to anINSERT orUPDATE operation, the new value is written to the redo log, but if the unexpected exit occurs before the redo log is flushed to disk, the previously allocated value could be reused when the auto-increment counter is initialized after the server is restarted.

The only circumstance in which InnoDB uses the equivalent of a SELECT MAX(ai_col) FROM_`tablename`_ FOR UPDATE statement to initialize an auto-increment counter is whenimporting a table without a .cfg metadata file. Otherwise, the current maximum auto-increment counter value is read from the .cfg metadata file if present. Aside from counter value initialization, the equivalent of aSELECT MAX(ai_col) FROM_`tablename`_ statement is used to determine the current maximum auto-increment counter value of the table when attempting to set the counter value to one that is smaller than or equal to the persisted counter value using an ALTER TABLE ... AUTO_INCREMENT =_`N`_ statement. For example, you might try to set the counter value to a lesser value after deleting some records. In this case, the table must be searched to ensure that the new counter value is not less than or equal to the actual current maximum counter value.

A server restart does not cancel the effect of theAUTO_INCREMENT = N table option. If you initialize the auto-increment counter to a specific value, or if you alter the auto-increment counter value to a larger value, the new value is persisted across server restarts.

The current maximum auto-increment value is persisted, preventing the reuse of previously allocated values.

If a SHOW TABLE STATUS statement examines a table before the auto-increment counter is initialized, InnoDB opens the table and initializes the counter value using the current maximum auto-increment value that is stored in the data dictionary. The value is then stored in memory for use by later inserts or updates. Initialization of the counter value uses a normal exclusive-locking read on the table which lasts to the end of the transaction. InnoDB follows the same procedure when initializing the auto-increment counter for a newly created table that has a user-specified auto-increment value greater than 0.

After the auto-increment counter is initialized, if you do not explicitly specify an auto-increment value when inserting a row,InnoDB implicitly increments the counter and assigns the new value to the column. If you insert a row that explicitly specifies an auto-increment column value, and the value is greater than the current maximum counter value, the counter is set to the specified value.

InnoDB uses the in-memory auto-increment counter as long as the server runs. When the server is stopped and restarted, InnoDB reinitializes the auto-increment counter, as described earlier.

The auto_increment_offset variable determines the starting point for theAUTO_INCREMENT column value. The default setting is 1.

The auto_increment_increment variable controls the interval between successive column values. The default setting is 1.

Notes

When an AUTO_INCREMENT integer column runs out of values, a subsequent INSERT operation returns a duplicate-key error. This is general MySQL behavior.