Pages

Active Database Duplication in Oracle 11g with Example

Another long-overdue feature, introduced in 11g, is the ability to clone/duplicate a database (for standby or otherwise) without the use of an RMAN backup.
In previous versions, duplications were based upon backups of the TARGET database in question. Now, you can duplicate a database (over the network), without an RMAN backup.
Here is a complete example of duplicating an 11g database on the same machine (Linux) using the new, aforementioned active database duplication:
1. Create any needed directories


mkdir /u03/app/oracle/oradata/duptestmkdir /u03/app/oracle/admin/duptest/adump

2. Create hard-coded network entries for your new, auxiliary database
Addition to SID_LIST_LISTENER in listener.ora:

(SID_DESC =      (GLOBAL_DBNAME = duptest.colestock.test)      (ORACLE_HOME = /u03/app/oracle/product/db/11.1.0.6)      (SID_NAME = duptest)    )

Addition to tnsames.ora:

DUPTEST =  
(DESCRIPTION =    
(ADDRESS_LIST =      
(ADDRESS = (PROTOCOL = TCP)(HOST = rac2.colestock.test)(PORT = 1523))    )    (CONNECT_DATA =      
        (SERVER = DEDICATED)      
         (SERVICE_NAME = duptest.colestock.test)    )  )

3. Create a passwordfile for new, auxiliary database (this MUST match the TARGET)

cd $ORACLE_HOME/dbsorapwd file=orapwduptest password=password

4. Create ‘dummy’ parameter file for auxiliary instance

[/u03/app/oracle/product/db/11.1.0.6/dbs nf@rac2]$ more initduptest.ora

db_name=duptest
control_files=/u03/app/oracle/oradata/duptest/control01.ctl, /u03/app/oracle/oradata/duptest/control02.ctl, /u03/app/oracle/oradata/duptest/control03.ctl

5. Add relevant entry to oratab on non-Windows environments

[/u03/app/oracle/product/db/11.1.0.6/dbs nf@rac2]$ grep duptest /etc/oratabduptest:/u03/app/oracle/product/db/11.1.0.6:N

6. ‘Nomount’ the auxiliary instance in preparation for duplication

[/u03/app/oracle/product/db/11.1.0.6/dbs duptest@rac2] $ export ORACLE_SID=duptest
[/u03/app/oracle/product/db/11.1.0.6/dbs duptest@rac2] $ . oraenv
[/u03/app/oracle/product/db/11.1.0.6/dbs duptest@rac2] $ sqlplus "/ as sysdba"

SQL*Plus: Release 11.1.0.6.0 - Production on Mon Jan 14 11:03:52 2011

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

Connected to an idle instance.

SQL> startup nomount
ORACLE instance started.

Total System Global Area  150667264 bytesFixed Size      1298472 bytesVariable Size     92278744 bytesDatabase Buffers    50331648 bytesRedo Buffers      6758400 bytesSQL> exit

7. Duplicate the database using RMAN


rman target=sys/password@nf auxiliary=sys/password@duptest

duplicate target database to duptest
2>    from active database
3>    db_file_name_convert '/nf/','/duptest/'
4>    spfile
5>    parameter_value_convert '/nf/','/duptest/'
6>    set log_file_name_convert '/nf/','/duptest/'
7>    set log_archive_dest_1='';

If successful, you should see output similar to the following:

Starting Duplicate Db at 14-JAN-11using target database control file instead of recovery catalogallocated channel: ORA_AUX_DISK_1channel ORA_AUX_DISK_1: SID=98 device type=DISK

contents of Memory Script:
{   backup as copy reuse   
file  '/u03/app/oracle/product/db/11.1.0.6/dbs/spfilenf.ora' 
auxiliary format  '/u03/app/oracle/product/db/11.1.0.6/dbs/spfileduptest.ora'   ;   
sql clone "alter system set spfile= ''/u03/app/oracle/product/db/11.1.0.6/dbs/spfileduptest.ora''";}

executing Memory Script

Starting backup at 14-JAN-11allocated channel: ORA_DISK_1channel ORA_DISK_1: SID=116 device type=DISKFinished backup at 14-JAN-11

sql statement: alter system set spfile= ''/u03/app/oracle/product/db/11.1.0.6/dbs/spfileduptest.ora''

contents of Memory Script:
{   
sql clone "alter system set  db_name =  ''DUPTEST'' comment= ''duplicate'' scope=spfile"; 
  
sql clone "alter system set  audit_file_dest =  ''/u03/app/oracle/admin/duptest/adump'' comment= '''' scope=spfile"; 
  
sql clone "alter system set  control_files =  ''/u03/app/oracle/oradata/duptest/control01.ctl'', ''/u03/app/oracle/oradata/duptest/control02.ctl'', ''/u03/app/oracle/oradata/duptest/control03.ctl'' comment= '''' scope=spfile"; 
  
sql clone "alter system set  log_file_name_convert =  ''/nf/'', ''/duptest/'' comment= '''' scope=spfile"; 
  
sql clone "alter system set  log_archive_dest_1 =  '''' comment= '''' scope=spfile"; 
  
shutdown clone immediate;   
startup clone nomount ;}

