Saturday, July 25, 2009

Cloning an Oracle 10g Database Using RMAN in an ASM Environment

Dear Friends,
Using RMAN I have cloned an Oracle 10g ASM Database successfully. I would like to share the steps that I followed during this process.
For understanding, Suppose that the actual database name is ASMDB and I am going to clone database with a different name like CLNDB.
*If the platform is Windows Operating System then first create a new Oracle Service Instance for clone Database (clndb).

C:\> oradim -new -sid clndb
Instance created
.

*Create Password file for clone database for remote logging purpose
D:\oracle\product\10.2.0\db_1\database>orapwd file=pwdCLNDB.ora password=xxxxxxx
(If the Operating System is Linux then the location for creating password file is /u01/oracle/product/10.2.0/db_1/dbs )

*After creating Oracle Service Instance and Password file you need to configure an Initialization parameter file for cloning database
For this you just copy Initialization parameter file of Actual database and configure accordingly or create an initialization parameter file with similar setting.
d:\oracle\product\10.2.0\db_1\database>copy initASMDB.ora initCLNDB.ora
1 file(s) copied.
d:\oracle\product\10.2.0\db_1\database>notepad initCLNDB.ora

*Create directory for destination files ADUMP, BDUMP , CDUMP ,UDUMP.
d:\oracle\product\10.2.0\db_1\admin>mkdir CLNDB
d:\oracle\product\10.2.0\db_1\admin>cd CLNDB
d:\oracle\product\10.2.0\db_1\admin\CLNDB>mkdir ADUMP BDUMP CDUMP UDUMP

*Configure clone database entries in Listener.ora file which locates in ORACLE_HOME/network/admin/listener.ora
d:\oracle\product\10.2.0\db_1\network\ADMIN>notepad listener.ora

*Configure tnsnames entry on clone database side.
d:\oracle\product\10.2.0\db_1\network\ADMIN>notepad tnsnames.ora

*Check both side for whether the network connection established successfully..
d:\oracle\product\10.2.0\db_1\network\ADMIN>LSNRCTL RELOAD
LSNRCTL for 32-bit Windows: Version 10.2.0.3.0 - Production on 10-JUL-2009 18:44:41
Copyright (c) 1991, 2006, Oracle. All rights reserved.
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=alinmabank-PC)(PORT=1521)))
The command completed successfully
d:\oracle\product\10.2.0\db_1\network\ADMIN>LSNRCTL STATUS
LSNRCTL for 32-bit Windows: Version 10.2.0.3.0 - Production on 10-JUL-2009 18:44:49
Copyright (c) 1991, 2006, Oracle. All rights reserved.
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=alinmabank-PC)(PORT=1521)))
STATUS of the LISTENER
------------------------
Alias LISTENER
Version TNSLSNR for 32-bit Windows: Version 10.2.0.3.0 - Production
Start Date 10-JUL-2009 18:20:07
Uptime 0 days 0 hr. 24 min. 42 sec
Trace Level off
Security ON: Local OS Authentication
SNMP OFF
Listener Parameter File d:\oracle\product\10.2.0\db_1\network\admin\listener.ora
Listener Log File d:\oracle\product\10.2.0\db_1\network\log\listener.log
Listening Endpoints Summary...
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=alinmabank-PC)(PORT=1521)))
Services Summary...
Service "ASMDB" has 1 instance(s).
Instance "ASMDB", status UNKNOWN, has 1 handler(s) for this service...
Service "CLNDB" has 1 instance(s).
Instance "CLNDB", status UNKNOWN, has 1 handler(s) for this service...
The command completed successfully

*Now it’s the time to go with RMAN for cloning the database.
Start the oracle service for Actual database.
d:\oracle\product\10.2.0\admin\CLNDB>net start oracleserviceasmdb
The OracleServiceASMDB service is starting.........
The OracleServiceASMDB service was started successfully.

*Set oracle_sid=asmdb
d:\oracle\product\10.2.0\admin\CLNDB>set oracle_sid=asmdb

*Connect the target database as well as auxiliary database at a time using RMAN
The Auxiliary database is nothing but the clone database

d:\oracle\product\10.2.0\admin\CLNDB>rman target / auxiliary sys/xxxx@clndb
Recovery Manager: Release 10.2.0.3.0 - Production on Fri Jul 10 18:54:07 2009
Copyright (c) 1982, 2005, Oracle. All rights reserved.
connected to target database: ASMDB (DBID=435026396)
connected to auxiliary database: CLNDB (not mounted)

*Take a complete database level backup of the database. Here I used a different disk group for backup my database , else the backup goes to Flash Recovery Area location (FRA) by default.
RMAN> backup database format '+bkpdisk';
Starting backup at 10-JUL-09
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=132 devtype=DISK
channel ORA_DISK_1: starting full datafile backupset
channel ORA_DISK_1: specifying datafile(s) in backupset
input datafile fno=00001 name=+DATA/asmdb/datafile/system.256.690827499
input datafile fno=00003 name=+DATA/asmdb/datafile/sysaux.257.690827499
input datafile fno=00005 name=+DATA/asmdb/datafile/example.265.690827669
input datafile fno=00002 name=+DATA/asmdb/datafile/undotbs1.258.690827501
input datafile fno=00006 name=+DATA/asmdb/datafile/data01.dbf
input datafile fno=00004 name=+DATA/asmdb/datafile/users.259.690827501
channel ORA_DISK_1: starting piece 1 at 10-JUL-09
channel ORA_DISK_1: finished piece 1 at 10-JUL-09
piece handle=+BKPDISK/asmdb/backupset/2009_07_10/nnndf0_tag20090710t232555_0.265.691889161 tag=TAG20090710T232555 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:01:55
Finished backup at 10-JUL-09
Starting Control File Autobackup at 10-JUL-09
piece handle=+FRA/asmdb/autobackup/2009_07_10/n_691889270.257.691889273 comment=NONE
Finished Control File Autobackup at 10-JUL-09

