Pages

Friday 16 December 2011

Migrating an Oracle database from non-ASM to ASM


 By Sangamesh B Satihal, Oracle DBA

We can configure an ASM using DBCA or manually. Once the ASM is configured on the server and diskgroup is created, any database that resides on that server can start using ASM for its data storage. We can achieve this by migrating all datafiles, controlfiles, redolog files, archive logs and, if required, parameter files to ASM.

Use the following steps to migrate an existing Oracle database from a local file system to ASM. These steps are applicable for both 10g and 11g releases.

1. In this example, we will use MYASMDB database to migrate from file system to ASM. Get the details of all files of the database MYASMDB as below. All of the files listed in this query will be relocated from the local file system to ASM:

#> . oraenv
ORACLE_SID = [oracle] ? MYASMDB
The Oracle base for ORACLE_HOME=/orasw/app/oracle/product/11_2_0_2 is /orasw/app/oracle
#= Testing Env =oracle@sangam /var/opt/oracle
#> sqlplus '/as sysdba'

SQL*Plus: Release 11.2.0.2.0 Production on Wed Dec 7 05:10:09 2011

Copyright (c) 1982, 2010, Oracle.  All rights reserved.

Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL> SQL> SELECT
  2      d.tablespace_name                     tablespace
  3    , d.file_name                           filename
  4    , d.bytes                               filesize
  5    , d.autoextensible                      autoextensible
  , d.increment_by * e.value              increment_by
  6    7    , d.maxbytes                            maxbytes
  8  FROM
  9      sys.dba_data_files d
 10    , v$datafile v
 11    , (SELECT value
 12       FROM v$parameter
 13       WHERE name = 'db_block_size') e
 14  WHERE
 15    (d.file_name = v.name)
 16  UNION
 17  SELECT
 18      d.tablespace_name                     tablespace
 19    , d.file_name                           filename
 20    , d.bytes                               filesize
 21    , d.autoextensible                      autoextensible
 22    , d.increment_by * e.value              increment_by
 23    , d.maxbytes                            maxbytes
 24  FROM
    sys.dba_temp_files d
 25   26    , (SELECT value
 27       FROM v$parameter
 28       WHERE name = 'db_block_size') e
 29  UNION
 30  SELECT
 31      '[ ONLINE REDO LOG ]'
 32    , a.member
 33    , b.bytes
 34    , null
 35    , TO_NUMBER(null)
  , TO_NUMBER(null)
 36   37  FROM
 38      v$logfile a
 39    , v$log b
 40  WHERE
 41      a.group# = b.group#
 42  UNION
 43  SELECT
 44      '[ CONTROL FILE    ]'
 45    , a.name
 46    , TO_NUMBER(null)
 47    , null
 48    , TO_NUMBER(null)
 49    , TO_NUMBER(null)
 50  FROM
 51      v$controlfile a
 52  ORDER BY 1,2
/ 53

Tablespace Name / File Class  Filename                                                               File Size Auto            Next             Max
----------------------------- ---------------------------------------------------------------- --------------- ---- --------------- ---------------
CISTS_01                      /oradata_01/MYASMDB/cists01.dbf                                 536,870,912 YES        8,388,608  34,359,721,984
SYSAUX                        /oradata_01/MYASMDB/SYSAUX.dbf                                  188,743,680 YES       10,485,760  34,359,721,984
SYSTEM                        /oradata_01/MYASMDB/system01.dbf                                501,219,328 YES       10,485,760  34,359,721,984
TEMP                          /oradata_01/MYASMDB/temp01.dbf                                   67,108,864 YES        8,388,608  34,359,721,984
TOOLS                         /oradata_01/MYASMDB/tools01.dbf                                  67,108,864 YES        8,388,608  34,359,721,984
UNDOTBS1                      /oradata_01/MYASMDB/UNDOTBS1.dbf                                379,584,512 YES            8,192  34,359,721,984
USERS                         /oradata_01/MYASMDB/user01.dbf                                  536,870,912 YES        8,388,608  34,359,721,984
XMLDBTS_01                    /oradata_01/MYASMDB/xmldbts01.dbf                               536,870,912 YES        8,388,608  34,359,721,984
[ CONTROL FILE    ]           /oradata_01/MYASMDB/control01.ctl
[ CONTROL FILE    ]           /oradata_01/MYASMDB/control02.ctl
[ CONTROL FILE    ]           /oradata_01/MYASMDB/control03.ctl
[ ONLINE REDO LOG ]           /oradata_01/MYASMDB/redo01.log                                   10,485,760
[ ONLINE REDO LOG ]           /oradata_01/MYASMDB/redo02.log                                
[ ONLINE REDO LOG ]           /oradata_01/MYASMDB/redo03.log                                   10,485,760
                                                                                             

