【DB筆試面試605】在Oracle中,SQL概要(SQL Profile)的作用是什麼?

  • 2019 年 10 月 10 日
  • 筆記

題目部分

在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上有索引

LHR@dlhr> select * from v$version;    BANNER  --------------------------------------------------------------------------------  Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production  PL/SQL Release 11.2.0.4.0 - Production  CORE    11.2.0.4.0      Production  TNS for IBM/AIX RISC System/6000: Version 11.2.0.4.0 - Production  NLSRTL Version 11.2.0.4.0 - Production    LHR@dlhr> Create table TB_LHR_20160525 as select * from dba_objects;    Table created.    LHR@dlhr> create index IND_TB_LHR_ID on TB_LHR_20160525(object_id);    Index created.  

查看SQL默認執行計劃,走了索引,通過指定Outline可以獲取到系統為我們生成的hint

LHR@dlhr> explain plan for select * from TB_LHR_20160525 where object_id= :a;    Explained.    LHR@dlhr> select * from table(dbms_xplan.display(null,null,'outline'));    PLAN_TABLE_OUTPUT  --------------------------------------------------------------------------------------------------------  Plan hash value: 4254050152    -----------------------------------------------------------------------------------------------  | Id  | Operation                   | Name            | Rows  | Bytes | Cost (%CPU)| Time     |  -----------------------------------------------------------------------------------------------  |   0 | SELECT STATEMENT            |                 |   886 |   179K|     7   (0)| 00:00:01 |  |   1 |  TABLE ACCESS BY INDEX ROWID| TB_LHR_20160525 |   886 |   179K|     7   (0)| 00:00:01 |  |*  2 |   INDEX RANGE SCAN          | IND_TB_LHR_ID   |   354 |       |     1   (0)| 00:00:01 |  -----------------------------------------------------------------------------------------------    Outline Data  -------------      /*+        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    */    Predicate Information (identified by operation id):  ---------------------------------------------------       2 - access("OBJECT_ID"=TO_NUMBER(:A))    Note  -----     - dynamic sampling used for this statement (level=2)    32 rows selected.  

如果我們想讓它走全表掃描,首先獲取全表掃描HINT

LHR@dlhr> explain plan for select /*+ full(TB_LHR_20160525) */* from TB_LHR_20160525 where object_id= :a;    Explained.    LHR@dlhr> select * from table(dbms_xplan.display(null,null,'outline'));    PLAN_TABLE_OUTPUT  -----------------------------------------------------------------------------------------  Plan hash value: 345881005    -------------------------------------------------------------------------------------  | Id  | Operation         | Name            | Rows  | Bytes | Cost (%CPU)| Time     |  -------------------------------------------------------------------------------------  |   0 | SELECT STATEMENT  |                 |   886 |   179K|   352   (2)| 00:00:05 |  |*  1 |  TABLE ACCESS FULL| TB_LHR_20160525 |   886 |   179K|   352   (2)| 00:00:05 |  -------------------------------------------------------------------------------------    Outline Data  -------------      /*+        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    */    Predicate Information (identified by operation id):  ---------------------------------------------------       1 - filter("OBJECT_ID"=TO_NUMBER(:A))    Note  -----     - dynamic sampling used for this statement (level=2)    31 rows selected.  

可以看到全表掃描的Hint已經為我們生成了,我們選取必要的hint就OK了,其它的可以不要,使用SQL Profile

LHR@dlhr> declare    2        v_hints sys.sqlprof_attr;    3  begin    4        v_hints := sys.sqlprof_attr('FULL(@"SEL$1" "TB_LHR_20160525"@"SEL$1")'); ----------從上面Outline Data部分獲取到的HINT    5        dbms_sqltune.import_sql_profile('select * from TB_LHR_20160525 where object_id= :a', ----------SQL語句部分    6                                 v_hints,    7                                 'TB_LHR_20160525', --------PROFILE 的名字    8                                  force_match => true);    9  end;   10  /    PL/SQL procedure successfully completed.    

查看是否生效,已經生效了:

LHR@dlhr> explain plan for select * from TB_LHR_20160525 where object_id= :a;    Explained.    LHR@dlhr> select * from table(dbms_xplan.display);    PLAN_TABLE_OUTPUT  ----------------------------------------------------------------------------------------------------------------------------Plan hash value: 345881005    -------------------------------------------------------------------------------------  | Id  | Operation         | Name            | Rows  | Bytes | Cost (%CPU)| Time     |  -------------------------------------------------------------------------------------  |   0 | SELECT STATEMENT  |                 |   886 |   179K|   352   (2)| 00:00:05 |  |*  1 |  TABLE ACCESS FULL| TB_LHR_20160525 |   886 |   179K|   352   (2)| 00:00:05 |  -------------------------------------------------------------------------------------    Predicate Information (identified by operation id):  ---------------------------------------------------       1 - filter("OBJECT_ID"=TO_NUMBER(:A))    Note  -----     - dynamic sampling used for this statement (level=2)     - SQL profile "TB_LHR_20160525" used for this statement    18 rows selected.    LHR@dlhr>  SELECT b.name,d.sql_text,  extractvalue(value(h),'.') as hints    2     FROM dba_sql_profiles d,SYS.SQLOBJ$DATA A,    3          SYS.SQLOBJ$ B,    4          TABLE(XMLSEQUENCE(EXTRACT(XMLTYPE(A.COMP_DATA),    5                                    '/outline_data/hint'))) h    6    where a.signature = b.signature    7      and a.category = b.category    8      and a.obj_type = b.obj_type    9      and a.plan_id = b.plan_id   10             and a.signature=d.signature   11             and D.name = 'TB_LHR_20160525';    NAME                           SQL_TEXT                                                                         HINTS  ------------------------------ -------------------------------------------------------------------------------- -------------------------------------------------------  TB_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程式設計師面試筆試寶典》,作者:李華榮。