This procedure will clone a database using a online copy of the source database files.
PART I
You have to follow steps 1 to step 8 is a prerequisite steps for creating clone database.
* 1. Make a note of the current archive log change number
Because the restored files will require recovery, some archive logs will be needed. This applies even if you are not intending to put the cloned database into archive log mode. Work out which will be the first required log by running the following query on the source database. Make a note of the change number that is returned:
SQL> select max(first_change#) chng
from v$archived_log
/
* 2. Prepare the begin/end backup scripts
The following sql will produce two scripts; begin_backup.sql and end_backup.sql. When executed, these scripts will either put the tablespaces into backup mode or take them out of it:
SQL> spool begin_backup.sql
select 'alter tablespace ' || tablespace_name || ' begin backup;' tsbb
from dba_tablespaces
where contents != 'TEMPORARY'
order by tablespace_name
/
SQL> spool off
SQL>spool end_backup.sql
select 'alter tablespace ' || tablespace_name || ' end backup;' tseb
from dba_tablespaces
where contents != 'TEMPORARY'
order by tablespace_name
/
SQL>spool off
* 3. Put the source database into backup mode
From sqlplus, run the begin backup script created in the last step:
SQL> @begin_backup
This will put all of the databases tablespaces into backup mode.
* 4. Copy the files to the new location
Copy, scp or ftp the files from the source database/machine to the target. Do not copy the control files across. Make sure that the files have the correct permissions and ownership.
* 5. Take the source database out of backup mode
Once the file copy has been completed, take the source database out of backup mode. Run the end backup script created in step 2. From sqlplus:
SQL>@end_backup
* 6. Copy archive logs
It is only necessary to copy archive logs created during the time the source database was in backup mode. Begin by archiving the current redo:
SQL> alter system archive log current;
Then, identify which archive log files are required. When run, the following query will ask for a change number. This is the number noted in step 1.
SQL> select name
from v$archived_log
where first_change# >= &change_no
order by name
/
Create an archive directory in the clone database.s file system and copy all of the identified logs into it.
* 7. Produce a pfile for the new database
This step assumes that you are using a spfile. If you are not, just copy the existing pfile.
From sqlplus:
SQL> create pfile='/u01/admin/clone/pfile/init.ora' from spfile;
This will create a new pfile in the /u01/admin/clone/pfile directory.
Once created, the new pfile will need to be edited. If the cloned database is to have a new name, this will need to be changed, as will any paths. Review the contents of the file and make alterations as necessary. Also think about adjusting memory parameters. If you are cloning a production database onto a slower development machine you might want to consider reducing some values.
Ensure that the archive log destination is pointing to the directory created in step 6.
* 8. Create the clone controlfile
Create a control file for the new database. To do this, connect to the source database and request a dump of the current control file. From sqlplus:
SQL> alter database backup controlfile to trace;
The file will require extensive editing before it can be used. Using your favourite editor make the following alterations:
o Remove all lines from the top of the file including the second 'STARTUP MOUNT' line (it's roughly halfway down the file).
o Remove any lines that start with --
o Remove any lines that start with a #
o Remove any blank lines in the 'CREATE CONTROLFILE' section.
o Remove the line 'RECOVER DATABASE USING BACKUP CONTROLFILE'
o Remove the line 'ALTER DATABASE OPEN RESETLOGS;'
o Make a copy of the 'ALTER TABLESPACE TEMP...' lines, and then remove them from the file. Make sure that you hang onto the command, it will be used later.
o Move to the top of the file to the 'CREATE CONTROLFILE' line. The word 'REUSE' needs to be changed to 'SET'. The database name needs setting to the new database name (if it is being changed). Decide whether the database will be put into archivelog mode or not.
o If the file paths are being changed, alter the file to reflect the changes.
Here is an example of how the file would look for a small database called CLONE which isn't in archivelog mode:
CREATE CONTROLFILE set DATABASE "clone" RESETLOGS NOARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 100
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 '/u01/app/oracle/product/10.2.0/oradata/clone/redo01.log' SIZE 50M,
GROUP 2 '/u01/app/oracle/product/10.2.0/oradata/clone/redo02.log' SIZE 50M,
GROUP 3 '/u01/app/oracle/product/10.2.0/oradata/clone/redo03.log' SIZE 50M
-- STANDBY LOGFILE
DATAFILE
'/u01/app/oracle/product/10.2.0/oradata/clone/system01.dbf',
'/u01/app/oracle/product/10.2.0/oradata/clone/undotbs01.dbf',
'/u01/app/oracle/product/10.2.0/oradata/clone/sysaux01.dbf',
'/u01/app/oracle/product/10.2.0/oradata/clone/users01.dbf',
'/u01/app/oracle/product/10.2.0/oradata/clone/example01.dbf'
CHARACTER SET WE8ISO8859P1
;
IMPORTANT: SAVE THIS FILE IN YOUR HOME DIRECTORY AS dbclone.sql
PART II
This are the steps to launch clone database
* 9. Add a new entry to oratab and source the environment
Edit the /etc/oratab (or /opt/oracle/oratab) and add an entry for the new database.
Source the new environment with '. oraenv' and verify that it has worked by issuing the following command:
echo $ORACLE_SID
If this doesn't output the new database sid go back and investigate.
* 10. Create the a password file
Use the following command to create a password file (add an appropriate password to the end of it):
orapwd file=${ORACLE_HOME}/dbs/orapw${ORACLE_SID} password=
* 11. Create the new control file(s)
Ok, now for the exciting bit! It is time to create the new controlfiles and open the database:
open new terminal and follow the steps:
[oracle@localhost ~]$ ORACLE_SID=clone
[oracle@localhost ~]$ sqlplus '/as sysdba'
SQL*Plus: Release 10.2.0.1.0 - Production on Tue May 12 18:54:56 2009
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> startup nomount pfile=/u01/admin/clone/pfile/init.ora
SQL> @/home/oracle/dbclone.sql
If all goes to plan you will see the instance start and then the message 'Control file created'.
* 12. Recover and open the database
The archive logs that were identified and copied in step 6 must now be applied to the database. Issue the following command from sqlplus:
SQL> recover database using BACKUP CONTROLFILE until cancel;
ORA-00279: change 542839 generated at 05/12/2009 02:38:29 needed for thread 1
ORA-00289: suggestion :
/u01/app/oracle/product/10.2.0/db_1/flash_recovery_area/CLONE/archivelog/2008_11_
25/o1_mf_1_3_%u_.arc
ORA-00280: change 542839 for thread 1 is in sequence #3
Specify log: {
IMPORTANT:You need to give the archived log name here and then say "Cancel" and open the database
/u01/app/oracle/oradata/CLONE/o1_mf_1_3_4lqgzpsg_.arc
ORA-00279: change 543072 generated at 11/25/2008 02:48:54 needed for thread 1
ORA-00289: suggestion :
/u01/app/oracle/product/10.2.0/db_1/flash_recovery_area/CLONE/archivelog/2008_11_
25/o1_mf_1_4_%u_.arc
ORA-00280: change 543072 for thread 1 is in sequence #4
ORA-00278: log file '/u01/app/oracle/oradata/CLONE/o1_mf_1_3_4lqgzpsg_.arc' no
longer needed for this recovery
Specify log: {
/u01/app/oracle/oradata/CLONE/o1_mf_1_4_4lqgzsbq_.arc
ORA-00279: change 543074 generated at 11/25/2008 02:48:57 needed for thread 1
ORA-00289: suggestion :
/u01/app/oracle/product/10.2.0/db_1/flash_recovery_area/CLONE/archivelog/2008_11_
25/o1_mf_1_5_%u_.arc
ORA-00280: change 543074 for thread 1 is in sequence #5
ORA-00278: log file '/u01/app/oracle/oradata/CLONE/o1_mf_1_4_4lqgzsbq_.arc' no
longer needed for this recovery
Specify log: {
cancel
Media recovery cancelled.
SQL> alter database open resetlogs;
AND THEN MAKE YOUR DATABASE TO ARCHIVELOG MODE
* 13. Create temp files
Using the 'ALTER TABLESPACE TEMP...' command from step 8, create the temp files. Make sure the paths to the file(s) are correct, then run it from sqlplus.
* 14. Perform a few checks
If the last couple of steps went smoothly, the database should be open. It is advisable to perform a few checks at this point:
o Check that the database has opened with:
SQL>select status from v$instance;
The status should be 'OPEN'
o Make sure that the datafiles are all ok:
SQL>select distinct status from v$datafile;
It should return only ONLINE and SYSTEM.
o Take a quick look at the alert log too.
* 15. Set the databases global name
The new database will still have the source databases global name. Run the following to reset it:
SQL>alter database rename global_name to
/
Note. no quotes!
* 16. Create a spfile
From sqlplus:
SQL>create spfile from pfile;
* 17. Change the database ID
If RMAN is going to be used to back-up the database, the database ID must be changed. If RMAN isn't going to be used, there is no harm in changing the ID anyway - and it's a good practice to do so.
From sqlplus:
SQL>shutdown immediate
SQL>startup mount
SQL>exit
From unix and linux:
nid target=/
NID will ask if you want to change the ID. Respond with 'Y'. Once it has finished, start the database up again in sqlplus:
SQL>shutdown immediate
SQL>startup mount
SQL>alter database open resetlogs
/
* 18. Configure TNS
Add entries for new database in the listener.ora and tnsnames.ora as necessary.
* 19. Finished
That's it!
Original documentation prepard by shutdownabort.com, Andrew Barry, I have made some changes in that documentation for easy understanding with the help of ASKDBA ORACLE FEED forum.
for further reference and more information:
http://www.shutdownabort.com/quickguides/clone_hot.php
http://askdba.org/forum/topic.php?id=18
1 comment:
Hello Arun,
when i run " SQL>select distinct status from v$datafile;"
i am getting.....
ONLINE
SYSTEM
RECOVER
-> Getting RECOVER is it an issue... if yes how to get rid of it...Can you please tell me... Thank you
Post a Comment