14 rows selected.

2. With the target database open, edit the initialization parameter control_files and db_create_file_dest to point to the ASM disk group + DATA.  Also configure db_recovery_file_dest to point to the ASM disk group +DATA as below.

SQL> ALTER SYSTEM SET control_files='+DATA' scope=spfile;
ALTER SYSTEM SET control_files='+DATA' scope=spfile
*
ERROR at line 1:
ORA-32001: write to SPFILE requested but no SPFILE is in use

Since DB was brought up with pfile so we got above error. Let us create spfile and bring up the database with spfile as blow.

SQL> shut immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> create spfile from pfile;

File created.

SQL> startup;
ORACLE instance started.

Total System Global Area 1603887104 bytes
Fixed Size                  2158744 bytes
Variable Size             419434344 bytes
Database Buffers         1174405120 bytes
Redo Buffers                7888896 bytes
Database mounted.
Database opened.
SQL>
SQL> ALTER SYSTEM SET control_files='+DATA' scope=spfile;

System altered.

SQL> ALTER SYSTEM SET db_create_file_dest='+DATA' scope=spfile;

System altered.

SQL> ALTER SYSTEM SET db_recovery_file_dest='+DATA' scope=spfile;

System altered.

3. Startup the target database in NOMOUNT mode:

SQL> SHUTDOWN IMMEDIATE;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup nomount;
ORACLE instance started.

Total System Global Area 1603887104 bytes
Fixed Size                  2158744 bytes
Variable Size             436211560 bytes
Database Buffers         1157627904 bytes
Redo Buffers                7888896 bytes
SQL> exit
Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
#= Testing Env =oracle@sangam /var/opt/oracle

4. From an RMAN session, copy one of your controlfiles from the local file system to its new location in ASM. The new controlfile will be copied to the value specified in the initialization parameter control_files

#> rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Wed Dec 7 05:25:46 2011

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

connected to target database: MYASMDB (not mounted)

RMAN> RESTORE CONTROLFILE FROM '/oradata_01/MYASMDB/control01.ctl';

Starting restore at 07-DEC-11
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=1345 device type=DISK

channel ORA_DISK_1: copied control file copy
output file name=+DATA/MYASMDB/controlfile/current.502.769238817
Finished restore at 07-DEC-11

5. From an RMAN or SQL*Plus session, mount the database. This will mount the database using the controlfile stored in ASM

RMAN> ALTER DATABASE MOUNT;

database mounted
released channel: ORA_DISK_1

6. From an RMAN session, copy the database files from the local file system to ASM

RMAN> BACKUP AS COPY DATABASE FORMAT '+DATA';

Starting backup at 07-DEC-11
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=1345 device type=DISK
channel ORA_DISK_1: starting datafile copy
input datafile file number=00005 name=/oradata_01/MYASMDB/cists01.dbf
output file name=+DATA/MYASMDB/datafile/cists_01.503.769238853 tag=TAG20111207T052733 RECID=1 STAMP=769238942
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:35
channel ORA_DISK_1: starting datafile copy
input datafile file number=00006 name=/oradata_01/MYASMDB/user01.dbf
output file name=+DATA/MYASMDB/datafile/users.504.769238949 tag=TAG20111207T052733 RECID=2 STAMP=769239026
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:25
channel ORA_DISK_1: starting datafile copy
input datafile file number=00007 name=/oradata_01/MYASMDB/xmldbts01.dbf
output file name=+DATA/MYASMDB/datafile/xmldbts_01.505.769239035 tag=TAG20111207T052733 RECID=3 STAMP=769239111
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:25
channel ORA_DISK_1: starting datafile copy
input datafile file number=00001 name=/oradata_01/MYASMDB/system01.dbf
output file name=+DATA/MYASMDB/datafile/system.506.769239119 tag=TAG20111207T052733 RECID=4 STAMP=769239191
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:15
channel ORA_DISK_1: starting datafile copy
input datafile file number=00003 name=/oradata_01/MYASMDB/UNDOTBS1.dbf
output file name=+DATA/MYASMDB/datafile/undotbs1.507.769239195 tag=TAG20111207T052733 RECID=5 STAMP=769239239
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:55
channel ORA_DISK_1: starting datafile copy
input datafile file number=00002 name=/oradata_01/MYASMDB/SYSAUX.dbf
output file name=+DATA/MYASMDB/datafile/sysaux.508.769239249 tag=TAG20111207T052733 RECID=6 STAMP=769239273
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile copy
input datafile file number=00004 name=/oradata_01/MYASMDB/tools01.dbf
output file name=+DATA/MYASMDB/datafile/tools.509.769239275 tag=TAG20111207T052733 RECID=7 STAMP=769239286
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:15
channel ORA_DISK_1: starting datafile copy
copying current control file
output file name=+DATA/MYASMDB/controlfile/backup.510.769239289 tag=TAG20111207T052733 RECID=8 STAMP=769239290
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 07-DEC-11
channel ORA_DISK_1: finished piece 1 at 07-DEC-11
piece handle=+DATA/MYASMDB/backupset/2011_12_07/nnsnf0_tag20111207t052733_0.511.769239291 tag=TAG20111207T052733 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 07-DEC-11



7. From an RMAN session, update the control file / data dictionary so that all database files point to the RMAN copy made in ASM

RMAN> SWITCH DATABASE TO COPY;

datafile 1 switched to datafile copy "+DATA/MYASMDB/datafile/system.506.769239119"
datafile 2 switched to datafile copy "+DATA/MYASMDB/datafile/sysaux.508.769239249"
datafile 3 switched to datafile copy "+DATA/MYASMDB/datafile/undotbs1.507.769239195"
datafile 4 switched to datafile copy "+DATA/MYASMDB/datafile/tools.509.769239275"
datafile 5 switched to datafile copy "+DATA/MYASMDB/datafile/cists_01.503.769238853"
datafile 6 switched to datafile copy "+DATA/MYASMDB/datafile/users.504.769238949"
datafile 7 switched to datafile copy "+DATA/MYASMDB/datafile/xmldbts_01.505.769239035"

RMAN> exit
Recovery Manager complete.
#= Testing Env =oracle@sangam /var/opt/oracle

8. From a SQL*Plus session, perform incomplete recovery and open the database using the RESETLOGS option

#> sqlplus '/as sysdba'

SQL*Plus: Release 11.2.0.2.0 Production on Wed Dec 7 05:35:40 2011

Copyright (c) 1982, 2010, Oracle.  All rights reserved.


Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - 64bit Production
With the Partitioning, Automatic Storage Management, OLAP, Data Mining
and Real Application Testing options

SQL> RECOVER DATABASE USING BACKUP CONTROLFILE UNTIL CANCEL;
ORA-00279: change 717263 generated at 12/07/2011 05:24:55 needed for thread 1
ORA-00289: suggestion : +DATA
ORA-15173: entry 'ARCHIVELOG' does not exist in directory 'MYASMDB'
ORA-00280: change 717263 for thread 1 is in sequence #177


Specify log: {<RET>=suggested | filename | AUTO | CANCEL}
cancel
Media recovery cancelled.
SQL> ALTER DATABASE OPEN RESETLOGS;

Database altered.

SQL> select name,status from v$database,v$instance;

NAME      STATUS
--------- ------------
MYASMDB  OPEN


9. From a SQL*Plus session, re-create any tempfiles that are still currently on the local file system to ASM. This is done by simply dropping the tempfiles from the local file system and re-creating them in ASM as below.
SQL> select tablespace_name, file_name, bytes from dba_temp_files;

TABLESPACE_NAME
------------------------------
FILE_NAME
--------------------------------------------------------------------------------
     BYTES
----------
TEMP
/oradata_01/MYASMDB/temp01.dbf
  67108864


SQL> alter database tempfile '/oradata_01/MYASMDB/temp01.dbf' drop including datafiles;

Database altered.

SQL> alter tablespace temp add tempfile size 512m;

Tablespace altered.

SQL> select tablespace_name, file_name, bytes from dba_temp_files;

TABLESPACE_NAME
------------------------------
FILE_NAME
--------------------------------------------------------------------------------
     BYTES
----------
TEMP
+DATA/MYASMDB/tempfile/temp.512.769239527
 536870912


