DOC HOME SITE MAP MAN PAGES GNU INFO SEARCH PRINT BOOK
 

(mysql.info) alter-table

Info Catalog (mysql.info) alter-database (mysql.info) data-definition (mysql.info) create-database
 
 13.1.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] [INDEX_NAME] [INDEX_TYPE] (INDEX_COL_NAME,...)
        | ADD [FULLTEXT|SPATIAL] [INDEX] [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' enables 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. This includes TABLE_OPTIONS
 modifications, for options such as `ENGINE', `AUTO_INCREMENT', and
 `AVG_ROW_LENGTH'. (However, `ALTER TABLE' ignores the `DATA DIRECTORY'
 and `INDEX DIRECTORY' table options.)   create-table, lists all
 table options.
 
 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 
 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 still uses `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, and 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, and then are
 automatically redirected to the new table without any failed updates.
 
 Note that if you use any option to `ALTER TABLE' other 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). 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 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 the
      first 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.
 
    * You can issue multiple `ADD', `ALTER', `DROP', and `CHANGE'
      clauses in a single `ALTER TABLE' statement, separated by commas.
      This is a MySQL extension to standard SQL, which allows only one of
      each clause per `ALTER TABLE' statement.  For example, to drop
      multiple columns in a single statement, do this:
 
           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 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. See  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 its data type. See  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:
 
           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:
 
           ALTER TABLE t1 CHANGE b b BIGINT NOT NULL;
 
      You can also use `MODIFY' to change a column's type without
      renaming it:
 
           ALTER TABLE t1 MODIFY b BIGINT NOT NULL;
 
    * 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.
 
    * When you change a data type using `CHANGE' or `MODIFY', MySQL
      tries to convert existing column values to the new type as well as
      possible.
 
    * To add a column at a specific position within a table row, use
      `FIRST' or `AFTER COL_NAME'. The default is to add the column
      last. You can also use `FIRST' and `AFTER' in `CHANGE' or `MODIFY'
      operations.
 
    * `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 
      data-type-defaults.
 
    * `DROP INDEX' removes an index. This is a MySQL extension to
      standard SQL. See  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.  _Note_: In older
      versions of MySQL, if no primary index existed, `DROP PRIMARY KEY'
      would drop the first `UNIQUE' index in the table. This is not the
      case in MySQL 5.0, where trying to use `DROP PRIMARY KEY' on a
      table with no primary key give rises to an error.
 
      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' enables you to create the new table with the rows in a
      specific order. Note that the table does not remain in this order
      after inserts and deletes.  This option is useful primarily when
      you know that you are mostly to query the rows in a certain order
      most of the time. By using this option after major changes to the
      table, you might be able to get higher performance. In some cases,
      it might make sorting easier for MySQL if the table is in order by
      the column that you want to order it by later.
 
    * 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.
 
      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'
      requires 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 ... (...)'. See 
      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. See  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. See  differences-from-ansi.
 
      You cannot add a foreign key and drop a foreign key in separate
      clauses of a single `ALTER TABLE' statement. You must use separate
      statements.
 
    * `InnoDB' supports the use of `ALTER TABLE' to drop foreign keys:
 
           ALTER TABLE TBL_NAME DROP FOREIGN KEY FK_SYMBOL;
 
      You cannot add a foreign key and drop a foreign key in separate
      clauses of a single `ALTER TABLE' statement. You must use separate
      statements.
 
      For more information, see  innodb-foreign-key-constraints.
 
    * If you want 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;
 
      *Warning:* The preceding 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.
 
      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.
 
      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 a new column which you add to a table (for example, with
      `ALTER TABLE ... ADD column').
 
    * 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;
 
      See  multiple-tablespaces.
 
 With the `mysql_info()' C API function, you can find out how many rows
 were copied, and (when `IGNORE' is used) how many rows were deleted due
 to duplication of unique key values. See  mysql-info.
 
 Here are some examples that show uses of `ALTER TABLE'. Begin with a
 table `t1' that is created as shown here:
 
      CREATE TABLE t1 (a INTEGER,b CHAR(10));
 
 To rename the table from `t1' to `t2':
 
      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':
 
      ALTER TABLE t2 MODIFY a TINYINT NOT NULL, CHANGE b c CHAR(20);
 
 To add a new `TIMESTAMP' column named `d':
 
      ALTER TABLE t2 ADD d TIMESTAMP;
 
 To add indexes on column `d' and on column `a':
 
      ALTER TABLE t2 ADD INDEX (d), ADD INDEX (a);
 
 To remove column `c':
 
      ALTER TABLE t2 DROP COLUMN c;
 
 To add a new `AUTO_INCREMENT' integer column named `c':
 
      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. See  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
 current maximum value in the column, no error message is given and the
 current sequence value is not changed._
 
 With `MyISAM' tables, if you do not change the `AUTO_INCREMENT' column,
 the sequence number is not affected. If you drop an `AUTO_INCREMENT'
 column and then add another `AUTO_INCREMENT' column, the numbers are
 resequenced beginning with 1.
 
 See also  alter-table-problems.
 
Info Catalog (mysql.info) alter-database (mysql.info) data-definition (mysql.info) create-database
automatically generated byinfo2html