DBA 日常管理过程中会遇到需要把特定的sql语句的执行计划从shared pool 中清除或者需要重新生产新的执行计划的要求。通常的alter system flush shared_pool;或者重新执行信息统计又会造成较大的影响,所以可以使用oracle提供的
dbms_shared_pool.purge 来清除某个特定的sql的执行计划。
下面是关于dbms_shared_pool.purge 的官方介绍:
The syntax for the DBMS_SHARED_POOL.PURGE package is:
procedure purge (name varchar2, flag char DEFAULT 'P', heaps number DEFAULT 1);
name: 指定要处理的对象的名称,有两种情况:
1 PL/SQL 对象 就是对象的名称
2 SQL对象,指定 'address','hash_value' 的 SQL 游标。
标记位 flag是可选的。如果忽略了该参数,则该包默认是包,过程,函数的名称并且忽视名称。否则,该参数就指定一个对象类型。标记位是大小写敏感的。
标记位代表的对象类型:
Value Kind of Object to keep
----- ----------------------
P package/procedure/function
Q sequence
R trigger
T type
JS java source
JC java class
JR java resource
JD java shared data
C cursor --游标
heaps: heaps to purge. e.g if heap 0 and heap 6 are to be purged.
1<<0 | 1<<6 => hex 0x41 => decimal 65. so specify heaps=>65.
Default is 1 i.e heap 0 which means the whole object will be purged.
实验环境 版本:11.2.0.1.0 dbms_shared_pool.purge 只能通过dba才能使用
oracle@rac1:rac1 /home/oracle>sqlplus yang/yang
SQL*Plus: Release 11.2.0.1.0 Production on Fri Jul 8 15:32:43 2011
yang@rac1>create table yangtab (id int) ;
Table created.
yang@rac1>select * from yangtab;
no rows selected
yang@rac1>select address,hash_value,executions,parse_calls
2 from v$sql where sql_text like 'select * from yangtab%';
ADDRESS HASH_VALUE EXECUTIONS PARSE_CALLS
---------------- ---------- ---------- -----------
00000001736EFBB8 3337951036 1 1
yang@rac1>exec dbms_shared_pool.purge('00000001736EFBB8,3337951036','C');
BEGIN dbms_shared_pool.purge('00000001736EFBB8,3337951036','C'); END;
*
ERROR at line 1:
ORA-06550: line 1, column 7:
PLS-00201: identifier 'DBMS_SHARED_POOL.PURGE' must be declared
ORA-06550: line 1, column 7:
PL/SQL: Statement ignored
yang@rac1>conn /as sysdba
Connected.
sys@rac1>create table yangt (id int);
Table created.
sys@rac1>select * from yangt;
no rows selected
sys@rac1>select address,hash_value,executions,parse_calls
2 from v$sql where sql_text like 'select * from yangt%';
ADDRESS HASH_VALUE EXECUTIONS PARSE_CALLS
---------------- ---------- ---------- -----------
00000001736EFBB8 3337951036 1 1 -- 使用普通用户时生成的。
0000000170D9BA50 2693392179 1 1
使用dbms_shared_pool.purge 删除第一个sql的游标。
sys@rac1> exec dbms_shared_pool.purge('00000001736EFBB8,3337951036','C');
PL/SQL procedure successfully completed.
sys@rac1>select address,hash_value,executions,parse_calls
2 from v$sql where sql_text like 'select * from yangt%';
ADDRESS HASH_VALUE EXECUTIONS PARSE_CALLS
---------------- ---------- ---------- -----------
0000000170D9BA50 2693392179 1 1
sys@rac1>exec dbms_shared_pool.purge('0000000170D9BA50,2693392179','C');
PL/SQL procedure successfully completed.
sys@rac1>select address,hash_value,executions,parse_calls
2 from v$sql where sql_text like 'select * from yangt%'
no rows selected