Mohamed Houri’s Oracle Notes

March 25, 2017

De-Correlated Lateral view: VW_DCL_mmm

Filed under: Oracle — hourim @ 5:18 pm

Oracle Cost Based Optimizer has a number of query rewrites and transformations both simple and complex, old and new. Wether you know very few of them or only the most common ones, I believe it is worth keeping yourself well updated with the new ones as it might introduce strange performance issue like the one I have encountered very recently. This new 12c transformation I want to explain here is known as De-Correlated Lateral view. It appears in execution plans as VW_DCL_mmm. This article examines this transformation in the context of a real life production query.

A critical query, executed several hundred of thousands of times within a two hours batch job consumes 67K of Logical I/O per execution. It made the job systematically fail with a time out error. The average execution time of this query being less than one second, I ruled out the possibility of using SQL monitoring report to spot where most of these Logical I/O are coming from. Hopefully the high number of times this query is launched during the batch job makes its activity sampled into ASH. As such, via the following simple query I knew exactly at which operations of the corresponding execution plan this query is spending most of its time and resource:

select
   sql_plan_line_id
  ,count(1)
from
   gv$active_session_history
where
 sample_time between to_date('22032017 23:00:18', 'ddmmyyyy hh24:mi:ss')
             and     to_date('22032017 23:50:18', 'ddmmyyyy hh24:mi:ss')
and
 sql_id = '94jkz74mvwmbj'
group by
   sql_plan_line_id
order by 2 desc;

SQL_PLAN_LINE_ID   COUNT(1)
---------------- ----------
              48         41
              47         9
	          11         8
              30         1
SQL> select * from table(dbms_xplan.display_curosr('94jkz74mvwmbj'));                                                                              
----------------------------------------------------------------          
| Id  | Operation                     | Name            | Rows  |                
-----------------------------------------------------------------                                                                                   
|*  11|  HASH JOIN OUTER              |                 |      3|     
|   12|  NESTED LOOP OUTER            |                 |      3|                                           
|   33|   TABLE ACCESS BY INDEX ROWID | T1              |      1|  
|*  34|   INDEX UNIQUE SCAN           | T1_PK           |      1|           
|   47|  VIEW                         | VW_DCL_52812513 |  5340K|                                           
|*  48|    TABLE ACCESS FULL          | T2              |  5340K|                                           
-----------------------------------------------------------------         

Reduced to the bare minimum, the above execution plan is the result of a left outer join between table T1 and table T2 using a primary-foreign key relationship (predicate n°11) and a mix of an OR and an AND predicate applied on table T2 (operation n° 48). We will see later in this article that the two bolded words above represent the key words of a Lateral View.

As per regards to the real life query I was practically sure that a NESTED LOOP with table T1 as the outer row source probing the inner row source via an existing foreign key index will end up by filtering table T2 using the OR and the AND predicate but only on the rows that survived the primary-foreign key join.

But what the heck is this VW_DCL_52812513 view? It is useless to say that I didn’t find any related information both using Google and MyOracle Support.

After a couple of hour of investigation at the client site I ended up finding a work around and pushed an urgent fix into PRODUCTION. Notice with me how the fix has transformed the statistics of this query and its batch job:

SQL> @sqlstats.sql 
Enter value for sql_id:  94jkz74mvwmbj

CHILD_NUMBER SQL_PROFILE                   PLAN_HASH_VALUE  AVG_GETS  EXECS
----------- ------------------------------ --------------- ---------- ------
4                                           1521027974       66288     1976  → old execution plan
6           PROFILE_94jkz74mvwmbj_MANUAL     553415384          90    10092  → new execution plan

In order to definitely understand this new transformation and share it with you I’ve engineered the following model:

Setting the Scenes

create table t1
as
 with generator as (
   select --+ materialize
      rownum id
   from dual
   connect by level <= 1000
)
select
    rownum id1,
    mod(rownum-1,2) flag1,
    mod(rownum-1,3) flag2,
    rownum          n1,
    lpad(rownum,30) v1
from
   generator v1,
   generator v2
where
   rownum <= 1e4;
   
alter table t1 add constraint t1_pk primary key (id1);

create table t2
as 
 select
    level id1
   ,trunc((rownum+2)/2) product_t1
   ,date '2012-06-07' + mod((level-1)*5,10) + interval '5' minute start_date
   ,date '2012-06-08' + mod((level-1)*5,10) + interval '5' minute end_date
   ,rpad('xx',10) padding
