Description
This statement is used to create a table in a database.
Syntax
CREATE [GLOBAL TEMPORARY] TABLE table_name
(table_definition_list) [table_option_list] [partition_option] [on_commit_option]
CREATE [GLOBAL TEMPORARY] TABLE table_name
(table_definition_list) [table_option_list] [partition_option] [AS] select;
table_definition_list:
table_definition [, table_definition ...]
table_definition:
column_definition
| [,
| [CONSTRAINT [constraint_name]] { PRIMARY KEY|UNIQUE } (column_name) //Add a constraint after all columns are created.
| [CONSTRAINT [constraint_name]] FOREIGN KEY (column_name, column_name ...) references_clause constraint_state
| [CONSTRAINT [constraint_name]] CHECK(expression) constraint_state
]
column_definition_list:
column_definition [, column_definition ...]
column_definition:
column_name data_type
[VISIBLE|INVISIBLE] [GENERATED BY DEFAULT AS IDENTITY | GENERATED ALWAYS AS IDENTITY]
{
[DEFAULT expression]
[NULL | NOT NULL]
[CONSTRAINT [constraint_name]] [ PRIMARY KEY|UNIQUE ] //Add a constraint when the column is created.
[CONSTRAINT [constraint_name] CHECK(expression) constraint_state]
[CONSTRAINT [constraint_name] references_clause]
|
[GENERATED ALWAYS] AS (expression) [VIRTUAL]
[NULL | NOT NULL] [UNIQUE KEY] [[PRIMARY] KEY] [UNIQUE LOWER_KEY]
}
references_clause:
REFERENCES table_name [ (column_name, column_name ...) ] [ON DELETE {CASCADE}]
constraint_state:
[RELY | NORELY] [USING INDEX index_option_list] [ENABLE | DISABLE] [VALIDATE | NOVALIDATE]
index_option_list:
index_option [ index_option ...]
index_option:
[GLOBAL | LOCAL]
| block_size
| compression
| STORING(column_name_list)
table_option_list:
table_option [ table_option ...]
table_option:
TABLEGROUP = tablegroup_name
| block_size
| compression
| ENABLE ROW MOVEMENT
| DISABLE ROW MOVEMENT
| physical_attribute
| parallel_clause
| DUPLICATE_SCOPE [=] 'none|cluster'
physical_attribute_list:
physical_attribute [physical_attribute]
physical_attribute:
PCTFREE [=] num
| PCTUSED num
| INITRANS num
| MAXTRANS num
| STORAGE(storage_option [storage_option] ...)
| TABLESPACE tablespace
parallel_clause:
{NOPARALLEL | PARALLEL integer}
compression:
NOCOMPRESS
| COMPRESS { BASIC | FOR OLTP | FOR QUERY [LOW | HIGH] | FOR ARCHIVE [LOW | HIGH]}
storage_option:
INITIAL num [K|M|G|T|P|E]
| NEXT num [K|M|G|T|P|E]
| MINEXTENTS num [K|M|G|T|P|E]
| MAXEXTENTS num [K|M|G|T|P|E]
partition_option:
PARTITION BY HASH(column_name_list)
[subpartition_option] hash_partition_define
| PARTITION BY RANGE (column_name_list)
[subpartition_option] (range_partition_list)
| PARTITION BY LIST (column_name_list)
[subpartition_option] (list_partition_list)
/*Template-based subpartitioning*/
subpartition_option:
SUBPARTITION BY HASH (column_name_list) hash_subpartition_define
| SUBPARTITION BY RANGE (column_name_list) SUBPARTITION TEMPLATE
(range_subpartition_list)
| SUBPARTITION BY LIST (column_name_list) SUBPARTITION TEMPLATE
(list_subpartition_list)
/*Non-template-based subpartitioning*/
subpartition_option:
SUBPARTITION BY HASH (column_name_list)
| SUBPARTITION BY RANGE (column_name_list)
| SUBPARTITION BY LIST (column_name_list)
subpartition_list:
(hash_subpartition_list)
| (range_subpartition_list)
| (list_subpartition_list)
hash_partition_define:
PARTITIONS partition_count [TABLESPACE tablespace] [compression]
| (hash_partition_list)
hash_partition_list:
hash_partition [, hash_partition ...]
hash_partition:
partition [partition_name] [subpartition_list/*Optional. Applies only to non-template-based subpartitioning*/]
hash_subpartition_define:
SUBPARTITIONS subpartition_count
| SUBPARTITION TEMPLATE (hash_subpartition_list)
hash_subpartition_list:
hash_subpartition [, hash_subpartition ...]
hash_subpartition:
subpartition [subpartition_name]
range_partition_list:
range_partition [, range_partition ...]
range_partition:
PARTITION [partition_name]
VALUES LESS THAN {(expression_list) | (MAXVALUE)}
[subpartition_list/*Optional. Applies only to non-template-based subpartitioning*/]
[ID = num] [physical_attribute_list] [compression]
range_subpartition_list:
range_subpartition [, range_subpartition ...]
range_subpartition:
SUBPARTITION subpartition_name
VALUES LESS THAN {(expression_list) | MAXVALUE} [physical_attribute_list]
list_partition_list:
list_partition [, list_partition] ...
list_partition:
PARTITION [partition_name]
VALUES (DEFAULT | expression_list)
[subpartition_list /*Optional. Applies only to non-template-based subpartitioning*/]
[ID num] [physical_attribute_list] [compression]
list_subpartition_list:
list_subpartition [, list_subpartition] ...
list_subpartition:
SUBPARTITION [partition_name] VALUES (DEFAULT | expression_list) [physical_attribute_list]
expression_list:
expression [, expression ...]
column_name_list:
column_name [, column_name ...]
partition_name_list:
partition_name [, partition_name ...]
partition_count | subpartition_count:
INT_VALUE
on_commit_option:
ON COMMIT DELETE ROWS
| ON COMMIT PRESERVE ROWS
Arguments
| Argument | Description |
|---|---|
| GLOBAL TEMPORARY | Specifies to create a global temporary table. |
| DEFAULT expression | Specifies the default value for a column. If expression contains a function that generates values from a sequence, the function must be followed by the DEFAULT keyword.
NoticeYou cannot set a default value for an auto-increment column. |
| BLOCK_SIZE | Specifies the microblock size of a table. |
| COMPRESSION | Specifies the storage format, encoding, and compression method. The following table describes the available options:
|
| tablegroup_name | Specifies the table group to which a table belongs. |
| VISIBLE | Specifies that a column is visible. This is the default column status. |
| INVISIBLE | Specifies that a column is invisible. After a column is set to INVISIBLE, it will not be displayed by default in a query. |
| GENERATED BY DEFAULT AS IDENTITY | GENERATED ALWAYS AS IDENTITY | Specifies an auto-increment column. The options are described as follows:
NoticeThe data type of the column must be numeric. |
| physical_attribute | PCTFREE: specifies the percentage of space to be reserved for each macroblock. The STORAGE and TABLESPACE attributes are provided for syntax compatibility during migration and do not take effect. |
| ENABLE ROW MOVEMENT | Specifies whether to allow row movement across partitions for updating partitioning keys. |
| ON COMMIT DELETE ROWS | Specifies to create a transaction-level temporary table. The data in this table is deleted when the transaction is committed. |
| ON COMMIT PRESERVE ROWS | Specifies to create a session-level temporary table. The data in this table is retained when the session is closed. |
| parallel_clause | Specifies the degree of parallelism at the table level:
NoticeIf the degree of parallelism is specified, the priority order is as follows: the degree of parallelism specified by hint > the degree of parallelism specified by |
| DUPLICATE_SCOPE | Specifies the attribute of a replicated table. It can take the following values:
cluster-level replicated tables. |
Examples
Create a table named
tbl1.obclient> CREATE TABLE tbl1 (col1 INT PRIMARY KEY, col2 VARCHAR(50)) ; Query OK, 0 rows affectedCreate a table partitioned by HASH with 8 partitions.
obclient> CREATE TABLE tbl4 (col1 INT PRIMARY KEY, col2 INT) PARTITION BY HASH(col1) PARTITIONS 8; Query OK, 0 rows affectedCreate a table partitioned by RANGE and subpartitioned by HASH.
obclient> CREATE TABLE tbl5 (col1 INT, col2 INT, col3 INT) PARTITION BY RANGE(col1) SUBPARTITION BY HASH(col2) SUBPARTITIONS 5 (PARTITION p0 VALUES LESS THAN(0), PARTITION p1 VALUES LESS THAN(100)); Query OK, 0 rows affectedEnable encoding, use
zstdas the compression algorithm, and set the macroblock reservation space to5%.obclient> CREATE TABLE tbl6 (col1 INT, col2 INT, col3 VARCHAR(64)) COMPRESS FOR ARCHIVE PCTFREE 5; Query OK, 0 rows affectedCreate a transaction-level temporary table.
obclient> CREATE GLOBAL TEMPORARY TABLE tbl7(col1 INT) ON COMMIT DELETE ROWS; Query OK, 0 rows affectedCreate a table with constraints.
obclient> CREATE TABLE tbl8 (col1 INT, col2 INT, col3 INT,CONSTRAINT equal_check1 CHECK(col2 = col3 * 2) ENABLE VALIDATE); Query OK, 0 rows affectedCreate a non-template-based RANGE-RANGE subpartitioned table.
obclient> CREATE TABLE tbl9 (col1 INT, col2 INT, col3 INT) PARTITION BY RANGE(col1) SUBPARTITION BY RANGE(col2) ( PARTITION p0 VALUES LESS THAN(100) ( SUBPARTITION p0_r1 VALUES LESS THAN(2019), SUBPARTITION p0_r2 VALUES LESS THAN(2020), SUBPARTITION p0_r3 VALUES LESS THAN(2021) ), PARTITION p1 VALUES LESS THAN(200) ( SUBPARTITION p1_r1 VALUES LESS THAN(2019), SUBPARTITION p1_r2 VALUES LESS THAN(2020), SUBPARTITION p1_r3 VALUES LESS THAN(2021) ), PARTITION p2 VALUES LESS THAN(300) ( SUBPARTITION p2_r1 VALUES LESS THAN(2019), SUBPARTITION p2_r2 VALUES LESS THAN(2020), SUBPARTITION p2_r3 VALUES LESS THAN(2021) ) ); Query OK, 0 rows affectedCreate a table named
tbl10with a DOP of3.obclient> CREATE TABLE tbl10(col1 INT PRIMARY KEY, col2 INT) PARALLEL 3; Query OK, 0 rows affectedDefine default values for columns by using functions.
obclient> CREATE SEQUENCE SEQ_PERSONIPTVSEQ START WITH 1 MINVALUE 1 MAXVALUE 10 INCREMENT BY 2 NOCYCLE NOORDER CACHE 30; Query OK, 0 rows affected obclient> SELECT LPAD(SEQ_PERSONIPTVSEQ.NEXTVAL,18,TO_CHAR(SYSDATE,'YYYY-MM-DD HH24:MI:SS')) FROM DUAL; +----------------------------------------------------------------------------+ | LPAD(SEQ_PERSONIPTVSEQ.NEXTVAL,18,TO_CHAR(SYSDATE,'YYYY-MM-DDHH24:MI:SS')) | +----------------------------------------------------------------------------+ | 2022-07-05 11:34:1 | +----------------------------------------------------------------------------+ 1 row in set obclient> CREATE TABLE FUNC_DEFAULT_TEST ( OID NUMBER(20,0) DEFAULT LPAD(SEQ_PERSONIPTVSEQ.NEXTVAL,18,TO_CHAR(SYSDATE,'YYYY-MM-DD HH24:MI:SS')) NOT NULL); Query OK, 0 rows affectedCreate a replica-level copy of the
clusternameddup_t1. You can insert data and read and write data from and to the replica-level copy as you would from and to a normal table. For a read request, if the Proxy is used, the read request can be routed to any OBServer node; if direct connection is used, the read request is processed on the OBServer node where the local replica is located.obclient> CREATE TABLE dup_t1(c1 int) DUPLICATE_SCOPE = 'cluster'; Query OK, 0 rows affected obclient> INSERT INTO dup_t1 VALUES(1); Query OK, 1 row affected obclient> SELECT * FROM dup_t1; +------+ | c1 | +------+ | 1 | +------+ 1 row in setCreate a table named
test_tbl1, and set thecol1column to an auto-increment column and the primary key.CREATE TABLE test_tbl1 ( col1 INT GENERATED BY DEFAULT AS IDENTITY, col2 VARCHAR2(50), PRIMARY KEY (col1) );
Limitations on global temporary tables in Oracle-compatible mode
- Temporary tables are used in various business scenarios in Oracle-compatible mode and have basic accuracy and functionality.
- Generally, temporary tables are used for compatibility and to reduce the amount of business modification. If the business scenarios are limited and the performance requirements for temporary tables are not high, you can use them. It is better to convert the business scenarios to use regular tables.
Performance and stability
- The SQL execution efficiency of temporary tables is similar to that of regular tables, without any particular advantages.
- When a transaction ends or a session disconnects, additional work, such as data cleanup, needs to be done for temporary tables, which results in extra overheads.
- The checks and cleans performed on temporary tables upon login may put pressure on the login thread, which can increase the login time. In severe cases, the login may fail.
Create a temporary table
When a temporary table is created, the system automatically modifies the table creation statement:
- It adds the
SYS_SESSION_IDcolumn as the primary key. - It adds the
SYS_SESS_CREATE_TIMEcolumn as a normal column. - It creates a hash-partitioned table that uses
SYS_SESSION_IDas the partitioning key with 16 fixed partitions.
For example:
CREATE GLOBAL TEMPORARY TABLE t1(
c1 INT,
c2 INT,
PRIMARY KEY(c1)
);
The system automatically modifies it into the following statement.
CREATE GLOBAL TEMPORARY TABLE t1(
SYS_SESSION_ID INT,
SYS_SESS_CREATE_TIME INT,
c1 INT,
c2 INT,
PRIMARY KEY(SYS_SESSION_ID, c1)
)
PARTITION BY HASH(SYS_SESSION_ID) PARTITIONS 16;
DML/Query statements in a temporary table
When the INSERT operation is performed, the system automatically inserts the session ID and creation time of the current session into the SYS_SESSION_ID column and the SYS_SESS_CREATE_TIME column by default.
For the UPDATE, DELETE, and SELECT operations, the system automatically adds the filter condition "SYS_SESSION_ID = session ID of the current session" to the SQL statement based on the temporary table. This condition allows the SQL optimizer to perform partition pruning and extract the query range.
Data cleanup in a temporary table
- For temporary tables with the
ON COMMIT DELETE ROWSoption (transaction temporary tables, which is also the default option), when a transaction ends, a new transaction is started and the data in the temporary table is deleted by executing theDELETEstatement. - For temporary tables with the
ON COMMIT PRESERVE ROWSoption (session temporary tables), when a session disconnects, the data in the temporary table is deleted by executing theDELETEstatement. - If session IDs are reused, in OceanBase Database V3.2.4 BP4 and earlier, the system checks the data of the current session ID upon login and performs an additional data cleanup if necessary.
- The login check and cleanup based on session IDs may lead to login failures (the cluster cannot be logged in).
Routing of data in a temporary table
Transaction temporary tables (
ON COMMIT DELETE ROWS) Accesses to a transaction temporary table can only be routed to the node where the transaction is initiated.Session temporary tables (
ON COMMIT PRESERVE ROWS) After a session accesses a temporary table, the OBServer node notifies the Proxy to allow subsequent requests from the Proxy to be sent only to the current session.
Drop a temporary table
You can successfully execute the DROP statement while performing DML operations, and all data in the temporary table will be deleted. This is different from Oracle, where you must wait until all sessions no longer hold resources of the temporary table before you can execute the DROP statement.
Cross-version support
| Feature | Supported in OceanBase Database V3.2.4 BP4 and earlier? | Supported in OceanBase Database V3.2.4 BP5 and V3.2.x later? | Supported in OceanBase Database V4.2.0? |
|---|---|---|---|
| Plan sharing among different sessions | No | No | Yes |
| Login without triggering checks and cleans | No | Yes | Yes |
MERGE INTO statement |
No | No | Yes |
Workarounds for severe issues
Unable to log in
- Stop the business related to temporary tables, delete temporary tables, or perform a major compaction. Generally, the system can recover on its own. If not, perform step 2.
- Restart the server where the login is failed.
Expansion of the PL cache due to plan reusability
For example, a statement defining a procedure p1 contains a temporary table:
CREATE PROCEDUCE p1 () (
INSERT INTO temp_table VALUES (xxx);
SELECT * FROM temp_table WHERE ROWNUM = 1 INTO var1;
);
Different sessions cannot share a plan for accessing the temporary table, so each session needs to compile the procedure p1 to generate a cache. This may lead to stability issues. You can modify the statement as follows to avoid this problem:
EXCUTE IMMEDIATE 'SELECT * FROM temp_table WHERE ROWNUM = 1 INTO var1;'
You can modify the temporary table statement into a dynamic SQL statement to bypass this issue.
Data not cleared after a failure
In the case of a failure, data may be left behind. At present, there is no automatic cleanup method. Generally, this does not affect the use of the temporary table. If a large amount of data is left behind, you can drop the temporary table and recreate it.