Exception tables
Exception tables are user-created tables that mimic the definition of the tables that are specified to be checked using the SET INTEGRITY statement with the IMMEDIATE CHECKED option. They are used to store copies of the rows that violate constraints in the tables being checked.
The exception tables that are used by the load utility are identical to the ones described here, and can therefore be reused during checking with the SET INTEGRITY statement.
Rules for creating an exception table
The rules for creating an exception table are as follows:
- If the table is protected by a security policy, the exception table must be protected by the same security policy.
- The first
n
columns of the exception table are the same as the columns of the table being checked. All column attributes, including name, data type, and length should be identical. For protected columns, the security label protecting the column must be the same in both tables. - All of the columns of the exception table must be free of constraints and triggers. Constraints include referential integrity and check constraints, as well as unique index constraints that could cause errors on insert.
- The
(n+1)
column of the exception table is an optional TIMESTAMP column. This serves to identify successive invocations of checking by the SET INTEGRITY statement on the same table, if the rows within the exception table have not been deleted before issuing the SET INTEGRITY statement to check the data. The timestamp precision can be any value from 0 to 12 and the value assigned will be the result of CURRENT TIMESTAMP special register - The
(n+2)
column should be of type CLOB(32K) or larger. This column is optional but recommended, and will be used to give the names of the constraints that the data within the row violates. If this column is not provided (as could be warranted if, for example, the original table had the maximum number of columns allowed), then only the row where the constraint violation was detected is copied. - The exception table should be created with both
(n+1)
and(n+2)
columns. - There is no enforcement of any particular name for the previously listed additional columns. However, the type specification must be exactly followed.
- No additional columns are allowed.
- If the original table has generated columns (including the IDENTITY property), the corresponding columns in the exception table should not specify the generated property.
- Users invoking the SET INTEGRITY statement to check data must hold the INSERT privilege on the exception tables.
- The exception table cannot be a data partitioned table, a range clustered table, or a detached table.
- The exception table cannot be a materialized query table or a staging table.
- The exception table cannot have any dependent refresh immediate materialized query tables or any dependent propagate immediate staging tables.
The information in the message
column has the following
structure:
Field number | Contents | Size | Comments |
---|---|---|---|
1 | Number of constraint violations | 5 bytes | Right justified padded with 0 |
2 | Type of first constraint violation | 1 byte |
|
3 | Length of constraint/columnb /index IDc | 5 bytes | Right justified padded with 0 |
4 | Constraint name/Column nameb/index IDc | length from the previous field | |
5 | Separator | 3 bytes | <space><colon><space> |
6 | Type of next constraint violation | 1 byte |
|
7 | Length of constraint/column/index ID | 5 bytes | Right justified padded with 0 |
8 | Constraint name/Column name/Index ID | length from the previous field | |
..... | ..... | ..... | Repeat Field 5 through 8 for each violation |
|
Handling rows in an exception table
The information in exception tables can be processed in various ways. Data can be corrected and rows re-inserted into the original tables.
If there are no INSERT triggers on the original table, transfer the corrected rows by issuing an INSERT statement with a subquery on the exception table.
- Design the INSERT triggers to be fired depending on the value in a column that has been defined explicitly for the purpose.
- Unload data from the exception tables and append it using the load utility. In this case, if you want to recheck the data, note that constraints checking is not confined to the appended rows.
- Save the trigger definition text from the relevant system catalog view. Then drop the INSERT trigger and use INSERT to transfer the corrected rows from the exception tables. Finally, re-create the trigger using the saved trigger definition.
No explicit provision is made to prevent the firing of triggers when inserting rows from exception tables.
Only one violation per row is reported for unique index violations.
If values with LONG VARCHAR, LONG VARGRAPHIC, or LOB data types are in the table, the values are not inserted into the exception table in the case of unique index violations.
Querying exception tables
The message column structure in an exception table is a concatenated list of constraint names, lengths, and delimiters, as described earlier. This information can be queried.
WITH IV (C1, C2, MSGCOL, CONSTNAME, I, J) AS
(SELECT C1, C2, MSGCOL,
CHAR(SUBSTR(MSGCOL, 12,
INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,7,5)),5,0)))),
1,
15+INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,7,5)),5,0))
FROM E1
UNION ALL
SELECT C1, C2, MSGCOL,
CHAR(SUBSTR(MSGCOL, J+6,
INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,J+1,5)),5,0)))),
I+1,
J+9+INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,J+1,5)),5,0))
FROM IV
WHERE I < INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,1,5)),5,0))
) SELECT C1, C2, CONSTNAME FROM IV;
WITH IV (C1, C2, MSGCOL, CONSTNAME, I, J) AS
(SELECT C1, C2, MSGCOL,
CHAR(SUBSTR(MSGCOL, 12,
INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,7,5)),5,0)))),
1,
15+INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,7,5)),5,0))
FROM E1
UNION ALL
SELECT C1, C2, MSGCOL,
CHAR(SUBSTR(MSGCOL, J+6,
INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,J+1,5)),5,0)))),
I+1,
J+9+INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,J+1,5)),5,0))
FROM IV
WHERE I < INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,1,5)),5,0))
) SELECT C1, C2, CONSTNAME FROM IV WHERE CONSTNAME = 'constraintname';
WITH IV (C1, C2, MSGCOL, CONSTNAME, CONSTTYPE, I, J) AS
(SELECT C1, C2, MSGCOL,
CHAR(SUBSTR(MSGCOL, 12,
INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,7,5)),5,0)))),
CHAR(SUBSTR(MSGCOL, 6, 1)),
1,
15+INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,7,5)),5,0))
FROM E1
UNION ALL
SELECT C1, C2, MSGCOL,
CHAR(SUBSTR(MSGCOL, J+6,
INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,J+1,5)),5,0)))),
CHAR(SUBSTR(MSGCOL, J, 1)),
I+1,
J+9+INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,J+1,5)),5,0))
FROM IV
WHERE I < INTEGER(DECIMAL(VARCHAR(SUBSTR(MSGCOL,1,5)),5,0))
) SELECT C1, C2, CONSTNAME FROM IV WHERE CONSTTYPE = 'K';