前往小程序,Get更优阅读体验!
立即前往
首页
学习
活动
专区
工具
TVP
发布
社区首页 >专栏 >如何使用coe_xfr_sql_profile绑定手工新生成的执行计划

如何使用coe_xfr_sql_profile绑定手工新生成的执行计划

原创
作者头像
lemotree
修改2022-07-04 10:20:42
7590
修改2022-07-04 10:20:42
举报
文章被收录于专栏:lemotreelemotree

coe_xfr_sql_profile.sql脚本网上找

1.原来的执行计划,走全表,direct path read

代码语言:txt
复制
SELECT 'ext.vivo.vivoIssue.model.ActivityRecords',
       A0.approveNO,
       A0.roleName,
       TO_CHAR (A0.createStampA2, 'dd mm yyyy hh24:mi:ss'),
       A0.markForDeleteA2,
       TO_CHAR (A0.modifyStampA2, 'dd mm yyyy hh24:mi:ss'),
       A0.idA2A2,
       A0.updateCountA2,
       TO_CHAR (A0.updateStampA2, 'dd mm yyyy hh24:mi:ss'),
       A0.wfName,
       A0.wfactivityId,
       A0.wfprocessId
  FROM wcadmin.Activity_Records A0
 WHERE ( (A0.wfprocessId = 'OR:wt.workflow.engine.WfProcess:5114968650' )) AND (A0.markForDeleteA2 = 0)
代码语言:txt
复制
SQL Text
------------------------------
SELECT 'ext.vivo.vivoIssue.model.ActivityRecords',A0.approveNO,A0.roleName,TO_CHAR(A0.createStampA2,'dd mm yyyy hh24:mi:ss'),A0.markForDeleteA2,TO_CHAR(A0.modifyStampA2,'dd mm yyyy hh24:mi:ss'),A0.idA2A2,A0.updateCountA2,TO_CHAR(A0.updateStampA2,'dd mm yyyy hh24:mi:ss'),A0.wfName,A0.wfactivityId,A0.wfprocessId FROM Activity_Records A0 WHERE ((A0.wfprocessId = :1 )) AND (A0.markForDeleteA2 = 0)

Global Information
------------------------------
 Status              :  DONE (ALL ROWS)
 Instance ID         :  1
 Session             :  WCADMIN (298:455)
 SQL ID              :  9bf751pc4r9c9
 SQL Execution ID    :  19283352
 Execution Started   :  05/06/2021 09:52:03
 First Refresh Time  :  05/06/2021 09:52:47
 Last Refresh Time   :  05/06/2021 09:53:12
 Duration            :  69s
 Module/Action       :  JDBC Thin Client/-
 Service             :  SYS$USERS
 Program             :  JDBC Thin Client
 Fetch Calls         :  1

Binds
========================================================================================================================
| Name | Position |      Type      |                                       Value                                       |
========================================================================================================================
| :1   |        1 | VARCHAR2(2000) | OR:wt.workflow.engine.WfProcess:5693043553                                        |
========================================================================================================================

Global Stats
=========================================================================================
| Elapsed |   Cpu   |    IO    | Application |  Other   | Fetch | Buffer | Read | Read  |
| Time(s) | Time(s) | Waits(s) |  Waits(s)   | Waits(s) | Calls |  Gets  | Reqs | Bytes |
=========================================================================================
|      69 |    0.76 |     5.64 |        0.00 |       63 |     1 |   196K | 1543 |   1GB |
=========================================================================================

