Oracle 还原库

数据库一般有两种常见故障
介质损坏
人为失误

防止介质损坏一般使用Data Guard等技术
防止人为失误,可以使用Oracle闪回功能.

但是人为失误一旦不能通过闪回恢复,就需要使用Rman恢复了。
使用Rman恢复,想想那个恢复速度和自己窘迫的样子还有里三层外三层的老板,领导,同事..

为了避免这个情况,可以使用另外一台服务器,做一个Oracle的还原库.
主库每隔一段时间,将归档日志推送至还原库的指定目录(scp,rsync,我们使用的是小花狸监控软件)
还原库每隔一段时间,应用归档日志.
也就是说,还原库的数据总是落后于生产数据库.类似于一个延迟的DataGuard。

 我们配置的还原库落后于生产数据库6-9个小时.
从还原库恢复人为错误,一般可以控制在30分钟之内.
而从Rman异机恢复,估计需要4-5个小时.

制作还原库一般有下面几个步骤
1.卸载还原库已经存在的数据库(如果还原库存在数据库实例)

shutdown abort;

startup mount exclusive restrict;

alter system enable restricted session;

drop database;
2.使用Rman备份生产数据库

CONFIGURE DEVICE TYPE DISK PARALLELISM 5 BACKUP TYPE TO BACKUPSET;

sql 'alter system archive log current';

BACKUP AS COMPRESSED BACKUPSET DATABASE ;

 3.在$ORACLE_HOME/dbs目录下,新建一个文件(init$SID.ora)
文件内仅仅有一行SID的配置
db_name=mvbox

 4.恢复spfile

先从Rman备份中,恢复spfile

[oracle@localhost/data/IP/2015_09_25]$rman target /

Recovery Manager: Release 10.2.0.4.0 - Production on Fri Sep 25 17:26:40 2015

Copyright (c) 1982, 2007, Oracle. All rights reserved.

connected to target database (not started)

RMAN> startup nomount;

Oracle instance started

Total System Global Area 171966464 bytes

Fixed Size 2082496 bytes
Variable Size 113248576 bytes
Database Buffers 50331648 bytes
Redo Buffers 6303744 bytes

RMAN> restore spfile to '/home/oracle/app/oracle/product/10.2.0/db_1/dbs/spfilemvbox.ora' from '/data/IP/2015_09_25/o1_mf_nnsnf_TAG20150925T134231_c09s9rq2_.bkp';

Starting restore at 25-SEP-15
using channel ORA_DISK_1

channel ORA_DISK_1: autobackup found: /data/IP/2015_09_25/o1_mf_nnsnf_TAG20150925T134231_c09s9rq2_.bkp
channel ORA_DISK_1: SPFILE restore from autobackup complete
Finished restore at 25-SEP-15
将spfile转换为pfile,然后修改相关的目录

create pfile='/tmp/pfile.ora' from spfile;

 vim /tmp/pfile.ora  主要是修改相关路径

Oracle 还原库

然后使用pfile启动数据库至nomount状态,由修改过的pfile再生成spfile

Oracle 还原库

5.恢复控制文件

RMAN> restore controlfile from '/data/IP/2015_09_25/o1_mf_ncnnf_TAG20150925T134231_c09s9pms_.bkp';

Starting restore at 25-SEP-15
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=1640 devtype=DISK

channel ORA_DISK_1: restoring control file
channel ORA_DISK_1: restore complete, elapsed time: 00:00:02
output filename=/data/oracledata/flash_recovery_area/control01.ctl
Finished restore at 25-SEP-15

RMAN> shutdown

Oracle instance shut down

RMAN> startup mount;

connected to target database (not started)
Oracle instance started
database mounted

Total System Global Area 53687091200 bytes

Fixed Size 2184048 bytes
Variable Size 4546628752 bytes
Database Buffers 49123688448 bytes
Redo Buffers 14589952 bytes

RMAN>

