DB2 10.5 for Linux, UNIX, and Windows

SET INTEGRITY statement

The SET INTEGRITY statement is used to set the integrity pending state on tables, place tables into full access state, and prune the contents of one or more staging tables.

The following operations can be performed with the SET INTEGRITY statement:
  • Bring one or more tables out of set integrity pending state (previously known as "check pending state") by performing required integrity processing on those tables.
  • Bring one or more tables out of set integrity pending state without performing required integrity processing on those tables.
  • Place one or more tables in set integrity pending state.
  • Place one or more tables into full access state.
  • Prune the contents of one or more staging tables.

When the statement is used to perform integrity processing for a table after it has been loaded or attached, the system can incrementally process the table by checking only the appended portion for constraints violations. If the subject table is a materialized query table or a staging table, and load, attach, or detach operations are performed on its underlying tables, the system can incrementally refresh the materialized query table or incrementally propagate to the staging table with only the delta portions of its underlying tables. However, there are some situations in which the system will not be able to perform such optimizations and will instead perform full integrity processing to ensure data integrity. Full integrity processing is done by checking the entire table for constraints violations, recomputing a materialized query table's definition, or marking a staging table as inconsistent. The latter implies that a full refresh of its associated materialized query table is required. There is also a situation in which you might want to explicitly request incremental processing by specifying the INCREMENTAL option.

The SET INTEGRITY statement is under transaction control.

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 only if DYNAMICRULES run behavior is in effect for the package (SQLSTATE 42509).

Authorization

The privileges required to execute the SET INTEGRITY statement depend on the purpose, as outlined in the following list.

Syntax

Read syntax diagramSkip visual syntax diagram
>>-SET--INTEGRITY----------------------------------------------->

          .-,----------.                                                                          
          V            |                                                                          
>--+-FOR----table-name-+--+-OFF--| access-mode-clause |--| cascade-clause |-+-----------------+-><
   |                      +-FULL ACCESS-------------------------------------+                 |   
   |                      '-PRUNE-------------------------------------------'                 |   
   |      .-,-------------------------------------.                                           |   
   |      V                                       |                                           |   
   +-FOR----table-name--| table-checked-options |-+--IMMEDIATE CHECKED--+-------------------+-+   
   |                                                                    '-| check-options |-' |   
   |      .-,---------------------------------------.                                         |   
   |      V                                         |                                         |   
   '-FOR----table-name--| table-unchecked-options |-+--IMMEDIATE UNCHECKED--------------------'   

access-mode-clause

   .-NO ACCESS---.   
|--+-------------+----------------------------------------------|
   '-READ ACCESS-'   

cascade-clause

   .-CASCADE IMMEDIATE--| to-descendent-types |-.   
|--+--------------------------------------------+---------------|
   '-CASCADE DEFERRED---------------------------'   

to-descendent-types

   .-TO ALL TABLES-------------------------.   
|--+---------------------------------------+--------------------|
   |     .-,-----------------------------. |   
   |     V                               | |   
   '-TO----+-MATERIALIZED QUERY TABLES-+-+-'   
           +-FOREIGN KEY TABLES--------+       
           '-STAGING TABLES------------'       

table-checked-options

   .-,----------------------------------.   
   V                                    |   
|----+-| online-options |-------------+-+-----------------------|
     +-GENERATE IDENTITY--------------+     
     '-| query-optimization-options |-'     

online-options

   .-ALLOW NO ACCESS----.   
|--+--------------------+---------------------------------------|
   +-ALLOW READ ACCESS--+   
   '-ALLOW WRITE ACCESS-'   

query-optimization-options

|--+---------------------------------------------------------------------------------------+--|
   | .-ALLOW QUERY OPTIMIZATION-.                                 .-WITH REFRESH AGE ANY-. |   
   '-+--------------------------+--USING REFRESH DEFERRED TABLES--+----------------------+-'   

check-options

|--●--| incremental-options |--●--+-----------------+----------->
                                  '-FORCE GENERATED-'   

>--●--+-------+--●--+-------------+----------------------------->
      '-PRUNE-'     '-FULL ACCESS-'   

>--●--+----------------------+----------------------------------|
      '-| exception-clause |-'   

incremental-options

|--+-----------------+------------------------------------------|
   +-INCREMENTAL-----+   
   '-NOT INCREMENTAL-'   

exception-clause

                  .-,-----------------------.   
                  V                         |   
|--FOR EXCEPTION----| in-table-use-clause |-+-------------------|

in-table-use-clause

|--IN--table-name--USE--table-name------------------------------|

table-unchecked-options

   .-,--------------------------------------.   
   V                                        |   
|----| integrity-options |--+-------------+-+-------------------|
                            '-FULL ACCESS-'     

integrity-options

