Mohamed Houri’s Oracle Notes

February 5, 2023

SPM baseline and historical execution plans

Filed under: Oracle — hourim @ 8:33 am

I have often wondered why when we consult a past execution plan that is protected by an SPM baseline, there is no Note at the bottom of that execution plan showing the use of that SPM?

SQL> select banner_full from v$version;

BANNER_FULL
------------------------------------------------------------------------
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0                                                                 

SQL> select count(1) from emp where deptno=30;

  COUNT(1)
----------
         6

SQL> select * from table(dbms_xplan.display_cursor)

SQL_ID  89mvrxmzsd1v3, child number 1
-------------------------------------
Plan hash value: 2083865914
-------------------------------------------
| Id  | Operation          | Name | Rows  |
-------------------------------------------
|   0 | SELECT STATEMENT   |      |       |
|   1 |  SORT AGGREGATE    |      |     1 |
|*  2 |   TABLE ACCESS FULL| EMP  |     6 |
-------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("DEPTNO"=30)

Note
-----
   - SQL plan baseline SQL_PLAN_1vbjb8bc7qryjc392520a used for this statement


exec dbms_workload_repository.add_colored_sql('89mvrxmzsd1v3');
exec dbms_workload_repository.create_snapshot;

SQL> select * from table(dbms_xplan.display_awr('89mvrxmzsd1v3')); --> please note: display_awr


SQL_ID 89mvrxmzsd1v3
--------------------
Plan hash value: 2083865914
-------------------------------------------
| Id  | Operation          | Name | Rows  |
-------------------------------------------
|   0 | SELECT STATEMENT   |      |       |
|   1 |  SORT AGGREGATE    |      |     1 |
|   2 |   TABLE ACCESS FULL| EMP  |     6 |
-------------------------------------------

--> There is no Note on SPM

There is good news. Starting with 21c this has been corrected by Oracle. Here is the demonstration:

SQL> select banner_full from v$version;

BANNER_FULL
------------------------------------------------------------------------
Oracle Database 21c Enterprise Edition Release 21.0.0.0.0 - Production
Version 21.3.0.0.0                                                                  

SQL> select count(1) from emp where deptno=30;

  COUNT(1)
----------
         6

SQL> select * from table(dbms_xplan.display_cursor);


SQL_ID  89mvrxmzsd1v3, child number 1
-------------------------------------
select count(1) from emp where deptno=30

Plan hash value: 2083865914

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |       |       |     3 (100)|          |
|   1 |  SORT AGGREGATE    |      |     1 |     3 |            |          |
|*  2 |   TABLE ACCESS FULL| EMP  |     6 |    18 |     3   (0)| 00:00:01 |
---------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("DEPTNO"=30)

Note
-----
   - SQL plan baseline SQL_PLAN_1vbjb8bc7qryjc392520a used for this statement


exec dbms_workload_repository.add_colored_sql('89mvrxmzsd1v3');
exec dbms_workload_repository.create_snapshot;

SQL> select * from table(dbms_xplan.display_awr('89mvrxmzsd1v3')); --> please note: display_awr

SQL_ID 89mvrxmzsd1v3
--------------------
select count(1) from emp where deptno=30

Plan hash value: 2083865914
-------------------------------------------
| Id  | Operation          | Name | Rows  |
-------------------------------------------
|   0 | SELECT STATEMENT   |      |       |
|   1 |  SORT AGGREGATE    |      |     1 |
|*  2 |   TABLE ACCESS FULL| EMP  |     6 |
-------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("DEPTNO"=30)

Note
-----
   - SQL plan baseline "SQL_PLAN_1vbjb8bc7qryjc392520a" used for this statement

This is the first time if my memory doesn’t fail me, that I see this Note on an SPM baseline appearing at the bottom of an execution plan coming from AWR. This becomes possible because Oracle has finally enriched the other_xml column of dba_hist_sql_plan with the SPM baseline information as shown below:

SQL> select banner_full from v$version;

BANNER_FULL
----------------------------------------------------------------------
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SELECT
     p.sql_id
    ,p.plan_hash_value
    ,t.spm_baseline
FROM   
  dba_hist_sql_plan p
 ,xmltable('for $i in /other_xml/info
               where $i/@type eq "baseline"
               return $i'
               passing xmltype(p.other_xml)
               columns spm_baseline varchar2(100) path '/') t
 WHERE p.sql_id = '89mvrxmzsd1v3'
 and   p.other_xml is not null;

no rows selected


SQL> select banner_full from v$version;

BANNER_FULL
-----------------------------------------------------------------------
Oracle Database 21c Enterprise Edition Release 21.0.0.0.0 - Production
Version 21.3.0.0.0

SELECT
     p.sql_id
    ,p.plan_hash_value
    ,t.spm_baseline
FROM   
  dba_hist_sql_plan p
 ,xmltable('for $i in /other_xml/info
               where $i/@type eq "baseline"
               return $i'
               passing xmltype(p.other_xml)
               columns spm_baseline varchar2(100) path '/') t
 WHERE p.sql_id = '89mvrxmzsd1v3'
 and   p.other_xml is not null;

SQL_ID        PLAN_HASH_VALUE SPM_BASELINE
------------- --------------- -----------------------------------
89mvrxmzsd1v3      2083865914 "SQL_PLAN_1vbjb8bc7qryjc392520a"

I remind for those who are not yet in 21c, that they can use Dom Brooks’s script to track the use of SPM in AWR

SQL> select banner_full from v$version;

BANNER_FULL
----------------------------------------------------------------------
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> @wasSPMUsed19c
Enter value for sql_id: 89mvrxmzsd1v3

   SNAP_ID DT                         SQL_ID        PLAN_HASH_VALUE       PHV2        SIG D I WHEN_BASELINE_CREATED
---------- -------------------------- ------------- --------------- ---------- ---------- - - --------------------------
      2241 04-FEB-2023 16:54          89mvrxmzsd1v3      2083865914 3281146378 2,1387E+18 Y Y 04-FEB-2023 16:52

Create a free website or 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)