Thursday 26 July 2012

Duplicating Database without connecting to Target Database or Catalog Database in Oracle 11g


In Oracle 10g version or earlier, while duplicating a database using RMAN, we had to connect to the Target database along with the Auxiliary Database. In oracle 11g, there is a new feature available, where in the duplication from the Target Database to the Auxiliary Database can be done using RMAN without connecting to the Target database or to the Catalog Database. Only thing what is required the full backup of the Target database. Below is the details on how to go ahead with duplicating the database without connecting to the Target Database or to the Auxiliary Database.
Target Database : myprim
Target Database Server : dev
Auxiliary Database : testdb
Auxiliary Database Server : uat
Step 1:
Take the incremental level 0 backup of the Target database using RMAN.
In my case, I had the backup of my target database (myprim) taken at the location “/u02/bkp”
[oracle@dev bkp]$ pwd
/u02/bkp
[oracle@dev bkp]$ ls -lrt
total 1076968
-rw-r–r– 1 oracle oinstall        75 Apr 14 21:59 dbid.txt
-rw-r—– 1 oracle oinstall  53648384 Apr 25 10:04 MYPRIM_inc0_06n9a795_1_1.bak
-rw-r—– 1 oracle oinstall 984506368 Apr 25 10:06 MYPRIM_inc0_07n9a79l_1_1.bak
-rw-r—– 1 oracle oinstall   9830400 Apr 25 10:06 MYPRIM_inc0_08n9a7cb_1_1.bak
-rw-r—– 1 oracle oinstall     37376 Apr 25 10:06 MYPRIM_inc0_09n9a7cg_1_1.bak
-rw-r—– 1 oracle oinstall  53684224 Apr 25 10:06 MYPRIM_inc0_0an9a7ci_1_1.bak
Step 2:
Copy these backup pieces from the Target server (location /u02/bkp) to the auxiliary server (location /u03/backup)
Also, copy the pfile (initmyprim.ora) of the Target database to the Auxiliary server.
Copying Backup Pieces:
[oracle@dev bkp]$ scp *.bak uat:/u03/backup
oracle@uat’s password:
MYPRIM_inc0_06n9a795_1_1.bak                  100%   51MB   3.4MB/s   00:15  
MYPRIM_inc0_07n9a79l_1_1.bak                  100%  939MB   1.8MB/s   08:29  
MYPRIM_inc0_08n9a7cb_1_1.bak                  100% 9600KB   4.7MB/s   00:02  
MYPRIM_inc0_09n9a7cg_1_1.bak                  100%   37KB  36.5KB/s   00:00  
MYPRIM_inc0_0an9a7ci_1_1.bak                  100%   51MB   5.1MB/s   00:10  
[oracle@dev bkp]$
Copying pfile of Target Database to Auxiliary Server:
[oracle@dev dbs]$ scp initmyprim.ora uat:/u01/app/oracle/product/11.2.0/dbhome_1/dbs/
oracle@uat’s password:
initmyprim.ora                                100%  921     0.9KB/s   00:01  
[oracle@dev dbs]$
Step 3:
On the Auxiliary server, edit the pfile that was copied earlier to the desired entries (dump locations, control file location, datafile locations, if using ASM then specify the desired disk group) and rename it to the desired instance name file (init.ora). Below is the sample I had it done.
inittestdb.ora
testdb.__db_cache_size=297795584
testdb.__java_pool_size=4194304
testdb.__large_pool_size=4194304
testdb.__oracle_base=’/u01/app/oracle’#ORACLE_BASE set from environment
testdb.__pga_aggregate_target=167772160
testdb.__sga_target=494927872
testdb.__shared_io_pool_size=0
testdb.__shared_pool_size=176160768
testdb.__streams_pool_size=4194304
*.audit_file_dest=‘/u01/app/oracle/admin/testdb/adump’
# *.audit_trail=’db’
*.compatible=’11.2.0.0.0′
*.control_files=’+DATA’
*.db_block_size=8192
*.db_create_file_dest=’+DATA’
*.db_domain=”
*.db_name=’testdb’
*.db_recovery_file_dest=’+ARCH’
*.db_recovery_file_dest_size=1073741824
*.diagnostic_dest=’/u01/app/oracle’
*.dispatchers=’(PROTOCOL=TCP) (SERVICE=testdbXDB)’
*.log_archive_format=’%t_%s_%r.dbf’
*.open_cursors=300
*.pga_aggregate_target=164626432
*.processes=150
*.remote_login_passwordfile=’EXCLUSIVE’
*.sga_target=494927872
*.undo_tablespace=’UNDOTBS1′
Step 4:
Create a password file for the Auxiliary Database using the ORAPWD utility.
orapwd file=/u01/app/oracle/product/11.2.0/dbhome_1/dbs/orapwtestdb password=
Step 5:
Start the auxiliary instance using the modified by pfile.
[oracle@uat ~]$ export ORACLE_HOME=/u01/app/oracle/product/11.2.0/dbhome_1
[oracle@uat ~]$ export ORACLE_SID=testdb
[oracle@uat ~]$ sqlplus sys/oracle as sysdba
SQL*Plus: Release 11.2.0.1.0 Production on Wed Apr 25 10:46:24 2012
Copyright (c) 1982, 2009, Oracle.  All rights reserved.
Connected to an idle instance.
SQL> startup nomount pfile=/u01/app/oracle/product/11.2.0/dbhome_1/dbs/inittestdb.ora
ORACLE instance started.
Total System Global Area  492707840 bytes
Fixed Size                  2214656 bytes
Variable Size             188744960 bytes
Database Buffers          297795584 bytes
Redo Buffers                3952640 bytes
SQL>
Step 6:
Connect the auxiliary instance through RMAN and start the duplication.
The duplication is done by specifying the location of the backup pieces. The command to be used is DUPLICATE DATABASE TO ‘’ BACKUP LOCATION ‘
[oracle@uat ~]$ rman auxiliary /
Recovery Manager: Release 11.2.0.1.0 – Production on Wed Apr 25 10:48:36 2012
Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.
connected to auxiliary database: TESTDB (not mounted)
RMAN> duplicate database to ‘testdb’ backup location ‘/u03/backup’;
Starting Duplicate Db at 26-APR-12
contents of Memory Script:
{
   sql clone “create spfile from memory”;
}
executing Memory Script
sql statement: create spfile from memory
contents of Memory Script:
{
   shutdown clone immediate;
   startup clone nomount;
}
executing Memory Script
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area     492707840 bytes
Fixed Size                     2214656 bytes
Variable Size                155190528 bytes
Database Buffers             331350016 bytes
Redo Buffers                   3952640 bytes
contents of Memory Script:
{
   sql clone “alter system set  control_files =
  ”+DATA/testdb/controlfile/current.293.781612663” comment=
 ”Set by RMAN” scope=spfile”;
   sql clone “alter system set  db_name =
 ”MYPRIM” comment=
 ”Modified by RMAN duplicate” scope=spfile”;
   sql clone “alter system set  db_unique_name =
 ”TESTDB” comment=
 ”Modified by RMAN duplicate” scope=spfile”;
   shutdown clone immediate;
   startup clone force nomount
   restore clone primary controlfile from  ‘/u03/backup/MYPRIM_inc0_08n9a7cb_1_1.bak’;
   alter clone database mount;
}
executing Memory Script
sql statement: alter system set  control_files =   ”+DATA/testdb/controlfile/current.293.781612663” comment= ”Set by RMAN” scope=spfile
sql statement: alter system set  db_name =  ”MYPRIM” comment= ”Modified by RMAN duplicate” scope=spfile
sql statement: alter system set  db_unique_name =  ”TESTDB” comment= ”Modified by RMAN duplicate” scope=spfile
Oracle instance shut down
Oracle instance started
Total System Global Area     492707840 bytes
Fixed Size                     2214656 bytes
Variable Size                155190528 bytes
Database Buffers             331350016 bytes
Redo Buffers                   3952640 bytes
Starting restore at 26-APR-12
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=23 device type=DISK
channel ORA_AUX_DISK_1: restoring control file
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:09
output file name=+DATA/testdb/controlfile/current.293.781612663
Finished restore at 26-APR-12
database mounted
released channel: ORA_AUX_DISK_1
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=23 device type=DISK
contents of Memory Script:
{
   set until scn  1015172;
   set newname for clone datafile  1 to new;
   set newname for clone datafile  2 to new;
   set newname for clone datafile  3 to new;
   set newname for clone datafile  4 to new;
   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 26-APR-12
using channel ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: starting datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_AUX_DISK_1: restoring datafile 00001 to +DATA
channel ORA_AUX_DISK_1: restoring datafile 00002 to +DATA
channel ORA_AUX_DISK_1: restoring datafile 00003 to +DATA
channel ORA_AUX_DISK_1: restoring datafile 00004 to +DATA
channel ORA_AUX_DISK_1: reading from backup piece /u03/backup/MYPRIM_inc0_07n9a79l_1_1.bak
channel ORA_AUX_DISK_1: piece handle=/u03/backup/MYPRIM_inc0_07n9a79l_1_1.bak tag=TAG20120425T100437
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:02:17
Finished restore at 26-APR-12
contents of Memory Script:
{
   switch clone datafile all;
}
executing Memory Script
datafile 1 switched to datafile copy
input datafile copy RECID=5 STAMP=781612862 file name=+DATA/testdb/datafile/system.292.781612727
datafile 2 switched to datafile copy
input datafile copy RECID=6 STAMP=781612862 file name=+DATA/testdb/datafile/sysaux.291.781612729
datafile 3 switched to datafile copy
input datafile copy RECID=7 STAMP=781612862 file name=+DATA/testdb/datafile/undotbs1.290.781612731
datafile 4 switched to datafile copy
input datafile copy RECID=8 STAMP=781612862 file name=+DATA/testdb/datafile/users.289.781612731
contents of Memory Script:
{
   set until scn  1015172;
   recover
   clone database
    delete archivelog
   ;
}
executing Memory Script
executing command: SET until clause
Starting recover at 26-APR-12
using channel ORA_AUX_DISK_1
starting media recovery
channel ORA_AUX_DISK_1: starting archived log restore to default destination
channel ORA_AUX_DISK_1: restoring archived log
archived log thread=1 sequence=10
channel ORA_AUX_DISK_1: restoring archived log
archived log thread=1 sequence=11
channel ORA_AUX_DISK_1: reading from backup piece /u03/backup/MYPRIM_inc0_0an9a7ci_1_1.bak
channel ORA_AUX_DISK_1: piece handle=/u03/backup/MYPRIM_inc0_0an9a7ci_1_1.bak tag=TAG20120425T100610
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
archived log file name=+ARCH/testdb/archivelog/2012_04_26/thread_1_seq_10.1075.781612867 thread=1 sequence=10
channel clone_default: deleting archived log(s)
archived log file name=+ARCH/testdb/archivelog/2012_04_26/thread_1_seq_10.1075.781612867 RECID=1 STAMP=781612868
archived log file name=+ARCH/testdb/archivelog/2012_04_26/thread_1_seq_11.1076.781612869 thread=1 sequence=11
channel clone_default: deleting archived log(s)
archived log file name=+ARCH/testdb/archivelog/2012_04_26/thread_1_seq_11.1076.781612869 RECID=2 STAMP=781612868
media recovery complete, elapsed time: 00:00:03
Finished recover at 26-APR-12
contents of Memory Script:
{
   shutdown clone immediate;
   startup clone nomount;
   sql clone “alter system set  db_name =
 ”TESTDB” 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
database dismounted
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area     492707840 bytes
Fixed Size                     2214656 bytes
Variable Size                155190528 bytes
Database Buffers             331350016 bytes
Redo Buffers                   3952640 bytes
sql statement: alter system set  db_name =  ”TESTDB” 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     492707840 bytes
Fixed Size                     2214656 bytes
Variable Size                155190528 bytes
Database Buffers             331350016 bytes
Redo Buffers                   3952640 bytes
sql statement: CREATE CONTROLFILE REUSE SET DATABASE “TESTDB” RESETLOGS ARCHIVELOG
  MAXLOGFILES     16
  MAXLOGMEMBERS      3
  MAXDATAFILES      100
  MAXINSTANCES     8
  MAXLOGHISTORY      292
 LOGFILE
  GROUP  1  SIZE 50 M ,
  GROUP  2  SIZE 50 M ,
  GROUP  3  SIZE 50 M
 DATAFILE
  ‘+DATA/testdb/datafile/system.292.781612727′
 CHARACTER SET WE8MSWIN1252
contents of Memory Script:
{
   set newname for clone tempfile  1 to new;
   switch clone tempfile all;
   catalog clone datafilecopy  “+DATA/testdb/datafile/sysaux.291.781612729″,
 ”+DATA/testdb/datafile/undotbs1.290.781612731″,
 ”+DATA/testdb/datafile/users.289.781612731″;
   switch clone datafile all;
}
executing Memory Script
executing command: SET NEWNAME
renamed tempfile 1 to +DATA in control file
cataloged datafile copy
datafile copy file name=+DATA/testdb/datafile/sysaux.291.781612729 RECID=1 STAMP=781612964
cataloged datafile copy
datafile copy file name=+DATA/testdb/datafile/undotbs1.290.781612731 RECID=2 STAMP=781612964
cataloged datafile copy
datafile copy file name=+DATA/testdb/datafile/users.289.781612731 RECID=3 STAMP=781612964
datafile 2 switched to datafile copy
input datafile copy RECID=1 STAMP=781612964 file name=+DATA/testdb/datafile/sysaux.291.781612729
datafile 3 switched to datafile copy
input datafile copy RECID=2 STAMP=781612964 file name=+DATA/testdb/datafile/undotbs1.290.781612731
datafile 4 switched to datafile copy
input datafile copy RECID=3 STAMP=781612964 file name=+DATA/testdb/datafile/users.289.781612731
contents of Memory Script:
{
   Alter clone database open resetlogs;
}
executing Memory Script
database opened
Finished Duplicate Db at 26-APR-12
RMAN>
Step 7:
Connect to the newly created database.
[oracle@uat ~]$ sqlplus / as sysdba
SQL*Plus: Release 11.2.0.1.0 Production on Thu Apr 26 10:44:36 2012
Copyright (c) 1982, 2009, Oracle.  All rights reserved.
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 – 64bit Production
With the Partitioning, Automatic Storage Management, OLAP, Data Mining
and Real Application Testing options
SQL> select status,instance_name from v$instance;
STATUS       INSTANCE_NAME
———— —————-
OPEN         testdb
SQL> select name from v$database;
NAME
———
TESTDB

Job Done!!