2013年(350)
分类: Oracle
2013-04-27 17:06:58
从RAC数据库恢复到单实例的数据库,需要DBA做的工作还是有一些的---我是指除了常规恢复操作之外。
设定环境如下:
源端:192.168.10.11:12
目标端:192.168.10.101 ,机器名jssnode1
目标端已好数据库,并升级至与源端相同的版本,参数配置合理并且磁盘空间充足,源端创建的集也已复制至目标端。
别的就不废话了,接下来小跑进入实战演练部分吧,首先检查目标端设置环境变量:
[oracle@jssnode1 ~]$ env | grep ORA
ORACLE_SID=jssdb
ORACLE_BASE=/data/ora10g
ORACLE_TERM=xterm
ORACLE_HOME=/data/ora10g/product/10.2.0/db_1进入命令行模式,并启动到NOMOUNT状态:
[oracle@jssnode1 ~]$ rman target /
Recovery Manager: Release 10.2.0.4.0 - Production on Thu Feb 4 15:49:12 2010
Copyright (c) 1982, 2007, Oracle. All rights reserved.
connected to target database (not started)
RMAN> startup nomount
startup failed: ORA-01078: failure in processing system parameters
LRM-00109: could not open parameter file ¨/data/ora10g/product/10.2.0/db_1/dbs/initjssdb.ora¨
starting Oracle instance without parameter file for retrival of spfile
Oracle instance started
Total System Global Area 159383552 bytes
Fixed Size 2082400 bytes
Variable Size 67111328 bytes
Database Buffers 83886080 bytes
Redo Buffers 6303744 bytes脑袋里蹦出了个大问号:怎么没见创建初始化参数文件,也能启动到NOMOUNT呢?当然可以啦,具体参考"涂抹ORACLE--三思笔记"中9.2.4.2小节中的相关内容。
启动过程中报错了,不管它,这里startup的目的只是为了给分配相应的内存区,以便让他能够执行下面的restore操作。
从备份集中恢复spfile并保存成pfile,操作如下:
RMAN> restore spfile to pfile ¨/data1/pfile.ora¨ from ¨/data/backup/07l53d5s_1_1¨;
Starting restore at 04-FEB-10
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=36 devtype=DISK
channel ORA_DISK_1: autobackup found: /data/backup/07l53d5s_1_1
channel ORA_DISK_1: SPFILE restore from autobackup complete
Finished restore at 04-FEB-10接下来要做的是个体力活,修改pfile.ora中的初始化参数,主要有两方面的修改:
原文件内容如下:
jssdbn1.__db_cache_size=104857600
jssdbn2.__db_cache_size=100663296
jssdbn1.__java_pool_size=4194304
jssdbn2.__java_pool_size=4194304
jssdbn1.__large_pool_size=4194304
jssdbn2.__large_pool_size=4194304
jssdbn1.__shared_pool_size=163577856
jssdbn2.__shared_pool_size=167772160
jssdbn1.__streams_pool_size=0
jssdbn2.__streams_pool_size=0
*.audit_file_dest=¨/data/ora10g/admin/jssdb/adump¨
*.background_dump_dest=¨/data/ora10g/admin/jssdb/bdump¨
*.cluster_database_instances=2
*.cluster_database=true
*.compatible=¨10.2.0.1.0¨
*.control_files=¨+ASMDISK1/jssdb/control01.ctl¨,¨+ASMDISK1/jssdb/control02.ctl¨,¨+ASMDISK1/jssdb/control03.ctl¨
*.core_dump_dest=¨/data/ora10g/admin/jssdb/cdump¨
*.db_block_size=8192
*.db_create_file_dest=¨+ASMDISK1¨
*.db_domain=¨¨
*.db_file_multiblock_read_count=16
*.db_name=¨jssdb¨
jssdbn1.instance_number=1
jssdbn2.instance_number=2
*.job_queue_processes=10
jssdbn1.log_archive_dest_1=¨location=/data/oradata/jssdbn1/archivelog¨
jssdbn2.log_archive_dest_1=¨location=/data/oradata/jssdbn2/archivelog¨
*.log_archive_dest_2=¨¨
jssdbn1.log_archive_dest_2=¨service=jssdbn2¨
jssdbn1.log_archive_local_first=FALSE
*.open_cursors=300
*.pga_aggregate_target=94371840
*.processes=150
*.remote_listener=¨LISTENERS_JSSDB¨
*.remote_login_passwordfile=¨exclusive¨
*.sga_target=283115520
jssdbn2.thread=2
jssdbn1.thread=1
*.undo_management=¨AUTO¨
jssdbn1.undo_tablespace=¨UNDOTBS1¨
jssdbn2.undo_tablespace=¨UNDOTBS2¨
*.user_dump_dest=¨/data/ora10g/admin/jssdb/udump¨最终修改完之后,三思这里的初始化参数如下,比如原来的文件精简不少:
*.audit_file_dest=¨/data/ora10g/admin/jssdb/adump¨
*.background_dump_dest=¨/data/ora10g/admin/jssdb/bdump¨
*.compatible=¨10.2.0.1.0¨
*.control_files=¨/data1/jssdb/control01.ctl¨,¨/data1/jssdb/control02.ctl¨,¨/data1/jssdb/control03.ctl¨
*.core_dump_dest=¨/data/ora10g/admin/jssdb/cdump¨
*.db_block_size=8192
*.db_domain=¨¨
*.db_file_multiblock_read_count=16
*.db_name=¨jssdb¨
*.job_queue_processes=10
*.log_archive_dest_1=¨location=/data1/jssdb/archivelog¨
*.open_cursors=300
*.pga_aggregate_target=94371840
*.processes=150
*.remote_login_passwordfile=¨exclusive¨
*.sga_target=283115520
*.undo_management=¨AUTO¨
*.undo_tablespace=¨UNDOTBS1¨
*.user_dump_dest=¨/data/ora10g/admin/jssdb/udump¨然后进入sqlplus命令行环境,通过编辑好的pfile创建spfile,并重启oracle到nomount状态:
SQL> create spfile from pfile =¨/data1/pfile.ora¨;
File created.
SQL> shutdown immediate
ORA-01507: database not mounted
ORACLE instance shut down.
SQL> startup nomount
ORACLE instance started.
Total System Global Area 285212672 bytes
Fixed Size 2083368 bytes
Variable Size 88081880 bytes
Database Buffers 188743680 bytes
Redo Buffers 6303744 bytes接下来要恢复控制文件了,再次进入RMAN命令行,注意操作前别忘了设置dbid(如何获取dbid就不说了吧),执行操作如下:
RMAN> set dbid=953576437
executing command: SET DBID
RMAN> restore controlfile from ¨/data/backup/07l53d5s_1_1¨;
Starting restore at 04-FEB-10
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=156 devtype=DISK
channel ORA_DISK_1: restoring control file
channel ORA_DISK_1: restore complete, elapsed time: 00:00:04
output filename=/data1/jssdb/control01.ctl
output filename=/data1/jssdb/control02.ctl
output filename=/data1/jssdb/control03.ctl
Finished restore at 04-FEB-10控制文件成功恢复到指定路径下。
下面就可以进入到mount状态了:
RMAN> alter database mount;
database mounted
released channel: ORA_DISK_1注册表库备份后生成的归档文件备份集:
RMAN> catalog backuppiece ¨/data/backup/08l53d64_1_1¨;
cataloged backuppiece
backup piece handle=/data/backup/08l53d64_1_1 recid=7 stamp=710179350由于之前在RMAN中配置了默认通道,这里也要将这些配置清除,操作如下:
RMAN> configure channel 1 device type disk clear;
old RMAN configuration parameters:
CONFIGURE CHANNEL 1 DEVICE TYPE DISK CONNECT ¨*¨;
old RMAN configuration parameters are successfully deleted
RMAN> configure channel 2 device type disk clear;
old RMAN configuration parameters:
CONFIGURE CHANNEL 2 DEVICE TYPE DISK CONNECT ¨*¨;
old RMAN configuration parameters are successfully deleted
RMAN> configure device type disk clear;
old RMAN configuration parameters:
CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
RMAN configuration parameters are successfully reset to default value接下来先别忙着做restore,有下列文件是需要我们预先进行处理的:
SQL> select file#,name from v$datafile;
FILE# NAME
---------- ------------------------------------------------------------
1 +ASMDISK1/jssdb/datafile/system.260.703671683
2 +ASMDISK1/jssdb/datafile/undotbs1.259.703671695
3 +ASMDISK1/jssdb/datafile/sysaux.266.703671697
4 +ASMDISK1/jssdb/datafile/undotbs2.258.703671705
5 +ASMDISK1/jssdb/datafile/users.257.703671709
6 +ASMDISK1/jssdb/datafile/jsstbs.269.703779631
6 rows selected.
SQL> select file#,name from v$tempfile;
FILE# NAME
---------- ------------------------------------------------------------
1 +ASMDISK1/jssdb/tempfile/temp.265.703671701
SQL> select member from v$logfile;
MEMBER
------------------------------------------------------------
+ASMDISK1/jssdb/onlinelog/group_1.263.703671679
+ASMDISK1/jssdb/onlinelog/group_2.261.703671681
+ASMDISK1/jssdb/onlinelog/group_3.256.703672257
+ASMDISK1/jssdb/onlinelog/group_4.268.703672257RMAN 中的SET命令可以用来为数据文件和临时文件重命名,这里三思就使用set命令对数据文件和临时文件的路径进行重定义,然后再执行恢复操作,如下:
RMAN> RUN {
2> SET NEWNAME FOR DATAFILE 1 to ¨/data1/jssdb/system01.dbf¨;
3> SET NEWNAME FOR DATAFILE 2 to ¨/data1/jssdb/undoa01.dbf¨;
4> SET NEWNAME FOR DATAFILE 3 to ¨/data1/jssdb/sysaux01.dbf¨;
5> SET NEWNAME FOR DATAFILE 4 to ¨/data1/jssdb/undob01.dbf¨;
6> SET NEWNAME FOR DATAFILE 5 to ¨/data1/jssdb/users01.dbf¨;
7> SET NEWNAME FOR DATAFILE 6 to ¨/data1/jssdb/jsstbs01.dbf¨;
8> SET NEWNAME FOR TEMPFILE 1 to ¨/data1/jssdb/temp01.dbf¨;
9> RESTORE DATABASE;
10> SWITCH DATAFILE ALL;
11> SWITCH TEMPFILE ALL;
12> }
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
Starting restore at 04-FEB-10
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=159 devtype=DISK
channel ORA_DISK_1: starting datafile backupset restore
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
restoring datafile 00001 to /data1/jssdb/system01.dbf
restoring datafile 00002 to /data1/jssdb/undoa01.dbf
restoring datafile 00003 to /data1/jssdb/sysaux01.dbf
restoring datafile 00004 to /data1/jssdb/undob01.dbf
restoring datafile 00005 to /data1/jssdb/users01.dbf
restoring datafile 00006 to /data1/jssdb/jsstbs01.dbf
channel ORA_DISK_1: reading from backup piece /data/backup/06l53d53_1_1
channel ORA_DISK_1: restored backup piece 1
piece handle=/data/backup/06l53d53_1_1 tag=TAG20100203T133531
channel ORA_DISK_1: restore complete, elapsed time: 00:00:25
Finished restore at 04-FEB-10
datafile 1 switched to datafile copy
input datafile copy recid=7 stamp=710096833 filename=/data1/jssdb/system01.dbf
datafile 2 switched to datafile copy
input datafile copy recid=8 stamp=710096833 filename=/data1/jssdb/undoa01.dbf
datafile 3 switched to datafile copy
input datafile copy recid=9 stamp=710096833 filename=/data1/jssdb/sysaux01.dbf
datafile 4 switched to datafile copy
input datafile copy recid=10 stamp=710096833 filename=/data1/jssdb/undob01.dbf
datafile 5 switched to datafile copy
input datafile copy recid=11 stamp=710096833 filename=/data1/jssdb/users01.dbf
datafile 6 switched to datafile copy
input datafile copy recid=12 stamp=710096833 filename=/data1/jssdb/jsstbs01.dbf
renamed temporary file 1 to /data1/jssdb/temp01.dbf in control file对数据库执行recover,由于我们只复制了备份集,而没有复制源库中新归档以及online redo文件,这里只能进行不完全的恢复(创建的备份并非一致性冷备份),也就是说,报错是必然的,不过没关系,只要能修复到一致性状态就好:
RMAN> recover database;
Starting recover at 04-FEB-10
using channel ORA_DISK_1
starting media recovery
unable to find archive log
archive log thread=2 sequence=98
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of recover command at 02/04/2010 17:24:11
RMAN-06054: media recovery requesting unknown log: thread 2 seq 98 lowscn 15874447接下来,我们不得不重建控制文件,以修复重做日志文件的路径:
SQL> alter database backup controlfile to trace;
Database altered.你也许在想,可以通过"alter database rename file"方式修改重做日志文件路径的啊,事实上"alter database rename file"方式极有可能触发" ORA-00600: internal error code, arguments: [kgeade_is_0], [], [], [], [], [], [], [] " 错误,经查这是ORACLE的一个BUG,对应BUG为7207932,通常是RAC环境从asm向文件系统迁移时被触发,在10204版本中依然存在,Doc ID: 742289.1对此有详细说明,号称11g版本中对该问题进行了修复。
获取控制文件创建脚本之后,稍加修改(主要是改redolog的路径),然后在sqlplus命令行环境下执行:
SQL> shutdown immediate
ORA-01109: database not open
Database dismounted.
ORACLE instance shut down.
SQL> startup nomount
ORACLE instance started.
Total System Global Area 285212672 bytes
Fixed Size 2083368 bytes
Variable Size 92276184 bytes
Database Buffers 184549376 bytes
Redo Buffers 6303744 bytes
SQL> CREATE CONTROLFILE REUSE DATABASE "JSSDB" RESETLOGS ARCHIVELOG
2 MAXLOGFILES 192
3 MAXLOGMEMBERS 3
4 MAXDATAFILES 1024
5 MAXINSTANCES 32
6 MAXLOGHISTORY 292
7 LOGFILE
8 GROUP 1 ¨/data1/jssdb/redo01.dbf¨ SIZE 50M,
9 GROUP 2 ¨/data1/jssdb/redo02.dbf¨ SIZE 50M
10 -- STANDBY LOGFILE
11 DATAFILE
12 ¨/data1/jssdb/system01.dbf¨,
13 ¨/data1/jssdb/undoa01.dbf¨,
14 ¨/data1/jssdb/sysaux01.dbf¨,
15 ¨/data1/jssdb/undob01.dbf¨,
16 ¨/data1/jssdb/users01.dbf¨,
17 ¨/data1/jssdb/jsstbs01.dbf¨
18 CHARACTER SET ZHS16GBK
19 ;
Control file created.
SQL> ALTER DATABASE ADD LOGFILE THREAD 2
2 GROUP 3 ¨/data1/jssdb/redo03.dbf¨ SIZE 50M,
3 GROUP 4 ¨/data1/jssdb/redo04.dbf¨ SIZE 50M;
Database altered.搞定,下面就可以打开数据库了:
SQL> alter database open resetlogs;
Database altered.接下来别忘了重建临时表空间的数据文件:
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE ¨/data1/jssdb/temp01.dbf¨ size 50m;
Tablespace altered.哎,做到这步,都还没有完啊,只是说目的基本达成,最后还需要收尾的工作。
清除未使用线程的redo日志组,操作如下:
SQL> select thread#,status,enabled from v$thread;
THREAD# STATUS ENABLED
---------- ------ --------
1 OPEN PUBLIC
2 CLOSED PRIVATE
SQL> select group#,thread#,archived,status from v$log;
GROUP# THREAD# ARC STATUS
---------- ---------- --- ----------------
1 1 YES INACTIVE
2 1 NO CURRENT
3 2 YES INACTIVE
4 2 NO CURRENT
SQL> alter database disable thread 2;
Database altered.
SQL> alter database drop logfile group 3;
Database altered.
SQL> alter database clear unarchived logfile group 4;
Database altered.
SQL> alter database drop logfile group 4;
Database altered.清除多余的undo文件。
SQL> select name from v$tablespace where name like ¨UNDO%¨;
NAME
------------------------------
UNDOTBS1
UNDOTBS2
SQL> show parameter undo_tablespace;
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
undo_tablespace string UNDOTBS1
SQL> drop tablespace undotbs2 including contents and datafiles;
Tablespace dropped.竣工!