MODIFY COLUMN

ALTER TABLE .. MODIFY COLUMN 语句用于修改已有表上的列,包括列的数据类型和属性。若要同时重命名,可改用 CHANGE COLUMN 语句。

从 v5.1.0 版本起,TiDB 开始支持 Reorg 类型变更,包括但不限于:

  • VARCHAR 转换为 BIGINT
  • DECIMAL 精度修改
  • VARCHAR(10)VARCHAR(5) 的长度压缩

语法图

  1. AlterTableStmt
  2. ::= 'ALTER' 'IGNORE'? 'TABLE' TableName ModifyColumnSpec ( ',' ModifyColumnSpec )*
  3. ModifyColumnSpec
  4. ::= 'MODIFY' ColumnKeywordOpt 'IF EXISTS' ColumnName ColumnType ColumnOption* ( 'FIRST' | 'AFTER' ColumnName )?
  5. ColumnType
  6. ::= NumericType
  7. | StringType
  8. | DateAndTimeType
  9. | 'SERIAL'
  10. ColumnOption
  11. ::= 'NOT'? 'NULL'
  12. | 'AUTO_INCREMENT'
  13. | 'PRIMARY'? 'KEY' ( 'CLUSTERED' | 'NONCLUSTERED' )?
  14. | 'UNIQUE' 'KEY'?
  15. | 'DEFAULT' ( NowSymOptionFraction | SignedLiteral | NextValueForSequence )
  16. | 'SERIAL' 'DEFAULT' 'VALUE'
  17. | 'ON' 'UPDATE' NowSymOptionFraction
  18. | 'COMMENT' stringLit
  19. | ( 'CONSTRAINT' Identifier? )? 'CHECK' '(' Expression ')' ( 'NOT'? ( 'ENFORCED' | 'NULL' ) )?
  20. | 'GENERATED' 'ALWAYS' 'AS' '(' Expression ')' ( 'VIRTUAL' | 'STORED' )?
  21. | 'REFERENCES' TableName ( '(' IndexPartSpecificationList ')' )? Match? OnDeleteUpdateOpt
  22. | 'COLLATE' CollationName
  23. | 'COLUMN_FORMAT' ColumnFormat
  24. | 'STORAGE' StorageMedia
  25. | 'AUTO_RANDOM' ( '(' LengthNum ')' )?
  26. ColumnName ::=
  27. Identifier ( '.' Identifier ( '.' Identifier )? )?

示例

Meta-Only Change

  1. CREATE TABLE t1 (id int not null primary key AUTO_INCREMENT, col1 INT);
  1. Query OK, 0 rows affected (0.11 sec)
  1. INSERT INTO t1 (col1) VALUES (1),(2),(3),(4),(5);
  1. Query OK, 5 rows affected (0.02 sec)
  2. Records: 5 Duplicates: 0 Warnings: 0
  1. ALTER TABLE t1 MODIFY col1 BIGINT;
  1. Query OK, 0 rows affected (0.09 sec)
  1. SHOW CREATE TABLE t1\G;
  1. *************************** 1. row ***************************
  2. Table: t1
  3. Create Table: CREATE TABLE `t1` (
  4. `id` int(11) NOT NULL AUTO_INCREMENT,
  5. `col1` bigint(20) DEFAULT NULL,
  6. PRIMARY KEY (`id`)
  7. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin AUTO_INCREMENT=30001
  8. 1 row in set (0.00 sec)

Reorg-Data Change

  1. CREATE TABLE t1 (id int not null primary key AUTO_INCREMENT, col1 INT);
  1. Query OK, 0 rows affected (0.11 sec)
  1. INSERT INTO t1 (col1) VALUES (12345),(67890);
  1. Query OK, 2 rows affected (0.00 sec)
  2. Records: 2 Duplicates: 0 Warnings: 0
  1. ALTER TABLE t1 MODIFY col1 VARCHAR(5);
  1. Query OK, 0 rows affected (2.52 sec)
  1. SHOW CREATE TABLE t1\G;
  1. *************************** 1. row ***************************
  2. Table: t1
  3. CREATE TABLE `t1` (
  4. `id` int(11) NOT NULL AUTO_INCREMENT,
  5. `col1` varchar(5) DEFAULT NULL,
  6. PRIMARY KEY (`id`) /*T![clustered_index] CLUSTERED */
  7. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin AUTO_INCREMENT=30001
  8. 1 row in set (0.00 sec)

注意:

  • 当所变更的类型与已经存在的数据行产生冲突时,TiDB 会进行报错处理。在上述例子中,TiDB 将进行如下报错:

    1. alter table t1 modify column col1 varchar(4);
    2. ERROR 1406 (22001): Data Too Long, field len 4, data len 5
  • 由于和 Async Commit 功能兼容,DDL 在开始进入到 Reorg Data 前会有一定时间(约 2.5s)的等待处理:

    1. Query OK, 0 rows affected (2.52 sec)

MySQL 兼容性

  • 不支持使用单个 ALTER TABLE 语句修改多个列,例如:

    1. ALTER TABLE t1 MODIFY col1 BIGINT, MODIFY id BIGINT NOT NULL;
    2. ERROR 1105 (HY000): Unsupported multi schema change
  • 不支持修改主键列上需要 Reorg-Data 的类型,但是支持修改 Meta-Only 的类型。例如:

    1. CREATE TABLE t (a int primary key);
    2. ALTER TABLE t MODIFY COLUMN a VARCHAR(10);
    3. ERROR 8200 (HY000): Unsupported modify column: column has primary key flag
    1. CREATE TABLE t (a int primary key);
    2. ALTER TABLE t MODIFY COLUMN a INT(10) UNSIGNED;
    3. ERROR 8200 (HY000): Unsupported modify column: column has primary key flag
    1. CREATE TABLE t (a int primary key);
    2. ALTER TABLE t MODIFY COLUMN a bigint;
    3. Query OK, 0 rows affected (0.01 sec)
  • 不支持修改生成列的类型。例如:

    1. CREATE TABLE t (a INT, b INT as (a+1));
    2. ALTER TABLE t MODIFY COLUMN b VARCHAR(10);
    3. ERROR 8200 (HY000): Unsupported modify column: column is generated
  • 不支持修改分区表上的列类型。例如:

    1. CREATE TABLE t (c1 INT, c2 INT, c3 INT) partition by range columns(c1) ( partition p0 values less than (10), partition p1 values less than (maxvalue));
    2. ALTER TABLE t MODIFY COLUMN c1 DATETIME;
    3. ERROR 8200 (HY000): Unsupported modify column: table is partition table
  • 不支持部分数据类型(例如,部分时间类型、Bit、Set、Enum、JSON 等)的变更,因为 TiDB cast 函数与 MySQL 的行为有一些兼容性问题。例如:

    1. CREATE TABLE t (a DECIMAL(13, 7));
    2. ALTER TABLE t MODIFY COLUMN a DATETIME;
    3. ERROR 8200 (HY000): Unsupported modify column: change from original type decimal(13,7) to datetime is currently unsupported yet

另请参阅