Tales From A Lazy Fat DBA

Its all about Databases & their performance, troubleshooting & much more …. ¯\_(ツ)_/¯

HINT REPORT, a lesser known 19c enhancement to DBMS_XPLAN …

Posted by FatDBA on March 21, 2022

Oracle 19c has a great enhancement added to the DBMS_XPLAN package called the ‘Hint Usage Report’, which is pretty helpful in reporting if an incorrect hint was used, or there was any syntax error with the hint or if there was an unresolved hint used in the SQL.

This you can use with the DBMS_XPLAN package and its functions like DISPLAY, DISPLAY_CURSOR, DISPLAY_WORKLOAD_REPOSITORY or DISPLAY_SQL_PLAN_BASELINE. By default, DBMS_XPLAN in the default TYPICAL format will report only invalid hints. The report shows the text of the hints. The hint may also have one of the following annotations:

E : indicates a syntax error.
N : indicates an unresolved hint.
U : indicates that the corresponding hint was not used in the final plan.

Lets do some tests to understand it better. For our tests I have a test table created called BIGTAB and loaded it with sample data.
First case, I will try the PARALLEL_INDEX hint with one of the Index (non-partitioned) to see what the Hint Report says.

SQL> explain plan for select /*+ PARALLEL_INDEX(BIGTAB,WEIGHT_IDX,2) */ * from bigtab where weight between -168444405 and 639413572;

Explained.

SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY(FORMAT=>'TYPICAL'));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
Plan hash value: 441133017

----------------------------------------------------------------------------
| Id  | Operation         | Name   | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |        | 13613 |   252K|    70   (2)| 00:00:01 |
|*  1 |  TABLE ACCESS FULL| BIGTAB | 13613 |   252K|    70   (2)| 00:00:01 |
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------

   1 - filter("WEIGHT">=(-168444405) AND "WEIGHT"<=639413572)

Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 1 (U - Unused (1))
---------------------------------------------------------------------------

   1 -  SEL$1 / BIGTAB@SEL$1
         U -  PARALLEL_INDEX(BIGTAB,WEIGHT_IDX,4)

20 rows selected.

SQL> 

Here we are getting UNUSED (U) for PARALLEL_INDEX hint that we have used against index WEIGHT_INDEX, but it wasn’t honored because the PARALLEL_INDEX hint parallelizes an index range scan of a partitioned index. This is a common mistake with parallel_index hint is using it against a non-partitioned index, where it will be ignored.

Let me try the next case where I will make a syntax error with the hint INDEX, will pass it as INDEXX and see what the report says.

06:04:55 SQL>
06:04:55 SQL>
06:04:55 SQL> explain plan for select /*+ INDEXX(BIGTAB,WEIGHT_IDX) */ * from bigtab where weight between -168444405 and 639413572;

Explained.

Elapsed: 00:00:00.05
06:08:35 SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY(FORMAT=>'BASIC +HINT_REPORT'));

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 441133017

------------------------------------
| Id  | Operation         | Name   |
------------------------------------
|   0 | SELECT STATEMENT  |        |
|   1 |  TABLE ACCESS FULL| BIGTAB |
------------------------------------

Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 1 (E - Syntax error (1))
---------------------------------------------------------------------------

   1 -  SEL$1
         E -  INDEXX

15 rows selected.

Elapsed: 00:00:00.17
06:08:40 SQL>

And it says that there is was a syntax error (E) with the HINT, hence ignored by the optimizer.

Now, I will be trying a correct/valid hint with the SQL Statement and see what the hint report says about it.

SQL> explain plan for select /*+ INDEX(BIGTAB,WEIGHT_IDX) */ * from bigtab where weight between -168444405 and 639413572;

Explained.

SQL>

SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY(FORMAT=>'BASIC +HINT_REPORT'));

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2994241301

----------------------------------------------------------
| Id  | Operation                           | Name       |
----------------------------------------------------------
|   0 | SELECT STATEMENT                    |            |
|   1 |  TABLE ACCESS BY INDEX ROWID BATCHED| BIGTAB     |
|   2 |   INDEX RANGE SCAN                  | WEIGHT_IDX |
----------------------------------------------------------

Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 1
---------------------------------------------------------------------------

   1 -  SEL$1 / BIGTAB@SEL$1
           -  INDEX(BIGTAB,WEIGHT_IDX)

16 rows selected.

And the report says that no error was reported and hint was correctly used, same can be seen in the change of access path of the execution plan.

