Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual Excerpts from this Manual

13.1.6 ALTER TABLE Syntax

    [alter_specification [, alter_specification] ...]

  | ADD [COLUMN] col_name column_definition
        [FIRST | AFTER col_name ]
  | ADD [COLUMN] (col_name column_definition,...)
  | ADD {INDEX|KEY} [index_name]
        [index_type] (index_col_name,...) [index_option] ...
        [index_type] (index_col_name,...) [index_option] ...
  | ADD [CONSTRAINT [symbol]]
        UNIQUE [INDEX|KEY] [index_name]
        [index_type] (index_col_name,...) [index_option] ...
  | ADD FULLTEXT [INDEX|KEY] [index_name]
        (index_col_name,...) [index_option] ...
  | ADD SPATIAL [INDEX|KEY] [index_name]
        (index_col_name,...) [index_option] ...
  | ADD [CONSTRAINT [symbol]]
        FOREIGN KEY [index_name] (index_col_name,...)
  | ALTER [COLUMN] col_name {SET DEFAULT literal | DROP DEFAULT}
  | CHANGE [COLUMN] old_col_name new_col_name column_definition
        [FIRST|AFTER col_name]
  | MODIFY [COLUMN] col_name column_definition
        [FIRST | AFTER col_name]
  | DROP [COLUMN] col_name
  | DROP {INDEX|KEY} index_name
  | DROP FOREIGN KEY fk_symbol
  | RENAME [TO|AS] new_tbl_name
  | RENAME {INDEX|KEY} old_index_name TO new_index_name
  | ORDER BY col_name [, col_name] ...
  | CONVERT TO CHARACTER SET charset_name [COLLATE collation_name]
  | [DEFAULT] CHARACTER SET [=] charset_name [COLLATE [=] collation_name]
  | ADD PARTITION (partition_definition)
  | DROP PARTITION partition_names
  | TRUNCATE PARTITION {partition_names | ALL}
  | REORGANIZE PARTITION partition_names INTO (partition_definitions)
  | ANALYZE PARTITION {partition_names | ALL}
  | CHECK PARTITION {partition_names | ALL}
  | OPTIMIZE PARTITION {partition_names | ALL}
  | REBUILD PARTITION {partition_names | ALL}
  | REPAIR PARTITION {partition_names | ALL}

    col_name [(length)] [ASC | DESC]


    KEY_BLOCK_SIZE [=] value
  | index_type
  | WITH PARSER parser_name
  | COMMENT 'string'

    table_option [[,] table_option] ...  (see CREATE TABLE options)

    (see CREATE TABLE options)

ALTER TABLE changes the structure of a table. For example, you can add or delete columns, create or destroy indexes, change the type of existing columns, or rename columns or the table itself. You can also change characteristics such as the storage engine used for the table or the table comment.

Following the table name, specify the alterations to be made. If none are given, ALTER TABLE does nothing.

The syntax for many of the permissible alterations is similar to clauses of the CREATE TABLE statement. See Section 13.1.14, “CREATE TABLE Syntax”, for more information.

table_options signifies table options of the kind that can be used in the CREATE TABLE statement, such as ENGINE, AUTO_INCREMENT, AVG_ROW_LENGTH, MAX_ROWS, or ROW_FORMAT. For a list of all table options and a description of each, see Section 13.1.14, “CREATE TABLE Syntax”. However, ALTER TABLE ignores the DATA DIRECTORY and INDEX DIRECTORY table options.

partition_options signifies options that can be used with partitioned tables for repartitioning, for adding, dropping, discarding, importing, merging, and splitting partitions, and for performing partitioning maintenance. It is possible for an ALTER TABLE statement to contain a PARTITION BY or REMOVE PARTITIONING clause in an addition to other alter specifications, but the PARTITION BY or REMOVE PARTITIONING clause must be specified last after any other specifications. The ADD PARTITION, DROP PARTITION, DISCARD PARTITION, IMPORT PARTITION, COALESCE PARTITION, REORGANIZE PARTITION, EXCHANGE PARTITION, ANALYZE PARTITION, CHECK PARTITION, and REPAIR PARTITION options cannot be combined with other alter specifications in a single ALTER TABLE, since the options just listed act on individual partitions. For more information about partition options, see Section 13.1.14, “CREATE TABLE Syntax”, and Section, “ALTER TABLE Partition Operations”. For information about and examples of ALTER TABLE ... EXCHANGE PARTITION statements, see Section 18.3.3, “Exchanging Partitions and Subpartitions with Tables”.

Prior to MySQL 5.7.6, partitioned InnoDB tables used the generic ha_partition partitioning handler employed by MyISAM and other storage engines not supplying their own partitioning handlers; in MySQL 5.7.6 and later, such tables are created using the InnoDB storage engine's own (or native) partitioning handler. Beginning with MySQL 5.7.9, you can upgrade an InnoDB table that was created in MySQL 5.7.6 or earlier (that is, created using ha_partition) to the InnoDB native partition handler using ALTER TABLE ... UPGRADE PARTITIONING. (Bug #76734, Bug #20727344) This version of ALTER TABLE does not accept any other options and can be used only on a single table at a time.


You can also use mysql_upgrade in MySQL 5.7.9 or later to upgrade older partitioned InnoDB tables to the native partitioning handler.

Some operations may result in warnings if attempted on a table for which the storage engine does not support the operation. These warnings can be displayed with SHOW WARNINGS. See Section, “SHOW WARNINGS Syntax”.

For information on troubleshooting ALTER TABLE, see Section B.5.7.1, “Problems with ALTER TABLE”.

Storage, Performance, and Concurrency Considerations

In most cases, ALTER TABLE makes a temporary copy of the original table. MySQL waits for other operations that are modifying the table, then proceeds. It incorporates the alteration into the copy, deletes the original table, and renames the new one. While ALTER TABLE is executing, the original table is readable by other sessions (with the exception noted shortly). Updates and writes to the table that begin after the ALTER TABLE operation begins are stalled until the new table is ready, then are automatically redirected to the new table without any failed updates. The temporary copy of the original table is created in the database directory of the new table. This can differ from the database directory of the original table for ALTER TABLE operations that rename the table to a different database.

