①创建大纲
create or replace outline outln_t1 for category category_t1 on select * from t1 where id=1;
alter system set use_stored_outlines=category_t1; --激活一个类目的存储大纲
--select sql_id,hash_value,child_number from v$sql where sql_text like 'select * from t1 where id=1;%';
--exec dbms_outln.create_outline(sql_id,'DEFAULT'); --通过过程创建
select category,ol_name,hintcount hints,sql_text from outln.ol$;
②将现有OUTLINE复制到新建的私有的OUTLINE中去 --1.当前会话下修改不影响其它会话,2.已存在outline需要修改时
create private outline prv_ol_t1 from outln_t1;
create private outline prv_ol_temp on select /*+ full(t1) */ * from t1 where id=1;--用提示生成一个全表扫描计划
③修改大纲(可以使用dbms_outln_edit包中所提供的过程进行修改或直接修改ol$hints)
SQL> select category,ol_name,hintcount hints,sql_text from outln.ol$; --公有大纲的提示数量
SQL> select ol_name,hint_text from outln.ol$hints; --公有大纲的提示内容
SQL> select category,ol_name,hintcount hints,sql_text from ol$; --私有大纲的提示数量
SQL> select ol_name,hint_text from ol$hints; --私有大纲的提示内容
OL_NAME HINT_TEXT
------------------------------ -------------------------
PRV_OL_T1 OUTLINE_LEAF(@"SEL$1")
PRV_OL_T1 IGNORE_OPTIM_EMBEDDED_HINTS
PRV_OL_T1 OPTIMIZER_FEATURES_ENABLE('11.2.0.3')
PRV_OL_T1 DB_VERSION('11.2.0.3')
PRV_OL_T1 ALL_ROWS
PRV_OL_T1 INDEX_RS_ASC(@"SEL$1" "T1"@"SEL$1" ("T1"."ID"))
PRV_OL_TEMP FULL(@"SEL$1" "T1"@"SEL$1")
PRV_OL_TEMP OUTLINE_LEAF(@"SEL$1")
PRV_OL_TEMP ALL_ROWS
PRV_OL_TEMP DB_VERSION('11.2.0.3')
PRV_OL_TEMP OPTIMIZER_FEATURES_ENABLE('11.2.0.3')
PRV_OL_TEMP IGNORE_OPTIM_EMBEDDED_HINTS
--直接修改ol$hints(私有大纲的提示内容)
UPDATE ol$hints SET ol_name=DECODE(OL_NAME,'PRV_OL_T1','PRV_OL_TEMP','PRV_OL_TEMP','PRV_OL_T1')
WHERE ol_name IN ('PRV_OL_T1','PRV_OL_TEMP');
--直接修改ol$hints(私有大纲的提示数量)
UPDATE ol$ ol1 SET hintcount=(SELECT hintcount FROM ol$ ol2 WHERE ol2.ol_name IN ('PRV_OL_T1','PRV_OL_TEMP') AND ol2.ol_name != ol1.ol_name) WHERE ol1.ol_name IN ('PRV_OL_T1','PRV_OL_TEMP');
④在修改之后必须使用refresh_private_outline过程对上述私有outline进行刷新
EXEC DBMS_OUTLN_EDIT.REFRESH_PRIVATE_OUTLINE ('PRV_OL_T1');
⑤为了对创建的私有OUTLINE进行检查而需要将参数use_private_outlines设置为true
alter session set use_private_outlines=true;
⑥在充分的检查结束后,能过执行下面的操作来达到共享使用的目的
create or replace outline outln_t1 from private PRV_OL_T1;
⑦在共享使用转换结束后,通过将参数use_private_outlines设置为false来结束修改之前的私有outline的执行
alter session set use_private_outlines=false;
⑧OUTLINE的观察:dba_outlines、dba_outline_hints
select hint from dba_outline_hints where name='OUTLN_T1';