MODIFY COLUMN

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

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

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

语法图

AlterTableStmt
ALTERIGNORETABLETableNameModifyColumnSpec,
ModifyColumnSpec
MODIFYColumnKeywordOptIF EXISTSColumnNameColumnTypeColumnOptionFIRSTAFTERColumnName
ColumnType
NumericTypeStringTypeDateAndTimeTypeSERIAL
ColumnOption
NOTNULLAUTO_INCREMENTPRIMARYKEYCLUSTEREDNONCLUSTEREDUNIQUEKEYDEFAULTNowSymOptionFractionSignedLiteralNextValueForSequenceSERIALDEFAULTVALUEONUPDATENowSymOptionFractionCOMMENTstringLitCONSTRAINTIdentifierCHECK(Expression)NOTENFORCEDNULLGENERATEDALWAYSAS(Expression)VIRTUALSTOREDREFERENCESTableName(IndexPartSpecificationList)MatchOnDeleteUpdateOptCOLLATECollationNameCOLUMN_FORMATColumnFormatSTORAGEStorageMediaAUTO_RANDOM(LengthNum)
ColumnName
Identifier.Identifier.Identifier

示例

Meta-Only Change

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

Reorg-Data Change

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

注意:

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

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

    Query OK, 0 rows affected (2.52 sec)

MySQL 兼容性

  • 不支持修改主键列上需要 Reorg-Data 的类型,但是支持修改 Meta-Only 的类型。例如:

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

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

    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)); ALTER TABLE t MODIFY COLUMN c1 DATETIME; ERROR 8200 (HY000): Unsupported modify column: table is partition table
  • 不支持部分数据类型(例如,部分时间类型、Bit、Set、Enum、JSON 等)的变更,因为 TiDB cast 函数与 MySQL 的行为有一些兼容性问题。例如:

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

另请参阅