DSN_STATEMENT_CACHE_TABLE
The statement cache table, DSN_STATEMENT_CACHE_TABLE, contains information about the SQL statements in the statement cache, information captured as the results of an EXPLAIN STATEMENT CACHE ALL statement.
Qualifiers
Your subsystem or data sharing group can contain multiple instances of these tables that are qualified by user ID. These tables are populated with statement cost information when you issue the EXPLAIN statement or bind. They are also populated when you specify EXPLAIN(YES) or EXPLAIN(ONLY) in a BIND or REBIND command. SQL optimization tools might also create EXPLAIN tables that are qualified by a user ID. You can find the SQL statement for creating an instance of these tables in member DSNTESC of the SDSNSAMP library.
Sample CREATE TABLE statement
You can find a sample CREATE TABLE statement for each EXPLAIN table in member DSNTESC of the prefix.SDSNSAMP library. You can call the ADMIN_EXPLAIN_MAINT stored procedure to create EXPLAIN tables, upgrade them to the format for the current Db2 release, or complete other maintenance tasks. See ADMIN_EXPLAIN_MAINT stored procedure for information about using the action input parameter to request each of these tasks.
Column descriptions
The following table shows the descriptions of the columns in DSN_STATEMENT_CACHE_TABLE.
Column name | Data Type | Description |
---|---|---|
STMT_ID | INTEGER NOT NULL | The statement ID; this value is the EDM unique token for the statement. |
STMT_TOKEN | VARCHAR(240) | The statement token; you provide this value as an identification string. |
COLLID | VARCHAR(128) NOT NULL |
The collection ID:
|
PROGRAM_NAME | VARCHAR(128) NOT NULL | The name of the package that performed the initial PREPARE for the statement. |
INV_DROPALT | CHAR(1) NOT NULL | This column is not used. |
INV_REVOKE | CHAR(1) NOT NULL | This column is not used. |
INV_LRU | CHAR(1) NOT NULL | This column is not used. |
INV_RUNSTATS | CHAR(1) NOT NULL | This column is not used. |
CACHED_TS | TIMESTAMP NOT NULL | The timestamp when the statement was stored in the dynamic statement cache.3 |
USERS | INTEGER NOT NULL | The number of current users of the statement. This number indicates the users that have prepared or run the statement during their current unit of work. 1,3 |
COPIES | INTEGER NOT NULL | The number of copies of the statement that are owned by all threads in the system. 1,3 |
LINES | INTEGER NOT NULL | The precompiler line number from the initial PREPARE of the statement. 1 |
PRIMAUTH | VARCHAR(128) NOT NULL | The primary authorization ID that did the initial PREPARE of the statement. |
CURSQLID | VARCHAR(128) NOT NULL | The CURRENT SQLID that did the initial PREPARE of the statement. |
BIND_QUALIFIER | VARCHAR(128) NOT NULL | The BIND qualifier. For unqualified table names, this is the object qualifier. |
BIND_ISO | CHAR(2) NOT NULL | The value of the ISOLATION BIND option that is in effect for this statement.
The value will be one of the following values:
|
BIND_CDATA | CHAR(1) NOT NULL | The value of the CURRENTDATA BIND option that is in effect for this statement.
The value will be one of the following values:
|
BIND_DYNRL | CHAR(1) NOT NULL | The value of the DYNAMICRULES BIND option that is in effect for this
statement. The value will be one of the following values:
|
BIND_DEGRE | CHAR(1) NOT NULL | The value of the CURRENT DEGREE special register that is in effect for this
statement. The value will be one of the following values:
|
BIND_SQLRL | CHAR(1) NOT NULL | The value of the CURRENT RULES special register that is in effect for this
statement. The value will be one of the following values:
|
BIND_CHOLD | CHAR(1) NOT NULL | The value of the WITH HOLD attribute of the PREPARE for this statement. The
value will be one of the following values:
|
STAT_TS | TIMESTAMP NOT NULL | Timestamp of the statistics. This is the timestamp when IFCID 318 is started. 2 |
STAT_EXEC | INTEGER NOT NULL | This column is deprecated. Use STAT_EXECB instead. |
STAT_GPAG | INTEGER NOT NULL | This column is deprecated. Use STAT_GPAGB instead. 1 |
STAT_SYNR | INTEGER NOT NULL | This column is deprecated. Use STAT_SYNRB instead. 1 |
STAT_WRIT | INTEGER NOT NULL | This column is deprecated. Use STAT_WRITB instead. 1 |
STAT_EROW | INTEGER NOT NULL | This column is deprecated. Use STAT_EROWB instead. 1 |
STAT_PROW | INTEGER NOT NULL | This column is deprecated. Use STAT_PROWB instead. 1 |
STAT_SORT | INTEGER NOT NULL | This column is deprecated. Use STAT_SORTB instead. 1 |
STAT_INDX | INTEGER NOT NULL | This column is deprecated. Use STAT_INDXB instead. |
STAT_RSCN | INTEGER NOT NULL | This column is deprecated. Use STAT_RSCNB instead. |
STAT_PGRP | INTEGER NOT NULL | This column is deprecated. Use STAT_PGRPB instead. |
STAT_ELAP | FLOAT NOT NULL | The accumulated elapsed time that is used for the statement. 2 |
STAT_CPU | FLOAT NOT NULL | The accumulated CPU time that is used for the statement. 2 |
STAT_SUS_SYNIO | FLOAT NOT NULL | The accumulated wait time for synchronous I/O operations for the statement. 2 |
STAT_SUS_LOCK | FLOAT NOT NULL | The accumulated wait time for lock requests for the statement. 2 |
STAT_SUS_SWIT | FLOAT NOT NULL | The accumulated wait time for synchronous execution unit switch for the statement. 2 |
STAT_SUS_GLCK | FLOAT NOT NULL | The accumulated wait time for global parent L-locks for this statement. 2 |
STAT_SUS_OTHR | FLOAT NOT NULL | The accumulated wait time for read activity that is done by another thread. 2 |
STAT_SUS_OTHW | FLOAT NOT NULL | The accumulated wait time for write activity done by another thread. 2 |
STAT_RIDLIMT | INTEGER NOT NULL | This column is deprecated. Use STAT_SORTB instead. |
STAT_RIDSTOR | INTEGER NOT NULL | This column is deprecated. Use STAT_SORTB instead. |
EXPLAIN_TS | TIMESTAMP NOT NULL | The timestamp for when the statement cache table is populated. |
SCHEMA | VARCHAR(128) NOT NULL | The value of the CURRENT SCHEMA special register. |
STMT_TEXT | CLOB(2M) NOT NULL | The statement that is being explained. |
STMT_ROWID | ROWID NOT NULL GENERATED ALWAYS | The ROWID of the statement. |
BIND_RO_TYPE | CHAR(1) NOT NULL WITH DEFAULT | The current specification of the REOPT option for the
statement3:
|
BIND_RA_TOT | INTEGER NOT NULL WITH DEFAULT | The total number of REBIND commands that have been issued for the dynamic statement because of the REOPT(AUTO) option.1,3 |
GROUP_MEMBER | VARCHAR(24) NOT NULL WITH DEFAULT | The member name of the Db2 that executed EXPLAIN. The column is blank if the Db2 subsystem was not in a data sharing environment when EXPLAIN was executed. |
STAT_EXECB | BIGINT NOT NULL WITH DEFAULT | The number of times this statement has been run. For a statement with a cursor, this is the number of OPENs.2 |
STAT_GPAGB | BIGINT NOT NULL WITH DEFAULT | The number of getpage operations that are performed for the statement. 2 |
STAT_SYNRB | BIGINT NOT NULL WITH DEFAULT | The number of synchronous buffer reads that are performed for the statement. 2 |
STAT_WRITB | BIGINT NOT NULL WITH DEFAULT | The number of buffer write operations that are performed for the statement. 2 |
STAT_EROWB | BIGINT NOT NULL WITH DEFAULT | The number of rows that are examined for the statement. 2 |
STAT_PROWB | BIGINT NOT NULL WITH DEFAULT | The number of rows that are processed for the statement. 2 |
STAT_SORTB | BIGINT NOT NULL WITH DEFAULT | The number of sorts that are performed for the statement.2 |
STAT_INDXB | BIGINT NOT NULL WITH DEFAULT | The number of index scans that are performed for the statement.2 |
STAT_RSCNB | BIGINT NOT NULL WITH DEFAULT | The number of table space scans that are performed for the statement.2 |
STAT_PGRPB | BIGINT NOT NULL WITH DEFAULT | The number of parallel groups that are created for the statement.2 |
STAT_RIDLIMTB | BIGINT NOT NULL WITH DEFAULT | The number of times a RID list was not used because the number of RIDs would have exceeded Db2 limits.2 |
STAT_RIDSTORB | BIGINT NOT NULL WITH DEFAULT | The number of times a RID list was not used because there is not enough storage available to hold the list of RIDs.2 |
LITERAL_REPL | CHAR(1) NOT NULL WITH DEFAULT | Identifies cached statements where the literal
values are replaced by the '&' symbol:3
|
STAT_SUS_LATCH | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for latch requests for the statement. |
STAT_SUS_PLATCH | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for page latch requests for the statement. |
STAT_SUS_DRAIN | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for drain lock requests for the statement. |
STAT_SUS_CLAIM | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for claim count requests for the statement. |
STAT_SUS_LOG | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for log writer requests for the statement. |
EXPANSION_REASON | CHAR(2) NOT NULL WITH DEFAULT |
This column applies only to statements that reference archive tables or temporal tables. For other statements, this column is blank.
Indicates the effect of the CURRENT TEMPORAL BUSINESS_TIME special register, the CURRENT TEMPORAL SYSTEM_TIME special register, and the SYSIBMADM.GET_ARCHIVE built-in global variable. These items are controlled by the BUSTIMESENSITIVE, SYSTIMESENSITIVE, and ARCHIVESENSITIVE bind options. Db2 implicitly adds certain syntax to the query if one of the following conditions are true:
This column can have one of the following values:
|
ACCELERATED | CHAR(10) | Identifies whether a cached dynamic statement was prepared for acceleration to
an accelerator server. Possible values are:
|
ACCELERATED (continued) |
(Continued from the previous row.)
Query acceleration behavior is specified by either the QUERY_ACCELERATION subsystem parameter, the QUERYACCELERATION bind option, or the CURRENT QUERY ACCELERATION special register, and depends on their order of precedence. The order of precedence (lowest to highest) is:
|
|
STAT_ACC_ELAP | BIGINT | The accumulated elapsed time for the accelerator. |
STAT_ACC_CPU | BIGINT | The accumulated CPU time for the accelerator. |
STAT_ACC_ROW | BIGINT | The accumulated number of rows that are returned from the accelerator. |
STAT_ACC_BYTE | BIGINT | The accumulated number of bytes that are returned from the accelerator. |
STAT_ACC_1ROW | BIGINT | The time waited for the first row of the query result to be available from the accelerator. |
STAT_ACC_DB2 | BIGINT | The total time the accelerator waited for Db2 to request query results. |
STAT_ACC_EXEC | BIGINT | The accumulated execution time for the accelerator. |
STAT_ACC_WAIT | BIGINT | The accumulated queue wait time for the accelerator. |
ACCEL_OFFLOAD_ELIGIBLE | CHAR(1) |
|
ACCELERATOR_NAME | VARCHAR(128) | The concatenated name of the accelerator server that processed the query. |
PER_STMT_ID | BIGINT NOT NULL | The statement identifier of the stabilized dynamic SQL statement. This value is set if this entry was stabilized to or loaded from the SYSIBM.SYSDNQRY catalog table |
STBLGRP | VARCHAR(128 ) NOT NULL | The stabilization group name specified in a START DYNQRY command. This value is set if this entry was stabilized to or loaded from the SYSIBM.SYSDNQRY catalog table. |
QUERY_HASH | CHAR(16) NOT NULL FOR BIT DATA | The hash key generated by the statement text. |
QUERY_HASH_VERSION | INTEGER NOT NULL | The version of QUERY_HASH. |
STABILIZED | CHAR(1) NOT NULL | Indicates whether the statement was stabilized. |
![]() ![]() |
![]() ![]() |
![]() ![]() |
CNO | BIGINT NOT NULL | The command number for the dynamic query capture monitor if applicable. Otherwise 0. |
STAT_SUS_CHILDLLOCK | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for child L-locks for the statement. |
STAT_SUS_OTHERLLOCK | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for other L-locks for the statement. |
STAT_SUS_PAGESETPLOCK | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for global pageset or partition L-locks for the statement. |
STAT_SUS_PAGEPLOCK | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for page P-locks for the statement. |
STAT_SUS_OTHERPLOCK | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for other P-locks for the statement. |
STAT_SUS_PIPE | FLOAT NOT NULL WITH DEFAULT | The accumulated wait time for pipe requests for the statement. |
STAT_SUS_PQSYNC | FLOAT NOT NULL WITH DEFAULT | The accumulated waittime for parallel query waits for the statement. |
STAT_ACC_TWDP | BIGINT | The accumulated wait time for the accelerator delay protocol. |
STAT_ACC_NWDP | BIGINT | The accumulated number of statements for which the wait time for the accelerator delay protocol has expired. |
STMT_HASHID2 | CHAR(8) FOR BIT DATA | Used to identify an SQL statement. Based on normalized SQL statement text.
|
STMT_HASH2VER | INTEGER | Used to identify the version of the hash algorithm that is used to compute the STMT_HASHID2 value. |
![]() ![]() |
![]() ![]() |
![]() ![]() |
AP_PLANHASH | CHAR(16) FOR BIT DATA | Used to identifier an access path based on selected columns of the PLAN_TABLE that contribute to the access path. This value excludes columns that do not affect the access path, such as APPLNAME, PROGNAME, VERSION, and others. |
AP_PLANHASHVER | INTEGER | Used to identify the version of the hash algorithm that is used to compute the AP_PLANHASH value. |
CONNECTION_TYPE | CHAR(8) | Connection type which did the PREPARE or BIND for the statement. |
CLIENT_USERID | VARCHAR(128) | The client user ID name information. |
CLIENT_APPLNAME | VARCHAR(255) | The client application name information. |
CLIENT_WRKSTNNAME | VARCHAR(255) | The client workstation name information. |
![]() ![]() |
![]() ![]() |
![]() ![]() |
- If the specified value exceeds 2147483647, the column contains the value 2147483647.
- Statistics are cumulative, across executions of the same statement, and across threads, if the value of COLLID is DSNDYNAMICSQLCACHE. If the value of COLLID is DSNEXPLAINMODEYES, the values are for a single run of the statement only. If the value of COLLID is DSNEXPLAINMODE EXPLAIN, the values of all statistics columns are 0.
- The column is not applicable when the value of the COLLID column is 'DSNEXPLAINMODEYES' or 'DSNEXPLAINMODEEXPLAIN'