闪回数据归档
虽然ORA-01555错误可以通过种种手段来避免和减少,但是随着时间的流逝,这些UNDO信息总会失去,那么能否将这些信息保存起来,使得数据库在一定的历史周期之内可以不断向后追溯,使得我们可以看到一个数据表在任意历史时间点上的切片呢?
从Oracle Database 11g开始,Oracle 提供了一个这样的功能:闪回数据归档(Flashback Data Archive)。通过这一功能Oracle数据库可以将UNDO数据进行归档,从而提供全面的历史数据查询,也因此Oracle引入一个新的概念 Oracle Total Recall,也即Oracle全面回忆功能。闪回数据归档可以和我们一直熟悉的日志归档类比,日志归档记录的是Redo的历史状态,用于保证恢复的连续性;而闪回归档记录的是UNDO的历史状态,可以用于对数据进行闪回追溯查询;后台进程LGWR用于将Redo信息写出到日志文件,ARCH进程负责进行日志归档;在Oracle 11g中,新增的后台进程FBDA(Flashback Data Archiver Process)则用于对闪回数据进行归档写出:
闪回归档数据甚至可以以年为单位进行保存,Oracle可以通过内部分区和压缩算法减少空间耗用,这一特性对于需要审计以及历史数据分区的环境尤其有用,但是注意,对于繁忙的数据库环境,闪回数据存储显然要耗用更多的存储空间。当然,用户可以根据需要,对部分表进行闪回数据归档,从而满足特定的业务需求。
因为闪回数据归档需要独立的存储,所以在使用该特性之前需要创建独立的ASSM(自动段空间管理)表空间:
sys@TQGZS11G> create tablespace fbda datafile '/oracle/oradata/tqgzs11g/FBDA.dbf' size 200M segment space management auto;
Tablespace created.
然后可以基于该表空间创建闪回数据归档区,FLASHBACK ARCHIVE ADMINISTER系统权限是创建闪回数据存档所必需的,此处使用SYS用户进行:
sys@TQGZS11G> create flashback archive fda tablespace fbda retention 1 month;
Flashback archive created.
此后就可以使用该归档区来记录数据表的闪回数据量。为了测试方便,先将UNDO表空间更改为较小,以使得UNDO数据能够尽快老化:
sys@TQGZS11G> create undo tablespace UNDOTBS2_SMALL datafile '/oracle/oradata/tqgzs11g/UNDOTBS2_SMALL.dbf' size 20M autoextend off;
Tablespace created.
sys@TQGZS11G> alter system set undo_tablespace= UNDOTBS2_SMALL;
System altered.
sys@TQGZS11G> show parameter undo
NAME TYPE VALUE
------------------------------------ ------------------------------ ------------------------------
undo_management string AUTO
undo_retention integer 900
undo_tablespace string UNDOTBS2_SMALL
接下来使用测试用户连接,对测试表执行闪回归档设置,FLASHBACK ARCHIVE对象权限是启用历史数据跟踪所必需的:
sys@TQGZS11G> conn tq/tq
Connected.
tq@TQGZS11G> select TABLE_NAME from user_tables;
TABLE_NAME
--------------------
T
EMP
tq@TQGZS11G> alter table t flashback archive fda;
Table altered.
取消对于数据表的闪回归档可以使用如下命令:
alter table table_name no flashback archive;
接下来记录一下SCN,从数据库表中删除部分数据:
tq@TQGZS11G> select dbms_flashback.get_system_change_number from dual;
GET_SYSTEM_CHANGE_NUMBER
------------------------
1142115
tq@TQGZS11G> select count(*) from t;
COUNT(*)
----------
69266
tq@TQGZS11G> delete from t where rownum < 1001;
1000 rows deleted.
tq@TQGZS11G> commit;
Commit complete.
现在执行闪回查询,则数据来自UNDO表空间:
tq@TQGZS11G> select count(*) from t as of scn 1142115;
COUNT(*)
----------
69266
Execution Plan
----------------------------------------------------------
Plan hash value: 2966233522
-------------------------------------------------------------------
| Id | Operation | Name | Rows | Cost (%CPU)| Time |
-------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 1048 (1)| 00:00:13 |
| 1 | SORT AGGREGATE | | 1 | | |
| 2 | TABLE ACCESS FULL| T | 69266 | 1048 (1)| 00:00:13 |
-------------------------------------------------------------------
接下来执行一小段批量循环代码,使UNDO数据老化覆盖:
tq@TQGZS11G> begin
2 for i in 1 .. 100 loop
3 delete from t where rownum < 31;
4 commit;
5 end loop;
6 end;
7 /
PL/SQL procedure successfully completed.
现在来看一下闪回数据归档发挥作用的闪回查询,通过执行计划能够看到和之前查询执行方式的不同:
tq@TQGZS11G> select count(*) from t as of scn 1142115;
COUNT(*)
----------
69266
Execution Plan
----------------------------------------------------------
Plan hash value: 1421074822
----------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
----------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | | 1151 (1)| 00:00:14 | | |
| 1 | SORT AGGREGATE | | 1 | | | | | |
| 2 | VIEW | | 20633 | | 1151 (1)| 00:00:14 | | |
| 3 | UNION-ALL | | | | | | | |
| 4 | PARTITION RANGE SINGLE| | 20295 | 515K| 69 (2)| 00:00:01 | 1 | 1 |
|* 5 | TABLE ACCESS FULL | SYS_FBA_HIST_72661 | 20295 | 515K| 69 (2)| 00:00:01 | 1 | 1 |
|* 6 | FILTER | | | | | | | |
|* 7 | HASH JOIN OUTER | | 338 | 669K| 1081 (1)| 00:00:13 | | |
|* 8 | TABLE ACCESS FULL | T | 3463 | 41556 | 1048 (1)| 00:00:13 | | |
| 9 | VIEW | | 19522 | 37M| 32 (0)| 00:00:01 | | |
|* 10 | TABLE ACCESS FULL | SYS_FBA_TCRV_72661 | 19522 | 37M| 32 (0)| 00:00:01 | | |
----------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
5 - filter("ENDSCN">1142115 AND "ENDSCN"<=1145328 AND ("STARTSCN" IS NULL OR "STARTSCN"<=1142115))
6 - filter("F"."STARTSCN"<=1142115 OR "F"."STARTSCN" IS NULL)
7 - access("T".ROWID=CHARTOROWID("F"."RID"(+)))
8 - filter("T"."VERSIONS_STARTSCN" IS NULL)
10 - filter(("ENDSCN" IS NULL OR "ENDSCN">1145328) AND ("STARTSCN" IS NULL OR "STARTSCN"<1145328))
Note
-----
- dynamic sampling used for this statement
通过以上执行计划可以看到,查询闪回来自SYS_FBA_TCRV_72661系统表,该表隶属于闪回归档表空间,用于记录闪回数据:
tq@TQGZS11G> desc SYS_FBA_TCRV_72661
Name Null? Type
----------------- -------- ---------------------
RID VARCHAR2(4000)
STARTSCN NUMBER
ENDSCN NUMBER
XID RAW(8)
OP VARCHAR2(1)
tq@TQGZS11G> select count(*) from SYS_FBA_TCRV_72661;
COUNT(*)
----------
18511
闪回功能生成的字典对象有多个,通过查询USER_TABLES/USER_OBJECTS视图可以获得这些对象的详细信息:
tq@TQGZS11G> select table_name,tablespace_name from user_tables where table_name like '%FBA%';
TABLE_NAME TABLESPACE_NAME
------------------------------ --------------------
SYS_FBA_DDL_COLMAP_72661 FBDA
SYS_FBA_TCRV_72661 FBDA
SYS_FBA_HIST_72661
tq@TQGZS11G> select object_name,object_type from user_objects where object_name like '%FBA%';
OBJECT_NAME OBJECT_TYPE
------------------------------ --------------------
SYS_FBA_DDL_COLMAP_72661 TABLE
SYS_FBA_HIST_72661 TABLE
SYS_FBA_HIST_72661 TABLE PARTITION
SYS_FBA_TCRV_72661 TABLE
SYS_FBA_TCRV_IDX_72661 INDEX
可以通过数据字典视图来查看关于闪回归档表的记录:
tq@TQGZS11G> select * from user_flashback_archive_tables;
TABLE_NAME OWNER_NAME FLASHBACK_ARCHIVE_NAME ARCHIVE_TABLE_NAME
---------- ---------- ------------------------------ --------------------
T TQ FDA SYS_FBA_HIST_72661
可以通过dict字典查询和闪回归档有关的数据字典表:
sys@TQGZS11G> select table_name from dict where table_name like '%FLASHBACK_ARCHIVE%';
TABLE_NAME
-----------------------------------
DBA_FLASHBACK_ARCHIVE
DBA_FLASHBACK_ARCHIVE_TABLES
DBA_FLASHBACK_ARCHIVE_TS
USER_FLASHBACK_ARCHIVE
USER_FLASHBACK_ARCHIVE_TABLES
总之,闪回数据归档是Oracle 11g提供的重要增强之一,通过合理使用这一增强,可以为数据库提供更为全面的数据生命周期管理,Oracle关于UNDO技术的进化至此又迈进了重要的一步。
阅读(1957) | 评论(0) | 转发(0) |