脚踏实地、勇往直前!
全部博文(1005)
分类: Oracle
2012-06-02 23:31:39
3.编造一个执行计划不对的SQL
select/*+ full(t)*/ count(1) from scott.tb_test t where t.id=1
我们知道在ID列上有索引,这个SQL走索引是正确的执行计划,但这里强制oracle走全表扫描,然后通过STA,看oracle给出的执行计划是否正确.
4.创建TUNING_TASK并执行
declare
l_task_name varchar2(30);
l_sql clob;
begin
l_sql := 'select/*+ full(t)*/ count(1) from scott.tb_test t where t.id=1';
l_task_name := DBMS_SQLTUNE.CREATE_TUNING_TASK(sql_text => l_sql,
user_name => 'SCOTT',
scope => 'COMPREHENSIVE',
time_limit => 60,
task_name => 'task_name01',
description => null);
dbms_sqltune.Execute_tuning_task(task_name => 'task_name01');
end;
5.查看oracle给出的优化建议
SQL> set serveroutput on;
SQL> set long 999999999;
SQL> SELECT DBMS_SQLTUNE.REPORT_TUNING_TASK('task_name01') FROM DUAL;
DBMS_SQLTUNE.REPORT_TUNING_TASK('TASK_NAME01')
--------------------------------------------------------------------------------
GENERAL INFORMATION SECTION
-------------------------------------------------------------------------------
Tuning Task Name : task_name01
Tuning Task Owner : SYS
Scope : COMPREHENSIVE
Time Limit(seconds) : 60
Completion Status : COMPLETED
Started at : 06/03/2012 00:07:58
Completed at : 06/03/2012 00:07:59
Number of SQL Profile Findings : 1
DBMS_SQLTUNE.REPORT_TUNING_TASK('MY_TASK_NAME01')
--------------------------------------------------------------------------------
-------------------------------------------------------------------------------
Schema Name: SCOTT
SQL ID : ga3q5tqjgsj5u
SQL Text : select/*+ full(t)*/ count(1) from scott.tb_test t where t.id=1
-------------------------------------------------------------------------------
FINDINGS SECTION (1 finding)
-------------------------------------------------------------------------------
1- SQL Profile Finding (see explain plans section below)
--------------------------------------------------------
DBMS_SQLTUNE.REPORT_TUNING_TASK('MY_TASK_NAME01')
--------------------------------------------------------------------------------
A potentially better execution plan was found for this statement.
Recommendation (estimated benefit: 84.11%)
------------------------------------------
- Consider accepting the recommended SQL profile.
execute dbms_sqltune.accept_sql_profile(task_name => 'task_name01',
replace => TRUE);
-------------------------------------------------------------------------------
EXPLAIN PLANS SECTION
-------------------------------------------------------------------------------
DBMS_SQLTUNE.REPORT_TUNING_TASK('TASK_NAME01')
--------------------------------------------------------------------------------
1- Original With Adjusted Cost
------------------------------
Plan hash value: 1372292586
--------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------
-- 当前的执行计划
DBMS_SQLTUNE.REPORT_TUNING_TASK('TASK_NAME01')
--------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 4 | 6 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 4 | | |
|* 2 | TABLE ACCESS FULL| TB_TEST | 1 | 4 | 6 (0)| 00:00:01 |
--------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
DBMS_SQLTUNE.REPORT_TUNING_TASK('TASK_NAME01')
--------------------------------------------------------------------------------
2 - filter("T"."ID"=1)
-- Oracle给出的执行计划
2- Using SQL Profile
--------------------
Plan hash value: 847665939
--------------------------------------------------------------------------------
---
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time
|
DBMS_SQLTUNE.REPORT_TUNING_TASK('TASK_NAME01')
--------------------------------------------------------------------------------
--------------------------------------------------------------------------------
---
| 0 | SELECT STATEMENT | | 1 | 4 | 1 (0)| 00:00:0
1 |
| 1 | SORT AGGREGATE | | 1 | 4 | |
|
|* 2 | INDEX RANGE SCAN| IDX_TB_TEST | 1 | 4 | 1 (0)| 00:00:0
1 |
--------------------------------------------------------------------------------
---
DBMS_SQLTUNE.REPORT_TUNING_TASK('TASK_NAME01')
--------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("T"."ID"=1)
-------------------------------------------------------------------------------
从上面的输出可以看出Oracle给出的执行计划是正确的.可以使用如下方法使用正确的执行计划
begin
dbms_sqltune.accept_sql_profile(task_name => 'task_name01', replace => TRUE);
end;
-- The End --