CREATE TABLE ================================= 描述 ----------- 该语句用来在数据库中创建一张新表。 格式 ----------- ```javascript CREATE [TEMPORARY] TABLE [IF NOT EXISTS] table_name (table_definition_list) [table_option_list] [partition_option] [AS] select; CREATE [TEMPORARY] TABLE [IF NOT EXISTS] table_name LIKE table_name; table_definition_list: table_definition [, table_definition ...] table_definition: column_definition | [CONSTRAINT [constraint_name]] PRIMARY KEY index_desc | [CONSTRAINT [constraint_name]] UNIQUE {INDEX | KEY} [index_name] index_desc | {INDEX | KEY} [index_name] index_desc | FULLTEXT [INDEX | KEY] [index_name] fulltext_index_desc 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 index_desc: (column_desc_list) [index_type] [index_option_list] fulltext_index_desc: (column_desc_list) CTXCAT(column_desc_list) [index_option_list] column_desc_list: column_desc [, column_desc ...] column_desc: column_name [(length)] [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 table_option_list: table_option [ table_option ...] table_option: [DEFAULT] {CHARSET | CHARACTER SET} [=] charset_name | [DEFAULT] COLLATE [=] collation_name | primary_zone | replica_num | table_tablegroup | block_size | compression | AUTO_INCREMENT [=] INT_VALUE | comment | DUPLICATE_SCOPE [=] "none|cluster" | LOCALITY [=] "locality description" | ROW_FORMAT [=] REDUNDANT|COMPACT|DYNAMIC|COMPRESSED|DEFAULT | PCTFREE [=] num | parallel_clause parallel_clause: {NOPARALLEL | PARALLEL integer} 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) | PARTITION BY LIST {(expression) | COLUMNS (column_name_list)} [subpartition_option] PARTITIONS partition_count 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) | SUBPARTITION BY LIST(expression) 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 ``` 参数说明 ------------- | **参数** | **描述** | |--------------------------|----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| | DUPLICATE_SCOPE | 用来指定复制表属性,取值如下: * none:表示该表是一个普通表 * zone:表示该表是一个复制表,leader需要将事务复制到本zone的所有F副本及R副本 * region:表示该表是一个复制表,leader需要将事务复制到本region的所有F副本及R副本 * cluster:表示该表是一个复制表,leader需要将事务复掉到cluster的所有F副本及R副本 不指定DUPLICATE_SCOPE的情况下,默认值为none。 | | ROW_FORMAT | 指定表是否开启encoding存储格式 * redundant * compact * dynamic * compressed * default | | BLOCK_SIZE | 指定表的微块大小 | | COMPRESSION | 指定表的压缩算法,取值如下: 1. none:不使用压缩算法 2. lz4_1.0: 使用lz4压缩算法 3. zstd_1.0: 使用zstd压缩算法 4. snappy_1.0: 使用snappy压缩算法 | | CHARSET \| CHARACTER SET | 指定表中列的默认字符集,可使用:utf8, utf8mb4, gbk, utf16, gb18030 | | COLLATE | 指定表中列的默认比较规则,可使用: utf8_bin, utf8_general_ci, utf8_unicode_ci, gbk_bin, gbk_chinese_ci, utf8mb4_general_ci, utf8mb4__general_cs, utf8mb4_bin, utf8mb4_unicode_ci, utf16_general_ci, utf16_bin, utf16_unicode_ci, gb18030_chinese_ci, gb18030_bin | | primary_zone | 指定主Zone(副本Leader所在 Zone)。 | | replica_num | 指定副本数。 | | table_tablegroup | 指定表所属的talegroup。 | | AUTO_INCREMENT | 指定表中自增列的初始值。 | | comment | 注释。 | | LOCALITY | 描述副本在Zone间的分布情况,如:F@z1,F@z2,F@z3,R@z4 表示z1, z2, z3为全功能副本,z4为只读副本。 | | PCTFREE | 指定宏块保留空间百分比。 | | parallel_clause | 指定表级别的并行度: * NOPARALLEL:并行度为1,默认配置 * PARALLEL integer:指定并行度,integer 取值大于等于 1。 | 举例 ----------- * 创建数据库表。 ```javascript CREATE TABLE test (c1 int primary key, c2 VARCHAR(50)) REPLICA_NUM = 3, PRIMARY_ZONE = 'zone1'; ``` * 创建表,并指定垂直分区。其中第一个分区只有列 c3,第二个分区包含列 c1、c2,没有列出的 c4、c5 列为第三个分区。 ```javascript CREATE TABLE t1(c1 int, c2 int, c3 int, c4 int, c5 int) PARTITION BY CLOUMN ( c3, (c1, c2)); ``` * 创建一个复制表。 ```javascript CREATE TABLE item() locality = 'F,R{all_server}@hz1, F,R{all_server}@hz2, F,R{all_server}@hz3' DUPLICATE_SCOPE="cluster" ``` * 创建带索引的表。 ```javascript create table t1 (c1 int primary key, c2 int, c3 int, index i1 (c2)); ``` * 创建 hash 分区,分区数为 8 的表。 ```javascript create table t1 (c1 int primary key, c2 int) partition by hash(c1) partitions 8; ``` * 创建一级分区为 range 分区,二级分区为 key 分区的表。 ```javascript create table t1 (c1 int, c2 int, c3 int) partition by range(c1) subpartition by key(c2, c3) subpartitions 5 (partition p0 values less than(0), partition p1 values less than(100)); ``` * 创建一列为 gbk, 一列为 utf8 的表。 ```javascript create table t1 (c1 varchar(10), c2 varchar(10) charset gbk collate gbk_bin) default charset utf8 collate utf8mb4_general_ci; ``` * 开启 encoding 并使用 zstd 压缩,宏块保留空间为 5%。 ```javascript create table t1 (c1 int, c2 int, c3 varchar(64)) compression 'zstd_1.0' ROW_FORMAT dynamic pctfree 5; ``` * 创建表 t1,并设置并行度为 3。 ```unknow create table t1(c1 int primary key, c2 int) parallel 3; ```