DB2 10.5 for Linux, UNIX, and Windows

SET CURRENT EXPLAIN MODE statement

The SET CURRENT EXPLAIN MODE statement changes the value of the CURRENT EXPLAIN MODE special register. It is not under transaction control.

Invocation

This statement can be embedded in an application program or issued interactively. It is an executable statement that can be dynamically prepared.

Authorization

None required.

Syntax

Read syntax diagramSkip visual syntax diagram
                             .-=-.   
>>-SET CURRENT EXPLAIN MODE -+---+------------------------------>

>--+-NO----------------------+---------------------------------><
   +-YES---------------------+   
   +-EXPLAIN--+--------+-----+   
   |          '-NORCAC-'     |   
   +-REOPT-------------------+   
   +-RECOMMEND INDEXES-------+   
   +-EVALUATE INDEXES--------+   
   +-RECOMMEND PARTITIONINGS-+   
   +-EVALUATE PARTITIONINGS--+   
   '-host-variable-----------'   

Description

NO
Disables the Explain facility. No Explain information is captured. NO is the initial value of the special register.
YES
Enables the Explain facility and causes Explain information to be inserted into the Explain tables for eligible dynamic SQL statements. All dynamic SQL statements are compiled and executed normally.
EXPLAIN
Enables the Explain facility and causes Explain information to be captured for any eligible dynamic SQL statement that is prepared. However, dynamic statements are not executed.
EXPLAIN NORCAC
Enables the Explain facility and causes Explain information to be captured for any eligible dynamic SQL statement that is prepared as if row or column access control (RCAC) was not activated. Dynamic statements are not executed. When this explain mode is set, explain facility would explain the plan as if RCAC was not present.
REOPT
Enables the Explain facility and causes Explain information to be captured for a static or dynamic SQL statement during statement reoptimization at execution time; that is, when actual values for the host variables, special registers, global variables, or parameter markers are available.
RECOMMEND INDEXES
Enables the SQL compiler to recommend indexes. All queries that are executed in this explain mode will populate the ADVISE_INDEX table with recommended indexes. In addition, Explain information will be captured in the Explain tables to reveal how the recommended indexes are used, but the statements are neither compiled nor executed.
EVALUATE INDEXES
Enables the SQL compiler to evaluate virtual recommended indexes for dynamic queries. Queries executed in this explain mode will be compiled and optimized using fabricated statistics based on the virtual indexes. The statements are not executed. The indexes to be evaluated are read from the ADVISE_INDEX table if the USE_INDEX column contains 'Y'. Existing non-unique indexes can also be ignored by setting the USE_INDEX column to 'I' and the EXISTS column to 'Y'. If a combination of USE_INDEX='I' and EXISTS='N' is given then index evaluation for the query will continue normally but the index in question will not be ignored.
RECOMMEND PARTITIONINGS
Specifies that the compiler is to recommend the best database partition for each table that is accessed by a specific query. The best database partitions are then written to an ADVISE_PARTITION table. The query is not executed.
EVALUATE PARTITIONINGS
Specifies that the compiler is to obtain the estimated performance of a query using the virtual database partitions specified in the ADVISE_PARTITION table.
host-variable
The host-variable must be of data type CHAR or VARCHAR and the length must not exceed 254. If a longer field is provided, an error will be returned (SQLSTATE 42815). The value specified must be NO, YES, EXPLAIN, RECOMMEND INDEXES, or EVALUATE INDEXES. If the actual value provided is larger than the replacement value specified, the input must be padded on the right with blanks. Leading blanks are not allowed (SQLSTATE 42815). All input values are treated as being case-insensitive. If a host-variable has an associated indicator variable, the value of that indicator variable must not indicate a null value (SQLSTATE 42815).

Notes

Example

The following statement sets the CURRENT EXPLAIN MODE special register, so that Explain information will be captured for any subsequent eligible dynamic SQL statements and the statement will not be executed.
   SET CURRENT EXPLAIN MODE = EXPLAIN