SQL> 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 Linux: Version 11.2.0.4.0 - Production
NLSRTL Version 11.2.0.4.0 - Production
SQL> create table test as select * from dba_objects;
Table created.
SQL> create index i_test_id on test(object_id);
Index created.
SQL> exec dbms_stats.gather_table_stats('SYS','TEST',cascade=>true);
PL/SQL procedure successfully completed.
SQL>
+++测试用PROFILE将索引范围扫描的执行计划调整为全表扫扫描
SQL> select object_name from test where object_id=10;
Execution Plan
----------------------------------------------------------
Plan hash value: 2225164668
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 30 | 2 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| TEST | 1 | 30 | 2 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | I_TEST_ID | 1 | | 1 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("OBJECT_ID"=10)
SQL> select /*+full(test)*/ object_name from test where object_id=10;
Execution Plan
----------------------------------------------------------
Plan hash value: 1357081020
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 30 | 337 (1)| 00:00:05 |
|* 1 | TABLE ACCESS FULL| TEST | 1 | 30 | 337 (1)| 00:00:05 |
--------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("OBJECT_ID"=10)
SQL> select sql_id,sql_text from v$sql where sql_text like '%from test%';
f9h894yhsf9bb select object_name from test where object_id=10
461yxn1fhgrkk select /*+full(test)*/ object_name from test where object_id=10
+++查看全表扫描执行计划的OUTLINE
SQL> SET PAGESIZE 10000
SQL> select * from table(dbms_xplan.display_cursor('461yxn1fhgrkk',null,'outline'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------------------------------------
SQL_ID 461yxn1fhgrkk, child number 0
-------------------------------------
select /*+full(test)*/ object_name from test where object_id=10
Plan hash value: 1357081020
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 337 (100)| |
|* 1 | TABLE ACCESS FULL| TEST | 1 | 30 | 337 (1)| 00:00:05 |
--------------------------------------------------------------------------
Outline Data
-------------
/*+
BEGIN_OUTLINE_DATA
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('11.2.0.4')
DB_VERSION('11.2.0.4')
ALL_ROWS
OUTLINE_LEAF(@"SEL$1")
FULL(@"SEL$1" "TEST"@"SEL$1")
END_OUTLINE_DATA
*/
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("OBJECT_ID"=10)
32 rows selected.
SQL>
+++创建SQLPROFILE
declare
v_hints sys.sqlprof_attr;
begin
v_hints:=sys.sqlprof_attr(
'BEGIN_OUTLINE_DATA',
'IGNORE_OPTIM_EMBEDDED_HINTS',
'OPTIMIZER_FEATURES_ENABLE(''11.2.0.4'')',
'DB_VERSION(''11.2.0.4'')',
'ALL_ROWS',
'OUTLINE_LEAF(@"SEL$1")',
'FULL(@"SEL$1" "TEST"@"SEL$1")',
'END_OUTLINE_DATA');
dbms_sqltune.import_sql_profile(
'Select object_name from test where object_id=10',
v_hints,'SQLPROFILE_MYPROFILE1',
force_match=>true,replace=>true);
end;
/
+++验证SQLPROFILE
SQL> set autot trace exp
SQL> select object_name from test where object_id=100;
Execution Plan
----------------------------------------------------------
Plan hash value: 1357081020
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 30 | 337 (1)| 00:00:05 |
|* 1 | TABLE ACCESS FULL| TEST | 1 | 30 | 337 (1)| 00:00:05 |
--------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("OBJECT_ID"=100)
Note
-----
- SQL profile "SQLPROFILE_MYPROFILE1" used for this statement
+++查看系统当前使用的PROFILE
SQL> select name,SQL_TEXT,TYPE,STATUS from dba_sql_profiles
NAME SQL_TEXT TYPE STATUS
---------------------- ------------------------------------------------------------ ------- --------
SQLPROFILE_MYPROFILE1 Select object_name from test where object_id=10 MANUAL ENABLED
阅读(1659) | 评论(0) | 转发(0) |