Purpose
You can use this statement to create a table in the database.
Syntax
CREATE [hint_options] TABLE [IF NOT EXISTS] table_name
(table_definition_list) [table_option_list] [partition_option] [[MERGE_ENGINE = {delete_insert | partial_update}] table_column_group_option] [IGNORE | REPLACE] [AS] select;
CREATE TABLE [IF NOT EXISTS] table_name
LIKE table_name;
table_definition_list:
table_definition [, table_definition ...]
table_definition:
column_definition_list
| [CONSTRAINT [constraint_name]] PRIMARY KEY index_desc
| [CONSTRAINT [constraint_name]] UNIQUE {INDEX | KEY}
[index_name] index_desc
| [CONSTRAINT [constraint_name]] FOREIGN KEY
[index_name] index_desc
REFERENCES reference_definition
[match_action][opt_reference_option_list]
| [FULLTEXT] {INDEX | KEY} [index_name] [index_type] (key_part,...) [WITH PARSER tokenizer_option] [PARSER_PROPERTIES[=](parser_properties_list)]
[index_option_list] [index_column_group_option]
| index_json_clause
| [CONSTRAINT [constraint_name]] CHECK(expression) constranit_state
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)]
| column_name data_type
[GENERATED ALWAYS] AS (expr) [VIRTUAL | STORED]
[opt_generated_column_attribute]
skip_index_option_list:
skip_index_option [,skip_index_option ...]
skip_index_option:
MIN_MAX
| SUM
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}
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
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
table_option_list:
table_option [ table_option ...]
table_option:
[DEFAULT] {CHARSET | CHARACTER SET} [=] charset_name
| [DEFAULT] COLLATE [=] collation_name
| table_tablegroup
| block_size
| lob_inrow_threshold [=] num
| compression
| AUTO_INCREMENT [=] INT_VALUE
| COMMENT string_value
| ROW_FORMAT [=] REDUNDANT|COMPACT|DYNAMIC|COMPRESSED|DEFAULT
| PCTFREE [=] num
| parallel_clause
| DUPLICATE_SCOPE [=] 'none|cluster'
| TABLE_MODE [=] 'table_mode_value'
| auto_increment_cache_size [=] INT_VALUE
| READ {ONLY | WRITE}
| ORGANIZATION [=] {INDEX | HEAP}
| 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}
| TIME_UNIT = {'hour' | 'day' | 'week' | 'month' | 'year'}
| PRECREATE_TIME = {'-1' | '0' | 'n {hour | day | week | month | year}'}
| EXPIRE_TIME = {'-1' | '0' | 'n {hour | day | week | month | year}'}
| TIME_ZONE = {'default' | 'time_zone'}
| BIGINT_PRECISION = {'none' | 'us' | 'ms' | 's'}
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
| PARTITION BY RANGE [COLUMNS]([column_name_list]) [SIZE('size_value')] (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)
| 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
table_column_group_option/index_column_group_option:
WITH COLUMN GROUP(all columns)
| WITH COLUMN GROUP(each column)
| WITH COLUMN GROUP(all columns, each column)
index_json_clause:
[UNIQUE] INDEX idx_json_name((CAST(json_column_name->'$.json_field_name' AS UNSIGNED ARRAY)))
| INDEX idx_json_name(column_name, [column_name, ...] (CAST(json_column_name->'$.json_field_name' AS CHAR(n) ARRAY)))
Parameters
| Parameter | Description | |
|---|---|---|
| hint_options | Optional. Specifies hint options. You can manually specify direct load hints, including APPEND, DIRECT, and NO_DIRECT. The hint format is /*+ [APPEND | DIRECT(need_sort,max_error,load_type)] parallel(N) |NO_DIRECT */. For more information about direct load data by using the CREATE TABLE AS SELECT statement, see Directly load data by using the CREATE TABLE AS SELECT statement in the Full direct load topic. |
|
| IF NOT EXISTS | If you specify IF NOT EXISTS and the table to be created already exists, the system does not report an error and does not create the table again. If you do not specify this parameter and the table to be created already exists, the system reports an error. |
|
| IGNORE | REPLACE | Optional. It is used in the CREATE TABLE ... SELECT statement to specify how to handle rows with duplicate unique key values. If you do not specify IGNORE or REPLACE, the system returns an error for rows with duplicate unique key values.
|
|
| PRIMARY KEY | The primary key of the created table. If this parameter is not specified, a hidden primary key is used. OceanBase Database allows you to modify the primary key of a table or use the ALTER TABLE statement to add a primary key to a table. For more information, see ALTER TABLE. |
|
| FOREIGN KEY | The foreign key of the created table. If you do not specify the name of the foreign key, it will be named in the format of table name + OBFK + time when the foreign key was created. For example, the foreign key created for Table t1 at 00:00:00 on August 1, 2021 is named as t1_OBFK_1627747200000000. A foreign key enables one table (child table) to reference data from another table (parent table). When an UPDATE or a DELETE operation affects a key value in the parent table that has matching rows in the child table, the result depends on the referential action specified in the ON UPDATE or ON DELETE clause. Valid referential actions:
SET DEFAULT action is also supported. |
|
| FULLTEXT | Optional. Specifies to create a full-text index. For more information about how to create a full-text index, see the Create a full-text index section in Create an index.
NoticeThe current version supports only local full-text indexes. |
|
| WITH PARSER tokenizer_option | Optional. Specifies the tokenizer for the full-text index. For more information, see tokenizer_option below. | |
| PARSER_PROPERTIES[=](parser_properties_list) | Optional. The attributes of the parser. For more information, see parser_properties.
NoteFor OceanBase Database V4.3.5, the |
|
| KEY | INDEX | The key or index of the created table. If you do not specify the name of the index, the name of the first column referenced by the index is used as the index name. If the index name is duplicate with an existing one, the index will be named in the format of underscore (_) + sequence number. For example, if the name of the index created based on column c1 conflicts with an existing index name, the index will be named as c1_2. You can execute the SHOW INDEX statement to query the indexes of a table. |
|
| key_part | Creates a normal or function-based index. | |
| index_col_name | The column name of the index. You can add ASC (ascending order) to the end of each column name. DESC (descending order) is not supported. By default, the columns are sorted in ascending order. Index-based sorting method: Data is first sorted by the values in the first column of index_col_name and by the values in the next column for the records with the same values in the first column. |
|
| expr | A valid function-based index expression. A Boolean expression, such as c1=c1, is allowed.
NoticeYou cannot create function-based indexes on generated columns in the current version of OceanBase Database. |
|
| ROW_FORMAT | The row format. Valid values:
|
|
| [GENERATED ALWAYS] AS (expr) [VIRTUAL | STORED] | Creates a generated column. expr specifies the expression used to evaluate the column value. Valid values:
|
|
| BLOCK_SIZE | The microblock size for the table. | |
| lob_inrow_threshold | Specifies the LOB field INROW threshold. If the data size of a LOB field exceeds this threshold, the excess data will be stored in the LOB Meta table as OUTROW. The default value is determined by the variable ob_default_lob_inrow_threshold. |
|
| COMPRESSION | The compression algorithm for the table. Valid values:
|
|
| CHARSET | CHARACTER SET | The default character set for columns in the table. For more information, see Character sets. | |
| COLLATE | The default collation for columns in the table. For more information, see Collations. | |
| table_tablegroup | The table group to which the table belongs. | |
| AUTO_INCREMENT | The start value of the auto-increment column in the table. OceanBase Database allows you to use auto-increment columns as the partitioning key. | |
| COMMENT | The comment. The comment is case-insensitive. | |
| PCTFREE | The percentage of space reserved for macroblocks. | |
| parallel_clause | The DOP at the table level. Valid values:
|
|
| DUPLICATE_SCOPE | The replicated table attribute. Valid values:
|
|
| CHECK | Specifies to restrict the range of values in the column.
SHOW CREATE TABLE statement.information_schema.TABLE_CONSTRAINTS view.information_schema.CHECK_CONSTRAINTS view. |
|
| constraint_name | The name of the constraint, which contains at most 64 characters.
|
|
| expression | The expression of the constraint.
|
|
| MERGE_ENGINE = {delete_insert | partial_update} | Optional. Specifies the table update model. The values are:
Note
|
| table_column_group_option/index_column_group_option | The columnstore options for the table or index. The following options are supported:
|
|
| SKIP_INDEX | The skip index attribute of the column. Valid values:
Notice
|
|
| index_json_clause | Specifies to create a multi-valued index. For more information about multi-valued indexes, see the Create a multi-valued index section in Create an index.
NoticeThe multi-valued index feature is still under experiment. We recommend that you do not use it in a production environment, to avoid impact on system stability. |
|
| json_column_name | The name of a JSON column in the table. | |
| idx_json_name | The name of the multi-valued index to be created. | |
| json_field_name | The name of the field to be indexed in a JSON column. | |
| TABLE_MODE | Optional. The threshold for triggering a major compaction, and the major compaction strategy. This parameter defines the major compaction behavior after a minor compaction. For more information, see table_mode_value. | |
| auto_increment_cache_size | Optional. The number of cached auto-increment values. The default value is 0, which means not to specify the cache size of the auto-increment column. In this case, the value of the tenant-level parameter auto_increment_cache_size is used. |
|
| READ {ONLY | WRITE} | Specifies the read and write privileges for the table. Details are as follows:
|
|
| ORGANIZATION [=] {INDEX | HEAP} | Specifies the storage order of data rows in the table, that is, the table organization mode. The values are as follows:
ORGANIZATION option is not specified, its value defaults to the value of the configuration item default_table_organization.
NoteFor OceanBase Database V4.3.5, the |
|
| enable_macro_block_bloom_filter [=] {True | False} | Specifies whether to persist the macro block-level bloom filter. The values are as follows:
NoteFor OceanBase Database V4.3.5, the |
|
| DYNAMIC_PARTITION_POLICY [=] (dynamic_partition_policy_list) | Specifies the dynamic partition management properties of the table, enabling automatic creation and deletion of partitions. dynamic_partition_policy_list is a list of configurable parameters for dynamic partition policies, separated by commas. For detailed information, refer to dynamic_partition_policy_option below.
NoteFor OceanBase Database V4.3.5, specifying dynamic partition management properties for tables is supported starting from V4.3.5 BP2. |
|
| PARTITION BY RANGE [COLUMNS]([column_name_list]) [SIZE('size_value')] | Specifies the creation of an automatic partition table. For more information, see Automatic partition splitting under the syntax for automatic partitioning when creating tables. | |
| SEMISTRUCT_ENCODING_TYPE | Optional parameter used to specify the type of semi-structured encoding. The details are as follows:
|
table_mode_value
Note
Among the listed table modes, except the NORMAL mode, all other modes represent QUEUING tables. QUEUING tables are the most basic type of tables. Except the NORMAL mode, other table modes indicate more proactive major compaction strategies.
NORMAL: In this mode, the probability of triggering a major compaction after a minor compaction is extremely low. This is the default value.QUEUING: In this mode, the probability of triggering a major compaction after a minor compaction is low.MODERATE: In this mode, the probability of triggering a major compaction after a minor compaction is moderate.SUPER: In this mode, the probability of triggering a major compaction after a minor compaction is high.EXTREME: In this mode, the probability of triggering a major compaction after a minor compaction is very high.
For more information about major compactions, see Adaptive major compactions.
tokenizer_option
SPACE: the default value. Specifies to tokenize the text by space. The following attributes can be specified:Attribute Value range min_token_size [1, 16] max_token_size [10, 84] NGRAM: specifies to tokenize the text based on N-Gram (Chinese). The following attribute can be specified:Attribute Value range ngram_token_size [1, 10] NGRAM2: specifies to split text into continuous characters within the range ofmin_ngram_sizetomax_ngram_size. The following attributes can be specified:Attribute Value Range min_ngram_size [1, 16] max_ngram_size [1, 16] Note
For OceanBase Database V4.3.5, the
NGRAM2tokenizer is supported starting from V4.3.5 BP2.BENG: specifies to tokenize the text based on Beng (basic English). The following attributes can be specified:Attribute Value range min_token_size [1, 16] max_token_size [10, 84] IK: specifies to tokenize the text based on IK (Chinese). Currently, only theutf-8character set is supported. The following attribute can be specified:Attribute Value range ik_mode smartmax_word
Note
For OceanBase Database V4.3.5, the
IKtokenizer is supported starting from V4.3.5 BP1.
parser_properties
min_token_size: the minimum token size. The default value is 3. The value range is 1 to 16.max_token_size: the maximum token size. The default value is 84. The value range is 10 to 84.ngram_token_size: the token size for theNGRAMtokenizer. The value range is 1 to 10. This attribute only applies to theNGRAMtokenizer.ik_mode: the parsing mode for theIKtokenizer. Valid values include:smart: the default value. Dictionary-based parsing is performed to improve the accuracy of parsing, with priority given to dictionary-based token boundaries. This may help reduce unnecessary expansion.max_word: the dictionary-based parsing is performed to identify the words defined in the dictionary. However, maximized expansion is not affected. The text will be split into more words in accordance with themax_wordmode even if they are defined in the dictionary.- min_ngram_size: specifies the minimum token length. The value range is [1, 16].
- max_ngram_size: specifies the maximum token length. The value range is [1, 16]. Here is an example:
CREATE TABLE tbl1 (col1 VARCHAR(200), col2 TEXT,
FULLTEXT INDEX fidx(col2) WITH PARSER ik PARSER_PROPERTIES=(ik_mode='max_word'));
dynamic_partition_policy_option
ENABLE = {true | false}: Optional. Indicates whether to enable dynamic partition management. This option can be modified. The values are as follows:true: Default value. Enables dynamic partition management.false: Disables dynamic partition management.
TIME_UNIT = {'hour' | 'day' | 'week' | 'month' | 'year'}: Required. Specifies the time unit for partitions, that is, the interval for automatically creating partition boundaries. This option cannot be modified. The values are as follows:hour: Partitioned by hourday: Partitioned by dayweek: Partitioned by weekmonth: Partitioned by monthyear: Partitioned by year
PRECREATE_TIME = {'-1' | '0' | 'n {hour | day | week | month | year}'}: Optional. Specifies the pre-creation time. Each time dynamic partition management is scheduled, partitions will be pre-created so that the maximum partition upper bound > now() + precreate_time. This option can be modified. The values are as follows:-1: Default value. No partitions are pre-created.0: Only the current partition is pre-created.n {hour | day | week | month | year}: Pre-create partitions for the specified time span. For example,3 hourmeans pre-create partitions for the next 3 hours.
Note
- When multiple partitions need to be pre-created, the interval between partition boundaries is determined by
TIME_UNIT. - The first pre-created partition boundary is the current maximum partition boundary rounded up to the next
TIME_UNIT.
EXPIRE_TIME = {'-1' | '0' | 'n {hour | day | week | month | year}'}: Optional. Specifies the partition expiration time. Each time dynamic partition management is scheduled, all expired partitions with partition upper bound < now() - expire_time will be deleted. This option can be modified. The values are as follows:-1: Default value. Partitions never expire.0: All partitions before the current partition expire.n {hour | day | week | month | year}: Partition expiration time. For example,1 daymeans partitions expire after 1 day.
TIME_ZONE = {'default' | 'time_zone'}: Optional. Specifies the time zone used when comparing the current time and the partition key of time types (date,datetime,year). This option cannot be modified. The values are as follows:default: Default value. No additional time zone is set, and the tenant time zone is used. For types other than those listed above, thetime_zonefield must be set todefault.time_zone: Custom time zone offset. For example,+8:00and other time zone offsets.
BIGINT_PRECISION = {'none' | 'us' | 'ms' | 's'}: Optional. Specifies the timestamp precision of abiginttype partition key. This option cannot be modified. The values are as follows:none: Default value. No precision (partition key is not of typebigint)us: Microsecond precisionms: Millisecond precisions: Second precision
For more information about creating dynamic partitioned tables, see Create a dynamic partitioned table.
Here is an example:
CREATE TABLE tbl2 (col1 INT, col2 DATETIME)
DYNAMIC_PARTITION_POLICY(
ENABLE = true,
TIME_UNIT = 'hour',
PRECREATE_TIME = '3 hour',
EXPIRE_TIME = '1 day',
TIME_ZONE = '+8:00',
BIGINT_PRECISION = 'none')
PARTITION BY RANGE COLUMNS (col2)(
PARTITION P0 VALUES LESS THAN ('2024-11-11 13:30:00')
)
Examples
Create a database table.
obclient> CREATE TABLE tbl1 (c1 INT PRIMARY KEY, c2 VARCHAR(50)); Query OK, 0 rows affectedCreate an indexed table.
obclient> CREATE TABLE tbl2 (c1 INT PRIMARY KEY, c2 INT, c3 INT, INDEX i1 (c2)); Query OK, 0 rows affectedCreate a table named
tbl3with a function-based index.obclient> CREATE TABLE tbl3 (c1 INT, c2 INT, INDEX i1 ((c1+1)), UNIQUE KEY ((c1+c2))); Query OK, 0 rows affected obclient> SHOW CREATE TABLE tbl3; +-------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | Table | Create Table | +-------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | tbl3 | CREATE TABLE `tbl3` ( `c1` int(11) DEFAULT NULL, `c2` int(11) DEFAULT NULL, UNIQUE KEY `functional_index` ((`c1` + `c2`)) BLOCK_SIZE 16384 LOCAL, KEY `i1` ((`c1` + 1)) BLOCK_SIZE 16384 LOCAL ) DEFAULT CHARSET = utf8mb4 ROW_FORMAT = DYNAMIC COMPRESSION = 'zstd_1.3.8' REPLICA_NUM = 2 BLOCK_SIZE = 16384 USE_BLOOM_FILTER = FALSE TABLET_SIZE = 134217728 PCTFREE = 0 | +-------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+Create a HASH-partitioned table with eight partitions.
obclient> CREATE TABLE tbl4 (c1 INT PRIMARY KEY, c2 INT) PARTITION BY HASH(c1) PARTITIONS 8; Query OK, 0 rows affectedCreate a RANGE-KEY-subpartitioned table.
obclient> CREATE TABLE tbl5 (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)); Query OK, 0 rows affectedCreate a table that uses
gbkfor one column andutf8for the other column.obclient> CREATE TABLE tbl6 (c1 VARCHAR(10), c2 VARCHAR(10) CHARSET GBK COLLATE gbk_bin) DEFAULT CHARSET utf8 COLLATE utf8mb4_general_ci; Query OK, 0 rows affectedEnable encoding and
zstdcompression for the table and reserve 5% of space for macroblocks.obclient> CREATE TABLE tbl7 (c1 INT, c2 INT, c3 VARCHAR(64)) COMPRESSION 'zstd_1.0' ROW_FORMAT DYNAMIC PCTFREE 5; Query OK, 0 rows affectedCreate a table named
tbl8and set the DOP to3.obclient> CREATE TABLE tbl8(c1 INT PRIMARY KEY, c2 INT) PARALLEL 3; Query OK, 0 rows affectedUse the auto-increment column as the partitioning key.
obclient> CREATE TABLE tbl9(inv_id BIGINT NOT NULL AUTO_INCREMENT,c1 BIGINT, PRIMARY KEY (inv_id) ) PARTITION BY HASH(inv_id) PARTITIONS 8; Query OK, 0 rows affectedSpecify a foreign key for the
ref_t2table. Specify to execute theSET NULLaction when anUPDATEoperation affects a key value in the parent table that has matching rows in the child table.obclient> CREATE TABLE ref_t1(c1 INT PRIMARY KEY, C2 INT); Query OK, 0 rows affected obclient> CREATE TABLE ref_t2(c1 INT PRIMARY KEY, C2 INT,FOREIGN KEY(c2) REFERENCES ref_t1(c1) ON UPDATE SET NULL); Query OK, 0 rows affectedCreate a table named
tbl10with theCHECKconstraint and view the constraint information.obclient> CREATE TABLE tbl10 (col1 INT, col2 INT, col3 INT, CONSTRAINT equal_check1 CHECK(col1 = col3 * 2)); Query OK, 0 rows affected obclient> SHOW CREATE TABLE tbl10; +-------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | Table | Create Table | +-------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | tbl10 | CREATE TABLE `tbl10` ( `col1` int(11) DEFAULT NULL, `col2` int(11) DEFAULT NULL, `col3` int(11) DEFAULT NULL, CONSTRAINT `equal_check1` CHECK ((`col1` = (`col3` * 2))) ) DEFAULT CHARSET = utf8mb4 ROW_FORMAT = DYNAMIC COMPRESSION = 'zstd_1.3.8' REPLICA_NUM = 1 BLOCK_SIZE = 16384 USE_BLOOM_FILTER = FALSE TABLET_SIZE = 134217728 PCTFREE = 0 | +-------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ 1 row in setCreate a table named
tbl11based on thetbl10table and view the table information.obclient> CREATE TABLE tbl11 LIKE tbl10; Query OK, 0 rows affected obclient> SHOW CREATE TABLE tbl11; +-------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | Table | Create Table | +-------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | tbl11 | CREATE TABLE `tbl11` ( `col1` int(11) DEFAULT NULL, `col2` int(11) DEFAULT NULL, `col3` int(11) DEFAULT NULL, CONSTRAINT `tbl11_OBCHECK_1650793233327894` CHECK ((`col1` = (`col3` * 2))) ) DEFAULT CHARSET = utf8mb4 ROW_FORMAT = DYNAMIC COMPRESSION = 'zstd_1.3.8' REPLICA_NUM = 1 BLOCK_SIZE = 16384 USE_BLOOM_FILTER = FALSE TABLET_SIZE = 134217728 PCTFREE = 0 | +-------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ 1 row in setCreate a cluster-level replicated table named
dup_t1.Log in to the
systenant and create a unit.obclient> CREATE RESOURCE UNIT IF NOT EXISTS 2c5g MAX_CPU 2, MEMORY_SIZE '5G'; Query OK, 0 rows affectedCreate a resource pool and set
UNIT_NUMto2.obclient> CREATE RESOURCE POOL tenant_pool UNIT = '2c5g', UNIT_NUM = 2, ZONE_LIST = ('z1', 'z2', 'z3'); Query OK, 0 rows affectedCreate a user tenant named
obmysqland specify the locality.obclient> CREATE TENANT obmysql resource_pool_list=('tenant_pool'), LOCALITY = "F@z1, F@z2, R@z3", PRIMARY_ZONE = "z1" SET ob_tcp_invited_nodes='%'; Query OK, 0 rows affectedLog in to the
obmysqluser tenant created in step 3 and create a replicated table.obclient> USE test; Database changed obclient> CREATE TABLE dup_t1(c1 INT) DUPLICATE_SCOPE = 'cluster'; Query OK, 0 rows affected(Optional) View the broadcast log stream. The replicated table is created on this log stream.
obclient> SELECT * FROM oceanbase.DBA_OB_LS WHERE FLAG LIKE "%DUPLICATE%"; +-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+-----------+ | LS_ID | STATUS | PRIMARY_ZONE | UNIT_GROUP_ID | LS_GROUP_ID | CREATE_SCN | DROP_SCN | SYNC_SCN | READABLE_SCN | FLAG | +-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+-----------+ | 1003 | NORMAL | z1;z2 | 0 | 0 | 1683267390195713284 | NULL | 1683337744205408139 | 1683337744205408139 | DUPLICATE | +-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+-----------+ 1 row in set(Optional) View the replica distribution of the replicated table in the
systenant. TheREPLICA_TYPEcolumn indicates the replica type.obclient> SELECT * FROM oceanbase.CDB_OB_TABLE_LOCATIONS WHERE TABLE_NAME = "dup_t1"; +-----------+---------------+------------+----------+------------+----------------+-------------------+------------+---------------+-----------+-------+------+----------------+----------+----------+--------------+-----------------+ | TENANT_ID | DATABASE_NAME | TABLE_NAME | TABLE_ID | TABLE_TYPE | PARTITION_NAME | SUBPARTITION_NAME | INDEX_NAME | DATA_TABLE_ID | TABLET_ID | LS_ID | ZONE | SVR_IP | SVR_PORT | ROLE | REPLICA_TYPE | DUPLICATE_SCOPE | +-----------+---------------+------------+----------+------------+----------------+-------------------+------------+---------------+-----------+-------+------+----------------+----------+----------+--------------+-----------------+ | 1002 | test | dup_t1 | 500002 | USER TABLE | NULL | NULL | NULL | NULL | 200001 | 1003 | z1 | 11.xxx.xxx.xxx | 36125 | LEADER | FULL | CLUSTER | | 1002 | test | dup_t1 | 500002 | USER TABLE | NULL | NULL | NULL | NULL | 200001 | 1003 | z1 | 11.xxx.xxx.xxx | 36124 | FOLLOWER | READONLY | CLUSTER | | 1002 | test | dup_t1 | 500002 | USER TABLE | NULL | NULL | NULL | NULL | 200001 | 1003 | z2 | 11.xxx.xxx.xxx | 36127 | FOLLOWER | FULL | CLUSTER | | 1002 | test | dup_t1 | 500002 | USER TABLE | NULL | NULL | NULL | NULL | 200001 | 1003 | z2 | 11.xxx.xxx.xxx | 36126 | FOLLOWER | READONLY | CLUSTER | | 1002 | test | dup_t1 | 500002 | USER TABLE | NULL | NULL | NULL | NULL | 200001 | 1003 | z3 | 11.xxx.xxx.xxx | 36128 | FOLLOWER | READONLY | CLUSTER | | 1002 | test | dup_t1 | 500002 | USER TABLE | NULL | NULL | NULL | NULL | 200001 | 1003 | z3 | 11.xxx.xxx.xxx | 36129 | FOLLOWER | READONLY | CLUSTER | +-----------+---------------+------------+----------+------------+----------------+-------------------+------------+---------------+-----------+-------+------+----------------+----------+----------+--------------+-----------------+ 6 rows in setInsert data into, read data from, and write data to the replicated table. If you connect to the database by using an OceanBase Database Proxy (ODP), the read request may be routed to any OBServer node. If you directly connect to an OBServer node, the read request is executed on the connected OBServer node as long as the local replica is readable.
obclient> INSERT INTO dup_t1 VALUES(1); Query OK, 1 row affected obclient> SELECT * FROM dup_t1; +------+ | c1 | +------+ | 1 | +------+ 1 row in set
Create a columnstore table named
tbl1_cg.CREATE TABLE tbl1_cg (col1 INT PRIMARY KEY, col2 VARCHAR(50)) WITH COLUMN GROUP(each column);Create a table with a columnstore index.
CREATE TABLE tbl2_cg (col1 INT PRIMARY KEY, col2 INT, col3 INT, INDEX i1 (col2) WITH COLUMN GROUP(each column));Create a columnstore table with a columnstore index.
CREATE TABLE tbl3_cg (col1 INT PRIMARY KEY, col2 INT, col3 INT, INDEX i1 (col2) WITH COLUMN GROUP(each column)) WITH COLUMN GROUP(each column);Create a table and specify the skip index attribute for a column.
CREATE TABLE test_skidx( col1 INT SKIP_INDEX(MIN_MAX, SUM), col2 FLOAT SKIP_INDEX(MIN_MAX), col3 VARCHAR(1024) SKIP_INDEX(MIN_MAX), col4 CHAR(10) );Create a table named
tbl1with acol1column of the integer type, and set the DOP to5. Specify that the data of thetbl1table is sourced from the results of querying thetbl2table.CREATE /*+ parallel(5) */ TABLE tbl1 (col1 INT) AS SELECT col1 FROM tbl2;- Create a table
tbwith the persistent macro block-level bloom filter enabled.
CREATE TABLE tb(c1 INT PRIMARY KEY, c2 INT) enable_macro_block_bloom_filter = True;- Create a table