前往小程序,Get更优阅读体验!
立即前往
首页
学习
活动
专区
工具
TVP
发布
社区首页 >专栏 >【DB笔试面试606】在Oracle中,coe_xfr_sql_profile.sql脚本的作用是什么?

【DB笔试面试606】在Oracle中,coe_xfr_sql_profile.sql脚本的作用是什么?

作者头像
小麦苗DBA宝典
发布2019-09-29 16:05:09
1.4K0
发布2019-09-29 16:05:09
举报

题目部分

在Oracle中,coe_xfr_sql_profile.sql脚本的作用是什么?

答案部分

使用coe_xfr_sql_profile.sql脚本生成sqlprof_attr数据

最麻烦的sqlprof_attr('FULL(t1@SEL$1)')是这里的格式如何写,在Mos上的文章note 215187.1中的sqlt.zip的目录utl中提供了脚本coe_xfr_sql_profile.sql可以生成这些信息。

1.建立测试表和数据

代码语言:javascript
复制
SYS@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 scott.test as select * from dba_objects;

Table created.

LHR@dlhr> create index scott.idx_test_01 on scott.test(object_id);

Index created.

LHR@dlhr> exec dbms_stats.gather_table_stats('scott','test',cascade=>true);

PL/SQL procedure successfully completed.

LHR@dlhr> update scott.test set object_id=10 where object_id>10;


LHR@dlhr> commit;
Commit complete.



LHR@dlhr> select OBJECT_ID ,count(1) from scott.test group by OBJECT_ID;

 OBJECT_ID   COUNT(1)
---------- ----------
         6          1
         7          1
         5          1
         8          1
         3          1
         2          1
        10      87076
         4          1
         9          1

9 rows selected.

2.执行查询语句

执行原有的查询语句,查看执行计划发现走索引,实际上这时表中大部分行的OBJECT_ID都已经被更新为10,所以走索引是不合理的。

代码语言:javascript
复制
LHR@dlhr> set autot traceonly explain stat
LHR@dlhr> 
LHR@dlhr> select * from scott.test where object_id=10;

87076 rows selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 3384190782

-------------------------------------------------------------------------------------------
| Id  | Operation                   | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |             |     1 |    98 |     2   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| TEST        |     1 |    98 |     2   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | IDX_TEST_01 |     1 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("OBJECT_ID"=10)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
      13060  consistent gets
          0  physical reads
          0  redo size
    9855485  bytes sent via SQL*Net to client
      64375  bytes received via SQL*Net from client
       5807  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      87076  rows processed

LHR@dlhr> select /*+ full(test)*/* from scott.test where object_id=10;

87076 rows selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 217508114

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |    98 |   351   (2)| 00:00:05 |
|*  1 |  TABLE ACCESS FULL| TEST |     1 |    98 |   351   (2)| 00:00:05 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("OBJECT_ID"=10)


Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
       6973  consistent gets
          0  physical reads
          0  redo size
    4159482  bytes sent via SQL*Net to client
      64375  bytes received via SQL*Net from client
       5807  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      87076  rows processed

3.查询上面两个语句的SQL_ID、PLAN_HASH_VALUE

代码语言:javascript
复制
LHR@dlhr> set autot off
LHR@dlhr> 
LHR@dlhr> col sql_text format a100
LHR@dlhr> select sql_text,sql_id,plan_hash_value from v$sql
  2  where sql_text like 'select * from scott.test where object_id=10%';

SQL_TEXT                                                                                             SQL_ID        PLAN_HASH_VALUE
---------------------------------------------------------------------------------------------------- ------------- ---------------
select * from scott.test where object_id=10                                                          cpk9jsg2qt52r      3384190782

LHR@dlhr> select sql_text,sql_id,plan_hash_value from v$sql
  2  where sql_text like 'select /*+ full(test)*/* from scott.test where object_id=10%';

SQL_TEXT                                                                                             SQL_ID        PLAN_HASH_VALUE
---------------------------------------------------------------------------------------------------- ------------- ---------------
select /*+ full(test)*/* from scott.test where object_id=10                                          06c2mucgn6t5g       217508114

4.把coe_xfr_sql_profile.sql放在$ORACLE_HOME/rdbms/admin下,或者放在/tmp下都可以。

5.对上面的两个SQL产生outline data的sql.

代码语言:javascript
复制
[ZHLHRSPMDB2:oracle]:/oracle>cd /tmp
[ZHLHRSPMDB2:oracle]:/tmp>
[ZHLHRSPMDB2:oracle]:/tmp>sqlplus / as sysdba

SQL*Plus: Release 11.2.0.4.0 Production on Thu May 26 09:15:14 2016

Copyright (c) 1982, 2013, Oracle.  All rights reserved.


Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
With the Partitioning, Real Application Clusters, OLAP, Data Mining
and Real Application Testing options

SYS@dlhr> @$ORACLE_HOME/rdbms/admin/coe_xfr_sql_profile.sql cpk9jsg2qt52r 3384190782

Parameter 1:
SQL_ID (required)



PLAN_HASH_VALUE AVG_ET_SECS
--------------- -----------
     3384190782        .046

Parameter 2:
PLAN_HASH_VALUE (required)


Values passed to coe_xfr_sql_profile:
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
SQL_ID         : "cpk9jsg2qt52r"
PLAN_HASH_VALUE: "3384190782"

SQL>BEGIN
  2    IF :sql_text IS NULL THEN
  3      RAISE_APPLICATION_ERROR(-20100, 'SQL_TEXT for SQL_ID &&sql_id. was not found in memory (gv$sqltext_with_newlines) or AWR (dba_hist_sqltext).');
  4    END IF;
  5  END;
  6  /
SQL>SET TERM OFF;
SQL>BEGIN
  2    IF :other_xml IS NULL THEN
  3      RAISE_APPLICATION_ERROR(-20101, 'PLAN for SQL_ID &&sql_id. and PHV &&plan_hash_value. was not found in memory (gv$sql_plan) or AWR (dba_hist_sql_plan).');
  4    END IF;
  5  END;
  6  /
SQL>SET TERM OFF;

Execute coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql
on TARGET system in order to create a custom SQL Profile
with plan 3384190782 linked to adjusted sql_text.


COE_XFR_SQL_PROFILE completed.

SQL>@$ORACLE_HOME/rdbms/admin/coe_xfr_sql_profile.sql 06c2mucgn6t5g 217508114

Parameter 1:
SQL_ID (required)



PLAN_HASH_VALUE AVG_ET_SECS
--------------- -----------
      217508114        .113

Parameter 2:
PLAN_HASH_VALUE (required)


Values passed to coe_xfr_sql_profile:
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
SQL_ID         : "06c2mucgn6t5g"
PLAN_HASH_VALUE: "217508114"

SQL>BEGIN
  2    IF :sql_text IS NULL THEN
  3      RAISE_APPLICATION_ERROR(-20100, 'SQL_TEXT for SQL_ID &&sql_id. was not found in memory (gv$sqltext_with_newlines) or AWR (dba_hist_sqltext).');
  4    END IF;
  5  END;
  6  /
SQL>SET TERM OFF;
SQL>BEGIN
  2    IF :other_xml IS NULL THEN
  3      RAISE_APPLICATION_ERROR(-20101, 'PLAN for SQL_ID &&sql_id. and PHV &&plan_hash_value. was not found in memory (gv$sql_plan) or AWR (dba_hist_sql_plan).');
  4    END IF;
  5  END;
  6  /
SQL>SET TERM OFF;

Execute coe_xfr_sql_profile_06c2mucgn6t5g_217508114.sql
on TARGET system in order to create a custom SQL Profile
with plan 217508114 linked to adjusted sql_text.


COE_XFR_SQL_PROFILE completed.

6.替换文件coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql中的SYS.SQLPROF_ATTR部分,把它更改为coe_xfr_sql_profile_06c2mucgn6t5g_217508114.sql中产生的SYS.SQLPROF_ATTR部分,其中:

coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql的SYS.SQLPROF_ATTR:

代码语言:javascript
复制
h := SYS.SQLPROF_ATTR(
q'[BEGIN_OUTLINE_DATA]',
q'[IGNORE_OPTIM_EMBEDDED_HINTS]',
q'[OPTIMIZER_FEATURES_ENABLE('11.2.0.4')]',
q'[DB_VERSION('11.2.0.4')]',
q'[ALL_ROWS]',
q'[OUTLINE_LEAF(@"SEL$1")]',
q'[INDEX_RS_ASC(@"SEL$1" "TEST"@"SEL$1" ("TEST"."OBJECT_ID"))]',
q'[END_OUTLINE_DATA]');

--coe_xfr_sql_profile_06c2mucgn6t5g_217508114.sql的SYS.SQLPROF_ATTR:
h := SYS.SQLPROF_ATTR(
q'[BEGIN_OUTLINE_DATA]',
q'[IGNORE_OPTIM_EMBEDDED_HINTS]',
q'[OPTIMIZER_FEATURES_ENABLE('11.2.0.4')]',
q'[DB_VERSION('11.2.0.4')]',
q'[ALL_ROWS]',
q'[OUTLINE_LEAF(@"SEL$1")]',
q'[FULL(@"SEL$1" "TEST"@"SEL$1")]',
q'[END_OUTLINE_DATA]');
生成的文件在当前目录:

7.执行替换过SYS.SQLPROF_ATTR的SQL,coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql

SQL> @/tmp/coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql

代码语言:javascript
复制
SQL>@coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql
SQL>REM
SQL>REM $Header: 215187.1 coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql 11.4.4.4 2016/05/26 carlos.sierra $
SQL>REM
SQL>REM Copyright (c) 2000-2012, Oracle Corporation. All rights reserved.
SQL>REM
SQL>REM AUTHOR
SQL>REM   carlos.sierra@oracle.com
SQL>REM
SQL>REM SCRIPT
SQL>REM   coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql
SQL>REM
SQL>REM DESCRIPTION
SQL>REM   This script is generated by coe_xfr_sql_profile.sql
SQL>REM   It contains the SQL*Plus commands to create a custom
SQL>REM   SQL Profile for SQL_ID cpk9jsg2qt52r based on plan hash
SQL>REM   value 3384190782.
SQL>REM   The custom SQL Profile to be created by this script
SQL>REM   will affect plans for SQL commands with signature
SQL>REM   matching the one for SQL Text below.
SQL>REM   Review SQL Text and adjust accordingly.
SQL>REM
SQL>REM PARAMETERS
SQL>REM   None.
SQL>REM
SQL>REM EXAMPLE
SQL>REM   SQL> START coe_xfr_sql_profile_cpk9jsg2qt52r_3384190782.sql;
SQL>REM
SQL>REM NOTES
SQL>REM   1. Should be run as SYSTEM or SYSDBA.
SQL>REM   2. User must have CREATE ANY SQL PROFILE privilege.
SQL>REM   3. SOURCE and TARGET systems can be the same or similar.
SQL>REM   4. To drop this custom SQL Profile after it has been created:
SQL>REM  EXEC DBMS_SQLTUNE.DROP_SQL_PROFILE('coe_cpk9jsg2qt52r_3384190782');
SQL>REM   5. Be aware that using DBMS_SQLTUNE requires a license
SQL>REM  for the Oracle Tuning Pack.
SQL>REM   6. If you modified a SQL putting Hints in order to produce a desired
SQL>REM  Plan, you can remove the artifical Hints from SQL Text pieces below.
SQL>REM  By doing so you can create a custom SQL Profile for the original
SQL>REM  SQL but with the Plan captured from the modified SQL (with Hints).
SQL>REM
SQL>WHENEVER SQLERROR EXIT SQL.SQLCODE;
SQL>REM
SQL>VAR signature NUMBER;
SQL>VAR signaturef NUMBER;
SQL>REM
SQL>DECLARE
  2  sql_txt CLOB;
  3  h       SYS.SQLPROF_ATTR;
  4  PROCEDURE wa (p_line IN VARCHAR2) IS
  5  BEGIN
  6  DBMS_LOB.WRITEAPPEND(sql_txt, LENGTH(p_line), p_line);
  7  END wa;
  8  BEGIN
  9  DBMS_LOB.CREATETEMPORARY(sql_txt, TRUE);
 10  DBMS_LOB.OPEN(sql_txt, DBMS_LOB.LOB_READWRITE);
 11  -- SQL Text pieces below do not have to be of same length.
 12  -- So if you edit SQL Text (i.e. removing temporary Hints),
 13  -- there is no need to edit or re-align unmodified pieces.
 14  wa(q'[select * from scott.test where object_id=10]');
 15  DBMS_LOB.CLOSE(sql_txt);
 16  h := SYS.SQLPROF_ATTR(
 17  q'[BEGIN_OUTLINE_DATA]',
 18  q'[IGNORE_OPTIM_EMBEDDED_HINTS]',
 19  q'[OPTIMIZER_FEATURES_ENABLE('11.2.0.4')]',
 20  q'[DB_VERSION('11.2.0.4')]',
 21  q'[ALL_ROWS]',
 22  q'[OUTLINE_LEAF(@"SEL$1")]',
 23  q'[FULL(@"SEL$1" "TEST"@"SEL$1")]',
 24  q'[END_OUTLINE_DATA]');
 25  :signature := DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(sql_txt);
 26  :signaturef := DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(sql_txt, TRUE);
 27  DBMS_SQLTUNE.IMPORT_SQL_PROFILE (
 28  sql_text    => sql_txt,
 29  profile     => h,
 30  name        => 'coe_cpk9jsg2qt52r_3384190782',
 31  description => 'coe cpk9jsg2qt52r 3384190782 '||:signature||' '||:signaturef||'',
 32  category    => 'DEFAULT',
 33  validate    => TRUE,
 34  replace     => TRUE,
 35  force_match => FALSE /* TRUE:FORCE (match even when different literals in SQL). FALSE:EXACT (similar to CURSOR_SHARING) */ );
 36  DBMS_LOB.FREETEMPORARY(sql_txt);
 37  END;
 38  /

