Documentation Home
MySQL 5.5 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 26.9Mb
PDF (A4) - 26.9Mb
PDF (RPM) - 25.3Mb
HTML Download (TGZ) - 6.3Mb
HTML Download (Zip) - 6.3Mb
HTML Download (RPM) - 5.3Mb
Man Pages (TGZ) - 157.6Kb
Man Pages (Zip) - 260.8Kb
Info (Gzip) - 2.6Mb
Info (Zip) - 2.6Mb
Excerpts from this Manual

13.1.7 ALTER TABLE Syntax

ALTER [ONLINE|OFFLINE] [IGNORE] TABLE tbl_name
    [alter_specification [, alter_specification] ...]
    [partition_options]

alter_specification:
    table_options
  | ADD [COLUMN] col_name column_definition
        [FIRST | AFTER col_name]
  | ADD [COLUMN] (col_name column_definition,...)
  | ADD {INDEX|KEY} [index_name]
        [index_type] (key_part,...) [index_option] ...
  | ADD [CONSTRAINT [symbol]] PRIMARY KEY
        [index_type] (key_part,...) [index_option] ...
  | ADD [CONSTRAINT [symbol]]
        UNIQUE [INDEX|KEY] [index_name]
        [index_type] (key_part,...) [index_option] ...
  | ADD FULLTEXT [INDEX|KEY] [index_name]
        (key_part,...) [index_option] ...
  | ADD SPATIAL [INDEX|KEY] [index_name]
        (key_part,...) [index_option] ...
  | ADD [CONSTRAINT [symbol]]
        FOREIGN KEY [index_name] (col_name,...)
        reference_definition
  | ALTER [COLUMN] col_name {SET DEFAULT literal | DROP DEFAULT}
  | CHANGE [COLUMN] old_col_name new_col_name column_definition
        [FIRST|AFTER col_name]
  | [DEFAULT] CHARACTER SET [=] charset_name [COLLATE [=] collation_name]
  | CONVERT TO CHARACTER SET charset_name [COLLATE collation_name]
  | {DISABLE|ENABLE} KEYS
  | {DISCARD|IMPORT} TABLESPACE
  | DROP [COLUMN] col_name
  | DROP {INDEX|KEY} index_name
  | DROP PRIMARY KEY
  | DROP FOREIGN KEY fk_symbol
  | FORCE
  | MODIFY [COLUMN] col_name column_definition
        [FIRST | AFTER col_name]
  | ORDER BY col_name [, col_name] ...
  | RENAME [TO|AS] new_tbl_name
  | ADD PARTITION (partition_definition)
  | DROP PARTITION partition_names
  | TRUNCATE PARTITION {partition_names | ALL}
  | COALESCE PARTITION number
  | 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}
  | PARTITION BY partitioning_expression
  | REMOVE PARTITIONING

key_part:
    col_name [(length)] [ASC | DESC]

index_type:
    USING {BTREE | HASH}

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

table_options:
    table_option [[,] table_option] ...

table_option:
    AUTO_INCREMENT [=] value
  | AVG_ROW_LENGTH [=] value
  | [DEFAULT] CHARACTER SET [=] charset_name
  | CHECKSUM [=] {0 | 1}
  | [DEFAULT] COLLATE [=] collation_name
  | COMMENT [=] 'string'
  | CONNECTION [=] 'connect_string'
  | {DATA|INDEX} DIRECTORY [=] 'absolute path to directory'
  | DELAY_KEY_WRITE [=] {0 | 1}
  | ENGINE [=] engine_name
  | INSERT_METHOD [=] { NO | FIRST | LAST }
  | KEY_BLOCK_SIZE [=] value
  | MAX_ROWS [=] value
  | MIN_ROWS [=] value
  | PACK_KEYS [=] {0 | 1 | DEFAULT}
  | PASSWORD [=] 'string'
  | ROW_FORMAT [=] {DEFAULT|DYNAMIC|FIXED|COMPRESSED|REDUNDANT|COMPACT}
  | TABLESPACE tablespace_name [STORAGE {DISK|MEMORY|DEFAULT}]
  | UNION [=] (tbl_name[,tbl_name]...)

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.

There are several additional aspects to the ALTER TABLE statement, described under the following topics in this section:

