Mohamed Houri’s Oracle Notes

June 19, 2013

Different sql id, different force matching signature, different rows processed with the same plan hash value

Filed under: explain plan — hourim @ 9:07 am

Very recently, two interesting blog articles, here and here, have been published to emphasize the possibility of having a same plan hash value for actually two different execution plans.

Since then, I started opening my eyes for any plan hash value that is shown for two or more execution plans. That’s way, the last week, when I was modeling an example for an outer join in response to a question that came up in the French forum, I was immediately attracted by the following sql I have engineered:

SQL> select
2             d.deptno
3            ,d.dname
4            ,e.hiredate
5      from
6            dept d, emp e
7      where
8            d.deptno = e.deptno(+)
9      AND EXISTS
10                 ( SELECT  NULL
11                   FROM    emp e2
12                   WHERE   e.deptno    = e2.deptno
13                   HAVING  MAX(e2.hiredate) = e.hiredate
14                  -- or e.hiredate is null
15                   )
16       ;

DEPTNO DNAME      HIREDATE
------ ---------- ---------
20    RESEARCH    12/01/83
30    SALES       03/12/81
10    ACCOUNTING  23/01/82

Plan hash value: 2339135578  --> note this plan hash value

PLAN_TABLE_OUTPUT
-----------------------------------------------------------------------------
| Id  | Operation            | Name | Starts | E-Rows | A-Rows |   A-Time   |
-----------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |      |      1 |        |      3 |00:00:00.01 |
|*  1 |  FILTER              |      |      1 |        |      3 |00:00:00.01 |
|*  2 |   HASH JOIN OUTER    |      |      1 |     14 |     15 |00:00:00.01 |
|   3 |    TABLE ACCESS FULL | DEPT |      1 |      4 |      4 |00:00:00.01 |
|   4 |    TABLE ACCESS FULL | EMP  |      1 |     14 |     14 |00:00:00.01 |
|*  5 |   FILTER             |      |     15 |        |      3 |00:00:00.01 |
|   6 |    SORT AGGREGATE    |      |     15 |      1 |     15 |00:00:00.01 |
|*  7 |     TABLE ACCESS FULL| EMP  |     15 |      5 |     70 |00:00:00.01 |
-----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter( IS NOT NULL)
2 - access("D"."DEPTNO"="E"."DEPTNO")
5 - filter(MAX("E2"."HIREDATE")=:B1) --> note this crucial point here
7 - filter("E2"."DEPTNO"=:B1)

And to this a little bit different sql:

SQL> select
2             d.deptno
3            ,d.dname
4            ,e.hiredate
5      from
6            dept d, emp e
7      where
8            d.deptno = e.deptno(+)
9      AND EXISTS
10            ( SELECT  NULL
11              FROM    emp e2
12              WHERE   e.deptno    = e2.deptno
13              HAVING  MAX(e2.hiredate) = e.hiredate
14              or e.hiredate is null  --> this part has been uncommented
15             )
16       ;

DEPTNO DNAME          HIREDATE
---------- -------------- --------
20 RESEARCH       12/01/83
30 SALES          03/12/81
10 ACCOUNTING     23/01/82
40 OPERATIONS

Plan hash value: 2339135578  --> the same plan hash value
-----------------------------------------------------------------------------
| Id  | Operation            | Name | Starts | E-Rows | A-Rows |   A-Time   |
-----------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |      |      1 |        |      4 |00:00:00.01 |
|*  1 |  FILTER              |      |      1 |        |      4 |00:00:00.01 |
|*  2 |   HASH JOIN OUTER    |      |      1 |     14 |     15 |00:00:00.01 |
|   3 |    TABLE ACCESS FULL | DEPT |      1 |      4 |      4 |00:00:00.01 |
|   4 |    TABLE ACCESS FULL | EMP  |      1 |     14 |     14 |00:00:00.01 |
|*  5 |   FILTER             |      |     15 |        |      4 |00:00:00.01 |
|   6 |    SORT AGGREGATE    |      |     15 |      1 |     15 |00:00:00.01 |
|*  7 |     TABLE ACCESS FULL| EMP  |     15 |      5 |     70 |00:00:00.01 |
-----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter( IS NOT NULL)
2 - access("D"."DEPTNO"="E"."DEPTNO")
5 - filter((MAX("E2"."HIREDATE")=:B1 OR :B2 IS NULL)) --> for a different predicate
7 - filter("E2"."DEPTNO"=:B1)

