Oracle 9i 開始支持閃回,Oracle10g開始全面支持閃回功能,Oracle11g有所完善,為大家快速的恢複數據,查詢歷史數據提供了很大的便捷方法。 本文主要對Oracle常用閃回使用做些詳細介紹,其中對於不常用的事務和版本閃回,這裡就不做介紹 一、Oracle閃回概述 二、Oracle閃 ...
Oracle 9i 開始支持閃回,Oracle10g開始全面支持閃回功能,Oracle11g有所完善,為大家快速的恢複數據,查詢歷史數據提供了很大的便捷方法。
本文主要對Oracle常用閃回使用做些詳細介紹,其中對於不常用的事務和版本閃回,這裡就不做介紹
一、Oracle閃回概述
閃回級別 | 閃回場景 | 閃回技術 | 對象依賴 | 影響數據 |
資料庫 | 表截斷、邏輯錯誤、其他多表意外事件 | 閃回DATABASE | 閃回日誌、undo | 是 |
DROP | 刪除表 | 閃回DROP | 回收站(recyclebin) | 是 |
表 | 更新、刪除、插入記錄 | 閃回TABLE | 還原數據,undo | 是 |
查詢 | 當前數據和歷史數據對比 | 閃回QUERY | 還原數據,undo | 否 |
版本查詢 | 比較行版本 | 閃回Version Query | 還原數據,undo | 否 |
事務查詢 | 比較 | 閃回Transaction Query | 還原數據,undo | 否 |
歸檔 | DDL、DML | 閃回Archive | 歸檔日誌 | 是 |
二、Oracle閃回使用詳解
1、閃回開啟
(1)開啟閃回必要條件
a.開啟歸檔日誌
SQL> archive log list; Database log mode Archive Mode Automatic archival Enabled Archive destination /home/U01/app/oracle/oradata/testdb/arch Oldest online log sequence 844 Next log sequence to archive 846 Current log sequence 846 ##如未開啟,在mount狀態執行alter database archivelog;
b.設置合理的閃回區
db_recovery_file_dest:指定閃回恢復區的位置
db_recovery_file_dest_size:指定閃回恢復區的可用空間大小
db_flashback_retention_target:指定資料庫可以回退的時間,單位為分鐘,預設1440分鐘(1天),實際取決於閃回區大小
(2)檢查是否開啟閃回
SQL> select flashback_on from v$database; FLASHBACK_ON ------------------ NO
(3)開啟閃回
a.開啟歸檔
mount狀態:alter database archivelog;
b.設置閃回區
SQL> alter system set db_recovery_file_dest='/home/U01/app/oracle/fast_recovery_area' scope=both; System altered. SQL> alter system set db_recovery_file_dest_size=60G scope=both; System altered. SQL> alter system set db_flashback_retention_target=4320 scope=both; System altered.
c.開啟flashback (10g在mount開啟)
SQL> alter database flashback on; Database altered.
(4)確定閃回開啟
SQL> select flashback_on from v$database; FLASHBACK_ON ------------------ YES
(5)關閉閃回
SQL> alter database flashback off; Database altered.
2、閃回使用
(1)閃回查詢
閃回查詢主要是根據Undo表空間數據進行多版本查詢,針對v$和x$動態性能視圖無效,但對DBA_、ALL_、USER_是有效的
a.閃回查詢
允許用戶查詢過去某個時間點的數據,用以重構由於意外刪除或更改的數據,數據不會變化。
SQL> select * from scott.dept; DEPTNO DNAME LOC ---------- -------------- ------------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON SQL> delete from scott.dept where deptno=40; 1 row deleted. SQL> commit; Commit complete. SQL> select * from scott.dept as of timestamp sysdate-10/1440; DEPTNO DNAME LOC ---------- -------------- ------------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON SQL> select * from scott.dept as of timestamp to_timestamp('2017-12-14 16:20:00','yyyy-mm-dd hh24:mi:ss'); DEPTNO DNAME LOC ---------- -------------- ------------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON SQL> select * from scott.dept as of scn 16801523; DEPTNO DNAME LOC ---------- -------------- ------------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON
b.閃回版本查詢
用於查詢行級資料庫隨時間變化的方法
c.閃回事務查詢
用於提供查看事務級別資料庫變化的方法
(2)閃回表(update/insert/delete)
閃回表就是對錶的數據做回退,回退到之前的某個時間點,其利用的是undo的歷史數據,與undo_retention設置有關,預設是14400分鐘(1天)
同樣,sys用戶表空間不支持閃回表,要想表閃回,需要允許表啟動行遷移(row movement)
閃回表示例:
SQL> flashback table scott.dept to timestamp to_timestamp('2017-12-14 16:20:00','yyyy-mm-dd hh24:mi:ss'); flashback table scott.dept to timestamp to_timestamp('2017-12-14 16:20:00','yyyy-mm-dd hh24:mi:ss') ERROR at line 1: ORA-08189: cannot flashback the table because row movement is not enabled SQL> select row_movement from dba_tables where table_name='DEPT' and owner='SCOTT'; ROW_MOVE -------- DISABLED SQL> alter table scott.dept enable row movement; Table altered. SQL> flashback table scott.dept to timestamp to_timestamp('2017-12-14 16:20:00','yyyy-mm-dd hh24:mi:ss'); Flashback complete. SQL> select * from scott.dept; DEPTNO DNAME LOC ---------- -------------- ------------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON SQL> alter table scott.dept disable row movement; Table altered.
(3)閃回DROP(drop table)
當一個表被drop掉,表會被放入recyclebin回收站,可通過回收站做表的閃回。表上的索引、約束等同樣會被恢復
不支持sys/system用戶表空間對象,可通過alter system set recyclebin=off;關閉回收站功能
閃回DROP示例:
SQL> select * from t ; ID NAME ---------- --------------------------------------- 1 2 3 4 30 SQL> drop table t; Table dropped. SQL> show recyclebin; ORIGINAL NAME RECYCLEBIN NAME OBJECT TYPE DROP TIME ---------------- ------------------------------ ------------ ------------------- T BIN$YEh2QcvZdJLgUxyAgQpnVQ==$0 TABLE 2017-12-14:15:02:06 SQL> flashback table t to before drop; Flashback complete. SQL> select * from t; ID NAME ---------- ------------------------------------- 1 2 3 4 30
備註:即使不開始flashback,只要開啟了recyclebin,那麼就可以閃回DROP表。
但如果連續覆蓋,就需要指定恢復的表名,如果已經存在表,則需要恢復重命名。
SQL> show recyclebin; ORIGINAL NAME RECYCLEBIN NAME OBJECT TYPE DROP TIME ---------------- ------------------------------ ------------ ------------------- T BIN$YEh2QcvddJLgUxyAgQpnVQ==$0 TABLE 2017-12-14:15:07:54 T BIN$YEh2QcvcdJLgUxyAgQpnVQ==$0 TABLE 2017-12-14:15:07:27 SQL> flashback table "BIN$YEh2QcvcdJLgUxyAgQpnVQ==$0" to before drop ; Flashback complete. SQL> show recyclebin; ORIGINAL NAME RECYCLEBIN NAME OBJECT TYPE DROP TIME ---------------- ------------------------------ ------------ ------------------- T BIN$YEh2QcvddJLgUxyAgQpnVQ==$0 TABLE 2017-12-14:15:07:54 SQL> flashback table t to before drop rename to tt; Flashback complete.
(4)閃回資料庫(truncate/多表數據變更)
資料庫閃回必須在mounted狀態下進行,基於快照的可以再open下進行閃回庫
閃回資料庫主要是將資料庫還原值過去的某個時間點或SCN,用於資料庫出現邏輯錯誤時,需要open database resetlogs
a.全庫閃回
資料庫閃回示例
SQL> select * from scott.EMP; EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO ---------- ---------- --------- ---------- ------------------- ---------- ---------- ---------- 7369 SMITH CLERK 7902 1980-12-17 00:00:00 800 20 7499 ALLEN SALESMAN 7698 1981-02-20 00:00:00 1600 300 30 7521 WARD SALESMAN 7698 1981-02-22 00:00:00 1250 500 30 7566 JONES MANAGER 7839 1981-04-02 00:00:00 2975 20 7654 MARTIN SALESMAN 7698 1981-09-28 00:00:00 1250 1400 30 7698 BLAKE MANAGER 7839 1981-05-01 00:00:00 2850 30 7782 CLARK MANAGER 7839 1981-06-09 00:00:00 2450 10 7788 SCOTT ANALYST 7566 1987-04-19 00:00:00 3000 20 7839 KING PRESIDENT 1981-11-17 00:00:00 5000 10 7844 TURNER SALESMAN 7698 1981-09-08 00:00:00 1500 0 30 7876 ADAMS CLERK 7788 1987-05-23 00:00:00 1100 20 7900 JAMES CLERK 7698 1981-12-03 00:00:00 950 30 7902 FORD ANALYST 7566 1981-12-03 00:00:00 3000 20 7934 MILLER CLERK 7782 1982-01-23 00:00:00 1300 10 14 rows selected. SQL> truncate table scott.EMP; Table truncated. SQL> shutdown immediate; Database closed. Database dismounted. ORACLE instance shut down. SQL> startup mount; ORACLE instance started. Total System Global Area 9.4067E+10 bytes Fixed Size 2263936 bytes Variable Size 9395242112 bytes Database Buffers 8.4557E+10 bytes Redo Buffers 112766976 bytes Database mounted. SQL> flashback database to timestamp to_timestamp('2017-12-14 14:12:46','yyyy-mm-dd HH24:MI:SS'); Flashback complete. SQL> alter database open resetlogs; Database altered. SQL> select * from scott.emp; EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO ---------- ---------- --------- ---------- ------------------- ---------- ---------- ---------- 7369 SMITH CLERK 7902 1980-12-17 00:00:00 800 20 7499 ALLEN SALESMAN 7698 1981-02-20 00:00:00 1600 300 30 7521 WARD SALESMAN 7698 1981-02-22 00:00:00 1250 500 30 7566 JONES MANAGER 7839 1981-04-02 00:00:00 2975 20 7654 MARTIN SALESMAN 7698 1981-09-28 00:00:00 1250 1400 30 7698 BLAKE MANAGER 7839 1981-05-01 00:00:00 2850 30 7782 CLARK MANAGER 7839 1981-06-09 00:00:00 2450 10 7788 SCOTT ANALYST 7566 1987-04-19 00:00:00 3000 20 7839 KING PRESIDENT 1981-11-17 00:00:00 5000 10 7844 TURNER SALESMAN 7698 1981-09-08 00:00:00 1500 0 30 7876 ADAMS CLERK 7788 1987-05-23 00:00:00 1100 20 7900 JAMES CLERK 7698 1981-12-03 00:00:00 950 30 7902 FORD ANALYST 7566 1981-12-03 00:00:00 3000 20 7934 MILLER CLERK 7782 1982-01-23 00:00:00 1300 10 14 rows selected.
b.快照閃回
(5)閃回歸檔(增加、修改、重命名、刪除表的列、truncate表、修改表的約束、以及修改分區表的分區規範)
3、閃回註意事項
(1)資料庫閃回需要在mounted下進行,並且open時需要使用resetlogs
(2)閃回DROP只能用於非系統表空間和本地管理的表空間,外鍵約束無法恢復,對方覆蓋、重命名需註意
(3)表DROP,對應的物化視圖會被徹底刪除,物化視圖不會存放在recyclebin里
(4)閃回表,如果在做過dml,然後進行了表結構修改、truncate等DDL操作,新增/刪除結構無法做閃回
(5)閃回歸檔,必須在assm管理tablespace和undo auto管理下進行
(6)註意閃回區管理,防止磁碟爆滿,閃回區空間不足等
三、備註
1、相關數據字典
V$FLASHBACK_DATABASE_LOG ##查看資料庫可閃回的時間點/SCN等信息
V$flashback_database_stat ##查看閃回日誌空間記錄信息
2、常用查詢語句
(1)查看資料庫狀態
SQL> select NAME,OPEN_MODE ,DATABASE_ROLE,CURRENT_SCN,FLASHBACK_ON from v$database; NAME OPEN_MODE DATABASE_ROLE CURRENT_SCN FLASHBACK_ON ------------- -------------------- ---------------- ----------- ------------------ TESTDB READ WRITE PRIMARY 16812246 YES
(2)獲取當前資料庫的系統時間和SCN
SQL> select to_char(systimestamp,'yyyy-mm-dd HH24:MI:SS') as sysdt , dbms_flashback.get_system_change_number scn from dual; SYSDT SCN ------------------- ---------- 2017-12-14 14:28:33 16813234
(3)查看資料庫可恢復的時間點
SQL> select * from V$FLASHBACK_DATABASE_LOG; OLDEST_FLASHBACK_SCN OLDEST_FLASHBACK_TI RETENTION_TARGET FLASHBACK_SIZE ESTIMATED_FLASHBACK_SIZE -------------------- ------------------- ---------------- -------------- ------------------------ 16801523 2017-12-14 11:35:05 4320 104857600 244113408
(4)查看閃回日誌空間情況
SQL> select * from V$flashback_database_stat; BEGIN_TIME END_TIME FLASHBACK_DATA DB_DATA REDO_DATA ESTIMATED_FLASHBACK_SIZE ------------------- ------------------- -------------- ---------- ---------- ------------------------ 2017-12-14 14:34:53 2017-12-14 14:56:43 1703936 9977856 1487872 0
(5)SCN和timestamp裝換關係查詢
select scn,to_char(time_dp,'yyyy-mm-dd hh24:mi:ss')from sys.smon_scn_time;
(6)閃回語句
a.閃回資料庫
FLASHBACK DATABASE TO TIMESTAMP to_timestamp('2017-12-14 14:28:33','yyyy-mm-dd HH24:MI:SS');;
flashback database to scn 16813234;
b.閃回DROP
其中table_name可以是刪除表名稱,也可以是別名
flashback table table_name to before drop;
flashback table table_name to before drop rename to table_name_new;
c.閃回表
flashback table table_name to scn scn_number;
flashback table table_name to timestamp to_timestamp('2017-12-14 14:28:33','yyyy-mm-dd hh24:mi:ss');
d.閃回查詢
select * from table_name as of timestamp to_timestamp('2017-12-14 14:28:33','yyyy-mm-dd hh24:mi:ss');
select * from scott.dept as of scn 16801523;
(7)閃回空間爆滿問題處理
請參照我之前的微博:http://blog.itpub.net/27067062/viewspace-2129130/