DOC HOME SITE MAP MAN PAGES GNU INFO SEARCH
 

(mysql.info.gz) ALTER TABLE

Info Catalog (mysql.info.gz) ALTER DATABASE (mysql.info.gz) Data Definition (mysql.info.gz) ALTER VIEW
 
 13.2.2 `ALTER TABLE' Syntax
 ---------------------------
 
      ALTER [IGNORE] TABLE TBL_NAME
          ALTER_SPECIFICATION [, ALTER_SPECIFICATION] ...
 
      ALTER_SPECIFICATION:
          ADD [COLUMN] COLUMN_DEFINITION [FIRST | AFTER COL_NAME ]
        | ADD [COLUMN] (COLUMN_DEFINITION,...)
        | ADD INDEX [INDEX_NAME] [INDEX_TYPE] (INDEX_COL_NAME,...)
        | ADD [CONSTRAINT [SYMBOL]]
              PRIMARY KEY [INDEX_TYPE] (INDEX_COL_NAME,...)
        | ADD [CONSTRAINT [SYMBOL]]
              UNIQUE [INDEX_NAME] [INDEX_TYPE] (INDEX_COL_NAME,...)
        | ADD [FULLTEXT|SPATIAL] [INDEX_NAME] (INDEX_COL_NAME,...)
        | ADD [CONSTRAINT [SYMBOL]]
              FOREIGN KEY [INDEX_NAME] (INDEX_COL_NAME,...)
              [REFERENCE_DEFINITION]
        | ALTER [COLUMN] COL_NAME {SET DEFAULT LITERAL | DROP DEFAULT}
        | CHANGE [COLUMN] OLD_COL_NAME COLUMN_DEFINITION
              [FIRST|AFTER COL_NAME]
        | MODIFY [COLUMN] COLUMN_DEFINITION [FIRST | AFTER COL_NAME]
        | DROP [COLUMN] COL_NAME
        | DROP PRIMARY KEY
        | DROP INDEX INDEX_NAME
        | DROP FOREIGN KEY FK_SYMBOL
        | DISABLE KEYS
        | ENABLE KEYS
        | RENAME [TO] NEW_TBL_NAME
        | ORDER BY COL_NAME
        | CONVERT TO CHARACTER SET CHARSET_NAME [COLLATE COLLATION_NAME]
        | [DEFAULT] CHARACTER SET CHARSET_NAME [COLLATE COLLATION_NAME]
        | DISCARD TABLESPACE
        | IMPORT TABLESPACE
        | 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.
 
 The syntax for many of the allowable alterations is similar to clauses
 of the `CREATE TABLE' statement.   `CREATE TABLE' CREATE TABLE.
 
 Some operations may result in warnings if attempted on a table for which
 the storage engine does not support the operation. In MySQL 4.1 and up,
 these warnings can be displayed with `SHOW WARNINGS'.   `SHOW
 WARNINGS' SHOW WARNINGS.
 
 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  Silent column 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.  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, then are
 automatically redirected to the new table without any failed updates.
 
 Note that if you use any other option to `ALTER TABLE' than `RENAME',
 MySQL always creates a temporary table, even if the data wouldn't
 strictly need to be copied (such as when you change the name of a
 column). We plan to fix this in the future, but because `ALTER TABLE'
 is not a statement that is normally used frequently, this isn't high on
 our TODO list.  For `MyISAM' tables, you can speed up the index
 re-creation operation (which is the slowest part of the alteration
 process) by setting the `myisam_sort_buffer_size' system variable to a
 high value.
 
    * To use `ALTER TABLE', you need `ALTER', `INSERT', and `CREATE'
      privileges for the 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.  If `IGNORE' isn't specified, the copy is aborted and
      rolled back if duplicate-key errors occur.  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 standard SQL, which allows only one of each clause
      per `ALTER TABLE' statement. For example, to drop multiple columns
      in a single statement:
 
           mysql> ALTER TABLE t2 DROP COLUMN c, DROP COLUMN d;
 
    * `CHANGE COL_NAME', `DROP COL_NAME', and `DROP INDEX' are MySQL
      extensions to standard SQL.
 
    * `MODIFY' is an Oracle extension to `ALTER TABLE'.
 
    * The word `COLUMN' is purely optional and can be omitted.
 
    * If you use `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.  There is no need to create a temporary
      table.  (You can also use the `RENAME TABLE' statement to rename
      tables.   `RENAME TABLE' RENAME TABLE.)
 
    * COLUMN_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'
      CREATE TABLE.
 
    * You can rename a column using a `CHANGE OLD_COL_NAME
      COLUMN_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 an old and new column name, 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 example, 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 existing column values to the new type as well as
      possible.
 
    * In MySQL 3.22 or later, you can use `FIRST' or `AFTER COL_NAME' to
      add a column at a specific position within a table row. The
      default is to add the column last.  From MySQL 4.0.1 on, you can
      also use `FIRST' and `AFTER' in `CHANGE' or `MODIFY' operations.
 
    * `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, as described in
       `CREATE TABLE' CREATE TABLE.
 
    * `DROP INDEX' removes an index. This is a MySQL extension to
      standard SQL.  `DROP INDEX' DROP INDEX.
 
    * 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 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 index. (Prior to MySQL 4.1.2,
      if no primary index exists, `DROP PRIMARY KEY' 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.)
 
      If you add a `UNIQUE INDEX' or `PRIMARY KEY' to a table, it is
      stored before any non-unique index so that MySQL can detect
      duplicate keys as early as possible.
 
    * `ORDER BY' allows you to create the new table with the rows in a
      specific order.  Note that the table will not remain in this order
      after inserts and deletes.  This option is mainly useful when you
      know that you are mostly going to query the rows in a certain
      order; by using this option after big 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.
 
    * If you use `ALTER TABLE' on a `MyISAM' table, all non-unique
      indexes are created in a separate batch (as for `REPAIR TABLE').
      This should make `ALTER TABLE' much faster when you have many
      indexes.
 
      As of MySQL 4.0, this feature can be activated explicitly.  `ALTER
      TABLE ... DISABLE KEYS' tells MySQL to stop updating non-unique
      indexes for a `MyISAM' table.  `ALTER TABLE ... ENABLE KEYS' then
      should be used to re-create missing indexes. MySQL 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' will require the `INDEX' privilege in addition to the
      privileges mentioned earlier.
 
    * The `FOREIGN KEY' and `REFERENCES' clauses are supported by the
      `InnoDB' storage engine, which implements `ADD [CONSTRAINT
      [SYMBOL]] FOREIGN KEY (...) REFERENCES ... (...)'.   `InnoDB'
      foreign key constraints InnoDB foreign key constraints.  For
      other storage engines, the clauses are parsed but ignored.  The
      `CHECK' clause is parsed but ignored by all storage engines.
       `CREATE TABLE' CREATE TABLE.  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.   Differences from ANSI.
 
    * Starting from MySQL 4.0.13, `InnoDB' supports the use of `ALTER
      TABLE' to drop foreign keys:
 
           ALTER TABLE YOURTABLENAME DROP FOREIGN KEY FK_SYMBOL;
 
      For more information, see  `InnoDB' foreign key constraints
      InnoDB foreign key constraints.
 
    * `ALTER TABLE' ignores the `DATA DIRECTORY' and `INDEX DIRECTORY'
      table options.
 
    * From MySQL 4.1.2 on, if you want to change 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;
 
      This is useful, for example, after upgrading from MySQL 4.0.x to
      4.1.x.   Charset-upgrading.
 
      *Warning:* The preceding operation will convert 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 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 don't specify the character set
      for a new column you add to a table (for example, with `ALTER
      TABLE ... ADD column').
 
      *Warning:* From MySQL 4.1.2 and up, `ALTER TABLE ... DEFAULT
      CHARACTER SET' and `ALTER TABLE ... CHARACTER SET' are equivalent
      and change only the default table character set. In MySQL 4.1
      releases before 4.1.2, `ALTER TABLE ...  DEFAULT CHARACTER SET'
      changes the default character set, but `ALTER TABLE ...  CHARACTER
      SET' (without `DEFAULT') changes the default character set _and
      also_ converts all columns to the new character set.
 
    * 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, then issue this statement:
 
           ALTER TABLE TBL_NAME IMPORT TABLESPACE;
 
       Multiple tablespaces.
 
    * With the `mysql_info()' C API function, 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.  
      `mysql_info()' mysql_info.
 
 
 Here are some examples that show uses of `ALTER TABLE'.  Begin with a
 table `t1' that is created as shown here:
 
      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 indexes on column `d' and on column `a':
 
      mysql> ALTER TABLE t2 ADD INDEX (d), ADD INDEX (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 PRIMARY KEY (c);
 
 Note that we indexed `c' (as a `PRIMARY KEY'), because `AUTO_INCREMENT'
 columns must be indexed, and also that we declare `c' as `NOT NULL',
 because primary key columns cannot be `NULL'.
 
 When you add an `AUTO_INCREMENT' column, column values are filled in
 with sequence numbers for you automatically.  For `MyISAM' tables, you
 can set the first sequence number by executing `SET INSERT_ID=VALUE'
 before `ALTER TABLE' or by using the `AUTO_INCREMENT=VALUE' table
 option.   `SET OPTION' SET OPTION.
 
 From MySQL 5.0.3, you can use the `ALTER TABLE ...
 AUTO_INCREMENT=VALUE' table option for `InnoDB' tables to set the
 sequence number for new rows if the value is greater than the maximum
 value in the `AUTO_INCREMENT' column.  If the value is less than the
 maximum column value, no error message is given and the current
 sequence value is not changed.
 
 With `MyISAM' tables, if you don't change the `AUTO_INCREMENT' column,
 the sequence number will not be affected. If you drop an
 `AUTO_INCREMENT' column and then add another `AUTO_INCREMENT' column,
 the numbers are resequenced beginning with 1.
 
  `ALTER TABLE' problems ALTER TABLE problems.
 
Info Catalog (mysql.info.gz) ALTER DATABASE (mysql.info.gz) Data Definition (mysql.info.gz) ALTER VIEW
automatically generated byinfo2html