RMAN's integration with ASM makes it a breeze to migrate a file-system based Oracle database to ASM with minimal downtime. RMAN's backup as copy command moves the datafiles to ASM. The procedure described here can be executed while database is online or offline. Database must be in ARCHIVELOG mode if you plan to move the database online. Otherwise, you need to shutdown the database to move it to ASM.
Please note that online move does require a small downtime to apply the archive logs. In addition, you also need to bring the database down to copy control files. If you plan to move the database to ASM in offline mode, then the downtime that would be needed to migrate the database is slightly more than the time it would take to copy the whole database to ASM.
This example shows how to move an Oracle database that currently resides on /u05 to +DATA_HRP ASM group.
Step 1: Move Temp Files to ASM
SQL> show parameter db_create
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
db_create_file_dest string +DATA_HRP
db_create_online_log_dest_1 string
db_create_online_log_dest_2 string
db_create_online_log_dest_3 string
db_create_online_log_dest_4 string
db_create_online_log_dest_5 string
SQL> select file_name from dba_temp_files;
FILE_NAME
--------------------------------------------------------------------------------
/u05/app/oracle/oradata/HRP/temp01.dbf
SQL> alter tablespace temp add tempfile size 100m;
Tablespace altered.
SQL> select file_name from dba_temp_files;
FILE_NAME
--------------------------------------------------------------------------------
/u05/app/oracle/oradata/HRP/temp01.dbf
+DATA_HRP/hrp/tempfile/temp.284.758901505
SQL> alter tablespace temp drop tempfile '/u05/app/oracle/oradata/HRP/temp01.dbf' ;
Tablespace altered.
SQL> select file_name from dba_temp_files ;
FILE_NAME
--------------------------------------------------------------------------------
+DATA_HRP/hrp/tempfile/temp.284.758901505
Step 2: Move Redo Log Files to ASM
SQL> alter database add logfile group 4 size 10m ;
Database altered.
SQL> alter database add logfile group 5 size 10m ;
Database altered.
SQL> alter database add logfile group 6 size 10m ;
Database altered.
SQL> alter system switch logfile ;
System altered.
SQL> alter database drop logfile group 1;
Database altered.
SQL> alter database drop logfile group 2;
Database altered.
SQL> alter database drop logfile group 3 ;
Database altered.
SQL> alter system switch logfile ;
System altered.
SQL> select member, group# from v$logfile ;
MEMBER GROUP#
------------------------------------------------------------ ----------
+DATA_HRP/hrp/onlinelog/group_4.285.758901721 4
+DATA_HRP/hrp/onlinelog/group_5.286.758901739 5
+DATA_HRP/hrp/onlinelog/group_6.287.758901751 6
Note: If you get an error while dropping a redo logfile, then drop the logs after database restart.
Step 3: Move Data Files to ASM
RMAN> backup as copy database format '+DATA_HRP' ;
input datafile file number=00001 name=/u05/app/oracle/oradata/HRP/system01.dbf
output file name=+DATA_HRP/hrp/datafile/system.277.758901101 tag=TAG20110811T135140 RECID=18 STAMP=758901110
input datafile file number=00002 name=/u05/app/oracle/oradata/HRP/sysaux01.dbf
output file name=+DATA_HRP/hrp/datafile/sysaux.278.758901117 tag=TAG20110811T135140 RECID=19 STAMP=758901122
input datafile file number=00003 name=/u05/app/oracle/oradata/HRP/undotbs01.dbf
output file name=+DATA_HRP/hrp/datafile/undotbs1.279.758901123 tag=TAG20110811T135140 RECID=20 STAMP=758901123
input datafile file number=00005 name=+DATA_HRP/hrp/datafile/test.268.758899993
output file name=+DATA_HRP/hrp/datafile/test.280.758901125 tag=TAG20110811T135140 RECID=21 STAMP=758901124
copying current control file
output file name=+DATA_HRP/hrp/controlfile/backup.281.758901125 tag=TAG20110811T135140 RECID=22 STAMP=758901126
input datafile file number=00004 name=/u05/app/oracle/oradata/HRP/users01.dbf
output file name=+DATA_HRP/hrp/datafile/users.282.758901127 tag=TAG20110811T135140 RECID=23 STAMP=758901126
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current SPFILE in backup set
channel ORA_DISK_1: starting piece 1 at 11-AUG-11
channel ORA_DISK_1: finished piece 1 at 11-AUG-11
piece handle=+DATA_HRP/hrp/backupset/2011_08_11/nnsnf0_tag20110811t135140_0.283.758901129 tag=TAG20110811T135140 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 11-AUG-11
SQL> shutdown immediate ;
SQL> startup mount ;
RMAN> switch database to copy;
datafile 1 switched to datafile copy "+DATA_HRP/hrp/datafile/system.277.758901101"
datafile 2 switched to datafile copy "+DATA_HRP/hrp/datafile/sysaux.278.758901117"
datafile 3 switched to datafile copy "+DATA_HRP/hrp/datafile/undotbs1.279.758901123"
datafile 4 switched to datafile copy "+DATA_HRP/hrp/datafile/users.282.758901127"
datafile 5 switched to datafile copy "+DATA_HRP/hrp/datafile/test.280.758901125"
If backup as copy command was executed while database was online, then recover the database.
RMAN> recover database;
RMAN> alter database open;
database opened
SQL> select file_name from dba_data_files ;
FILE_NAME
--------------------------------------------------------------------------------
+DATA_HRP/hrp/datafile/users.282.758901127
+DATA_HRP/hrp/datafile/undotbs1.279.758901123
+DATA_HRP/hrp/datafile/sysaux.278.758901117
+DATA_HRP/hrp/datafile/system.277.758901101
+DATA_HRP/hrp/datafile/test.280.758901125
Step 4: Move Controlfile to ASM
SQL> show parameter control
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
control_files string /u05/app/oracle/oradata/HRP
/control01.ctl, /u05/app/oracl
e/oradata/HRP/control02.ctl
SQL> alter system set control_files='+DATA_HRP/hrp/controlfile/control01.ctl','+DATA_HRP/hrp/controlfile/control02.ctl'scope=spfile ;
System altered.
SQL> shutdown immediate ;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup nomount ;
ORACLE instance started.
Total System Global Area 1570009088 bytes
Fixed Size 2226832 bytes
Variable Size 419431792 bytes
Database Buffers 1140850688 bytes
Redo Buffers 7499776 bytes
SQL> show parameter control
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
control_files string +DATA_HRP/hrp/controlfile/c
ontrol01.ctl,+DATA_HRP/hrp/
controlfile/control02.ctl
RMAN> restore controlfile from '/u05/app/oracle/oradata/HRP/control01.ctl' ;
Starting restore at 11-AUG-11
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=101 device type=DISK
channel ORA_DISK_1: copied control file copy
output file name=+DATA_HRP/hrp/controlfile/control01.ctl
Finished restore at 11-AUG-11
Step 5: Move SPFILE to ASM
SQL> create pfile from spfile ;
File created.
SQL> create spfile='+DATA_HRP/hrp/spfilehrp.ora' from pfile ;
File created.
[oracle@racnode1 Scripts]$ cd $ORACLE_HOME/dbs
[oracle@racnode1 dbs]$ rm initHRP.ora
[oracle@racnode1 dbs]$ rm spfileHRP.ora
[oracle@racnode1 dbs]$ echo "SPFILE='+DATA_HRP/hrp/spfilehrp.ora'" > initHRP.ora
SQL> shutdown immediate ;
SQL> startup ;
Step 6: Delete old Database on File System (Optional)
[oracle@racnode1 templates]$ rman nocatalog target /
Recovery Manager: Release 11.2.0.2.0 - Production on Thu Aug 11 15:14:21 2011
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
connected to target database: HRP (DBID=1884251670)
using target database control file instead of recovery catalog
RMAN> delete copy ;
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=145 device type=DISK
specification does not match any archived log in the repository
List of Datafile Copies
=======================
Key File S Completion Time Ckp SCN Ckp Time
------- ---- - --------------- ---------- ---------------
24 1 A 11-AUG-11 1034160 11-AUG-11
Name: /u05/app/oracle/oradata/HRP/system01.dbf
13 1 A 11-AUG-11 1033690 11-AUG-11
Name: +DATA_HRP/hrp/datafile/system.270.758900761
Tag: TAG20110811T134559
25 2 A 11-AUG-11 1034160 11-AUG-11
Name: /u05/app/oracle/oradata/HRP/sysaux01.dbf
14 2 A 11-AUG-11 1033690 11-AUG-11
Name: +DATA_HRP/hrp/datafile/sysaux.271.758900775
Tag: TAG20110811T134559
26 3 A 11-AUG-11 1034160 11-AUG-11
Name: /u05/app/oracle/oradata/HRP/undotbs01.dbf
15 3 A 11-AUG-11 1033690 11-AUG-11
Name: +DATA_HRP/hrp/datafile/undotbs1.272.758900791
Tag: TAG20110811T134559
27 4 A 11-AUG-11 1034160 11-AUG-11
Name: /u05/app/oracle/oradata/HRP/users01.dbf
16 4 A 11-AUG-11 1033690 11-AUG-11
Name: +DATA_HRP/hrp/datafile/users.275.758900793
Tag: TAG20110811T134559
28 5 A 11-AUG-11 1034160 11-AUG-11
Name: +DATA_HRP/hrp/datafile/test.268.758899993
17 5 A 11-AUG-11 1033690 11-AUG-11
Name: +DATA_HRP/hrp/datafile/test.273.758900791
Tag: TAG20110811T134559
List of Control File Copies
===========================
Key S Completion Time Ckp SCN Ckp Time
------- - --------------- ---------- ---------------
29 A 11-AUG-11 1036591 11-AUG-11
Name: +DATA_HRP/hrp/controlfile/control02.ctl
Tag: TAG20110811T141829
22 A 11-AUG-11 1034160 11-AUG-11
Name: +DATA_HRP/hrp/controlfile/backup.281.758901125
Tag: TAG20110811T135140
6 A 11-AUG-11 1033690 11-AUG-11
Name: +DATA_HRP/hrp/controlfile/backup.274.758900793
Tag: TAG20110811T134559
1 A 10-AUG-11 985693 10-AUG-11
Name: /u05/app/oracle/db/11.2.0.2/assistants/dbca/templates/HRP.ctl
Tag: TAG20110810T144120
Do you really want to delete the above objects (enter YES or NO)? YES
deleted datafile copy
datafile copy file name=/u05/app/oracle/oradata/HRP/system01.dbf RECID=24 STAMP=758901280
deleted datafile copy
datafile copy file name=+DATA_HRP/hrp/datafile/system.270.758900761 RECID=13 STAMP=758900812
deleted datafile copy
datafile copy file name=/u05/app/oracle/oradata/HRP/sysaux01.dbf RECID=25 STAMP=758901280
deleted datafile copy
datafile copy file name=+DATA_HRP/hrp/datafile/sysaux.271.758900775 RECID=14 STAMP=758900812
deleted datafile copy
datafile copy file name=/u05/app/oracle/oradata/HRP/undotbs01.dbf RECID=26 STAMP=758901280
deleted datafile copy
datafile copy file name=+DATA_HRP/hrp/datafile/undotbs1.272.758900791 RECID=15 STAMP=758900812
deleted datafile copy
datafile copy file name=/u05/app/oracle/oradata/HRP/users01.dbf RECID=27 STAMP=758901280
deleted datafile copy
datafile copy file name=+DATA_HRP/hrp/datafile/users.275.758900793 RECID=16 STAMP=758900812
deleted datafile copy
datafile copy file name=+DATA_HRP/hrp/datafile/test.268.758899993 RECID=28 STAMP=758901280
deleted datafile copy
datafile copy file name=+DATA_HRP/hrp/datafile/test.273.758900791 RECID=17 STAMP=758900812
deleted control file copy
control file copy file name=+DATA_HRP/hrp/controlfile/control02.ctl RECID=29 STAMP=758902710
deleted control file copy
control file copy file name=+DATA_HRP/hrp/controlfile/backup.281.758901125 RECID=22 STAMP=758901126
deleted control file copy
control file copy file name=+DATA_HRP/hrp/controlfile/backup.274.758900793 RECID=6 STAMP=758900793
deleted control file copy
control file copy file name=/u05/app/oracle/db/11.2.0.2/assistants/dbca/templates/HRP.ctl RECID=1 STAMP=758817680
Deleted 14 objects
No comments:
Post a Comment