SQL Plan Monitoring Details (Plan Hash Value=2164340334)
==========================================================================================================================================================
| Id |      Operation      |       Name       |  Rows   | Cost  |   Time    | Start  | Execs |   Rows   | Read | Read  | Activity |   Activity Detail    |
|    |                     |                  | (Estim) |       | Active(s) | Active |       | (Actual) | Reqs | Bytes |   (%)    |     (# samples)      |
==========================================================================================================================================================
|  0 | SELECT STATEMENT    |                  |         |       |        26 |    +44 |     1 |        8 |      |       |          |                      |
|  1 |   TABLE ACCESS FULL | ACTIVITY_RECORDS |      7M | 51180 |        70 |     +1 |     1 |        8 |  998 |   1GB |   100.00 | Cpu (61)             |
|    |                     |                  |         |       |           |        |       |          |      |       |          | direct path read (8) |
==========================================================================================================================================================

2.生成新的执行计划,plan hash value

代码语言:txt
复制
set autotr trace;
set timing on;


SELECT /*+ index(A0 ACTIVITY_RECORDS$COMPOSITE20) */ 'ext.vivo.vivoIssue.model.ActivityRecords',
       A0.approveNO,
       A0.roleName,
       TO_CHAR (A0.createStampA2, 'dd mm yyyy hh24:mi:ss'),
       A0.markForDeleteA2,
       TO_CHAR (A0.modifyStampA2, 'dd mm yyyy hh24:mi:ss'),
       A0.idA2A2,
       A0.updateCountA2,
       TO_CHAR (A0.updateStampA2, 'dd mm yyyy hh24:mi:ss'),
       A0.wfName,
       A0.wfactivityId,
       A0.wfprocessId
  FROM wcadmin.Activity_Records A0
 WHERE ( (A0.wfprocessId = 'OR:wt.workflow.engine.WfProcess:5114968650' )) AND (A0.markForDeleteA2 = 0)
 
 
 
Execution Plan
----------------------------------------------------------
Plan hash value: 1494048713

------------------------------------------------------------------------------------------------------------
| Id  | Operation                   | Name                         | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |                              |  7399K|   987M|   192K  (1)| 00:38:31 |
|*  1 |  TABLE ACCESS BY INDEX ROWID| ACTIVITY_RECORDS             |  7399K|   987M|   192K  (1)| 00:38:31 |
|*  2 |   INDEX RANGE SCAN          | ACTIVITY_RECORDS$COMPOSITE20 |  7603K|       |  7587   (1)| 00:01:32 |
------------------------------------------------------------------------------------------------------------

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

   1 - filter("A0"."MARKFORDELETEA2"=0)
   2 - access("A0"."WFPROCESSID"='OR:wt.workflow.engine.WfProcess:5114968650')


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          8  consistent gets
          0  physical reads
          0  redo size
       2230  bytes sent via SQL*Net to client
        520  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          6  rows processed

SQL> 
 
 

3.通过 coe_xfr_sql_profile.sql绑定新的执行计划

代码语言:txt
复制
sqlplus / as sysdba

SQL> @coe_xfr_sql_profile.sql

Parameter 1:
SQL_ID (required)

Enter value for 1: 9bf751pc4r9c9


PLAN_HASH_VALUE AVG_ET_SECS
--------------- -----------
     2164340334       2.794

Parameter 2:
PLAN_HASH_VALUE (required)

Enter value for 2: 1494048713

Values passed to coe_xfr_sql_profile:
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
SQL_ID         : "9bf751pc4r9c9"
PLAN_HASH_VALUE: "1494048713"

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_9bf751pc4r9c9_1494048713.sql
on TARGET system in order to create a custom SQL Profile
with plan 1494048713 linked to adjusted sql_text.


COE_XFR_SQL_PROFILE completed.
代码语言:txt
复制
SQL>@coe_xfr_sql_profile_9bf751pc4r9c9_1494048713.sql
SQL>REM
SQL>REM $Header: 215187.1 coe_xfr_sql_profile_9bf751pc4r9c9_1494048713.sql 11.4.4.4 2021/05/06 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_9bf751pc4r9c9_1494048713.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 9bf751pc4r9c9 based on plan hash
SQL>REM   value 1494048713.
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_9bf751pc4r9c9_1494048713.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_9bf751pc4r9c9_1494048713');
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 'ext.vivo.vivoIssue.model.ActivityRecords',A0.approveNO,A]');
 15  wa(q'[0.roleName,TO_CHAR(A0.createStampA2,'dd mm yyyy hh24:mi:ss'),A0.]');
 16  wa(q'[markForDeleteA2,TO_CHAR(A0.modifyStampA2,'dd mm yyyy hh24:mi:ss']');
 17  wa(q'[),A0.idA2A2,A0.updateCountA2,TO_CHAR(A0.updateStampA2,'dd mm yyy]');
 18  wa(q'[y hh24:mi:ss'),A0.wfName,A0.wfactivityId,A0.wfprocessId FROM Act]');
 19  wa(q'[ivity_Records A0 WHERE ((A0.wfprocessId = :1 )) AND (A0.markForD]');
 20  wa(q'[eleteA2 = 0)]');
 21  DBMS_LOB.CLOSE(sql_txt);
 22  h := SYS.SQLPROF_ATTR(
 23  q'[BEGIN_OUTLINE_DATA]',
 24  q'[IGNORE_OPTIM_EMBEDDED_HINTS]',
 25  q'[OPTIMIZER_FEATURES_ENABLE('11.2.0.4')]',
 26  q'[DB_VERSION('11.2.0.4')]',
 27  q'[OPT_PARAM('optimizer_index_cost_adj' 10)]',
 28  q'[ALL_ROWS]',
 29  q'[OUTLINE_LEAF(@"SEL$1")]',
 30  q'[INDEX_RS_ASC(@"SEL$1" "A0"@"SEL$1" ("ACTIVITY_RECORDS"."WFPROCESSID"))]',
 31  q'[END_OUTLINE_DATA]');
 32  :signature := DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(sql_txt);
 33  :signaturef := DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(sql_txt, TRUE);
 34  DBMS_SQLTUNE.IMPORT_SQL_PROFILE (
 35  sql_text    => sql_txt,
 36  profile     => h,
 37  name        => 'coe_9bf751pc4r9c9_1494048713',
 38  description => 'coe 9bf751pc4r9c9 1494048713 '||:signature||' '||:signaturef||'',
 39  category    => 'DEFAULT',
 40  validate    => TRUE,
 41  replace     => TRUE,
 42  force_match => FALSE /* TRUE:FORCE (match even when different literals in SQL). FALSE:EXACT (similar to CURSOR_SHARING) */ );
 43  DBMS_LOB.FREETEMPORARY(sql_txt);
 44  END;
 45  /





