DROP COLUMN

DROP COLUMN 语句用于从指定的表中删除列。在 TiDB 中,COLUMN 为在线操作,不会阻塞表中的数据读写。

语法图

  1. AlterTableStmt ::=
  2. 'ALTER' IgnoreOptional 'TABLE' TableName ( AlterTableSpecListOpt AlterTablePartitionOpt | 'ANALYZE' 'PARTITION' PartitionNameList ( 'INDEX' IndexNameList )? AnalyzeOptionListOpt )
  3. AlterTableSpec ::=
  4. TableOptionList
  5. | 'SET' 'TIFLASH' 'REPLICA' LengthNum LocationLabelList
  6. | 'CONVERT' 'TO' CharsetKw ( CharsetName | 'DEFAULT' ) OptCollate
  7. | 'ADD' ( ColumnKeywordOpt IfNotExists ( ColumnDef ColumnPosition | '(' TableElementList ')' ) | Constraint | 'PARTITION' IfNotExists NoWriteToBinLogAliasOpt ( PartitionDefinitionListOpt | 'PARTITIONS' NUM ) )
  8. | ( ( 'CHECK' | 'TRUNCATE' ) 'PARTITION' | ( 'OPTIMIZE' | 'REPAIR' | 'REBUILD' ) 'PARTITION' NoWriteToBinLogAliasOpt ) AllOrPartitionNameList
  9. | 'COALESCE' 'PARTITION' NoWriteToBinLogAliasOpt NUM
  10. | 'DROP' ( ColumnKeywordOpt IfExists ColumnName RestrictOrCascadeOpt | 'PRIMARY' 'KEY' | 'PARTITION' IfExists PartitionNameList | ( KeyOrIndex IfExists | 'CHECK' ) Identifier | 'FOREIGN' 'KEY' IfExists Symbol )
  11. | 'EXCHANGE' 'PARTITION' Identifier 'WITH' 'TABLE' TableName WithValidationOpt
  12. | ( 'IMPORT' | 'DISCARD' ) ( 'PARTITION' AllOrPartitionNameList )? 'TABLESPACE'
  13. | 'REORGANIZE' 'PARTITION' NoWriteToBinLogAliasOpt ReorganizePartitionRuleOpt
  14. | 'ORDER' 'BY' AlterOrderItem ( ',' AlterOrderItem )*
  15. | ( 'DISABLE' | 'ENABLE' ) 'KEYS'
  16. | ( 'MODIFY' ColumnKeywordOpt IfExists | 'CHANGE' ColumnKeywordOpt IfExists ColumnName ) ColumnDef ColumnPosition
  17. | 'ALTER' ( ColumnKeywordOpt ColumnName ( 'SET' 'DEFAULT' ( SignedLiteral | '(' Expression ')' ) | 'DROP' 'DEFAULT' ) | 'CHECK' Identifier EnforcedOrNot | 'INDEX' Identifier IndexInvisible )
  18. | 'RENAME' ( ( 'COLUMN' | KeyOrIndex ) Identifier 'TO' Identifier | ( 'TO' | '='? | 'AS' ) TableName )
  19. | LockClause
  20. | AlgorithmClause
  21. | 'FORCE'
  22. | ( 'WITH' | 'WITHOUT' ) 'VALIDATION'
  23. | 'SECONDARY_LOAD'
  24. | 'SECONDARY_UNLOAD'
  25. ColumnName ::=
  26. Identifier ( '.' Identifier ( '.' Identifier )? )?

示例

  1. CREATE TABLE t1 (id INT NOT NULL PRIMARY KEY AUTO_INCREMENT, col1 INT NOT NULL, col2 INT NOT NULL);
  1. Query OK, 0 rows affected (0.12 sec)
  1. INSERT INTO t1 (col1,col2) VALUES (1,1),(2,2),(3,3),(4,4),(5,5);
  1. Query OK, 5 rows affected (0.02 sec)
  2. Records: 5 Duplicates: 0 Warnings: 0
  1. SELECT * FROM t1;
  1. +----+------+------+
  2. | id | col1 | col2 |
  3. +----+------+------+
  4. | 1 | 1 | 1 |
  5. | 2 | 2 | 2 |
  6. | 3 | 3 | 3 |
  7. | 4 | 4 | 4 |
  8. | 5 | 5 | 5 |
  9. +----+------+------+
  10. 5 rows in set (0.01 sec)
  1. ALTER TABLE t1 DROP COLUMN col1, DROP COLUMN col2;
  1. ERROR 1105 (HY000): can't run multi schema change
  1. SELECT * FROM t1;
  1. +----+------+------+
  2. | id | col1 | col2 |
  3. +----+------+------+
  4. | 1 | 1 | 1 |
  5. | 2 | 2 | 2 |
  6. | 3 | 3 | 3 |
  7. | 4 | 4 | 4 |
  8. | 5 | 5 | 5 |
  9. +----+------+------+
  10. 5 rows in set (0.00 sec)
  1. ALTER TABLE t1 DROP COLUMN col1;
  1. Query OK, 0 rows affected (0.27 sec)
  1. SELECT * FROM t1;
  1. +----+------+
  2. | id | col2 |
  3. +----+------+
  4. | 1 | 1 |
  5. | 2 | 2 |
  6. | 3 | 3 |
  7. | 4 | 4 |
  8. | 5 | 5 |
  9. +----+------+
  10. 5 rows in set (0.00 sec)

MySQL 兼容性

  • 目前不支持在一条语句中同时删除多个列。
  • 目前不支持删除主键列或组合索引相关列。

另请参阅