Table Options

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 descriptions of all table options, see Section 13.1.17, “CREATE TABLE Syntax”. However, ALTER TABLE ignores DATA DIRECTORY and INDEX DIRECTORY when given as table options. ALTER TABLE permits them only as partitioning options, and, as of MySQL 5.5.54, requires that you have the FILE privilege.

Use of table options with ALTER TABLE provides a convenient way of altering single table characteristics. For example:

  • If t1 is currently not an InnoDB table, this statement changes its storage engine to InnoDB:

    ALTER TABLE t1 ENGINE = InnoDB;
    • See Section 14.11.1.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.

    • You can also use ALTER TABLE tbl_name FORCE to perform a null alter operation that rebuilds the table.

    • The outcome of attempting to change the storage engine of a table 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.10, “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 InnoDB table to use compressed row-storage format:

    ALTER TABLE t1 ROW_FORMAT = COMPRESSED;
  • To reset the current auto-increment value:

    ALTER TABLE t1 AUTO_INCREMENT = 13;

    You cannot reset the counter to a value less than or equal to any that have already been used. For 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 plus one. For InnoDB, if the value is less than the current maximum value in the column, no error occurs and the current sequence value is not changed.

  • To change the default table character set:

    ALTER TABLE t1 CHARACTER SET = utf8;

    See also Changing the Character Set.

  • To add (or change) a table comment:

    ALTER TABLE t1 COMMENT = 'New table comment';

To verify that the table options were changed as intended, use SHOW CREATE TABLE, or query the INFORMATION_SCHEMA.TABLES table.

Performance and Space Requirements

ALTER TABLE operations are processed using either the table-copy method or in-place method. Operations that use the table-copy method are performed on a temporary copy of the original table, which can require more time, particularly for large tables. Operations that use the in place method do not create temporary copy of the table and tend to be faster.

ALTER TABLE operations that are performed on a temporary copy of the original table wait for other operations that are modifying the table to complete. After alterations are applied to the table copy, data is copied over, the original table is deleted, and the table copy is renamed to the name of the original table. While the ALTER TABLE operation executes, the original table is readable by other sessions (with the exception noted shortly). Updates and writes to the table started after the ALTER TABLE operation begins are stalled until the new table is ready, then are automatically redirected to the new table. The temporary copy of the table is created in the database directory of the original table unless it is a RENAME TO operation that moves the table to a database that resides in a different directory.

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.

To force use of the table-copy method for an ALTER TABLE operation that would otherwise not use it, enable the old_alter_table system variable.

For InnoDB tables, a table-copying ALTER TABLE operation on table that resides in a shared tablespace such as the system tablespace can increase the amount of space used by the tablespace. Such operations require as much additional space as the data in the table plus indexes. For a table residing in a shared tablespace, the additional space used during the operation is not released back to the operating system as it is for a table that resides in a file-per-table tablespace.

ALTER TABLE operations that use the in-place method include:

  • ALTER TABLE tbl_name RENAME TO new_tbl_name operations executed without any other options. MySQL renames 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.32, “RENAME TABLE Syntax”.) Privileges granted specifically for the renamed table are not migrated to the new name. They must be changed manually.

  • Operations that only modify table metadata. These operations are immediate because the server only needs to alter the table frm file, not touch table contents. Metadata-only operations include:

    • Renaming a column (except for InnoDB tables).

    • Changing the default value of a column (except for NDB tables; see Limitations of NDBCLUSTER online operations).

    • 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 requires a table copy. Adding members in the middle of the list causes renumbering of existing members, which requires a table copy.

  • Adding or dropping a secondary index, for InnoDB and NDBCLUSTER tables. See Section 14.16, “InnoDB Fast Index Creation”.

  • For NDBCLUSTER tables, operations that add and drop indexes on variable-width columns. These operations occur online, without table copying and without blocking concurrent DML actions for most of their duration. See Section 13.1.7.2, “ALTER TABLE Online Operations in NDB Cluster 7.2”.

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.

ALTER TABLE with ADD PARTITION, DROP PARTITION, COALESCE PARTITION, REBUILD PARTITION, or REORGANIZE PARTITION does not create 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.

Note

Pending INSERT DELAYED statements are lost if a table is write locked and ALTER TABLE is used to modify the table structure.