Next, let me try any optimizer related hint, I will try the optimizer_index_cost_adj HINT to make the SQL more or less index friendly

03:32:43 SQL> explain plan for select /*+ opt_param('optimizer_index_cost_adj',20) */ * from bigtab where weight between -168444405 and 639413572;

Explained.

Elapsed: 00:00:00.00
03:32:53 SQL> 

03:32:58 SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY(FORMAT=>'BASIC +HINT_REPORT'));

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 441133017

------------------------------------
| Id  | Operation         | Name   |
------------------------------------
|   0 | SELECT STATEMENT  |        |
|   1 |  TABLE ACCESS FULL| BIGTAB |
------------------------------------

Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 1
---------------------------------------------------------------------------

   0 -  STATEMENT
           -  opt_param('optimizer_index_cost_adj',20)

15 rows selected.

Elapsed: 00:00:00.02

And that worked too as no error or any status flag was reported in the hint report.

Next, I will try a non existing Index and will see what the report says about it.

SQL> explain plan for select /*+ INDEX(FATDBA_INDEX) */ * from bigtab where weight between -168444405 and 639413572;

Explained.

SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY(FORMAT=>'BASIC +HINT_REPORT'));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
Plan hash value: 441133017

------------------------------------
| Id  | Operation         | Name   |
------------------------------------
|   0 | SELECT STATEMENT  |        |
|   1 |  TABLE ACCESS FULL| BIGTAB |
------------------------------------

Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 1 (N - Unresolved (1))

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
---------------------------------------------------------------------------

   1 -  SEL$1
         N -  INDEX(FATDBA_INDEX)

15 rows selected.

SQL>

And the report says it was UNRESOLVED (N) as the Index doesn’t exists.

Let me try one more case where I will pass two bad or contradictory hints, will use both first_rows and all_rows together and will see what happens.

SQL> explain plan for select /*+ first_rows(1) all_rows */ * from BIGTAB;

Explained.

SQL> select * from dbms_xplan.display(format=>'basic +alias +hint_report');

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
Plan hash value: 441133017

------------------------------------
| Id  | Operation         | Name   |
------------------------------------
|   0 | SELECT STATEMENT  |        |
|   1 |  TABLE ACCESS FULL| BIGTAB |
------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------

   1 - SEL$1 / BIGTAB@SEL$1

Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 2 (U - Unused (2))
---------------------------------------------------------------------------

   0 -  STATEMENT
         U -  all_rows / hint conflicts with another in sibling query block
         U -  first_rows(1) / hint conflicts with another in sibling query block

21 rows selected.

SQL>

The preceding report shows that the all_rows and first_rows(1) CBO mode hints conflict with one other. As the First_rows attempts to optimize the query to get the very first row back to the client as fast as possible, whereas All_rows attempts to optimize the query to get the very last row as fast as possible.

Last example I will try to pass multiple hints where few of them will be valid and rest invalid. I will pass FULL & PARALLEL valid hints, and will use two INDEX unresolved hints and one UNRESOLVED hint of MERGE with query block.

SQL> explain plan for select /*+ FULL(bigtab) INDEX(WEIGHT_IDX) INDEX(ID_IDX) MERGE(@SEL$1) PARALLEL(2) */ * from bigtab where weight between -168444405 and 639413572;

Explained.

SQL> select * from dbms_xplan.display(format=>'basic +alias +hint_report');

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 305217024

-----------------------------------------
| Id  | Operation            | Name     |
-----------------------------------------
|   0 | SELECT STATEMENT     |          |
|   1 |  PX COORDINATOR      |          |
|   2 |   PX SEND QC (RANDOM)| :TQ10000 |
|   3 |    PX BLOCK ITERATOR |          |
|   4 |     TABLE ACCESS FULL| BIGTAB   |
-----------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

   1 - SEL$1
   4 - SEL$1 / BIGTAB@SEL$1

Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 5 (U - Unused (1), N - Unresolved (2))
---------------------------------------------------------------------------

   0 -  STATEMENT
           -  PARALLEL(2)

   1 -  SEL$1
         N -  INDEX(ID_IDX)
         N -  INDEX(WEIGHT_IDX)
         U -  MERGE(@SEL$1)

   4 -  SEL$1 / BIGTAB@SEL$1
           -  FULL(bigtab)

32 rows selected.

Hope It Helped!
Prashant Dixit

Advertisement

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Twitter picture

You are commenting using your Twitter account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

 
%d bloggers like this: