Migrating Oracle Database 12cR1 from File System to ASM using RMAN

Migrating Oracle Database 12cR1 from File System to ASM using RMAN.

There are many ways which can be used to migrate Oracle Database from File System to ASM. ‘RMAN backup as copy’ is one of the methods of migrating database from File System to ASM.

In this demonstration Oracle RDBMS version is 12.1.0.2 and Grid Infrastructure is also 12.1.0.2. Here I’m assuming you already have up and running ASM instance with +DATA and +FRA ASM diskgroups.
If you haven’t created ASM instance yet, you can check this article.

 1. Let’s check the Name and Version of the database.

SQL> select NAME,VERSION,DATABASE_STATUS, HOST_NAME from v$database,v$instance;

NAME          VERSION    DATABASE_STATUS  HOST_NAME
---------- ----------   ----------------  --------------------
DEMTEST    12.1.0.2.0    ACTIVE           dbnode1.demunix.com

2. Let’s check location of Parameter file, Control file, Datafile, Tempfile and Redo Logfile of the database DEMTEST.

SQL> show parameter pfile

NAME          TYPE        VALUE
---------     ----------- ---------------------------------------------------------------
spfile        string      /u01/app/oracle/product/12.1.0/dbhome_1/dbs/spfileDEMTEST.ora

SQL> show parameter control_files

NAME           TYPE        VALUE
-------------- ----------- --------------------------------------------------------------------------
control_files  string      /u01/app/oracle/oradata/DEMTEST/controlfile/o1_mf_ftgqw2ry_.ctl,
                           /u01/app/oracle/fast_recovery_area/DEMTEST/controlfile/o1_mf_ftgqw321_.ctl

SQL> select FILE_NAME from DBA_DATA_FILES;

FILE_NAME
--------------------------------------------------------------------------------
/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_users_ftgqthfw_.dbf
/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_undotbs1_ftgqtjo8_.dbf
/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_system_ftgqqt14_.dbf
/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_sysaux_ftgqoro6_.dbf

4 rows selected.

SQL> select name from v$tempfile;

NAME
--------------------------------------------------------------------------------
/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_temp_ftgqxgmk_.tmp

SQL> select MEMBER from v$logfile;

MEMBER
--------------------------------------------------------------------------------
/u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_3_ftgqwfrs_.log
/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log
/u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_2_ftgqwb52_.log
/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_2_ftgqwbss_.log
/u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_1_ftgqw68q_.log
/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_1_ftgqw771_.log

6 rows selected.

3.Let’s check Instance Name and Version of Grid Infrastructure.

SQL> select INSTANCE_NAME,VERSION,DATABASE_STATUS,HOST_NAME from v$instance;

INSTANCE_NAME      VERSION   DATABASE_STATUS    HOST_NAME
--------------- -----------  ----------------   ---------------------
+ASM            12.1.0.2.0    ACTIVE            dbnode1.demunix.com

As we can see, ASM instance is running on same host.

4. Let’s check available diskgroups.

SQL> select NAME,TOTAL_MB,FREE_MB from v$asm_diskgroup;

NAME       TOTAL_MB    FREE_MB
---------- --------   --------
DATA          20480      20480
FRA           20480      20480

We have DATA and FRA diskgroups as well.

5. We’ll step by step migrate all database files from File System to ASM.

  • First we’ll migrate parameter file using RMAN. We’ll take backup of spfile and then restore it to ASM disk.

Let’s  Invoke RMAN.

[oracle@dbnode1 dbs]$ rman target /

Recovery Manager: Release 12.1.0.2.0 - Production on Sun Sep 23 17:07:48 2018

Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved.

connected to target database: DEMTEST (DBID=1537672932)

Let’s Take Backup of spfile.

RMAN> backup as backupset spfile;

Starting backup at 23-SEP-18
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=240 device type=DISK
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 23-SEP-18
channel ORA_DISK_1: finished piece 1 at 23-SEP-18
piece handle=/u01/app/oracle/fast_recovery_area/DEMTEST/backupset/2018_09_23/o1_mf_nnsnf_TAG20180923T164615_ftgxj06x_.bkp tag=TAG20180923T164615 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 23-SEP-18

Restore it on ASM disk.

RMAN> restore spfile to '+DATA/spfileDEMTEST.ora';

Starting restore at 23-SEP-18
using channel ORA_DISK_1

channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: restoring SPFILE
output file name=+DATA/spfileDEMTEST.ora
channel ORA_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/DEMTEST/backupset/2018_09_23/o1_mf_nnsnf_TAG20180923T164615_ftgxj06x_.bkp
channel ORA_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/DEMTEST/backupset/2018_09_23/o1_mf_nnsnf_TAG20180923T164615_ftgxj06x_.bkp tag=TAG20180923T164615
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:03
Finished restore at 23-SEP-18
  • Let’s now rename old pfile and spfile from $ORACLE_HOME/dbs location and create new pfile pointing to path of new spfile in ASM disk.

Navigate to $ORACLE_HOME/dbs

[oracle@dbnode1 ~]$ cd $ORACLE_HOME/dbs

Rename old spfile.

[oracle@dbnode1 dbs]$ mv spfileDEMTEST.ora spfileDEMTEST_old.ora

Create new pfile.

[oracle@dbnode1 dbs]$ vi initDEMTEST.ora

Add below entry.

spfile='+DATA/spfileDEMTEST.ora'

[ESC] > :wq > Enter (to save and exit)

Now bounce the database and check if it’s showing new location for spfile.

SQL> Show Parameter pfile

NAME      TYPE    VALUE
-------   ------  -----------------------
spfile    string  +DATA/spfiledemtest.ora

Yeah, spfile is now migrated to ASM


  • Now migrate control files using RMAN. To perform this operation, your database should be in nomount mode.

Invoke RMAN.

RMAN> restore controlfile to '+DATA' from '/u01/app/oracle/oradata/DEMTEST/controlfile/o1_mf_ftgqw2ry_.ctl';

Starting restore at 23-SEP-18
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=237 device type=DISK

channel ORA_DISK_1: copied control file copy
Finished restore at 23-SEP-18

RMAN> restore controlfile to '+FRA' from '/u01/app/oracle/fast_recovery_area/DEMTEST/controlfile/o1_mf_ftgqw321_.ctl';

Starting restore at 23-SEP-18
using channel ORA_DISK_1

channel ORA_DISK_1: copied control file copy
Finished restore at 23-SEP-18

Set new location for control files using alter system command.

SQL> alter system set control_files='+DATA/DEMTEST/CONTROLFILE/current.282.987613865','+FRA/DEMTEST/CONTROLFILE/current.260.987613935' scope=spfile;

System altered.

Now bounce the database and startup the database in mount mode and check if it’s showing new location for control files.

SQL> show parameter control_files

NAME            TYPE        VALUE
-------------   ----------- -----------------------------------------------------
control_files   string      +DATA/DEMTEST/CONTROLFILE/current.282.987613865,
                            +FRA/DEMTEST/CONTROLFILE/current.260.987613935

Now the control files are also migrated to ASM, let’s migrate datafiles now.

  • We’ll migrate datafile using RMAN Backup as copy method. Make sure database is in mount mode.

Let’s invoke RMAN prompt.

[oracle@dbnode1 dbs]$ rman target/

Recovery Manager: Release 12.1.0.2.0 - Production on Sun Sep 23 17:34:25 2018

Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved.

connected to target database: DEMTEST (DBID=1537672932, not open)

Fire backup as copy command.

RMAN> backup as copy database format '+DATA';

