技术活动
CUUG学员就业信息
学员感言、就业资讯
报名热线
文档
当前您的位置:首页 > 技术活动 > 技术中心 > 文档
Oracle 基于备份控制文件的恢复-CUUG

  通常在当前控制文件丢失,或者当前的控制文件与需要恢复的控制文件不一致的情况下,我们需要重新创建一个控制文件或者使用 unsing

  backup controlfile方式来恢复控制文件。说简单点,只要是备份的控制文件与当前的控制文件不一致进行恢复数据库,就需要使用到 unsing

  backup controlfile方式,而一旦使用了该方式,则需使用resetlgos选项来打开数据库。

  一、基于备份控制文件的恢复注意事项(无论是否使用恢复目录catalog)

  1、即使没有数据文件需要还原,当使用unsing backup controlfile 方式时必须结合 recover 命令

  2、不论使用备份的控制文件进行时点恢复或完全恢复,必须使用 open resetlogs 方式打开数据库

  3、如果联机日志不可访问,必须使用不完全恢复到联机日志文件中最早的一个SCN之前。这是因为RMAN并不备份联机日志文件

  4、在恢复期间,RMAN自动搜索联机日志和没有记录在RMAN存储仓库中的归档日志以完成恢复

  5、RMAN会根据初始化参数文件中归档位置以及控制文件联机日志信息自动寻找有效的归档日志和联机日志。使用unsing backup controlfile方

  式时,在恢复期间,一旦归档目的地以及归档格式发生变化,或添加新的联机日志成员将收到RMAN-06054错误信息。

  本文主要使用热备方式来完成演示

  二、演示unsing backup controlfile的使用

  1、控制文件全部丢失的情形(控制文件备份后发生变化)

  -->首先使用热备脚本进行备份

  sys@SYBO2SZ> get db_hot_bak.sql

  1 set feedback off heading off verify off

  2 set pagesize 0 linesize 200

  3 define dir='/u02/database/SYBO2SZ/backup/hotbak'

  4 define script='/tmp/tmphotbak.sql'

  5 spool &script

  6 select 'ho cp '||name||' &dir' from v$datafile;

  7 spool off

  8 alter database begin backup;

  9 start &script

  10 alter database end backup;

  11 alter database backup controlfile to '&dir/contlbak.ctl' reuse;

  12 create pfile='&dir/initSYBO2SZ.ora' from spfile;

  13* set feedback on heading on verify on pagesize 100

  sys@SYBO2SZ> @db_hot_bak

  sys@SYBO2SZ> show parameter control_files

  NAME TYPE VALUE

  ------------------------------------ ----------- ------------------------------

  control_files string /u02/database/SYBO2SZ/controlf

  /cntl1SYBO2SZ.ctl, /u02/databa

  se/SYBO2SZ/controlf/cntl2SYBO2

  SZ.ctl, /u02/database/SYBO2SZ/

  controlf/cntl3SYBO2SZ.ctl

  -->为数据库添加新的表空间,此时控制文件将不同于先前备份的控制文件

  sys@SYBO2SZ> create tablespace tbs datafile '/u02/database/SYBO2SZ/oradata/tbs_tmp.dbf' size 10m autoextend on;

  Tablespace created.

  -->为数据库添加对象

  sys@SYBO2SZ> create table tb_emp tablespace tbs as select * from scott.emp ;

  Table created.

  sys@SYBO2SZ> select count(*) from tb_emp;

  COUNT(*)

  ----------

  14

  sys@SYBO2SZ> select * from v$log;

  GROUP# THREAD# SEQUENCE# BYTES MEMBERS ARC STATUS FIRST_CHANGE# FIRST_TIM

  ---------- ---------- ---------- ---------- ---------- --- ---------------- ------------- ---------

  3 1 116 20971520 2 NO CURRENT 1078066 08-SEP-12

  4 1 115 20971520 2 YES INACTIVE 1063428 08-SEP-12

  sys@SYBO2SZ> select to_char(sysdate,'yyyymmdd hh24:mi:ss') from dual;

  TO_CHAR(SYSDATE,

  -----------------

  20120908 16:30:41

  -->切换日志

  sys@SYBO2SZ> alter system archive log current;

  System altered.

  -->删除部分记录用于恢复后验证

  sys@SYBO2SZ> delete from tb_emp where deptno=10;

  3 rows deleted.

  sys@SYBO2SZ> commit;

  Commit complete.

  sys@SYBO2SZ> alter system archive log current;

  System altered.

  sys@SYBO2SZ> ho ls -hltr /u02/database/SYBO2SZ/archive

  total 143M

  -rw-r----- 1 oracle oinstall 15M 2012-09-08 16:20 arch_792094299_1_115.arc

  -rw-r----- 1 oracle oinstall 236K 2012-09-08 16:30 arch_792094299_1_116.arc

  -rw-r----- 1 oracle oinstall 9.0K 2012-09-08 16:32 arch_792094299_1_117.arc

  -->异常关机

  sys@SYBO2SZ> shutdown abort;

  ORACLE instance shut down.

  -->模拟所有控制文件丢失

  sys@SYBO2SZ> ho rm -rf /u02/database/SYBO2SZ/controlf/*

  sys@SYBO2SZ> ho ls /u02/database/SYBO2SZ/controlf/

  -->启动后收到ORA-00205错误

  sys@SYBO2SZ> startup

  ORACLE instance started.

  Total System Global Area 599785472 bytes

  Fixed Size 2074568 bytes

  Variable Size 276826168 bytes

  Database Buffers 314572800 bytes

  Redo Buffers 6311936 bytes

  ORA-00205: error in identifying control file, check alert log for more info

  sys@SYBO2SZ> select instance_name,status from v$instance;

  INSTANCE_NAME STATUS

  ---------------- ------------

  SYBO2SZ STARTED

  sys@SYBO2SZ> select name,open_mode from v$database;

  select name,open_mode from v$database

  *

  ERROR at line 1:

  ORA-01507: database not mounted

  -->还原控制文件

  sys@SYBO2SZ> ho cp /u02/database/SYBO2SZ/backup/hotbak/contlbak.ctl /u02/database/SYBO2SZ/controlf/cntl1SYBO2SZ.ctl

  sys@SYBO2SZ> ho cp /u02/database/SYBO2SZ/backup/hotbak/contlbak.ctl /u02/database/SYBO2SZ/controlf/cntl2SYBO2SZ.ctl

  sys@SYBO2SZ> ho cp /u02/database/SYBO2SZ/backup/hotbak/contlbak.ctl /u02/database/SYBO2SZ/controlf/cntl3SYBO2SZ.ctl

  -->mount数据库

  sys@SYBO2SZ> alter database mount;

  Database altered.

  -->由于仅仅是丢失了控制文件,因此我们只还原控制文件

  -->恢复数据库,提示需要使用BACKUP CONTROLFILE选项,因为控制文件在备份后发生了变化

  sys@SYBO2SZ> recover database;

  ORA-00283: recovery session canceled due to errors

  ORA-01610: recovery using the BACKUP CONTROLFILE option must be done

  -->提示需要实用到116归档日志

  sys@SYBO2SZ> recover database using backup controlfile;

  ORA-00279: change 1078785 generated at 09/08/2012 16:20:48 needed for thread 1

  ORA-00289: suggestion : /u02/database/SYBO2SZ/archive/arch_792094299_1_116.arc

  ORA-00280: change 1078785 for thread 1 is in sequence #116

  -->下面提示在介质恢复期间有未知的文件添加到控制文件,且文件id为9

  -->由此可以推断文件9是记录在尾数为116的归档日志中,正好与前面查看的归档日志时间相符

  Specify log: {=suggested | filename | AUTO | CANCEL}

  auto

  ORA-00283: recovery session canceled due to errors

  ORA-01244: unnamed datafile(s) added to control file by media recovery

  ORA-01110: data file 9: '/u02/database/SYBO2SZ/oradata/tbs_tmp.dbf'

  ORA-01112: media recovery not started

  -->使用alter database create datafile重建数据文件

  -->此处故意使用了不同于创建之前的文件名tbs.dbf,此处并没有任何影响,相对于对数据文件进行了重命名

  sys@SYBO2SZ> alter database create datafile 9 as '/u02/database/SYBO2SZ/oradata/tbs.dbf';

  Database altered.

  -->尝试再次恢复,需要使用为数位116的归档日志,输入auto后,尾数为116,117的不在需要

  sys@SYBO2SZ> recover database using backup controlfile;

  ORA-00279: change 1078817 generated at 09/08/2012 16:29:19 needed for thread 1

  ORA-00289: suggestion : /u02/database/SYBO2SZ/archive/arch_792094299_1_116.arc

  ORA-00280: change 1078817 for thread 1 is in sequence #116

  Specify log: {=suggested | filename | AUTO | CANCEL}

  auto

  ORA-00279: change 1078886 generated at 09/08/2012 16:30:52 needed for thread 1

  ORA-00289: suggestion : /u02/database/SYBO2SZ/archive/arch_792094299_1_117.arc

  ORA-00280: change 1078886 for thread 1 is in sequence #117

  ORA-00278: log file '/u02/database/SYBO2SZ/archive/arch_792094299_1_116.arc' no longer needed for this recovery

  ORA-00279: change 1078922 generated at 09/08/2012 16:32:22 needed for thread 1

  ORA-00289: suggestion : /u02/database/SYBO2SZ/archive/arch_792094299_1_118.arc

  ORA-00280: change 1078922 for thread 1 is in sequence #118

  ORA-00278: log file '/u02/database/SYBO2SZ/archive/arch_792094299_1_117.arc' no longer needed for this recovery

  -->提示未找尾数为118的归档日志,118本身还没有归档,因此来说此时是联机日志

  ORA-00308: cannot open archived log '/u02/database/SYBO2SZ/archive/arch_792094299_1_118.arc'

  ORA-27037: unable to obtain file status

  Linux-x86_64 Error: 2: No such file or directory

  Additional information: 3

  -->再次恢复

  sys@SYBO2SZ> recover database using backup controlfile;

  ORA-00279: change 1078922 generated at 09/08/2012 16:32:22 needed for thread 1

  ORA-00289: suggestion : /u02/database/SYBO2SZ/archive/arch_792094299_1_118.arc

  ORA-00280: change 1078922 for thread 1 is in sequence #118

  -->直接指定redo日志,介质恢复成功

  Specify log: {=suggested | filename | AUTO | CANCEL}

  /u02/database/SYBO2SZ/redolog/log3aSYBO2SZ.log

  Log applied.

  Media recovery complete.

  -->下面需要使用RESETLOGS选项打开数据库

  sys@SYBO2SZ> alter database open;

  alter database open

  *

  ERROR at line 1:

  ORA-01589: must use RESETLOGS or NORESETLOGS option for database open

  sys@SYBO2SZ> alter database open resetlogs;

  Database altered.

  -->验证新建对象的总记录数,正好等于删除后的记录数11条

  sys@SYBO2SZ> select count(*) from tb_emp;

  COUNT(*)

  ----------

  11

  2、删除表空间模拟控制文件变化的情形

  下面的这个例子的处理方式并非最佳,此处仅仅为演示unsing backup controlfile的用法且使用了不完全恢复方式,对于单个数据文件和

  sys@SYBO2SZ> archive log list; -->看看归档情况,log sequence从1开始

  Database log mode Archive Mode

  Automatic archival Enabled

  Archive destination /u02/database/SYBO2SZ/archive/

  Oldest online log sequence 1

  Next log sequence to archive 1

  Current log sequence 1

  sys@SYBO2SZ> alter system switch logfile;

  -->首先热备数据库

  sys@SYBO2SZ> @db_hot_bak

  -->新的incarnation 793471702已经产生,可以看到同时也产生了一个尾数为118的上一个incarnation的归档日志

  sys@SYBO2SZ> ho ls -hltr /u02/database/SYBO2SZ/archive

  total 54M

  -rw-r----- 1 oracle oinstall 1.0K 2012-09-08 16:48 arch_792094299_1_118.arc

  -rw-r----- 1 oracle oinstall 9.0K 2012-09-08 16:48 arch_792094299_1_117.arc

  -rw-r----- 1 oracle oinstall 43K 2012-09-08 16:51 arch_793471702_1_1.arc

  -->删除表空间以更新控制文件

  sys@SYBO2SZ> drop tablespace tbs including contents and datafiles;

  Tablespace dropped.

  sys@SYBO2SZ> alter system switch logfile;

  System altered.

  -->切换日志后,新增了尾数为2的归档日志

  sys@SYBO2SZ> ho ls -hltr /u02/database/SYBO2SZ/archive

  total 54M

  -rw-r----- 1 oracle oinstall 1.0K 2012-09-08 16:48 arch_792094299_1_118.arc

  -rw-r----- 1 oracle oinstall 9.0K 2012-09-08 16:48 arch_792094299_1_117.arc

  -rw-r----- 1 oracle oinstall 43K 2012-09-08 16:51 arch_793471702_1_1.arc

  -rw-r----- 1 oracle oinstall 50K 2012-09-08 16:58 arch_793471702_1_2.arc

  sys@SYBO2SZ> show parameter background_dump_dest

  NAME TYPE VALUE

  ------------------------------------ ----------- ------------------------------

  background_dump_dest string /u02/database/SYBO2SZ/bdump

  -->从alert log file中查询表空间被删除的准确时间

  sys@SYBO2SZ> ho cat -n /u02/database/SYBO2SZ/bdump/alert_SYBO2SZ.log | grep tbs.dbf

  6959 '/u02/database/SYBO2SZ/oradata/imp_tbs.dbf'

  6962 '/u02/database/SYBO2SZ/oradata/imp_tbs.dbf'...

  11014 alter database create datafile 9 as '/u02/database/SYBO2SZ/oradata/tbs.dbf'

  11016 Completed: alter database create datafile 9 as '/u02/database/SYBO2SZ/oradata/tbs.dbf'

  11273 Deleted file /u02/database/SYBO2SZ/oradata/tbs.dbf

  -->下面可以看到表空间及数据文件被删除的时间

  -->同时也看到了控制文件进行了自动备份,因为RMAN配置中控制文件自动备份被置为ON

  -->此处使用之前备份的控制文件来恢复测试,因此此处不考虑使用自动备份的控制文件

  sys@SYBO2SZ> ho more +11270 /u02/database/SYBO2SZ/bdump/alert_SYBO2SZ.log

  Sat Sep 8 16:57:56 2012

  drop tablespace tbs including contents and datafiles

  Sat Sep 8 16:57:58 2012

  Deleted file /u02/database/SYBO2SZ/oradata/tbs.dbf

  Starting control autobackup

  Control autobackup written to DISK device

  handle '/u02/database/SYBO2SZ/backup/rman/20120907/SYBO2SZ_lev1_201209071410_c-209726751-20120908-05'

  Completed: drop tablespace tbs including contents and datafiles

  sys@SYBO2SZ> shutdown immediate;

  -->还原控制文件及所有的数据文件

  sys@SYBO2SZ> ho cp /u02/database/SYBO2SZ/backup/hotbak/contlbak.ctl /u02/database/SYBO2SZ/controlf/cntl1SYBO2SZ.ctl

  sys@SYBO2SZ> ho cp /u02/database/SYBO2SZ/backup/hotbak/contlbak.ctl /u02/database/SYBO2SZ/controlf/cntl2SYBO2SZ.ctl

  sys@SYBO2SZ> ho cp /u02/database/SYBO2SZ/backup/hotbak/contlbak.ctl /u02/database/SYBO2SZ/controlf/cntl3SYBO2SZ.ctl

  sys@SYBO2SZ> ho cp /u02/database/SYBO2SZ/backup/hotbak/*.dbf /u02/database/SYBO2SZ/oradata/.

  sys@SYBO2SZ> ho cp /u02/database/SYBO2SZ/backup/hotbak/undotbs* /u02/database/SYBO2SZ/undo/.

  sys@SYBO2SZ> startup mount;

  ORACLE instance started.

  -->使用using backup controlfile选项以及设定时间点来恢复数据库

  sys@SYBO2SZ> recover database until time '2012-09-08:16:57:56' using backup controlfile;

  ORA-00279: change 1079138 generated at 09/08/2012 16:55:09 needed for thread 1

  ORA-00289: suggestion : /u02/database/SYBO2SZ/archive/arch_793471702_1_2.arc

  ORA-00280: change 1079138 for thread 1 is in sequence #2

  Specify log: {=suggested | filename | AUTO | CANCEL}

  auto

  Log applied.

  Media recovery complete.

  sys@SYBO2SZ> alter database open resetlogs;

  Database altered.

  -->验证恢复的对象中的记录数

  sys@SYBO2SZ> select count(*) from tb_emp;

  COUNT(*)

  ----------

  11