♣题目 部分
在Oracle中,SQL概要(SQL Profile)的作用是什么?
♣答案部分
SQL Profile就是为某条SQL语句提供除了系统统计信息、对象(表和索引等)统计信息之外的其它信息,比如运行环境、额外的更准确的统计信息,以帮助优化器为SQL语句选择更适合的执行计划。SQL Profile可以说是Outline的进化。Outline能够实现的功能SQL Profile也完全能够实现,而SQL Profile具有Outline不具备的优化,最重要的有两点:①SQL Profile更容易生成、更改和控制。②SQL Profile在对SQL语句的支持上做得更好,也就是适用范围更广。
对于sqlprof_attr部分的数据可以使用脚本coe_xfr_sql_profile.sql脚本生成。
使用SQL Profile的两个目的:①锁定或者说是稳定执行计划。②在不能修改应用中的SQL的情况下使SQL语句按指定的执行计划运行。
SQL Profile最大的优点是在不修改SQL语句和会话执行环境的情况下去优化SQL的执行效率,适合无法在应用程序中修改SQL时。
SQL Profile对以下类型语句有效:
l SELECT语句;
l UPDATE语句;
l INSERT语句(仅当使用SELECT子句时有效);
l DELETE语句;
l CREATE语句(仅当使用SELECT子句时有效);
l MERGE语句(仅当作UPDATE和INSERT操作时有效)。
另外,使用SQL Profile还必须有CREATE ANY SQL PROFILE、DROP ANY SQL PROFILE和ALTER ANY SQL PROFILE等系统权限。
有两种生成SQL Profile的方法,分别是手动和采用STA来生成。
(一)SQL Profile使用示例--手工创建SQL Profile
创建测试表,根据DBA_OBJECTS创建,OBJECT_ID上有索引
1LHR@dlhr> select * from v$version; 2 3BANNER 4-------------------------------------------------------------------------------- 5Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production 6PL/SQL Release 11.2.0.4.0 - Production 7CORE 11.2.0.4.0 Production 8TNS for IBM/AIX RISC System/6000: Version 11.2.0.4.0 - Production 9NLSRTL Version 11.2.0.4.0 - Production1011LHR@dlhr> Create table TB_LHR_20160525 as select * from dba_objects;1213Table created.1415LHR@dlhr> create index IND_TB_LHR_ID on TB_LHR_20160525(object_id);1617Index created.select * from v$version; 3BANNER 4-------------------------------------------------------------------------------- 5Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production 6PL/SQL Release 11.2.0.4.0 - Production 7CORE 11.2.0.4.0 Production 8TNS for IBM/AIX RISC System/6000: Version 11.2.0.4.0 - Production 9NLSRTL Version 11.2.0.4.0 - Production 11LHR@dlhr> Create table TB_LHR_20160525 as select * from dba_objects; 13Table created. 15LHR@dlhr> create index IND_TB_LHR_ID on TB_LHR_20160525(object_id); 17Index created.
查看SQL默认执行计划,走了索引,通过指定Outline可以获取到系统为我们生成的hint
1LHR@dlhr> explain plan for select * from TB_LHR_20160525 where object_id= :a; 2 3Explained. 4 5LHR@dlhr> select * from table(dbms_xplan.display(null,null,'outline')); 6 7PLAN_TABLE_OUTPUT 8-------------------------------------------------------------------------------------------------------- 9Plan hash value: 42540501521011-----------------------------------------------------------------------------------------------12| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |13-----------------------------------------------------------------------------------------------14| 0 | SELECT STATEMENT | | 886 | 179K| 7 (0)| 00:00:01 |15| 1 | TABLE ACCESS BY INDEX ROWID| TB_LHR_20160525 | 886 | 179K| 7 (0)| 00:00:01 |16|* 2 | INDEX RANGE SCAN | IND_TB_LHR_ID | 354 | | 1 (0)| 00:00:01 |17-----------------------------------------------------------------------------------------------1819Outline Data20-------------2122 /*+23 BEGIN_OUTLINE_DATA24 INDEX_RS_ASC(@"SEL$1" "TB_LHR_20160525"@"SEL$1" ("TB_LHR_20160525"."OBJECT_ID"))25 OUTLINE_LEAF(@"SEL$1")26 ALL_ROWS27 DB_VERSION('11.2.0.4')28 OPTIMIZER_FEATURES_ENABLE('11.2.0.4')29 IGNORE_OPTIM_EMBEDDED_HINTS30 END_OUTLINE_DATA31 */3233Predicate Information (identified by operation id):34---------------------------------------------------3536 2 - access("OBJECT_ID"=TO_NUMBER(:A))3738Note39-----40 - dynamic sampling used for this statement (level=2)414232 rows selected.explain plan for select * from TB_LHR_20160525 where object_id= :a; 3Explained. 5LHR@dlhr> select * from table(dbms_xplan.display(null,null,'outline')); 7PLAN_TABLE_OUTPUT 8-------------------------------------------------------------------------------------------------------- 9Plan hash value: 4254050152 11----------------------------------------------------------------------------------------------- 12| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | 13----------------------------------------------------------------------------------------------- 14| 0 | SELECT STATEMENT | | 886 | 179K| 7 (0)| 00:00:01 | 15| 1 | TABLE ACCESS BY INDEX ROWID| TB_LHR_20160525 | 886 | 179K| 7 (0)| 00:00:01 | 16|* 2 | INDEX RANGE SCAN | IND_TB_LHR_ID | 354 | | 1 (0)| 00:00:01 | 17----------------------------------------------------------------------------------------------- 19Outline Data 20------------- /*+ BEGIN_OUTLINE_DATA INDEX_RS_ASC(@"SEL$1" "TB_LHR_20160525"@"SEL$1" ("TB_LHR_20160525"."OBJECT_ID")) OUTLINE_LEAF(@"SEL$1") ALL_ROWS DB_VERSION('11.2.0.4') OPTIMIZER_FEATURES_ENABLE('11.2.0.4') IGNORE_OPTIM_EMBEDDED_HINTS END_OUTLINE_DATA */ 33Predicate Information (identified by operation id): 34--------------------------------------------------- 2 - access("OBJECT_ID"=TO_NUMBER(:A)) 38Note 39----- - dynamic sampling used for this statement (level=2) rows selected.
如果我们想让它走全表扫描,首先获取全表扫描HINT
1LHR@dlhr> explain plan for select /*+ full(TB_LHR_20160525) */* from TB_LHR_20160525 where object_id= :a; 2 3Explained. 4 5LHR@dlhr> select * from table(dbms_xplan.display(null,null,'outline')); 6 7PLAN_TABLE_OUTPUT 8----------------------------------------------------------------------------------------- 9Plan hash value: 3458810051011-------------------------------------------------------------------------------------12| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |13-------------------------------------------------------------------------------------14| 0 | SELECT STATEMENT | | 886 | 179K| 352 (2)| 00:00:05 |15|* 1 | TABLE ACCESS FULL| TB_LHR_20160525 | 886 | 179K| 352 (2)| 00:00:05 |16-------------------------------------------------------------------------------------1718Outline Data19-------------2021 /*+22 BEGIN_OUTLINE_DATA23 FULL(@"SEL$1" "TB_LHR_20160525"@"SEL$1")24 OUTLINE_LEAF(@"SEL$1")25 ALL_ROWS26 DB_VERSION('11.2.0.4')27 OPTIMIZER_FEATURES_ENABLE('11.2.0.4')28 IGNORE_OPTIM_EMBEDDED_HINTS29 END_OUTLINE_DATA30 */3132Predicate Information (identified by operation id):33---------------------------------------------------3435 1 - filter("OBJECT_ID"=TO_NUMBER(:A))3637Note38-----39 - dynamic sampling used for this statement (level=2)404131 rows selected.explain plan for select /*+ full(TB_LHR_20160525) */* from TB_LHR_20160525 where object_id= :a; 3Explained. 5LHR@dlhr> select * from table(dbms_xplan.display(null,null,'outline')); 7PLAN_TABLE_OUTPUT 8----------------------------------------------------------------------------------------- 9Plan hash value: 345881005 11------------------------------------------------------------------------------------- 12| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | 13------------------------------------------------------------------------------------- 14| 0 | SELECT STATEMENT | | 886 | 179K| 352 (2)| 00:00:05 | 15|* 1 | TABLE ACCESS FULL| TB_LHR_20160525 | 886 | 179K| 352 (2)| 00:00:05 | 16------------------------------------------------------------------------------------- 18Outline Data 19------------- /*+ BEGIN_OUTLINE_DATA FULL(@"SEL$1" "TB_LHR_20160525"@"SEL$1") OUTLINE_LEAF(@"SEL$1") ALL_ROWS DB_VERSION('11.2.0.4') OPTIMIZER_FEATURES_ENABLE('11.2.0.4') IGNORE_OPTIM_EMBEDDED_HINTS END_OUTLINE_DATA */ 32Predicate Information (identified by operation id): 33--------------------------------------------------- 1 - filter("OBJECT_ID"=TO_NUMBER(:A)) 37Note 38----- - dynamic sampling used for this statement (level=2) rows selected.
可以看到全表扫描的Hint已经为我们生成了,我们选取必要的hint就OK了,其它的可以不要,使用SQL Profile
1LHR@dlhr> declare 2 2 v_hints sys.sqlprof_attr; 3 3 begin 4 4 v_hints := sys.sqlprof_attr('FULL(@"SEL$1" "TB_LHR_20160525"@"SEL$1")'); ----------从上面Outline Data部分获取到的HINT 5 5 dbms_sqltune.import_sql_profile('select * from TB_LHR_20160525 where object_id= :a', ----------SQL语句部分 6 6 v_hints, 7 7 'TB_LHR_20160525', --------PROFILE 的名字 8 8 force_match => true); 9 9 end;10 10 /1112PL/SQL procedure successfully completed.13declare v_hints sys.sqlprof_attr; begin v_hints := sys.sqlprof_attr('FULL(@"SEL$1" "TB_LHR_20160525"@"SEL$1")'); ----------从上面Outline Data部分获取到的HINT dbms_sqltune.import_sql_profile('select * from TB_LHR_20160525 where object_id= :a', ----------SQL语句部分 v_hints, 'TB_LHR_20160525', --------PROFILE 的名字 force_match => true); end; / 12PL/SQL procedure successfully completed.
查看是否生效,已经生效了:
1LHR@dlhr> explain plan for select * from TB_LHR_20160525 where object_id= :a; 2 3Explained. 4 5LHR@dlhr> select * from table(dbms_xplan.display); 6 7PLAN_TABLE_OUTPUT 8----------------------------------------------------------------------------------------------------------------------------Plan hash value: 345881005 910-------------------------------------------------------------------------------------11| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |12-------------------------------------------------------------------------------------13| 0 | SELECT STATEMENT | | 886 | 179K| 352 (2)| 00:00:05 |14|* 1 | TABLE ACCESS FULL| TB_LHR_20160525 | 886 | 179K| 352 (2)| 00:00:05 |15-------------------------------------------------------------------------------------1617Predicate Information (identified by operation id):18---------------------------------------------------1920 1 - filter("OBJECT_ID"=TO_NUMBER(:A))2122Note23-----24 - dynamic sampling used for this statement (level=2)25 - SQL profile "TB_LHR_20160525" used for this statement262718 rows selected.2829LHR@dlhr> SELECT b.name,d.sql_text, extractvalue(value(h),'.') as hints30 2 FROM dba_sql_profiles d,SYS.SQLOBJ$DATA A,31 3 SYS.SQLOBJ$ B,32 4 TABLE(XMLSEQUENCE(EXTRACT(XMLTYPE(A.COMP_DATA),33 5 '/outline_data/hint'))) h34 6 where a.signature = b.signature35 7 and a.category = b.category36 8 and a.obj_type = b.obj_type37 9 and a.plan_id = b.plan_id38 10 and a.signature=d.signature39 11 and D.name = 'TB_LHR_20160525'; 4041NAME SQL_TEXT HINTS42------------------------------ -------------------------------------------------------------------------------- -------------------------------------------------------43TB_LHR_20160525 select * from TB_LHR_20160525 where object_id= :a FULL(@"SEL$1" "TB_LHR_20160525"@"SEL$1")explain plan for select * from TB_LHR_20160525 where object_id= :a; 3Explained. 5LHR@dlhr> select * from table(dbms_xplan.display); 7PLAN_TABLE_OUTPUT 8----------------------------------------------------------------------------------------------------------------------------Plan hash value: 345881005 10------------------------------------------------------------------------------------- 11| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | 12------------------------------------------------------------------------------------- 13| 0 | SELECT STATEMENT | | 886 | 179K| 352 (2)| 00:00:05 | 14|* 1 | TABLE ACCESS FULL| TB_LHR_20160525 | 886 | 179K| 352 (2)| 00:00:05 | 15------------------------------------------------------------------------------------- 17Predicate Information (identified by operation id): 18--------------------------------------------------- 1 - filter("OBJECT_ID"=TO_NUMBER(:A)) 22Note 23----- - dynamic sampling used for this statement (level=2) - SQL profile "TB_LHR_20160525" used for this statement rows selected. 29LHR@dlhr> SELECT b.name,d.sql_text, extractvalue(value(h),'.') as hints FROM dba_sql_profiles d,SYS.SQLOBJ$DATA A, SYS.SQLOBJ$ B, TABLE(XMLSEQUENCE(EXTRACT(XMLTYPE(A.COMP_DATA), '/outline_data/hint'))) h where a.signature = b.signature and a.category = b.category and a.obj_type = b.obj_type and a.plan_id = b.plan_id and a.signature=d.signature and D.name = 'TB_LHR_20160525'; 41NAME SQL_TEXT HINTS 42------------------------------ -------------------------------------------------------------------------------- ------------------------------------------------------- 43TB_LHR_20160525 select * from TB_LHR_20160525 where object_id= :a FULL(@"SEL$1" "TB_LHR_20160525"@"SEL$1")
最麻烦的sqlprof_attr('FULL(t1@SEL$1)')是这里的格式如何写,在Mos上的文章note 215187.1中的sqlt.zip的目录utl中提供了脚本coe_xfr_sql_profile.sql可以生成这些信息。
本文选自《Oracle程序员面试笔试宝典》,作者:李华荣。
详细内容可以添加麦老师微信或QQ私聊。
About Me:小麦苗
● 本文作者:小麦苗,只专注于数据库的技术,更注重技术的运用
● 作者博客地址:http://blog.itpub.net/26736162/abstract/1/
● 本系列题目来源于作者的学习笔记,部分整理自网络,若有侵权或不当之处还请谅解
● 版权所有,欢迎分享本文,转载请保留出处
● QQ:646634621 QQ群:618766405
● 提供OCP、OCM和高可用部分最实用的技能培训
● 题目解答若有不当之处,还望各位朋友批评指正,共同进步
DBA宝典
长按下图识别二维码或微信扫描下图二维码来关注小麦苗的微信公众号:xiaomaimiaolhr,学习最实用的数据库技术。
喜欢就点击“好看”吧