|--+-ALL------------------------+-------------------------------|
   | .-,----------------------. |   
   | V                        | |   
   '---+-FOREIGN KEY--------+-+-'   
       +-CHECK--------------+       
       +-MATERIALIZED QUERY-+       
       +-GENERATED COLUMN---+       
       '-STAGING------------'       

Description

FOR table-name
Identifies one or more tables for integrity processing. It must be a table described in the catalog and must not be a view, catalog table, or typed table.
OFF
Specifies that the tables are placed in set integrity pending state. Only very limited activity is allowed on a table that is in set integrity pending state.
access-mode-clause
Specifies the readability of the table while it is in set integrity pending state.
NO ACCESS
Specifies that the table is to be put in set integrity pending no access state, which does not allow read or write access to the table.
READ ACCESS
Specifies that the table is to be put in set integrity pending read access state, which allows read access to the non-appended portion of the table. This option is not allowed on a table that is in set integrity pending no access state (SQLSTATE 428FH).
cascade-clause
Specifies whether the set integrity pending state of the table referenced in the SET INTEGRITY statement is to be immediately cascaded to descendent tables.
CASCADE IMMEDIATE
Specifies that the set integrity pending state is to be immediately extended to descendent tables.
to-descendent-types
Specifies the type of descendent tables to which the set integrity pending state is immediately cascaded.
TO ALL TABLES
Specifies that the set integrity pending state is to be immediately cascaded to all descendent tables of the tables in the invocation list. Descendent tables include all descendent foreign key tables, immediate staging tables, and immediate materialized query tables that are descendants of the tables in the invocation list, or descendants of descendent foreign key tables.

Specifying TO ALL TABLES is equivalent to specifying TO FOREIGN KEY TABLES, TO MATERIALIZED QUERY TABLES, and TO STAGING TABLES, all in the same statement.

TO MATERIALIZED QUERY TABLES
If only TO MATERIALIZED QUERY TABLES is specified, the set integrity pending state is to be immediately cascaded only to descendent immediate materialized query tables. Other descendent tables might later be put in set integrity pending state, if necessary, when the table is brought out of set integrity pending state. If both TO FOREIGN KEY TABLES and TO MATERIALIZED QUERY TABLES are specified, the set integrity pending state will be immediately cascaded to all descendent foreign key tables, all descendent immediate materialized query tables of the tables in the invocation list, and to all immediate materialized query tables that are descendants of the descendent foreign key tables.
TO FOREIGN KEY TABLES
Specifies that the set integrity pending state is to be immediately cascaded to descendent foreign key tables. Other descendent tables might later be put in set integrity pending state, if necessary, when the table is brought out of set integrity pending state.
TO STAGING TABLES
Specifies that the set integrity pending state is to be immediately cascaded to descendent staging tables. Other descendent tables might later be put in set integrity pending state, if necessary, when the table is brought out of set integrity pending state. If both TO FOREIGN KEY TABLES and TO STAGING TABLES are specified, the set integrity pending state will be immediately cascaded to all descendent foreign key tables, all descendent immediate staging tables of the tables in the invocation list, and to all immediate staging tables that are descendants of the descendent foreign key tables.
CASCADE DEFERRED
Specifies that only the tables in the invocation list are to be put in set integrity pending state. The states of the descendent tables will remain unchanged. Descendent foreign key tables might later be implicitly put in set integrity pending state when their parent tables are checked for constraints violations. Descendent immediate materialized query tables and descendent immediate staging tables might be implicitly put in set integrity pending state when one of their underlying tables is checked for integrity violations. A query of a table that is in the set integrity pending state might succeed if an eligible materialized query table that is not in the set integrity pending state is accessed by the query instead of the specified table.
If cascade-clause is not specified, the set integrity pending state is immediately cascaded to all descendent tables.
IMMEDIATE CHECKED
Specifies that the table is to be taken out of set integrity pending state by performing required integrity processing on the table. This is done in accordance with the information set in the STATUS and CONST_CHECKED columns of the SYSCAT.TABLES catalog view. That is:
  • The value in the STATUS column must be 'C' (the table is in set integrity pending state), or an error is returned (SQLSTATE 51027), unless the table is a descendent foreign key table, descendent materialized query table, or descendent staging table of a table that is specified in the list, is in set integrity pending state, and whose intermediate ancestors are also in the list.
  • If the table being checked is in set integrity pending state, the value in CONST_CHECKED indicates which integrity options are to be checked.

When the table is taken out of set integrity pending state, its descendent tables are, if necessary, put in set integrity pending state. A warning to indicate that descendent tables have been put in set integrity pending state is returned (SQLSTATE 01586).

If the table is a system-maintained materialized query table, the data is checked against the query and refreshed as necessary. (IMMEDIATE CHECKED cannot be used for user-maintained materialized query tables or shadow tables.) If the table is a staging table, the data is checked against its query definition and propagated as necessary.

