ALTER TABLE
描述
该语句用来修改已存在的表的结构,例如修改表及表属性、新增列、修改列及属性、删除列等。
语法
alter_table_stmt:
ALTER TABLE [TEMPORARY] table_name alter_table_action_list;
alter_table_action_list:
alter_table_action [, alter_table_action ...]
alter_table_action:
ADD [COLUMN] column_definition
[ opt_position_column ]
| ADD [COLUMN] (column_definition_list)
| ADD [CONSTRAINT [constraint_name]] UNIQUE {INDEX | KEY}
[index_name] index_desc
| ADD [CONSTRAINT [constraint_name]] FOREIGN KEY
[index_name] index_desc
REFERENCES reference_definition
[match_action][opt_reference_option_list]
| ADD PRIMARY KEY (column_name)
| ADD CONSTRAINT [constraint_name] CHECK (expression)[[NOT] ENFORCED]
| ADD PARTITION (range_partition_list)
| ADD {INDEX | KEY} [index_name] [index_type] (key_part,...) [index_option_list][index_column_group_option] [algorithm = algorithm_value] [lock = lock_value]
| ADD FULLTEXT [INDEX | KEY] [index_name](column_name, [column_name ...]) [WITH PARSER tokenizer_option] [PARSER_PROPERTIES[=](parser_properties_list)] [LOCAL]
| ADD COLUMN GROUP([all columns, ]each column) [DELAYED]
| ALTER [COLUMN] column_name {
SET DEFAULT const_value
| DROP DEFAULT
}
| ALTER {CHECK | CONSTRAINT} symbol [NOT] ENFORCED
| ALTER INDEX index_name
[VISIBLE | INVISIBLE]
| CHANGE [COLUMN] column_name column_definition
| DROP [COLUMN] column_name [, DROP COLUMN column_name ...]
| DROP {PARTITION | SUBPARTITION} partition_name_list
| DROP TABLEGROUP
| DROP FOREIGN KEY fk_name
| DROP PRIMARY KEY [, ADD PRIMARY KEY (column)]
| DROP CHECK constraint_name
| DROP COLUMN GROUP([all columns, ]each column)
| MODIFY [COLUMN] column_definition
| RENAME COLUMN old_col_name [TO|AS] new_col_name
| RENAME [TO|AS] table_name
| RENAME {INDEX | KEY} old_index_name [TO|AS] new_index_name
| [SET] table_option_list
| TRUNCATE {PARTITION | SUBPARTITION} partition_name_list
| EXCHANGE PARTITION partition_name WITH TABLE origin_table_name WITHOUT VALIDATION
| REORGANIZE PARTITION partition_name INTO (split_range_partition_list)
| PARTITION BY {RANGE [COLUMNS]([column_name_list]) [SIZE('size_value')] [range_partition_list]
| partition_option}
| MODIFY PARTITION partition_name ADD SUBPARTITION (add_subpartition_option)
| FORCE
column_definition_list:
column_definition [, column_definition ...]
column_definition:
column_name data_type
[DEFAULT const_value] [AUTO_INCREMENT]
[NULL | NOT NULL] [[PRIMARY] KEY] [UNIQUE [KEY]] [COMMENT string_value] [SKIP_INDEX(skip_index_option_list)] [ opt_position_column ]
skip_index_option_list:
skip_index_option [,skip_index_option ...]
skip_index_option:
MIN_MAX
| SUM
opt_position_column:
FIRST | BEFORE | AFTER column_name
index_desc:
(column_desc_list) [index_type] [index_option_list]
match_action:
MATCH {SIMPLE | FULL | PARTIAL}
opt_reference_option_list:
reference_option [,reference_option ...]
reference_option:
ON {DELETE | UPDATE} {RESTRICT | CASCADE | SET NULL | NO ACTION | SET DEFAULT}
column_desc_list:
column_desc [, column_desc ...]
column_desc:
column_name [(length)] [ASC | DESC]
key_part:
{index_col_name [(length)] | (expr)} [ASC | DESC]
index_type:
USING BTREE
index_option_list:
index_option [ index_option ...]
index_option:
[GLOBAL | LOCAL]
| block_size
| compression
| STORING(column_name_list)
| COMMENT string_value
index_column_group_option:
WITH COLUMN GROUP([all columns, ]each column)
algorithm_value:
default
| inplace
| copy
| instant
lock_value:
default
| none
| shared
| exclusive
tokenizer_option:
SPACE
| NGRAM
| BENG
| IK
| NGRAM2
parser_properties_list:
parser_properties, [parser_properties]
parser_properties:
min_token_size = int_value
| max_token_size = int_value
| ngram_token_size = int_value
| ik_mode = 'char_value'
| min_ngram_size = int_value
| max_ngram_size = int_value
table_option_list:
table_option [ table_option ...]
table_option:
| block_size
| lob_inrow_threshold [=] num
| compression
| AUTO_INCREMENT [=] INT_VALUE
| COMMENT string_value
| parallel_clause
| TABLE_MODE [=] 'table_mode_value'
| AUTO_INCREMENT_CACHE_SIZE [=] INT_VALUE
| READ {ONLY | WRITE}
| enable_macro_block_bloom_filter [=] {True | False}
| DYNAMIC_PARTITION_POLICY [=] (dynamic_partition_policy_list)
| SEMISTRUCT_ENCODING_TYPE [=] 'encoding'
parallel_clause:
{NOPARALLEL | PARALLEL integer}
table_mode_value:
NORMAL
| QUEUING
| MODERATE
| SUPER
| EXTREME
dynamic_partition_policy_list:
dynamic_partition_policy_option [, dynamic_partition_policy_option ...]
dynamic_partition_policy_option:
ENABLE = {true | false}
| PRECREATE_TIME = {'-1' | '0' | 'n {hour | day | week | month | year}'}
| EXPIRE_TIME = {'-1' | '0' | 'n {hour | day | week | month | year}'}
partition_option:
PARTITION BY HASH(expression)
[subpartition_option] PARTITIONS partition_count
| PARTITION BY KEY([column_name_list])
[subpartition_option] PARTITIONS partition_count
| PARTITION BY RANGE {(expression) | COLUMNS (column_name_list)}
[subpartition_option] (range_partition_list)
subpartition_option:
SUBPARTITION BY HASH(expression)
SUBPARTITIONS subpartition_count
| SUBPARTITION BY KEY(column_name_list)
SUBPARTITIONS subpartition_count
| SUBPARTITION BY RANGE {(expression) | COLUMNS (column_name_list)}
(range_subpartition_list)
split_range_partition_list:
PARTITION split_partition_name VALUES LESS THAN (value)
[, PARTITION split_partition_name VALUES LESS THAN (value) ...]
, PARTITION split_partition_name VALUES LESS THAN (source_value)
range_partition_list:
range_partition [, range_partition ...]
range_partition:
PARTITION partition_name
VALUES LESS THAN {(expression_list) | MAXVALUE}
range_subpartition_list:
range_subpartition [, range_subpartition ...]
range_subpartition:
SUBPARTITION subpartition_name
VALUES LESS THAN {(expression_list) | MAXVALUE}
expression_list:
expression [, expression ...]
column_name_list:
column_name [, column_name ...]
partition_name_list:
partition_name [, partition_name ...]
partition_count | subpartition_count:
INT_VALUE
add_subpartition_option:
{SUBPARTITION subpartition_name VALUES LESS THAN range_partition_expr
[, SUBPARTITION subpartition_name VALUES LESS THAN range_partition_expr] ...}
| {SUBPARTITION subpartition_name VALUES IN list_partition_expr
[, SUBPARTITION subpartition_name VALUES IN list_partition_expr] ...}
参数说明
| 参数 | 描述 |
|---|---|
| TEMPORARY | 为可选项,表示修改临时表。 |
| ADD [COLUMN] | 增加列,支持增加生成列。 |
| [FIRST | BEFORE | AFTER column_name] | 将新增的列作为表的第一列或在 column_name 列之前/之后。 目前,seekdb 仅支持在 ADD COLUMN 语法中设置列的位置。 |
| CHANGE [COLUMN] | 修改列名和列定义,仅支持增加特定字符数据类型(VARCHAR、VARBINARY、CHAR 等)的长度。 |
| MODIFY [COLUMN] | 修改列属性。 |
| ALTER [COLUMN] {SET DEFAULT const_value | DROP DEFAULT} | 修改列的默认值。 |
| DROP [COLUMN] | 删除列。 不允许删除主键列。 |
| ADD FOREIGN KEY | 增加外键。 如果不指定外键名,则会使用表名 + OBFK + 创建时间命名。(例如,在 2021 年 8 月 1 日 00:00:00 为 t1 表创建的外键名称为 t1_OBFK_1627747200000000)。外键允许跨表交叉引用相关数据,当 UPDATE 或 DELETE 操作影响与子表相匹配行的父表中键值时,其结果取决于 ON UPDATE 和 ON DELETE 子句的引用操作:
SET DEFAULT 操作。 |
| ADD PRIMARY KEY | 增加主键。 可以指定一个或多个列作为主键。如果是多个列,它们将组成复合主键。 |
| ADD {INDEX | KEY} | 用于增加索引。有关添加索引的介绍请参加下文 ADD INDEX KEY |
| ADD FULLTEXT [INDEX | KEY] | 增加全文索引。有关创建全文索引的介绍信息,参见 创建索引 下创建全文索引章节。 |
| WITH PARSER tokenizer_option | 可选项,指定全文索引的分词器。详细介绍可参见下文 tokenizer_option。 |
| PARSER_PROPERTIES[=](parser_properties_list) | 可选项,指定分词器的属性。详细介绍可参见下文 parser_properties。 |
| ALTER INDEX | 修改索引是否可见,当索引状态为 INVISIBLE 时,SQL 优化器将不会选择该索引。 |
| key_part | 创建(函数)索引。 |
| index_col_name | 指定索引的列名,每个列名后都支持 ASC(升序),不支持 DESC(降序)。默认为升序。 建立索引的排序方式为:首先以 index_col_name 中第一个列的值排序;该列值相同的记录,按下一列名的值排序;以此类推。 |
| expr | 表示合法的函数索引表达式,且允许是布尔表达式,例如 c1=c1。注意 seekdb 当前版本禁止创建生成列上的函数索引。 |
| ADD [PARTITION] |