How to clone database on the same host with different name
Step by steps cloning operation is described below. The scenario is,
-Source database shaik be cloned as shaikcl
-Datafile named E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\*.dbf will be cloned as F:\ORACLE\SHAIKCL\*.dbf
-Controlfile named E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\*.ctl will be cloned as
F:\ORACLE\*.CTL
-In cloned database adump,bdump,cdump,udump will be located in F:\ORACLE\*dump
Step 01:
In source database identify the datafile location and redo logfile location.
On windows machine,
C:\Documents and Settings\Queen>set ORACLE_SID=shaik
On linux based machine,
$export ORACLE_SID=shaik
C:\Documents and Settings\Queen>sqlplus / as sysdba
SQL*Plus: Release 10.2.0.1.0 - Production on Mon Oct 6 23:19:45 2008
Copyright (c) 1982, 2005, Oracle. All rights reserved.
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
SQL> col file_name format a70
SQL> set linesize 160
SQL> select file_name, file_id from dba_data_files;
FILE_NAME FILE_ID
---------------------------------------------------------------------- ----------
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\USERS01.DBF 4
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\SYSAUX01.DBF 3
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\UNDOTBS01.DBF 2
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\SYSTEM01.DBF 1
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\EXAMPLE01.DBF 5
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\TEST_TBS01.DBF 6
6 rows selected.
SQL> select member from v$logfile;
MEMBER
----------------------------------------------------------------
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO02.LOG
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO01.LOG
Step 02:
Create a pfile from source spfile and controfile trace from source controlfile.
SQL> create pfile='f:\pfile.ora' from spfile;
File created.
SQL> alter database backup controlfile to trace as 'f:\controlfile.ctl';
Database altered.
On linux based system as linux file structure to save controlfile. Like instead of f:\controlfile.ctl use /oracle/controlfile.ctl
Step 03:
Shutdown the source database.
SQL> shut immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
Step 04:
Create the required directory for the cloned database. You should do this step in previous.
SQL> host
Microsoft Windows XP [Version 5.1.2600]
(C) Copyright 1985-2001 Microsoft Corp.
C:\Documents and Settings\Queen>mkdir f:\oracle
C:\Documents and Settings\Queen>mkdir f:\oracle\shaikcl
On unix based machine adjust the location as you wish to create clone database.
Step 05:
Copy datafiles and redo log files to the location of f:\oracle\shaikcl
C:\Documents and Settings\Queen>copy E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\*.dbf f:\oracle\shaikcl
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\EXAMPLE01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\SYSAUX01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\SYSTEM01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\TEMP01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\TEST_TBS01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\UNDOTBS01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\USERS01.DBF
7 file(s) copied.
C:\Documents and Settings\Queen>copy E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\*.log f:\oracle\shaikcl
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO01.LOG
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO02.LOG
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO03.LOG
3 file(s) copied.
Step 06:
At this stage task with the source database is finished. Edit the pfile f:\pfile.ora and change parameter control_files, db_name, different dump directory in order to reflect cloned database name and location.
On windows,
C:\Documents and Settings\Queen>notepad f:\pfile.ora
shaikcl.__db_cache_size=25165824
shaikcl.__java_pool_size=4194304
shaikcl.__large_pool_size=4194304
shaikcl.__shared_pool_size=62914560
shaikcl.__streams_pool_size=0
*.audit_file_dest='F:\oracle\adump'
*.audit_trail='DB','EXTENDED'
*.background_dump_dest='F:\oracle\bdump'
*.compatible='10.2.0.1.0'
*.control_files='F:\oracle\control01.ctl',
'F:\oracle\control02.ctl','F:\oracle\control03.ctl'
*.core_dump_dest='F:\oracle\cdump'
*.db_block_size=8192
*.db_create_file_dest='C:\'
*.db_domain=''
*.db_file_multiblock_read_count=16
*.db_name='shaikcl'
*.db_recovery_file_dest_size=2147483648
*.db_recovery_file_dest='c:\test'
*.dispatchers='(PROTOCOL=TCP) (SERVICE=shaikclXDB)'
*.job_queue_processes=10
*.log_archive_dest_1='LOCATION=c:\test'
*.log_archive_dest_2='LOCATION=g:\'
*.log_archive_dest_3='LOCATION=USE_DB_RECOVERY_FILE_DEST'
*.open_cursors=300
*.pga_aggregate_target=202375168
*.processes=150
*.remote_login_passwordfile='EXCLUSIVE'
*.sga_target=104857600
*.undo_management='AUTO'
*.undo_tablespace='UNDOTBS1'
*.user_dump_dest='F:\oracle\udump'
On linux based system use as, $vi pfile.ora
Step 07:
Edit the created text controlfile and change the database name along with logfile and datafile location and use SET DATABASE database_name in the controlfile creation script.
On windows,
C:\Documents and Settings\Queen>notepad f:\CONTROLFILE.CTL
STARTUP NOMOUNT PFILE='F:\PFILE.ORA'
CREATE CONTROLFILE REUSE SET DATABASE "shaikcl" RESETLOGS ARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 100
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 'F:\ORACLE\SHAIKCL\REDO01.LOG' SIZE 50M,
GROUP 2 'F:\ORACLE\SHAIKCL\REDO02.LOG' SIZE 50M,
GROUP 3 'F:\ORACLE\SHAIKCL\REDO03.LOG' SIZE 50M
DATAFILE
'F:\ORACLE\SHAIKCL\SYSTEM01.DBF',
'F:\ORACLE\SHAIKCL\UNDOTBS01.DBF',
'F:\ORACLE\SHAIKCL\SYSAUX01.DBF',
'F:\ORACLE\SHAIKCL\USERS01.DBF',
'F:\ORACLE\SHAIKCL\EXAMPLE01.DBF',
'F:\ORACLE\SHAIKCL\TEST_TBS01.DBF'
CHARACTER SET WE8MSWIN1252
;
On unix based system open the controlfile with any editor software and then edit.
Step 08:Avoid this step if you are on unix based system. On windows, with oradim create new oracle service shaikcl. However if you are on unix machine then simply ignore this step.
C:\Documents and Settings\Queen>oradim -new -sid shaikcl
Instance created.
Step 09:
Set environmental variable to shaikcl and connect to instance as sysdba.
C:\Documents and Settings\Queen>set ORACLE_SID=shaikcl
On unix based system, export ORACLE_SID=shaikcl
C:\Documents and Settings\Queen>sqlplus / as sysdba
SQL*Plus: Release 10.2.0.1.0 - Production on Tue Oct 7 00:04:32 2008
Copyright (c) 1982, 2005, Oracle. All rights reserved.
Connected to an idle instance.
Step 10:
Run the controlfile creation script.
On windows,
SQL> @f:\controlfile.ctl
ORACLE instance started.
Total System Global Area 104857600 bytes
Fixed Size 1247516 bytes
Variable Size 71304932 bytes
Database Buffers 25165824 bytes
Redo Buffers 7139328 bytes
Control file created.
On unix based system run the modified controlfile script where you saved.
Step 11:
Open the database with resetlogs option.
SQL> alter database open resetlogs;
Database altered.
Check the cloned database name.
SQL> show parameter db_name
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
db_name string shaikcl
You can check the cloned database datafile location.
SQL> select file_name from dba_data_files;
FILE_NAME
--------------------------------------------------------------------------------
F:\ORACLE\SHAIKCL\TEST_TBS01.DBF
F:\ORACLE\SHAIKCL\EXAMPLE01.DBF
F:\ORACLE\SHAIKCL\USERS01.DBF
F:\ORACLE\SHAIKCL\SYSAUX01.DBF
F:\ORACLE\SHAIKCL\UNDOTBS01.DBF
F:\ORACLE\SHAIKCL\SYSTEM01.DBF
6 rows selected.
-Source database shaik be cloned as shaikcl
-Datafile named E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\*.dbf will be cloned as F:\ORACLE\SHAIKCL\*.dbf
-Controlfile named E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\*.ctl will be cloned as
F:\ORACLE\*.CTL
-In cloned database adump,bdump,cdump,udump will be located in F:\ORACLE\*dump
Step 01:
In source database identify the datafile location and redo logfile location.
On windows machine,
C:\Documents and Settings\Queen>set ORACLE_SID=shaik
On linux based machine,
$export ORACLE_SID=shaik
C:\Documents and Settings\Queen>sqlplus / as sysdba
SQL*Plus: Release 10.2.0.1.0 - Production on Mon Oct 6 23:19:45 2008
Copyright (c) 1982, 2005, Oracle. All rights reserved.
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
SQL> col file_name format a70
SQL> set linesize 160
SQL> select file_name, file_id from dba_data_files;
FILE_NAME FILE_ID
---------------------------------------------------------------------- ----------
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\USERS01.DBF 4
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\SYSAUX01.DBF 3
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\UNDOTBS01.DBF 2
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\SYSTEM01.DBF 1
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\EXAMPLE01.DBF 5
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\TEST_TBS01.DBF 6
6 rows selected.
SQL> select member from v$logfile;
MEMBER
----------------------------------------------------------------
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO02.LOG
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO01.LOG
Step 02:
Create a pfile from source spfile and controfile trace from source controlfile.
SQL> create pfile='f:\pfile.ora' from spfile;
File created.
SQL> alter database backup controlfile to trace as 'f:\controlfile.ctl';
Database altered.
On linux based system as linux file structure to save controlfile. Like instead of f:\controlfile.ctl use /oracle/controlfile.ctl
Step 03:
Shutdown the source database.
SQL> shut immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
Step 04:
Create the required directory for the cloned database. You should do this step in previous.
SQL> host
Microsoft Windows XP [Version 5.1.2600]
(C) Copyright 1985-2001 Microsoft Corp.
C:\Documents and Settings\Queen>mkdir f:\oracle
C:\Documents and Settings\Queen>mkdir f:\oracle\shaikcl
On unix based machine adjust the location as you wish to create clone database.
Step 05:
Copy datafiles and redo log files to the location of f:\oracle\shaikcl
C:\Documents and Settings\Queen>copy E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\*.dbf f:\oracle\shaikcl
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\EXAMPLE01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\SYSAUX01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\SYSTEM01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\TEMP01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\TEST_TBS01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\UNDOTBS01.DBF
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\USERS01.DBF
7 file(s) copied.
C:\Documents and Settings\Queen>copy E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\*.log f:\oracle\shaikcl
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO01.LOG
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO02.LOG
E:\ORACLE\PRODUCT\10.2.0\ORADATA\SHAIK\REDO03.LOG
3 file(s) copied.
Step 06:
At this stage task with the source database is finished. Edit the pfile f:\pfile.ora and change parameter control_files, db_name, different dump directory in order to reflect cloned database name and location.
On windows,
C:\Documents and Settings\Queen>notepad f:\pfile.ora
shaikcl.__db_cache_size=25165824
shaikcl.__java_pool_size=4194304
shaikcl.__large_pool_size=4194304
shaikcl.__shared_pool_size=62914560
shaikcl.__streams_pool_size=0
*.audit_file_dest='F:\oracle\adump'
*.audit_trail='DB','EXTENDED'
*.background_dump_dest='F:\oracle\bdump'
*.compatible='10.2.0.1.0'
*.control_files='F:\oracle\control01.ctl',
'F:\oracle\control02.ctl','F:\oracle\control03.ctl'
*.core_dump_dest='F:\oracle\cdump'
*.db_block_size=8192
*.db_create_file_dest='C:\'
*.db_domain=''
*.db_file_multiblock_read_count=16
*.db_name='shaikcl'
*.db_recovery_file_dest_size=2147483648
*.db_recovery_file_dest='c:\test'
*.dispatchers='(PROTOCOL=TCP) (SERVICE=shaikclXDB)'
*.job_queue_processes=10
*.log_archive_dest_1='LOCATION=c:\test'
*.log_archive_dest_2='LOCATION=g:\'
*.log_archive_dest_3='LOCATION=USE_DB_RECOVERY_FILE_DEST'
*.open_cursors=300
*.pga_aggregate_target=202375168
*.processes=150
*.remote_login_passwordfile='EXCLUSIVE'
*.sga_target=104857600
*.undo_management='AUTO'
*.undo_tablespace='UNDOTBS1'
*.user_dump_dest='F:\oracle\udump'
On linux based system use as, $vi pfile.ora
Step 07:
Edit the created text controlfile and change the database name along with logfile and datafile location and use SET DATABASE database_name in the controlfile creation script.
On windows,
C:\Documents and Settings\Queen>notepad f:\CONTROLFILE.CTL
STARTUP NOMOUNT PFILE='F:\PFILE.ORA'
CREATE CONTROLFILE REUSE SET DATABASE "shaikcl" RESETLOGS ARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 100
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 'F:\ORACLE\SHAIKCL\REDO01.LOG' SIZE 50M,
GROUP 2 'F:\ORACLE\SHAIKCL\REDO02.LOG' SIZE 50M,
GROUP 3 'F:\ORACLE\SHAIKCL\REDO03.LOG' SIZE 50M
DATAFILE
'F:\ORACLE\SHAIKCL\SYSTEM01.DBF',
'F:\ORACLE\SHAIKCL\UNDOTBS01.DBF',
'F:\ORACLE\SHAIKCL\SYSAUX01.DBF',
'F:\ORACLE\SHAIKCL\USERS01.DBF',
'F:\ORACLE\SHAIKCL\EXAMPLE01.DBF',
'F:\ORACLE\SHAIKCL\TEST_TBS01.DBF'
CHARACTER SET WE8MSWIN1252
;
On unix based system open the controlfile with any editor software and then edit.
Step 08:Avoid this step if you are on unix based system. On windows, with oradim create new oracle service shaikcl. However if you are on unix machine then simply ignore this step.
C:\Documents and Settings\Queen>oradim -new -sid shaikcl
Instance created.
Step 09:
Set environmental variable to shaikcl and connect to instance as sysdba.
C:\Documents and Settings\Queen>set ORACLE_SID=shaikcl
On unix based system, export ORACLE_SID=shaikcl
C:\Documents and Settings\Queen>sqlplus / as sysdba
SQL*Plus: Release 10.2.0.1.0 - Production on Tue Oct 7 00:04:32 2008
Copyright (c) 1982, 2005, Oracle. All rights reserved.
Connected to an idle instance.
Step 10:
Run the controlfile creation script.
On windows,
SQL> @f:\controlfile.ctl
ORACLE instance started.
Total System Global Area 104857600 bytes
Fixed Size 1247516 bytes
Variable Size 71304932 bytes
Database Buffers 25165824 bytes
Redo Buffers 7139328 bytes
Control file created.
On unix based system run the modified controlfile script where you saved.
Step 11:
Open the database with resetlogs option.
SQL> alter database open resetlogs;
Database altered.
Check the cloned database name.
SQL> show parameter db_name
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
db_name string shaikcl
You can check the cloned database datafile location.
SQL> select file_name from dba_data_files;
FILE_NAME
--------------------------------------------------------------------------------
F:\ORACLE\SHAIKCL\TEST_TBS01.DBF
F:\ORACLE\SHAIKCL\EXAMPLE01.DBF
F:\ORACLE\SHAIKCL\USERS01.DBF
F:\ORACLE\SHAIKCL\SYSAUX01.DBF
F:\ORACLE\SHAIKCL\UNDOTBS01.DBF
F:\ORACLE\SHAIKCL\SYSTEM01.DBF
6 rows selected.
Comments
Post a Comment