*Here I have already configured automatic backup of Controlfile which backups up Controlfile as well as Spfile whenever the modification are done in database.
Now use DUPLICATE TARGET DATABASE command to clone the database, It is the only one command that makes everything for cloning.
Obviously it is really important step that should not forget
.
RMAN> duplicate target database to clndb;
Starting Duplicate Db at 10-JUL-09
using target database control file instead of recovery catalog
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: sid=156 devtype=DISK
contents of Memory Script:
{
set until scn 686765;
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;
set newname for clone datafile 5 to new;
set newname for clone datafile 6 to new;
restore
check readonly
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
executing command: SET NEWNAME
Starting restore at 10-JUL-09
using channel ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: starting datafile backupset restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
restoring datafile 00001 to +DATA
restoring datafile 00002 to +DATA
restoring datafile 00003 to +DATA
restoring datafile 00004 to +DATA
restoring datafile 00005 to +DATA
restoring datafile 00006 to +DATA
channel ORA_AUX_DISK_1: reading from backup piece +BKPDISK/asmdb/backupset/2009_07_07/nnndf0_tag20090707t210710_0.264.691621633
channel ORA_AUX_DISK_1: restored backup piece 1
piece handle=+BKPDISK/asmdb/backupset/2009_07_07/nnndf0_tag20090707t210710_0.264.691621633 tag=TAG20090707T210710
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:02:06
Finished restore at 10-JUL-09
sql statement: CREATE CONTROLFILE REUSE SET DATABASE "CLNDB" 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/clndb/datafile/system.275.691890537'
CHARACTER SET WE8MSWIN1252
contents of Memory Script:
{
switch clone datafile all;
}
executing Memory Script
released channel: ORA_AUX_DISK_1
datafile 2 switched to datafile copy
input datafile copy recid=1 stamp=691890658 filename=+DATA/clndb/datafile/undotbs1.283.691890537
datafile 3 switched to datafile copy
input datafile copy recid=2 stamp=691890658 filename=+DATA/clndb/datafile/sysaux.276.691890537
datafile 4 switched to datafile copy
input datafile copy recid=3 stamp=691890658 filename=+DATA/clndb/datafile/users.286.691890537
datafile 5 switched to datafile copy
input datafile copy recid=4 stamp=691890658 filename=+DATA/clndb/datafile/example.280.691890537
datafile 6 switched to datafile copy
input datafile copy recid=5 stamp=691890658 filename=+DATA/clndb/datafile/data.287.691890537
contents of Memory Script:
{
set until scn 686765;
recover
clone database
delete archivelog
;
}
executing Memory Script
executing command: SET until clause
Starting recover at 10-JUL-09
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: sid=152 devtype=DISK
starting media recovery
archive log thread 1 sequence 7 is already on disk as file +DATA/asmdb/arc00007_0690827617.001
archive log filename=+DATA/asmdb/arc00007_0690827617.001 thread=1 sequence=7
media recovery complete, elapsed time: 00:00:10
Finished recover at 10-JUL-09
contents of Memory Script:
{
shutdown clone;
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 612368384 bytes
Fixed Size 1292036 bytes
Variable Size 171968764 bytes
Database Buffers 432013312 bytes
Redo Buffers 7094272 bytes
sql statement: CREATE CONTROLFILE REUSE SET DATABASE "CLNDB" 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/clndb/datafile/system.275.691890537'
CHARACTER SET WE8MSWIN1252
contents of Memory Script:
{
set newname for clone tempfile 1 to new;
switch clone tempfile all;
catalog clone datafilecopy "+DATA/clndb/datafile/undotbs1.283.691890537";
catalog clone datafilecopy "+DATA/clndb/datafile/sysaux.276.691890537";
catalog clone datafilecopy "+DATA/clndb/datafile/users.286.691890537";
catalog clone datafilecopy "+DATA/clndb/datafile/example.280.691890537";
catalog clone datafilecopy "+DATA/clndb/datafile/data.287.691890537";
switch clone datafile all;
}
executing Memory Script
executing command: SET NEWNAME
renamed temporary file 1 to +DATA in control file
cataloged datafile copy
datafile copy filename=+DATA/clndb/datafile/undotbs1.283.691890537 recid=1 stamp=691891216
cataloged datafile copy
datafile copy filename=+DATA/clndb/datafile/sysaux.276.691890537 recid=2 stamp=691891216
cataloged datafile copy
datafile copy filename=+DATA/clndb/datafile/users.286.691890537 recid=3 stamp=691891216
cataloged datafile copy
datafile copy filename=+DATA/clndb/datafile/example.280.691890537 recid=4 stamp=691891216
cataloged datafile copy
datafile copy filename=+DATA/clndb/datafile/data.287.691890537 recid=5 stamp=691891217
datafile 2 switched to datafile copy
input datafile copy recid=1 stamp=691891216 filename=+DATA/clndb/datafile/undotbs1.283.691890537
datafile 3 switched to datafile copy
input datafile copy recid=2 stamp=691891216 filename=+DATA/clndb/datafile/sysaux.276.691890537
datafile 4 switched to datafile copy
input datafile copy recid=3 stamp=691891216 filename=+DATA/clndb/datafile/users.286.691890537
datafile 5 switched to datafile copy
input datafile copy recid=4 stamp=691891216 filename=+DATA/clndb/datafile/example.280.691890537
datafile 6 switched to datafile copy
input datafile copy recid=5 stamp=691891217 filename=+DATA/clndb/datafile/data.287.691890537
contents of Memory Script:
{
Alter clone database open resetlogs;
}
executing Memory Script
database opened
Finished Duplicate Db

Please, feel free to leave a comment on this Post.

Oracle RAC node unavailable with error: Server unexpectedly closed network connection6]clsc_connect: (0x251c670) no listener at (ADDRESS=(PROTOCOL=ipc)(KEY=OCSSD_LL_node2_))

 Early midnight I received a call from the monitoring team that one of the critical production database node is not available. As I am aware...