Monday, April 6, 2009

Clone Database Manually

Clone an Oracle database using an online/hot backup:
This procedure will clone a database using a online copy of the source database files. Before beginning though, there are a few things that are worth noting about online/hot backups:
  1. When a tablespace is put into backup mode, Oracle will write entire blocks to redo rather than the usual change vectors. For this reason, do not perform a hot backup during periods of heavy database activity - it could lead to a lot of archive logs being created.
  2. This procedure will put all tablespaces into backup mode at the same time. If the source database is quite large and you think that it might take a long time to copy, consider copying the tablespaces one at a time, or in groups.
  3. While the backup is in progress, it will not be possible to take the tablespaces offline normally or shut down the instance.

Ok, lets get started...

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:


cr_hot_backup.sql

set lines 999 pages 999
set verify off
set feedback off
set heading off


spool begin_backup.sql


select 'alter tablespace ' tablespace_name ' begin backup;' tsbb
from dba_tablespaces
where contents != 'TEMPORARY'
order by tablespace_name
/
spool off

spool end_backup.sql


select 'alter tablespace ' tablespace_name ' end backup;' tseb
from dba_tablespaces
where contents != 'TEMPORARY'
order by tablespace_name
/
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 data 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='init.ora' from spfile;

This will create a new pfile in the $ORACLE_HOME/dbs 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 as '/home/oracle/cr_clone_test.sql';

The file will require extensive editing before it can be used. Using your favourite editor make the following alterations:

  1. Remove all lines from the top of the file up to but not including the second 'STARTUP MOUNT' line (it's roughly halfway down the file).
  2. Remove any lines that start with --
  3. Remove any lines that start with a #
  4. Remove any blank lines in the 'CREATE CONTROLFILE' section.
  5. Remove the line 'RECOVER DATABASE USING BACKUP CONTROLFILE'
  6. Remove the line 'ALTER DATABASE OPEN RESETLOGS;'
  7. 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.
  8. 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.
  9. 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 dg9a which isn't in archivelog mode:

STARTUP NOMOUNT
CREATE CONTROLFILE SET DATABASE "DG9A" RESETLOGS FORCE LOGGING NOARCHIVELOG
MAXLOGFILES 50
MAXLOGMEMBERS 5
MAXDATAFILES 100
MAXINSTANCES 1
MAXLOGHISTORY 453
LOGFILE
GROUP 1 '/u03/oradata/dg9a/redo01.log' SIZE 100M,
GROUP 2 '/u03/oradata/dg9a/redo02.log' SIZE 100M,
GROUP 3 '/u03/oradata/dg9a/redo03.log' SIZE 100M
DATAFILE
'/u03/oradata/dg9a/system01.dbf',
'/u03/oradata/dg9a/undotbs01.dbf',
'/u03/oradata/dg9a/cwmlite01.dbf',
'/u03/oradata/dg9a/drsys01.dbf',
'/u03/oradata/dg9a/example01.dbf',
'/u03/oradata/dg9a/indx01.dbf',
'/u03/oradata/dg9a/odm01.dbf',
'/u03/oradata/dg9a/tools01.dbf',
'/u03/oradata/dg9a/users01.dbf',
'/u03/oradata/dg9a/xdb01.dbf',
'/u03/oradata/dg9a/andy01.dbf',
'/u03/oradata/dg9a/psstats01.dbf',
'/u03/oradata/dg9a/planner01.dbf'
CHARACTER SET WE8ISO8859P1
;

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 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=xxx

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:

sqlplus "/ as sysdba"
SQL>@/home/oracle/cr_clone_test.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;
When prompted to 'Specify log' enter 'auto'.

Oracle will then apply all the available logs, and then error with ORA-00308. This is normal, it simply means that all available logs have been applied.

Open the database with reset logs:

SQL>alter database open resetlogs;

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:
Check that the database has opened with:

SQL> select status from v$instance;
The status should be 'OPEN'

Make sure that the datafiles are all ok:

SQL>select distinct status from v$datafile;
It should return only ONLINE and SYSTEM.

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 new_database_global_name;
Note. no quotes!

16. Create a spfileFrom 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:

nid target=username/Password

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.

Finished......

No comments:

Post a Comment