我们经常会碰到一些线上的SQL问题,因为执行计划不对,可能需要添加HINT才能解决。但是添加HINT就意味着需要修改应用代码。一般一个应用代码的修改、测试及发布,可能需要两三个工作日才可完成。咱们数据库可等不起这个时间,必须要在短时间内解决这个SQL问题。这时候,SQL PROFILE就挺身而出了!它可以让DBA在不修改应用代码程序的情况下,修改SQL的执行计划。
要使用SQL PROFILE,必须要有create any sql profile,drop any sql profile,alter any sql profile的权限。在11G中不建议给ANY PROFILE的权限,最好是administer sql management object权限
SQL调优建议器的核心接口是通过dbms_sqltune包来提供的。为了开始一个调优任务,则必须要调用函数create_tuning_task.
第一步,创建一个调优任务
SET TERMOUT ON FEEDBACK OFF VERIFY OFF SCAN ON LONG 1000000 ECHO ON VARIABLE tuning_task VARCHAR2(30) BEGIN :tuning_task := dbms_sqltune.create_tuning_task(sql_id => ’09w1j9gt9pnng’); –SQL_ID需要替换 dbms_sqltune.execute_tuning_task(:tuning_task); END; /第二步,分析调优结果
SELECT dbms_sqltune.report_tuning_task(:tuning_task) FROM dual; …… 1- SQL Profile Finding (see explain plans section below) ——————————————————– A potentially better execution plan was found for this statement. Recommendation (estimated benefit: 99.97%) —————————————— - Consider accepting the recommended SQL profile. execute dbms_sqltune.accept_sql_profile(task_name => ‘TASK_23′, task_owner => ‘SHUJUKUAI’, replace => TRUE); ——————————————————————————- EXPLAIN PLANS SECTION - —————————————————————————— 1- Original With Adjusted Cost —————————— Plan hash value: 1950795681 ————————————————————————— | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ————————————————————————— | 0 | SELECT STATEMENT | | 1 | 5 | 4913 (1)| 00:00:59 | | 1 | SORT AGGREGATE | | 1 | 5 | | | |* 2 | TABLE ACCESS FULL| TEST | 1 | 5 | 4913 (1)| 00:00:59 | ————————————————————————— Predicate Information (identified by operation id): ————————————————— 2 – filter(“OBJECT_ID”<10) 2- Using SQL Profile ——————– Plan hash value: 917719789 —————————————————————————— | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | —————————————————————————— | 0 | SELECT STATEMENT | | 1 | 5 | 3 (0)| 00:00:01 | | 1 | SORT AGGREGATE | | 1 | 5 | | | |* 2 | INDEX RANGE SCAN| TEST_IND | 1 | 5 | 3 (0)| 00:00:01 | —————————————————————————— Predicate Information (identified by operation id): ————————————————— 2 – access(“OBJECT_ID”<10) ——————————————————————————-从上面的调优结果中看出,ORACLE给了另一个更好的调优建议。但是我们是否需要接受它呢?
第三步,接受此调优建议
DECLARE my_sqlprofile_name VARCHAR2(30); BEGIN my_sqlprofile_name := DBMS_SQLTUNE.ACCEPT_SQL_PROFILE ( task_name => ‘TASK_23′, name => ‘my_sql_profile’, category =>’test’, –若不设置,则于DEFAULT description => ‘shujukuai test sql profile’, force_match => TRUE); –指定文档标准化 END; /注:force_match为true,则SQL文本的空白、大小写和字面 量均不区分;不过,如果SQL语句中出现绑定变更就不能消除字面量影响了。force_match为false,则仅不区分大小写和空白。
当我们的SQL概要被数据库所接受以后,则可以在dba_sql_profiles中查看到对应的信息。
第四步,激活SQL概要
SQL概要的激活是由sqltule_category参数在系统级或会话级来控制的。由于刚刚在接受SQL概要的时候,指定了category为TEST,所以我们需要做以下修改才可能使用它:
ALTER SESSION SET SQLTUNE_CATEGORY=TEST;第五步,验证
explain plan for select /*+ full(test)*/ count(*) from test where object_id<10; select * from table(dbms_xplan.display(null,null,’outline’)); Outline Data ————- /*+ BEGIN_OUTLINE_DATA INDEX(@”SEL$1″ “TEST”@”SEL$1” (“TEST”.”OBJECT_ID”)) OUTLINE_LEAF(@”SEL$1″) ALL_ROWS DB_VERSION(’11.2.0.2′) OPTIMIZER_FEATURES_ENABLE(’11.2.0.2′) IGNORE_OPTIM_EMBEDDED_HINTS END_OUTLINE_DATA */ Predicate Information (identified by operation id): ————————————————— 2 – access(“OBJECT_ID”<10) Note —– - SQL profile “my_sql_profile” used for this statement第六步,线下模拟删除PROFILE
BEGIN DBMS_SQLTUNE.DROP_SQL_PROFILE( name => ‘my_sql_profile’ ); END; /第七步,导入SQL PROFILE
declare v_hints sys.sqlprof_attr; v_sql_fulltext clob; begin select SQL_FULLTEXT into v_sql_fulltext from v$sqlarea where sql_id =‘ar1b2dvf3dayj’; –替换SQL_ID v_hints := sys.sqlprof_attr(‘INDEX(@”SEL$1″SEL$1” (“TEST”.”OBJECT_ID”))’, ‘OUTLINE_LEAF(@”SEL$1″)’, ’ALL_ROWS’, ’IGNORE_OPTIM_EMBEDDED_HINTS’); dbms_sqltune.import_sql_profile( name =>’import_sql_profile’, sql_text => v_sql_fulltext, profile => v_hints, description => ‘how to use sql_profile’, force_match => true); end; /第八步,再次验证执行计划
以上简单的八步,就完成了线下的SQL PROFILE产生与验证。剩下的,只需要把第七步再拿到线上执行并验证即可。
虽然SQL PROFILE用法简单,也可以迅速地解决线上SQL问题。但是,把这玩意儿长期放在数据库中,总感觉是一种隐患。我对它的理解,sql profile仅可用于应急,最终还是得由应用程序修改,解决问题后,删除sql profile,这我才可放心。
另外,有一点是需要提醒的,当SQL概要依赖的对象被删除的时候,SQL概要并不会删除。ORACLE为什么不把它级联删除掉呢? 可以想像一下,当删除一个索引的时候,基本可以说明它是没有价值的。但是如索引重新组织或重建后,我们可能还是需要SQL PROFILE的,如果在重建的时候删除了,使用这个profile的SQL语句又杯具了。
--1
SQL>
create table t1 as select object_id,object_name from dba_objects where
rownum<=50000;
SQL> create table t2 as select * from
dba_objects;
SQL> create index t2_idx on t2(object_id);
SQL> exec
dbms_stats.gather_table_stats(user,'t1',cascade=>true,method_opt=>'for all
columns size 1');
SQL> exec
dbms_stats.gather_table_stats(user,'t2',cascade=>true,method_opt=>'for all
columns size 1');
SQL> exec
dbms_stats.set_table_stats('TEST1','T1',numrows=>49953);
--2
explain plan for select /*+ use_nl(t1 t2) index(t2) */
t1.*,t2.owner from t1,t2 where t1.object_name like '%T1%' and t1.object_id=t2.object_id;
--3
SQL> var
tuning_task varchar2(100);
SQL> DECLARE
2 l_sql_id
v$session.prev_sql_id%TYPE;
3 l_tuning_task VARCHAR2(30);
4
BEGIN
5 l_sql_id:='4zbqykx89yc8v';
6 l_tuning_task :=
dbms_sqltune.create_tuning_task(sql_id => l_sql_id);
7
:tuning_task:=l_tuning_task;
8
dbms_sqltune.execute_tuning_task(l_tuning_task);
9
dbms_output.put_line(l_tuning_task);
10 END;
11 /
SQL> print tuning_task;
TUNING_TASK
-------------------------------------------------------------------
任务_74
SQL> SELECT
dbms_sqltune.report_tuning_task(:tuning_task) FROM dual;
DBMS_SQLTUNE.REPORT_TUNING_TASK(:TUNING_TASK)
--------------------------------------------------------------------------------
GENERAL INFORMATION SECTION
-------------------------------------------------------------------------------
Tuning Task Name : 任务_74
Tuning Task Owner
: TEST1
Scope : COMPREHENSIVE
Time
Limit(seconds) : 1800
Completion Status :
COMPLETED
Started at : 12/15/2010 09:56:02
Completed at : 12/15/2010 09:56:03
Number of SQL
Profile Findings : 1
-------------------------------------------------------------------------------
Schema Name: TEST1
SQL ID : 4zbqykx89yc8v
SQL Text : select
t1.*,t2.owner from t1,t2 where t1.object_name like '%T1%'
and
t1.object_id=t2.object_id
-------------------------------------------------------------------------------
FINDINGS SECTION (1 finding)
-------------------------------------------------------------------------------
1- SQL Profile Finding (see explain plans section below)
--------------------------------------------------------
为此语句找到了性能
Recommendation (estimated benefit: 46.62%)
------------------------------------------
-考虑接受推荐的 SQL
executedbms_sqltune.accept_sql_profile(task_name => '任务_74', replace = TRUE);
-------------------------------------------------------------------------------
EXPLAIN PLANS SECTION
-------------------------------------------------------------------------------
1- Original With Adjusted Cost
------------------------------
Plan hash value: 1838229974
---------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 29 | 1160 | 219 (4)| 00:00:03 |
|* 1 | HASH JOIN | | 29 | 1160 | 219 (4)| 00:00:03 |
|* 2 | TABLE ACCESS FULL| T1 | 29 | 841 | 59 (6)| 00:00:01 |
| 3 | TABLE ACCESS FULL| T2 | 49954 | 536K| 159 (2)| 00:00:02 |
---------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 -
access("T1"."OBJECT_ID"="T2"."OBJECT_ID")
2 - filter("T1"."OBJECT_NAME"
LIKE '%T1%')
2- Using SQL Profile
--------------------
Plan
hash value: 3787413387
--------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
Time |
--------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 29 | 1160 | 117 (3)|
00:00:02 |
| 1 | TABLE ACCESS BY INDEX ROWID| T2 | 1 | 11 |
2 (0)| 00:00:01 |
| 2 | NESTED LOOPS | | 29
| 1160 | 117 (3)| 00:00:02 |
|* 3 | TABLE ACCESS FULL | T1
| 29 | 841 | 59 (6)| 00:00:01 |
|* 4 | INDEX RANGE SCAN
| T2_IDX | 1 | | 1 (0)| 00:00:01 |
--------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 -
filter("T1"."OBJECT_NAME" LIKE '%T1%')
4 -
access("T1"."OBJECT_ID"="T2"."OBJECT_ID")
--4
SQL>
execute dbms_sqltune.accept_sql_profile(task_name => :tuning_task,replace
=> TRUE,force_match=>true);
--5
select name,category,signature,type,status,force_matching
from dba_sql_profiles;
select * from sys.sqlprof$attr;
--6
SQL>
exec
dbms_sqltune.drop_sql_profile('SYS_SQLPROF_014b39f084c88000');
SQL> declare
2 v_hints
sys.sqlprof_attr;
3 begin
4
v_hints:=sys.sqlprof_attr('USE_NL(T1 T2)','INDEX(T2)');
5
dbms_sqltune.import_sql_profile('select t1.*,t2.owner from t1,t2 where
t1.object_name like ''%T1%'' and t1.object_id=t2.object_id',
6
v_hints,'SQLPROFILE_NAME1',force_match=>true);
7 end;
8
/
SQL> select attr_val from
dba_sql_profiles a, sys.sqlprof$attr b where a.signature = b.signature and a.name='SQLPROFILE_NAME1';
--=================================================================================
1:/*+
hists arfter*/调优后
SET AUTOT
TRACE EXP
set lines 200 pages 123
select * from
table(dbms_xplan.display_cursor('xxxxxxxx',null,'outline'));
2:创建sql
profile
declare
v_hints sys.sqlprof_attr;
v_sql_fulltext clob;
begin
select SQL_FULLTEXT into v_sql_fulltext from v$sqlarea where sql_id
='xxxxxxxx';
v_hints := sys.sqlprof_attr(
'INDEX(@"SEL$1"
("TEST"."OBJECT_ID"))',
'OUTLINE_LEAF(@"SEL$1″)',
'ALL_ROWS',
'IGNORE_OPTIM_EMBEDDED_HINTS'
);
dbms_sqltune.import_sql_profile(
name
=>'import_sql_profile_1223',
sql_text =>
v_sql_fulltext,
profile => v_hints,
description => 'erp xxxx sql_profile',
force_match=>true,replace=>true);
end;
/