Database monitor performance analysis example 3

Your next step may include further analysis of the table scan data. The previous examples contained a column titled Index Advised. A 'Y' (yes) in this column is a hint from the query optimizer that the query may perform better with an index to access the data. For the queries where an index is advised, notice that the rows selected by the query are low in comparison to the total number of rows in the table. This is another indication that a table scan may not be optimal. Finally, a long execution time may highlight queries that may be improved by performance tuning.

The next logical step is to look into the index advised optimizer hint. The following query can be used for this:

SELECT A.System_Table_Schema, A.System_Table_Name, 
     A.Index_Advised, A.Index_Advised_Columns, 
     A.Index_Advised_Columns_Count, B.Open_Id, 
     C.Statement_Text_Long 
   FROM LIB/QQQ3000 A INNER JOIN LIB/QQQ3014 B 
     ON (A.Join_Column = B.Join_Column AND 
     A.Unique_Count = B.Unique_Count) 
     LEFT OUTER JOIN LIB/QQQ1000 C 
     ON (A.Join_Column = C.Join_Column AND 
     A.Unique_Count = C.Unique_Count) 
   WHERE A.Index_Advised = 'Y'

There are two slight modifications from the first example. First, the selected columns have been changed. Most important is the selection of column Index_Advised_Columns that contains a list of possible key columns to use when creating the index suggested by the query optimizer. Second, the query selection limits the output to those table scan queries where the optimizer advises that an index be created (A.Index_Advised = 'Y'). The table below shows what the results might look like.

Table 1. Output with Recommended Key Columns
Lib Name Table Name Index Advised Advised Key columns Advised Primary Key Query OPNID Statement Text
LIB1 TBL1 Y FLD1 1  
SELECT * FROM LIB1/TBL1
WHERE FLD1 = 'A'
LIB1 TBL1 Y FLD1, FLD2 1  
SELECT * FROM LIB1/TBL1
WHERE FLD1 = 'B' AND
FLD2 > 9000
LIB1 TBL4 Y FLD1, FLD4 1 QRY04  

At this point you should determine whether it makes sense to create a permanent index as advised by the optimizer. In this example, creating one index over LIB1/TBL1 satisfies all three queries since each use a primary or left-most key column of FLD1. By creating one index over LIB1/TBL1 with key columns FLD1, FLD2, there is potential to improve the performance of the second query even more. The frequency these queries are run and the overhead of maintaining an additional index over the table should be considered when deciding whether to create the suggested index.

If you create a permanent index over FLD1, FLD2 the next sequence of steps is as follows:

  1. Start the performance monitor again
  2. Re-run the application
  3. End the performance monitor
  4. Re-evaluate the data.

It is likely that the three index-advised queries are no longer performing table scans.