Clone/Refresh Oracle Database using RMAN DUPLICATE without Recovery Catalog or Target DB
From 11gR2 onwards, it is possible to duplicate the Oracle
Database without using Recovery Catalog. To achieve the same, I am using 2
different databases named as “ORADB112” and “ORADB113”. ORADB112 is the TARGET
database and ORADB113 is the DUPLICATED database. Though I am duplicating the
database on the same server but the same article can help you duplicate the
database on different systems as well. Please follow the below mentioned
guidelines to understand the process:
1) Put the database in archivelog mode (It's not mandatory
but making the example more practical)
SQL> startup mount
ORACLE instance started.
Total System Global Area 3140026368 bytes
Fixed Size 2285344 bytes
Variable Size 1845493984 bytes
Database Buffers 1275068416 bytes
Redo Buffers 17178624 bytes
Database mounted.
SQL> alter database archivelog;
Database altered.
SQL> alter database open;
Database altered.
SQL> archive log list;
Database log mode Archive Mode
Automatic archival Enabled
Archive destination USE_DB_RECOVERY_FILE_DEST
Oldest online log sequence 177
Next log sequence to archive 179
Current log sequence 179
2) Enabling the Recovery Location (FRA) by providing proper
path and size.
SQL> alter system set db_recovery_file_dest_size=5G scope=both;
System altered.
SQL> alter system set db_recovery_file_dest='F:\Database\FRA' scope=both;
System altered.
SQL> show parameter recovery
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
db_recovery_file_dest string F:\Database\FRA
db_recovery_file_dest_size big integer 5G
recovery_parallelism integer 0
3) Create random tablespace, user and make some enteries
(Not necessary, just time pass)
SQL> create tablespace TAB_1 datafile 'F:\DATABASE\ORADB112\TAB_1_01.DBF' size 10M autoextend on;
Tablespace created.
SQL> select tablespace_name from dba_tablespaces;
TABLESPACE_NAME
------------------------------
SYSTEM
SYSAUX
UNDOTBS1
TEMP
USERS
TAB_1
6 rows selected.
SQL> select name from V$datafile;
NAME
----------------------------------------------
F:\DATABASE\ORADB112\SYSTEM01.DBF
F:\DATABASE\ORADB112\SYSAUX01.DBF
F:\DATABASE\ORADB112\UNDOTBS01.DBF
F:\DATABASE\ORADB112\USERS01.DBF
F:\DATABASE\ORADB112\TAB_1_01.DBF
SQL>
SQL> create user TOM identified by tom123;
SQL> grant create session, resource, create table to TOM;
SQL> alter user TOM default tablespace TAB_1 quota unlimited on TAB_1;
SQL> conn tom/tom123@oradb112
Connected.
SQL>
SQL> create table t1 (id number, name varchar2(20), gender char(2));
insert into t1 values (1, 'ABC', 'M');
insert into t1 values (2, 'DEF', 'M');
insert into t1 values (2, 'GHI', 'F');
insert into t1 values (3, 'JKL', 'M');
insert into t1 values (4, 'MNO', 'F');
insert into t1 values (5, 'PQR', 'M');
insert into t1 values (6, 'STU', 'F');
insert into t1 values (7, 'VWXYZ', 'F');
SQL> select * from t1;
ID NAME GE
---------- -------------------- --
1 ABC M
2 DEF M
2 GHI F
3 JKL M
4 MNO F
5 PQR M
6 STU F
7 VWXYZ F
8 rows selected.
4) Connect to RMAN and take the database, archivelog,
controlfile and SPFile backup.
C:\Users\parain>rman target /
Recovery Manager: Release 11.2.0.4.0 - Production on Thu May 17 19:35:36 2018
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
connected to target database: ORADB112 (DBID=1219145645)
RMAN> CONFIGURE CONTROLFILE AUTOBACKUP ON;
new RMAN configuration parameters:
CONFIGURE CONTROLFILE AUTOBACKUP ON;
new RMAN configuration parameters are successfully stored
RMAN>
RMAN> run {
2> backup format 'F:\Database\Backups\%U' database;
3> backup format 'F:\Database\Backups\%U' archivelog all;
4> }
Starting backup at 17-MAY-18
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=68 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=00001 name=F:\DATABASE\ORADB112\SYSTEM01.DBF
input datafile file number=00002 name=F:\DATABASE\ORADB112\SYSAUX01.DBF
input datafile file number=00003 name=F:\DATABASE\ORADB112\UNDOTBS01.DBF
input datafile file number=00005 name=F:\DATABASE\ORADB112\TAB_1_01.DBF
input datafile file number=00004 name=F:\DATABASE\ORADB112\USERS01.DBF
channel ORA_DISK_1: starting piece 1 at 17-MAY-18
channel ORA_DISK_1: finished piece 1 at 17-MAY-18
piece handle=F:\DATABASE\BACKUPS\01T352F4_1_1 tag=TAG20180517T193707 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:45
Finished backup at 17-MAY-18
Starting backup at 17-MAY-18
current log archived
using channel ORA_DISK_1
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=179 RECID=1 STAMP=976390346
input archived log thread=1 sequence=180 RECID=2 STAMP=976390675
channel ORA_DISK_1: starting piece 1 at 17-MAY-18
channel ORA_DISK_1: finished piece 1 at 17-MAY-18
piece handle=F:\DATABASE\BACKUPS\02T352GJ_1_1 tag=TAG20180517T193755 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:03
Finished backup at 17-MAY-18
Starting Control File and SPFILE Autobackup at 17-MAY-18
piece handle=F:\DATABASE\FRA\ORADB112\AUTOBACKUP\2018_05_17\O1_MF_S_976390678_FHV35ZSQ_.BKP comment=NONE
Finished Control File and SPFILE Autobackup at 17-MAY-18
6) Create a password file for the Auxiliary Instance (the
new database which you are going to create using the backups). For this, just
copy the password file of the TARGET database from
$ORACLE_HOME/dbs (On linux/Unix) OR
$ORACLE_HOME/database (On Windows)
7) Copy the same to the server where you are going to create
the database and rename it as per the new database. Like in my case, I changed
the name of the password file from "SPFILEORADB112.ORA" to
"SPFILEORADB113.ORA".
8) Create a parameter file to start the Auxiliary instance for
your new database. Define just one parameter DB_NAME inside it.
Note:- You can start the instance of your Oracle database by using
only one parameter i.e. DB_NAME.
DB_NAME=oradb113
9) Create the Oracle Service for the new database with the
below mentioned command,
oradim -new -sid oradb113 -intpwd sys
10) Start the database using your new parameter file to NOMOUNT state and connect RMAN with the auxiliary instance.
C:\Users\parain>sqlplus / as sysdba
SQL*Plus: Release 11.2.0.4.0 Production on Thu May 17 22:47:58 2018
Copyright (c) 1982, 2013, Oracle. All rights reserved.
Connected to an idle instance.
SQL> startup nomount pfile=F:\app\parain\product\11.2.0\dbhome_1\database\initoradb113.ora
ORACLE instance started.
Total System Global Area 271437824 bytes
Fixed Size 2280328 bytes
Variable Size 213910648 bytes
Database Buffers 50331648 bytes
Redo Buffers 4915200 bytes
SQL> quit
Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options>
C:\Users\parain>rman auxiliary /
Recovery Manager: Release 11.2.0.4.0 - Production on Thu May 17 22:56:34 2018
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
connected to auxiliary database: ORADB113 (not mounted)
RMAN>
11) Create your script for RMAN duplication to create your new
database like the one I have shown below:
run {
DUPLICATE DATABASE TO oradb113
SPFILE
set control_files='F:\Database\oradb113\control01.ctl','F:\Database\oradb113\control02.ctl'
set db_file_name_convert='F:\Database\oradb112','F:\Database\oradb113'
set log_file_name_convert='F:\Database\oradb112','F:\Database\oradb113'
BACKUP LOCATION 'F:\Database\Backups';
}
12) Run the same on RMAN prompt and once the execution of the
same will be done, your new database will be ready. The RMAN automatically
handles the tasks after you run the script like taking database bounce and
starting it up again.
RMAN> run {
2> DUPLICATE DATABASE TO oradb113
3> SPFILE
4> set control_files='F:\Database\oradb113\control01.ctl','F:\Database\oradb113\control02.ctl'
5> set db_file_name_convert='F:\Database\oradb112','F:\Database\oradb113'
6> set log_file_name_convert='F:\Database\oradb112','F:\Database\oradb113'
7> BACKUP LOCATION 'F:\Database\Backups';
8> }
Starting Duplicate Db at 17-MAY-18
contents of Memory Script:
{
restore clone spfile to 'F:\APP\PARAIN\PRODUCT\11.2.0\DBHOME_1\DATABASE\SPFILEORADB113.ORA' from
'F:\DATABASE\Backups\O1_MF_S_976392144_FHV4MS5H_.BKP';
sql clone "alter system set spfile= ''F:\APP\PARAIN\PRODUCT\11.2.0\DBHOME_1\DATABASE\SPFILEORADB113.ORA''";
}
executing Memory Script
Starting restore at 17-MAY-18
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=216 device type=DISK
channel ORA_AUX_DISK_1: restoring spfile from AUTOBACKUP F:\DATABASE\Backups\O1_MF_S_976392144_FHV4MS5H_.BKP
channel ORA_AUX_DISK_1: SPFILE restore from AUTOBACKUP complete
Finished restore at 17-MAY-18
sql statement: alter system set spfile= ''F:\APP\PARAIN\PRODUCT\11.2.0\DBHOME_1\DATABASE\SPFILEORADB113.ORA''
contents of Memory Script:
{
sql clone "alter system set db_name =
''ORADB113'' comment=
''duplicate'' scope=spfile";
sql clone "alter system set control_files =
''F:\Database\oradb113\control01.ctl'', ''F:\Database\oradb113\control02.ctl'' comment=
'''' scope=spfile";
sql clone "alter system set db_file_name_convert =
''F:\Database\oradb112'', ''F:\Database\oradb113'' comment=
'''' scope=spfile";
sql clone "alter system set log_file_name_convert =
''F:\Database\oradb112'', ''F:\Database\oradb113'' comment=
'''' scope=spfile";
shutdown clone immediate;
startup clone nomount;
}
executing Memory Script
sql statement: alter system set db_name = ''ORADB113'' comment= ''duplicate'' scope=spfile
sql statement: alter system set control_files = ''F:\Database\oradb113\control01.ctl'',
''F:\Database\oradb113\control02.ctl''
comment= '''' scope=spfile
sql statement: alter system set db_file_name_convert = ''F:\Database\oradb112'', ''F:\Database\oradb113''
comment= '''' scope=spfile
sql statement: alter system set log_file_name_convert = ''F:\Database\oradb112'', ''F:\Database\oradb113''
comment= '''' scope=spfile
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 3140026368 bytes
Fixed Size 2285344 bytes
Variable Size 1811939552 bytes
Database Buffers 1308622848 bytes
Redo Buffers 17178624 bytes
contents of Memory Script:
{
sql clone "alter system set db_name =
''ORADB112'' comment=
''Modified by RMAN duplicate'' scope=spfile";
sql clone "alter system set db_unique_name =
''ORADB113'' comment=
''Modified by RMAN duplicate'' scope=spfile";
shutdown clone immediate;
startup clone force nomount
restore clone primary controlfile from 'F:\DATABASE\Backups\O1_MF_S_976392144_FHV4MS5H_.BKP';
alter clone database mount;
}
executing Memory Script
sql statement: alter system set db_name = ''ORADB112'' comment= ''Modified by RMAN duplicate'' scope=spfile
sql statement: alter system set db_unique_name = ''ORADB113'' comment= ''Modified by RMAN duplicate'' scope=spfile
Oracle instance shut down
Oracle instance started
Total System Global Area 3140026368 bytes
Fixed Size 2285344 bytes
Variable Size 1811939552 bytes
Database Buffers 1308622848 bytes
Redo Buffers 17178624 bytes
Starting restore at 17-MAY-18
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=156 device type=DISK
channel ORA_AUX_DISK_1: restoring control file
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=F:\DATABASE\ORADB113\CONTROL01.CTL
output file name=F:\DATABASE\ORADB113\CONTROL02.CTL
Finished restore at 17-MAY-18
database mounted
released channel: ORA_AUX_DISK_1
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=156 device type=DISK
contents of Memory Script:
{
set until scn 3336255;
set newname for datafile 1 to
"F:\DATABASE\ORADB113\SYSTEM01.DBF";
set newname for datafile 2 to
"F:\DATABASE\ORADB113\SYSAUX01.DBF";
set newname for datafile 3 to
"F:\DATABASE\ORADB113\UNDOTBS01.DBF";
set newname for datafile 4 to
"F:\DATABASE\ORADB113\USERS01.DBF";
set newname for datafile 5 to
"F:\DATABASE\ORADB113\TAB_1_01.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
executing command: SET NEWNAME
Starting restore at 17-MAY-18
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 F:\DATABASE\ORADB113\SYSTEM01.DBF
channel ORA_AUX_DISK_1: restoring datafile 00002 to F:\DATABASE\ORADB113\SYSAUX01.DBF
channel ORA_AUX_DISK_1: restoring datafile 00003 to F:\DATABASE\ORADB113\UNDOTBS01.DBF
channel ORA_AUX_DISK_1: restoring datafile 00004 to F:\DATABASE\ORADB113\USERS01.DBF
channel ORA_AUX_DISK_1: restoring datafile 00005 to F:\DATABASE\ORADB113\TAB_1_01.DBF
channel ORA_AUX_DISK_1: reading from backup piece F:\DATABASE\BACKUPS\O1_MF_NNNDF_TAG20180517T200134_FHV4L6RH_.BKP
channel ORA_AUX_DISK_1: piece handle=F:\DATABASE\BACKUPS\O1_MF_NNNDF_TAG20180517T200134_FHV4L6RH_.BKP
tag=TAG20180517T200134
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:35
Finished restore at 17-MAY-18
contents of Memory Script:
{
switch clone datafile all;
}
executing Memory Script
datafile 1 switched to datafile copy
input datafile copy RECID=6 STAMP=976393556 file name=F:\DATABASE\ORADB113\SYSTEM01.DBF
datafile 2 switched to datafile copy
input datafile copy RECID=7 STAMP=976393556 file name=F:\DATABASE\ORADB113\SYSAUX01.DBF
datafile 3 switched to datafile copy
input datafile copy RECID=8 STAMP=976393556 file name=F:\DATABASE\ORADB113\UNDOTBS01.DBF
datafile 4 switched to datafile copy
input datafile copy RECID=9 STAMP=976393556 file name=F:\DATABASE\ORADB113\USERS01.DBF
datafile 5 switched to datafile copy
input datafile copy RECID=10 STAMP=976393557 file name=F:\DATABASE\ORADB113\TAB_1_01.DBF
contents of Memory Script:
{
set until scn 3336255;
recover
clone database
delete archivelog
;
}
executing Memory Script
executing command: SET until clause
Starting recover at 17-MAY-18
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=182
channel ORA_AUX_DISK_1: reading from backup piece F:\DATABASE\BACKUPS\09T353UF_1_1
channel ORA_AUX_DISK_1: piece handle=F:\DATABASE\BACKUPS\09T353UF_1_1 tag=TAG20180517T200222
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:02
archived log file name=F:\DATABASE\FRA\ORADB113\ARCHIVELOG\2018_05_17\O1_MF_1_182_FHV5ZZ2S_.ARC thread=1 sequence=182
channel clone_default: deleting archived log(s)
archived log file name=F:\DATABASE\FRA\ORADB113\ARCHIVELOG\2018_05_17\O1_MF_1_182_FHV5ZZ2S_.ARC RECID=1 STAMP=976393559
media recovery complete, elapsed time: 00:00:02
Finished recover at 17-MAY-18
Oracle instance started
Total System Global Area 3140026368 bytes
Fixed Size 2285344 bytes
Variable Size 1811939552 bytes
Database Buffers 1308622848 bytes
Redo Buffers 17178624 bytes
contents of Memory Script:
{
sql clone "alter system set db_name =
''ORADB113'' 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 = ''ORADB113'' 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 3140026368 bytes
Fixed Size 2285344 bytes
Variable Size 1811939552 bytes
Database Buffers 1308622848 bytes
Redo Buffers 17178624 bytes
sql statement: CREATE CONTROLFILE REUSE SET DATABASE "ORADB113" RESETLOGS ARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 100
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 ( 'F:\DATABASE\ORADB113\REDO01.LOG' ) SIZE 50 M REUSE,
GROUP 2 ( 'F:\DATABASE\ORADB113\REDO02.LOG' ) SIZE 50 M REUSE,
GROUP 3 ( 'F:\DATABASE\ORADB113\REDO03.LOG' ) SIZE 50 M REUSE
DATAFILE
'F:\DATABASE\ORADB113\SYSTEM01.DBF'
CHARACTER SET WE8MSWIN1252
contents of Memory Script:
{
set newname for tempfile 1 to
"F:\DATABASE\ORADB113\TEMP01.DBF";
switch clone tempfile all;
catalog clone datafilecopy "F:\DATABASE\ORADB113\SYSAUX01.DBF",
"F:\DATABASE\ORADB113\UNDOTBS01.DBF",
"F:\DATABASE\ORADB113\USERS01.DBF",
"F:\DATABASE\ORADB113\TAB_1_01.DBF";
switch clone datafile all;
}
executing Memory Script
executing command: SET NEWNAME
renamed tempfile 1 to F:\DATABASE\ORADB113\TEMP01.DBF in control file
cataloged datafile copy
datafile copy file name=F:\DATABASE\ORADB113\SYSAUX01.DBF RECID=1 STAMP=976393619
cataloged datafile copy
datafile copy file name=F:\DATABASE\ORADB113\UNDOTBS01.DBF RECID=2 STAMP=976393619
cataloged datafile copy
datafile copy file name=F:\DATABASE\ORADB113\USERS01.DBF RECID=3 STAMP=976393619
cataloged datafile copy
datafile copy file name=F:\DATABASE\ORADB113\TAB_1_01.DBF RECID=4 STAMP=976393619
datafile 2 switched to datafile copy
input datafile copy RECID=1 STAMP=976393619 file name=F:\DATABASE\ORADB113\SYSAUX01.DBF
datafile 3 switched to datafile copy
input datafile copy RECID=2 STAMP=976393619 file name=F:\DATABASE\ORADB113\UNDOTBS01.DBF
datafile 4 switched to datafile copy
input datafile copy RECID=3 STAMP=976393619 file name=F:\DATABASE\ORADB113\USERS01.DBF
datafile 5 switched to datafile copy
input datafile copy RECID=4 STAMP=976393619 file name=F:\DATABASE\ORADB113\TAB_1_01.DBF
contents of Memory Script:
{
Alter clone database open resetlogs;
}
executing Memory Script
database opened
Finished Duplicate Db at 17-MAY-18
13) Once done, you can check if you can verify your newly
created database by logging into it.
C:\Users\parain>sqlplus / as sysdba
SQL*Plus: Release 11.2.0.4.0 Production on Thu May 17 20:28:21 2018
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
SQL> select name, open_mode from V$database;
NAME OPEN_MODE
--------- --------------------
ORADB113 READ WRITE
SQL> show parameter spfile;
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
spfile string F:\APP\PARAIN\PRODUCT\11.2.0\D
BHOME_1\DATABASE\SPFILEORADB11
3.ORA
I hope this helps !!
No comments:
Post a Comment