[+/-]
ALTER [ONLINE|OFFLINE] [IGNORE] TABLEtbl_name[alter_specification[,alter_specification] ...] [partition_options]alter_specification:table_options| ADD [COLUMN]col_namecolumn_definition[FIRST | AFTERcol_name] | ADD [COLUMN] (col_namecolumn_definition,...) | ADD {INDEX|KEY} [index_name] [index_type] (index_col_name,...) [index_option] ... | ADD [CONSTRAINT [symbol]] PRIMARY KEY [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,...)reference_definition| ALGORITHM [=] {DEFAULT|INPLACE|COPY} | ALTER [COLUMN]col_name{SET DEFAULTliteral| DROP DEFAULT} | CHANGE [COLUMN]old_col_namenew_col_namecolumn_definition[FIRST|AFTERcol_name] | LOCK [=] {DEFAULT|NONE|SHARED|EXCLUSIVE} | MODIFY [COLUMN]col_namecolumn_definition[FIRST | AFTERcol_name] | DROP [COLUMN]col_name| DROP PRIMARY KEY | DROP {INDEX|KEY}index_name| DROP FOREIGN KEYfk_symbol| DISABLE KEYS | ENABLE KEYS | RENAME [TO|AS]new_tbl_name| ORDER BYcol_name[,col_name] ... | CONVERT TO CHARACTER SETcharset_name[COLLATEcollation_name] | [DEFAULT] CHARACTER SET [=]charset_name[COLLATE [=]collation_name] | DISCARD TABLESPACE | IMPORT TABLESPACE | FORCE | ADD PARTITION (partition_definition) | DROP PARTITIONpartition_names| TRUNCATE PARTITION {partition_names| ALL} | COALESCE PARTITIONnumber| REORGANIZE PARTITIONpartition_namesINTO (partition_definitions) | EXCHANGE PARTITIONpartition_nameWITH TABLEtbl_name| 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} | REMOVE PARTITIONINGindex_col_name:col_name[(length)] [ASC | DESC]index_type: USING {BTREE | HASH}index_option: KEY_BLOCK_SIZE [=]value|index_type| WITH PARSERparser_name| COMMENT 'string'table_options:table_option[[,]table_option] ... (seeCREATE TABLEoptions)partition_options: (seeCREATE TABLEoptions)
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.
To use
ALTER TABLE, you needALTER,CREATE, andINSERTprivileges for the table. Renaming a table requiresALTERandDROPon the old table,ALTER,CREATE, andINSERTon the new table.Following the table name, specify the alterations to be made. If none are given,
ALTER TABLEdoes nothing.The syntax for many of the permissible alterations is similar to clauses of the
CREATE TABLEstatement.column_definitionclauses use the same syntax forADDandCHANGEas forCREATE TABLE. See Section 13.1.17, “CREATE TABLE Syntax”, for more information.The word
COLUMNis optional and can be omitted.You can issue multiple
ADD,ALTER,DROP, andCHANGEclauses in a singleALTER TABLEstatement, separated by commas. This is a MySQL extension to standard SQL, which permits only one of each clause perALTER TABLEstatement. For example, to drop multiple columns in a single statement, do this:ALTER TABLE t2 DROP COLUMN c, DROP COLUMN d;
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 13.7.5.41, “SHOW WARNINGS Syntax”. For information on troubleshootingALTER TABLE, see Section B.5.6.1, “Problems with ALTER TABLE”.For usage examples, see Section 13.1.7.3, “ALTER TABLE Examples”.
With the
mysql_info()C API function, you can find out how many rows were copied byALTER TABLE, and (whenIGNOREis used) how many rows were deleted due to duplication of unique key values. See Section 23.8.7.35, “mysql_info()”.
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 a list of all table options and
a description of each, 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.6.35, 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
t1is currently not anInnoDBtable, this statement changes its storage engine toInnoDB:ALTER TABLE t1 ENGINE = InnoDB;
See Section 14.8.5, “Converting Tables from MyISAM to InnoDB” for considerations when switching tables to the
InnoDBstorage engine.When you specify an
ENGINEclause,ALTER TABLErebuilds the table. This is true even if the table already has the specified storage engine.Running
ALTER TABLEon an existingtbl_nameENGINE=INNODBInnoDBtable performs a “null”ALTER TABLEoperation, which can be used to defragment anInnoDBtable, as described in Section 14.12.4, “Defragmenting a Table”. RunningALTER TABLEon antbl_nameFORCEInnoDBtable performs the same function.As of MySQL 5.6.17,
ALTER TABLEandtbl_nameENGINE=INNODBALTER TABLEuse online DDL. For more information, see Section 14.13.1, “Overview of Online DDL”.tbl_nameFORCEThe 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_SUBSTITUTIONSQL mode, as described in Section 5.1.8, “Server SQL Modes”.To prevent inadvertent loss of data,
ALTER TABLEcannot be used to change the storage engine of a table toMERGEorBLACKHOLE.
To change the
InnoDBtable 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 the value that is currently in use. For both
InnoDBandMyISAM, if the value is less than or equal to the maximum value currently in theAUTO_INCREMENTcolumn, the value is reset to the current maximumAUTO_INCREMENTcolumn value plus one.To change the default table character set:
ALTER TABLE t1 CHARACTER SET = utf8;
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
INFORMATION_SCHEMA.TABLES.
Performance and Storage Considerations
ALTER TABLE operations that are
not performed in place make 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 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 that resides in a shared
tablespace, the additional space used during a table-copying
ALTER TABLE 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 are
performed in place do not require creating a temporary copy of the
original table. These operations include:
ALTER TABLEoperations onInnoDBtables that are supported by theInnoDBonline DDL feature. For an overview of supported operations, see Section 14.13.1, “Overview of Online DDL”. For information about performance and concurrency of online DDL operations, see Section 14.13.2, “Performance and Concurrency Considerations for Online DDL”.ALTER TABLE. When run without other options, MySQL renames files that correspond to the tabletbl_nameRENAME TOnew_tbl_nametbl_namewithout making a copy. (You can also use theRENAME TABLEstatement 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.Alterations that modify only table metadata and not table data are immediate because the server only needs to alter the table
.frmfile, not touch table contents. The following changes are made in this way:Renaming a column, except for the
InnoDBstorage engine before MySQL 5.6.6.Changing the default value of a column (except for
NDBtables; see Limitations of MySQL Cluster online operations).Changing the definition of an
ENUMorSETcolumn 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 aSETcolumn 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.
Renaming an index, except for
InnoDB.Adding or dropping an index, for
InnoDBandNDB. See Section 14.13.1, “Overview of Online DDL”.For
NDBtables, operations that add and drop indexes on variable-width columns 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 MySQL Cluster”.
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.
You can force an ALTER TABLE operation that
would otherwise not use the table copy 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.)
As of MySQL 5.6.16, 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.
If an ALTER TABLE operation on a multicolumn
index used to partition a table by KEY changes
the order of the columns, it can only be performed using
ALGORITHM=COPY.
MySQL Cluster supports online ALTER TABLE
operations using the ALGORITHM=INPLACE syntax
in MySQL NDB Cluster 7.3 and later. MySQL Cluster also supports an
older syntax specific to NDB that uses the
ONLINE and OFFLINE keywords.
These keywords are deprecated beginning with MySQL NDB Cluster
7.3; they continue to be supported in MySQL NDB Cluster 7.4, but
are subject to removal in a future version of MySQL Cluster. See
Section 13.1.7.2, “ALTER TABLE Online Operations in MySQL Cluster”, for the exact
syntax and other particulars.
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.
Using the LOCK Clause to Control Concurrency
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:
LOCK = DEFAULT
Maximum level of concurrency for the given
ALGORITHMclause (if any) andALTER TABLEoperation: Permit concurrent reads and writes if supported. If not, permit concurrent reads if supported. If not, enforce exclusive access.LOCK = NONE
If supported, permit concurrent reads and writes. Otherwise, return an error message.
LOCK = SHARED
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
ALGORITHMclause (if any) andALTER TABLEoperation. If concurrent reads are not supported, return an error message.LOCK = EXCLUSIVE
Enforce exclusive access. This will be done even if concurrent reads/writes are supported by the storage engine for the given
ALGORITHMclause (if any) andALTER TABLEoperation.
Pending INSERT DELAYED statements
are lost if a table is write locked and
ALTER TABLE is used to modify the
table structure.
Column Attributes
You can rename a column using a
CHANGEclause. To do so, specify the old and new column names and the definition that the column currently has. For example, to rename anold_col_namenew_col_namecolumn_definitionINTEGERcolumn fromatob, you can do this:ALTER TABLE t1 CHANGE a b INTEGER;
To change a column's type but not the name,
CHANGEsyntax still requires an old and new column name, even if they are the same. For example:ALTER TABLE t1 CHANGE b b BIGINT NOT NULL;
You can also use
MODIFYto change a column's type without renaming it:ALTER TABLE t1 MODIFY b BIGINT NOT NULL;
MODIFYis an extension toALTER TABLEfor Oracle compatibility.When you use
CHANGEorMODIFY,column_definitionmust include the data type and all attributes that should apply to the new column, other than index attributes such asPRIMARY KEYorUNIQUE. Attributes present in the original definition but not specified for the new definition are not carried forward. Suppose that a columncol1is defined asINT UNSIGNED DEFAULT 1 COMMENT 'my column'and you modify the column as follows:ALTER TABLE t1 MODIFY col1 BIGINT;
The resulting column will be defined as
BIGINT, but will not include the attributesUNSIGNED DEFAULT 1 COMMENT 'my column'. To retain them, the statement should be:ALTER TABLE t1 MODIFY col1 BIGINT UNSIGNED DEFAULT 1 COMMENT 'my column';
When you change a data type using
CHANGEorMODIFY, MySQL tries to convert existing column values to the new type as well as possible.WarningThis 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.8, “Server SQL Modes”).To add a column at a specific position within a table row, use
FIRSTorAFTER. The default is to add the column last. You can also usecol_nameFIRSTandAFTERinCHANGEorMODIFYoperations to reorder columns within a table.If you use
CHANGEorMODIFYto 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.CHANGEis a MySQL extension to standard SQL.col_nameALTER ... SET DEFAULTorALTER ... DROP DEFAULTspecify a new default value for a column or remove the old default value, respectively. If the old default is removed and the column can beNULL, the new default isNULL. If the column cannot beNULL, MySQL assigns a default value as described in Section 11.6, “Data Type Default Values”.
Primary Keys and Indexes
DROP PRIMARY KEYdrops the primary key. If there is no primary key, an error occurs. For information about the performance characteristics of primary keys, especially forInnoDBtables, see Section 8.3.2, “Using Primary Keys”.If you add a
UNIQUE INDEXorPRIMARY KEYto a table, MySQL stores it before any nonunique index to permit detection of duplicate keys as early as possible.IGNOREis a MySQL extension to standard SQL. It controls howALTER TABLEworks if there are duplicates on unique keys in the new table or if warnings occur when strict mode is enabled. IfIGNOREis not specified, the copy is aborted and rolled back if duplicate-key errors occur. IfIGNOREis 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.6.17, the
IGNOREclause is deprecated and its use generates a warning.IGNOREis removed in MySQL 5.7.DROP INDEXremoves an index. This is a MySQL extension to standard SQL. See Section 13.1.24, “DROP INDEX Syntax”. If you are unsure of the index name, useSHOW INDEX FROM.tbl_nameSome storage engines permit you to specify an index type when creating an index. The syntax for the
index_typespecifier isUSING. For details abouttype_nameUSING, 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_optionvalues specify additional options for an index. For details about permissibleindex_optionvalues, see Section 13.1.13, “CREATE INDEX Syntax”.If you use
ALTER TABLEon aMyISAMtable, all nonunique indexes are created in a separate batch (as forREPAIR TABLE). This should makeALTER TABLEmuch faster when you have many indexes.For
MyISAMtables, key updating can be controlled explicitly. UseALTER TABLE ... DISABLE KEYSto tell MySQL to stop updating nonunique indexes. Then useALTER TABLE ... ENABLE KEYSto re-create missing indexes.MyISAMdoes 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. UsingALTER TABLE ... DISABLE KEYSrequires theINDEXprivilege in addition to the privileges mentioned earlier.While the nonunique indexes are disabled, they are ignored for statements such as
SELECTandEXPLAINthat otherwise would use them.After an
ALTER TABLEstatement, it may be necessary to runANALYZE TABLEto update index cardinality information. See Section 13.7.5.23, “SHOW INDEX Syntax”.
Foreign Keys
Before MySQL 5.6.7, using
ALTER TABLEto change the definition of a foreign key column could cause a loss of referential integrity. For example, changing a foreign key column that containedNULLvalues to beNOT NULLcaused theNULLvalues to be the empty string. Similarly, anALTER TABLE IGNOREthat removed rows in a parent table could break referential integrity.As of 5.6.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)toVARCHAR(30)is permitted, but changing it toVARCHAR(1024)is not because that alters the number of length bytes required to store individual values. A workaround is to useALTER TABLE ... DROP FOREIGN KEYbefore changing the column definition andALTER TABLE ... ADD FOREIGN KEYafterward.The
FOREIGN KEYandREFERENCESclauses are supported by theInnoDBandNDBstorage engines, which implementADD [CONSTRAINT [. See Section 14.8.7, “InnoDB and FOREIGN KEY Constraints”. For other storage engines, the clauses are parsed but ignored. Thesymbol]] FOREIGN KEY [index_name] (...) REFERENCES ... (...)CHECKclause 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, unlikeCREATE TABLE,ADD FOREIGN KEYignoresindex_nameif given and uses an automatically generated foreign key name. As a workaround, include theCONSTRAINTclause to specify the foreign key name:ADD CONSTRAINT
nameFOREIGN KEY (....) ...ImportantThe inline
REFERENCESspecifications where the references are defined as part of the column specification are silently ignored. MySQL only acceptsREFERENCESclauses defined as part of a separateFOREIGN KEYspecification.NotePartitioned
InnoDBtables do not support foreign keys. This restriction does not apply toNDBtables, including those explicitly partitioned by[LINEAR] KEY. See Section 19.6.2, “Partitioning Limitations Relating to Storage Engines”, for more information.The
InnoDBandNDBstorage engines support the use ofALTER TABLEto drop foreign keys:ALTER TABLE
tbl_nameDROP FOREIGN KEYfk_symbol;Prior to MySQL 5.6.6, adding and dropping a foreign key in the same
ALTER TABLEstatement 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 sameALTER TABLEstatement is supported forALTER TABLE ... ALGORITHM=INPLACEbut remains unsupported forALTER TABLE ... ALGORITHM=COPY.ALTER TABLEchanges internally generated foreign key constraint names and user-defined foreign key constraint names that contain the string “tbl_nameRENAMEnew_tbl_nametbl_name_ibfk_” to reflect the new table name.InnoDBinterprets foreign key constraint names that contain the string “tbl_name_ibfk_” as internally generated names.
Dropping Columns
If a table contains only one column, the column cannot be dropped. If what you intend is to remove the table, use
DROP TABLEinstead.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.
DROPis a MySQL extension to standard SQL.col_name
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 TABLEtbl_nameCONVERT TO CHARACTER SETcharset_name[COLLATEcollation_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:
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 TABLEtbl_nameDEFAULT CHARACTER SETcharset_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).
Discarding and Importing InnoDB Tablespaces
An InnoDB table created in its own
file-per-table
tablespace can be discarded and imported using the
DISCARD TABLESPACE and IMPORT
TABLESPACE options. These options can be used to import
a file-per-table tablespace from a backup or to copy a
file-per-table tablespace from one database server to another. See
Section 14.7.6, “Copying File-Per-Table Tablespaces to Another Server”.
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.
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, for
adding, dropping, 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,
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.17, “CREATE TABLE Syntax”, and
Section 13.1.7.1, “ALTER TABLE Partition Operations”. For
information about and examples of ALTER TABLE ...
EXCHANGE PARTITION statements, see
Section 19.3.3, “Exchanging Partitions and Subpartitions with Tables”.
not want to use the ALTER TABLE ... MODIFY
syntax.
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;
E.g.
mysql> describe Temp_Table;
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.
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
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`),
CONSTRAINT `fk_1` FOREIGN KEY (`id1`) REFERENCES `tbl1` (`id`) ON DELETE CASCADE,
CONSTRAINT `fk_2` FOREIGN KEY (`id2`) REFERENCES `tbl2` (`id`) ON DELETE CASCADE
In this situation, you have to drop both FOREIGN KEYs first, in order to can drop the UNIQUE KEY.
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.
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.
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.:
ALTER TABLE mytable DROP PRIMARY KEY, ADD PRIMARY KEY(col1,col2);
alter table table_name modify col_name bigint default null;
Any pre-existing indexes or foreign keys on the column are not affected.
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
http://dev.mysql.com/doc/refman/5.0/en/identifier-case-sensitivity.html
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.
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.
use db_old;
alter table tab_name rename db_new.tab_name;
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'
http://codex.wordpress.org/Converting_Database_Character_Sets
From MyISAM engine to InnoDB engine: set db_name and db_username then copy and paste the follow lines on a Linux/MacOSX shell.
DB_NAME="db_name";
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:
http://forums.mysql.com/read.php?20,244395,244421#msg-244421
http://www.examplenow.com/mysql/alter
--John
ALTER TABLE mytable ADD COLUMN dummy1 VARCHAR(40) AFTER id ADD COLUMN dummy2 VARCHAR(12) AFTER dummy1;
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.
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:
http://nabtron.com/alter-sequence-columns-field-database-table-mysql-phpmyadmin/1914/
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;"
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`) ;
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; //
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 $$
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.
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.
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