When the integrity of a child table is checked:
  • None of its parents can be in set integrity pending state, or
  • Each of its parents must be checked for constraints violations in the same SET INTEGRITY statement
When an immediate materialized query table is refreshed, or deltas are propagated to a staging table:
  • None of its underlying tables can be in set integrity pending state, or
  • Each of its underlying tables must be checked in the same SET INTEGRITY statement
Otherwise, an error is returned (SQLSTATE 428A8).
table-checked-options
online-options
Specifies the accessibility of the table while it is being processed.
ALLOW NO ACCESS
Specifies that no other users can access the table while it is being processed, except if they are using the Uncommitted Read isolation level.
ALLOW READ ACCESS
Specifies that other users have read-only access to the table while it is being processed.
ALLOW WRITE ACCESS
Specifies that other users have read and write access to the table while it is being processed.
GENERATE IDENTITY
Specifies that if the table includes an identity column, the values are generated by the SET INTEGRITY statement. By default, when the GENERATE IDENTITY option is specified, only attached rows will have their identity column values generated by the SET INTEGRITY statement. The NOT INCREMENTAL option must be specified in conjunction with the GENERATE IDENTITY option to have the SET INTEGRITY statement generate identity column values for all rows in the table, including attached rows, loaded rows, and existing rows. If the GENERATE IDENTITY option is not specified, the current identity column values for all rows in the table are left unchanged. When the table is a system-period temporal table, GENERATE IDENTITY with the NOT INCREMENTAL option is allowed only if you first issue an ALTER TABLE statement with the DROP VERSIONING clause (SQLSTATE 428FH).
query-optimization-options
Specifies the query optimization options for the maintenance of REFRESH DEFERRED materialized query tables.
ALLOW QUERY OPTIMIZATION USING REFRESH DEFERRED TABLES WITH REFRESH AGE ANY
Specifies that when the CURRENT REFRESH AGE special register is set to 'ANY', the maintenance of table-name will allow REFRESH DEFERRED materialized query tables to be used to optimize the query that maintains table-name. If table-name is not a REFRESH DEFERRED materialized query table, an error is returned (SQLSTATE 428FH). REFRESH IMMEDIATE materialized query tables are always considered during query optimization.
check-options
incremental-options
INCREMENTAL
Specifies the application of integrity processing on the appended portion (if any) of the table. If such a request cannot be satisfied (that is, the system detects that the whole table needs to be checked for data integrity), an error is returned (SQLSTATE 55019).
NOT INCREMENTAL
Specifies the application of integrity processing on the whole table. If the table is a materialized query table, the materialized query table definition is recomputed. If the table has at least one constraint defined on it, this option causes full processing of descendent foreign key tables and descendent immediate materialized query tables. If the table is a staging table, it is set to an inconsistent state.
If the incremental-options clause is not specified, the system determines whether incremental processing is possible; if not, the whole table is checked.
FORCE GENERATED
If the table includes generated by expression columns, the values are computed on the basis of the expression and stored in the column. If this option is not specified, the current values are compared to the computed value of the expression, as though an equality check constraint were in effect. If the table is processed for integrity incrementally, generated columns are computed only for the appended portion. When the table is a system-period temporal table, the FORCE GENERATED option is allowed only if you first issue an ALTER TABLE statement with the DROP VERSIONING clause (SQLSTATE 428FH).
PRUNE
This option can be specified for staging tables only. Specifies that the content of the staging table is to be pruned, and that the staging table is to be set to an inconsistent state. If any table in the table-name list is not a staging table, an error is returned (SQLSTATE 428FH). If the INCREMENTAL check option is also specified, an error is returned (SQLSTATE 428FH).
FULL ACCESS
Specifies that the table is to become fully accessible after the SET INTEGRITY statement executes.

When an underlying table (that has dependent immediate materialized query tables or dependent immediate staging tables) in the invocation list is incrementally processed, the underlying table is put in no data movement state, as required, after the SET INTEGRITY statement executes. When all incrementally refreshable dependent immediate materialized query tables and staging tables are taken out of set integrity pending state, the underlying table is automatically brought out of the no data movement state into the full access state. If the FULL ACCESS option is specified with the IMMEDIATE CHECKED option, the underlying table is put directly in full access state (bypassing the no data movement state). In DB2® Version 9.7. Fix Pack 1 and later, specifying the FULL ACCESS option only removes the dependency between the dependent tables and underlying table. The underlying table continues to be unavailable until the data partition detach process is completed by the asynchronous partition detach task.

Dependent immediate materialized query tables that have not been refreshed might undergo a full recomputation in the subsequent REFRESH TABLE statement, and dependent immediate staging tables that have not had the appended portions of the table propagated to them might be flagged as inconsistent.