6.还原数据文件,并恢复
将生产数据库的归档日志也拷贝到指定的目录

RMAN> catalog start with '/data/IP';
生产数据库的文件都放在/dbdata/oracledata/mvbox/挂载点
而还原库的数据文件在/data/oracledata/oradata/mvbox/挂载点

 在生产数据库运行查询
select
'set newname for datafile ' || file_id ||
' to ''' ||
replace(file_name,'/dbdata/oracledata/mvbox','/data/oracledata/oradata/mvbox')||''';' 
from  dba_data_files;


然后根据这个查询的结果,拼出还原库执行的命令

 先还原数据文件

run{
CONFIGURE DEVICE TYPE DISK PARALLELISM 5 BACKUP TYPE TO BACKUPSET;
set newname for datafile 4 to '/data/oracledata/oradata/mvbox/users01.dbf';
set newname for datafile 3 to '/data/oracledata/oradata/mvbox/sysaux01.dbf';
set newname for datafile 1 to '/data/oracledata/oradata/mvbox/system01.dbf';
set newname for datafile 5 to '/data/oracledata/oradata/mvbox/system02.dbf';
set newname for datafile 6 to '/data/oracledata/oradata/mvbox/sysaux02.dbf';
set newname for datafile 7 to '/data/oracledata/oradata/mvbox/users02.dbf';
set newname for datafile 8 to '/data/oracledata/oradata/mvbox/users03.dbf';
set newname for datafile 9 to '/data/oracledata/oradata/mvbox/users04.dbf';
set newname for datafile 10 to '/data/oracledata/oradata/mvbox/users05.dbf';
set newname for datafile 12 to '/data/oracledata/oradata/mvbox/users06.dbf';
set newname for datafile 13 to '/data/oracledata/oradata/mvbox/system03.dbf';
set newname for datafile 14 to '/data/oracledata/oradata/mvbox/sysaux03.dbf';
set newname for datafile 27 to '/data/oracledata/oradata/mvbox/users19.dbf';
set newname for datafile 15 to '/data/oracledata/oradata/mvbox/users07.dbf';
set newname for datafile 16 to '/data/oracledata/oradata/mvbox/users08.dbf';
set newname for datafile 17 to '/data/oracledata/oradata/mvbox/users09.dbf';
set newname for datafile 18 to '/data/oracledata/oradata/mvbox/users10.dbf';
set newname for datafile 19 to '/data/oracledata/oradata/mvbox/users11.dbf';
set newname for datafile 20 to '/data/oracledata/oradata/mvbox/users12.dbf';
set newname for datafile 21 to '/data/oracledata/oradata/mvbox/users13.dbf';
set newname for datafile 22 to '/data/oracledata/oradata/mvbox/users14.dbf';
set newname for datafile 23 to '/data/oracledata/oradata/mvbox/users15.dbf';
set newname for datafile 24 to '/data/oracledata/oradata/mvbox/users16.dbf';
set newname for datafile 25 to '/data/oracledata/oradata/mvbox/users17.dbf';
set newname for datafile 26 to '/data/oracledata/oradata/mvbox/users18.dbf';
set newname for datafile 28 to '/data/oracledata/oradata/mvbox/users20.dbf';
set newname for datafile 33 to '/data/oracledata/oradata/mvbox/users21.dbf';
set newname for datafile 34 to '/data/oracledata/oradata/mvbox/users22.dbf';
set newname for datafile 35 to '/data/oracledata/oradata/mvbox/undotbs.dbf';
restore database;
switch datafile all;
}

找到生产数据库传输过来的归档日志文件,找到最后一个文件

Oracle 还原库

恢复到最后一个归档日志文件序列.


run{
CONFIGURE DEVICE TYPE DISK PARALLELISM 5 BACKUP TYPE TO BACKUPSET;
set until sequence 7939; 
recover database;
}


然后open数据库
生产库有block change tracking
还原库可以关闭
另外,查看恢复的时间点


alter database disable block change tracking;

 
alter database open read only;

select to_char(scn_to_timestamp(CURRENT_SCN),'yyyy-mm-dd HH24:mi:ss') ts from v$database;

这时候,还原库已经搭建完成.

生产库有一个程序,每隔30分钟,会将归档日志传送过来.
还原库这边,只需要定期恢复即可(恢复到6小时之前)

0 */3 * * * /root/testoracle.sh

#!/bin/bash
  source ~/.bashrc
    rman target / <<EOF
    shutdown
    startup mount
    catalog start with '/data/IP' noprompt;
    recover database until time "sysdate - interval '6' hour";
    sql 'alter database open read only';
EOF

7.把还原库拉起到读写模式.
    如果到了第七步,就有麻烦了.
    这意味着,生产数据库挂了,DataGuard的备机也挂了.
    只能把还原库拉起来暂时作为生产库使用.

    尝试将停留在下午4点的还原库,恢复至下午6点,并拉起为读写模式。

恢复之前

Oracle 还原库

执行RMAN命令

rman:
shutdown;
startup mount;
catalog start with '/data/IP' noprompt;
recover database until time "to_date('20150925 18:00:00','yyyymmdd hh24:mi:ss')";

    RMAN执行


RMAN> shutdown;

using target database control file instead of recovery catalog
database closed
database dismounted
Oracle instance shut down

RMAN> startup mount;

connected to target database (not started)
Oracle instance started
database mounted

Total System Global Area 53687091200 bytes

Fixed Size 2184048 bytes
Variable Size 4546628752 bytes
Database Buffers 49123688448 bytes
Redo Buffers 14589952 bytes

RMAN> catalog start with '/data/IP' noprompt;

searching for all files that match the pattern /data/IP

List of Files Unknown to the Database
=====================================
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7945_c0bh8dgv_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7942_c0bc4hv5_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7944_c0bfx7l2_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7940_c0b7ntyf_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7941_c0b9kdlw_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7943_c0bdkzyp_.arc
cataloging files...
cataloging done

List of Cataloged Files
=======================
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7945_c0bh8dgv_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7942_c0bc4hv5_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7944_c0bfx7l2_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7940_c0b7ntyf_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7941_c0b9kdlw_.arc
File Name: /data/IP/archivelog/2015_09_25/o1_mf_1_7943_c0bdkzyp_.arc

RMAN> recover database until time "to_date('20150925 18:00:00','yyyymmdd hh24:mi:ss')";

Starting recover at 25-SEP-15
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=1641 devtype=DISK
allocated channel: ORA_DISK_2
channel ORA_DISK_2: sid=1639 devtype=DISK
allocated channel: ORA_DISK_3
channel ORA_DISK_3: sid=1638 devtype=DISK
allocated channel: ORA_DISK_4
channel ORA_DISK_4: sid=1637 devtype=DISK
allocated channel: ORA_DISK_5
channel ORA_DISK_5: sid=1636 devtype=DISK

starting media recovery

archive log thread 1 sequence 7939 is already on disk as file /data/IP/archivelog/2015_09_25/o1_mf_1_7939_c0b5fr87_.arc
archive log thread 1 sequence 7940 is already on disk as file /data/IP/archivelog/2015_09_25/o1_mf_1_7940_c0b7ntyf_.arc
archive log filename=/data/IP/archivelog/2015_09_25/o1_mf_1_7939_c0b5fr87_.arc thread=1 sequence=7939
archive log filename=/data/IP/archivelog/2015_09_25/o1_mf_1_7940_c0b7ntyf_.arc thread=1 sequence=7940
media recovery complete, elapsed time: 00:04:07
Finished recover at 25-SEP-15
    进入sqlplus,修改联机重做日志的位置.因为这个位置还是生产库的,还原库上不一定有这个路径.


SQL> select 'alter database rename file ''' ||member|| ''' to ''/data/oracledata/oradata/mvbox/redo' || rownum ||'.log'';' sql from v$logfile;

SQL
alter database rename file '/data/oracledata/oradata/mvbox/redo04.log1' to '/data/oracledata/oradata/mvbox/redo1.log';
alter database rename file '/data/dblog/redo04.log2' to '/data/oracledata/oradata/mvbox/redo2.log';
alter database rename file '/data/oracledata/oradata/mvbox/redo05.log3' to '/data/oracledata/oradata/mvbox/redo3.log';
alter database rename file '/data/dblog/redo05.log4' to '/data/oracledata/oradata/mvbox/redo4.log';
alter database rename file '/data/oracledata/oradata/mvbox/redo06.log5' to '/data/oracledata/oradata/mvbox/redo5.log';
alter database rename file '/data/dblog/redo06.log6' to '/data/oracledata/oradata/mvbox/redo6.log';
alter database rename file '/data/oracledata/oradata/mvbox/redo07.log7' to '/data/oracledata/oradata/mvbox/redo7.log';
alter database rename file '/data/dblog/redo07.log8' to '/data/oracledata/oradata/mvbox/redo8.log';
alter database rename file '/data/oracledata/oradata/mvbox/redo08.log9' to '/data/oracledata/oradata/mvbox/redo9.log';
alter database rename file '/data/dblog/redo08.log10' to '/data/oracledata/oradata/mvbox/redo10.log';

10 rows selected.

alter database rename file '/data/oracledata/oradata/mvbox/redo04.log1' to '/data/oracledata/oradata/mvbox/redo1.log';

Database altered.

alter database rename file '/data/dblog/redo04.log2' to '/data/oracledata/oradata/mvbox/redo2.log';

Database altered.

alter database rename file '/data/oracledata/oradata/mvbox/redo05.log3' to '/data/oracledata/oradata/mvbox/redo3.log';

Database altered.

alter database rename file '/data/dblog/redo05.log4' to '/data/oracledata/oradata/mvbox/redo4.log';

Database altered.

alter database rename file '/data/oracledata/oradata/mvbox/redo06.log5' to '/data/oracledata/oradata/mvbox/redo5.log';

Database altered.

alter database rename file '/data/dblog/redo06.log6' to '/data/oracledata/oradata/mvbox/redo6.log';

Database altered.

alter database rename file '/data/oracledata/oradata/mvbox/redo07.log7' to '/data/oracledata/oradata/mvbox/redo7.log';

Database altered.

alter database rename file '/data/dblog/redo07.log8' to '/data/oracledata/oradata/mvbox/redo8.log';

Database altered.

alter database rename file '/data/oracledata/oradata/mvbox/redo08.log9' to '/data/oracledata/oradata/mvbox/redo9.log';

Database altered.

SQL> alter database rename file '/data/dblog/redo08.log10' to '/data/oracledata/oradata/mvbox/redo10.log';

Database altered.

SQL> alter database open resetlogs;

Database altered.

SQL>

    现在数据库虽然已经拉起来了,但是注意还有临时表空间。
  给默认临时表空间增加一个数据文件.
  然后删除其他数据文件,重新添加
  (备份不包括临时表空间,所以拉起之后,临时表空间需要另外处理一下)

ALTER TABLESPACE TEMP
ADD TEMPFILE '/data/oracledata/oradata/mvbox/temp03.dbf'
SIZE 4G 
AUTOEXTEND ON
NEXT 128M
MAXSIZE 30G;

ALTER TABLESPACE TEMP DROP TEMPFILE '/dbdata/oracledata/mvbox/temp01.dbf';
ALTER TABLESPACE TEMP DROP TEMPFILE '/dbdata/oracledata/mvbox/temp02.dbf';

还原库搭建完成.

凡事豫则立,不豫则废
我一定要牢记一点,
不要相信自己的技术,
尽量完善各种预案,一旦遇到技术难题,不能解决.
最后一定要切的过来,不丢数据.
永远不因为数据丢失的问题道歉.

相关推荐