from
   dual
connect by level <=1e4;

alter table t2 add constraint t2_pk primary key (id1);
alter table t2 add constraint t2_t1_fk foreign key (product_t1) references t1(id1);

-- creating an index covering the FK deadlock threat and other business requirements
create index idx_t2_usr_1 on t2(product_t1, start_date);

Here’s below the query (and its execution plan) with which I have reproduced the interesting part of the client’s real life query:

explain plan for
select
   t1.*
  ,t2.*
from
   t1
left outer join
   t2
on
  (t1.id1 = t2.product_t1
  and
     (t2.start_date <= :1 and t2.end_date >= :2
        or (t2.id1 > 100)
     )
  );

SQL> select * from table(dbms_xplan.display);                                                                                                  
-------------------------------------------------------                                           
| Id  | Operation           | Name            | Rows  |                                           
------------------------------------------------------                                           
|   0 | SELECT STATEMENT    |                 | 14925 |                                           
|*  1 |  HASH JOIN OUTER    |                 | 14925 |                                             
|   2 |   TABLE ACCESS FULL | T1              | 10000 |                                           
|   3 |   VIEW              | VW_DCL_C83A7ED5 |  9926 |                                           
|*  4 |    TABLE ACCESS FULL| T2              |  9926 |                                           
------------------------------------------------------                                           
                                                                                                                                  
Predicate Information (identified by operation id):                                                                               
---------------------------------------------------                                                                                                                                                                                         
   1 - access("T1"."ID1"="ITEM_2"(+))                                                                                             
   4 - filter("T2"."ID1">100 OR "T2"."START_DATE"<=:1 
         AND "T2"."END_DATE">=:2) 

Spot again how the predicate part can be so crucial to indicate the way you should pursue when troubleshooting query performance issues:

Predicate Information (identified by operation id):                                                                               
--------------------------------------                                                                                                                                                                                        
   1 - access("T1"."ID1"="ITEM_2"(+))                

While I recognize the (+) symbol as the Oracle way of re-architecting and ANSI outer join, I admit that I have no idea what the heck is this ITEM_2 in predicate n°1?

When all else fails then a 10053 trace file might help

alter session set tracefile_identifier='VW_DCL_MHO_XXXX';
alter session set events '10053 trace name context forever, level 1';
explain plan for
select
   t1.*
  ,t2.*
from
   t1
left outer join
   t2
on
  (t1.id1 = t2.product_t1
  and
     (t2.start_date <= :1 and t2.end_date >= :2
        or (t2.id1 > 100)
     )
  );
alter session set events '10053 trace name context off';           

Digging a little bit into the generated trace file I found that Oracle has transformed the original query into the following one:

SELECT 
  t1.id1 id1,
  t1.flag1 flag1,
  t1.flag2 flag2,
  t1.n1 n1,
  t1.v1 v1,
  vw_dcl_1b0973d4.item_1 id1,
  vw_dcl_1b0973d4.item_2 product_t1,
  vw_dcl_1b0973d4.item_3 start_date,
  vw_dcl_1b0973d4.item_4 end_date,
  vw_dcl_1b0973d4.item_5 padding
FROM c##mhouri.t1 t1,
  (SELECT 
    t2.id1 item_1_0,
    t2.product_t1 item_2_1,
    t2.start_date item_3_2,
    t2.end_date item_4_3,
    t2.padding item_5_4
  FROM c##mhouri.t2 t2
  WHERE t2.start_date<=:b1 AND t2.end_date >=:b2
  OR t2.id1           >100
  ) VW_DCL_1B0973D4
WHERE t1.id1=VW_DCL_1B0973D4.item_2(+) 

Simply put Oracle did two things:
1. Created a Lateral view
2. De-Correlated this lateral view by excluding the join predicate with table T1 from the Lateral view

This is clearly backed up by the following lines in the same trace file