When an underlying table in the invocation list requires full processing, or does not have dependent immediate materialized query tables, or dependent immediate staging tables, the underlying table is put directly into full access state after the SET INTEGRITY statement executes, regardless of whether the FULL ACCESS option was specified.

exception-clause
FOR EXCEPTION
Specifies that any row that is in violation of a constraint being checked is to be moved to an exception table. Even if errors are detected, the table is taken out of set integrity pending state. A warning to indicate that one or more rows have been moved to the exception tables is returned (SQLSTATE 01603).

If the FOR EXCEPTION option is not specified and any constraints are violated, only the first detected violation is returned (SQLSTATE 23514). If there is a violation in any table, all of the tables are left in set integrity pending state.

It is recommended to always use the FOR EXCEPTION option when checking for constraints violations to prevent a rollback of the SET INTEGRITY statement if a violation is found.

When the table specified after the IN keyword is a system-period temporal table, the FOR EXCEPTION option is allowed only if you first issue an ALTER TABLE statement with the DROP VERSIONING clause (SQLSTATE 428FH).

IN table-name
Specifies the table from which rows that violate constraints are to be moved. There must be one exception table specified for each table being checked. This clause cannot be specified for a materialized query table or a staging table (SQLSTATE 428A7).
USE table-name
Specifies the exception table into which error rows are to be moved.
FULL ACCESS
If the FULL ACCESS option is specified as the only operation of the statement, the table is placed into the full access state without being rechecked for integrity violations. However, dependent immediate materialized query tables that have not been refreshed might require a full recomputation in subsequent REFRESH TABLE statements, and dependent immediate staging tables that have not had the delta portions of the table propagated to them might be changed to incomplete state. This option can only be specified for a table that is in the no data movement state or the no access state, but not in the set integrity pending state (SQLSTATE 428FH).
PRUNE
This option can be specified for staging tables only. Specifies that the content of the staging table is to be pruned, and that the staging table is to be set to an inconsistent state. If any table in the table-name list is not a staging table, an error is returned (SQLSTATE 428FH).
table-unchecked-options
integrity-options
Used to define the types of required integrity processing that are to be bypassed when the table is taken out of the set integrity pending state.
ALL
The table will be immediately taken out of set integrity pending state without any of its required integrity processing being performed.
FOREIGN KEY
Required foreign key constraints checking will not be performed when the table is brought out of set integrity pending state.
CHECK
Required check constraints checking will not be performed when the table is brought out of set integrity pending state.
MATERIALIZED QUERY
Required refreshing of a materialized query table will not be performed when the table is brought out of set integrity pending state.
GENERATED COLUMN
Required generated column constraints checking will not be performed when the table is brought out of set integrity pending state.
STAGING
Required propagation of data to a staging table will not be performed when the table is brought out of set integrity pending state.

If no other types of integrity processing are required on the table after a specific type of integrity processing has been marked as bypassed, the table is immediately taken out of set integrity pending state.

FULL ACCESS
Specifies that the tables are to become fully accessible after the SET INTEGRITY statement executes.

When an underlying table in the invocation list is incrementally processed, and it has dependent immediate materialized query tables or dependent immediate staging tables, the underlying table is placed, as required, in the no data movement state after the SET INTEGRITY statement executes. When all incrementally refreshable dependent immediate materialized query tables and staging tables have been taken out of set integrity pending state, the underlying table is automatically brought out of the no data movement state into the full access state. If the FULL ACCESS option is specified with the IMMEDIATE UNCHECKED option, the underlying table is placed directly in full access state (it bypasses the no data movement state). Dependent immediate materialized query tables that have not been refreshed might undergo a full recomputation in the subsequent REFRESH TABLE statement, and dependent immediate staging tables that have not had the appended portions of the table propagated to them might be flagged as inconsistent.

In DB2 V9.7. Fix Pack 1 and later, specifying the FULL ACCESS option only removes the dependency between the dependent tables and underlying table. The underlying table continues to be unavailable until the data partition detach process is completed by the asynchronous partition detach task.

When an underlying table in the invocation list requires full processing, or does not have dependent immediate materialized query tables, or dependent immediate staging tables, the underlying table is placed directly in full access state after the SET INTEGRITY statement executes, regardless of whether the FULL ACCESS option has been specified.

If the FULL ACCESS option has been specified with the IMMEDIATE UNCHECKED option, and the statement does not bring the table out of set integrity pending state, an error is returned (SQLSTATE 428FH).

IMMEDIATE UNCHECKED
Specifies one of the following:
  • The table is to be brought out of set integrity pending state immediately without any required integrity processing.
  • The table is to have one or more types of required integrity processing bypassed when the table is brought out of set integrity pending state by a subsequent SET INTEGRITY statement using the IMMEDIATE CHECKED option.

Consider the data integrity implications of this option before using it. See the "Notes" section.

Notes

Examples