PL/SQL procedure successfully completed.

SQL>WHENEVER SQLERROR CONTINUE
SQL>SET ECHO OFF;


            SIGNATURE
---------------------
 11333654156062445582


           SIGNATUREF
---------------------
 11333654156062445582


... manual custom SQL Profile has been created


COE_XFR_SQL_PROFILE_9bf751pc4r9c9_1494048713 completed

4. 查看新的执行计划,已用上了profile,走了index,性能改善。

代码语言:txt
复制
SQL>list
  1* select * from table(dbms_xplan.display_cursor('9bf751pc4r9c9',0,'ADVANCED'))
SQL>set line 150
SQL>/

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID  9bf751pc4r9c9, child number 0
-------------------------------------
SELECT 'ext.vivo.vivoIssue.model.ActivityRecords',A0.approveNO,A0.roleNa
me,TO_CHAR(A0.createStampA2,'dd mm yyyy
hh24:mi:ss'),A0.markForDeleteA2,TO_CHAR(A0.modifyStampA2,'dd mm yyyy
hh24:mi:ss'),A0.idA2A2,A0.updateCountA2,TO_CHAR(A0.updateStampA2,'dd mm
yyyy hh24:mi:ss'),A0.wfName,A0.wfactivityId,A0.wfprocessId FROM
Activity_Records A0 WHERE ((A0.wfprocessId = :1 )) AND
(A0.markForDeleteA2 = 0)

Plan hash value: 1494048713

------------------------------------------------------------------------------------------------------------
| Id  | Operation                   | Name                         | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |                              |       |       |   192K(100)|          |
|*  1 |  TABLE ACCESS BY INDEX ROWID| ACTIVITY_RECORDS             |  7399K|   987M|   192K  (1)| 00:38:31 |
|*  2 |   INDEX RANGE SCAN          | ACTIVITY_RECORDS$COMPOSITE20 |  7603K|       |  7587   (1)| 00:01:32 |
------------------------------------------------------------------------------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

   1 - SEL$1 / A0@SEL$1
   2 - SEL$1 / A0@SEL$1

Outline Data
-------------

  /*+
      BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('11.2.0.4')
      DB_VERSION('11.2.0.4')
      OPT_PARAM('optimizer_index_cost_adj' 10)
      ALL_ROWS
      OUTLINE_LEAF(@"SEL$1")
      INDEX_RS_ASC(@"SEL$1" "A0"@"SEL$1" ("ACTIVITY_RECORDS"."WFPROCESSID"))
      END_OUTLINE_DATA
  */

Peeked Binds (identified by position):
--------------------------------------

   1 - :1 (VARCHAR2(30), CSID=873): 'OR:wt.workflow.engine.WfProcess:5684065862'

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

   1 - filter("A0"."MARKFORDELETEA2"=0)
   2 - access("A0"."WFPROCESSID"=:1)

Column Projection Information (identified by operation id):
-----------------------------------------------------------

   1 - "A0"."APPROVENO"[VARCHAR2,6], "A0"."ROLENAME"[VARCHAR2,900], "A0"."CREATESTAMPA2"[DATE,7],
       "A0"."MARKFORDELETEA2"[NUMBER,22], "A0"."MODIFYSTAMPA2"[DATE,7], "A0"."IDA2A2"[NUMBER,22],
       "A0"."UPDATECOUNTA2"[NUMBER,22], "A0"."UPDATESTAMPA2"[DATE,7], "A0"."WFNAME"[VARCHAR2,900],
       "A0"."WFACTIVITYID"[VARCHAR2,900], "A0"."WFPROCESSID"[VARCHAR2,210]
   2 - "A0".ROWID[ROWID,10], "A0"."WFPROCESSID"[VARCHAR2,210]

Note
-----
   - SQL profile coe_9bf751pc4r9c9_1494048713 used for this statement

SQL>

原创声明:本文系作者授权腾讯云开发者社区发表,未经许可,不得转载。

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

原创声明:本文系作者授权腾讯云开发者社区发表,未经许可,不得转载。

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

评论
登录后参与评论
0 条评论
热度
最新
推荐阅读
目录
  • 1.原来的执行计划,走全表,direct path read
  • 2.生成新的执行计划,plan hash value
  • 3.通过 coe_xfr_sql_profile.sql绑定新的执行计划
  • 4. 查看新的执行计划,已用上了profile,走了index,性能改善。
相关产品与服务
数据库
云数据库为企业提供了完善的关系型数据库、非关系型数据库、分析型数据库和数据库生态工具。您可以通过产品选择和组合搭建,轻松实现高可靠、高可用性、高性能等数据库需求。云数据库服务也可大幅减少您的运维工作量,更专注于业务发展,让企业一站式享受数据上云及分布式架构的技术红利!
领券
问题归档专栏文章快讯文章归档关键词归档开发者手册归档开发者手册 Section 归档