标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 kfed MySQL恢复 ORA-00312 ORA-00607 ORA-00704 ORA-01110 ORA-01555 ORA-01578 ORA-08103 ORA-600 2131 ORA-600 2662 ORA-600 2663 ORA-600 3020 ORA-600 4000 ORA-600 4137 ORA-600 4193 ORA-600 4194 ORA-600 16703 ORA-600 kcbzib_kcrsds_1 ORA-600 KCLCHKBLK_4 ORA-15042 ORA-15196 ORACLE 12C oracle dul ORACLE PATCH Oracle Recovery Tools oracle加密恢复 oracle勒索 oracle勒索恢复 oracle异常恢复 Oracle 恢复 ORACLE恢复 ORACLE数据库恢复 oracle 比特币 OSD-04016 YOUR FILES ARE ENCRYPTED 勒索恢复 比特币加密文章分类
- Others (2)
- 中间件 (2)
- WebLogic (2)
- 操作系统 (102)
- 数据库 (1,682)
- DB2 (22)
- MySQL (73)
- Oracle (1,544)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (159)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (7)
- Oracle ASM (67)
- Oracle Bug (8)
- Oracle RAC (53)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (565)
- Oracle安装升级 (92)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (79)
- PostgreSQL (18)
- PostgreSQL恢复 (6)
- SQL Server (27)
- SQL Server恢复 (8)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- 断电引起的ORA-08102: 未找到索引关键字, 对象号 39故障处理
- ORA-00227: corrupt block detected in control file
- 手工删除19c rac
- 解决oracle数据文件路径有回车故障
- .wstop扩展名勒索数据库恢复
- Oracle Recovery Tools工具一键解决ORA-00376 ORA-01110故障(文件offline)
- OGG-02771 Input trail file format RELEASE 19.1 is different from previous trail file form at RELEASE 11.2.
- OGG-02246 Source redo compatibility level 19.0.0 requires trail FORMAT 12.2 or higher
- GoldenGate 19安装和打patch
- dd破坏asm磁盘头恢复
- 删除asmlib磁盘导致磁盘组故障恢复
- Kylin Linux 安装19c
- ORA-600 krse_arc_complete.4
- Oracle 19c 202410补丁(RUs+OJVM)
- ntfs MFT损坏(ntfs文件系统故障)导致oracle异常恢复
- .mkp扩展名oracle数据文件加密恢复
- 清空redo,导致ORA-27048: skgfifi: file header information is invalid
- A_H_README_TO_RECOVER勒索恢复
- 通过alert日志分析客户自行对一个数据库恢复的来龙去脉和点评
- ORA-12514: TNS: 监听进程不能解析在连接描述符中给出的SERVICE_NAME
标签归档:dbms_shared_pool.purge
dbms_shared_pool.purge工作原理猜测
思考为什么dbms_shared_pool.purge清理掉某条sql在shared pool中的信息,为什么当该sql再次执行的时候FIRST_LOAD_TIME时间没有发生改变
测试purge某条sql,再次加重该sql,FIRST_LOAD_TIME不变
SQL> select to_char(sysdate,'yyyy-mm-dd hh24:mi:ss') from dual; TO_CHAR(SYSDATE,'YY ------------------- 2013-02-12 16:44:00 SQL> select SQL_ID,FIRST_LOAD_TIME from v$sql where sql_text like 'select to_char(sysdate,%dual'; SQL_ID FIRST_LOAD_TIME ------------- -------------------------------------- 46zkt5sgbxrxv 2013-02-12/16:43:59 SQL> SELECT ADDRESS,HASH_VALUE,SQL_TEXT FROM V$SQLAREA where sql_id='46zkt5sgbxrxv'; ADDRESS HASH_VALUE -------- ---------- SQL_TEXT -------------------------------------------------------------------------------- 2587FFAC 515825595 select to_char(sysdate,'yyyy-mm-dd hh24:mi:ss') from dual SQL> exec dbms_shared_pool.purge('2587FFAC,515825595','C'); PL/SQL procedure successfully completed. SQL> SELECT ADDRESS,HASH_VALUE,SQL_TEXT FROM V$SQLAREA where sql_id='46zkt5sgbxrxv'; no rows selected SQL> !date Tue Feb 12 16:55:15 CST 2013 SQL> select to_char(sysdate,'yyyy-mm-dd hh24:mi:ss') from dual; TO_CHAR(SYSDATE,'YY ------------------- 2013-02-12 16:55:23 SQL> select FIRST_LOAD_TIME FROM V$SQLAREA where sql_id='46zkt5sgbxrxv'; FIRST_LOAD_TIME -------------------------------------- 2013-02-12/16:43:59
这里可以看出来第一次执行sql语句的时候,FIRST_LOAD_TIME为2013-02-12/16:43:59,然后我使用dbms_shared_pool.purge”清除掉”了SQL语句在shared pool中的信息,但是当我再次执行执行相同的sql时候,查询发现FIRST_LOAD_TIME时间未发生改变.因为v$sql中对应的只有一张基表x$kglcursor_child,并没有where条件,而让记录不在v$sql中显示,证明是x$基表的东西发生了改变,而该基表是直接来自内存,从而个人猜测,oracle的dbms_shared_pool.purge是在shared pool该sql的内存某些部位增加了某些标记,从而使得该sql不能在v$sql等相关视图中显示,如果sql以前占用的内存区域没有被老化出shared pool,下次该sql再次访问的时候,优先启用该内存区域并修改相关值,从而出现了我们的FIRST_LOAD_TIME不改变的现象.
验证猜测
--session 1 SQL> exec dbms_shared_pool.purge('2587FFAC,515825595','C'); PL/SQL procedure successfully completed. SQL> select FIRST_LOAD_TIME FROM V$SQLAREA where sql_id='46zkt5sgbxrxv'; no rows selected SQL> declare 2 begin 3 FOR a IN 1..10000000 4 LOOP 5 EXECUTE IMMEDIATE 'insert into t_xifenfei values ('||a||')'; 6 END LOOP; 7 commit; 8 end; 9 / --session 2 SQL> select count(sql_text) from v$sql where sql_text like 'insert into t_xifenfei%' 2 ; COUNT(SQL_TEXT) --------------- 444 SQL> / COUNT(SQL_TEXT) --------------- 445 SQL> / COUNT(SQL_TEXT) --------------- 444 SQL> / COUNT(SQL_TEXT) --------------- 442 --动态sql还在执行,但是共享池中的该sql不再增加,说明共享池已经满, --部分历史的sql语句已经被刷新出共享池purge的sql语句肯定被老化出来了shared pool,然后再次执行该sql语句 --session 3 SQL> select to_char(sysdate,'yyyy-mm-dd hh24:mi:ss') from dual; TO_CHAR(SYSDATE,'YY ------------------- 2013-02-12 17:09:08 SQL> select SQL_ID,FIRST_LOAD_TIME from v$sql where sql_text like 'select to_char(sysdate,%dual'; SQL_ID FIRST_LOAD_TIME ------------- -------------------------------------- 46zkt5sgbxrxv 2013-02-12/17:09:07
这里可以看到当shared pool发生部分数据被刷出来之时,而且根据先进先出的原则,我们可以知道开始被purge的sql语句肯定被老化出shared pool,从而当再次执行相同sql的时候,生成了新的FIRST_LOAD_TIME,从而验证了部分猜测.
在此也补充另外一个朋友的咨询问题:在什么情况下FIRST_LOAD_TIME会发生改变,我认为是当sql语句占用的内存区域被老化出去,然后再进入内存的时候会发生改变,flush shared_pool实现效果和老化出来一样
SQL> select to_char(sysdate,'yyyy-mm-dd hh24:mi:ss') from dual; TO_CHAR(SYSDATE,'YY ------------------- 2013-02-12 17:09:08 SQL> select SQL_ID,FIRST_LOAD_TIME from v$sql where sql_text like 'select to_char(sysdate,%dual'; SQL_ID FIRST_LOAD_TIME ------------- -------------------------------------- 46zkt5sgbxrxv 2013-02-12/17:09:07 SQL> alter system flush shared_pool; System altered. SQL> select SQL_ID,FIRST_LOAD_TIME from v$sql where sql_text like 'select to_char(sysdate,%dual'; no rows selected SQL> select to_char(sysdate,'yyyy-mm-dd hh24:mi:ss') from dual; TO_CHAR(SYSDATE,'YY ------------------- 2013-02-12 18:52:33 SQL> select SQL_ID,FIRST_LOAD_TIME from v$sql where sql_text like 'select to_char(sysdate,%dual'; SQL_ID FIRST_LOAD_TIME ------------- -------------------------------------- 46zkt5sgbxrxv 2013-02-12/18:52:33
因为shared pool的东西很复杂,我这里也只是大概的初步猜测,没有深入到系统级别dump之类的方法分析,如果有兴趣的朋友可以深入研究并探讨.