executing Memory Script

sql statement: alter system set  db_name =  ''DUPTEST'' comment= ''duplicate'' scope=spfile

sql statement: alter system set  audit_file_dest =  ''/u03/app/oracle/admin/duptest/adump'' comment= '''' scope=spfile

sql statement: alter system set  control_files =  ''/u03/app/oracle/oradata/duptest/control01.ctl'', ''/u03/app/oracle/oradata/duptest/control02.ctl'', ''/u03/app/oracle/oradata/duptest/control03.ctl'' comment= '''' scope=spfile

sql statement: alter system set  log_file_name_convert =  ''/nf/'', ''/duptest/'' comment= '''' scope=spfile

sql statement: alter system set  log_archive_dest_1 =  '''' comment= '''' scope=spfile

Oracle instance shut down

connected to auxiliary database (not started)Oracle instance started

Total System Global Area     422670336 bytes

Fixed Size                     1300352 bytesVariable Size                406849664 bytesDatabase Buffers               8388608 bytesRedo Buffers                   6131712 bytes

contents of Memory Script:
{   set newname for datafile  1 to  "/u03/app/oracle/oradata/duptest/system01.dbf";   
set newname for datafile  2 to  "/u03/app/oracle/oradata/duptest/sysaux01.dbf";   
set newname for datafile  3 to  "/u03/app/oracle/oradata/duptest/undotbs01.dbf";   
set newname for datafile  4 to  "/u03/app/oracle/oradata/duptest/users01.dbf";   
set newname for datafile  5 to  "/u03/app/oracle/oradata/duptest/flashback_data01.dbf";   
set newname for datafile  6 to  "/u03/app/oracle/oradata/duptest/ts201.dbf";   
set newname for datafile  7 to  "/u03/app/oracle/oradata/duptest/ts301.dbf";   
set newname for datafile  8 to  "/u03/app/oracle/oradata/duptest/ts401.dbf";   
backup as copy reuse   
datafile  1 auxiliary format  "/u03/app/oracle/oradata/duptest/system01.dbf"   
datafile  2 auxiliary format  "/u03/app/oracle/oradata/duptest/sysaux01.dbf"   
datafile  3 auxiliary format  "/u03/app/oracle/oradata/duptest/undotbs01.dbf"   
datafile  4 auxiliary format  "/u03/app/oracle/oradata/duptest/users01.dbf"   
datafile  5 auxiliary format  "/u03/app/oracle/oradata/duptest/flashback_data01.dbf"   
datafile  6 auxiliary format  "/u03/app/oracle/oradata/duptest/ts201.dbf" 
datafile  7 auxiliary format  "/u03/app/oracle/oradata/duptest/ts301.dbf" 
datafile  8 auxiliary format  "/u03/app/oracle/oradata/duptest/ts401.dbf"   ;   
sql 'alter system archive log current';}
executing Memory Script

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

executing command: SET NEWNAME

Starting backup at 14-JAN-11using channel ORA_DISK_1channel ORA_DISK_1: starting datafile copyinput datafile file number=00003 name=/u03/app/oracle/oradata/nf/undotbs01.dbfoutput file name=/u03/app/oracle/oradata/duptest/undotbs01.dbf tag=TAG20110114T115711 RECID=0 STAMP=0channel ORA_DISK_1: datafile copy complete, elapsed time: 00:02:28channel ORA_DISK_1: starting datafile copyinput datafile file number=00004 name=/u03/app/oracle/oradata/nf/users01.dbfoutput file name=/u03/app/oracle/oradata/duptest/users01.dbf tag=TAG20110114T115711 RECID=0 STAMP=0channel ORA_DISK_1: datafile copy complete, elapsed time: 00:02:37channel ORA_DISK_1: starting datafile copyinput datafile file number=00001 name=/u03/app/oracle/oradata/nf/system01.dbfoutput file name=/u03/app/oracle/oradata/duptest/system01.dbf tag=TAG20110114T115711 RECID=0 STAMP=0channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:06channel ORA_DISK_1: starting datafile copyinput datafile file number=00002 name=/u03/app/oracle/oradata/nf/sysaux01.dbfoutput file name=/u03/app/oracle/oradata/duptest/sysaux01.dbf tag=TAG20110114T115711 RECID=0 STAMP=0channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:57channel ORA_DISK_1: starting datafile copyinput datafile file number=00006 name=/u03/app/oracle/oradata/nf/ts201.dbfoutput file name=/u03/app/oracle/oradata/duptest/ts201.dbf tag=TAG20110114T115711 RECID=0 STAMP=0channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:26channel ORA_DISK_1: starting datafile copyinput datafile file number=00005 name=/u03/app/oracle/oradata/nf/flashback_data01.dbfoutput file name=/u03/app/oracle/oradata/duptest/flashback_data01.dbf tag=TAG20110114T115711 RECID=0 STAMP=0channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:15channel ORA_DISK_1: starting datafile copyinput datafile file number=00007 name=/u03/app/oracle/oradata/nf/ts301.dbfoutput file name=/u03/app/oracle/oradata/duptest/ts301.dbf tag=TAG20110114T115711 RECID=0 STAMP=0channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07channel ORA_DISK_1: starting datafile copyinput datafile file number=00008 name=/u03/app/oracle/oradata/nf/ts401.dbfoutput file name=/u03/app/oracle/oradata/duptest/ts401.dbf tag=TAG20110114T115711 RECID=0 STAMP=0channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07Finished backup at 14-JAN-11

sql statement: alter system archive log current
sql statement: 
CREATE CONTROLFILE REUSE SET DATABASE "DUPTEST" RESETLOGS ARCHIVELOG   
MAXLOGFILES     16  
MAXLOGMEMBERS      3  
MAXDATAFILES      100  
MAXINSTANCES     8  
MAXLOGHISTORY      292 
LOGFILE  
GROUP  1 ( '/u03/app/oracle/oradata/duptest/redo01.log' ) SIZE 50 M REUSE,
GROUP  2 ( '/u03/app/oracle/oradata/duptest/redo02.log' ) SIZE 50 M REUSE,GROUP  3 ( '/u03/app/oracle/oradata/duptest/redo03.log' ) SIZE 50 M  REUSE
DATAFILE  '/u03/app/oracle/oradata/duptest/system01.dbf' 
CHARACTER SET WE8MSWIN1252

contents of Memory Script:
{   backup as copy reuse   
archivelog like  "/u03/app/oracle/oradata/nf/arch/nf_1_277_635081437.arc" auxiliary format  "/u03/app/oracle/product/db/11.1.0.6/dbs/archnf_1_277_635081437.arc"   ;   
catalog clone archivelog  "/u03/app/oracle/product/db/11.1.0.6/dbs/archnf_1_277_635081437.arc";   
switch clone datafile all;}
executing Memory Script

Starting backup at 14-JAN-11using channel ORA_DISK_1channel ORA_DISK_1: starting archived log copyinput archived log thread=1 sequence=277 RECID=329 STAMP=643982787output file name=/u03/app/oracle/product/db/11.1.0.6/dbs/archnf_1_277_635081437.arc RECID=0 STAMP=0channel ORA_DISK_1: archived log copy complete, elapsed time: 00:00:01Finished backup at 14-JAN-11

cataloged archived logarchived log file name=/u03/app/oracle/product/db/11.1.0.6/dbs/archnf_1_277_635081437.arc RECID=1 STAMP=643982804

datafile 2 switched to datafile copyinput datafile copy RECID=1 STAMP=643982804 file name=/u03/app/oracle/oradata/duptest/sysaux01.dbfdatafile 3 switched to datafile copyinput datafile copy RECID=2 STAMP=643982805 file name=/u03/app/oracle/oradata/duptest/undotbs01.dbfdatafile 4 switched to datafile copyinput datafile copy RECID=3 STAMP=643982805 file name=/u03/app/oracle/oradata/duptest/users01.dbfdatafile 5 switched to datafile copyinput datafile copy RECID=4 STAMP=643982805 file name=/u03/app/oracle/oradata/duptest/flashback_data01.dbfdatafile 6 switched to datafile copyinput datafile copy RECID=5 STAMP=643982805 file name=/u03/app/oracle/oradata/duptest/ts201.dbfdatafile 7 switched to datafile copyinput datafile copy RECID=6 STAMP=643982805 file name=/u03/app/oracle/oradata/duptest/ts301.dbfdatafile 8 switched to datafile copyinput datafile copy RECID=7 STAMP=643982805 file name=/u03/app/oracle/oradata/duptest/ts401.dbf

contents of Memory Script:
{   set until scn  3167561;   
recover   clone database    
delete archivelog   ;}

executing Memory Script

executing command: SET until clause

Starting recover at 14-JAN-11allocated channel: ORA_AUX_DISK_1channel ORA_AUX_DISK_1: SID=151 device type=DISK

starting media recovery

archived log for thread 1 with sequence 277 is already on disk as file /u03/app/oracle/product/db/11.1.0.6/dbs/archnf_1_277_635081437.arcarchived log file name=/u03/app/oracle/product/db/11.1.0.6/dbs/archnf_1_277_635081437.arc thread=1 sequence=277media recovery complete, elapsed time: 00:00:03Finished recover at 14-JAN-11

contents of Memory Script:
{   shutdown clone immediate;   
startup clone nomount ;}

executing Memory Script

database dismounted
Oracle instance shut down

connected to auxiliary database (not started)Oracle instance started

Total System Global Area     422670336 bytes

Fixed Size                     1300352 bytesVariable Size                406849664 bytesDatabase Buffers               8388608 bytesRedo Buffers                   6131712 bytessql statement: 

CREATE CONTROLFILE REUSE SET DATABASE "DUPTEST" RESETLOGS ARCHIVELOG   MAXLOGFILES     16  MAXLOGMEMBERS      3  MAXDATAFILES      100  MAXINSTANCES     8  MAXLOGHISTORY      292 LOGFILE  GROUP  1 ( '/u03/app/oracle/oradata/duptest/redo01.log' ) SIZE 50 M  REUSE,  GROUP  2 ( '/u03/app/oracle/oradata/duptest/redo02.log' ) SIZE 50 M  REUSE,  GROUP  3 ( '/u03/app/oracle/oradata/duptest/redo03.log' ) SIZE 50 M  REUSE DATAFILE  '/u03/app/oracle/oradata/duptest/system01.dbf' CHARACTER SET WE8MSWIN1252

contents of Memory Script:
{   set newname for tempfile  1 to  "/u03/app/oracle/oradata/duptest/temp01.dbf";   
switch clone tempfile all;   
catalog clone datafilecopy "/u03/app/oracle/oradata/duptest/sysaux01.dbf";catalog clone datafilecopy "/u03/app/oracle/oradata/duptest/undotbs01.dbf";   
catalog clone datafilecopy  "/u03/app/oracle/oradata/duptest/users01.dbf";
catalog clone datafilecopy  "/u03/app/oracle/oradata/duptest/flashback_data01.dbf";   
catalog clone datafilecopy  "/u03/app/oracle/oradata/duptest/ts201.dbf"
catalog clone datafilecopy  "/u03/app/oracle/oradata/duptest/ts301.dbf";
catalog clone datafilecopy  "/u03/app/oracle/oradata/duptest/ts401.dbf";
switch clone datafile all;}

executing Memory Script

executing command: SET NEWNAME

renamed tempfile 1 to /u03/app/oracle/oradata/duptest/temp01.dbf in control file

cataloged datafile copydatafile copy file name=/u03/app/oracle/oradata/duptest/sysaux01.dbf RECID=1 STAMP=643982828

cataloged datafile copydatafile copy file name=/u03/app/oracle/oradata/duptest/undotbs01.dbf RECID=2 STAMP=643982829

cataloged datafile copydatafile copy file name=/u03/app/oracle/oradata/duptest/users01.dbf RECID=3 STAMP=643982829

cataloged datafile copydatafile copy file name=/u03/app/oracle/oradata/duptest/flashback_data01.dbf RECID=4 STAMP=643982829

cataloged datafile copydatafile copy file name=/u03/app/oracle/oradata/duptest/ts201.dbf RECID=5 STAMP=643982829

cataloged datafile copydatafile copy file name=/u03/app/oracle/oradata/duptest/ts301.dbf RECID=6 STAMP=643982829

cataloged datafile copydatafile copy file name=/u03/app/oracle/oradata/duptest/ts401.dbf RECID=7 STAMP=643982829

datafile 2 switched to datafile copyinput datafile copy RECID=1 STAMP=643982828 file name=/u03/app/oracle/oradata/duptest/sysaux01.dbfdatafile 3 switched to datafile copyinput datafile copy RECID=2 STAMP=643982829 file name=/u03/app/oracle/oradata/duptest/undotbs01.dbfdatafile 4 switched to datafile copyinput datafile copy RECID=3 STAMP=643982829 file name=/u03/app/oracle/oradata/duptest/users01.dbfdatafile 5 switched to datafile copyinput datafile copy RECID=4 STAMP=643982829 file name=/u03/app/oracle/oradata/duptest/flashback_data01.dbfdatafile 6 switched to datafile copyinput datafile copy RECID=5 STAMP=643982829 file name=/u03/app/oracle/oradata/duptest/ts201.dbfdatafile 7 switched to datafile copyinput datafile copy RECID=6 STAMP=643982829 file name=/u03/app/oracle/oradata/duptest/ts301.dbfdatafile 8 switched to datafile copyinput datafile copy RECID=7 STAMP=643982829 file name=/u03/app/oracle/oradata/duptest/ts401.dbf

contents of Memory Script:
{   Alter clone database open resetlogs;}

executing Memory Script

database openedFinished Duplicate Db at 14-JAN-11