先用我们具有flashback archive administer 权限的用户试试: SQL> conn dvd/dvd; Connected. SQL> alter flashback archive fla1 set default; alter flashback archive fla1 set default * ERROR at line 1: ORA-55611: No privilege to manage default Flashback Archive
报错,没有权限,用sysdba 测试成功: SQL> conn / as sysdba; Connected. SQL> alter flashback archive fla1 set default;
Flashback archive altered.
注意一点,只能有一个默认的Flashback archive.
SQL> select flashback_archive_name name, status from dba_flashback_archive; NAME STATUS ---------- ------- FLA1 DEFAULT FLA2
当前默认的Flashback Archive 是FLA1,我们将默认改成FLA2,在查看: SQL> alter flashback archive fla2 set default; Flashback archive altered.
SQL> select flashback_archive_name name, status from dba_flashback_archive; NAME STATUS ---------- ------- FLA1 FLA2 DEFAULT
SQL> alter flashback archive fla1 purge before scn 1315755078; Flashback archive altered.
我这里只是演示一个SCN。 具体要结合自己的情况。
2.4.6.2.3 Dropping a Flashback Data Archive
Drop a Flashback Data Archive with the DROP FLASHBACK ARCHIVE statement. Dropping a Flashback Data Archive deletes its historical data, but does not drop its tablespaces. -- 删除Flashback Archive 不会删除相应的表空间
示例: SQL> DROP FLASHBACK ARCHIVE fla2; Flashback archive dropped.
SQL> select flashback_archive_name name, status from dba_flashback_archive; NAME STATUS ---------- ------- FLA1
2.4.6.2.4 Specifying the Default Flashback Data Archive
By default, the system has no default Flashback Data Archive. If you are logged on as SYSDBA, you can specify default Flashback Data Archive in either of these ways: 默认情况下,没有default Flashback Data Archive. 当以sysdba 登陆之后,就可以指定它。
2.4.1 修改已经存在的Flashback Archive 为default SQL> alter flashback archive fla1 set default; Flashback archive altered.
SQL> alter flashback archive fla10 set default; alter flashback archive fla10 set default * ERROR at line 1: ORA-55605: Incorrect Flashback Archive is specified
The default Flashback Data Archive for the system is the default Flashback Data Archive for every user who does not have his or her own default Flashback Data Archive.
官网的定义如下: A Flashback Data Archive provides the ability to track and store transactional changes to a table over its lifetime. A Flashback Data Archive is useful for compliance with record stage policies and audit reports. --Flashback Data Archive 在它的有效期内将保存事务改变的信息。 A Flashback Data Archive consists of one or more tablespaces or parts thereof. You can have multiple Flashback Data Archives. If you are logged on as SYSDBA, you can specify a default Flashback Data Archive for the system. A Flashback Data Archive is configured with retention time. Data archived in the Flashback Data Archive is retained for the retention time. -- FDA 包含一个或者多个表空间,我们可以创建多个FDA。 当以sysdba 登陆时,可以指定default FDA。 By default, flashback archiving is off for any table. You can enable flashback archiving for a table if all of these conditions are true: -- 默认情况下,FDA 是关闭的,当具备一下条件时,我们可以启用FDA。
(1). You have the FLASHBACK ARCHIVE object privilege on the Flashback Data Archive to use for that table. (2). The table is neither nested, clustered, temporary, remote, or external. (3). The table contains neither LONG nor nested columns.
After flashback archiving is enabled for a table, you can disable it only if you either have the FLASHBACK ARCHIVE ADMINISTER system privilege or you are logged on as SYSDBA. --当FDA 启动以后,只有具有FLASHBACK ARCHIVE ADMINISTER 权限的用户或者用SYSDBA登陆的用户才可以禁用FDA。
When choosing a Flashback Data Archive for a specific table, consider the data retention requirements for the table and the retention times of the Flashback Data Archives on which you have the FLASHBACK ARCHIVE object privilege.
给用户赋: SQL> create user dvd identified by dvd default tablespace users temporary tablespace temp; User created.
SQL> grant resource,connect to dvd; Grant succeeded.
SQL> grant flashback archive administer to dvd; Grant succeeded.
SQL> select * from dba_sys_privs where grantee='DVD';
GRANTEE PRIVILEGE ADM ----------------------- ---------------------------------------- --- DVD FLASHBACK ARCHIVE ADMINISTER NO DVD UNLIMITED TABLESPACE NO
Oracle 11g中flashback增加了:Flashback Data Archive 特性。该技术与之前的Flashback的实现机制不同,通过将变化数据另外存储到创建的闪回归档区(Flashback Archive)中,以和undo区别开来,这样就可以为闪回归档区单独设置存储策略,使之可以闪回到指定时间之前的旧数据而不影响undo策略。并且可以根据需要指定哪些数据库对象需要保存历史变化数据,而不是将数据库中所有对象的变化数据都保存下来,这样可以极大地减少空间需求。 Flashback Data Archive并不是记录数据库的所有变化,而只是记录了指定表的数据变化。所以,Flashback Data Archive是针对对象的保护,是Flashback Database的有力补充。
通过Flashback Data Archive,可以查询指定对象的任何时间点(只要满足保护策略)的数据,而且不需要用到undo,这在有审计需要的环境,或者是安全性特别重要的高可用数据库中,是一个非常好的特性。缺点就是如果该表变化很频繁,对空间的要求可能很高。
Flashback archive相关数据字典 *_FLASHBACK_ARCHIVE Displays information about Flashback Data Archive files. *_FLASHBACK_ARCHIVE_TS Displays tablespaces of Flashback Data Archive files. *_FLASHBACK_ARCHIVE_TABLES Displays information about tables that are enabled for Data Flashback Archive files.
* 代表DBA 或者User。
Flashback archive的后台进程 Oracle11g为Flashback data archive特性专门引入了一个新的后台进程FBDA,用于将追踪表(traced table,也就是将指定使用flashback data archive的table)的历史变化数据转存到闪回归档区。
SQL> select name,description from v$bgprocess where name='FBDA'; NAME DESCRIPTION ----- ----------------------------------------------------------- FBDA Flashback Data Archiver Process
Flashback archive 的限制条件 (1)Flashback data archive只能在ASSM的tablespace上创建 (2)Flashback data archive要求必须使用自动undo管理, 即 undo_management 参数为auto
2.4.6.2 Flashback Data Archive 的相关操作
2.4.6.2.1 Creating a Flashback Data Archive
Create a Flashback Data Archive with the CREATE FLASHBACK ARCHIVE statement, specifying: (1)Name of the Flashback Data Archive (2)Name of the first tablespace of the Flashback Data Archive (3)(Optional) Maximum amount of space that the Flashback Data Archive can use in the first tablespace。The default is unlimited. Unless your space quota on the first tablespace is also unlimited, you must specify this value; otherwise, error ORA-55621 occurs. (4)Retention time (number of days that Flashback Data Archive data for the table is guaranteed to be stored)
If you are logged on as SYSDBA, you can also specify that this is the default Flashback Data Archive for the system. If you omit this option, you can still make this Flashback Data Archive the default later . -- 如果以SYSDBA 登陆,还可以指定default Flashback Data Archive。 如果没有指定,也可以通过alter flashback archive 命令来指定。
SQL> revoke unlimited tablespace from dvd; Revoke succeeded.
SQL> alter user dvd quota 10m on fda4; User altered.
SQL> conn dvd/dvd; Connected.
SQL> create flashback archive fla5 tablespace fda4 retention 1 day; create flashback archive fla5 tablespace fda4 retention 1 day * ERROR at line 1: ORA-55621: User quota on tablespace "FDA4" is not enough for Flashback Archive
报错。
修改用户的配合,在创建,成功:
SQL> conn / as sysdba; Connected.
SQL> grant unlimited tablespace to dvd; Grant succeeded.
With the ALTER FLASHBACK ARCHIVE statement, you can: -- 使用alter flashback archive 可以修改如下内容: (1)Change the retention time of a Flashback Data Archive (2)Purge some or all of its data (3)Add, modify, and remove tablespaces
Note: Removing all tablespaces of a Flashback Data Archive causes an error. If you are logged on as SYSDBA, you can also use the ALTER FLASHBACK ARCHIVE statement to make a specific file the default Flashback Data Archive for the system. -- 不能移除Flashback Data Archive里的所有表空间。 否则报错。 如果用sysdba 登陆,可以修改默认的Flashback archive。
例如: SQL> select row_movement from user_tables where table_name='C'; ROW_MOVE -------- ENABLED
要启用或禁止某表row movement,可以通过下列语句:
--启用 SQL> ALTER TABLE table_name ENABLE ROW MOVEMENT; 表已更改。 --禁止 SQL> ALTER TABLE table_name DISABLE ROW MOVEMENT; 表已更改。
举例: SQL> create table C (id number(2)); 表已创建。 SQL> insert into C values(1); 已创建 1 行。 SQL> insert into C values(2); 已创建 1 行。 SQL> commit; 提交完成。 SQL> select * from c; ID ---------- 1 2
SQL> alter session set nls_date_format="yyyy-mm-dd hh24:mi:ss"; 会话已更改。 SQL> select sysdate from dual; SYSDATE ------------------- 2009-10-15 21:17:47 SQL> select current_scn from v$database; CURRENT_SCN ----------- 1103864
删除数据并恢复 SQL> delete from C; 已删除2行。 SQL> commit; 提交完成。 SQL> alter table c enable row movement; 表已更改。 SQL> flashback table c to scn 1103864; 闪回完成。
或者 SQL> flashback table c to timestamp to_timestamp('2009-10-15 21:17:47','yyyy-mm-dd hh24:mi:ss');
在Oracle 11g里又出了一个新特性:Oracle Flashback Data Archive. 在11g的官方文档里搜到了相关内容说明,参考: Using Oracle Flashback Technology --Using Flashback Data Archive (Oracle Total Recall) http://download.oracle.com/docs/cd/E11882_01/appdev.112/e17125/adfns_flashback.htm#BJFIEJGG
举例: SQL> create table B (id number(2)) rowdependencies; 表已创建。 SQL> insert into B values(1); 已创建 1 行。 SQL> insert into B values(2); 已创建 1 行 SQL> insert into B values(3); 已创建 1 行。 SQL> commit; 提交完成。 SQL> select ora_rowscn, id from B; ORA_ROWSCN ID ---------- ---------- 1100560 1 1100560 2 1100560 3
SQL> analyze table B compute statistics; 表已分析。 SQL> select ora_rowscn, id from B; ORA_ROWSCN ID ---------- ---------- 1100560 1 1100560 2 1100560 3
SQL> delete from B; 已删除4行。 SQL> select ora_rowscn, id from B; 未选定行 SQL> insert into B values(1); 已创建 1 行。 SQL> commit; 提交完成。 SQL> insert into B values(2); 已创建 1 行。 SQL> commit; 提交完成。 SQL> select ora_rowscn, id from B; ORA_ROWSCN ID ---------- ---------- 1100723 1 1100729 2
示例: SQL> insert into B values(3); 已创建 1 行。 SQL> commit; 提交完成。 SQL> select * from B; ID ---------- 1 2 3
查看视图,每个事务都对应相同的XID SQL>Select xid,operation,commit_scn,undo_sql from flashback_transaction_query where xid in (Select versions_xid from B versions between scn minvalue and maxvalue);
或者 SQL>select xid,commit_scn,commit_timestamp,operation,undo_sql from flashback_transaction_query q where q.xid in(select versions_xid from B versions between scn 413946 and 413959);
Oracle 在内部都是使用scn,即使你指定的是as of timestamp,oracle 也会将其转换成scn,系统时间标记与scn 之间存在一张表,即SYS 下的SMON_SCN_TIME
SQL> desc sys.smon_scn_time 名称 是否为空? 类型 ----------------------------------------- -------- -------------------------- THREAD NUMBER TIME_MP NUMBER TIME_DP DATE SCN_WRP NUMBER SCN_BAS NUMBER NUM_MAPPINGS NUMBER TIM_SCN_MAP RAW(1200) SCN NUMBER ORIG_THREAD NUMBER
Flashback Drop 可以闪回与表相关联的对象, 如果是其他的对象,比如function,procedure,trigger等。 这时候,就需要使用到ALL_SOURCE 表来进行Flashback Query。
先看联机文档对该表的说明: ALL_SOURCE describes the text source of the stored objects accessible to the current user.
Related Views DBA_SOURCE describes the text source of all stored objects in the database. USER_SOURCE describes the text source of the stored objects owned by the current user. This view does not display the OWNER column.
Column Datatype NULL Description OWNER VARCHAR2(30) NOT NULL Owner of the object NAME VARCHAR2(30) NOT NULL Name of the object TYPE VARCHAR2(12)
Type of object: FUNCTION, JAVA SOURCE, PACKAGE, PACKAGE BODY, PROCEDURE, TRIGGER, TYPE, TYPE BODY LINE NUMBER NOT NULL Line number of this line of source TEXT VARCHAR2(4000)
Text source of the stored object
如果我们误删除了某些对象,如procedure,就可以使用all_source 表进行恢复。
SQL> desc dba_source Name Null? Type ----------------------------------------- -------- ---------------------------- OWNER VARCHAR2(30) NAME VARCHAR2(30) TYPE VARCHAR2(12) LINE NUMBER TEXT VARCHAR2(4000)
查看dba_source 的所有type SQL> select type from dba_source group by type;
TYPE ------------ PROCEDURE PACKAGE PACKAGE BODY TYPE BODY TRIGGER FUNCTION TYPE
7 rows selected.
基于timestamp恢复的语句 SQL>SELECT text FROM dba_source AS OF TIMESTAMP TO_TIMESTAMP ('XXXXX', 'YYYY-MM-DD HH24:MI:SS') WHERE owner = 'XXXX' AND name = '你删除的对象名' ORDER BY line;
示例:
创建函数: SQL> CREATE OR REPLACE function getdate return date as v_date date; begin select sysdate into v_date from dual; return v_date; end; / Function created.
查询函数: SQL> alter session set nls_date_format='yyyy-mm-dd hh24:mi:ss'; Session altered.
SQL> select getdate() from dual; GETDATE() ------------------- 2011-04-07 21:02:09
查询dba_source 表: SQL> select text from dba_source where name='GETDATE' order by line;
TEXT -------------------------------------------------------------------------------- function getdate return date as v_date date; begin select sysdate into v_date from dual; return v_date; end;
7 rows selected.
drop 函数,在查询,记录不存在 SQL> drop function getdate; Function dropped.
SQL> select text from dba_source where name='GETDATE' order by line; no rows selected
使用我们的Flashback Query 查询: SQL> select text from dba_source as of timestamp to_timestamp('2011-04-07 21:02:09','yyyy-mm-dd hh24:mi:ss') where name='GETDATE' order by line;
TEXT -------------------------------------------------------------------------------- function getdate return date as v_date date; begin select sysdate into v_date from dual; return v_date; end;
最熟悉的伪列就是 ROWID, 它相当于一个指针,指向记录在磁盘上的位置。ORA_ROWSCN 是Oracle 10g 新增的,暂且把它看作是记录最后一次被修改时的SCN。 Flashback Version Query 就是通过这个伪列来跟踪出记录的变化历史。
举个例子: SQL> select * from A; ID ---------- 2 1 3 4
SQL> insert into A values(5); 已创建 1 行。
SQL> select * from A; ID ---------- 2 1 3 4 5 SQL> commit; 提交完成。 SQL> select ora_rowscn, id from A; ORA_ROWSCN ID ---------- ---------- 1098443 2 1098443 1 1098443 3 1098443 4 1098443 5
获取更多的历史信息 SQL>Select versions_xid,versions_startscn,versions_endscn, DECODE(versions_operation,'I','Insert','U','Update','D','Delete', 'Original') "Operation", id from A versions between scn minvalue and maxvalue;
或者 SQL>select xid,commit_scn,commit_timestamp,operation,undo_sql from flashback_transaction_query q where q.xid in(select versions_xid from B versions between scn 413946 and 413959);
Flashback query 有多种方式构建查询记录集,记录集的选择范围可以基于时间或基于scn,甚至可以同时查询出记录在undo 表空间中不同事务时的前映象。 用法与标准查询非常类似,要通过flashback query 查询undo 中的撤销数据,最简单的方式只需要在标准查询语句的表名后面跟上as of timestamp(基于时间)或as of scn(基于scn)即可。 as of timestamp|scn 的语法是自9iR2 后才开始提供支持。
2.4.4.1.2 As of timestamp 的示例:
SQL> alter session set nls_date_format='YYYY-MM-DD hh24:mi:ss'; 会话已更改。
SQL> select sysdate from dual; SYSDATE ------------------- 2009-10-15 19:04:16
SQL> select * from A; ID ---------- 2 1 3 4
模拟用户误操作,删除数据 SQL> delete from A; 已删除4行。 SQL> commit; 提交完成。 SQL> select * from A; 未选定行
查看删除之前的状态:假设当前距离删除数据已经有5 分钟左右的话: SQL> select * from A as of timestamp sysdate-5/1440; ID ---------- 2 1 3 4 或者: SQL>select * from A as of timestamp to_timestamp('2009-10-15 19:04:16','YYYY-MM-DD hh24:mi:ss'); ID ---------- 2 1 3 4
用Flashback Query恢复之前的数据: SQL>Insert into A select * from A as of timestamp to_timestamp('2009-10-15 19:04:16','YYYY-MM-DD hh24:mi:ss'); 已创建4行。 SQL> COMMIT; 提交完成。 SQL> select * from A; ID ---------- 2 1 3 4
如上述示例中所表示的,as of timestamp 的确非常易用,但是在某些情况下,我们建议使用as of scn 的方式执行flashback query,比如需要对多个相互有主外键约束的表进行恢复时,如果使用as of timestamp 的方式,可能会由于时间点不统一的缘故造成数据选择或插入失败,通过scn 方式则能够确保记录的约束一致性。
2.4.4.1.3. As of scn 示例
查看SCN: SQL>SELECT dbms_flashback.get_system_change_number FROM dual; SQL>SELECT CURRENT_SCN FROM V$DATABASE;
SQL> SELECT CURRENT_SCN FROM V$DATABASE; CURRENT_SCN ----------- 1095782
删除数据: SQL> delete from A; 已删除4行。 SQL> commit; 提交完成。
查看删除之前的状态: SQL> select * from A as of scn 1095782; ID ---------- 2 1 3 4
用Flashback Query恢复之前的数据: SQL> insert into A select * from A as of scn 1095782; 已创建4行。 SQL> commit; 提交完成。 SQL> select * from A; ID ---------- 2 1 3 4
SQL> drop table B; 表已删除。 SQL> create table B(name varchar(20)); 表已创建。 SQL> drop table B; 表已删除。
SQL> select original_name,object_name from recyclebin;
ORIGINAL_NAME OBJECT_NAME -------------------------------- ------------------------------ B BIN$vYuv+g9fTi2exYP9X2048Q==$0 B BIN$geQ9+NekSjuRvzG+TqDVWw==$0
SQL> flashback table "BIN$vYuv+g9fTi2exYP9X2048Q==$0" to before drop; 闪回完成。
When you drop a table, the database does not immediately remove the space associated with the table. The database renames the table and places it and any associated objects in a recycle bin, where, in case the table was dropped in error, it can be recovered at a later time. This feature is called Flashback Drop, and the FLASHBACK TABLE statement is used to restore the table. Before discussing the use of the FLASHBACK TABLE statement for this purpose, it is important to understand how the recycle bin works, and how you manage its contents.
The recycle bin is actually a data dictionary table containing information about dropped objects. Dropped tables and any associated objects such as indexes, constraints, nested tables, and the likes are not removed and still occupy space. They continue to count against user space quotas, until specifically purged from the recycle bin or the unlikely situation where they must be purged by the database because of tablespace space constraints.
SQL> show parameter recycle NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ buffer_pool_recycle string db_recycle_cache_size big integer 0 recyclebin string on
禁用该功能: SQL> alter system set recyclebin=off; SQL> alter system set recyclebin=on;
SQL> alter session set recyclebin=off; SQL> alter session set recyclebin=on;
禁用后删除的对象将直接删除,不会写到Recycle中,当然在删除时,指定purge 参数,表也将直接删除,不会写到recyclebin中。 SQL> drop table name purge;
查看recyclebin中的对象列表: SQL> select * from A; ID ---------- 1 2 3
SQL> drop table A; 表已删除。 SQL> show recyclebin ORIGINAL NAME RECYCLEBIN NAME OBJECT TYPE DROP TIME ---------------- ----------------------------- ------------ A BIN$RWXQQcTPRde0ws4h9ewJcg==$0 TABLE 2009-10-15:12:44:33
查看recyclebin中对象: SQL> select original_name,object_name from recyclebin; ORIGINAL_NAME OBJECT_NAME -------------------------------- ------------------------------ A BIN$RWXQQcTPRde0ws4h9ewJcg==$0
查看recyblebin对象里的内容: SQL> select * from "BIN$RWXQQcTPRde0ws4h9ewJcg==$0"; ID ---------- 1 2 3
表空间的Recycle Bin 区域只是一个逻辑区域,而不是从表空间上物理的划出一块区域固定用于回收站,因此Recycle Bin是和普通对象共用表空间的存储区域,或者说是Recycle Bin的对象要和普通对象抢夺存储空间。 当发生空间不够时,Oracle会按照先入先出的顺序覆盖Recycle Bin中的对象。