ALTER [IGNORE] TABLE tbl_name alter_spec [, alter_spec ...]
alter_specification:
ADD [COLUMN] create_definition [FIRST | AFTER column_name ]
or ADD INDEX [index_name] (index_col_name,...)
or ADD PRIMARY KEY (index_col_name,...)
or ADD UNIQUE [index_name] (index_col_name,...)
or ALTER [COLUMN] col_name {SET DEFAULT literal | DROP DEFAULT}
or CHANGE [COLUMN] old_col_name create_definition
or MODIFY [COLUMN] create_definition
or DROP [COLUMN] col_name
or DROP PRIMARY KEY
or DROP INDEX index_name
or RENAME [AS] new_tbl_name
or table_options
ALTER TABLE allows you to change the structure of an existing 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 the comment for the table and type of the table.
CREATE TABLE.
If you use ALTER TABLE to change a column specification but
DESCRIBE tbl_name indicates that your column was not changed, it is
possible that MySQL ignored your modification for one of the reasons
described in 7.6.1 Silent column specification changes. For example, if you try to change
a VARCHAR column to CHAR, MySQL will still use
VARCHAR if the table contains other variable-length columns.
ALTER TABLE works by making a temporary copy of the original table.
The alteration is performed on the copy, then the original table is
deleted and the new one is renamed. This is done in such a way that
all updates are automatically redirected to the new table without
any failed updates. While ALTER TABLE is executing, the original
table is readable by other clients. Updates and writes to the table
are stalled until the new table is ready.
-
To use
ALTER TABLE, you need select, insert,
delete, update, create and drop
privileges on the table.
-
IGNORE is a MySQL extension to ANSI SQL92.
It controls how ALTER TABLE works if there are duplicates on
unique keys in the new table.
If IGNORE isn't specified, the copy is aborted and rolled back.
If IGNORE is specified, then for rows with duplicates on a unique
key, only the first row is used; the others are deleted.
-
You can issue multiple
ADD, ALTER, DROP and
CHANGE clauses in a single ALTER TABLE statement. This is a
MySQL extension to ANSI SQL92, which allows only one of each clause
per ALTER TABLE statement.
-
CHANGE col_name, DROP col_name and DROP
INDEX are MySQL extensions to ANSI SQL92.
-
MODIFY is an Oracle extension to ALTER TABLE.
-
The optional word
COLUMN is a pure noise word and can be omitted.
-
If you use
ALTER TABLE tbl_name RENAME AS new_name without any other
options, MySQL simply renames the files that correspond to the table
tbl_name. There is no need to create the temporary table.
-
create_definition clauses use the same syntax for ADD and
CHANGE as for CREATE TABLE. Note that this syntax includes
the column name, not just the column type.
CREATE TABLE.
-
You can rename a column using a
CHANGE old_col_name create_definition
clause. To do so, specify the old and new column names and the type that
the column currently has. For example, to rename an INTEGER column
from a to b, you can do this:
mysql> ALTER TABLE t1 CHANGE a b INTEGER;
If you want to change a column's type but not the name, CHANGE
syntax still requires two column names even if they are the same. For
example:
mysql> ALTER TABLE t1 CHANGE b b BIGINT NOT NULL;
However, as of MySQL 3.22.16a, you can also use MODIFY to
change a column's type without renaming it:
mysql> ALTER TABLE t1 MODIFY b BIGINT NOT NULL;
-
If you use
CHANGE or MODIFY to shorten a column for which
an index exists on part of the column (for instance, if you have an index
on the first 10 characters of a VARCHAR column), you cannot make
the column shorter than the number of characters that are indexed.
-
When you change a column type using
CHANGE or MODIFY,
MySQL tries to convert data to the new type as well as possible.
-
In MySQL 3.22 or later, you can use
FIRST or ADD ...
AFTER col_name to add a column at a specific position within a table row.
The default is to add the column last.
-
ALTER COLUMN specifies a new default value for a column
or removes the old default value.
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.
Default value assignment is described in
CREATE TABLE.
-
DROP INDEX removes an index. This is a MySQL extension to
ANSI SQL92.
-
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.
-
DROP PRIMARY KEY drops the primary index. If no such
index exists, it drops the first UNIQUE index in the table.
(MySQL marks the first UNIQUE key as the PRIMARY KEY
if no PRIMARY KEY was specified explicitly.)
-
With the C API function
mysql_info(), you can find out how many
records were copied, and (when IGNORE is used) how many records were
deleted due to duplication of unique key values.
-
The
FOREIGN KEY, CHECK and REFERENCES clauses don't
actually do anything. The syntax for them is provided only for compatibility,
to make it easier to port code from other SQL servers and to run applications
that create tables with references.
5.3 Functionality missing from MySQL.
Here is an example that shows some of the uses of ALTER TABLE. We
begin with a table t1 that is created as shown below:
mysql> CREATE TABLE t1 (a INTEGER,b CHAR(10));
To rename the table from t1 to t2:
mysql> ALTER TABLE t1 RENAME t2;
To change column a from INTEGER to TINYINT NOT NULL
(leaving the name the same), and to change column b from
CHAR(10) to CHAR(20) as well as renaming it from b to
c:
mysql> ALTER TABLE t2 MODIFY a TINYINT NOT NULL, CHANGE b c CHAR(20);
To add a new TIMESTAMP column named d:
mysql> ALTER TABLE t2 ADD d TIMESTAMP;
To add an index on column d, and make column a the primary key:
mysql> ALTER TABLE t2 ADD INDEX (d), ADD PRIMARY KEY (a);
To remove column c:
mysql> ALTER TABLE t2 DROP COLUMN c;
To add a new AUTO_INCREMENT integer column named c:
mysql> ALTER TABLE t2 ADD c INT UNSIGNED NOT NULL AUTO_INCREMENT,
ADD INDEX (c);
Note that we indexed c, because AUTO_INCREMENT columns must be
indexed, and also that we declare c as NOT NULL, because
indexed columns cannot be NULL.
When you add an AUTO_INCREMENT column, column values are filled in
with sequence numbers for you automatically.