Adding and Dropping Columns

Use ADD to add new columns to a table, and DROP to remove existing columns. DROP col_name is a MySQL extension to standard SQL.

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.

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

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.

Renaming, Redefining, and Reordering Columns

The CHANGE, MODIFY, and ALTER clauses enable the names and definitions of existing columns to be altered. They have these comparative characteristics:

  • CHANGE:

    • Can rename a column and change its definition, or both.

    • Has more capability than MODIFY, but at the expense of convenience for some operations. CHANGE requires naming the column twice if not renaming it.

    • With FIRST or AFTER, can reorder columns.

  • MODIFY:

    • Can change a column definition but not its name.

    • More convenient than CHANGE to change a column definition without renaming it.

    • With FIRST or AFTER, can reorder columns.

  • ALTER: Used only to change a column default value.

CHANGE is a MySQL extension to standard SQL. MODIFY is a MySQL extension for Oracle compatibility.

To alter a column to change both its name and definition, use CHANGE, specifying the old and new names and the new definition. For example, to rename an INT NOT NULL column from a to b and change its definition to use the BIGINT data type while retaining the NOT NULL attribute, do this:

ALTER TABLE t1 CHANGE a b BIGINT NOT NULL;

To change a column definition but not its name, use CHANGE or MODIFY. With CHANGE, the syntax requires two column names, so you must specify the same name twice to leave the name unchanged. For example, to change the definition of column b, do this:

ALTER TABLE t1 CHANGE b b INT NOT NULL;

MODIFY is more convenient to change the definition without changing the name because it requires the column name only once:

ALTER TABLE t1 MODIFY b INT NOT NULL;

To change a column name but not its definition, use CHANGE. The syntax requires a column definition, so to leave the definition unchanged, you must respecify the definition the column currently has. For example, to rename an INT NOT NULL column from b to a, do this:

ALTER TABLE t1 CHANGE b a INT NOT NULL;

For column definition changes using CHANGE or MODIFY, the 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, intending to change only INT to BIGINT:

ALTER TABLE t1 MODIFY col1 BIGINT;

That statement changes the data type from INT to BIGINT, but it also drops the UNSIGNED, DEFAULT, and COMMENT attributes. To retain them, the statement must include them explicitly:

ALTER TABLE t1 MODIFY col1 BIGINT UNSIGNED DEFAULT 1 COMMENT 'my column';

For data type changes using CHANGE or MODIFY, MySQL tries to convert existing column values to the new type as well as possible.

Warning

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.10, “Server SQL Modes”).

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.

For columns renamed by CHANGE, MySQL automatically renames these references to the renamed column:

  • Indexes that refer to the old column, including indexes and disabled MyISAM indexes.

For columns renamed by CHANGE, MySQL does not automatically rename these references to the renamed column:

  • Foreign keys that refer to the old column.

  • Partition expressions that refer to the renamed column. You must use CHANGE to redefine such expressions in the same ALTER TABLE statement as the one that renames the column.

  • Views and stored programs that refer to the renamed column. You must manually alter the definition of these objects to refer to the new column name.

To reorder columns within a table, use FIRST and AFTER in CHANGE or MODIFY operations.

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.6, “Data Type Default Values”.

Primary Keys and Indexes

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, “Primary Key Optimization”.

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.

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.

Note