DCL: Checking validity of lateral view decorrelation SEL$BCD4421C (#1)
DCL: Passed decorrelation validity for lateral view block SEL$BCD4421C (#1)
DCL: Decorrelation of lateral view query block SEL$BCD4421C (#1).
Registered qb: SEL$6226B99A 0x693ad4d0 (VIEW DECORRELATED SEL$BCD4421C; SEL$BCD4421C)

Since I have finally succeeded to understand what this transformation is I knew what else I have to do:

explain plan for
select /*+ optimizer_features_enable('11.2.0.4') */
   t1.*
  ,t2.*
from
   t1
left outer join
   t2
on
  (t1.id1 = t2.product_t1
  and
     (t2.start_date <= :1 and t2.end_date >= :2
        or (t2.id1 > 100)
     )
  );

SQL> select * from table(dbms_xplan.display);                                                                                                                                                                                                       
--------------------------------------------------------------                       
| Id  | Operation                     | Name         | Rows  |                                   
--------------------------------------------------------------                                   
|   0 | SELECT STATEMENT              |              | 10000 |                                   
|   1 |  NESTED LOOPS OUTER           |              | 10000 |                                   
|   2 |   TABLE ACCESS FULL           | T1           | 10000 |                                   
|   3 |   VIEW                        |              |     1 |                                   
|*  4 |    TABLE ACCESS BY INDEX ROWID| T2           |     1 |                                   
|*  5 |     INDEX RANGE SCAN          | IDX_T2_USR_1 |     1 |                                   
--------------------------------------------------------------                                   
                                                                                                                                  
Predicate Information (identified by operation id):                                                                               
---------------------------------------------------                                                                                                                                                                                                           
   4 - filter("T2"."ID1">100 OR "T2"."START_DATE"<=:1 AND "T2"."END_DATE">=:2)                                                    
   5 - access("T1"."ID1"="T2"."PRODUCT_T1")                   

This exactly what I was expecting at the beginning of my investigations. Annihilating the effect of the de-correlated lateral view will open a much better path at least for my real life query case.

Summary

As of now I hope that this article can help identifying what a VW_DCL_mmm transformation is. I hope as well that google will hist this article when asked about this particular transformation.

March 18, 2017

12cR2: SPM and cursor bind awareness property

Filed under: Oracle — hourim @ 7:24 am

In the previous article we knew that, as of Oracle 12cR2, it is now possible to capture SPM baselined plans from AWR historical tables. In this article we are going to see how in 12cR2 a cursor will immediately stop to be bind aware when it is protected by a single SPM plan. The basic idea driving this new implementation is that, since the Adaptive Cursor Sharing main goal is to generate multiple optimal execution plans, if you decide to constrain it with a single SPM plan, you are implicitly asking Oracle to stop generating multiple execution plans.

Let’s demonstrate this new ACS-SPM relationship using the same model as that of the preceding article

Setting the Scenes

create table t_acs(n1 number, n2 number);

BEGIN
 for j in 1..1200150 loop
  if j = 1 then
    insert into t_acs values (j, 1);
  elsif j>1 and j<=101 then
    insert into t_acs values(j, 100);
  elsif j>101 and j<=1101 then
    insert into t_acs values (j, 1000);
  elsif j>10001 and j<= 110001 then
    insert into t_acs values(j,10000); 
  else
    insert into t_acs values(j, 1000000); end if;
 end loop; 
commit;
END;
/

create index t_acs_i1 on t_acs(n2);

BEGIN 
  dbms_stats.gather_table_stats
     (user
     ,'t_acs'
     ,method_opt => 'for all columns size skewonly' 
     ,cascade => true
     ,estimate_percent => dbms_stats.auto_sample_size );
END; 
/

var ln2 number;
exec :ln2 := 100
select count(1) from t_acs where n2 = :ln2;

exec :ln2 := 1e6
select count(1) from t_acs where n2 = :ln2;
select count(1) from t_acs where n2 = :ln2;

exec :ln2 := 100
select count(1) from t_acs where n2 = :ln2;


Observation

The execution of the above script will end up by producing two bind sensitive, bind aware and shareable cursors as shown below:

select 
    sql_id
  ,child_number
  ,is_bind_sensitive 
  ,is_bind_aware
  ,executions
from
   v$sql 
where
   sql_id = 'f2pmwazy1rnfd'
and is_shareable = 'Y';

SQL_ID        CHILD_NUMBER I I EXECUTIONS
------------- ------------ - - ----------
f2pmwazy1rnfd            1 Y Y          1 → full scan plan
f2pmwazy1rnfd            2 Y Y          1 → index range scan plan

So far so good.
What if I decide to create a SPM execution plan in order to constrain the above query to use always the index range scan plan?

SQL> alter session set optimizer_capture_sql_plan_baselines = TRUE;

SQL> select count(1) from t_acs where n2 = :ln2;

  COUNT(1)
----------
       100

SQL> select count(1) from t_acs where n2 = :ln2;

  COUNT(1)
----------
       100

SQL> alter session set optimizer_capture_sql_plan_baselines = FALSE;

SQL> col plan_name format a40
SQL> select 
        plan_name ,origin, accepted, enabled
     from dba_sql_plan_baselines;

PLAN_NAME                        ORIGIN          ACC ENA
------------------------------- ---------------- --- ---
SQL_PLAN_fn4mhg52jx5z125348c47  AUTO-CAPTURE     YES YES

As such the next time I will run this query it will use the index range scan SPM baselined plan as shown below:

SQL> select count(1) from t_acs where n2 = :ln2;

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

SQL_ID  f2pmwazy1rnfd, child number 1                                                                                                                                              
-------------------------------------                                                                                                                                                                                                                                                                                                                                                                                                                                                                      
Plan hash value: 1882749816                                                                                                                                                                                                                                                                                                                                    
----------------------------------------------                                                                                                    
| Id  | Operation         | Name     | Rows  |                                                                                                   
----------------------------------------------                                                                                                    
|   0 | SELECT STATEMENT  |          |       |                                                                                                    
|   1 |  SORT AGGREGATE   |          |     1 |                                                                                                     
|*  2 |   INDEX RANGE SCAN| T_ACS_I1 |   100 |                                                                                                  
----------------------------------------------                                                                                                    
                                                                                                                                                                                   
Predicate Information (identified by operation id):                                                                                                                                
---------------------------------------------------                                                                                                                                                                                                                                                                                              
   2 - access("N2"=:LN2)                                                                                                                                                           
                                                                                                                                                                                   
Note                                                                                                                                                                               
-----                                                                                                                                                                              
- SQL plan baseline SQL_PLAN_fn4mhg52jx5z125348c47 used for this statement  

But what you might ignore is that, following the creation of this SPM baselined plan, Oracle did something behind the scene as shown via the following cursor new situation:

select 
    sql_id
  ,child_number
  ,is_bind_sensitive 
  ,is_bind_aware
  ,executions
from
   v$sql 
where
   sql_id = 'f2pmwazy1rnfd'
and is_shareable = 'Y';

SQL_ID        CHILD_NUMBER I I EXECUTIONS
------------- ------------ - - ----------
f2pmwazy1rnfd            1 N N          1

If you analyze carefully the new situation compared to the old one you will realize that the following actions have been done behind the scenes

1. The previous child cursors n°1 and n°2 has been flushed out.
2. A new no bind sensitive and no bind aware child cursor n°1 has been created

It is the number of execution (only 1) of child cursor n°1 which clearly explains that the previous two bind aware cursors have been flushed out from memory due to the new SPM baselined plan. The child cursor n°0 is still in the shared pool but is in a non shareable status.

SQL> select 
        sql_id
      ,child_number
      ,is_bind_sensitive 
      ,is_bind_aware
      ,is_shareable
      ,executions
    from
       v$sql 
   where
      sql_id = 'f2pmwazy1rnfd';

SQL_ID        CHILD_NUMBER I I I EXECUTIONS
------------- ------------ - - - ----------
f2pmwazy1rnfd            0 Y N N          2 → non shareable
f2pmwazy1rnfd            1 N N Y          1

That’s the new 12cR2 implementation managing the relationship between ACS and SPM. ACS is disabled when it is constrained by a single accepted and enabled SPM plan.

If we disable the previous SPM baseline the cursor becomes bind aware after a warm up period as usual

SQL> @disSPM.sql 
Enter value for plan_name: SQL_PLAN_fn4mhg52jx5z125348c47

SQL> select 
          plan_name ,origin, enabled
      from dba_sql_plan_baselines;

PLAN_NAME                       ORIGIN       ENA
------------------------------- ------------ ---
SQL_PLAN_fn4mhg52jx5z125348c47  AUTO-CAPTURE NO 

exec :ln2 :=1e6
select count(1) from t_acs where n2 = :ln2;

exec :ln2 := 100
select count(1) from t_acs where n2 = :ln2;

etc…./...

SQL> select 
        sql_id
      ,child_number
      ,is_bind_sensitive 
      ,is_bind_aware
      ,is_shareable
      ,executions
    from
       v$sql 
   where
      sql_id = 'f2pmwazy1rnfd'
  ;

SQL_ID        CHILD_NUMBER I I I EXECUTIONS
------------- ------------ - - - ----------
f2pmwazy1rnfd            0 Y N N          2
f2pmwazy1rnfd            1 Y N N          3
f2pmwazy1rnfd            2 Y Y Y          1 → bind aware full scan
f2pmwazy1rnfd            3 Y Y Y          1 → bind aware range scan

Summary

As of Oracle 12cR2 when an ACS cursor having multiple optimal execution plans is constrained by a single enabled and accepted SPM plan, Oracle will age it out from memory and cancel its bind sensitive and bind aware properties. This will remain intact until the SPM is dropped or disabled. In the next article we will see what happens to an ACS cursor when one of its multiple accepted and enabled SPM plan is rendered unreproducible.

March 17, 2017

12cR2 : Capturing SPM plans from AWR

Filed under: Oracle,Sql Plan Managment — hourim @ 6:45 pm

A couple of years ago I set myself a best practice goal of preferring SPM baselines over SQL-Profiles. I must recognize that I failed to achieve this goal. Fortunately as of Oracle 12cR2 it becomes possible to load SPM baselined plans directly from AWR tables. This is why I am now unexcused to do not operate the switch.

Let’s see first how we can load SPM plans using AWR historical tables

Setting the Scenes

create table t_acs(n1 number, n2 number);

BEGIN
 for j in 1..1200150 loop
  if j = 1 then
    insert into t_acs values (j, 1);
  elsif j>1 and j<=101 then
    insert into t_acs values(j, 100);
  elsif j>101 and j<=1101 then
    insert into t_acs values (j, 1000);
  elsif j>10001 and j<= 110001 then
    insert into t_acs values(j,10000); 
  else
    insert into t_acs values(j, 1000000); end if;
 end loop; 
commit;
END;
/

create index t_acs_i1 on t_acs(n2);

BEGIN 
  dbms_stats.gather_table_stats
     (user
     ,'t_acs'
     ,method_opt => 'for all columns size skewonly' 
     ,cascade => true
     ,estimate_percent => dbms_stats.auto_sample_size );
END; 
/

exec dbms_workload_repository.create_snapshot;
var ln2 number;
exec :ln2 := 100
select count(1) from t_acs where n2 = :ln2;

exec :ln2 := 1e6
select count(1) from t_acs where n2 = :ln2;
select count(1) from t_acs where n2 = :ln2;

exec :ln2 := 100
select count(1) from t_acs where n2 = :ln2;

exec dbms_workload_repository.create_snapshot;

If you copy and past the above SQL code into a SQL PLUS session and issue the following select you should find that you have already two bind aware cursors:

select 
    sql_id
  ,child_number
  ,is_bind_sensitive 
  ,is_bind_aware
  ,executions
from
   v$sql 
where
   sql_id = 'f2pmwazy1rnfd'
and is_shareable = 'Y';

SQL_ID        CHILD_NUMBER I I EXECUTIONS
------------- ------------ - - ----------
f2pmwazy1rnfd            1 Y Y          1
f2pmwazy1rnfd            2 Y Y          1

The bind awareness property of the above cursor has nothing to do with the bottom line of this article. It is here just because I will use the same model in my next article where this time this particular property becomes necessary.

If I would have decided to create a SQL profile over the above cursor I would have then opted for Carlos Sierra coe_xfr_sql_profile.sql script as shown below:

SQL> @coe_xfr_sql_profile.sql

Parameter 1:
SQL_ID (required)

Enter value for 1: f2pmwazy1rnfd


PLAN_HASH_VALUE AVG_ET_SECS
--------------- -----------
      535703726 ,054       
     1882749816 ,085       

Parameter 2:
PLAN_HASH_VALUE (required)

Enter value for 2: 1882749816

Values passed:
~~~~~~~~~~~~~
SQL_ID         : "f2pmwazy1rnfd"
PLAN_HASH_VALUE: "1882749816"

Execute coe_xfr_sql_profile_f2pmwazy1rnfd_1882749816.sql
on TARGET system in order to create a custom SQL Profile
with plan 1882749816 linked to adjusted sql_text.

SQL>@coe_xfr_sql_profile_f2pmwazy1rnfd_1882749816.sql
... manual custom SQL Profile has been created

COE_XFR_SQL_PROFILE_f2pmwazy1rnfd_1882749816 completed

As such the next time I will run this query it will use the fixed SQL Profile as shown below:

SQL> select count(1) from t_acs where n2 = :ln2;

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

Plan hash value: 1882749816                                                     
                                                                                
------------------------------------------------------ 
| Id  | Operation         | Name     | Rows  | Bytes |  
------------------------------------------------------ 
|   0 | SELECT STATEMENT  |          |       |       |  
|   1 |  SORT AGGREGATE   |          |     1 |     3 |   
|*  2 |   INDEX RANGE SCAN| T_ACS_I1 |   100 |   300 |  
------------------------------------------------------
                                                                                
Predicate Information (identified by operation id):                             
---------------------------------------------------                                                                                         
   2 - access("N2"=:LN2)                                                        
                                                                                
Note                                                                            
-----                                                                           
- SQL profile coe_f2pmwazy1rnfd_1882749816 used for this statement

However until the arrival of 12cR2 it was impossible to load a SPM plan baseline for the above cursor using corresponding AWR historical execution plan. Hopefully it is now possible. This is below how to capture SPM plan from AWR:

SQL>@LoadSPMfromAwr.sql
Listing latest AWR snapshots ...

   SNAP_ID END_INTERVAL_TIME          
---------- ---------------------------
        14 08/03/17 13:20:09,251000000
        15 08/03/17 14:00:13,233000000
        16 08/03/17 15:07:46,465000000
        17 09/03/17 01:13:41,092000000
        18 09/03/17 12:11:26,748000000
        19 10/03/17 01:07:36,836000000
        20 10/03/17 10:08:54,214000000
        21 10/03/17 12:35:26,590000000
        22 11/03/17 01:04:40,947000000
        23 12/03/17 12:41:35,578000000
        24 12/03/17 15:03:55,730000000
        25 13/03/17 02:21:01,517000000
        26 13/03/17 12:53:22,204000000
        27 13/03/17 15:43:46,522000000
        28 14/03/17 13:13:07,716000000
        29 15/03/17 12:55:54,089000000
        30 16/03/17 12:59:39,201000000
        31 17/03/17 02:09:14,047000000
        32 17/03/17 10:38:33,520000000
        33 17/03/17 12:50:59,072000000

20 rows selected. 

Enter begin snapshot id: 14
Enter end   snapshot id: 27
Enter value for sql_filter: sql_text like ''select count(1) from t_acs%''

SQL> select 
      plan_name ,origin
    from dba_sql_plan_baselines;

PLAN_NAME                                ORIGIN                       
---------------------------------------- ---------------------
SQL_PLAN_fn4mhg52jx5z125348c47           MANUAL-LOAD-FROM-AWR         
SQL_PLAN_fn4mhg52jx5z13069e6f9           MANUAL-LOAD-FROM-AWR   


SQL> select count(1) from t_acs where n2 = :ln2;

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


SQL_ID  f2pmwazy1rnfd, child number 1
-------------------------------------
select count(1) from t_acs where n2 = :ln2
 
Plan hash value: 1882749816
 
------------------------------------------------------
| Id  | Operation         | Name     | Rows  | Bytes | 
------------------------------------------------------
|   0 | SELECT STATEMENT  |          |       |       |
|   1 |  SORT AGGREGATE   |          |     1 |     3 | 
|*  2 |   INDEX RANGE SCAN| T_ACS_I1 |   100 |   300 | 
-------------------------------------------------------
 
Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("N2"=:LN2)
 
Note
-----
   - SQL profile coe_f2pmwazy1rnfd_1882749816 used for this statement
   - SQL plan baseline SQL_PLAN_fn4mhg52jx5z125348c47 used for this statement

You have to choose the snap interval that includes historical details of your sql_id

Here’s below the content of the script I used to capture SPM plan from AWR

PROMPT Listing latest AWR snapshots ...
SELECT snap_id, end_interval_time 
FROM dba_hist_snapshot 
WHERE end_interval_time > SYSDATE - 30
ORDER BY end_interval_time;

ACCEPT bsnapid NUMBER PROMPT "Enter begin snapshot id: "
ACCEPT esnapid NUMBER PROMPT "Enter end   snapshot id: "

SET TERMOUT OFF PAGESIZE 0 HEADING OFF LINESIZE 1000 TRIMSPOOL ON TRIMOUT ON TAB OFF

declare
  rs pls_integer;
begin
  rs := dbms_spm.load_plans_from_awr('&bsnapid', '&esnapid', '&sql_filter');
end;
/

SET TERMOUT ON PAGESIZE 5000 HEADING ON

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)