The exception referred to earlier is that ALTER TABLE blocks reads (not just writes) at the point where it is ready to install a new version of the table .frm file, discard the old file, and clear outdated table structures from the table and table definition caches. At this point, it must acquire an exclusive lock. To do so, it waits for current readers to finish, and blocks new reads (and writes).

For MyISAM tables, you can speed up index re-creation (the slowest part of the alteration process) by setting the myisam_sort_buffer_size system variable to a high value.

For some operations, an in-place ALTER TABLE is possible that does not require a temporary table:

  • For ALTER TABLE tbl_name RENAME TO new_tbl_name without any other options, MySQL simply renames any files that correspond to the table tbl_name without making a copy. (You can also use the RENAME TABLE statement to rename tables. See Section 13.1.28, “RENAME TABLE Syntax”.) Any privileges granted specifically for the renamed table are not migrated to the new name. They must be changed manually.

  • Alterations that modify only table metadata and not table data are immediate because the server only needs to alter the table .frm file, not touch table contents. The following changes are fast alterations that can be made this way:

    • Renaming a column.

    • Changing the default value of a column.

    • Changing the definition of an ENUM or SET column by adding new enumeration or set members to the end of the list of valid member values, as long as the storage size of the data type does not change. For example, adding a member to a SET column that has 8 members changes the required storage per value from 1 byte to 2 bytes; this will require a table copy. Adding members in the middle of the list causes renumbering of existing members, which requires a table copy.

  • ALTER TABLE with DISCARD ... PARTITION ... TABLESPACE or IMPORT ... PARTITION ... TABLESPACE do not create any temporary tables or temporary partition files.

    ALTER TABLE with ADD PARTITION, DROP PARTITION, COALESCE PARTITION, REBUILD PARTITION, or REORGANIZE PARTITION does not create any temporary tables (except when used with NDB tables); however, these operations can and do create temporary partition files.

    ADD or DROP operations for RANGE or LIST partitions are immediate operations or nearly so. ADD or COALESCE operations for HASH or KEY partitions copy data between all partitions, unless LINEAR HASH or LINEAR KEY was used; this is effectively the same as creating a new table, although the ADD or COALESCE operation is performed partition by partition. REORGANIZE operations copy only changed partitions and do not touch unchanged ones.

  • Renaming an index.

  • Adding or dropping an index, for InnoDB.

You can force an ALTER TABLE operation that would otherwise not require a table copy to use the temporary table method (as supported in MySQL 5.0) by setting the old_alter_table system variable to ON, or specifying ALGORITHM=COPY as one of the alter_specification clauses. If there is a conflict between the old_alter_table setting and an ALGORITHM clause with a value other than DEFAULT, the ALGORITHM clause takes precedence. (ALGORITHM = DEFAULT is the same a specifying no ALGORITHM clause at all.)

Specifying ALGORITHM=INPLACE makes the operation use the in-place technique for clauses and storage engines that support it, and fail with an error otherwise, thus avoiding a lengthy table copy if you try altering a table that uses a different storage engine than you expect. See Section 14.10, “InnoDB and Online DDL” for information about online DDL for InnoDB tables.

As of MySQL 5.7.4, ALTER TABLE upgrades MySQL 5.5 temporal columns to 5.6 format for ADD COLUMN, CHANGE COLUMN, MODIFY COLUMN, ADD INDEX, and FORCE operations. This conversion cannot be done using the INPLACE algorithm because the table must be rebuilt, so specifying ALGORITHM=INPLACE in these cases results in an error. Specify ALGORITHM=COPY if necessary.

