Description
This statement creates 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 {SET NULL | 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/*Only for 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/*Only for 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 /*Only for 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
Parameter description
| Parameter | Description |
|---|---|
| GLOBAL TEMPORARY | Specifies to create a temporary table. |
| DEFAULT expression | Specifies the default value of a column. The expression parameter can contain a function expression that generates values from a sequence.
NoticeAn auto-increment column cannot have a default value. |
| BLOCK_SIZE | Specifies the microblock size of a table. |
| COMPRESSION | Specifies the storage format, encoding, and compression method. The parameter value can be one of the following:
|
| tablegroup_name | Specifies the table group to which a table belongs. |
| FOREIGN KEY | Specifies a foreign key for a created table. If the foreign key name is not specified, it will be named by using the table name, OBFK, and the creation time. (For example, the foreign key created for the t1 table at 00:00:00 on August 1, 2021, will be named t1_OBFK_1627747200000000. ) A foreign key allows cross-reference of related data across tables. The ON DELETE clause specifies the action to be performed when a row in the parent table that contains a matching key value is deleted or updated. The action depends on whether the CASCADE or SET NULL clause is used:
|
| VISIBLE | Specifies that a column is visible. This is the default column status. |
| INVISIBLE | Specifies that a column is invisible. When a column is set to INVISIBLE, it will not be displayed by default in query results. |
| GENERATED BY DEFAULT AS IDENTITY | GENERATED ALWAYS AS IDENTITY | Specifies an auto-increment column. The options are as follows:
NoticeThe data type of the column must be numeric. |
| physical_attribute | PCTFREE: the percentage of space reserved for macroblocks. The STORAGE and TABLESPACE parameters are provided only 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 and delete the data when the transaction is committed. |
| ON COMMIT PRESERVE ROWS | Specifies to create a session-level temporary table and delete the data when the session is closed. |
| parallel_clause | Specifies the degree of parallelism at the table level:
NoticeWhen 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 replicated tables. Valid values are:
cluster: specifies that the table is a replicated table. The leader needs to copy transactions to all full-featured (F) and read-only (R) replicas in the current tenant.
|
Examples
Create a table named
tbl1.obclient> CREATE TABLE tbl1 (col1 INT PRIMARY KEY, col2 VARCHAR(50)) ; Query OK, 0 rows affectedCreate a table with
8partitions.obclient> CREATE TABLE tbl4 (col1 INT PRIMARY KEY, col2 INT) PARTITION BY HASH(col1) PARTITIONS 8; Query OK, 0 rows affectedCreate a table with RANGE partitioning and HASH subpartitioning.
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 the
zstdcompression 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 affectedDefine a foreign key for the
ref_t2table. When aDELETEoperation affects a matching row in a subtable, the value of the primary key in the parent table is set toNULL.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 DELETE SET NULL); Query OK, 0 rows affectedCreate a table with RANGE + RANGE subpartitioning.
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 the
tbl10table with a DOP of3.obclient> CREATE TABLE tbl10(col1 INT PRIMARY KEY, col2 INT) PARALLEL 3; Query OK, 0 rows affectedSet the default value of a column based on a function.
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 replicated table named
dup_t1at the cluster level. You can insert data and read and write data from a replicated table in the same way as from a normal table. For a read request, if you use a Proxy, the request can be routed to any OBServer node; if you directly connect to an OBServer node and the local replica is available, the read request is processed on the OBServer node you are connected to.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. The values in thecol1column of the table will auto-increment and the column is set as 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 compatibility mode
- Temporary tables are used in various business scenarios in Oracle compatibility mode and ensure basic accuracy and functionality.
- Generally, the purpose of using temporary tables is to maintain compatibility and reduce business modifications. 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 normal tables, without any notable advantages.
- When a transaction ends or a session disconnects, additional data cleanup needs to be performed for temporary tables, which causes extra overheads.
- The data check and cleanup performed for temporary tables upon login may put pressure on the login thread, thus lengthening the login time. In severe cases, the login may fail.
Create a temporary table
By default, the database system automatically modifies the table creation statement as follows:
- Adds the
SYS_SESSION_IDcolumn as the primary key. - Adds the
SYS_SESS_CREATE_TIMEcolumn as a normal column. - Creates a hash-partitioned table with 16 partitions, using the
SYS_SESSION_IDcolumn as the partitioning key.
For example:
CREATE GLOBAL TEMPORARY TABLE t1(
c1 INT,
c2 INT,
PRIMARY KEY(c1)
);
is automatically modified 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 you execute the INSERT statement, the database system automatically inserts the session ID of the current session and the creation time of the session into the SYS_SESSION_ID and SYS_SESS_CREATE_TIME columns, respectively.
When you execute the UPDATE, DELETE, or SELECT statement, the database system automatically modifies the SQL statement as follows: adds the filter condition "SYS_SESSION_ID = session ID of the current session" to the statement. With this condition, the SQL optimizer can 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 to delete the data in the temporary table by executing theDELETEstatement. - For temporary tables with the
ON COMMIT PRESERVE ROWSoption (session temporary tables), when a session disconnects, theDELETEstatement is executed to delete the data in the temporary table. - Since session IDs can be reused, in OceanBase Database V3.2.4 BP4 and earlier, the data of the current session ID is checked upon login. If additional data cleanup is required, it is performed.
- Data check and cleanup based on non-unique session IDs may cause login failures (cluster unavailable).
Routing of a temporary table
For transaction temporary tables (
ON COMMIT DELETE ROWS) Accesses to the transaction temporary table within a transaction can only be routed to the node where the transaction was started.For 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 routed only to the current session.
Drop a temporary table
You can successfully execute the DROP statement while executing an DML statement, to delete a temporary table and all its data. This behavior differs from that in 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 V3.2.4 BP4 and earlier? | Supported in V3.2.4 BP5 and V3.2.x later? | Supported in V4.2.0? |
|---|---|---|---|
| Plan sharing among different sessions | No | No | Yes |
| No check and cleanup upon login | No | Yes | Yes |
MERGE INTO statement |
No | No | Yes |
Workarounds for severe issues
Unable to log in
- Stop the business using the temporary table, delete the temporary table, or perform a major compaction. Generally, the issue can be resolved on its own. If not, proceed to step 2.
- Restart the server where the login failure occurred.
PL cache bloat due to plan reusability
For example, a procedure definition statement that contains a temporary table:
CREATE PROCEDUCE p1 () (
INSERT INTO temp_table VALUES (xxx);
SELECT * FROM temp_table WHERE ROWNUM = 1 INTO var1;
);
Accesses to the temporary table by different sessions cannot share a plan. Each session needs to compile the procedure p1 to generate a cache for it. This may lead to stability issues. You can rewrite the SQL statement as follows:
EXCUTE IMMEDIATE 'SELECT * FROM temp_table WHERE ROWNUM = 1 INTO var1;'
Rewriting the SQL statement of the temporary table into a dynamic SQL statement can bypass this issue.
Data not cleared after a failure
In some cases, data may be left after a failure. 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, you can drop the temporary table and rebuild it.