Duplicate (Clone) Oracle Database to the Same Machine (同一机器数据库还原)(二)
continual…
Duplicate (Clone) Oracle Database to the Same Machine (同一机器数据库还原)(一)
2. Backup-based Duplication
When an DB operation error occurred , and flashback technique can not be used, you can use this way do a database point in time recover on same db server, to clone a new db to recover, then drop.
This is very simple to perform:
Create a backup of the source DB (if you do not have one already):
[oracle@dbserver58 admin]$ env|grep ORA
ORACLE_SID=pora58
ORACLE_BASE=/oracle
ORACLE_HOME=/oracle/product/11.2.0/db_1
RMAN> backup database;
Starting backup at 11-NOV-14
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=1710 device type=DISK
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00002 name=/oradata/pora58/sysaux01.dbf
input datafile file number=00004 name=/oradata/pora58/users01.dbf
input datafile file number=00001 name=/oradata/pora58/system01.dbf
input datafile file number=00003 name=/oradata/pora58/undotbs01.dbf
channel ORA_DISK_1: starting piece 1 at 11-NOV-14
channel ORA_DISK_1: finished piece 1 at 11-NOV-14
piece handle=/backup/fra/PORA58/backupset/2014_11_11/o1_mf_nnndf_TAG20141111T150900_b63fjdfl_.bkp tag=TAG20141111T150900 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current control file in backup set
including current SPFILE in backup set
channel ORA_DISK_1: starting piece 1 at 11-NOV-14
channel ORA_DISK_1: finished piece 1 at 11-NOV-14
piece handle=/backup/fra/PORA58/backupset/2014_11_11/o1_mf_ncsnf_TAG20141111T150900_b63fk6l6_.bkp tag=TAG20141111T150900 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 11-NOV-14
$ sqlplus / as sysdba SQL*Plus: Release 11.2.0.4.0 Production on Tue Nov 11 15:09:35 2014 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options USERNAME INST_NAME HOST_NAME SID SERIAL# VERSION STARTED SPID -------------------- -------------------- ------------------------- ----- -------- ---------- -------- --------------- SYS pora58 dbserver58 1426 1335 11.2.0.4.0 20141111 25025 SQL> select dbms_flashback.GET_SYSTEM_CHANGE_NUMBER from dual; GET_SYSTEM_CHANGE_NUMBER ------------------------ 4840862 SQL> create table system.test as select * from dba_objects; Table created. SQL> select dbms_flashback.GET_SYSTEM_CHANGE_NUMBER from dual; GET_SYSTEM_CHANGE_NUMBER ------------------------ 4840986 SQL> update system.test set object_name='truncated'; 87491 rows updated. Note: We think this operation is wrong SQL> commit; Commit complete. SQL> select dbms_flashback.GET_SYSTEM_CHANGE_NUMBER from dual; GET_SYSTEM_CHANGE_NUMBER ------------------------ 4841040
Auxiliary db TNSNAME,LISTENER,PASSWORD, AUDIT FILE PATH config and created ,here omit.
DB CLONE point in time recovery
[oracle@dbserver58 ~]$ export ORACLE_SID=new58 [oracle@dbserver58 dbs]$ env|grep ORA ORACLE_SID=new58 ORACLE_BASE=/oracle ORACLE_HOME=/oracle/product/11.2.0/db_1 [oracle@dbserver58 ~]$ rman target sys/oracle@db1 auxiliary / Recovery Manager: Release 11.2.0.4.0 - Production on Tue Nov 11 15:37:41 2014 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: PORA58 (DBID=745023158) connected to auxiliary database: DUMMY (not mounted) RMAN> run{ 2> allocate channel prmy1 type disk; 3> allocate auxiliary channel stby type disk; 4> duplicate target database TO new58 5> UNTIL scn 4840986 6> spfile 7> parameter_value_convert 'pora58','new58' 8> set db_unique_name='new58' 9> set db_file_name_convert='/oradata/pora58/','/oradata/new58/' 10> set log_file_name_convert='/oradata/pora58/','/oradata/new58/' 11> set control_files='/oradata/new58/control01.ctl','/oradata/new58/control02.ctl' 12> set log_archive_max_processes='5' 13> BACKUP LOCATION '/backup/fra/PORA58/backupset/2014_11_11' 14> ; 15> } allocated channel: prmy1 channel prmy1: SID=571 device type=DISK allocated channel: stby channel stby: SID=396 device type=DISK Starting Duplicate Db at 11-NOV-14 released channel: prmy1 released channel: stby RMAN-00571: =========================================================== RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS =============== RMAN-00571: =========================================================== RMAN-03002: failure of Duplicate Db command at 11/11/2014 15:39:14 RMAN-05501: aborting duplication of target database RMAN-06457: UNTIL SCN (4840986) is ahead of last SCN in archived logs (4825354) # target pora58 SQL> select thread#, status, enabled, checkpoint_time, checkpoint_change# from v$thread; THREAD# STATUS ENABLED CHECKPOINT_TIME CHECKPOINT_CHANGE# ---------- ------ -------- ----------------- ------------------ 1 OPEN PUBLIC 20141111 10:00:31 4825354 SQL> alter system checkpoint; System altered. SQL> alter system archive log current; System altered. SQL> select thread#, status, enabled, checkpoint_time, checkpoint_change# from v$thread; THREAD# STATUS ENABLED CHECKPOINT_TIME CHECKPOINT_CHANGE# ---------- ------ -------- ----------------- ------------------ 1 OPEN PUBLIC 20141111 15:40:46 4842411 [oracle@dbserver58 ~]$ cd $ORACLE_HOME/dbs [oracle@dbserver58 dbs]$ ls hc_new58.dat hc_pora58.dat init.ora lkNEW58 lkPORA58 orapwnew58 orapwpora58 snapcf_pora58.f spfilenew58.ora spfilepora58.ora [oracle@dbserver58 dbs]$ rm spfilenew58.ora [oracle@dbserver58 dbs]$ rman target sys/oracle@db1 auxiliary / Recovery Manager: Release 11.2.0.4.0 - Production on Tue Nov 11 15:45:06 2014 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: PORA58 (DBID=745023158) connected to auxiliary database (not started) RMAN> run{ 2> allocate channel prmy1 type disk; 3> allocate auxiliary channel stby type disk; 4> duplicate target database TO new58 5> UNTIL scn 4840986 6> spfile 7> parameter_value_convert 'pora58','new58' 8> set db_unique_name='new58' 9> set db_file_name_convert='/oradata/pora58/','/oradata/new58/' 10> set log_file_name_convert='/oradata/pora58/','/oradata/new58/' 11> set control_files='/oradata/new58/control01.ctl','/oradata/new58/control02.ctl' 12> set log_archive_max_processes='5' 13> BACKUP LOCATION '/backup/fra/PORA58/backupset/2014_11_11' 14> ; 15> } [oracle@dbserver58 dbs]$ rman target / Recovery Manager: Release 11.2.0.4.0 - Production on Tue Nov 11 15:45:35 2014 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database (not started) RMAN> startup nomount force startup failed: ORA-01078: failure in processing system parameters LRM-00109: could not open parameter file '/oracle/product/11.2.0/db_1/dbs/initnew58.ora' starting Oracle instance without parameter file for retrieval of spfile Oracle instance started Total System Global Area 1068937216 bytes Fixed Size 2260088 bytes Variable Size 285213576 bytes Database Buffers 775946240 bytes Redo Buffers 5517312 bytes rman target sys/oracle@db1 auxiliary / run{ allocate channel prmy1 type disk; allocate auxiliary channel stby type disk; duplicate target database TO new58 UNTIL scn 4840986 spfile parameter_value_convert 'pora58','new58' set db_unique_name='new58' set db_file_name_convert='/oradata/pora58/','/oradata/new58/' set log_file_name_convert='/oradata/pora58/','/oradata/new58/' set control_files='/oradata/new58/control01.ctl','/oradata/new58/control02.ctl' set log_archive_max_processes='5' BACKUP LOCATION '/backup/fra/PORA58/backupset/2014_11_11' ; } [oracle@dbserver58 dbs]$ rman target sys/oracle@db1 auxiliary / Recovery Manager: Release 11.2.0.4.0 - Production on Tue Nov 11 15:45:48 2014 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: PORA58 (DBID=745023158) connected to auxiliary database: DUMMY (not mounted) RMAN> run{ 2> allocate channel prmy1 type disk; 3> allocate auxiliary channel stby type disk; 4> duplicate target database TO new58 5> UNTIL scn 4840986 6> spfile 7> parameter_value_convert 'pora58','new58' 8> set db_unique_name='new58' 9> set db_file_name_convert='/oradata/pora58/','/oradata/new58/' 10> set log_file_name_convert='/oradata/pora58/','/oradata/new58/' 11> set control_files='/oradata/new58/control01.ctl','/oradata/new58/control02.ctl' 12> set log_archive_max_processes='5' 13> BACKUP LOCATION '/backup/fra/PORA58/backupset/2014_11_11' 14> ; 15> } using target database control file instead of recovery catalog allocated channel: prmy1 channel prmy1: SID=1426 device type=DISK allocated channel: stby channel stby: SID=396 device type=DISK Starting Duplicate Db at 11-NOV-14 contents of Memory Script: { set until scn 4840986; restore clone spfile to '/oracle/product/11.2.0/db_1/dbs/spfilenew58.ora'; sql clone "alter system set spfile= ''/oracle/product/11.2.0/db_1/dbs/spfilenew58.ora''"; } executing Memory Script executing command: SET until clause Starting restore at 11-NOV-14 WARNING: A restore time was estimated based on the supplied UNTIL SCN channel stby: starting datafile backup set restore channel stby: restoring SPFILE output file name=/oracle/product/11.2.0/db_1/dbs/spfilenew58.ora channel stby: reading from backup piece /backup/fra/PORA58/backupset/2014_11_11/o1_mf_ncsnf_TAG20141111T150900_b63fk6l6_.bkp channel stby: piece handle=/backup/fra/PORA58/backupset/2014_11_11/o1_mf_ncsnf_TAG20141111T150900_b63fk6l6_.bkp tag=TAG20141111T150900 channel stby: restored backup piece 1 channel stby: restore complete, elapsed time: 00:00:01 Finished restore at 11-NOV-14 sql statement: alter system set spfile= ''/oracle/product/11.2.0/db_1/dbs/spfilenew58.ora'' contents of Memory Script: { sql clone "alter system set db_name = ''NEW58'' comment= ''duplicate'' scope=spfile"; sql clone "alter system set audit_file_dest = ''/oracle/admin/new58/adump'' comment= '''' scope=spfile"; sql clone "alter system set dispatchers = ''(PROTOCOL=TCP) (SERVICE=new58XDB)'' comment= '''' scope=spfile"; sql clone "alter system set log_archive_format = ''new58_%t_%s_%r.arc'' comment= '''' scope=spfile"; sql clone "alter system set db_unique_name = ''new58'' comment= '''' scope=spfile"; sql clone "alter system set db_file_name_convert = ''/oradata/pora58/'', ''/oradata/new58/'' comment= '''' scope=spfile"; sql clone "alter system set log_file_name_convert = ''/oradata/pora58/'', ''/oradata/new58/'' comment= '''' scope=spfile"; sql clone "alter system set control_files = ''/oradata/new58/control01.ctl'', ''/oradata/new58/control02.ctl'' comment= '''' scope=spfile"; sql clone "alter system set log_archive_max_processes = 5 comment= '''' scope=spfile"; shutdown clone immediate; startup clone nomount; } executing Memory Script sql statement: alter system set db_name = ''NEW58'' comment= ''duplicate'' scope=spfile sql statement: alter system set audit_file_dest = ''/oracle/admin/new58/adump'' comment= '''' scope=spfile sql statement: alter system set dispatchers = ''(PROTOCOL=TCP) (SERVICE=new58XDB)'' comment= '''' scope=spfile sql statement: alter system set log_archive_format = ''new58_%t_%s_%r.arc'' comment= '''' scope=spfile sql statement: alter system set db_unique_name = ''new58'' comment= '''' scope=spfile sql statement: alter system set db_file_name_convert = ''/oradata/pora58/'', ''/oradata/new58/'' comment= '''' scope=spfile sql statement: alter system set log_file_name_convert = ''/oradata/pora58/'', ''/oradata/new58/'' comment= '''' scope=spfile sql statement: alter system set control_files = ''/oradata/new58/control01.ctl'', ''/oradata/new58/control02.ctl'' comment= '''' scope=spfile sql statement: alter system set log_archive_max_processes = 5 comment= '''' scope=spfile Oracle instance shut down connected to auxiliary database (not started) Oracle instance started Total System Global Area 6012973056 bytes Fixed Size 2264176 bytes Variable Size 1711276944 bytes Database Buffers 4294967296 bytes Redo Buffers 4464640 bytes allocated channel: stby channel stby: SID=1423 device type=DISK contents of Memory Script: { set until scn 4840986; sql clone "alter system set db_name = ''PORA58'' comment= ''Modified by RMAN duplicate'' scope=spfile"; sql clone "alter system set db_unique_name = ''NEW58'' comment= ''Modified by RMAN duplicate'' scope=spfile"; shutdown clone immediate; startup clone force nomount restore clone primary controlfile; alter clone database mount; } executing Memory Script executing command: SET until clause sql statement: alter system set db_name = ''PORA58'' comment= ''Modified by RMAN duplicate'' scope=spfile sql statement: alter system set db_unique_name = ''NEW58'' comment= ''Modified by RMAN duplicate'' scope=spfile Oracle instance shut down Oracle instance started Total System Global Area 6012973056 bytes Fixed Size 2264176 bytes Variable Size 1711276944 bytes Database Buffers 4294967296 bytes Redo Buffers 4464640 bytes allocated channel: stby channel stby: SID=1423 device type=DISK Starting restore at 11-NOV-14 channel stby: starting datafile backup set restore channel stby: restoring control file channel stby: reading from backup piece /backup/fra/PORA58/backupset/2014_11_11/o1_mf_ncsnf_TAG20141111T150900_b63fk6l6_.bkp channel stby: piece handle=/backup/fra/PORA58/backupset/2014_11_11/o1_mf_ncsnf_TAG20141111T150900_b63fk6l6_.bkp tag=TAG20141111T150900 channel stby: restored backup piece 1 channel stby: restore complete, elapsed time: 00:00:01 output file name=/oradata/new58/control01.ctl output file name=/oradata/new58/control02.ctl Finished restore at 11-NOV-14 database mounted contents of Memory Script: { set until scn 4840986; set newname for datafile 1 to "/oradata/new58/system01.dbf"; set newname for datafile 2 to "/oradata/new58/sysaux01.dbf"; set newname for datafile 3 to "/oradata/new58/undotbs01.dbf"; set newname for datafile 4 to "/oradata/new58/users01.dbf"; restore clone database ; } executing Memory Script executing command: SET until clause executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME Starting restore at 11-NOV-14 channel stby: starting datafile backup set restore channel stby: specifying datafile(s) to restore from backup set channel stby: restoring datafile 00001 to /oradata/new58/system01.dbf channel stby: restoring datafile 00002 to /oradata/new58/sysaux01.dbf channel stby: restoring datafile 00003 to /oradata/new58/undotbs01.dbf channel stby: restoring datafile 00004 to /oradata/new58/users01.dbf channel stby: reading from backup piece /backup/fra/PORA58/backupset/2014_11_11/o1_mf_nnndf_TAG20141111T150900_b63fjdfl_.bkp channel stby: piece handle=/backup/fra/PORA58/backupset/2014_11_11/o1_mf_nnndf_TAG20141111T150900_b63fjdfl_.bkp tag=TAG20141111T150900 channel stby: restored backup piece 1 channel stby: restore complete, elapsed time: 00:00:25 Finished restore at 11-NOV-14 contents of Memory Script: { switch clone datafile all; } executing Memory Script datafile 1 switched to datafile copy input datafile copy RECID=8 STAMP=863365623 file name=/oradata/new58/system01.dbf datafile 2 switched to datafile copy input datafile copy RECID=9 STAMP=863365623 file name=/oradata/new58/sysaux01.dbf datafile 3 switched to datafile copy input datafile copy RECID=10 STAMP=863365623 file name=/oradata/new58/undotbs01.dbf datafile 4 switched to datafile copy input datafile copy RECID=11 STAMP=863365623 file name=/oradata/new58/users01.dbf contents of Memory Script: { set until scn 4840986; recover clone database delete archivelog ; } executing Memory Script executing command: SET until clause Starting recover at 11-NOV-14 starting media recovery archived log for thread 1 with sequence 53 is already on disk as file /oradata/arch/pora58_1_53_860491320.arc archived log file name=/oradata/arch/pora58_1_53_860491320.arc thread=1 sequence=53 media recovery complete, elapsed time: 00:00:01 Finished recover at 11-NOV-14 Oracle instance started Total System Global Area 6012973056 bytes Fixed Size 2264176 bytes Variable Size 1711276944 bytes Database Buffers 4294967296 bytes Redo Buffers 4464640 bytes contents of Memory Script: { sql clone "alter system set db_name = ''NEW58'' comment= ''Reset to original value by RMAN'' scope=spfile"; sql clone "alter system reset db_unique_name scope=spfile"; shutdown clone immediate; startup clone nomount; } executing Memory Script sql statement: alter system set db_name = ''NEW58'' comment= ''Reset to original value by RMAN'' scope=spfile sql statement: alter system reset db_unique_name scope=spfile Oracle instance shut down connected to auxiliary database (not started) Oracle instance started Total System Global Area 6012973056 bytes Fixed Size 2264176 bytes Variable Size 1711276944 bytes Database Buffers 4294967296 bytes Redo Buffers 4464640 bytes allocated channel: stby channel stby: SID=1423 device type=DISK sql statement: CREATE CONTROLFILE REUSE SET DATABASE "NEW58" RESETLOGS ARCHIVELOG MAXLOGFILES 16 MAXLOGMEMBERS 3 MAXDATAFILES 100 MAXINSTANCES 8 MAXLOGHISTORY 292 LOGFILE GROUP 1 ( '/oradata/new58/redo01.rlog' ) SIZE 200 M REUSE, GROUP 2 ( '/oradata/new58/redo02.rlog' ) SIZE 200 M REUSE, GROUP 3 ( '/oradata/new58/redo03.rlog' ) SIZE 200 M REUSE, GROUP 4 ( '/oradata/new58/redo04.rlog' ) SIZE 200 M REUSE DATAFILE '/oradata/new58/system01.dbf' CHARACTER SET ZHS16GBK contents of Memory Script: { set newname for tempfile 1 to "/oradata/new58/temp01.dbf"; switch clone tempfile all; catalog clone datafilecopy "/oradata/new58/sysaux01.dbf", "/oradata/new58/undotbs01.dbf", "/oradata/new58/users01.dbf"; switch clone datafile all; } executing Memory Script executing command: SET NEWNAME renamed tempfile 1 to /oradata/new58/temp01.dbf in control file cataloged datafile copy datafile copy file name=/oradata/new58/sysaux01.dbf RECID=1 STAMP=863365638 cataloged datafile copy datafile copy file name=/oradata/new58/undotbs01.dbf RECID=2 STAMP=863365638 cataloged datafile copy datafile copy file name=/oradata/new58/users01.dbf RECID=3 STAMP=863365638 datafile 2 switched to datafile copy input datafile copy RECID=1 STAMP=863365638 file name=/oradata/new58/sysaux01.dbf datafile 3 switched to datafile copy input datafile copy RECID=2 STAMP=863365638 file name=/oradata/new58/undotbs01.dbf datafile 4 switched to datafile copy input datafile copy RECID=3 STAMP=863365638 file name=/oradata/new58/users01.dbf Reenabling controlfile options for auxiliary database Executing: alter database add supplemental log data Executing: alter database force logging contents of Memory Script: { Alter clone database open resetlogs; } executing Memory Script database opened Finished Duplicate Db at 11-NOV-14 released channel: prmy1 released channel: stby RMAN> exit
$ sqlplus / as sysdba
SQL*Plus: Release 11.2.0.4.0 Production on Tue Nov 11 15:49:48 2014
Copyright (c) 1982, 2013, Oracle. All rights reserved.
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 – 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
USERNAME INST_NAME HOST_NAME SID SERIAL# VERSION STARTED SPID OPID CPID SADDR PADDR
——————– ——————– ————————- —– ——– ———- ——– ————— —– ————— —————- —————-
SYS new58 dbserver58 853 7 11.2.0.4.0 20141111 26099 19 26098 00000001C5AFBBC8 00000001C5117AA8
SQL> select object_name from system.test where rownum<=10; OBJECT_NAME ---------------------------------------------------------------------- ICOL$ I_USER1 CON$ UNDO$ C_COBJ# I_OBJ# PROXY_ROLE_DATA$ I_IND1 I_CDEF2 I_OBJ5 10 rows selected. # source db (pora58) SQL> select object_name from system.test where rownum<=10; OBJECT_NAME ------------------------------------------------------------------ truncated truncated truncated truncated truncated truncated truncated truncated truncated truncated 10 rows selected. Tip: You can using UNTIL TIME as well as UNTIL SCN. SCN_TO_TIMESTAMP: for converting given scn to timestamp value ; TIMESTAMP_TO_SCN : For getting SCN equivalent of the given timestamp value. You must do to_timestamp convertion for the character value. --over--
对不起,这篇文章暂时关闭评论。