Starting backup at 23-SEP-18
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=16 device type=DISK
channel ORA_DISK_1: starting datafile copy
input datafile file number=00001 name=/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_system_ftgqqt14_.dbf
output file name=+DATA/DEMTEST/DATAFILE/system.283.987615079 tag=TAG20180923T173118 RECID=1 STAMP=987615117
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:45
channel ORA_DISK_1: starting datafile copy
input datafile file number=00003 name=/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_sysaux_ftgqoro6_.dbf
output file name=+DATA/DEMTEST/DATAFILE/sysaux.284.987615125 tag=TAG20180923T173118 RECID=2 STAMP=987615150
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:35
channel ORA_DISK_1: starting datafile copy
input datafile file number=00004 name=/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_undotbs1_ftgqtjo8_.dbf
output file name=+DATA/DEMTEST/DATAFILE/undotbs1.285.987615159 tag=TAG20180923T173118 RECID=3 STAMP=987615162
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07
channel ORA_DISK_1: starting datafile copy
copying current control file
output file name=+DATA/DEMTEST/CONTROLFILE/backup.286.987615167 tag=TAG20180923T173118 RECID=4 STAMP=987615169
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:03
channel ORA_DISK_1: starting datafile copy
input datafile file number=00006 name=/u01/app/oracle/oradata/DEMTEST/datafile/o1_mf_users_ftgqthfw_.dbf
output file name=+DATA/DEMTEST/DATAFILE/users.287.987615171 tag=TAG20180923T173118 RECID=5 STAMP=987615170
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 23-SEP-18
channel ORA_DISK_1: finished piece 1 at 23-SEP-18
piece handle=+DATA/DEMTEST/BACKUPSET/2018_09_23/nnsnf0_tag20180923t173118_0.288.987615171 tag=TAG20180923T173118 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01

Now switch the database to copy.

RMAN> switch database to copy;

datafile 1 switched to datafile copy "+DATA/DEMTEST/DATAFILE/system.283.987615079"
datafile 3 switched to datafile copy "+DATA/DEMTEST/DATAFILE/sysaux.284.987615125"
datafile 4 switched to datafile copy "+DATA/DEMTEST/DATAFILE/undotbs1.285.987615159"
datafile 6 switched to datafile copy "+DATA/DEMTEST/DATAFILE/users.287.987615171"
  • Let’s migrate the templfile to ASM using RMAN run job. Make sure database is mounted.

Invoke RMAN.

[oracle@dbnode1 ~]$ rman target/

Recovery Manager: Release 12.1.0.2.0 - Production on Sun Sep 23 18:12:36 2018

Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved.

connected to target database: DEMTEST (DBID=1537672932, not open)

Run job command to set new name for Tempfile.

RMAN>run
{
set newname for tempfile '/u01/data/learndb/temp01.dbf' to '+DATA';
switch tempfile all;
}

executing command: SET NEWNAME

using target database control file instead of recovery catalog
renamed tempfile 1 to +DATA in control file
  • Now open the database and check new locations for datafiles and tempfile.
SQL> select FILE_NAME from dba_data_files;

FILE_NAME
------------------------------------------------
+DATA/DEMTEST/DATAFILE/users.287.987615171
+DATA/DEMTEST/DATAFILE/undotbs1.285.987615159
+DATA/DEMTEST/DATAFILE/system.283.987615079
+DATA/DEMTEST/DATAFILE/sysaux.284.987615125

4 rows selected.

SQL> select name from v$tempfile;

NAME
------------------------------------------------
+DATA/DEMTEST/TEMPFILE/temp.289.987617849

We’re done with datafiles and tempfile as well, Now we’re left with Redo Logfile only.

  • Let’s add log members at new location, in ASM.

Let’s check available logfile and their path and status.

SQL> SELECT a.group#, b.member, a.status FROM v$log a, v$logfile b WHERE a.group#=b.group#;

GROUP#  MEMBER                                                                       STATUS
------- ---------------------------------------------------------------------------  ----------
     3   /u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_3_ftgqwfrs_.log             INACTIVE
     3   /u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log  INACTIVE
     2   /u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_2_ftgqwb52_.log             CURRENT
     2   /u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_2_ftgqwbss_.log  CURRENT
     1   /u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_1_ftgqw68q_.log             INACTIVE
     1   /u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_1_ftgqw771_.log  INACTIVE

6 rows selected.

Add log members at new location, in ASM.

SQL> alter database add logfile member '+data' to group 1;

Database altered.

SQL> alter database add logfile member '+data' to group 2;

Database altered.

SQL> alter database add logfile member '+data' to group 3;

Database altered.

SQL> alter database add logfile member '+fra' to group 1;