10. From a SQL*Plus session, re-create any online redo logfiles that are still currently on the local file system to ASM. This is done by simply dropping the logfiles from the local file system and re-creating them in ASM as below.

Note : While dropping  redolog group, make sure that it is not current redolog  group.  If you do so, you will get error as
SQL> ALTER DATABASE DROP LOGFILE GROUP 1;
ALTER DATABASE DROP LOGFILE GROUP 1
*
ERROR at line 1:
ORA-01624: log 1 needed for crash recovery of instance MYASMDB (thread 1)
ORA-00312: online log 1 thread 1: '<file_name>'

It cab resolved by making that redogroup inactive by switching log file or by performing checkpoint on the database.

SQL> set linesize 500;
SQL> select a.group#, a.member, b.bytes from v$logfile a, v$log b where a.group# = b.group#;

    GROUP#
----------
MEMBER
--------------------------------------
     BYTES
----------
         1
/oradata_01/MYASMDB/redo01.log
  10485760

         2
/oradata_01/MYASMDB/redo02.log
  10485760

    GROUP#
----------
MEMBER

      BYTES
----------

         3
/oradata_01/MYASMDB/redo03.log
  10485760


SQL> set pagesize 500;
SQL> /

    GROUP#
----------
MEMBER

     BYTES
----------
         1
/oradata_01/MYASMDB/redo01.log
  10485760

         2
/oradata_01/MYASMDB/redo02.log
  10485760

         3
/oradata_01/MYASMDB/redo03.log
  10485760


SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 CURRENT
         2 UNUSED
         3 UNUSED

SQL> alter system switch logfile;

System altered.

SQL> /

System altered.

SQL> /

System altered.

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 CURRENT
         2 INACTIVE
         3 INACTIVE

SQL> alter system switch logfile;

System altered.

SQL> /

System altered.

SQL> select group#,status from v$log;

    GROUP# STATUS
---------- ----------------
         1 INACTIVE
         2 INACTIVE
         3 CURRENT

SQL> alter database drop logfile group 1;

Database altered.

SQL> alter database add logfile group 1 size 100m;

Database altered.

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 UNUSED
         2 INACTIVE
         3 CURRENT

SQL> alter database drop logfile group 2;

Database altered.

SQL> alter database add logfile group 2 size 100m;

Database altered.

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 UNUSED
         2 UNUSED
         3 CURRENT

SQL> alter system switch logfile;

System altered.

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 CURRENT
         2 UNUSED
         3 ACTIVE

SQL>  alter system switch logfile;

System altered.

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 ACTIVE
         2 CURRENT
         3 ACTIVE

SQL> alter system switch logfile;

System altered.

SQL>  select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 ACTIVE
         2 ACTIVE
         3 CURRENT

SQL> alter system switch logfile;
/
System altered.

SQL> /

System altered.

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 INACTIVE
         2 CURRENT
         3 INACTIVE

SQL> alter database drop logfile group 3;

Database altered.

SQL> alter database add logfile group 3 size 100m;

Database altered.

11. Verify that all online redo logfiles have been created in ASM

SQL> select a.group#, a.member, b.bytes from v$logfile a, v$log b where a.group# = b.group#;

    GROUP#
----------
MEMBER

     BYTES
----------
         1
+DATA/MYASMDB/onlinelog/group_1.513.769239709
 104857600

         2
+DATA/MYASMDB/onlinelog/group_2.515.769239751
 104857600

         3
+DATA/MYASMDB/onlinelog/group_3.517.769239855
 104857600

         1
+DATA/MYASMDB/onlinelog/group_1.514.769239709
 104857600

         2
+DATA/MYASMDB/onlinelog/group_2.516.769239751
 104857600

         3
+DATA/MYASMDB/onlinelog/group_3.518.769239855
 104857600


6 rows selected.

12. Perform the below steps to relocate the SPFILE from the local file system to an ASM disk group.

SQL> create pfile from spfile;

File created.

SQL> CREATE SPFILE='+DATA/MYASMDB/spfileMYASMDB.ora' from pfile;

File created.

SQL> SHUTDOWN IMMEDIATE;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup;
ORACLE instance started.

Total System Global Area 1603887104 bytes
Fixed Size                  2158744 bytes
Variable Size             452988776 bytes
Database Buffers         1140850688 bytes
Redo Buffers                7888896 bytes
Database mounted.
Database opened.

13. Verify that all database files have been created in ASM

