Oracle 11g如何清除share pool中某条SQL的执行计划
以前在Oracle 10g数据库上,如果遇到绑定窥探导致执行计划慢的情况,想要清除某条SQL的执行计划,让它硬解析,找了很久都没有找到直接操作share pool的方法(总不能alter system flush shared_pool),只能通过对表ddl使SQL硬解析。现在终于找到了,使用sys.dbms_shared_pool.purge,在11g下可以直接使用,但在10g上需要alter session set events '5614566 trace name context forever'。
SQL> select * from v$version;
BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
PL/SQL Release 11.2.0.1.0 - Production
CORE 11.2.0.1.0 Production
TNS for Linux: Version 11.2.0.1.0 - Production
NLSRTL Version 11.2.0.1.0 - Production
SQL> drop table test purge;
SQL> create table test as select * from dba_objects;
SQL> exec dbms_stats.gather_table_stats(user,'test');
SQL> select /*gg*/count(*) from test;
COUNT(*)
----------
79747
SQL> col SQL_TEXT format a35
SQL> col ADDRESS format a18
SQL> col HASH_VALUE format a10
SQL> select s.SQL_TEXT, s.ADDRESS, s.HASH_VALUE||''
from v$sqlarea s
where sql_text like 'select /*gg*/count(*) from test%';
SQL_TEXT ADDRESS S.HASH_VALUE||''
----------------------------------- ------------------ --------------------------------
select /*gg*/count(*) from test 0000000300B06D70 728448230
SQL> exec sys.dbms_shared_pool.purge('0000000300B06D70,728448230','c');
PL/SQL 过程已成功完成。
SQL> select s.SQL_TEXT, s.ADDRESS, s.HASH_VALUE||''
from v$sqlarea s
where sql_text like 'select /*gg*/count(*) from test%';
未选定行