Database altered.

SQL> alter database add logfile member '+fra' to group 2;

Database altered.

SQL> alter database add logfile member '+fra' to group 3;

Database altered.

Let’s check if logfile are added to new location.

SQL> SELECT a.group#, b.member, a.status FROM v$log a, v$logfile b WHERE a.group#=b.group#;

GROUP#   MEMBER                                                                         STATUS
-------  ------------------------------------------------------------------------------ ----------
      3  /u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_3_ftgqwfrs_.log                INACTIVE
      3  /u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log     INACTIVE
      2  /u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_2_ftgqwb52_.log                CURRENT
      2  /u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_2_ftgqwbss_.log     CURRENT
      1  /u01/app/oracle/oradata/DEMTEST/onlinelog/o1_mf_1_ftgqw68q_.log                INACTIVE
      1  /u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_1_ftgqw771_.log     INACTIVE
      1  +DATA/DEMTEST/ONLINELOG/group_1.290.987618533                                  INACTIVE
      2  +DATA/DEMTEST/ONLINELOG/group_2.291.987618543                                  CURRENT
      3  +DATA/DEMTEST/ONLINELOG/group_3.292.987618549                                  INACTIVE
      1  +FRA/DEMTEST/ONLINELOG/group_1.261.987618569                                   INACTIVE
      2  +FRA/DEMTEST/ONLINELOG/group_2.262.987618577                                   CURRENT
      3  +FRA/DEMTEST/ONLINELOG/group_3.263.987618581                                   INACTIVE

12 rows selected.

They’re added, now let’s drop old logfiles from file system.

To drop logfile member, Status should not be in current mode.

SQL> ALTER DATABASE DROP LOGFILE MEMBER '/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log';
ALTER DATABASE DROP LOGFILE MEMBER '/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log'
*
ERROR at line 1:
ORA-01609: log 3 is the current log for thread 1 - cannot drop members
ORA-00312: online log 3 thread 1:
'/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log'
ORA-00312: online log 3 thread 1: '+DATA/DEMTEST/ONLINELOG/group_3.292.987618549'
ORA-00312: online log 3 thread 1: '+FRA/DEMTEST/ONLINELOG/group_3.263.987618581'

Let’s drop active and inactive members from each group.

There should be at least one logfile each group to delete old member.

SQL> ALTER DATABASE DROP LOGFILE MEMBER '/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log';
ALTER DATABASE DROP LOGFILE MEMBER '/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log'
*
ERROR at line 1:
ORA-00362: member is required to form a valid logfile in group 3
ORA-01517: log member: '/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log'

Perform switch logfile to switch them to ASM member so that member from file system can be dropped.

SQL> alter system switch logfile;

System altered.

Now try to drop.

SQL> ALTER DATABASE DROP LOGFILE MEMBER '/u01/app/oracle/fast_recovery_area/DEMTEST/onlinelog/o1_mf_3_ftgqwgnj_.log';

Database altered.

Once you’re done with dropping all members from each group, verify the location of new members in each group.

SQL> SELECT a.group#, b.member, a.status FROM v$log a, v$logfile b WHERE a.group#=b.group#;

GROUP#     MEMBER                                            STATUS
---------- ------------------------------------------------- ----------
         1 +DATA/DEMTEST/ONLINELOG/group_1.290.987618533     ACTIVE
         2 +DATA/DEMTEST/ONLINELOG/group_2.291.987618543     ACTIVE
         3 +DATA/DEMTEST/ONLINELOG/group_3.292.987618549     CURRENT
         1 +FRA/DEMTEST/ONLINELOG/group_1.261.987618569      ACTIVE
         2 +FRA/DEMTEST/ONLINELOG/group_2.262.987618577      ACTIVE
         3 +FRA/DEMTEST/ONLINELOG/group_3.263.987618581      CURRENT

6 rows selected.

We’re done with migrating logfiles as well. So with this step, our database is now successfully migrated from File System to Oracle ASM.

 

Peace 🙂

1 thought on “Migrating Oracle Database 12cR1 from File System to ASM using RMAN

Comments are closed.