diff --git a/optimizer/spm_fix/README.md b/optimizer/spm_fix/README.md
new file mode 100644
index 00000000..3cbc5d74
--- /dev/null
+++ b/optimizer/spm_fix/README.md
@@ -0,0 +1,41 @@
+This demo shows you how you can use SQL plan management (SPM) to fix a SQL statement that is experiencing a performance regression caused by a sub-optimal plan.
+
+SPM will search for historic plans, choose the best one and enforce it with a SQL plan baseline.
+
+This demonstration is intended for use in Oracle Database 18c onwards. The primary script is "spm.sql", which demonstrates how to use SPM to find and implement a better plan.
+
+Create the user, create the tables and then run "example.sql". It works as follows:
+
+- Tables T1 and T2 have data skew
+- Q1 is a query that joins T1 and T2
+- Histograms tell the optimizer about the skew so Q1 performs well
+- We drop the histograms and this induces a poor plan for Q1
+- SPM is initiated and it finds the previous good plan
+- The good plan is tested (automatically) by SPM and a SQL plan baseline is created
+- Q1 now uses the good plan
+
+```
+$ sqlplus / as sysdba [or connect to PDB ADMIN]
+SQL> @@user
+SQL> connect spmdemo/spmdemo
+--
+-- Create test tables
+--
+SQL> @@tab
+--
+-- Review/execute the following script
+--
+SQL> @@example
+```
+
+Note that AWR is accessed. Check the Oracle Database License Guide for details.
+
+The test creates two tables T1 and T2 - use a test database
+
+DISCLAIMER:
+
-- These scripts are provided for educational purposes only.
+
-- They are NOT supported by Oracle World Wide Technical Support.
+
-- The scripts have been tested and they appear to work as intended.
+
-- You should always run scripts on a test instance.
+
+
diff --git a/optimizer/spm_fix/drop.sql b/optimizer/spm_fix/drop.sql
new file mode 100644
index 00000000..a272c6ea
--- /dev/null
+++ b/optimizer/spm_fix/drop.sql
@@ -0,0 +1,15 @@
+DECLARE
+ l_plans_dropped PLS_INTEGER;
+BEGIN
+
+ FOR REC IN (SELECT DISTINCT SQL_HANDLE FROM DBA_SQL_PLAN_BASELINES )
+-- WHERE CREATOR = 'SPMDEMO')
+ LOOP
+ L_PLANS_DROPPED := DBMS_SPM.DROP_SQL_PLAN_BASELINE (
+ sql_handle => rec.sql_handle,
+ PLAN_NAME => NULL);
+ END LOOP;
+
+END;
+/
+
diff --git a/optimizer/spm_fix/droph.sql b/optimizer/spm_fix/droph.sql
new file mode 100644
index 00000000..82859358
--- /dev/null
+++ b/optimizer/spm_fix/droph.sql
@@ -0,0 +1,3 @@
+set echo on
+exec dbms_stats.delete_column_stats(user,'t1','d',no_invalidate=>false,col_stat_type=>'HISTOGRAM');
+exec dbms_stats.delete_column_stats(user,'t2','d',no_invalidate=>false,col_stat_type=>'HISTOGRAM');
diff --git a/optimizer/spm_fix/example.lst b/optimizer/spm_fix/example.lst
new file mode 100644
index 00000000..0f0f5080
--- /dev/null
+++ b/optimizer/spm_fix/example.lst
@@ -0,0 +1,529 @@
+SQL> @example
+Connected.
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.01
+
+ SUM(T1.C) SUM(T2.C)
+---------- ----------
+ 250001 250001
+
+Elapsed: 00:00:00.22
+
+PLAN_TABLE_OUTPUT
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+SQL_ID 0ptw8zskuh9r4, child number 2
+-------------------------------------
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where
+ t1.a = t2.a and t1.d = 10
+
+Plan hash value: 3534348942
+
+--------------------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
+--------------------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | | | 560 (100)| |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+| 2 | NESTED LOOPS | | 2 | 44 | 560 (2)| 00:00:01 |
+| 3 | NESTED LOOPS | | 2 | 44 | 560 (2)| 00:00:01 |
+|* 4 | TABLE ACCESS FULL | T1 | 2 | 26 | 554 (2)| 00:00:01 |
+|* 5 | INDEX RANGE SCAN | T2I | 1 | | 2 (0)| 00:00:01 |
+| 6 | TABLE ACCESS BY INDEX ROWID| T2 | 1 | 9 | 3 (0)| 00:00:01 |
+--------------------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+---------------------------------------------------
+
+ 4 - filter("T1"."D"=10)
+ 5 - access("T1"."A"="T2"."A")
+
+
+25 rows selected.
+
+Elapsed: 00:00:00.05
+
+ SUM(T1.C) SUM(T2.C)
+---------- ----------
+ 1 1
+
+Elapsed: 00:00:00.01
+
+PLAN_TABLE_OUTPUT
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+SQL_ID 7455bm00pr945, child number 1
+-------------------------------------
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where
+ t1.a = t2.a and t1.d = 1000
+
+Plan hash value: 3534348942
+
+--------------------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
+--------------------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | | | 560 (100)| |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+| 2 | NESTED LOOPS | | 2 | 44 | 560 (2)| 00:00:01 |
+| 3 | NESTED LOOPS | | 2 | 44 | 560 (2)| 00:00:01 |
+|* 4 | TABLE ACCESS FULL | T1 | 2 | 26 | 554 (2)| 00:00:01 |
+|* 5 | INDEX RANGE SCAN | T2I | 1 | | 2 (0)| 00:00:01 |
+| 6 | TABLE ACCESS BY INDEX ROWID| T2 | 1 | 9 | 3 (0)| 00:00:01 |
+--------------------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+---------------------------------------------------
+
+ 4 - filter("T1"."D"=1000)
+ 5 - access("T1"."A"="T2"."A")
+
+
+25 rows selected.
+
+Elapsed: 00:00:00.03
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.40
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:19.99
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.27
+SQL> exec dbms_stats.delete_column_stats(user,'t1','d',no_invalidate=>false,col_stat_type=>'HISTOGRAM');
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.00
+SQL> exec dbms_stats.delete_column_stats(user,'t2','d',no_invalidate=>false,col_stat_type=>'HISTOGRAM');
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.01
+SQL> --
+SQL> -- Q1 now uses a NL JOIN, which in this case is bad because of data skew
+SQL> -- The query has experienced a performance regression
+SQL> --
+SQL> @@q1
+SQL> set timing on
+SQL> --
+SQL> -- The adaptive plan feature can potentially avoid performance regressions
+SQL> -- associate with the wrong join type being chosen, so we are going to disable it because
+SQL> -- we WANT to induce a performance regression for SPM to fix.
+SQL> --
+SQL> --
+SQL> -- Literals are used rather than bind variables to
+SQL> -- avoid adaptive cursor sharing from changing the plan
+SQL> --
+SQL>
+SQL> select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c)
+ 2 from t1, t2
+ 3 where t1.a = t2.a
+ 4 and t1.d = 10;
+
+ SUM(T1.C) SUM(T2.C)
+---------- ----------
+ 250001 250001
+
+Elapsed: 00:00:00.20
+SQL>
+SQL> @plan
+SQL> set linesize 250
+SQL> set trims on
+SQL> set tab off
+SQL> set tab off
+SQL> set pagesize 1000
+SQL> column plan_table_output format a180
+SQL>
+SQL> SELECT *
+ 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'TYPICAL'));
+
+PLAN_TABLE_OUTPUT
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+SQL_ID 0ptw8zskuh9r4, child number 3
+-------------------------------------
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where
+ t1.a = t2.a and t1.d = 10
+
+Plan hash value: 3534348942
+
+--------------------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
+--------------------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | | | 560 (100)| |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+| 2 | NESTED LOOPS | | 2 | 44 | 560 (2)| 00:00:01 |
+| 3 | NESTED LOOPS | | 2 | 44 | 560 (2)| 00:00:01 |
+|* 4 | TABLE ACCESS FULL | T1 | 2 | 26 | 554 (2)| 00:00:01 |
+|* 5 | INDEX RANGE SCAN | T2I | 1 | | 2 (0)| 00:00:01 |
+| 6 | TABLE ACCESS BY INDEX ROWID| T2 | 1 | 9 | 3 (0)| 00:00:01 |
+--------------------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+---------------------------------------------------
+
+ 4 - filter("T1"."D"=10)
+ 5 - access("T1"."A"="T2"."A")
+
+
+25 rows selected.
+
+Elapsed: 00:00:00.04
+SQL>
+SQL> --
+SQL> -- Now 'repair' the plan - SPM will find the better plan in AWR,
+SQL> -- test execute it and then create a SQL plan baseline to enforce it
+SQL> --
+SQL> -- Automatic SQL Plan management will look in AWR for resource-intensive
+SQL> -- SQL so it is capable of finding our regressed plan automatically.
+SQL> --
+SQL> -- But in this case, the DBA has to identify the long-running SQL statement
+SQL> -- by SQL ID and Plan Hash Value. However, once this has been done, SPM will
+SQL> -- locate, test and apply the better plan automatically.
+SQL> --
+SQL> --
+SQL> @@spm
+SQL> var rep clob
+SQL> set linesize 250
+SQL> set pagesize 10000
+SQL> set trims on
+SQL> set tab off
+SQL> set long 1000000
+SQL> column report format a200
+SQL> set echo on
+SQL>
+SQL> exec select '' into :rep from dual;
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.00
+SQL>
+SQL> --
+SQL> -- This example assumes that you have the bad plan in the
+SQL> -- cursor cache but this is not essential. Take a look
+SQL> -- at the documentation for DBMS_SPM because there are a
+SQL> -- large number of options for creating the initial SQL plan
+SQL> -- baseline. Also, you might even have a SQL plan baseline already.
+SQL> --
+SQL> -- The example SQL ID hard coded in this example
+SQL> --
+SQL>
+SQL> set linesize 100
+SQL> set trims on
+SQL> set tab off
+SQL> set pagesize 1000
+SQL> column plan_table_output format 95
+SQL>
+SQL> var childid varchar2(100)
+SQL> var childnum number
+SQL> --
+SQL> -- The SQL_ID of our SQL statement
+SQL> --
+SQL> exec :childid := '0ptw8zskuh9r4';
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.00
+SQL>
+SQL> exec select max(child_number) into :childnum from v$sql where sql_id = :childid;
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.00
+SQL>
+SQL> SELECT *
+ 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'BASIC', SQL_ID=>:childid, cursor_child_no=>:childnum));
+
+PLAN_TABLE_OUTPUT
+----------------------------------------------------------------------------------------------------
+EXPLAINED SQL STATEMENT:
+------------------------
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where
+ t1.a = t2.a and t1.d = 10
+
+Plan hash value: 3534348942
+
+----------------------------------------------
+| Id | Operation | Name |
+----------------------------------------------
+| 0 | SELECT STATEMENT | |
+| 1 | SORT AGGREGATE | |
+| 2 | NESTED LOOPS | |
+| 3 | NESTED LOOPS | |
+| 4 | TABLE ACCESS FULL | T1 |
+| 5 | INDEX RANGE SCAN | T2I |
+| 6 | TABLE ACCESS BY INDEX ROWID| T2 |
+----------------------------------------------
+
+
+19 rows selected.
+
+Elapsed: 00:00:00.04
+SQL>
+SQL> accept myphv char prompt 'Enter the plan hash value of the bad NL plan (above): '
+Enter the plan hash value of the bad NL plan (above): 3534348942
+SQL>
+SQL> DECLARE
+ 2 tname varchar2(1000);
+ 3 ename varchar2(1000);
+ 4 n number;
+ 5 sig number;
+ 6 sqlid varchar2(1000) := :childid;
+ 7 phv number := &myphv;
+ 8 handle varchar2(1000);
+ 9 nc number;
+ 10 BEGIN
+ 11 select count(*) into nc
+ 12 from v$sql
+ 13 where sql_id = sqlid
+ 14 and plan_hash_value = phv;
+ 15
+ 16 if (nc = 0)
+ 17 then
+ 18 raise_application_error(-20001, 'The SQL_ID/PHV combination not found in V$SQL');
+ 19 end if;
+ 20
+ 21 select exact_matching_signature into sig
+ 22 from v$sqlarea
+ 23 where sql_id = sqlid;
+ 24
+ 25 -- Enabled=NO because we will assume that this is a bad plan
+ 26
+ 27 n := dbms_spm.load_plans_from_cursor_cache(
+ 28 sql_id => sqlid,
+ 29 plan_hash_value=> phv,
+ 30 enabled => 'no');
+ 31
+ 32 select distinct sql_handle
+ 33 into handle
+ 34 from dba_sql_plan_baselines
+ 35 where signature = sig;
+ 36
+ 37 tname := DBMS_SPM.CREATE_EVOLVE_TASK(sql_handle=>handle);
+ 38
+ 39 DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ 40 task_name => tname,
+ 41 parameter => 'ALTERNATE_PLAN_BASELINE',
+ 42 value => 'EXISTING');
+ 43
+ 44 --
+ 45 -- You can use CURSOR_CACHE+SQL_TUNING_SET+AUTOMATIC_WORKLOAD_REPOSITORY
+ 46 -- if you have the Oracle Tuning and Oracle Diagnostic Packs.
+ 47 -- See Oracle License Guide for details.
+ 48 --
+ 49 DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ 50 task_name => tname,
+ 51 parameter => 'ALTERNATE_PLAN_SOURCE',
+ 52 value => 'CURSOR_CACHE+AUTOMATIC_WORKLOAD_REPOSITORY');
+ 53
+ 54 DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ 55 task_name => tname,
+ 56 parameter => 'ALTERNATE_PLAN_LIMIT',
+ 57 value => 'UNLIMITED');
+ 58
+ 59 ename := DBMS_SPM.EXECUTE_EVOLVE_TASK(tname);
+ 60
+ 61 n := DBMS_SPM.IMPLEMENT_EVOLVE_TASK(tname);
+ 62
+ 63 select DBMS_SPM.REPORT_EVOLVE_TASK(task_name=>tname) into :rep from dual;
+ 64 END;
+ 65 /
+old 7: phv number := &myphv;
+new 7: phv number := 3534348942;
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:02.71
+SQL>
+SQL> set echo off
+Note!
+Take a look at the following report to confirm that the previous plan
+passes the performance criteria to be accepted.
+Be aware that on some systems the difference may not be significant
+enough to warrant acceptance of the SQL plan baseline.
+If this happens in your case, you should increase the number of rows
+in the test tables to boost the performance difference between
+the nested loop and hash join versions of the test query.
+
+REPORT
+----------------------------------------------------------------------------------------------------
+GENERAL INFORMATION SECTION
+---------------------------------------------------------------------------------------------
+
+ Task Information:
+ ---------------------------------------------
+ Task Name : TASK_296
+ Task Owner : SPMDEMO
+ Execution Name : EXEC_366
+ Execution Type : SPM EVOLVE
+ Scope : COMPREHENSIVE
+ Status : COMPLETED
+ Started : 10/07/2019 03:53:27
+ Finished : 10/07/2019 03:53:29
+ Last Updated : 10/07/2019 03:53:29
+ Global Time Limit : 2147483646
+ Per-Plan Time Limit : UNUSED
+ Number of Errors : 0
+---------------------------------------------------------------------------------------------
+
+SUMMARY SECTION
+---------------------------------------------------------------------------------------------
+ Number of plans processed : 1
+ Number of findings : 1
+ Number of recommendations : 1
+ Number of errors : 0
+---------------------------------------------------------------------------------------------
+
+DETAILS SECTION
+---------------------------------------------------------------------------------------------
+ Object ID : 2
+ Test Plan Name : SQL_PLAN_2jnv3vhwv9nsnc6a45b88
+ Base Plan Name : Cost-based plan
+ SQL Handle : SQL_28d363dc39b4d314
+ Parsing Schema : SPMDEMO
+ Test Plan Creator : SYS
+ SQL Text : select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from
+ t1, t2 where t1.a = t2.a and t1.d = 10
+
+Execution Statistics:
+-----------------------------
+ Base Plan Test Plan
+ ---------------------------- ----------------------------
+ Elapsed Time (s): .043147 .012352
+ CPU Time (s): .041965 .01203
+ Buffer Gets: 2215 439
+ Optimizer Cost: 560 1109
+ Disk Reads: 0 0
+ Direct Writes: 0 0
+ Rows Processed: 0 0
+ Executions: 5 9
+
+
+FINDINGS SECTION
+---------------------------------------------------------------------------------------------
+
+Findings (1):
+-----------------------------
+ 1. The plan was verified in 2.08500 seconds. It passed the benefit criterion
+ because its verified performance was 2.80103 times better than that of the
+ baseline plan.
+
+Recommendation:
+-----------------------------
+ Consider accepting the plan. Execute
+ dbms_spm.accept_sql_plan_baseline(task_name => 'TASK_296', object_id => 2,
+ task_owner => 'SPMDEMO');
+
+
+EXPLAIN PLANS SECTION
+---------------------------------------------------------------------------------------------
+
+Baseline Plan
+-----------------------------
+ Plan Id : 2303
+ Plan Hash Value : 3467815966
+
+---------------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost | Time |
+---------------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | 1 | 22 | 560 | 00:00:01 |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+| 2 | NESTED LOOPS | | 2 | 44 | 560 | 00:00:01 |
+| 3 | NESTED LOOPS | | 2 | 44 | 560 | 00:00:01 |
+| * 4 | TABLE ACCESS FULL | T1 | 2 | 26 | 554 | 00:00:01 |
+| * 5 | INDEX RANGE SCAN | T2I | 1 | | 2 | 00:00:01 |
+| 6 | TABLE ACCESS BY INDEX ROWID | T2 | 1 | 9 | 3 | 00:00:01 |
+---------------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+------------------------------------------
+* 4 - filter("T1"."D"=10)
+* 5 - access("T1"."A"="T2"."A")
+
+Hint Report (identified by operation id / Query Block Name / Object Alias):
+Total hints for statement: 1 (U - Unused (1))
+-------------------------------------------------------------------------------
+
+ 0 - STATEMENT
+ U - NO_ADAPTIVE_PLAN / rejected by IGNORE_OPTIM_EMBEDDED_HINTS
+
+Test Plan
+-----------------------------
+ Plan Id : 2304
+ Plan Hash Value : 3332660104
+
+---------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost | Time |
+---------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | 1 | 22 | 1109 | 00:00:01 |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+| * 2 | HASH JOIN | | 2 | 44 | 1109 | 00:00:01 |
+| * 3 | TABLE ACCESS FULL | T1 | 2 | 26 | 554 | 00:00:01 |
+| 4 | TABLE ACCESS FULL | T2 | 500000 | 4500000 | 552 | 00:00:01 |
+---------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+------------------------------------------
+* 2 - access("T1"."A"="T2"."A")
+* 3 - filter("T1"."D"=10)
+
+Hint Report (identified by operation id / Query Block Name / Object Alias):
+Total hints for statement: 1 (U - Unused (1))
+-------------------------------------------------------------------------------
+
+ 0 - STATEMENT
+ U - NO_ADAPTIVE_PLAN / rejected by IGNORE_OPTIM_EMBEDDED_HINTS
+---------------------------------------------------------------------------------------------
+
+
+Elapsed: 00:00:00.00
+
+ SUM(T1.C) SUM(T2.C)
+---------- ----------
+ 250001 250001
+
+Elapsed: 00:00:00.13
+
+PLAN_TABLE_OUTPUT
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+SQL_ID 0ptw8zskuh9r4, child number 3
+-------------------------------------
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where
+ t1.a = t2.a and t1.d = 10
+
+Plan hash value: 906334482
+
+----------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
+----------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | | | 1109 (100)| |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+|* 2 | HASH JOIN | | 2 | 44 | 1109 (2)| 00:00:01 |
+|* 3 | TABLE ACCESS FULL| T1 | 2 | 26 | 554 (2)| 00:00:01 |
+| 4 | TABLE ACCESS FULL| T2 | 500K| 4394K| 552 (2)| 00:00:01 |
+----------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+---------------------------------------------------
+
+ 2 - access("T1"."A"="T2"."A")
+ 3 - filter("T1"."D"=10)
+
+Hint Report (identified by operation id / Query Block Name / Object Alias):
+Total hints for statement: 1 (U - Unused (1))
+---------------------------------------------------------------------------
+
+ 0 - STATEMENT
+ U - NO_ADAPTIVE_PLAN / rejected by IGNORE_OPTIM_EMBEDDED_HINTS
+
+Note
+-----
+ - SQL plan baseline SQL_PLAN_2jnv3vhwv9nsnc6a45b88 used for this statement
+
+
+34 rows selected.
+
+Elapsed: 00:00:00.03
+SQL> spool off
diff --git a/optimizer/spm_fix/example.sql b/optimizer/spm_fix/example.sql
new file mode 100644
index 00000000..3500dad9
--- /dev/null
+++ b/optimizer/spm_fix/example.sql
@@ -0,0 +1,53 @@
+connect spmdemo/spmdemo
+--
+-- Drop existing SQL plan baselines to reset test
+--
+@@drop
+--
+-- Observe the correct HASH JOIN plan because of data skew
+--
+@@q1
+--
+-- Observe the correct NL JOIN plan for this predicate
+--
+@@q2
+--
+-- Run the testq1 multiple times and capture in AWR
+-- Assuming a SQL Disagnostics Pack licence.
+--
+-- We could also load Q1 into a SQL Tuning Set because
+-- this source is also searched by SPM for previous plans.
+-- SQL tuning sets required a SQL Tuning Pack licence.
+--
+@@q1many
+--
+-- Induce a bad plan for Q1 by dropping the histograms
+-- so that the optimizer is no longer aware of skew
+--
+@@droph
+--
+-- Q1 now uses a NL JOIN, which in this case is bad because of data skew
+-- The query has experienced a performance regression
+--
+@@q1
+--
+-- Now 'repair' the plan - SPM will find the better plan in AWR,
+-- test execute it and then create a SQL plan baseline to enforce it
+--
+-- Automatic SQL Plan management will look in AWR for resource-intensive
+-- SQL so it is capable of finding our regressed plan automatically.
+--
+-- But in this case, the DBA has to identify the long-running SQL statement
+-- by SQL ID and Plan Hash Value. However, once this has been done, SPM will
+-- locate, test and apply the better plan automatically.
+--
+--
+@@spm
+--
+-- Observe the HASH JOIN plan enforced by a SQL plan baseline
+--
+@@q1
+--
+-- The "pawr.sql" scipt is provided to purge AWR snapshots if
+-- you want to run multiple tests and 'reset' AWR in between.
+--
diff --git a/optimizer/spm_fix/gatherh.sql b/optimizer/spm_fix/gatherh.sql
new file mode 100644
index 00000000..1bcf8c77
--- /dev/null
+++ b/optimizer/spm_fix/gatherh.sql
@@ -0,0 +1,5 @@
+--
+-- Gather statistics with histograms
+--
+exec dbms_stats.gather_table_stats(user,'t1',method_opt=>'for all columns size 254',no_invalidate=>false)
+exec dbms_stats.gather_table_stats(user,'t2',method_opt=>'for all columns size 254',no_invalidate=>false)
diff --git a/optimizer/spm_fix/pawr.sql b/optimizer/spm_fix/pawr.sql
new file mode 100644
index 00000000..2359c835
--- /dev/null
+++ b/optimizer/spm_fix/pawr.sql
@@ -0,0 +1,4 @@
+select snap_id,to_char(begin_interval_time,'YYYY-DD-MM HH24:MI')
+from dba_hist_snapshot order by 1;
+
+exec dbms_workload_repository.drop_snapshot_range(low_snap_id => &low, high_snap_id=>&hi);
diff --git a/optimizer/spm_fix/plan.sql b/optimizer/spm_fix/plan.sql
new file mode 100644
index 00000000..1bc66e2b
--- /dev/null
+++ b/optimizer/spm_fix/plan.sql
@@ -0,0 +1,9 @@
+set linesize 250
+set trims on
+set tab off
+set tab off
+set pagesize 1000
+column plan_table_output format a180
+
+SELECT *
+FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'TYPICAL'));
diff --git a/optimizer/spm_fix/q1.lst b/optimizer/spm_fix/q1.lst
new file mode 100644
index 00000000..782cac40
--- /dev/null
+++ b/optimizer/spm_fix/q1.lst
@@ -0,0 +1,61 @@
+SQL> @q1
+SQL> set timing on
+SQL> --
+SQL> -- The adaptive plan feature can potentially avoid performance regressions
+SQL> -- associate with the wrong join type being chosen, so we are going to disable it because
+SQL> -- we WANT to induce a performance regression for SPM to fix.
+SQL> --
+SQL>
+SQL> select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c)
+ 2 from t1, t2
+ 3 where t1.a = t2.a
+ 4 and t1.d = 10;
+
+ SUM(T1.C) SUM(T2.C)
+---------- ----------
+ 500001 500001
+
+Elapsed: 00:00:00.22
+SQL>
+SQL> @plan
+SQL> set linesize 250
+SQL> set trims on
+SQL> set tab off
+SQL> set tab off
+SQL> set pagesize 1000
+SQL> column plan_table_output format a180
+SQL>
+SQL> SELECT *
+ 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'TYPICAL'));
+
+PLAN_TABLE_OUTPUT
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+SQL_ID 0ptw8zskuh9r4, child number 2
+-------------------------------------
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where
+ t1.a = t2.a and t1.d = 10
+
+Plan hash value: 906334482
+
+------------------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time |
+------------------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | | | | 3778 (100)| |
+| 1 | SORT AGGREGATE | | 1 | 22 | | | |
+|* 2 | HASH JOIN | | 495K| 10M| 11M| 3778 (1)| 00:00:01 |
+|* 3 | TABLE ACCESS FULL| T1 | 493K| 6264K| | 1099 (1)| 00:00:01 |
+| 4 | TABLE ACCESS FULL| T2 | 1000K| 8789K| | 1095 (1)| 00:00:01 |
+------------------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+---------------------------------------------------
+
+ 2 - access("T1"."A"="T2"."A")
+ 3 - filter("T1"."D"=10)
+
+
+23 rows selected.
+
+Elapsed: 00:00:00.46
+SQL>
+SQL> spool off
diff --git a/optimizer/spm_fix/q1.sql b/optimizer/spm_fix/q1.sql
new file mode 100644
index 00000000..f3b251bc
--- /dev/null
+++ b/optimizer/spm_fix/q1.sql
@@ -0,0 +1,18 @@
+set timing on
+--
+-- The adaptive plan feature can potentially avoid performance regressions
+-- associate with the wrong join type being chosen, so we are going to disable it because
+-- we WANT to induce a performance regression for SPM to fix.
+--
+--
+-- Literals are used rather than bind variables to
+-- avoid adaptive cursor sharing from changing the plan
+--
+
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c)
+from t1, t2
+where t1.a = t2.a
+and t1.d = 10;
+
+@plan
+
diff --git a/optimizer/spm_fix/q1_fixed.lst b/optimizer/spm_fix/q1_fixed.lst
new file mode 100644
index 00000000..08112fc3
--- /dev/null
+++ b/optimizer/spm_fix/q1_fixed.lst
@@ -0,0 +1,49 @@
+SQL> @@q1
+
+ SUM(T1.C) SUM(T2.C)
+---------- ----------
+ 250001 250001
+
+Elapsed: 00:00:00.12
+
+PLAN_TABLE_OUTPUT
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+SQL_ID 0ptw8zskuh9r4, child number 3
+-------------------------------------
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where
+ t1.a = t2.a and t1.d = 10
+
+Plan hash value: 906334482
+
+----------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
+----------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | | | 1109 (100)| |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+|* 2 | HASH JOIN | | 2 | 44 | 1109 (2)| 00:00:01 |
+|* 3 | TABLE ACCESS FULL| T1 | 2 | 26 | 554 (2)| 00:00:01 |
+| 4 | TABLE ACCESS FULL| T2 | 500K| 4394K| 552 (2)| 00:00:01 |
+----------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+---------------------------------------------------
+
+ 2 - access("T1"."A"="T2"."A")
+ 3 - filter("T1"."D"=10)
+
+Hint Report (identified by operation id / Query Block Name / Object Alias):
+Total hints for statement: 1 (U - Unused (1))
+---------------------------------------------------------------------------
+
+ 0 - STATEMENT
+ U - NO_ADAPTIVE_PLAN / rejected by IGNORE_OPTIM_EMBEDDED_HINTS
+
+Note
+-----
+ - SQL plan baseline SQL_PLAN_2jnv3vhwv9nsnc6a45b88 used for this statement
+
+
+34 rows selected.
+
+Elapsed: 00:00:00.04
+SQL> spool off
diff --git a/optimizer/spm_fix/q1_poor.lst b/optimizer/spm_fix/q1_poor.lst
new file mode 100644
index 00000000..7073b766
--- /dev/null
+++ b/optimizer/spm_fix/q1_poor.lst
@@ -0,0 +1,63 @@
+SQL> @q1
+SQL> set timing on
+SQL> --
+SQL> -- The adaptive plan feature can potentially avoid performance regressions
+SQL> -- associate with the wrong join type being chosen, so we are going to disable it because
+SQL> -- we WANT to induce a performance regression for SPM to fix.
+SQL> --
+SQL>
+SQL> select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c)
+ 2 from t1, t2
+ 3 where t1.a = t2.a
+ 4 and t1.d = 10;
+
+ SUM(T1.C) SUM(T2.C)
+---------- ----------
+ 500001 500001
+
+Elapsed: 00:00:00.34
+SQL>
+SQL> @plan
+SQL> set linesize 250
+SQL> set trims on
+SQL> set tab off
+SQL> set tab off
+SQL> set pagesize 1000
+SQL> column plan_table_output format a180
+SQL>
+SQL> SELECT *
+ 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'TYPICAL'));
+
+PLAN_TABLE_OUTPUT
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+SQL_ID 0ptw8zskuh9r4, child number 3
+-------------------------------------
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where
+ t1.a = t2.a and t1.d = 10
+
+Plan hash value: 3534348942
+
+--------------------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
+--------------------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | | | 1105 (100)| |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+| 2 | NESTED LOOPS | | 2 | 44 | 1105 (1)| 00:00:01 |
+| 3 | NESTED LOOPS | | 2 | 44 | 1105 (1)| 00:00:01 |
+|* 4 | TABLE ACCESS FULL | T1 | 2 | 26 | 1099 (1)| 00:00:01 |
+|* 5 | INDEX RANGE SCAN | T2I | 1 | | 2 (0)| 00:00:01 |
+| 6 | TABLE ACCESS BY INDEX ROWID| T2 | 1 | 9 | 3 (0)| 00:00:01 |
+--------------------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+---------------------------------------------------
+
+ 4 - filter("T1"."D"=10)
+ 5 - access("T1"."A"="T2"."A")
+
+
+25 rows selected.
+
+Elapsed: 00:00:00.12
+SQL>
+SQL> spool off
diff --git a/optimizer/spm_fix/q1a.sql b/optimizer/spm_fix/q1a.sql
new file mode 100644
index 00000000..c45be04b
--- /dev/null
+++ b/optimizer/spm_fix/q1a.sql
@@ -0,0 +1,14 @@
+set autotrace on statistics
+set timing on
+--
+-- The adaptive plan feature can potentially avoid performance regressions
+-- associate with the wrong join type being chosen, so we are going to disable it because
+-- we WANT to induce a performance regression for SPM to fix.
+--
+
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c)
+from t1, t2
+where t1.a = t2.a
+and t1.d = 10;
+
+set autotrace off
diff --git a/optimizer/spm_fix/q1many.lst b/optimizer/spm_fix/q1many.lst
new file mode 100644
index 00000000..a488bd44
--- /dev/null
+++ b/optimizer/spm_fix/q1many.lst
@@ -0,0 +1,29 @@
+SQL> @q1many
+SQL> @@snap
+SQL> EXEC DBMS_WORKLOAD_REPOSITORY.create_snapshot;
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:01.01
+SQL> declare
+ 2 n1 number(10);
+ 3 n2 number(10);
+ 4 begin
+ 5 for i in 1..100
+ 6 loop
+ 7 execute immediate
+ 8 'select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where t1.a = t2.a and t1.d = 10' into n1,n2;
+ 9 end loop;
+ 10 end;
+ 11 /
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:14.85
+SQL> @@snap
+SQL> EXEC DBMS_WORKLOAD_REPOSITORY.create_snapshot;
+
+PL/SQL procedure successfully completed.
+
+Elapsed: 00:00:00.48
+SQL> spool off
diff --git a/optimizer/spm_fix/q1many.sql b/optimizer/spm_fix/q1many.sql
new file mode 100644
index 00000000..bdd3b9b1
--- /dev/null
+++ b/optimizer/spm_fix/q1many.sql
@@ -0,0 +1,13 @@
+@@snap
+declare
+ n1 number(10);
+ n2 number(10);
+begin
+ for i in 1..100
+ loop
+ execute immediate
+ 'select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from t1, t2 where t1.a = t2.a and t1.d = 10' into n1,n2;
+ end loop;
+end;
+/
+@@snap
diff --git a/optimizer/spm_fix/q2.sql b/optimizer/spm_fix/q2.sql
new file mode 100644
index 00000000..b0e0081a
--- /dev/null
+++ b/optimizer/spm_fix/q2.sql
@@ -0,0 +1,9 @@
+set timing on
+
+select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c)
+from t1, t2
+where t1.a = t2.a
+and t1.d = 1000;
+
+@plan
+
diff --git a/optimizer/spm_fix/snap.sql b/optimizer/spm_fix/snap.sql
new file mode 100644
index 00000000..8e932052
--- /dev/null
+++ b/optimizer/spm_fix/snap.sql
@@ -0,0 +1 @@
+EXEC DBMS_WORKLOAD_REPOSITORY.create_snapshot;
diff --git a/optimizer/spm_fix/spm.lst b/optimizer/spm_fix/spm.lst
new file mode 100644
index 00000000..e69628b2
--- /dev/null
+++ b/optimizer/spm_fix/spm.lst
@@ -0,0 +1,228 @@
+SQL> @spm
+SQL>
+SQL> exec select '' into :rep from dual;
+
+PL/SQL procedure successfully completed.
+
+SQL>
+SQL> DECLARE
+ 2 tname varchar2(1000);
+ 3 ename varchar2(1000);
+ 4 n number;
+ 5 sig number;
+ 6 sqlid varchar2(1000) := '0ptw8zskuh9r4';
+ 7 phv number := 3534348942;
+ 8 handle varchar2(1000);
+ 9 nc number;
+ 10 BEGIN
+ 11 select count(*) into nc
+ 12 from v$sql
+ 13 where sql_id = sqlid
+ 14 and plan_hash_value = phv;
+ 15
+ 16 if (nc = 0)
+ 17 then
+ 18 raise_application_error(-20001, 'The SQL_ID/PHV combination not found in V$SQL');
+ 19 end if;
+ 20
+ 21 select exact_matching_signature into sig
+ 22 from v$sqlarea
+ 23 where sql_id = sqlid;
+ 24
+ 25 -- Enabled=NO because we will assume that this is a bad plan
+ 26
+ 27 n := dbms_spm.load_plans_from_cursor_cache(
+ 28 sql_id => sqlid,
+ 29 plan_hash_value=> phv,
+ 30 enabled => 'no');
+ 31
+ 32 select distinct sql_handle
+ 33 into handle
+ 34 from dba_sql_plan_baselines
+ 35 where signature = sig;
+ 36
+ 37 tname := DBMS_SPM.CREATE_EVOLVE_TASK(sql_handle=>handle);
+ 38
+ 39 DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ 40 task_name => tname,
+ 41 parameter => 'ALTERNATE_PLAN_BASELINE',
+ 42 value => 'EXISTING');
+ 43
+ 44 --
+ 45 -- You can use CURSOR_CACHE+SQL_TUNING_SET+AUTOMATIC_WORKLOAD_REPOSITORY
+ 46 -- if you have the Oracle Tuning and Oracle Diagnostic Packs.
+ 47 -- See Oracle License Guide for details.
+ 48 --
+ 49 DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ 50 task_name => tname,
+ 51 parameter => 'ALTERNATE_PLAN_SOURCE',
+ 52 value => 'CURSOR_CACHE+AUTOMATIC_WORKLOAD_REPOSITORY');
+ 53
+ 54 DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ 55 task_name => tname,
+ 56 parameter => 'ALTERNATE_PLAN_LIMIT',
+ 57 value => 'UNLIMITED');
+ 58
+ 59 ename := DBMS_SPM.EXECUTE_EVOLVE_TASK(tname);
+ 60
+ 61 n := DBMS_SPM.IMPLEMENT_EVOLVE_TASK(tname);
+ 62
+ 63 select DBMS_SPM.REPORT_EVOLVE_TASK(task_name=>tname) into :rep from dual;
+ 64 END;
+ 65 /
+
+PL/SQL procedure successfully completed.
+
+SQL>
+SQL> set echo off
+Note!
+Take a look at the following report to confirm that the previous plan
+passes the performance criteria to be accepted.
+Be aware that on some systems the difference may not be significant
+enough to warrant acceptance of the SQL plan baseline.
+If this happens in your case, you should increase the number of rows
+in the test tables to boost the performance difference between
+the nested loop and hash join versions of the test query.
+
+REPORT
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+GENERAL INFORMATION SECTION
+---------------------------------------------------------------------------------------------
+
+ Task Information:
+ ---------------------------------------------
+ Task Name : TASK_386
+ Task Owner : SYS
+ Execution Name : EXEC_496
+ Execution Type : SPM EVOLVE
+ Scope : COMPREHENSIVE
+ Status : COMPLETED
+ Started : 10/02/2019 11:04:48
+ Finished : 10/02/2019 11:04:51
+ Last Updated : 10/02/2019 11:04:51
+ Global Time Limit : 2147483646
+ Per-Plan Time Limit : UNUSED
+ Number of Errors : 0
+---------------------------------------------------------------------------------------------
+
+SUMMARY SECTION
+---------------------------------------------------------------------------------------------
+ Number of plans processed : 1
+ Number of findings : 1
+ Number of recommendations : 1
+ Number of errors : 0
+---------------------------------------------------------------------------------------------
+
+DETAILS SECTION
+---------------------------------------------------------------------------------------------
+ Object ID : 2
+ Test Plan Name : SQL_PLAN_2jnv3vhwv9nsnc6a45b88
+ Base Plan Name : Cost-based plan
+ SQL Handle : SQL_28d363dc39b4d314
+ Parsing Schema : SPMDEMO
+ Test Plan Creator : SYS
+ SQL Text : select /*+ NO_ADAPTIVE_PLAN */ sum(t1.c), sum(t2.c) from
+ t1, t2 where t1.a = t2.a and t1.d = 10
+
+Execution Statistics:
+-----------------------------
+ Base Plan Test Plan
+ ---------------------------- ----------------------------
+ Elapsed Time (s): .075204 .02097
+ CPU Time (s): .073579 .020487
+ Buffer Gets: 15988 1131
+ Optimizer Cost: 1105 2197
+ Disk Reads: 0 0
+ Direct Writes: 0 0
+ Rows Processed: 0 0
+ Executions: 4 7
+
+
+FINDINGS SECTION
+---------------------------------------------------------------------------------------------
+
+Findings (1):
+-----------------------------
+ 1. The plan was verified in 2.28500 seconds. It passed the benefit criterion
+ because its verified performance was 8.06107 times better than that of the
+ baseline plan.
+
+Recommendation:
+-----------------------------
+ Consider accepting the plan. Execute
+ dbms_spm.accept_sql_plan_baseline(task_name => 'TASK_386', object_id => 2,
+ task_owner => 'SYS');
+
+
+EXPLAIN PLANS SECTION
+---------------------------------------------------------------------------------------------
+
+Baseline Plan
+-----------------------------
+ Plan Id : 4005
+ Plan Hash Value : 3467815966
+
+---------------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost | Time |
+---------------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | 1 | 22 | 1105 | 00:00:01 |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+| 2 | NESTED LOOPS | | 2 | 44 | 1105 | 00:00:01 |
+| 3 | NESTED LOOPS | | 2 | 44 | 1105 | 00:00:01 |
+| * 4 | TABLE ACCESS FULL | T1 | 2 | 26 | 1099 | 00:00:01 |
+| * 5 | INDEX RANGE SCAN | T2I | 1 | | 2 | 00:00:01 |
+| 6 | TABLE ACCESS BY INDEX ROWID | T2 | 1 | 9 | 3 | 00:00:01 |
+---------------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+------------------------------------------
+* 4 - filter("T1"."D"=10)
+* 5 - access("T1"."A"="T2"."A")
+
+Hint Report (identified by operation id / Query Block Name / Object Alias):
+Total hints for statement: 1 (U - Unused (1))
+-------------------------------------------------------------------------------
+
+ 0 - STATEMENT
+ U - NO_ADAPTIVE_PLAN / rejected by IGNORE_OPTIM_EMBEDDED_HINTS
+
+Test Plan
+-----------------------------
+ Plan Id : 4006
+ Plan Hash Value : 3332660104
+
+----------------------------------------------------------------------------
+| Id | Operation | Name | Rows | Bytes | Cost | Time |
+----------------------------------------------------------------------------
+| 0 | SELECT STATEMENT | | 1 | 22 | 2197 | 00:00:01 |
+| 1 | SORT AGGREGATE | | 1 | 22 | | |
+| * 2 | HASH JOIN | | 2 | 44 | 2197 | 00:00:01 |
+| * 3 | TABLE ACCESS FULL | T1 | 2 | 26 | 1099 | 00:00:01 |
+| 4 | TABLE ACCESS FULL | T2 | 1000000 | 9000000 | 1095 | 00:00:01 |
+----------------------------------------------------------------------------
+
+Predicate Information (identified by operation id):
+------------------------------------------
+* 2 - access("T1"."A"="T2"."A")
+* 3 - filter("T1"."D"=10)
+
+Hint Report (identified by operation id / Query Block Name / Object Alias):
+Total hints for statement: 1 (U - Unused (1))
+-------------------------------------------------------------------------------
+
+ 0 - STATEMENT
+ U - NO_ADAPTIVE_PLAN / rejected by IGNORE_OPTIM_EMBEDDED_HINTS
+---------------------------------------------------------------------------------------------
+
+
+SQL> !vi REA*
+
+SQL> !vi RE*
+
+SQL> !vi spm.sql
+
+SQL>
+SQL>
+SQL> !vi spm.sql
+
+SQL> exit
diff --git a/optimizer/spm_fix/spm.sql b/optimizer/spm_fix/spm.sql
new file mode 100644
index 00000000..6d41030b
--- /dev/null
+++ b/optimizer/spm_fix/spm.sql
@@ -0,0 +1,119 @@
+var rep clob
+set linesize 250
+set pagesize 10000
+set trims on
+set tab off
+set long 1000000
+column report format a200
+set echo on
+
+exec select '' into :rep from dual;
+
+--
+-- This example assumes that you have the bad plan in the
+-- cursor cache but this is not essential. Take a look
+-- at the documentation for DBMS_SPM because there are a
+-- large number of options for creating the initial SQL plan
+-- baseline. Also, you might even have a SQL plan baseline already.
+--
+-- The example SQL ID hard coded in this example
+--
+
+set linesize 100
+set trims on
+set tab off
+set pagesize 1000
+column plan_table_output format 95
+
+var childid varchar2(100)
+var childnum number
+--
+-- The SQL_ID of our SQL statement
+--
+exec :childid := '0ptw8zskuh9r4';
+
+exec select max(child_number) into :childnum from v$sql where sql_id = :childid;
+
+SELECT *
+FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'BASIC', SQL_ID=>:childid, cursor_child_no=>:childnum));
+
+accept myphv char prompt 'Enter the plan hash value of the bad NL plan (above): '
+
+DECLARE
+ tname varchar2(1000);
+ ename varchar2(1000);
+ n number;
+ sig number;
+ sqlid varchar2(1000) := :childid;
+ phv number := &myphv;
+ handle varchar2(1000);
+ nc number;
+BEGIN
+ select count(*) into nc
+ from v$sql
+ where sql_id = sqlid
+ and plan_hash_value = phv;
+
+ if (nc = 0)
+ then
+ raise_application_error(-20001, 'The SQL_ID/PHV combination not found in V$SQL');
+ end if;
+
+ select exact_matching_signature into sig
+ from v$sqlarea
+ where sql_id = sqlid;
+
+-- Enabled=NO because we will assume that this is a bad plan
+
+ n := dbms_spm.load_plans_from_cursor_cache(
+ sql_id => sqlid,
+ plan_hash_value=> phv,
+ enabled => 'no');
+
+ select distinct sql_handle
+ into handle
+ from dba_sql_plan_baselines
+ where signature = sig;
+
+ tname := DBMS_SPM.CREATE_EVOLVE_TASK(sql_handle=>handle);
+
+ DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ task_name => tname,
+ parameter => 'ALTERNATE_PLAN_BASELINE',
+ value => 'EXISTING');
+
+--
+-- You can use CURSOR_CACHE+SQL_TUNING_SET+AUTOMATIC_WORKLOAD_REPOSITORY
+-- if you have the Oracle Tuning and Oracle Diagnostic Packs.
+-- See Oracle License Guide for details.
+--
+ DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ task_name => tname,
+ parameter => 'ALTERNATE_PLAN_SOURCE',
+ value => 'CURSOR_CACHE+AUTOMATIC_WORKLOAD_REPOSITORY');
+
+ DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
+ task_name => tname,
+ parameter => 'ALTERNATE_PLAN_LIMIT',
+ value => 'UNLIMITED');
+
+ ename := DBMS_SPM.EXECUTE_EVOLVE_TASK(tname);
+
+ n := DBMS_SPM.IMPLEMENT_EVOLVE_TASK(tname);
+
+ select DBMS_SPM.REPORT_EVOLVE_TASK(task_name=>tname) into :rep from dual;
+END;
+/
+
+set echo off
+--
+PROMPT Note!
+PROMPT Take a look at the following report to confirm that the previous plan
+PROMPT passes the performance criteria to be accepted.
+PROMPT Be aware that on some systems the difference may not be significant
+PROMPT enough to warrant acceptance of the SQL plan baseline.
+PROMPT If this happens in your case, you should increase the number of rows
+PROMPT in the test tables to boost the performance difference between
+PROMPT the nested loop and hash join versions of the test query.
+--
+select :rep report from dual;
diff --git a/optimizer/spm_fix/sql.sql b/optimizer/spm_fix/sql.sql
new file mode 100644
index 00000000..e5afd2be
--- /dev/null
+++ b/optimizer/spm_fix/sql.sql
@@ -0,0 +1,2 @@
+select sql_id,plan_hash_value,sql_text from v$sql where sql_text like '%NO_ADAPTIVE_PLAN%'
+/
diff --git a/optimizer/spm_fix/tab.lst b/optimizer/spm_fix/tab.lst
new file mode 100644
index 00000000..0f0be582
--- /dev/null
+++ b/optimizer/spm_fix/tab.lst
@@ -0,0 +1,75 @@
+SQL> --
+SQL> -- Create two tables with a skewed dataset
+SQL> --
+SQL> drop table t1 purge;
+drop table t1 purge
+ *
+ERROR at line 1:
+ORA-00942: table or view does not exist
+
+
+SQL> drop table t2 purge;
+drop table t2 purge
+ *
+ERROR at line 1:
+ORA-00942: table or view does not exist
+
+
+SQL>
+SQL> create table t1 (a number(10), b varchar2(1000), c number(10), d number(10));
+
+Table created.
+
+SQL>
+SQL>
+SQL> var str VARCHAR2(10)
+SQL> exec :str := dbms_random.string('u',10);
+
+PL/SQL procedure successfully completed.
+
+SQL> insert /*+ APPEND */ into t1
+ 2 select DECODE(parity, 0,rn, 1,rn+1000000), :str, 1, DECODE(parity, 0,rn, 1,10)
+ 3 from (
+ 4 select trunc((rownum+1)/2) as rn, mod(rownum+1,2) as parity
+ 5 from (select null from dual connect by level <= 1000)
+ 6 , (select null from dual connect by level <= 500)
+ 7 );
+
+500000 rows created.
+
+SQL>
+SQL> commit;
+
+Commit complete.
+
+SQL>
+SQL> create table t2 as select * from t1;
+
+Table created.
+
+SQL>
+SQL> create index t1i on t1 (a);
+
+Index created.
+
+SQL> create index t2i on t2 (a);
+
+Index created.
+
+SQL>
+SQL> --
+SQL> -- Gather with histograms
+SQL> --
+SQL> @@gatherh
+SQL> --
+SQL> -- Gather statistics with histograms
+SQL> --
+SQL> exec dbms_stats.gather_table_stats(user,'t1',method_opt=>'for all columns size 254',no_invalidate=>false)
+
+PL/SQL procedure successfully completed.
+
+SQL> exec dbms_stats.gather_table_stats(user,'t2',method_opt=>'for all columns size 254',no_invalidate=>false)
+
+PL/SQL procedure successfully completed.
+
+SQL> spool off
diff --git a/optimizer/spm_fix/tab.sql b/optimizer/spm_fix/tab.sql
new file mode 100644
index 00000000..9372b06a
--- /dev/null
+++ b/optimizer/spm_fix/tab.sql
@@ -0,0 +1,33 @@
+set echo on
+spool tab
+--
+-- Create two tables with a skewed dataset
+--
+drop table t1 purge;
+drop table t2 purge;
+
+create table t1 (a number(10), b varchar2(1000), c number(10), d number(10));
+
+
+var str VARCHAR2(10)
+exec :str := dbms_random.string('u',10);
+insert /*+ APPEND */ into t1
+select DECODE(parity, 0,rn, 1,rn+1000000), :str, 1, DECODE(parity, 0,rn, 1,10)
+from (
+ select trunc((rownum+1)/2) as rn, mod(rownum+1,2) as parity
+ from (select null from dual connect by level <= 1000)
+ , (select null from dual connect by level <= 500)
+ );
+
+commit;
+
+create table t2 as select * from t1;
+
+create index t1i on t1 (a);
+create index t2i on t2 (a);
+
+--
+-- Gather with histograms
+--
+@@gatherh
+spool off
diff --git a/optimizer/spm_fix/user.sql b/optimizer/spm_fix/user.sql
new file mode 100644
index 00000000..2a61d849
--- /dev/null
+++ b/optimizer/spm_fix/user.sql
@@ -0,0 +1,2 @@
+create user spmdemo identified by spmdemo;
+grant dba to spmdemo;
diff --git a/optimizer/spm_fix/x.sql b/optimizer/spm_fix/x.sql
new file mode 100644
index 00000000..4a5c3156
--- /dev/null
+++ b/optimizer/spm_fix/x.sql
@@ -0,0 +1,3 @@
+SELECT *
+FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'BASIC', SQL_ID=>'0ptw8zskuh9r4',cursor_child_no=>1))
+/