The DECLARE GLOBAL TEMPORARY TABLE statement defines a temporary table for the current session. The declared temporary table description does not appear in the system catalog. It is not persistent and cannot be shared with other sessions. Each session that defines a declared global temporary table of the same name has its own unique description of the temporary table. When the session terminates, the rows of the table are deleted, and the description of the temporary table is dropped.
Invocation
This statement can be embedded in an application program or issued through the use of dynamic SQL statements. It is an executable statement that can be dynamically prepared.
Authorization
The privileges held by the authorization ID of the statement must include at least one of the following:
When defining a table using LIKE or a fullselect, the privileges held by the authorization ID of the statement must also include at least one of the following on each identified table or view:
Syntax
>>-DECLARE GLOBAL TEMPORARY TABLE--table-name-------------------> .-,------------------------. V | >-----+-(-----| column-definition |---+---)--------------------------+> +-LIKE--+-table-name2-+---+-------------------+----------------+ | '-view-name---' '-| copy-options |--' | '-AS--(--fullselect--)--DEFINITION ONLY--+-------------------+-' '-| copy-options |--' .-ON COMMIT DELETE ROWS---. >----*--+--------------+--*--+-------------------------+---*--NOT LOGGED--*-> '-WITH REPLACE-' '-ON COMMIT PRESERVE ROWS-' >----+----------------------+---*-------------------------------> '-IN--tablespace-name--' >----+------------------------------------------------------------------+---*-> | .-,--------------. | | V | .-USING HASHING-. | '-PARTITIONING KEY--(-----column-name---+---)--+---------------+---' >-------------------------------------------------------------->< column-definition |---column-name---| data-type |----+---------------------+------| '-| column-options |--' column-options |---*--+-----------+---*--+------------------------------------------------------+---*--> '-NOT NULL--' +-| default-clause |-----------------------------------+ '-GENERATED--+-ALWAYS-----+---AS--| identity-clause |--' '-BY DEFAULT-' >---------------------------------------------------------------| copy-options .-COLUMN ATTRIBUTES-. .-EXCLUDING IDENTITY--+-------------------+--. |---*--+---------------------------------------+---*--+--------------------------------------------+---*--> | .-COLUMN-. | | .-COLUMN ATTRIBUTES-. | '--+-INCLUDING-+--+--------+--DEFAULTS--' '-INCLUDING IDENTITY-+-------------------+---' '-EXCLUDING-' >---------------------------------------------------------------|
Description
Each session that defines a declared global temporary table with the same table-name has its own unique description of that declared global temporary table. The WITH REPLACE clause must be specified if table-name identifies a declared temporary table that already exists in the session (SQLSTATE 42710).
It is possible that a table, view, alias, or nickname already exists in the catalog, with the same name and the schema name SESSION. In this case:
A table may have the following:
FOR BIT DATA can be specified as part of character string data types.
The use of LIKE is an implicit definition of n columns, where n is the number of columns in the identified table or view.
Column default and identity column attributes may be included or excluded, based on the copy-attributes clauses.
The implicit definition does not include any other attributes of the identified table or view. Thus, the new table does not have any unique constraints, foreign key constraints, triggers, or indexes. The table is created in the table space either implicitly or explicitly, as specified by the IN clause.
The names used for table-name2 and view-name can not be the same as the name of the global temporary table that is being created (SQLSTATE 428EC).
The implicit definition includes the column name, data type, and nullability characteristic of each of the result columns of fullselect.
If LIKE table-name2 is specified, and table-name2 identifies a base table or declared temporary table, then INCLUDING COLUMN DEFAULTS is the default.
This clause is the default, except when LIKE table-name is specified and table-name identifies a base table or declared temporary table.
When WITH REPLACE is not specified, then the name specified must not identify a declared global temporary table that already exists in the current session (SQLSTATE 42710).
If more than one table space still qualifies, the final choice is made by the database manager. When no USER TEMPORARY table space qualifies, an error is raised (SQLSTATE 42727).
Determination of the table space may change when:
The sufficient page size of a table is determined by either the byte count of the row or the number of columns. Refer to Row Size for more information.
If this clause is not specified, and this table resides in a multiple partition nodegroup, then the partitioning key is defined as the first column of declared temporary table.
For declared temporary tables, in table spaces defined on single-partition nodegroups, any collection of columns can be used to define the partitioning key. If you do not specify this parameter, no partitioning key is created.
Note that partitioning key columns cannot be updated (SQLSTATE 42997).
Notes
In order to reference the declared global temporary table in an SQL statement (other than the DECLARE GLOBAL TEMPORARY TABLE statement), the table must be explicitly or implicitly qualified by the schema name SESSION. If table-name is not qualified by SESSION, declared global temporary tables are not considered when resolving the reference.
A reference to SESSION.table-name in a connection that has not declared a global temporary table by that name will attempt to resolve from persistent objects in the catalog. If no such object exists, an error occurs (SQLSTATE 42704).
When a rollback operation terminates a unit of work or a savepoint in P, and that unit of work or savepoint includes the declaration of SESSION.T, then the rollback includes the operation DROP SESSION.T.
If a rollback operation terminates a unit of work or a savepoint in P, and that unit of work or savepoint includes the drop of a declared temporary table SESSION.T, then the rollback will undo the drop of the table, but the table will have been emptied.