生产上要做灾备系统的应急切换演练,灾备端是由OGG搭建的。由于生产库都比较大10多T,不想演练后重新初始化灾备库,Oracle生产库版本为10.2.0.4,于是想到10g的新特性flashback database。演练开始前记录一个还原点,演练结束后闪回到这个还原点,重新同步ogg即可。
测试闪加数据库。
一、开启FLASHBACK DATABASE
数据库版本:10.2.0.4
启用FLASHBACK DATABASE数据库必须为ARCHIVELOG模式,还需要有一个闪回恢复区用于存储闪回日志,RAC中闪回恢复区必须在集群文件系统或ASM中。
--数据库已开启归档,但还未启用FLASHBACK
SQL> select flashback_on,log_mode from v$database;
FLASHBACK_ON LOG_MODE
------------------------------------------------------ ------------------------------------
NO ARCHIVELOG
--调整参数
SQL> alter system set db_recovery_file_dest_size=3G scope=spfile;
System altered.
SQL> alter system set db_recovery_file_dest='/u01/app/oracle/flashback_area/' scope=spfile;
System altered.
SQL> alter system set db_flashback_retention_target=2880 scope=spfile;
System altered.
--关闭数据库
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
--启动到mount状态,开启FLASHBACK
SQL> startup mount;
ORACLE instance started.
Total System Global Area 599785472 bytes
Fixed Size 2085776 bytes
Variable Size 192941168 bytes
Database Buffers 398458880 bytes
Redo Buffers 6299648 bytes
Database mounted.
SQL> alter database flashback on;
Database altered.
--启动数据库
SQL> alter database open;
Database altered.
--查看新状态
SQL> select flashback_on,log_mode from v$database;
FLASHBACK_ON LOG_MODE
------------------------------------------------------ ------------------------------------
YES ARCHIVELOG
官方文档:http://docs.oracle.com/cd/B19306_01/backup.102/b14192/rpfbdb003.htm#sthref509
db_recovery_file_dest_size参数表示闪回恢复区的大小
db_recovery_file_dest参数表示闪回恢复区目录
db_flashback_retention_target表是闪回日志保留的时间,单位为分,默认1440(1天)
查看闪回恢复区里已生成闪回日志
1234 [oracle@rhel5 flashback_area]$ cd /u01/app/oracle/flashback_area/MYDB/flashback/
[oracle@rhel5 flashback]$ ls -l
total 8020
-rw-r----- 1 oracle oinstall 8200192 Jan 9 14:48 o1_mf_d76cxc1r_.flb
二、创建测试表
SQL> conn zx/zx
Connected.
SQL> create table flash_t as select * from all_tables;
Table created.
SQL> insert into flash_t select * from flash_t;
1559 rows created.
SQL> /
3118 rows created.
SQL> commit;
Commit complete.
SQL> select count(*) from flash_t;
COUNT(*)
----------
6236
三、查看数据库可以闪回的时间点
SQL> select * from V$FLASHBACK_DATABASE_LOG;
OLDEST_FLASHBACK_SCN OLDEST_FLASHBACK_ RETENTION_TARGET FLASHBACK_SIZE ESTIMATED_FLASHBACK_SIZE
-------------------- ----------------- ---------------- -------------- ------------------------
7762668 20170109 14:37:32 2880 14467072 590954496
四、测试闪回数据库到一个时间点
--记录当前SCN用于闪回数据库
SQL> SELECT CURRENT_SCN FROM V$DATABASE;
CURRENT_SCN
-----------
7765990
--删除测试表
SQL> conn / as sysdba
Connected.
SQL> select count(*) from zx.flash_t;
COUNT(*)
----------
6236
SQL> drop table zx.flash_t;
Table dropped.
SQL> select count(*) from zx.flash_t;
select count(*) from zx.flash_t
*
ERROR at line 1:
ORA-00942: table or view does not exist
--闪回数据库
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount;
ORACLE instance started.
Total System Global Area 599785472 bytes
Fixed Size 2085776 bytes
Variable Size 192941168 bytes
Database Buffers 398458880 bytes
Redo Buffers 6299648 bytes
Database mounted.
--执行闪回
SQL> flashback database to scn 7765990;
Flashback complete.
--以resetlogs方式打开数据库
SQL> alter database open resetlogs;
--可以使用alter database open read only打开数据库查看闪回后数据库的状态,如果闪回的不理想,重启到mount模式重新做flashback database
Database altered.
--验证测试表得到恢复
SQL> select count(*) from zx.flash_t;
COUNT(*)
----------
6236
闪回还可以指定时间或还原点
FLASHBACK DATABASE TO RESTORE POINT BEFORE_CHANGES;
FLASHBACK DATABASE TO TIME "TO_DATE('09/20/00','MM/DD/YY')";
官方文档:http://docs.oracle.com/cd/B19306_01/backup.102/b14192/flashptr005.htm#BGBDCAFA
: