InnoDB Online DDL Operations with the INSTANT Alter Algorithm
Discover the INSTANT algorithm, which modifies table metadata without rebuilding the table, enabling extremely fast schema changes like adding columns.
Column Operations
ALTER TABLE ... ADD COLUMN
ALTER TABLE ... ADD COLUMNIn MariaDB 10.3.2 and later, InnoDB supports adding columns to a table with ALGORITHM set to INSTANT if the new column is the last column in the table. See MDEV-11369 for more information. If the table has a hidden FTS_DOC_ID column is present, then this is not supported.
In MariaDB 10.4 and later, InnoDB supports adding columns to a table with ALGORITHM set to INSTANT, regardless of where in the column list the new column is added.
When this operation is performed with ALGORITHM set to INSTANT, the tablespace file will have a non-canonical storage format. See Non-canonical Storage Format Caused by Some Operations for more information.
With the exception of adding an auto-increment column, this operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example, this succeeds:
CREATE OR REPLACE TABLE tab (
a INT PRIMARY KEY,
b VARCHAR(50)
);
SET SESSION alter_algorithm='INSTANT';
ALTER TABLE tab ADD COLUMN c VARCHAR(50);
Query OK, 0 rows affected (0.004 sec)And this succeeds in MariaDB 10.4 and later:
CREATE OR REPLACE TABLE tab (
a INT PRIMARY KEY,
b VARCHAR(50)
);
SET SESSION alter_algorithm='INSTANT';
ALTER TABLE tab ADD COLUMN c VARCHAR(50) AFTER a;
Query OK, 0 rows affected (0.004 sec)This applies to ALTER TABLE ... ADD COLUMN for InnoDB tables.
See Instant ADD COLUMN for InnoDB for more information.
ALTER TABLE ... DROP COLUMN
ALTER TABLE ... DROP COLUMNIn MariaDB 10.4 and later, InnoDB supports dropping columns from a table with ALGORITHM set to INSTANT. See MDEV-15562 for more information.
When this operation is performed with ALGORITHM set to INSTANT, the tablespace file will have a non-canonical storage format. See Non-canonical Storage Format Caused by Some Operations for more information.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example:
This applies to ALTER TABLE ... DROP COLUMN for InnoDB tables.
ALTER TABLE ... MODIFY COLUMN
ALTER TABLE ... MODIFY COLUMNThis applies to ALTER TABLE ... MODIFY COLUMN for InnoDB tables.
Reordering Columns
In MariaDB 10.4 and later, InnoDB supports reordering columns within a table with ALGORITHM set to INSTANT. See MDEV-15562 for more information.
When this operation is performed with ALGORITHM set to INSTANT, the tablespace file will have a non-canonical storage format. See Non-canonical Storage Format Caused by Some Operations for more information.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example:
Changing the Data Type of a Column
InnoDB does not support modifying a column's data type with ALGORITHM set to INSTANT in most cases. There are some exceptions:
InnoDB supports increasing the length of
VARCHARcolumns with ALGORITHM set toINSTANT, unless it would require changing the number of bytes requires to represent the column's length. AVARCHARcolumn that is between 0 and 255 bytes in size requires 1 byte to represent its length, while aVARCHARcolumn that is 256 bytes or longer requires 2 bytes to represent its length. This means that the length of a column cannot be increased with ALGORITHM set toINSTANTif the original length was less than 256 bytes, and the new length is 256 bytes or more.In MariaDB 10.4.3 and later, InnoDB supports increasing the length of
VARCHARcolumns with ALGORITHM set toINSTANTwith no restrictions if the ROW_FORMAT table option is set to REDUNDANT. See MDEV-15563 for more information.In MariaDB 10.4.3 and later, InnoDB also supports increasing the length of
VARCHARcolumns with ALGORITHM set toINSTANTin a more limited manner if the ROW_FORMAT table option is set to COMPACT, DYNAMIC, or COMPRESSED. In this scenario, the following limitations apply:The length can be increased with ALGORITHM set to
INSTANTif the original length of the column is 127 bytes or less, and the new length of the column is 256 bytes or more.The length can be increased with ALGORITHM set to
INSTANTif the original length of the column is 255 bytes or less, and the new length of the column is still 255 bytes or less.The length can be increased with ALGORITHM set to
INSTANTif the original length of the column is 256 bytes or more, and the new length of the column is still 256 bytes or more.The length can not be increased with ALGORITHM set to
INSTANTif the original length was between 128 bytes and 255 bytes, and the new length is 256 bytes or more.See MDEV-15563 for more information.
The supported operations in this category support the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example, this fails:
But this succeeds because the original length of the column is less than 256 bytes, and the new length is still less than 256 bytes:
But this fails because the original length of the column is between 128 bytes and 255 bytes, and the new length is greater than 256 bytes:
But this succeeds in MariaDB 10.4.3 and later because the table has ROW_FORMAT=REDUNDANT:
And this succeeds in MariaDB 10.4.3 and later because the table has ROW_FORMAT=DYNAMIC and the column's original length is 127 bytes or less:
And this succeeds in MariaDB 10.4.3 and later because the table has ROW_FORMAT=COMPRESSED and the column's original length is 127 bytes or less:
But this fails even in MariaDB 10.4.3 and later because the table has ROW_FORMAT=DYNAMIC and the column's original length is between 128 bytes and 255 bytes:
Changing a Column to NULL
In MariaDB 10.4.3 and later, InnoDB supports modifying a column to allow NULL values with ALGORITHM set to INSTANT if the ROW_FORMAT table option is set to REDUNDANT. See MDEV-15563 for more information.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example:
Changing a Column to NOT NULL
InnoDB does not support modifying a column to not allow NULL values with ALGORITHM set to INSTANT.
For example:
Adding a New ENUM Option
ENUM OptionInnoDB supports adding a new ENUM option to a column with ALGORITHM set to INSTANT. In order to add a new ENUM option with ALGORITHM set to INSTANT, the following requirements must be met:
It must be added to the end of the list.
The storage requirements must not change.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example, this succeeds:
But this fails:
Adding a New SET Option
SET OptionInnoDB supports adding a new SET option to a column with ALGORITHM set to INSTANT. In order to add a new SET option with ALGORITHM set to INSTANT, the following requirements must be met:
It must be added to the end of the list.
The storage requirements must not change.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example, this succeeds:
But this fails:
Removing System Versioning from a Column
In MariaDB 10.3.8 and later, InnoDB supports removing system versioning from a column with ALGORITHM set to INSTANT. In order for this to work, the system_versioning_alter_history system variable must be set to KEEP. See MDEV-16330 for more information.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example:
ALTER TABLE ... ALTER COLUMN
ALTER TABLE ... ALTER COLUMNThis applies to ALTER TABLE ... ALTER COLUMN for InnoDB tables.
Setting a Column's Default Value
InnoDB supports modifying a column's DEFAULT value with ALGORITHM set to INSTANT.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example:
Removing a Column's Default Value
InnoDB supports removing a column's DEFAULT value with ALGORITHM set to INSTANT.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
ALTER TABLE ... CHANGE COLUMN
ALTER TABLE ... CHANGE COLUMNInnoDB supports renaming a column with ALGORITHM set to INSTANT, unless the column's data type or attributes changed in addition to the name.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example, this succeeds:
But this fails:
This applies to ALTER TABLE ... CHANGE COLUMN for InnoDB tables.
Index Operations
ALTER TABLE ... ADD PRIMARY KEY
ALTER TABLE ... ADD PRIMARY KEYInnoDB does not support adding a primary key to a table with ALGORITHM set to INSTANT.
For example:
This applies to ALTER TABLE ... ADD PRIMARY KEY for InnoDB tables.
ALTER TABLE ... DROP PRIMARY KEY
ALTER TABLE ... DROP PRIMARY KEYInnoDB does not support dropping a primary key with ALGORITHM set to INSTANT.
For example:
This applies to ALTER TABLE ... DROP PRIMARY KEY for InnoDB tables.
ALTER TABLE ... ADD INDEX and CREATE INDEX
ALTER TABLE ... ADD INDEX and CREATE INDEXThis applies to ALTER TABLE ... ADD INDEX and CREATE INDEX for InnoDB tables.
Adding a Plain Index
InnoDB does not support adding a plain index to a table with ALGORITHM set to INSTANT.
For example, this fails:
And this fails:
Adding a Fulltext Index
InnoDB does not support adding a FULLTEXT index to a table with ALGORITHM set to INSTANT.
For example, this fails:
And this fails:
Adding a Spatial Index
InnoDB does not support adding a SPATIAL index to a table with ALGORITHM set to INSTANT.
For example, this fails:
And this fails:
ALTER TABLE ... ADD FOREIGN KEY
ALTER TABLE ... ADD FOREIGN KEYInnoDB does not support adding foreign key constraints to a table with ALGORITHM set to INSTANT.
For example:
This applies to ALTER TABLE ... ADD FOREIGN KEY for InnoDB tables.
ALTER TABLE ... DROP FOREIGN KEY
ALTER TABLE ... DROP FOREIGN KEYInnoDB supports dropping foreign key constraints from a table with ALGORITHM set to INSTANT.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example:
This applies to ALTER TABLE ... DROP FOREIGN KEY for InnoDB tables.
Table Operations
ALTER TABLE ... AUTO_INCREMENT=...
ALTER TABLE ... AUTO_INCREMENT=...InnoDB supports changing a table's AUTO_INCREMENT value with ALGORITHM set to INSTANT.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example:
This applies to ALTER TABLE ... AUTO_INCREMENT=... for InnoDB tables.
ALTER TABLE ... ROW_FORMAT=...
ALTER TABLE ... ROW_FORMAT=...InnoDB does not support changing a table's row format with ALGORITHM set to INSTANT.
For example:
This applies to ALTER TABLE ... ROW_FORMAT=... for InnoDB tables.
ALTER TABLE ... KEY_BLOCK_SIZE=...
ALTER TABLE ... KEY_BLOCK_SIZE=...InnoDB does not support changing a table's KEY_BLOCK_SIZE with ALGORITHM set to INSTANT.
For example:
This applies to KEY_BLOCK_SIZE=... for InnoDB tables.
ALTER TABLE ... PAGE_COMPRESSED=1 and ALTER TABLE ... PAGE_COMPRESSION_LEVEL=...
ALTER TABLE ... PAGE_COMPRESSED=1 and ALTER TABLE ... PAGE_COMPRESSION_LEVEL=...In MariaDB 10.3.10 and later, InnoDB supports setting a table's PAGE_COMPRESSED value to 1 with ALGORITHM set to INSTANT. InnoDB does not support changing a table's PAGE_COMPRESSED value from 1 to 0 with ALGORITHM set to INSTANT.
In these versions, InnoDB also supports changing a table's PAGE_COMPRESSION_LEVEL value with ALGORITHM set to INSTANT.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
See MDEV-16328 for more information.
For example, this succeeds:
And this succeeds:
But this fails:
This applies to ALTER TABLE ... PAGE_COMPRESSED=... and ALTER TABLE ... PAGE_COMPRESSION_LEVEL=... for InnoDB tables.
ALTER TABLE ... DROP SYSTEM VERSIONING
ALTER TABLE ... DROP SYSTEM VERSIONINGInnoDB does not support dropping system versioning from a table with ALGORITHM set to INSTANT.
For example:
This applies to ALTER TABLE ... DROP SYSTEM VERSIONING for InnoDB tables.
ALTER TABLE ... DROP CONSTRAINT
ALTER TABLE ... DROP CONSTRAINTIn MariaDB 10.3.6 and later, InnoDB supports dropping a CHECK constraint from a table with ALGORITHM set to INSTANT. See MDEV-16331 for more information.
This operation supports the non-locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to NONE. When this strategy is used, all concurrent DML is permitted.
For example:
This applies to ALTER TABLE ... DROP CONSTRAINT for InnoDB tables.
ALTER TABLE ... FORCE
ALTER TABLE ... FORCEInnoDB does not support forcing a table rebuild with ALGORITHM set to INSTANT.
For example:
This applies to ALTER TABLE ... FORCE for InnoDB tables.
ALTER TABLE ... ENGINE=InnoDB
ALTER TABLE ... ENGINE=InnoDBInnoDB does not support forcing a table rebuild with ALGORITHM set to INSTANT.
For example:
This applies to ALTER TABLE ... ENGINE=InnoDB for InnoDB tables.
OPTIMIZE TABLE ...
OPTIMIZE TABLE ...InnoDB does not support optimizing a table with ALGORITHM set to INSTANT.
For example:
This applies to OPTIMIZE TABLE for InnoDB tables.
ALTER TABLE ... RENAME TO and RENAME TABLE ...
ALTER TABLE ... RENAME TO and RENAME TABLE ...InnoDB supports renaming a table with ALGORITHM set to INSTANT.
This operation supports the exclusive locking strategy. This strategy can be explicitly chosen by setting the LOCK clause to EXCLUSIVE. When this strategy is used, concurrent DML is not permitted.
For example, this succeeds:
And this succeeds:
This applies to ALTER TABLE ... RENAME TO and RENAME TABLE for InnoDB tables.
Limitations
Limitations Related to Generated (Virtual and Persistent/Stored) Columns
Generated columns do not currently support online DDL for all of the same operations that are supported for "real" columns.
See Generated (Virtual and Persistent/Stored) Columns: Statement Support for more information on the limitations.
Non-canonical Storage Format Caused by Some Operations
Some operations cause a table's tablespace file to use a non-canonical storage format when the INSTANT algorithm is used. The affected operations include:
These operations require the following non-canonical changes to the storage format:
A hidden metadata record at the start of the clustered index is used to store each column's DEFAULT value. This makes it possible to add new columns that have default values without rebuilding the table.
A BLOB in the hidden metadata record is used to store column mappings. This makes it possible to drop or reorder columns without rebuilding the table. This also makes it possible to add columns to any position or drop columns from any position in the table without rebuilding the table.
If a column is dropped, old records will contain garbage in that column's former position, and new records are written with NULL values, empty strings, or dummy values.
This non-canonical storage format has the potential to incur some performance or storage overhead for all subsequent DML operations. If you notice some issues like this and you want to normalize a table's storage format to avoid this problem, then you can do so by forcing a table rebuild by executing ALTER TABLE ... FORCE with ALGORITHM set to INPLACE:
However, keep in mind that there are certain scenarios where you may not be able to rebuild the table with ALGORITHM set to INPLACE. See InnoDB Online DDL Operations with ALGORITHM=INPLACE: Limitations for more information on those cases. If you hit one of those scenarios, but you still want to rebuild the table, then you would have to do so with ALGORITHM set to COPY.
Known Bugs
There are some known bugs that could lead to issues when an InnoDB DDL operation is performed using the INSTANT algorithm. This algorithm will usually be chosen by default if the operation supports the algorithm.
The effect of many of these bugs is that the table seems to forget that its tablespace file is in the non-canonical storage format.
If you are concerned that a table may be affected by one of these bugs, then your best option would be to normalize the table structure. This can be done by rebuilding the table:
If you are concerned about these bugs, and you want to perform an operation that supports the INSTANT algorithm, but you want to avoid using that algorithm, then you can set the algorithm to INPLACE and add the FORCE keyword to the ALTER TABLE statement:
Closed Bugs
MDEV-20066: This bug could cause a table to become corrupt if a column was added instantly. It is fixed in MariaDB 10.3.18 and MariaDB 10.4.8.
MDEV-20117: This bug could cause a table to become corrupt if a column was dropped instantly. It is fixed in MariaDB 10.4.9.
MDEV-19743: This bug could cause a table to become corrupt during page reorganization if a column was added instantly. It is fixed in MariaDB 10.3.17 and MariaDB 10.4.7.
MDEV-19783: This bug could cause a table to become corrupt if a column was added instantly. It is fixed in MariaDB 10.3.17 and MariaDB 10.4.7
MDEV-20090: This bug could cause a table to become corrupt if columns were added, dropped, or reordered instantly. It is fixed in MariaDB 10.4.9.
MDEV-18519: This bug could cause a table to become corrupt if a column was added instantly. It is fixed in MariaDB 10.6.9, MariaDB 10.7.5, MariaDB 10.8.4 and MariaDB 10.9.2.
MDEV-18519: This bug could cause a table to become corrupt if a column was added instantly. This isn't and won't be fixed in versions less than MariaDB 10.6.
This page is licensed: CC BY-SA / Gnu FDL
Last updated
Was this helpful?