Due to a bug related to Fast Index Creation (Bug #40344), ALTER IGNORE TABLE ... ADD UNIQUE INDEX does not delete duplicate rows. The IGNORE keyword is ignored. If any duplicate rows exist, the operation fails with a Duplicate entry error. A workaround is to set old_alter_table=1 prior to running an ALTER IGNORE TABLE ... ADD UNIQUE INDEX statement.

SET SESSION old_alter_table=1

DROP INDEX removes an index. This is a MySQL extension to standard SQL. See Section 13.1.24, “DROP INDEX Syntax”. To determine index names, use SHOW INDEX FROM tbl_name.

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.13, “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. For details about permissible index_option values, see Section 13.1.13, “CREATE INDEX Syntax”.

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.

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

Foreign Keys

If ALTER TABLE for an InnoDB table results in changes to column values (for example, because a column is truncated), InnoDB's FOREIGN KEY constraint checks do not notice possible violations caused by changing the values.

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.11.1.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.17, “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.7.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 (....) ...
Important

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

Note

Partitioned InnoDB tables do not support foreign keys. For more information, see Section 19.5.2, “Partitioning Limitations Relating to Storage Engines”.

InnoDB supports the use of ALTER TABLE to drop foreign keys:

ALTER TABLE tbl_name DROP FOREIGN KEY fk_symbol;

Adding and dropping a foreign key in separate clauses of a single ALTER TABLE statement may be problematic in some cases and is therefore unsupported. Use separate statements for each operation.

ALTER TABLE tbl_name RENAME new_tbl_name changes internally generated foreign key constraint names and user-defined foreign key constraint names that contain the string tbl_name_ibfk_ to reflect the new table name. InnoDB interprets foreign key constraint names that contain the string tbl_name_ibfk_ as internally generated names.

Changing the Character Set

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 [COLLATE collation_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 changes 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 does not fit in a TEXT column's length bytes, so MySQL converts 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 attribute and a subsequent CONVERT TO operation will not apply to them.

If charset_name is DEFAULT in a CONVERT TO CHARACTER SET operation, the character set named by the character_set_database system variable is used.

Warning

The CONVERT TO operation converts column values between the original and named 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:

ALTER TABLE t1 CHANGE c1 c1 BLOB;
ALTER TABLE t1 CHANGE c1 c1 TEXT CHARACTER SET utf8;

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 the foreign_key_checks system variable 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).

Discarding and Importing InnoDB Tablespaces

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

ALTER TABLE tbl_name DISCARD TABLESPACE;

This deletes the current .ibd file, so be sure that you have a backup first. Attempting to access the table while the tablespace file is discarded results in an error.

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

ALTER TABLE tbl_name IMPORT TABLESPACE;

The tablespace file must have been created on the server into which it is imported later.

Note

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

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

Row Order for MyISAM Tables

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 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.

Note

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.

Partitioning Options

partition_options signifies options that can be used with partitioned tables for repartitioning, to add, drop, discard, merge, and split partitions, and to perform 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, COALESCE PARTITION, REORGANIZE 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 a list of partition options and a description of each, see Section 13.1.17, “CREATE TABLE Syntax”. For additional information, see Section 13.1.7.1, “ALTER TABLE Partition Operations”.


User Comments
User comments in this section are, as the name implies, provided by MySQL users. The MySQL documentation team is not responsible for, nor do they endorse, any of the information provided here.
  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.

"ALTER TABLE tablename CHANGE columnname columnname TIMESTAMP DEFAULT CURRENT_TIMESTAMP;"
  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 volumes.id = 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.
)
begin
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
)
then
-- select 'exists';
if (ifPresent = 'leaveUnchanged')
then
set doDrop = 0;
set doAdd = 0;
set doModify = 0;
set outcome = 0;
elseif (ifPresent = 'dropAndReplace')
then
set doDrop = 1;
set doAdd = 1;
set doModify = 0;
set outcome = 1;
elseif (ifPresent = 'modifyExisting')
then
set doDrop = 0;
set doAdd = 0;
set doModify = 1;
set outcome = 2;
end if;
else
-- 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)
then
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)
then
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` add column `', columnName, '` ', columnDefinition);
if (columnComment is not null)
then
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)
then
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` modify column `', columnName, '` ', columnDefinition);
if (columnComment is not null)
then
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)
BEGIN
DECLARE sqls,tablexs,cols TEXT;
DECLARE done INT DEFAULT 0;

DECLARE CONTINUE HANDLER FOR SQLSTATE '02000' SET done=1;

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

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

SET @sql=CONCAT('CREATE TABLE ',tablex,' LIKE ',tablexs);
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;
DEALLOCATE PREPARE 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';

IF NOT done THEN
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;
DEALLOCATE PREPARE stmt1;
END IF;
END $$

AND

CREATE PROCEDURE `clone_table_sync`(IN table_namex VARCHAR(100), IN idx INT)
BEGIN
DECLARE done, ids INT DEFAULT 0;
DECLARE table_namexs TEXT;

DECLARE CONTINUE HANDLER FOR SQLSTATE '02000' SET done=1;

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;
DEALLOCATE PREPARE stmt1;

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

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 http://techleaks.us/ . 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.