Database Migration to ASM with short downtime

See how to migrate to ASM with the downtime it takes only to shutdown and restart the instance – in other words, the downtime will be in the range of only minutes on a production system. The example is done on a small Linux server using Oracle Database Enterprise Edition 11.2.0.2, but should work very similar on other platforms and with the 10g version as well.

SQL> select * from v$version;

BANNER
----------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - 64bit Production
PL/SQL Release 11.2.0.2.0 - Production
CORE    11.2.0.2.0      Production
TNS for Linux: Version 11.2.0.2.0 - Production
NLSRTL Version 11.2.0.2.0 - Production

SQL> select log_mode from v$database;

LOG_MODE
------------
ARCHIVELOG
SQL> select name from v$datafile union select name from v$tempfile;

NAME
---------------------------------
/home/oracle/prima/sysaux01.dbf
/home/oracle/prima/system01.dbf
/home/oracle/prima/temp01.dbt
/home/oracle/prima/undotbs01.dbf
/home/oracle/prima/users01.dbf

SQL> select name from v$controlfile;

NAME
--------------------------------
/home/oracle/prima/control01.ctl

SQL> select member from v$logfile;

MEMBER
-------------------------------
/home/oracle/prima/log_g1m1.rdo
/home/oracle/prima/log_g2m1.rdo

This is my standard demo Database. I have installed already Grid Infrastructure (Marketing name for the combination of Oracle Restart & ASM) for a standalone server. Also, I have already prepared 16 fake ‚Raw Devices‘, each of 250m in size. Yes, my system is tiny – it’s my notebook. Continuing to start the ASM instance and then create the two recommended diskgroups DATA and FRA. We have the option to use the comfortable GUI asmca (11g New Feature, it can also create  quorum failgroups meanwhile) or go with the command line:

[oracle@uhesse-pc ~]$ cat /u01/app/11.2.0/grid/dbs/init+ASM.ora
#init+ASM.ora

instance_type='asm'
asm_diskstring='/dev/raw/raw*'
remote_login_passwordfile='EXCLUSIVE'
diagnostic_dest='/u01/app/oracle/'
asm_diskgroups=data,fra

After connecting to the ASM instance and startup , which will produce an error message, because data and fra do not exist yet, we create them like this:

SQL> CREATE DISKGROUP data NORMAL REDUNDANCY
 FAILGROUP fg1 DISK
 '/dev/raw/raw1' NAME disk01,
 '/dev/raw/raw2' NAME disk02,
 '/dev/raw/raw3' NAME disk03,
 '/dev/raw/raw4' NAME disk04
 FAILGROUP fg2 DISK
 '/dev/raw/raw5' NAME disk05,
 '/dev/raw/raw6' NAME disk06,
 '/dev/raw/raw7' NAME disk07,
 '/dev/raw/raw8' NAME disk08;

Each file, placed on DATA will be mirrored across the fg1 and fg2 on the stripe layer. All drives in fg1 or in fg2 could fail without losing data.

SQL> CREATE DISKGROUP fra EXTERNAL REDUNDANCY
 DISK
 '/dev/raw/raw9'  NAME disk09,
 '/dev/raw/raw10' NAME disk10,
 '/dev/raw/raw11' NAME disk11,
 '/dev/raw/raw12' NAME disk12,
 '/dev/raw/raw13' NAME disk13,
 '/dev/raw/raw14' NAME disk14,
 '/dev/raw/raw15' NAME disk15,
 '/dev/raw/raw16' NAME disk16;

FRA has no redundancy – should one drive fail we would lose all data on FRA. Next is an Online Backup with Image Copies to the DATA diskgroup. No downtime involved.

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

Starting backup at 01-DEC-10
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=19 device type=DISK
channel ORA_DISK_1: starting datafile copy
input datafile file number=00001 name=/home/oracle/prima/system01.dbf
output file name=+DATA/prima/datafile/system.256.736599607 tag=TAG20101201T110002 RECID=1 STAMP=736599624
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile copy
input datafile file number=00002 name=/home/oracle/prima/sysaux01.dbf
output file name=+DATA/prima/datafile/sysaux.257.736599629 tag=TAG20101201T110002 RECID=2 STAMP=736599634
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07
channel ORA_DISK_1: starting datafile copy
input datafile file number=00003 name=/home/oracle/prima/undotbs01.dbf
output file name=+DATA/prima/datafile/undotbs1.258.736599641 tag=TAG20101201T110002 RECID=3 STAMP=736599646
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:15
channel ORA_DISK_1: starting datafile copy
input datafile file number=00004 name=/home/oracle/prima/users01.dbf
output file name=+DATA/prima/datafile/users.259.736599655 tag=TAG20101201T110002 RECID=4 STAMP=736599655
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
channel ORA_DISK_1: starting datafile copy
copying current control file
output file name=+DATA/prima/controlfile/backup.260.736599657 tag=TAG20101201T110002 RECID=5 STAMP=736599662
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07
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 01-DEC-10
channel ORA_DISK_1: finished piece 1 at 01-DEC-10
piece handle=+DATA/prima/backupset/2010_12_01/nnsnf0_tag20101201t110002_0.261.736599665 tag=TAG20101201T110002 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:07
Finished backup at 01-DEC-10

Now we change some dynamic parameters to point to the new Database resp. Recovery Area:

SQL> alter system set db_recovery_file_dest_size=1800m;

System altered.

SQL> alter system set db_recovery_file_dest='+FRA';

System altered.

SQL> alter system set db_create_file_dest='+DATA';

System altered.

Archivelogs will now be created into FRA. We also put our spfile there. The ‚from memory‘ clause is an 11g New Feature.

SQL> create spfile='+DATA/spfileprima.ora' from memory;
 
 File created.

We remove our spfile from $ORACLE_HOME/dbs and replace it with a pointer to the new spfile:

SQL> host cat /u01/app/oracle/product/11.2.0/dbhome_1/dbs/initprima.ora
spfile='+DATA/spfileprima.ora'

Attention: Now we need to shutdown and restart the productive instance and have a short downtime:

SQL> startup force nomount

ORACLE instance started.

Total System Global Area  417546240 bytes
Fixed Size                  2227072 bytes
Variable Size             352322688 bytes
Database Buffers           54525952 bytes
Redo Buffers                8470528 bytes

The controlfiles should also be (mirrored) on ASM. Therefore:

SQL> alter system set control_files='+DATA','+FRA' scope=spfile;

System altered.

Restart to make the modified CONTROL_FILES parameter active:

SQL> startup force nomount
ORACLE instance started.

Total System Global Area  417546240 bytes
Fixed Size                  2227072 bytes
Variable Size             352322688 bytes
Database Buffers           54525952 bytes
Redo Buffers                8470528 bytes

We only need to restore controlfiles to the new location, switch to the new datafiles on DATA and recover the latest changes that where done since the online backup:

[oracle@uhesse-pc ~]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Wed Dec 1 11:13:33 2010

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

connected to target database: PRIMA (not mounted)

RMAN> restore controlfile from '/home/oracle/prima/control01.ctl';

Starting restore at 01-DEC-10
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=99 device type=DISK

channel ORA_DISK_1: copied control file copy
output file name=+DATA/prima/controlfile/current.263.736600443
output file name=+FRA/prima/controlfile/current.256.736600443
Finished restore at 01-DEC-10

RMAN> alter database mount;

database mounted
released channel: ORA_DISK_1

RMAN> switch database to copy;

datafile 1 switched to datafile copy "+DATA/prima/datafile/system.256.736599607"
datafile 2 switched to datafile copy "+DATA/prima/datafile/sysaux.257.736599629"
datafile 3 switched to datafile copy "+DATA/prima/datafile/undotbs1.258.736599641"
datafile 4 switched to datafile copy "+DATA/prima/datafile/users.259.736599655"

