- The most important information that you need to be aware of if you plan to use SQL Profiles is that you need an Enterprise Edition + Diagnostic Pack + Tuning Pack license. If you don't have these licenses you are not allowed to use SQL Profiles, or the other way around Oracle can claim you need to pay these licenses if you're going to use SQL Profiles.
Therefore if you're already on Oracle 11g you might want to use SQL Baselines instead for the same purpose -
Update August 2012: SQL Baselines are only available with Enterprise Edition.
Jonathan Lewis for example recently wrote a short note on how to apply a baseline from a hinted statement to a non-hinted, which is what you usually want to achieve when dealing with third-party applications where you can't modify the source code.
More details about SQL Baselines can be found in the documentation, Kerry Osborne for example has some more examples and quirks he found summarized in his post about SQL Baselines.
If you're not yet on 11g and therefore can't use SQL Baselines you can still use Stored Outlines instead of SQL Profiles if you don't have the licences mentioned - as shown below the DBMS_OUTLN.CREATE_OUTLINE procedure unfortunately doesn't always work as expected. Therefore you can try to "hack" a Stored Outline as for example demonstrated by Charles Hooper here. His post also contains references to other sources on My Oracle Support and by Jonathan Lewis that describe that technique in more detail.
- I'm a bit puzzled that this post is such popular. I spend a significant amount of my time on performance related issues but I rarely resort to the techniques described here and the other mentioned posts about "Plan Stability". So I'm a bit curious and would like to encourage readers to leave a comment here why they think they need to use "Plan Stability" - there are usually a lot of others options I would evaluate first before thinking about using some kind of Plan Stability.
Original post: If you have the need for plan stability - that is telling the database to use a particular execution plan no matter what the optimizer thinks otherwise - then you might be in the situation that the "good" execution plan is already available in the shared pool or in the AWR, so it would be handy if you could simply tell Oracle to use that particular execution plan to create a Stored Outline.
Note that in 11g this is all possible using the new SQL Plan Management framework (SPM), but that is not available in 10g, so we need to think differently.
In 10g the DBMS_OUTLN package has been enhanced with the CREATE_OUTLINE procedure to create an outline from an existing child cursor in the shared pool.
Please note that in releases prior to 10.2.0.4 there was a severe bug that caused your session to crash when using DBMS_OUTLN.CREATE_OUTLINE (Bug 5454975 which has been fixed in 10.2.0.4). The workaround is to enable the creation of stored outlines by issuing "alter session set create_stored_outlines = true;" before using DBMS_OUTLN.CREATE_OUTLINE. For more information see the Metalink Notes 463288.1 and 445126.1.
Note that from 10g on the hints required to create an outline are stored as part of the plan table in the OTHER_XML column as part of the XML detail information.
You can use the ADVANCED or OUTLINE option of the DBMS_XPLAN.DISPLAY* functions to display that OUTLINE information. For more information see e.g. here.
So let's try DBMS_OUTLN.CREATE_OUTLINE in 10.2.0.4:
SQL>
SQL> drop table t_fetch_first_rows purge;
Table dropped.
SQL>
SQL> create table t_fetch_first_rows (
2 id number not null,
3 name varchar2(30) not null,
4 type varchar2(30) not null,
5 measure number
6 );
Table created.
SQL>
SQL> create index idx_fetch_first_rows on t_fetch_first_rows (type, id);
Index created.
SQL>
SQL> -- create an empty table
SQL> -- and gather statistics on it
SQL> exec dbms_stats.gather_table_stats(null, 't_fetch_first_rows', no_invalidate=>true)
PL/SQL procedure successfully completed.
SQL>
SQL> -- now put in some data
SQL> insert /*+ append */ into t_fetch_first_rows (
2 id,
3 name,
4 type,
5 measure)
6 select object_id, object_name, object_type, object_id as measure
7 from all_objects, (select level as id from dual connect by level <= 1000) dup
8 where object_type in ('VIEW', 'SCHEDULE')
9 and rownum <= 1000;
1000 rows created.
SQL>
SQL> commit;
Commit complete.
SQL>
SQL> -- This is going to use
SQL> -- the wrong plan
SQL> -- that we - only for demonstration purposes -
SQL> -- attempt to keep now
SQL> select sum(measure), count(*) from (
2 select * from t_fetch_first_rows
3 where type = 'VIEW'
4 order by id
5 );
SUM(MEASURE) COUNT(*)
------------ ----------
900000 1000
SQL>
SQL> -- uses index
SQL> select * from table(dbms_xplan.display_cursor(null, null, 'OUTLINE'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
SQL_ID c2trqja6wh561, child number 0
-------------------------------------
select sum(measure), count(*) from ( select * from t_fetch_first_rows where type
= 'VIEW' order by id )
Plan hash value: 1903859112
------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 1 (100)|
| 1 | SORT AGGREGATE | | 1 | 43 | |
| 2 | TABLE ACCESS BY INDEX ROWID| T_FETCH_FIRST_ROWS | 1 | 43 | 0 (0)|
|* 3 | INDEX RANGE SCAN | IDX_FETCH_FIRST_ROWS | 1 | | 0 (0)|
------------------------------------------------------------------------------------------
Outline Data
-------------
/*+
BEGIN_OUTLINE_DATA
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2"
("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRST_ROWS"."ID"))
END_OUTLINE_DATA
*/
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("TYPE"='VIEW')
41 rows selected.
SQL>
SQL> -- now gather statistics again
SQL> -- on table with data
SQL> exec dbms_stats.gather_table_stats(null, 't_fetch_first_rows', no_invalidate=>true)
PL/SQL procedure successfully completed.
SQL>
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> -- now the EXPLAIN PLAN tells us
SQL> -- full table scan
SQL> select * from table(dbms_xplan.display(null, null, 'OUTLINE'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2125410158
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 3 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
|* 2 | TABLE ACCESS FULL| T_FETCH_FIRST_ROWS | 1000 | 11000 | 3 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Outline Data
-------------
/*+
BEGIN_OUTLINE_DATA
FULL(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2")
OUTLINE(@"SEL$2")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
MERGE(@"SEL$73523A42")
OUTLINE_LEAF(@"SEL$51F12574")
ALL_ROWS
OPT_PARAM('query_rewrite_enabled' 'false')
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
IGNORE_OPTIM_EMBEDDED_HINTS
END_OUTLINE_DATA
*/
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("TYPE"='VIEW')
33 rows selected.
SQL>
SQL> -- These are the hints
SQL> -- stored in the child cursor
SQL> -- in the shared pool
SQL> -- It clearly shows an index access
SQL> select
2 substr(extractvalue(value(d), '/hint'), 1, 100) as outline_hints
3 from
4 xmltable('/*/outline_data/hint'
5 passing (
6 select
7 xmltype(other_xml) as xmlval
8 from
9 v$sql_plan
10 where
11 hash_value = 2378699969
12 and child_number = 0
13 and other_xml is not null
14 )
15 ) d;
OUTLINE_HINTS
----------------------------------------------------------------------------------------------------
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2" ("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRS
11 rows selected.
SQL>
SQL> -- Create the outline based on that cursor
SQL> exec dbms_outln.create_outline(2378699969, 0, 'TEST')
PL/SQL procedure successfully completed.
SQL>
SQL> -- Oops, where is my index scan gone?
SQL> select substr(hint, 1, 100) as hint from user_outline_hints;
HINT
--------------------------------------------------------------------------------
FULL(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2")
OUTLINE(@"SEL$2")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
MERGE(@"SEL$73523A42")
OUTLINE_LEAF(@"SEL$51F12574")
ALL_ROWS
OPT_PARAM('query_rewrite_enabled' 'false')
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
IGNORE_OPTIM_EMBEDDED_HINTS
11 rows selected.
SQL>
SQL> -- Use the outline
SQL> alter session set use_stored_outlines = TEST;
Session altered.
SQL>
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> -- Uses outline (see Note section)
SQL> -- but full table scan
SQL> -- So that didn't work as expected
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2125410158
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 3 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
|* 2 | TABLE ACCESS FULL| T_FETCH_FIRST_ROWS | 1000 | 11000 | 3 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("TYPE"='VIEW')
Note
-----
- outline "SYS_OUTLINE_09032900314557403" used for this statement
18 rows selected.
SQL>
SQL> alter session set use_stored_outlines = false;
Session altered.
SQL>
SQL> -- drop the outline
SQL> declare
2 outline_name varchar2(30);
3 begin
4 select
5 name
6 into
7 outline_name
8 from
9 user_outlines
10 where
11 category = 'TEST';
12
13 execute immediate 'drop outline ' || outline_name;
14 end;
15 /
PL/SQL procedure successfully completed.
SQL>
SQL> -- This is the plan
SQL> -- we get based on the present statistics
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2125410158
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 3 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
|* 2 | TABLE ACCESS FULL| T_FETCH_FIRST_ROWS | 1000 | 11000 | 3 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("TYPE"='VIEW')
14 rows selected.
SQL>
SQL> spool off
So that didn't work as expected. Although we were able to create an outline from the child cursor, it obviously didn't use the plan associated with the child cursor. Tracing the session didn't reveal why the CREATE_OUTLINE didn't use the outline information available from the shared pool.
Running the same test case in a slightly different order so that the outline is created before the statistics change corroborates the theory that the DBMS_OUTLN.CREATE_OUTLINE procedure might take the SQL from the cursor and internally execute an CREATE OUTLINE ... ON ..., and for whatever reason doesn't use the already available outline information.
SQL>
SQL> drop table t_fetch_first_rows purge;
Table dropped.
SQL>
SQL> create table t_fetch_first_rows (
2 id number not null,
3 name varchar2(30) not null,
4 type varchar2(30) not null,
5 measure number
6 );
Table created.
SQL>
SQL> create index idx_fetch_first_rows on t_fetch_first_rows (type, id);
Index created.
SQL>
SQL> -- create an empty table
SQL> -- and gather statistics on it
SQL> exec dbms_stats.gather_table_stats(null, 't_fetch_first_rows', no_invalidate=>true)
PL/SQL procedure successfully completed.
SQL>
SQL> -- now put in some data
SQL> insert /*+ append */ into t_fetch_first_rows (
2 id,
3 name,
4 type,
5 measure)
6 select object_id, object_name, object_type, object_id as measure
7 from all_objects, (select level as id from dual connect by level <= 1000) dup
8 where object_type in ('VIEW', 'SCHEDULE')
9 and rownum <= 1000;
1000 rows created.
SQL>
SQL> commit;
Commit complete.
SQL>
SQL> -- This is going to use
SQL> -- the wrong plan
SQL> -- that we - only for demonstration purposes -
SQL> -- attempt to keep now
SQL> select sum(measure), count(*) from (
2 select * from t_fetch_first_rows
3 where type = 'VIEW'
4 order by id
5 );
SUM(MEASURE) COUNT(*)
------------ ----------
900000 1000
SQL>
SQL> -- uses index
SQL> select * from table(dbms_xplan.display_cursor(null, null, 'OUTLINE'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
SQL_ID c2trqja6wh561, child number 0
-------------------------------------
select sum(measure), count(*) from ( select * from t_fetch_first_rows where type
= 'VIEW' order by id )
Plan hash value: 1903859112
------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 1 (100)|
| 1 | SORT AGGREGATE | | 1 | 43 | |
| 2 | TABLE ACCESS BY INDEX ROWID| T_FETCH_FIRST_ROWS | 1 | 43 | 0 (0)|
|* 3 | INDEX RANGE SCAN | IDX_FETCH_FIRST_ROWS | 1 | | 0 (0)|
------------------------------------------------------------------------------------------
Outline Data
-------------
/*+
BEGIN_OUTLINE_DATA
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2"
("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRST_ROWS"."ID"))
END_OUTLINE_DATA
*/
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("TYPE"='VIEW')
41 rows selected.
SQL>
SQL> -- Create the outline based on that cursor
SQL> exec dbms_outln.create_outline(2378699969, 0, 'TEST')
PL/SQL procedure successfully completed.
SQL>
SQL> -- Now we have the index scan in the outline
SQL> select substr(hint, 1, 100) as hint from user_outline_hints;
HINT
--------------------------------------------------------------------------------
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2" ("T_FETCH_FIRST_ROWS".
OUTLINE(@"SEL$2")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
MERGE(@"SEL$73523A42")
OUTLINE_LEAF(@"SEL$51F12574")
ALL_ROWS
OPT_PARAM('query_rewrite_enabled' 'false')
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
IGNORE_OPTIM_EMBEDDED_HINTS
11 rows selected.
SQL>
SQL> -- now gather statistics again
SQL> -- on table with data
SQL> exec dbms_stats.gather_table_stats(null, 't_fetch_first_rows', no_invalidate=>true)
PL/SQL procedure successfully completed.
SQL>
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> -- now the EXPLAIN PLAN tells us
SQL> -- full table scan
SQL> select * from table(dbms_xplan.display(null, null, 'OUTLINE'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2125410158
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 3 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
|* 2 | TABLE ACCESS FULL| T_FETCH_FIRST_ROWS | 1000 | 11000 | 3 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Outline Data
-------------
/*+
BEGIN_OUTLINE_DATA
FULL(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2")
OUTLINE(@"SEL$2")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
MERGE(@"SEL$73523A42")
OUTLINE_LEAF(@"SEL$51F12574")
ALL_ROWS
OPT_PARAM('query_rewrite_enabled' 'false')
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
IGNORE_OPTIM_EMBEDDED_HINTS
END_OUTLINE_DATA
*/
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("TYPE"='VIEW')
33 rows selected.
SQL>
SQL> -- These are the hints
SQL> -- stored in the child cursor
SQL> -- in the shared pool
SQL> -- It clearly shows an index access
SQL> select
2 substr(extractvalue(value(d), '/hint'), 1, 100) as outline_hints
3 from
4 xmltable('/*/outline_data/hint'
5 passing (
6 select
7 xmltype(other_xml) as xmlval
8 from
9 v$sql_plan
10 where
11 hash_value = 2378699969
12 and child_number = 0
13 and other_xml is not null
14 )
15 ) d;
OUTLINE_HINTS
----------------------------------------------------------------------------------------------------
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2" ("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRS
11 rows selected.
SQL>
SQL> -- Use the outline
SQL> alter session set use_stored_outlines = TEST;
Session altered.
SQL>
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> -- Uses outline (see Note section)
SQL> -- this time correctly
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1903859112
-----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 9 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
| 2 | TABLE ACCESS BY INDEX ROWID| T_FETCH_FIRST_ROWS | 1000 | 11000 | 9 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | IDX_FETCH_FIRST_ROWS | 1000 | | 4 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("TYPE"='VIEW')
Note
-----
- outline "SYS_OUTLINE_09032900320095604" used for this statement
19 rows selected.
SQL>
SQL> alter session set use_stored_outlines = false;
Session altered.
SQL>
SQL> -- drop the outline
SQL> declare
2 outline_name varchar2(30);
3 begin
4 select
5 name
6 into
7 outline_name
8 from
9 user_outlines
10 where
11 category = 'TEST';
12
13 execute immediate 'drop outline ' || outline_name;
14 end;
15 /
PL/SQL procedure successfully completed.
SQL>
SQL> -- This is the plan
SQL> -- we get based on the present statistics
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2125410158
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 3 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
|* 2 | TABLE ACCESS FULL| T_FETCH_FIRST_ROWS | 1000 | 11000 | 3 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("TYPE"='VIEW')
14 rows selected.
SQL>
SQL> spool off
So that worked, but still the question remains why DBMS_OUTLN.CREATE_OUTLINE doesn't use the available outline information in the shared pool.
Now let's turn to a different approach to achieve the same. 10g introduced SQL profiles that are primarily used to amend information that is not available to the cost based optimizer, e.g. in case of correlated column values the SQL Tuning Advisor of 10g can suggest to accept a SQL profile that scales the cardinality estimate so that the cardinality estimate is in the right ballpark.
A good explanation of SQL profiles can be found in Christian Antognini's publications.
But since SQL profiles internally consist of a set of hints, it could be possible to use SQL profiles instead of Stored Outlines to achieve the same.
There are two interesting aspects regarding this approach:
- We could use different sources to get the outline, e.g. instead of the shared pool we could get the hints from the AWR tables.
- SQL profiles support a "FORCE_MATCH" option that works similar to the CURSOR_SHARING literal replacement logic, i.e. SQL profiles can be forced to apply to multiple SQL statements that differ only by the literals used (i.e. no usage of bind variables).
So we are faced with two challenges in this regard:
1. Get the outline information, i.e. the full set of hints to provide plan stability 2. Create a SQL profile that consists of these hints
Get the outline information
There are two ways how the outline information could be obtained:
a) Use the DBMS_XPLAN.DISPLAY* functions with the ADVANCED or OUTLINE option and parse the this output to get the set of hints
b) Directly query the underlying tables/views to get the XML stored in the OTHER_XML column and extract the hints from that XML
a) Use the DBMS_XPLAN.DISPLAY* functions
Let me digress a little bit. Looking at the (already parsed a bit) output we get from the official DBMS_XPLAN function:
SQL>
SQL> with a as (
2 select
3 rownum as r_no
4 , a.*
5 from
6 table(
7 dbms_xplan.display_cursor(
8 'c2trqja6wh561'
9 , 0
10 , 'OUTLINE'
11 )
12 ) a
13 ),
14 b as (
15 select
16 min(r_no) as start_r_no
17 from
18 a
19 where
20 a.plan_table_output = 'Outline Data'
21 ),
22 c as (
23 select
24 min(r_no) as end_r_no
25 from
26 a
27 , b
28 where
29 a.r_no > b.start_r_no
30 and a.plan_table_output = ' */'
31 ),
32 d as (
33 select
34 instr(a.plan_table_output, 'BEGIN_OUTLINE_DATA') as start_col
35 from
36 a
37 , b
38 where
39 r_no = b.start_r_no + 4
40 )
41 select
42 substr(a.plan_table_output, d.start_col) as outline_hints
43 from
44 a
45 , b
46 , c
47 , d
48 where
49 a.r_no >= b.start_r_no + 4
50 and a.r_no <= c.end_r_no - 1
51 order by
52 a.r_no;
OUTLINE_HINTS
--------------------------------------------------------------------------
BEGIN_OUTLINE_DATA
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2"
("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRST_ROWS"."ID"))
END_OUTLINE_DATA
14 rows selected.
SQL>
You'll notice that the INDEX_RS_ASC hint is split across two lines, so we can't simply use that query output to construct the hints because these hints would be potentially illegal and therefore we need to merge/concatenate these split lines.
This is a variation of the well known "columns-to-rows" aka. STRAGG/CONCAT issue and there are multiple ways how to deal with that using plain SQL.
For more information about this particular issue, see e.g. the SQL snippets site.
Here are two ways how to achieve that concatenation using hierarchical queries or the SQL MODEL clause introduced in 10g:
SQL>
SQL> with a as (
2 select
3 rownum as r_no
4 , a.*
5 from
6 table(
7 dbms_xplan.display_cursor(
8 'c2trqja6wh561'
9 , 0
10 , 'OUTLINE'
11 )
12 ) a
13 ),
14 b as (
15 select
16 min(r_no) as start_r_no
17 from
18 a
19 where
20 a.plan_table_output = 'Outline Data'
21 ),
22 c as (
23 select
24 min(r_no) as end_r_no
25 from
26 a
27 , b
28 where
29 a.r_no > b.start_r_no
30 and a.plan_table_output = ' */'
31 ),
32 d as (
33 select
34 instr(a.plan_table_output, 'BEGIN_OUTLINE_DATA') as start_col
35 from
36 a
37 , b
38 where
39 r_no = b.start_r_no + 4
40 ),
41 e as (
42 select a.r_no
43 , substr(a.plan_table_output, d.start_col) as outline_hints
44 from
45 a
46 , b
47 , c
48 , d
49 where
50 a.r_no >= b.start_r_no + 4
51 and a.r_no <= c.end_r_no - 1
52 order by
53 a.r_no
54 ),
55 f as (
56 select
57 case substr(e.outline_hints, 1, 1)
58 when ' '
59 then r_no - 1
60 else null
61 end as par_id,
62 e.*
63 from
64 e
65 )
66 select
67 replace(aggr,'|', '') as aggr
68 from (
69 select
70 par_id
71 , sys_connect_by_path(trim(outline_hints), '|') as aggr
72 , level as lvl
73 from
74 f
75 where
76 connect_by_isleaf = 1
77 start with
78 par_id is null
79 connect by
80 prior r_no = par_id
81 order siblings by
82 r_no
83 );
AGGR
-------------------------------------------------------------------------------------------------------------
BEGIN_OUTLINE_DATA
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2"("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRST_ROWS"."ID"))
END_OUTLINE_DATA
13 rows selected.
SQL>
And here using the MODEL clause:
SQL>
SQL> with a as (
2 select
3 rownum as r_no
4 , a.*
5 from
6 table(
7 dbms_xplan.display_cursor(
8 'c2trqja6wh561'
9 , 0
10 , 'OUTLINE'
11 )
12 ) a
13 ),
14 b as (
15 select
16 min(r_no) as start_r_no
17 from
18 a
19 where
20 a.plan_table_output = 'Outline Data'
21 ),
22 c as (
23 select
24 min(r_no) as end_r_no
25 from
26 a
27 , b
28 where
29 a.r_no > b.start_r_no
30 and a.plan_table_output = ' */'
31 ),
32 d as (
33 select
34 instr(a.plan_table_output, 'BEGIN_OUTLINE_DATA') as start_col
35 from
36 a
37 , b
38 where
39 r_no = b.start_r_no + 4
40 ),
41 e as (
42 select
43 a.r_no
44 , substr(a.plan_table_output, d.start_col) as outline_hints
45 from
46 a
47 , b
48 , c
49 , d
50 where
51 a.r_no >= b.start_r_no + 4
52 and a.r_no <= c.end_r_no - 1
53 ),
54 f as (
55 select
56 case substr(e.outline_hints, 1, 1)
57 when ' '
58 then null
59 else r_no
60 end as grp_id
61 , e.*
62 from
63 e
64 ),
65 g as (
66 select
67 case
68 when grp_id is null
69 then last_value(grp_id ignore nulls) over (order by r_no)
70 else null
71 end as par_id
72 , f.*
73 from
74 f
75 )
76 select
77 aggr
78 from
79 g
80 model
81 return updated rows
82 partition by (
83 nvl(grp_id, par_id) as grp
84 )
85 dimension by (
86 row_number() over (
87 partition by
88 nvl(grp_id, par_id)
89 order by
90 r_no
91 ) as rn
92 )
93 measures (
94 cast(outline_hints as varchar2(4000)) as aggr
95 , r_no
96 )
97 rules
98 iterate (1000)
99 until presentv(aggr[ITERATION_NUMBER+3],1,2)=2 (
100 aggr[1] = aggr[1] ||
101 trim(aggr[ITERATION_NUMBER+2])
102 )
103 order by r_no
104 ;
AGGR
----------------------------------------------------------------------------------------------------------------------------------
BEGIN_OUTLINE_DATA
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2" ("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRST_ROWS"."ID"))
END_OUTLINE_DATA
13 rows selected.
SQL>
b) Directly query the underlying tables/views to get the XML
The other option would be to query the respective tables/views directly to obtain the hints from the XML stored in the OTHER_XML column of execution plans.
Here we can use the powerful XML functions of Oracle 10g:
SQL>
SQL> select
2 extractvalue(value(d), '/hint') as outline_hints
3 from
4 xmltable('/*/outline_data/hint'
5 passing (
6 select
7 xmltype(other_xml) as xmlval
8 from
9 v$sql_plan
10 where
11 sql_id = 'c2trqja6wh561'
12 and child_number = 0
13 and other_xml is not null
14 )
15 ) d;
OUTLINE_HINTS
-------------------------------------------------------------------------------------------------------------
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2" ("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRST_ROWS"."ID"))
11 rows selected.
SQL>
Instead of V$SQL_PLAN/V$SQL we could e.g. use DBA_HIST_SQL_PLAN/DBA_HIST_SQLTEXT to obtain the outline information from the AWR.
Create a SQL profile that consists of these hints
Now the second challenge is how to generate a SQL profile once we have identified the hints to use.
Here comes the DBMS_SQLTUNE package into the picture. It offers an (not officially documented) procedure IMPORT_SQL_PROFILE that is obviously used by the import facilities to create SQL profiles.
-- NAME: import_sql_profile - import a SQL profile
-- PURPOSE: This procedure is only used by import.
-- INPUTS: (see accept_sql_profile)
-- REQUIRES: "CREATE ANY SQL PROFILE" privilege
--
PROCEDURE import_sql_profile(
sql_text IN CLOB,
profile IN sqlprof_attr,
name IN VARCHAR2 := NULL,
description IN VARCHAR2 := NULL,
category IN VARCHAR2 := NULL,
validate IN BOOLEAN := TRUE,
replace IN BOOLEAN := FALSE,
force_match IN BOOLEAN := FALSE);
It simply takes a collection of varchar2(500) strings that make up the profile.
So we can combine the two things into a procedure that generates us a SQL profile from either the shared pool or the AWR. Here's one for the shared pool. It takes four parameters: The SQL_ID, the child_number, the SQL profile category and whether to force a match or not.
declare
ar_profile_hints sys.sqlprof_attr;
cl_sql_text clob;
begin
select
extractvalue(value(d), '/hint') as outline_hints
bulk collect
into
ar_profile_hints
from
xmltable('/*/outline_data/hint'
passing (
select
xmltype(other_xml) as xmlval
from
v$sql_plan
where
sql_id = '&&1'
and child_number = &&2
and other_xml is not null
)
) d;
select
sql_fulltext
into
cl_sql_text
from
v$sql
where
sql_id = '&&1'
and child_number = &&2;
dbms_sqltune.import_sql_profile(
sql_text => cl_sql_text
, profile => ar_profile_hints
, category => '&&3'
, name => 'PROFILE_&&1'
-- use force_match => true
-- to use CURSOR_SHARING=SIMILAR
-- behaviour, i.e. match even with
-- differing literals
, force_match => &&4
);
end;
/
Here's the one for the AWR. It takes as parameter the SQL_ID, the PLAN_HASH_VALUE and like the first one the SQL profile category and the FORCE_MATCH option.
declare
ar_profile_hints sys.sqlprof_attr;
cl_sql_text clob;
begin
select
extractvalue(value(d), '/hint') as outline_hints
bulk collect
into
ar_profile_hints
from
xmltable('/*/outline_data/hint'
passing (
select
xmltype(other_xml) as xmlval
from
dba_hist_sql_plan
where
sql_id = '&&1'
and plan_hash_value = &&2
and other_xml is not null
)
) d;
select
sql_text
into
cl_sql_text
from
dba_hist_sqltext
where
sql_id = '&&1';
dbms_sqltune.import_sql_profile(
sql_text => cl_sql_text
, profile => ar_profile_hints
, category => '&&3'
, name => 'PROFILE_&&1'
-- use force_match => true
-- to use CURSOR_SHARING=SIMILAR
-- behaviour, i.e. match even with
-- differing literals
, force_match => &&4
);
end;
/
So let's try all the stuff in one shot:
SQL>
SQL> drop table t_fetch_first_rows purge;
Table dropped.
SQL>
SQL> create table t_fetch_first_rows (
2 id number not null,
3 name varchar2(30) not null,
4 type varchar2(30) not null,
5 measure number
6 );
Table created.
SQL>
SQL> create index idx_fetch_first_rows on t_fetch_first_rows (type, id);
Index created.
SQL>
SQL> -- create an empty table
SQL> -- and gather statistics on it
SQL> exec dbms_stats.gather_table_stats(null, 't_fetch_first_rows', no_invalidate=>true)
PL/SQL procedure successfully completed.
SQL>
SQL> -- now put in some data
SQL> insert /*+ append */ into t_fetch_first_rows (
2 id,
3 name,
4 type,
5 measure)
6 select object_id, object_name, object_type, object_id as measure
7 from all_objects, (select level as id from dual connect by level <= 1000) dup
8 where object_type in ('VIEW', 'SCHEDULE')
9 and rownum <= 1000;
1000 rows created.
SQL>
SQL> commit;
Commit complete.
SQL>
SQL> -- This is going to use
SQL> -- the wrong plan
SQL> -- that we - only for demonstration purposes -
SQL> -- attempt to keep now
SQL> select sum(measure), count(*) from (
2 select * from t_fetch_first_rows
3 where type = 'VIEW'
4 order by id
5 );
SUM(MEASURE) COUNT(*)
------------ ----------
900000 1000
SQL>
SQL> -- uses index
SQL> select * from table(dbms_xplan.display_cursor(null, null, 'OUTLINE'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
SQL_ID c2trqja6wh561, child number 0
-------------------------------------
select sum(measure), count(*) from ( select * from t_fetch_first_rows where type
= 'VIEW' order by id )
Plan hash value: 1903859112
------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 1 (100)|
| 1 | SORT AGGREGATE | | 1 | 43 | |
| 2 | TABLE ACCESS BY INDEX ROWID| T_FETCH_FIRST_ROWS | 1 | 43 | 0 (0)|
|* 3 | INDEX RANGE SCAN | IDX_FETCH_FIRST_ROWS | 1 | | 0 (0)|
------------------------------------------------------------------------------------------
Outline Data
-------------
/*+
BEGIN_OUTLINE_DATA
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2"
("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRST_ROWS"."ID"))
END_OUTLINE_DATA
*/
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("TYPE"='VIEW')
41 rows selected.
SQL>
SQL> -- now gather statistics again
SQL> -- on table with data
SQL> exec dbms_stats.gather_table_stats(null, 't_fetch_first_rows', no_invalidate=>true)
PL/SQL procedure successfully completed.
SQL>
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> -- now the EXPLAIN PLAN tells us
SQL> -- full table scan
SQL> select * from table(dbms_xplan.display(null, null, 'OUTLINE'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2125410158
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 3 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
|* 2 | TABLE ACCESS FULL| T_FETCH_FIRST_ROWS | 1000 | 11000 | 3 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Outline Data
-------------
/*+
BEGIN_OUTLINE_DATA
FULL(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2")
OUTLINE(@"SEL$2")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
MERGE(@"SEL$73523A42")
OUTLINE_LEAF(@"SEL$51F12574")
ALL_ROWS
OPT_PARAM('query_rewrite_enabled' 'false')
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
IGNORE_OPTIM_EMBEDDED_HINTS
END_OUTLINE_DATA
*/
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("TYPE"='VIEW')
33 rows selected.
SQL>
SQL> -- These are the hints
SQL> -- stored in the child cursor
SQL> -- in the shared pool
SQL> -- It clearly shows an index access
SQL> select
2 substr(extractvalue(value(d), '/hint'), 1, 100) as outline_hints
3 from
4 xmltable('/*/outline_data/hint'
5 passing (
6 select
7 xmltype(other_xml) as xmlval
8 from
9 v$sql_plan
10 where
11 sql_id = 'c2trqja6wh561'
12 and child_number = 0
13 and other_xml is not null
14 )
15 ) d;
OUTLINE_HINTS
----------------------------------------------------------------------------------------------------
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.4')
OPT_PARAM('query_rewrite_enabled' 'false')
ALL_ROWS
OUTLINE_LEAF(@"SEL$51F12574")
MERGE(@"SEL$73523A42")
OUTLINE(@"SEL$1")
OUTLINE(@"SEL$73523A42")
ELIMINATE_OBY(@"SEL$2")
OUTLINE(@"SEL$2")
INDEX_RS_ASC(@"SEL$51F12574" "T_FETCH_FIRST_ROWS"@"SEL$2" ("T_FETCH_FIRST_ROWS"."TYPE" "T_FETCH_FIRS
11 rows selected.
SQL>
SQL> -- Create the SQL profile based on that cursor
SQL> @create_profile_from_shared_pool c2trqja6wh561 0 TEST true
SQL> declare
2 ar_profile_hints sys.sqlprof_attr;
3 cl_sql_text clob;
4 begin
5 select
6 extractvalue(value(d), '/hint') as outline_hints
7 bulk collect
8 into
9 ar_profile_hints
10 from
11 xmltable('/*/outline_data/hint'
12 passing (
13 select
14 xmltype(other_xml) as xmlval
15 from
16 v$sql_plan
17 where
18 sql_id = '&&1'
19 and child_number = &&2
20 and other_xml is not null
21 )
22 ) d;
23
24 select
25 sql_text
26 into
27 cl_sql_text
28 from
29 -- replace with dba_hist_sqltext
30 -- if required for AWR based
31 -- execution
32 v$sql
33 -- sys.dba_hist_sqltext
34 where
35 sql_id = '&&1'
36 and child_number = &&2;
37 -- plan_hash_value = &&2;
38
39 dbms_sqltune.import_sql_profile(
40 sql_text => cl_sql_text
41 , profile => ar_profile_hints
42 , category => '&&3'
43 , name => 'PROFILE_&&1'
44 -- use force_match => true
45 -- to use CURSOR_SHARING=SIMILAR
46 -- behaviour, i.e. match even with
47 -- differing literals
48 , force_match => &&4
49 );
50 end;
51 /
old 18: sql_id = '&&1'
new 18: sql_id = 'c2trqja6wh561'
old 19: and child_number = &&2
new 19: and child_number = 0
old 35: sql_id = '&&1'
new 35: sql_id = 'c2trqja6wh561'
old 36: and child_number = &&2;
new 36: and child_number = 0;
old 37: -- plan_hash_value = &&2;
new 37: -- plan_hash_value = 0;
old 42: , category => '&&3'
new 42: , category => 'TEST'
old 43: , name => 'PROFILE_&&1'
new 43: , name => 'PROFILE_c2trqja6wh561'
old 48: , force_match => &&4
new 48: , force_match => true
PL/SQL procedure successfully completed.
SQL>
SQL> alter session set sqltune_category = 'TEST';
Session altered.
SQL>
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> -- Uses SQL profile (see Note section)
SQL> -- and uses index
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1903859112
-----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 9 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
| 2 | TABLE ACCESS BY INDEX ROWID| T_FETCH_FIRST_ROWS | 1000 | 11000 | 9 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | IDX_FETCH_FIRST_ROWS | 1000 | | 4 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("TYPE"='VIEW')
Note
-----
- SQL profile "PROFILE_c2trqja6wh561" used for this statement
19 rows selected.
SQL>
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW2'
6 order by id
7 );
Explained.
SQL>
SQL> -- Very cool: Still uses SQL profile (see Note section)
SQL> -- although no exact text match
SQL> -- this is not possible using Stored Outlines
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1903859112
-----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 3 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
| 2 | TABLE ACCESS BY INDEX ROWID| T_FETCH_FIRST_ROWS | 1 | 11 | 3 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | IDX_FETCH_FIRST_ROWS | 1 | | 2 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("TYPE"='VIEW2')
Note
-----
- SQL profile "PROFILE_c2trqja6wh561" used for this statement
19 rows selected.
SQL>
SQL> alter session set sqltune_category = 'DEFAULT';
Session altered.
SQL>
SQL> -- drop the SQL profile
SQL> exec dbms_sqltune.drop_sql_profile('PROFILE_c2trqja6wh561')
PL/SQL procedure successfully completed.
SQL>
SQL> -- This is the plan
SQL> -- we get based on the present statistics
SQL> explain plan
2 for
3 select sum(measure), count(*) from (
4 select * from t_fetch_first_rows
5 where type = 'VIEW'
6 order by id
7 );
Explained.
SQL>
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2125410158
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 11 | 3 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 11 | | |
|* 2 | TABLE ACCESS FULL| T_FETCH_FIRST_ROWS | 1000 | 11000 | 3 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("TYPE"='VIEW')
14 rows selected.
SQL>
You can see two things here:
1. The SQL profile created forces the plan we wanted, so it seems to work as expected
2. The FORCE_MATCH option of the SQL profiles allows to use this profile even for SQLs that are not an exact text match of the original statement. This is something that is as far as I know not possible using Stored Outlines.
So if you have the need to fix the execution plan, and you have that plan already in the shared pool or the AWR, using above procedures allow you to generate a SQL profile which seems to do exactly what we want.
Given the fact that the SQL profile even allows to share the plan for SQLs that differ only by literals I definitely favor the SQL profiles over the Stored Outlines approach.