Well, nothing new per regard to the two related blog articles mentioned above.  However it is worth pointing out how two different sql_id with two different force matching signature and producing two different result sets, could end up sharing the same plan hash value of two execution plans differencing by their predicate part as shown below:

select
  sql_id
 ,child_number
 ,force_matching_signature
 ,rows_processed
 ,plan_hash_value
from
v$sql
where sql_text like '%MAX(e2.hiredate)%'
and   sql_text not like '%v$sql%';

SQL_ID        CHILD_NUMBER FORCE_MATCHING_SIGNATURE ROWS_PROCESSED PLAN_HASH_VALUE
------------- ------------ ------------------------ -------------- ---------------
ba39fv7txcsbk            0 6256287308517838235              4      2339135578
b2kggnvz02ctk            0 1563627505656661161              3      2339135578

In this context of plan hash value inspection, Carlos sierra from the Oracle support published a blog article showing that his sqltxplain tool has the ability to consider execution plan using not only the plan hash value but two additional pieces of information which are SQLT Plan Hash Value1 and SQLT Plan Hash Value2. The last information is related to the predicate part which is here the central point of difference between “my” two execution plans.

Well, why not try sqltxtract for this case using sql_id ba39fv7txcsbk (click on the picture to enlarge it)?

Plan hash value2

Spot how the sqltxtract module shows the presence of two execution plans having the same plan hash value (2339135578) but different plan hash value2(62199 and 22135). This plan hash value2 concerns a difference into the access and/or the filter predicates.

But wait, this doesn’t mean that the sql_id ba39fv7txcsbk has necessarily got two different execution plans. All what it clearly indicates is that the plan hash value of this parent sql_id has been seen two times, each time with a different access and/or filter predicates. This is confirmed by the sql scripts given by Carlos sierra which when applied to this particular case gives this:


SQL> start c:\psql_id
Enter value for sql_id: ba39fv7txcsbk

no rows selected

Meaning that this sql_id has not got a difference in the predicate part of its execution plan.


SQL> start c:\phash

Enter value for plan_hash_value: 2339135578

ID  TYPE     SQL_ID         CHILD_NUMBER  PREDICATES
---- -------- -------------- ------------- ------------------------------------------
5   filter  ba39fv7txcsbk    0             (MAX("E2"."HIREDATE")=:B1 OR :B2 IS NULL)
5   filter  b2kggnvz02ctk    0              MAX("E2"."HIREDATE")=:B1

Meaning that this plan_hash_value has got two execution plans having two different predicate parts for two different sql_ids

3 Comments »

  1. Mohamed,
    SQLT and SQLHC will be enhanced on their next release incorporating this issue as an “Observation”. In other words, if the SQL being analyzed has child cursors with same PHV but one or more predicates are different, then a health-check will report this finding as an observation.
    Cheers — Carllos

    Comment by Carlos Sierra — June 19, 2013 @ 9:41 am | Reply

  2. Hi Carlos,

    Thanks for your comment.

    Thanks also for the effort you’ve deployed to develop SQLT and to let us using it.

    Best regards

    Comment by hourim — June 19, 2013 @ 9:47 am | Reply

  3. […] I have already successfully installed SQLTXPLAIN on Oracle 11.2.0.1. My first work on SQLTXPLAIN was to go back to personal engineered performance problems ”traditionally” solved and ask myself  “What would I have pointed out using SQLTXPLAIN in such a performance issue?’’. Up to now this is my sole strategy of using this tool like what I have published here and here […]

    Pingback by SQLTXPLAIN under Oracle 12c | Mohamed Houri’s Oracle Notes — November 18, 2013 @ 8:15 am | Reply


RSS feed for comments on this post. TrackBack URI

Leave a comment

This site uses Akismet to reduce spam. Learn how your comment data is processed.

Blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud's blog

Just another blog : Databases, Linux and other stuffs

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)