RMAN> recover database;

Starting recover at 01-DEC-10
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=99 device type=DISK

starting media recovery
media recovery complete, elapsed time: 00:00:01

Finished recover at 01-DEC-10

RMAN> alter database open;

Downtime is over! End users can connect while we do some additional work:

SQL> select name from v$datafile union select name from v$tempfile;

NAME
--------------------------------------------------------------------------------
+DATA/prima/datafile/sysaux.257.736599629
+DATA/prima/datafile/system.256.736599607
+DATA/prima/datafile/undotbs1.258.736599641
+DATA/prima/datafile/users.259.736599655
/home/oracle/prima/temp01.dbt

The tempfile was not touched by RMAN during the backup or switch to copy. We need to do that manually:

SQL> alter database  tempfile '/home/oracle/prima/temp01.dbt' drop;

Database altered.

SQL> alter tablespace temp add tempfile size 50m;

Tablespace altered.

SQL> select name from v$datafile union select name from v$tempfile;

NAME
--------------------------------------------------------------------------------
+DATA/prima/datafile/sysaux.257.736599629
+DATA/prima/datafile/system.256.736599607
+DATA/prima/datafile/undotbs1.258.736599641
+DATA/prima/datafile/users.259.736599655
+DATA/prima/tempfile/temp.264.736600915

Everything nice. But our Online Logs are still on the filesystem:

SQL> select member from v$logfile;

MEMBER
-----------------------------------
/home/oracle/prima/log_g1m1.rdo
/home/oracle/prima/log_g2m1.rdo

This can also be fixed online:

SQL> alter database add logfile size 20m;
 
 Database altered.
 
 SQL> alter database add logfile size 20m;
 
 Database altered.

Gave us two new groups mirrored across DATA and FRA. Now we drop the old groups:

SQL> alter system switch logfile;
 
 System altered.
 
 SQL> alter system switch logfile;
 
 System altered.
 
 SQL> alter system checkpoint;
 
 System altered.
 
 SQL> alter database drop logfile group 1;
 
 Database altered.
 
 SQL> alter database drop logfile group 2;
 
 Database altered.
 
 SQL> select member from v$logfile;
 
 MEMBER
 --------------------------------------------------------------------------------
 +DATA/prima/onlinelog/group_3.264.736612757
 +FRA/prima/onlinelog/group_3.257.736612759
 +DATA/prima/onlinelog/group_4.265.736612765
 +FRA/prima/onlinelog/group_4.258.736612769

That was it. We may now do a backup of the database to FRA:

RMAN> backup database;

Starting backup at 01-DEC-10
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=105 device type=DISK
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00001 name=+DATA/prima/datafile/system.256.736608851
input datafile file number=00002 name=+DATA/prima/datafile/sysaux.257.736608873
input datafile file number=00003 name=+DATA/prima/datafile/undotbs1.258.736608885
input datafile file number=00004 name=+DATA/prima/datafile/users.259.736608899
channel ORA_DISK_1: starting piece 1 at 01-DEC-10
channel ORA_DISK_1: finished piece 1 at 01-DEC-10
piece handle=+FRA/prima/backupset/2010_12_01/nnndf0_tag20101201t145715_0.259.736613837 tag=TAG20101201T145715 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:16
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current control file in backup set
including current SPFILE in backup set
channel ORA_DISK_1: starting piece 1 at 01-DEC-10
channel ORA_DISK_1: finished piece 1 at 01-DEC-10
piece handle=+FRA/prima/backupset/2010_12_01/ncsnf0_tag20101201t145715_0.260.736613853 tag=TAG20101201T145715 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 01-DEC-10

Conclusion: It is relatively simple and only needs a short downtime to migrate your Database to ASM, mainly the process is an RMAN Online Backup with Image Copies.

Addendum: See here for a recent example by Pete Sharman about using Enterprise Manager 12c to do an ASM Migration.

