SQL Reference

DECLARE GLOBAL TEMPORARY TABLE

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

table-name
Names the temporary table. The qualifier, if specified explicitly, must be SESSION, otherwise an error is returned (SQLSTATE 428EK). If the qualifier is not specified, SESSION is implicitly assigned.

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:

column-definition
Defines the attributes of a column of the temporary table.

column-name
Names a column of the table. The name cannot be qualified and the same name cannot be used for more than one column of the table (SQLSTATE 42711).

A table may have the following:

  • a 4K page size with maximum of 500 columns where the byte counts of the columns must not be greater than 4005 in a 4K page size. Refer to Row Size for more details.
  • an 8K page size with maximum of 1 012 columns where the byte counts of the columns must not be greater than 8 101. Refer to Row Size for more details.
  • a 16K page size with maximum of 1 012 columns where the byte counts of the columns must not be greater than 16 293. Refer to Row Size for more details.
  • a 32K page size with maximum of 1 012 columns where the byte counts of the columns must not be greater than 32 677. Refer to Row Size for more details.

data-type
See data-type in CREATE TABLE for allowable types. Note that BLOB, CLOB, DBCLOB, LONG VARCHAR, LONG VARGRAPHIC, DATALINK, reference, and structured types cannot be used with declared global temporary tables (SQLSTATE 42962). This exception includes distinct types sourced on these restricted types.

FOR BIT DATA can be specified as part of character string data types.

column-options
Defines additional options related to the columns of the table.

NOT NULL
Prevents the column from containing null values. See NOT NULL in CREATE TABLE for specification of null values.

default-clause
See default-clause in CREATE TABLE for specification of defaults.

identity-clause
See identity-clause in CREATE TABLE for specification of identity columns.

LIKE table-name2 or view-name
Specifies that the columns of the table have exactly the same name and description as the columns of the identified table (table-name2) or view (view-name), or nickname (nickname). The name specified after LIKE must identify a table, view or nickname that exists in the catalog or a declared temporary table. A typed table or typed view cannot be specified (SQLSTATE 428EC).

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).

AS (fullselect) DEFINITION ONLY
Specifies that the table definition is based on the column definitions from the result of a query expression. The use of AS (fullselect) is an implicit definition of n columns for the declared global temporary table, where n is the number of columns that would result from fullselect. The columns of the new table are defined by the columns that result from the fullselect. Every select list element must have a unique name (SQLSTATE 42711). The AS clause can be used in the select-clause to provide unique names.

The implicit definition includes the column name, data type, and nullability characteristic of each of the result columns of fullselect.

copy-options
These options specify whether or not to copy additional attributes of the source result table definition (table, view, or fullselect).

INCLUDING COLUMN DEFAULTS
Column defaults for each updatable column of the source result table definition are copied. Columns that are not updatable will not have a default defined in the corresponding column of the created table.

If LIKE table-name2 is specified, and table-name2 identifies a base table or declared temporary table, then INCLUDING COLUMN DEFAULTS is the default.

EXCLUDING COLUMN DEFAULTS
Column defaults are not copied from the source result table definition.

This clause is the default, except when LIKE table-name is specified and table-name identifies a base table or declared temporary table.

INCLUDING IDENTITY COLUMN ATTRIBUTES
If available, identity column attributes (START WITH, INCREMENT BY, and CACHE values) are copied from the source's result table definition. It is possible to copy these attributes if the element of the corresponding column in the table, view, or fullselect is the name of a column of a table, or the name of a column of a view, which directly or indirectly maps to the column name of a base table with the identity property. In all other cases, the columns of the new temporary table will not get the identity property. For example:
  • the select list of the fullselect includes multiple instances of the name of an identity column (that is, selecting the same column more than once)
  • the select list of the fullselect includes multiple identity columns (that is, it involves a join)
  • the identity column is included in an expression in the select list
  • the fullselect includes a set operation (union, except, or intersect).

EXCLUDING IDENTITY COLUMN ATTRIBUTES
Identity column attributes are not copied from the source result table definition.

ON COMMIT
Specifies the action taken on the global temporary table when a COMMIT operation is performed.

DELETE ROWS
All rows of the table will be deleted if no WITH HOLD cursor is open on the table. This is the default.

PRESERVE ROWS
Rows of the table will be preserved.

NOT LOGGED
Changes to the table are not logged, including creation of the table. When a ROLLBACK (or ROLLBACK TO SAVEPOINT) operation is performed and the table was changed in the unit of work (or savepoint), then all rows of the table are deleted. If the table was created in the unit of work (or savepoint), then that table will be dropped. If the table was dropped in the unit of work (or savepoint) then the table will be restored, but with no rows. Furthermore, if a statement that performs an INSERT, UPDATE, or DELETE operation on the table encounters an error, all rows of the table are deleted.

WITH REPLACE
Indicates that, in the case that a declared global temporary table already exists with the specified name, the existing table is replaced with the temporary table defined by this statement (and all rows of the existing table are deleted).

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).

IN tablespace-name
Identifies the table space in which the global temporary table will be instantiated. The table space must exist and be a USER TEMPORARY table space (SQLSTATE 42838), over which the authorization ID of the statement has USE privilege (SQLSTATE 42501). If this clause is not specified, a table space for the table is determined by choosing the USER TEMPORARY table space with the smallest sufficient page size over which the authorization ID of the statement has USE privilege. When more than one table space qualifies, preference is given according to who was granted the USE privilege:
  1. the authorization ID
  2. a group to which the authorization ID belongs
  3. PUBLIC

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.

PARTITIONING KEY (column-name,...)
Specifies the partitioning key used when data in the table is partitioned. Each column-name must identify a column of the table and the same column must not be identified more than once.

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).

USING HASHING
Specifies the use of the hashing function as the partitioning method for data distribution. This is the only partitioning method supported.

Notes


Footnotes:

89
None of the privileges are granted with the GRANT option, and none of the privileges appear in the catalog table.


[ Top of Page | Previous Page | Next Page ]