Oracle 9i闪回查询的新特性

Oracle 9i闪回查询的新特性:

从Oracle 9i开始,Oracle开始提供闪回查询特性(flashback query),允许将回滚段中的数据进行闪回。通过这个例子来看一下这个从Oracle 9i开始提供的新特性。

先查询一下当前数据库的SCN:

sys@TQGZS> select dbms_flashback.get_system_change_number scn from dual;
       SCN
----------
   6369465

在SCOTT用户下更新雇员号为7698,7782,7788的工资为4000:

scott@TQGZS> update emp set sal=4000 where empno in (7698,7782,7788);
3 rows updated.
scott@TQGZS> commit;
Commit complete.

通过特定的语法,可以将SCN为6369465的历史状态数据查询出来:

scott@TQGZS> select * from emp as of scn 6369465 where empno in (7698,7782,7788);
     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 19-APR-87       3000                    20

在结果中,注意到3名员工的薪水恢复到了之前值。而在当前的查询中,这个数值是变化后的4000:

scott@TQGZS> select * from emp where empno in (7698,7782,7788);
     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7788 SCOTT      ANALYST         7566 19-APR-87       4000                    20
      7782 CLARK      MANAGER         7839 09-JUN-81       4000                    10
      7698 BLAKE      MANAGER         7839 01-MAY-81       4000                    30

由于这个查询需要从UNDO中获取前镜像信息,如果UNDO中的信息被覆盖,则以上查询将会失败。为了模拟不同的情况,创建一个新的UNDO表空间,切换数据库使用新的UNDO表空间,再将原表空间Offline:

sys@TQGZS> create undo tablespace undotbs02 datafile '/u01/oracle/oradata/tqgzs/undotbs02.dbf' size 2M;
Tablespace created.
sys@TQGZS> alter system set undo_tablespace=undotbs02;
System altered.
sys@TQGZS> alter tablespace undotbs1 offline;
Tablespace altered.
sys@TQGZS> alter session set events = 'immediate trace name flush_cache';
Session altered.

再来查询,此时出现错误,记录该文件已经不可读取:

scott@TQGZS> select * from emp as of scn 6369465 where empno in (7698,7782,7788);
select * from emp as of scn 6369465 where empno in (7698,7782,7788)
              *
ERROR at line 1:
ORA-00376: file 2 cannot be read at this time
ORA-01110: data file 2: '/u01/oracle/oradata/tqgzs/undotbs01.dbf'

将UNDOTBS1重新启用,则此时前镜像信息再次可以查询:

sys@TQGZS> alter tablespace undotbs1 online;
Tablespace altered.
sys@TQGZS> alter system set undo_tablespace=undotbs1;
System altered.

在其他Session执行大量事务,使得前镜像信息被覆盖:

scott@TQGZS> begin
  2  for i in 1 .. 2000 loop
  3  update emp set sal=4000;
  4  rollback;
  5  end loop;
  6  end;
  7  /
PL/SQL procedure successfully completed.
scott@TQGZS> /
PL/SQL procedure successfully completed.

观察回滚段的使用:

sys@TQGZS> select usn,xacts,rssize,hwmsize from v$rollstat where usn=8;
       USN      XACTS     RSSIZE    HWMSIZE
---------- ---------- ---------- ----------
         8          1     122880     122880

那么再次查询就可能收到如下错误:

scott@TQGZS> select * from emp as of scn 6369465 where empno in (7698,7782,7788);
select * from emp as of scn 6369465 where empno in (7698,7782,7788)
              *
ERROR at line 1:
ORA-01555: snapshot too old: rollback segment number 8 with name "_SYSSMU8$" too small

ORA-01555错误出现,说明要查询的前镜像信息已经失去。

- The End -