PL/SQL procedure successfully completed.

SQL>WHENEVER SQLERROR CONTINUE
SQL>SET ECHO OFF;

            SIGNATURE
---------------------
 10910590721604799112


           SIGNATUREF
---------------------
 15966118871002195466


... manual custom SQL Profile has been created


COE_XFR_SQL_PROFILE_cpk9jsg2qt52r_3384190782 completed

8.查看产生的sql profile,此时原语句在不加hint的情况下也走全表扫了select * from dba_sql_profiles;

代码语言:javascript
复制
SYS@dlhr> col sql_text for a50
SYS@dlhr> col hints for a50
SYS@dlhr>  SELECT b.name,to_char(d.sql_text) 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 = 'coe_cpk9jsg2qt52r_3384190782';

NAME                           SQL_TEXT                                           HINTS
------------------------------ -------------------------------------------------- --------------------------------------------------
coe_cpk9jsg2qt52r_3384190782   select * from scott.test where object_id=10        BEGIN_OUTLINE_DATA
coe_cpk9jsg2qt52r_3384190782   select * from scott.test where object_id=10        IGNORE_OPTIM_EMBEDDED_HINTS
coe_cpk9jsg2qt52r_3384190782   select * from scott.test where object_id=10        OPTIMIZER_FEATURES_ENABLE('11.2.0.4')
coe_cpk9jsg2qt52r_3384190782   select * from scott.test where object_id=10        DB_VERSION('11.2.0.4')
coe_cpk9jsg2qt52r_3384190782   select * from scott.test where object_id=10        ALL_ROWS
coe_cpk9jsg2qt52r_3384190782   select * from scott.test where object_id=10        OUTLINE_LEAF(@"SEL$1")
coe_cpk9jsg2qt52r_3384190782   select * from scott.test where object_id=10        FULL(@"SEL$1" "TEST"@"SEL$1")
coe_cpk9jsg2qt52r_3384190782   select * from scott.test where object_id=10        END_OUTLINE_DATA

8 rows selected.

9.验证SQL Profile是否生效

代码语言:javascript
复制
SYS@dlhr> set autot traceonly explain stat
SYS@dlhr> select * from scott.test where object_id=10;

87076 rows selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 217508114

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |    98 |   351   (2)| 00:00:05 |
|*  1 |  TABLE ACCESS FULL| TEST |     1 |    98 |   351   (2)| 00:00:05 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("OBJECT_ID"=10)

Note
-----
   - SQL profile "coe_cpk9jsg2qt52r_3384190782" used for this statement


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       6973  consistent gets
          0  physical reads
          0  redo size
    4159482  bytes sent via SQL*Net to client
      64375  bytes received via SQL*Net from client
       5807  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      87076  rows processed

注意:

① 这个测试只是为了演示通过coe_xfr_sql_profile.sql实现手动加hint的方法,实际上面的语句问题的处理最佳的方法应该是重新收集SCOTT.TEST的统计信息才对。

② 当一条SQL既有Sql Profile又有Stored Outline时,优化器优先选择stored outline。

③ 通过Sql Profile手动加Hint的方法很简单,而为SQL添加最合理的Hint才是关键。

④ 测试完后,可以通过exec dbms_sqltune.drop_sql_profile(name =>'coe_cpk9jsg2qt52r_3384190782' );删除这个Sql Profile。

⑤ 执行coe_xfr_sql_profile.sql脚本的时候用户需要对当前目录有生成文件的权限,最好当前目录是/tmp。

本文选自《Oracle程序员面试笔试宝典》,作者:李华荣。

本文参与 腾讯云自媒体分享计划,分享自微信公众号。
原始发表:2019-08-01,如有侵权请联系 cloudcommunity@tencent.com 删除

本文分享自 DB宝 微信公众号,前往查看

如有侵权,请联系 cloudcommunity@tencent.com 删除。

本文参与 腾讯云自媒体分享计划  ,欢迎热爱写作的你一起参与!

评论
登录后参与评论
0 条评论
热度
最新
推荐阅读
领券
问题归档专栏文章快讯文章归档关键词归档开发者手册归档开发者手册 Section 归档