, ,

  1. #1 von Tom Cullen am Februar 25, 2011 - 15:01

    Hi Uwe, Very informative post! Would this same approach work if the database was migrated to ASM and a new server at the same time? On old server backup as copy to FRA on disk, backup FRA to tape, restore to ASM DATA DG on new server, switch database to copy, recover db?
    Any feedback is appreciated!
    Thanks, Tom Cullen Senior DBA 11gR2 OCP

  2. #2 von Uwe Hesse am März 14, 2011 - 17:00

    Hi Tom,
    yes I think so. Should work similar, but I haven’t done it yet. Would be nice if you could share how you did it after you did 🙂

  3. #3 von Akshaya am November 8, 2011 - 15:50

    Hi Uwe

    Nice post.Ca you update this post with an example with solaris 10 sparc or x86 .

    It will be highly appreciated.

    Akshaya

  4. #4 von Uwe Hesse am November 9, 2011 - 12:45

    Hi Akshaya,

    thanks for your comment! I am very busy these days, unfortunately, so I cannot cover solaris topics. It should work in the same way, though, if your target database on solaris OS uses ASM.

  5. #5 von Pablo Laborde am November 25, 2011 - 20:30

    Hi Uve

    Excelent step-by-step guide to move to ASM…..short and clear.
    I wonder if you can cover the situation of doing this with 1 primary and 2 stby instances with FSFO and with the idea of not recreate the stby’s due to this change.
    TIA
    Pablo

  6. #6 von Uwe Hesse am November 28, 2011 - 17:12

    Pablo,

    thank you for the nice feedback! To your question: You can make use of Data Guard to minimize the downtime it takes to migrate to ASM. This is described here, e.g.

    Klicke, um auf maa-wp-10gr2-asmmigrationwithdg-133513.pdf zuzugreifen

    In this case, you do not recreate your Standby DB, but you migrate it to ASM, similar as described in the posting for a Standalone DB.

  7. #7 von Chaitra am September 15, 2012 - 17:11

    Very nice explanation

  8. #8 von Uwe Hesse am September 17, 2012 - 11:03

    Thank you, Chaitra, much appreciated!

  9. #9 von Razvan am April 5, 2013 - 09:33

    Hello Uve,
    Very nice article.

    I have one question : we have a single instance database running on a server ( file system based storage ) and we want to convert to RAC ( asm storage ).
    We want to convert first the instance to ASM storage ( following the steps described in this article ) and then manually convert single instance to RAC.

    The question is : When I install GRID I should/must choose Single Instance or I can directly use RAC databases options , even if as the first step the database will be ran as single instance and only after that converted to RAC ?

    Thank you,
    Razvan.

  10. #10 von Uwe Hesse am April 8, 2013 - 08:26

    Hi Razvan, that should work just fine: Installing Grid Infrastructure for a Cluster and migrate a Single Instance upon it, I mean. See here for a description: http://docs.oracle.com/cd/E11882_01/install.112/e24660/cvrt2rac.htm Notice especially C.2.1.2 Complete Oracle Clusterware Installation (that’s what you plan to do)

  11. #11 von Amol am September 24, 2013 - 10:01

    Thanks for this wonderful walk through for migration to ASM. I could follow the steps and migrate our database to ASM successfuflly.

    Regards,
    Amol.

  12. #12 von Uwe Hesse am September 30, 2013 - 14:21

    Amol, I really do appreciate that you took the time to share your positive experience 🙂

  13. #13 von Jamal Khan am Oktober 7, 2014 - 12:43

    This article is simple and clear 🙂

  14. #14 von Fanni am April 12, 2019 - 15:35

    Can any one guide me for window server step to migrate standalone data base to ASM.

  1. articles

Hinterlasse einen Kommentar

Diese Seite verwendet Akismet, um Spam zu reduzieren. Erfahre, wie deine Kommentardaten verarbeitet werden..