SQL>
SQL> SELECT
  2      d.tablespace_name                     tablespace
  3    , d.file_name                           filename
  4    , d.bytes                               filesize
  5    , d.autoextensible                      autoextensible
  6    , d.increment_by * e.value              increment_by
  7    , d.maxbytes                            maxbytes
  8  FROM
  9      sys.dba_data_files d
 10    , v$datafile v
 11    , (SELECT value
 12       FROM v$parameter
 13       WHERE name = 'db_block_size') e
 14  WHERE
 15    (d.file_name = v.name)
UNION
 16   17  SELECT
 18      d.tablespace_name                     tablespace
 19    , d.file_name                           filename
  , d.bytes                               filesize
 20   21    , d.autoextensible                      autoextensible
 22    , d.increment_by * e.value              increment_by
 23    , d.maxbytes                            maxbytes
 24  FROM
 25      sys.dba_temp_files d
 26    , (SELECT value
 27       FROM v$parameter
 28       WHERE name = 'db_block_size') e
 29  UNION
 30  SELECT
 31      '[ ONLINE REDO LOG ]'
 32    , a.member
 33    , b.bytes
 34    , null
 35    , TO_NUMBER(null)
 36    , TO_NUMBER(null)
 37  FROM
 38      v$logfile a
 39    , v$log b
 40  WHERE
 41      a.group# = b.group#
 42  UNION
SELECT
 43   44      '[ CONTROL FILE    ]'
 45    , a.name
 46    , TO_NUMBER(null)
 47    , null
 48    , TO_NUMBER(null)
 49    , TO_NUMBER(null)
 50  FROM
 51      v$controlfile a
 52  ORDER BY 1,2
 53  /

Tablespace Name / File Class  Filename                                                               File Size Auto            Next             Max
----------------------------- ---------------------------------------------------------------- --------------- ---- --------------- ---------------
CISTS_01                      +DATA/MYASMDB/datafile/cists_01.503.769238853                       536,870,912 YES        8,388,608  34,359,721,984
SYSAUX                        +DATA/MYASMDB/datafile/sysaux.508.769239249                         188,743,680 YES       10,485,760  34,359,721,984
SYSTEM                        +DATA/MYASMDB/datafile/system.506.769239119                         501,219,328 YES       10,485,760  34,359,721,984
TEMP                          +DATA/MYASMDB/tempfile/temp.512.769239527                           536,870,912 YES      262,144,000  34,359,721,984
TOOLS                         +DATA/MYASMDB/datafile/tools.509.769239275                           67,108,864 YES        8,388,608  34,359,721,984
UNDOTBS1                      +DATA/MYASMDB/datafile/undotbs1.507.769239195                       379,584,512 YES            8,192  34,359,721,984
USERS                         +DATA/MYASMDB/datafile/users.504.769238949                          536,870,912 YES        8,388,608  34,359,721,984
XMLDBTS_01                    +DATA/MYASMDB/datafile/xmldbts_01.505.769239035                     536,870,912 YES        8,388,608  34,359,721,984
[ CONTROL FILE    ]           +DATA/MYASMDB/controlfile/current.502.769238817
[ ONLINE REDO LOG ]           +DATA/MYASMDB/onlinelog/group_1.513.769239709                       104,857,600
[ ONLINE REDO LOG ]           +DATA/MYASMDB/onlinelog/group_1.514.769239709                       104,857,600
[ ONLINE REDO LOG ]           +DATA/MYASMDB/onlinelog/group_2.515.769239751                       104,857,600
[ ONLINE REDO LOG ]           +DATA/MYASMDB/onlinelog/group_2.516.769239751                       104,857,600
[ ONLINE REDO LOG ]           +DATA/MYASMDB/onlinelog/group_3.517.769239855                       104,857,600
[ ONLINE REDO LOG ]           +DATA/MYASMDB/onlinelog/group_3.518.769239855                       104,857,600
                                                                                             
15 rows selected.

14. At this point, the target database(MYASMDB) is open with all of its datafiles, controlfiles, online redo logfiles, tempfiles, and SPFILE stored in ASM. If we want to remove the database files that were stored on the local file system , this can be done from an RMAN session by executing below command. You could also then remove the old version of the controfile(s) that were stored on the local file system. All local file system files can be removed manually also.

RMAN> DELETE NOPROMPT FORCE COPY;





No comments:

Post a Comment