Starting with MySQL 5.7.6, an ALTER TABLE operation on a multicolumn index used to partition a table by KEY cannot be performed online when the operation would change the order of the columns. In such cases, you must use a copying ALTER TABLE instead. (Bug #17896265)

You can control the level of concurrent reading and writing of the table while it is being altered, using the LOCK clause. Specifying a non-default value for this clause lets you require a certain amount of concurrent access or exclusivity during the alter operation, and halts the operation if the requested degree of locking is not available. The parameters for the LOCK clause are:


    Maximum level of concurrency for the given ALGORITHM clause (if any) and ALTER TABLE operation: Permit concurrent reads and writes if supported. If not, permit concurrent reads if supported. If not, enforce exclusive access.


    If supported, permit concurrent reads and writes. Otherwise, return an error message.


    If supported, permit concurrent reads but block writes. Note that writes will be blocked even if concurrent writes are supported by the storage engine for the given ALGORITHM clause (if any) and ALTER TABLE operation. If concurrent reads are not supported, return an error message.


    Enforce exclusive access. This will be done even if concurrent reads/writes are supported by the storage engine for the given ALGORITHM clause (if any) and ALTER TABLE operation.

The WITHOUT VALIDATION and WITH VALIDATION clauses affect whether ALTER TABLE performs an in-place operation for VIRTUAL generated column modifications. See ALTER TABLE and Generated Columns.

You can also use ALTER TABLE tbl_name FORCE to perform a null alter operation that rebuilds the table. Previously the FORCE option was recognized but ignored. As of MySQL 5.7.4, online DDL support is provided for the FORCE option. For more information, see Section 14.10.1, “Overview of Online DDL”.

Usage Notes

  • To use ALTER TABLE, you need ALTER, CREATE, and INSERT privileges for the table. Renaming a table requires ALTER and DROP on the old table, ALTER, CREATE, and INSERT on the new table.

  • IGNORE is a MySQL extension to standard SQL. It controls how ALTER TABLE works if there are duplicates on unique keys in the new table or if warnings occur when strict mode is enabled. If IGNORE is not specified, the copy is aborted and rolled back if duplicate-key errors occur. If IGNORE is specified, only one row is used of rows with duplicates on a unique key. The other conflicting rows are deleted. Incorrect values are truncated to the closest matching acceptable value.

    As of MySQL 5.7.4, the IGNORE clause for ALTER TABLE is removed and its use produces an error.

  • table_option signifies a table option of the kind that can be used in the CREATE TABLE statement, such as ENGINE, AUTO_INCREMENT, AVG_ROW_LENGTH, MAX_ROWS, ROW_FORMAT, and TABLESPACE. For a list of all table options and a description of each, see Section 13.1.14, “CREATE TABLE Syntax”. However, ALTER TABLE ignores the DATA DIRECTORY and INDEX DIRECTORY table options.

    • For example, to convert a table to be an InnoDB table, use this statement:


      See Section 14.5.4, “Converting Tables from MyISAM to InnoDB” for considerations when switching tables to the InnoDB storage engine.

      When you specify an ENGINE clause, ALTER TABLE rebuilds the table. This is true even if the table already has the specified storage engine.

      Running ALTER TABLE tbl_name ENGINE=INNODB on an existing InnoDB table performs a null ALTER TABLE operation, which can be used to defragment an InnoDB table, as described in Section 14.9.4, “Defragmenting a Table”. Running ALTER TABLE tbl_name FORCE on an InnoDB table performs the same function.

      As of MySQL 5.7.4, both ALTER TABLE tbl_name ENGINE=INNODB and ALTER TABLE tbl_name FORCE use online DDL (ALGORITHM=COPY). For more information, see Section 14.10.1, “Overview of Online DDL”.

      The outcome of attempting to change a table's storage engine is affected by whether the desired storage engine is available and the setting of the NO_ENGINE_SUBSTITUTION SQL mode, as described in Section 5.1.7, “Server SQL Modes”.

      To prevent inadvertent loss of data, ALTER TABLE cannot be used to change the storage engine of a table to MERGE or BLACKHOLE.

    • To change the value of the AUTO_INCREMENT counter to be used for new rows, do this:


      You cannot reset the counter to a value less than or equal to the value that is currently in use. For both InnoDB and MyISAM, if the value is less than or equal to the maximum value currently in the AUTO_INCREMENT column, the value is reset to the current maximum AUTO_INCREMENT column value plus one.

    • As of MySQL 5.7.6, with the introduction of general tablespaces, you can use ALTER TABLE with the TABLESPACE option to move an InnoDB table to an existing general tablespace, a file-per-table tablespace, or the system tablespace.

      To move a table from a file-per-table tablespace or from the system tablespace to a general tablespace, specify the name of the general tablespace. The general tablespace must exist. See CREATE TABLESPACE for more information.

      ALTER TABLE tbl_name TABLESPACE [=] tablespace_name

      To assign a table from a general tablespace or file-per-table tablespace to the system tablespace, specify innodb_system as the tablespace name.

      ALTER TABLE tbl_name ... TABLESPACE [=] innodb_system

      To assign a table from the system tablespace or a general tablespace to a file-per-table tablespace, specify innodb_file_per_table as the tablespace name.

      ALTER TABLE tbl_name ... TABLESPACE [=] innodb_file_per_table

      ALTER TABLE ... TABLESPACE operations always cause a full table rebuild, even if the TABLESPACE attribute has not changed from its previous value.

      ALTER TABLE ... TABLESPACE syntax does not support moving a table from a temporary tablespace to a persistent tablespace.

      The DATA DIRECTORY clause, which is supported with CREATE TABLE ... TABLESPACE, is not supported with ALTER TABLE ... TABLESPACE, and is ignored if specified.

      For more information about the capabilities and limitations of the TABLESPACE option, see CREATE TABLE.

  • You can issue multiple ADD, ALTER, DROP, and CHANGE clauses in a single ALTER TABLE statement, separated by commas. This is a MySQL extension to standard SQL, which permits only one of each clause per ALTER TABLE statement. For example, to drop multiple columns in a single statement, do this:

  • CHANGE col_name, DROP col_name, and DROP INDEX are MySQL extensions to standard SQL.

  • The word COLUMN is optional and can be omitted.

  • column_definition clauses use the same syntax for ADD and CHANGE as for CREATE TABLE. See Section 13.1.14, “CREATE TABLE Syntax”.

  • You can rename a column using a CHANGE old_col_name new_col_name column_definition clause. To do so, specify the old and new column names and the definition that the column currently has. For example, to rename an INTEGER column from a to b, you can do this:


    To change a column's type but not the name, CHANGE syntax still requires an old and new column name, even if they are the same. For example:


    You can also use MODIFY to change a column's type without renaming it:


    MODIFY is an extension to ALTER TABLE for Oracle compatibility.

    When you use CHANGE or MODIFY, column_definition must include the data type and all attributes that should apply to the new column, other than index attributes such as PRIMARY KEY or UNIQUE. Attributes present in the original definition but not specified for the new definition are not carried forward. Suppose that a column col1 is defined as INT UNSIGNED DEFAULT 1 COMMENT 'my column' and you modify the column as follows:


    The resulting column will be defined as BIGINT, but will not include the attributes UNSIGNED DEFAULT 1 COMMENT 'my column'. To retain them, the statement should be:

  • When you change a data type using CHANGE or MODIFY, MySQL tries to convert existing column values to the new type as well as possible.


    This conversion may result in alteration of data. For example, if you shorten a string column, values may be truncated. To prevent the operation from succeeding if conversions to the new data type would result in loss of data, enable strict SQL mode before using ALTER TABLE (see Section 5.1.7, “Server SQL Modes”).

  • To add a column at a specific position within a table row, use FIRST or AFTER col_name. The default is to add the column last. You can also use FIRST and AFTER in CHANGE or MODIFY operations to reorder columns within a table.

  • ALTER ... SET DEFAULT or ALTER ... DROP DEFAULT specify a new default value for a column or remove the old default value, respectively. If the old default is removed and the column can be NULL, the new default is NULL. If the column cannot be NULL, MySQL assigns a default value as described in Section 11.7, “Data Type Default Values”.

  • DROP INDEX removes an index. This is a MySQL extension to standard SQL. See Section 13.1.21, “DROP INDEX Syntax”. If you are unsure of the index name, use SHOW INDEX FROM tbl_name.

  • If columns are dropped from a table, the columns are also removed from any index of which they are a part. If all columns that make up an index are dropped, the index is dropped as well. If you use CHANGE or MODIFY to shorten a column for which an index exists on the column, and the resulting column length is less than the index length, MySQL shortens the index automatically.

  • If a table contains only one column, the column cannot be dropped. If what you intend is to remove the table, use DROP TABLE instead.

  • DROP PRIMARY KEY drops the primary key. If there is no primary key, an error occurs. For information about the performance characteristics of primary keys, especially for InnoDB tables, see Section 8.3.2, “Using Primary Keys”.

    If you add a UNIQUE INDEX or PRIMARY KEY to a table, MySQL stores it before any nonunique index to permit detection of duplicate keys as early as possible.

  • Some storage engines permit you to specify an index type when creating an index. The syntax for the index_type specifier is USING type_name. For details about USING, see Section 13.1.11, “CREATE INDEX Syntax”. The preferred position is after the column list. Support for use of the option before the column list will be removed in a future MySQL release.

    index_option values specify additional options for an index. USING is one such option. For details about permissible index_option values, see Section 13.1.11, “CREATE INDEX Syntax”.

  • RENAME INDEX old_index_name TO new_index_name renames an index. This is a MySQL extension to standard SQL. The content of the table remains unchanged. old_index_name must be the name of an existing index in the table that is not dropped by the same ALTER TABLE statement. new_index_name is the new index name, which cannot duplicate the name of an index in the resulting table after changes have been applied. Neither index name can be PRIMARY.

  • After an ALTER TABLE statement, it may be necessary to run ANALYZE TABLE to update index cardinality information. See Section, “SHOW INDEX Syntax”.

  • ORDER BY enables you to create the new table with the rows in a specific order. This option is useful primarily when you know that you are mostly to query the rows in a certain order most of the time. By using this option after major changes to the table, you might be able to get higher performance. In some cases, it might make sorting easier for MySQL if the table is in order by the column that you want to order it by later.


    The table does not remain in the specified order after inserts and deletes.

    ORDER BY syntax permits one or more column names to be specified for sorting, each of which optionally can be followed by ASC or DESC to indicate ascending or descending sort order, respectively. The default is ascending order. Only column names are permitted as sort criteria; arbitrary expressions are not permitted. This clause should be given last after any other clauses.

    ORDER BY does not make sense for InnoDB tables because InnoDB always orders table rows according to the clustered index.


    When used on a partitioned table, ALTER TABLE ... ORDER BY orders rows within each partition only.

  • If you use ALTER TABLE on a MyISAM table, all nonunique indexes are created in a separate batch (as for REPAIR TABLE). This should make ALTER TABLE much faster when you have many indexes.

    For MyISAM tables, key updating can be controlled explicitly. Use ALTER TABLE ... DISABLE KEYS to tell MySQL to stop updating nonunique indexes. Then use ALTER TABLE ... ENABLE KEYS to re-create missing indexes. MyISAM does this with a special algorithm that is much faster than inserting keys one by one, so disabling keys before performing bulk insert operations should give a considerable speedup. Using ALTER TABLE ... DISABLE KEYS requires the INDEX privilege in addition to the privileges mentioned earlier.

    While the nonunique indexes are disabled, they are ignored for statements such as SELECT and EXPLAIN that otherwise would use them.

  • In MySQL 5.7, the server prohibits changes to foreign key columns that have the potential to cause loss of referential integrity. It also prohibits changes to the data type of such columns that may be unsafe. For example, changing VARCHAR(20) to VARCHAR(30) is permitted, but changing it to VARCHAR(1024) is not because that alters the number of length bytes required to store individual values. A workaround is to use ALTER TABLE ... DROP FOREIGN KEY before changing the column definition and ALTER TABLE ... ADD FOREIGN KEY afterward.

  • The FOREIGN KEY and REFERENCES clauses are supported by the InnoDB storage engine, which implements ADD [CONSTRAINT [symbol]] FOREIGN KEY [index_name] (...) REFERENCES ... (...). See Section 14.5.6, “InnoDB and FOREIGN KEY Constraints”. For other storage engines, the clauses are parsed but ignored. The CHECK clause is parsed but ignored by all storage engines. See Section 13.1.14, “CREATE TABLE Syntax”. The reason for accepting but ignoring syntax clauses is for compatibility, to make it easier to port code from other SQL servers, and to run applications that create tables with references. See Section 1.8.2, “MySQL Differences from Standard SQL”.

    For ALTER TABLE, unlike CREATE TABLE, ADD FOREIGN KEY ignores index_name if given and uses an automatically generated foreign key name. As a workaround, include the CONSTRAINT clause to specify the foreign key name:

    ADD CONSTRAINT name FOREIGN KEY (....) ...

    The inline REFERENCES specifications where the references are defined as part of the column specification are silently ignored. MySQL only accepts REFERENCES clauses defined as part of a separate FOREIGN KEY specification.


    Partitioned InnoDB tables do not support foreign keys. See Section 18.6.2, “Partitioning Limitations Relating to Storage Engines”, for more information.

  • MySQL supports the use of ALTER TABLE to drop foreign keys:

    ALTER TABLE tbl_name DROP FOREIGN KEY fk_symbol;

    For more information, see Section 14.5.6, “InnoDB and FOREIGN KEY Constraints”.

  • Prior to MySQL 5.6.6, adding and dropping a foreign key in the same ALTER TABLE statement may be problematic in some cases and is therefore unsupported. Separate statements should be used for each operation. As of MySQL 5.6.6, adding and dropping a foreign key in the same ALTER TABLE statement is supported for ALTER TABLE ... ALGORITHM=INPLACE but remains unsupported for ALTER TABLE ... ALGORITHM=COPY.

  • For an InnoDB table that is created with its own file-per-table tablespace in an .ibd file, that file can be discarded and imported. To discard the .ibd file, use this statement:


    This deletes the current file-per-table .ibd file, so be sure that you have a backup first. Attempting to modify the table contents while the tablespace file is discarded results in an error. You can perform the DDL operations listed in Section 14.10, “InnoDB and Online DDL” while the tablespace file is discarded.

    To import the backup .ibd file back into the table, copy it into the database directory, and then issue this statement:


    The tablespace file need not necessarily have been created on the server into which it is imported later. In MySQL 5.7, importing a tablespace file from another server works if the both servers have GA (General Availablility) status and their versions are within the same series. Otherwise, the file must have been created on the server into which it is imported.


    The ALTER TABLE ... IMPORT TABLESPACE feature does not enforce foreign key constraints on imported data.

    ALTER TABLE ... DISCARD TABLESPACE and ALTER TABLE ...IMPORT TABLESPACE are not supported for tables that belong to a general tablespace.

    See Section 14.4.4, “InnoDB File-Per-Table Tablespaces”.

  • To change the table default character set and all character columns (CHAR, VARCHAR, TEXT) to a new character set, use a statement like this:

    ALTER TABLE tbl_name CONVERT TO CHARACTER SET charset_name;

    The statement also changes the collation of all character columns. If you specify no COLLATE clause to indicate which collation to use, the statement uses default collation for the character set. If this collation is inappropriate for the intended table use (for example, if it would change from a case-sensitive collation to a case-insensitive collation), specify a collation explicitly.

    For a column that has a data type of VARCHAR or one of the TEXT types, CONVERT TO CHARACTER SET will change the data type as necessary to ensure that the new column is long enough to store as many characters as the original column. For example, a TEXT column has two length bytes, which store the byte-length of values in the column, up to a maximum of 65,535. For a latin1 TEXT column, each character requires a single byte, so the column can store up to 65,535 characters. If the column is converted to utf8, each character might require up to three bytes, for a maximum possible length of 3 × 65,535 = 196,605 bytes. That length will not fit in a TEXT column's length bytes, so MySQL will convert the data type to MEDIUMTEXT, which is the smallest string type for which the length bytes can record a value of 196,605. Similarly, a VARCHAR column might be converted to MEDIUMTEXT.

    To avoid data type changes of the type just described, do not use CONVERT TO CHARACTER SET. Instead, use MODIFY to change individual columns. For example:

    ALTER TABLE t MODIFY latin1_text_col TEXT CHARACTER SET utf8;
    ALTER TABLE t MODIFY latin1_varchar_col VARCHAR(M) CHARACTER SET utf8;

    If you specify CONVERT TO CHARACTER SET binary, the CHAR, VARCHAR, and TEXT columns are converted to their corresponding binary string types (BINARY, VARBINARY, BLOB). This means that the columns no longer will have a character set and a subsequent CONVERT TO operation will not apply to them.

    If charset_name is DEFAULT, the database character set is used.


    The CONVERT TO operation converts column values between the character sets. This is not what you want if you have a column in one character set (like latin1) but the stored values actually use some other, incompatible character set (like utf8). In this case, you have to do the following for each such column:


    The reason this works is that there is no conversion when you convert to or from BLOB columns.

    To change only the default character set for a table, use this statement:

    ALTER TABLE tbl_name DEFAULT CHARACTER SET charset_name;

    The word DEFAULT is optional. The default character set is the character set that is used if you do not specify the character set for columns that you add to a table later (for example, with ALTER TABLE ... ADD column).

    When foreign_key_checks is enabled, which is the default setting, character set conversion is not permitted on tables that include a character string column used in a foreign key constraint. The workaround is to disable foreign_key_checks before performing the character set conversion. You must perform the conversion on both tables involved in the foreign key constraint before re-enabling foreign_key_checks. If you re-enable foreign_key_checks after converting only one of the tables, an ON DELETE CASCADE or ON UPDATE CASCADE operation could corrupt data in the referencing table due to implicit conversion that occurs during these operations (Bug #45290, Bug #74816).

With the mysql_info() C API function, you can find out how many rows were copied by ALTER TABLE, and (when IGNORE is used) how many rows were deleted due to duplication of unique key values. See Section, “mysql_info()”.

ALTER TABLE and Generated Columns

ALTER TABLE operations permitted for generated columns are ADD, MODIFY, and CHANGE.

  • Generated columns can be added.

  • The data type and expression of generated columns can be modified.

  • Generated columns can be renamed or dropped, if no other column refers to them.

  • Virtual generated columns cannot be altered to stored generated columns, or vice versa. To work around this, drop the column, then add it with the new definition.

  • Nongenerated columns can be altered to stored but not virtual generated columns.

  • Stored but not virtual generated columns can be altered to nongenerated columns. The stored generated values become the values of the nongenerated column.

  • ADD COLUMN is not an in-place operation for stored columns (done without using a temporary table) because the expression must be evaluated by the server. For stored columns, indexing changes are done in place, and expression changes are not done in place. Changes to column comments are done in place.

  • ADD COLUMN and DROP COLUMN are in-place operations for virtual columns. However, adding or dropping a virtual column cannot be performed in combination with other ALTER TABLE operations.

  • As of MySQL 5.7.8, InnoDB supports secondary indexes on virtual generated columns. Adding or dropping a secondary index on a virtual generated column is an in-place operation. For more information, see Secondary Indexes and Virtual Generated Columns.

  • When a VIRTUAL generated column is added to a table or modified, it is not ensured that data being calculated by the generated column expression will not be out of range for the column. This can lead to inconsistent data being returned and unexpectedly failed statements. As of MySQL 5.7.9, to permit control over whether validation occurs for such columns, ALTER TABLE supports WITHOUT VALIDATION and WITH VALIDATION clauses:

    • With WITHOUT VALIDATION (the default if neither clause is specified), an in-place operation is performed (if possible), data integrity is not checked, and the statement finishes more quickly. However, later reads from the table might report warnings or errors for the column if values are out of range.

    • With WITH VALIDATION, ALTER TABLE copies the table. If an out-of-range or any other error occurs, the statement fails. Because a table copy is performed, the statement takes longer.

    WITHOUT VALIDATION and WITH VALIDATION are permitted only with ADD COLUMN, CHANGE COLUMN, and MODIFY COLUMN operations. An ER_WRONG_USAGE error occurs otherwise.

  • As of MySQL 5.7.10, if expression evaluation causes truncation or provides incorrect input to a function, the ALTER TABLE statement terminates with an error and the DDL operation is rejected.

Download this Manual
User Comments
  Posted by Tom S on December 18, 2002
IF you want to change a SET or ENUM column you may
not want to use the ALTER TABLE ... MODIFY
It tries to keep the actual string values and not
the integer representation of the values, even
though they are stored as integers.
For example, if you just want to make a change in
spelling of the values in your enum column or your
set column, consider doing it like this:
ALTER TABLE table ADD new_column ...;
UPDATE table SET new_column = old_column + 0;
ALTER TABLE table DROP old_column;
  Posted by David Bell on August 15, 2003
You can use Alter Table to optimise a table without locking out selects (only writes), by altering a column to be the same as it's current definition. This is better than using repair table which obtains a read/write lock.

mysql> describe Temp_Table;
| Field | Type | Null | Key | Default | Extra |
| ID | int(10) unsigned | YES | | NULL | |
1 row in set (0.00 sec)

mysql> alter table Temp_Table change column ID ID int unsigned;

This will cause mysql to re-create the table and thus remove any deleted space.

This is useful for 24/7 databases where you don't want to completely lock a table.
  Posted by Mark Mackay on July 9, 2004
If you are just changing a column name on a MyISAM table and want to avoid duplicating the entire table, try the following (no warranty provided but worked for me):

For peace-of-mind -- try this with some dummy data first!

1. Backup the <original_table>.frm file from your master table (and the data if you can, but you're probably reading this because you can't).

2. create table with the identical schema to the one you want to alter (type "show create table <tablename> and just change the name to something). Lets say you called the table "rename_temp1"

3. execute the "alter table <rename_temp1> change <old_column_name> <new_column_name> char(128) not null" [substituting your the old definition -- ensuring you keep column type the same]

3. Ensuring you a have made a copy of your original .frm file -- copy the <rename_temp1>.frm file to <original_table>.frm.

4. voila -- all going well your column should be renamed without a full copy in/out (very useful for 140G tables...)

5. probably best to run a myisamchck on the table before making live again
  Posted by Hadi Rastgou on July 13, 2005
When you want to drop a UNIQUE KEY in an InnoDb table, have to pay attention not to occure this situation:
Please check that columns used in the UNIQUE KEY are not used as FOREIGN KEY (each of them).
If so, must to drop that Forign keys first.
See Example below please.

UNIQUE KEY `unique` (`id1`, `id2`),

In this situation, you have to drop both FOREIGN KEYs first, in order to can drop the UNIQUE KEY.
  Posted by Flemming Funch on November 5, 2005
If you're trying to convert a whole database to a different character set, and you thought you might have to change the fields one by one, this kind of command is really handy:

ALTER TABLE tablename CONVERT TO CHARACTER SET utf8 COLLATE utf8_general_ci;

However, after using it on a lot of tables I made the grim discovery that for older myisam tables that didn't have any character set, it mangled the length of most varchar fields. Specifically, it divided their length with 3. Bizarrely, it didn't lose the existing data, even though it was longer than the field lengths, but it was a problem with new records and with indexes.

So, if you're going to do a character set converstion, make sure the table already has a character set. That it doesn't might not be immediately obvious, as tools like phpMyAdmin will show the default character set, if the table or the field doesn't have one set.
  Posted by Daniel Cottrell on November 21, 2005
TO ADD A FOREIGN KEY TO AN EXISTING TABLE (I couldn't see a good example) you can do this:

alter table users add foreign key(favGenre) references products_genre(gid);

Where favgenre is the column of the table that has the foreign key and products_genre(gid) is the table and primary key you are referencing.
  Posted by Duane Hitz on March 31, 2006
Attempting to "ALTER TABLE ... DROP PRIMARY KEY" on a table when an AUTO_INCREMENT column exists in the key generates an error:

ERROR 1075 (42000): Incorrect table definition; there can be only one auto column and it must be defined as a key.

To make this work without erroring, drop and re-add the new primary key in a single statement, e.g.:

  Posted by Rachel McConnell on September 7, 2006
You can't drop a NOT NULL constraint on a column the way you can a foreign key or an index, or a default. Instead, just use the 'change' or 'modify' syntax and leave off the NOT NULL bit:

alter table table_name modify col_name bigint default null;

Any pre-existing indexes or foreign keys on the column are not affected.
  Posted by Geoffrey Hoffman on June 17, 2007
If you are trying to change the case of a table name using the ALTER TABLE syntax and it appears to fail silently,

or if you try to RENAME TABLE something TO soMeThiNg and get a 'table already exists' error,

or if you try to CREATE TABLE MixedCaseTableName and get a table named mixedcasetablename, these are not bugs:

See: Identifier Case Sensitivity

If your development environment has MySQL5 and you're hosting on MySQL4 you can get 'table not found' errors based on the case of the table names.
  Posted by Cengiz Gunay on November 27, 2007
As mentioned above, ALTER TABLE is going to make a temporary copy of the whole table data (.MYD) in the same directory as the original table and not in the temporary directories given to MySQL.

In some cases a third copy of the table (.TMD) is made. This means you must have up to three copies of free space in that directory. Unfortunately MySQL does not break the files into pieces if it runs out of space.

As a table grows larger this process becomes more expensive. Therefore, keys and indices must be added as early as possible to large tables in spite of the update cost that comes with each insert.
  Posted by Reinhard Vielhaber on March 14, 2008
For moving a table from one database to another just do:

use db_old;
alter table tab_name rename db_new.tab_name;
  Posted by John Walker on May 16, 2008
There seem to any number of convoluted methods (not to mention some finger wagging by purists questioning the practice, even here) for altering the sequence of fields in a MySQL table but ALTER does the job as prescribed. It isn't completely self-evident from the description above so here's what worked for me:

ALTER TABLE tablex CHANGE colx colx colxtype AFTER coly.

That is, you're not changing the name of the column but still need to specify 'oldname newname' as 'oldname oldname'
  Posted by Nadav Kavalerchik on March 26, 2009
  Posted by federico cattozzi on April 10, 2009
If you want to change the table's engine for all tables, you can use this code to generate your sql script.

From MyISAM engine to InnoDB engine: set db_name and db_username then copy and paste the follow lines on a Linux/MacOSX shell.

mysql --user=db_username -p --execute="USE information_schema; SELECT CONCAT(\"ALTER TABLE \`\", TABLE_SCHEMA,\"\`.\`\", TABLE_NAME, \"\` TYPE = InnoDB;\") as MySQLCMD from TABLES where TABLE_SCHEMA = \""${DB_NAME}"\";" > ${DB_NAME}-temp.sql;
#delete first line
sed '/MySQLCMD/d' ${DB_NAME}-temp.sql > ${DB_NAME}-innodb.sql;
mysql --user=db_username -p < ${DB_NAME}-innodb.sql;
rm ${DB_NAME}-temp.sql;
rm ${DB_NAME}-innodb.sql;

You can customize the code above for your OS.

I used code from here:,244395,244421#msg-244421

  Posted by John45 G on May 18, 2009
Found some good alter table here:

  Posted by David Friedman on May 7, 2010
It is okay to add two or more columns in the same query where the before and after clauses refer to newly created columns:

  Posted by Bill Vogel on May 27, 2010
If you use "ALTER TABLE mytable AUTO_INCREMENT = N" the MySQL server will create a new table, copy all the data from the old table to the new, delete the old and then rename the new one even though there is no structural change to the table. The server response will show that all the rows have been "affected", like this:
mysql> alter table mytable auto_increment=1000000;
Query OK, 512691 rows affected (1 min 4.55 sec)
Records: 512691 Duplicates: 0 Warnings: 0

There are potential issues that may arise from the table copy, especially if you didn't expect it! I.e. is there a sufficient amount of free disk space for the second copy of the data, etc., etc..

The bottom line for me is to go back to the "old fashioned way" - just insert a dummy row and explicitly set the AUTO_INCREMENT column to N - 1, then immediately delete the dummy row. The next row that is inserted will start at N and go from there.

  Posted by nabeel khan on June 13, 2010
none of the alter code sql queries were working for me in phpmyadmin

however after digging much, finally found something that may help you all.

use this query code:

ALTER TABLE table_name MODIFY column_to_move column_type AFTER column_to_reference

have explained it with example here:
  Posted by Karen Sanasaryan on August 11, 2010
If you need copy big MYISAM tables, just create a new table with same structure (SHOW CREATE TABLE table_to_copy; CREATE TABLE new_table %old table structure%), then copy old table's .frm, .MYD and .MYI files, rename copied files from old_name.* to new_name.*, then run ANALYZE TABLE new_name. No need to restart MySql.
  Posted by Ayden Bissessar on December 6, 2010
If you want to ALTER a table and set the default value to CURRENT_TIMESTAMP for a timestamp column, the listed syntax of "ALTER TABLE foo ALTER COLUMN ts SET DEFAULT CURRENT_TIMESTAMP" will NOT work.

Instead, the syntax below will work. You also need to put the column name twice, I don't know why, it just works.

  Posted by Arthur Liu on February 8, 2011

When adding a new column to a table, and making it a foreign key, if you get

ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails

please check :

1, The new column must be an index column,
2, All value in the new column must be valid foreign keys.

Here are correct steps:
(Suppose you have author in volumes table, but want to add it to books table.)

ALTER TABLE books ADD COLUMN `author` int(10) unsigned NOT NULL ;
ALTER TABLE books ADD INDEX (author) ;
UPDATE books SET author = ( SELECT author FROM volumes WHERE = books.volume_id ) ;
ALTER TABLE books ADD FOREIGN KEY (author) REFERENCES `users` (`id`) ;

  Posted by Claude Warren on March 22, 2011
It is not possible to change a column name on an InnoDB table if the column participates in a foreign key without first dropping the foreign key. It does not matter if the column is used to reference another table or if it is referenced by another table in the foreign key.
  Posted by Lincoln Rickwood on June 24, 2011
Stored procedure to add a column (sorry about the lack of indentation, the comment box seems to strip leading spaces.)

delimiter //
drop procedure if exists AddTableColumn //
create procedure AddTableColumn
( in schemaName varchar(128) -- If null use name of current schema;
, in tableName varchar(128) -- If null an exception will be thrown.
, in columnName varchar(128) -- If null an exception will be thrown.
, in columnDefinition varchar(1024) -- E.g. 'int not null default 1' (Can include comment here if columnComment is null.)
, in columnComment varchar(1024) -- E.g. 'comment about column.' Can be null. (If null then the comment can be included in columnDefinition.)
, in ifPresent enum('leaveUnchanged', 'dropAndReplace', 'modifyExisting') -- null=leaveUnchanged.
, out outcome tinyint(1) -- 0=unchanged, 1=replaced, 2=modified, 4=added.
declare doDrop tinyint(1) default null;
declare doAdd tinyint(1) default null;
declare doModify tinyint(1) default null;
declare tmpSql varchar(4096) default '';

set schemaName = coalesce(schemaName, schema());
set ifPresent = coalesce(ifPresent, 'leaveUnchanged');
-- select schemaName, ifPresent;
if exists
(select *
from `information_schema`.`COLUMNS`
where `COLUMN_NAME` = columnName
and `TABLE_NAME` = tableName
and `TABLE_SCHEMA` = schemaName
-- select 'exists';
if (ifPresent = 'leaveUnchanged')
set doDrop = 0;
set doAdd = 0;
set doModify = 0;
set outcome = 0;
elseif (ifPresent = 'dropAndReplace')
set doDrop = 1;
set doAdd = 1;
set doModify = 0;
set outcome = 1;
elseif (ifPresent = 'modifyExisting')
set doDrop = 0;
set doAdd = 0;
set doModify = 1;
set outcome = 2;
end if;
-- select 'not-exists';
set doDrop = 0;
set doAdd = 1;
set doModify = 0;
set outcome = 4;
end if;

-- select doDrop, doAdd, doModify, outcome;
if (doDrop = 1)
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` drop column `', columnName, '` ');
set @sql = tmpSql;
prepare tmp_stmt from @sql;
execute tmp_stmt;
deallocate prepare tmp_stmt;
end if;

if (doAdd = 1)
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` add column `', columnName, '` ', columnDefinition);
if (columnComment is not null)
set tmpSql = concat(tmpSql, ' comment "', columnComment, '"');
end if;
set @sql = tmpSql;
prepare tmp_stmt from @sql;
execute tmp_stmt;
deallocate prepare tmp_stmt;
end if;

if (doModify = 1)
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` modify column `', columnName, '` ', columnDefinition);
if (columnComment is not null)
set tmpSql = concat(tmpSql, ' comment "', columnComment, '"');
end if;
set @sql = tmpSql;
prepare tmp_stmt from @sql;
execute tmp_stmt;
deallocate prepare tmp_stmt;
end if;
end; //

  Posted by Pavel Tishkin on September 8, 2011
CREATE PROCEDURE `clone_table`(IN tablex TEXT)
DECLARE sqls,tablexs,cols TEXT;


SET tablexs = CONCAT(tablex,'_tmp');

SET @sql=CONCAT('ALTER TABLE `',tablex,'` RENAME TO `',tablexs,'`');
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;

SET @sql=CONCAT('CREATE TABLE ',tablex,' LIKE ',tablexs);
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;

SELECT column_name INTO cols
FROM `information_schema`.`COLUMNS`
WHERE table_name=tablexs
AND table_schema=DATABASE()
AND column_key='pri' AND extra='auto_increment';

SELECT `auto_increment` INTO @id
FROM `information_schema`.`TABLES`
WHERE table_name=tablexs
AND table_schema=DATABASE();

SET @sql=CONCAT('ALTER TABLE `',tablex,'` AUTO_INCREMENT=',@id);
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;
END $$


CREATE PROCEDURE `clone_table_sync`(IN table_namex VARCHAR(100), IN idx INT)
DECLARE table_namexs TEXT;


SET table_namexs = CONCAT(table_namex,'_tmp');

SELECT `auto_increment` INTO ids
FROM `information_schema`.`TABLES`
WHERE table_name=table_namexs
AND table_schema=DATABASE();

WHILE ids>idx DO
SET @sql=CONCAT('INSERT IGNORE INTO `',table_namex,'` SELECT * FROM `',table_namexs,
'` WHERE i_id>',idx,' AND i_id<=',(idx+5000));
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;

-- SELECT SLEEP(1) INTO @tmp2;
SET idx=idx+5000;

END $$
  Posted by Jonathan Evans on December 3, 2011
An addition to John Walker's example above for reordering the columns in a table.

ALTER TABLE tablex CHANGE colx colx colxtype AFTER coly

Not only do you need to specify 'oldname newname' as 'oldname oldname', you also need to respecify the type of 'oldname' as 'colxtype' (or change it of course) for the statement to work.
  Posted by Ferdous Khan on January 12, 2012
ALTER TABLE sales.order ADD UNIQUE(order_ref);

This command will update 'sales' databases 'order' tables 'order_ref' column to become uniquely indexed. If the column already have some duplicate data, an error message will be prompted.
  Posted by Robert Kline on August 12, 2014
Note that if you include 'UNIQUE' as part of the column definition in an ALTER TABLE MODIFY COLUMN ... statement for a column which was original defined as UNIQUE, MySQL will create a second UNIQUE index. What you need to do if you don't want that second index (any why would you? as it does nothing but slow things down), and you're dealing with scripted changes which you have to give to a separate DBA team who won't accept any instructions which involve manual work (so they won't examine the results of the ALTER TABLE statement to find out the name of the extra index which needs to be dropped), on a server over which you don't have administrative privileges, is to leave out the UNIQUE keyword from the column definition, knowing that MySQL will leave the UNIQUE constraint in place. It's as if MySQL doesn't consider 'UNIQUE' as part of the column definition (even though the syntax rules include it as part of column_definition).
  Posted by Saif Ullah on September 6, 2014
If you are just changing a column name on a MyISAM table and want to avoid duplicating the entire table, try the following (no warranty provided but worked for me for my website . I wasted my 4 days looking and searching all around this..):

For peace-of-mind -- try this with some dummy data first!

1. Backup the <original_table>.frm file from your master table (and the data if you can, but you're probably reading this because you can't).

2. create table with the identical schema to the one you want to alter (type "show create table <tablename> and just change the name to something). Lets say you called the table "rename_temp1"

3. execute the "alter table <rename_temp1> change <old_column_name> <new_column_name> char(128) not null" [substituting your the old definition -- ensuring you keep column type the same]

3. Ensuring you a have made a copy of your original .frm file -- copy the <rename_temp1>.frm file to <original_table>.frm.

4. voila -- all going well your column should be renamed without a full copy in/out (very useful for 140G tables...)

5. probably best to run a myisamchck on the table before making live again
Sign Up Login You must be logged in to post a comment.