Visit Counter

Tuesday, September 20, 2016

Migrate from Non-ASM to ASM Oracle 12c Database



SQL> conn / as sysdba
Connected.
SQL> select status from v$instance;

STATUS
------------
OPEN

SQL> select name from v$datafile;

NAME
--------------------------------------------------------------------------------
/ora/app/oracle/oradata/oratest/system01.dbf
/ora/app/oracle/oradata/oratest/sysaux01.dbf
/ora/app/oracle/oradata/oratest/undotbs01.dbf
/ora/app/oracle/oradata/oratest/pdbseed/system01.dbf
/ora/app/oracle/oradata/oratest/users01.dbf
/ora/app/oracle/oradata/oratest/pdbseed/sysaux01.dbf
/ora/app/oracle/oradata/oratest/poratest/system01.dbf
/ora/app/oracle/oradata/oratest/poratest/sysaux01.dbf
/ora/app/oracle/oradata/oratest/poratest/poratest_users01.dbf

9 rows selected.

SQL> select name from v$controlfile;

NAME
--------------------------------------------------------------------------------
/ora/app/oracle/oradata/oratest/control01.ctl
/ora/app/oracle/fast_recovery_area/oratest/control02.ctl

SQL> select member from v$logfile;

MEMBER
--------------------------------------------------------------------------------
/ora/app/oracle/oradata/oratest/redo03.log
/ora/app/oracle/oradata/oratest/redo02.log
/ora/app/oracle/oradata/oratest/redo01.log

SQL>




SQL>
SQL> show parameter db_reco

NAME     TYPE VALUE
------------------------------------ ----------- ------------------------------
db_recovery_file_dest     string /ora/app/oracle/fast_recovery_
area
db_recovery_file_dest_size     big integer 4800M
SQL>              
SQL>
SQL>
SQL>
SQL> show parameter db_create_file

NAME     TYPE VALUE
------------------------------------ ----------- ------------------------------
db_create_file_dest     string
SQL>    
SQL>
SQL>
SQL>
SQL>
SQL> show parameter control

NAME     TYPE VALUE
------------------------------------ ----------- ------------------------------
control_file_record_keep_time     integer 7
control_files     string /ora/app/oracle/oradata/orates
t/control01.ctl, /ora/app/orac
le/fast_recovery_area/oratest/
control02.ctl
control_management_pack_access     string DIAGNOSTIC+TUNING
SQL>
SQL>
SQL>
SQL>
SQL> archive log list
Database log mode       Archive Mode
Automatic archival       Enabled
Archive destination       /ora/app/oratestarch1/
Oldest online log sequence     4
Next log sequence to archive   6
Current log sequence       6
SQL>

SQL> show parameter control_files

NAME     TYPE VALUE
------------------------------------ ----------- ------------------------------
control_files     string /ora/app/oracle/oradata/orates
t/control01.ctl, /ora/app/orac
le/fast_recovery_area/oratest/
control02.ctl
SQL>







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

System altered.

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

System altered.

SQL> show parameter control_files

NAME     TYPE VALUE
------------------------------------ ----------- ------------------------------
control_files     string /ora/app/oracle/oradata/orates
t/control01.ctl, /ora/app/orac
le/fast_recovery_area/oratest/
control02.ctl
SQL> show parameter db_create_file_dest

NAME     TYPE VALUE
------------------------------------ ----------- ------------------------------
db_create_file_dest     string +DATA
SQL>


[oracle@rac01 bin]$ ./rman target /

Recovery Manager: Release 12.1.0.1.0 - Production on Tue Sep 27 00:34:44 2016

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

connected to target database: ORATEST (DBID=3458553188)

RMAN> backup current controlfile format '/ora/app/control.ctl';

Starting backup at 27-SEP-16
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=78 device type=DISK
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
channel ORA_DISK_1: starting piece 1 at 27-SEP-16
channel ORA_DISK_1: finished piece 1 at 27-SEP-16
piece handle=/ora/app/control.ctl tag=TAG20160927T003813 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:04
Finished backup at 27-SEP-16

Starting Control File and SPFILE Autobackup at 27-SEP-16
piece handle=/ora/app/oracle/fast_recovery_area/ORATEST/autobackup/2016_09_27/o1_mf_s_923618301_cym5bh20_.bkp comment=NONE
Finished Control File and SPFILE Autobackup at 27-SEP-16

RMAN>




RMAN> shutdown immediate;

database closed
database dismounted
Oracle instance shut down



RMAN> startup nomount

connected to target database (not started)
Oracle instance started

Total System Global Area     597098496 bytes

Fixed Size                     2291136 bytes
Variable Size                289409600 bytes
Database Buffers             301989888 bytes
Redo Buffers                   3407872 bytes

RMAN> restore controlfile from '/ora/app/control.ctl';

Starting restore at 27-SEP-16
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=32 device type=DISK

channel ORA_DISK_1: restoring control file
channel ORA_DISK_1: restore complete, elapsed time: 00:00:26
output file name=+DATA/ORATEST/CONTROLFILE/current.282.923618939
Finished restore at 27-SEP-16

RMAN>



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

Starting backup at 27-SEP-16
Starting implicit crosscheck backup at 27-SEP-16
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=32 device type=DISK
Crosschecked 1 objects
Finished implicit crosscheck

backup at 27-SEP-16

Starting implicit crosscheck copy at 27-SEP-16
using channel ORA_DISK_1
Finished implicit crosscheck copy at 27-SEP-16

searching for all files in the recovery area
cataloging files...
cataloging done

List of Cataloged Files
=======================
File Name: /ora/app/oracle/fast_recovery_area/ORATEST/autobackup/2016_09_27/o1_mf_s_923618301_cym5bh20_.bkp

using channel ORA_DISK_1
channel ORA_DISK_1: starting datafile copy
input datafile file number=00003 name=/ora/app/oracle/oradata/oratest/sysaux01.dbf
output file name=+DATA/ORATEST/DATAFILE/sysaux.283.923619095 tag=TAG20160927T005133 RECID=3 STAMP=923619184
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:37
channel ORA_DISK_1: starting datafile copy
input datafile file number=00001 name=/ora/app/oracle/oradata/oratest/system01.dbf
output file name=+DATA/ORATEST/DATAFILE/system.284.923619193 tag=TAG20160927T005133 RECID=4 STAMP=923619250
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:05
channel ORA_DISK_1: starting datafile copy
input datafile file number=00009 name=/ora/app/oracle/oradata/oratest/poratest/sysaux01.dbf
output file name=+DATA/ORATEST/3D0B2B62361C7521E0532D0000C0E40F/DATAFILE/sysaux.285.923619259 tag=TAG20160927T005133 RECID=5 STAMP=923619288
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:35
channel ORA_DISK_1: starting datafile copy
input datafile file number=00007 name=/ora/app/oracle/oradata/oratest/pdbseed/sysaux01.dbf
output file name=+DATA/ORATEST/3D098F4378AF394BE0532D0000C0C78E/DATAFILE/sysaux.286.923619295 tag=TAG20160927T005133 RECID=6 STAMP=923619334
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:45
channel ORA_DISK_1: starting datafile copy
input datafile file number=00008 name=/ora/app/oracle/oradata/oratest/poratest/system01.dbf
output file name=+DATA/ORATEST/3D0B2B62361C7521E0532D0000C0E40F/DATAFILE/system.287.923619339 tag=TAG20160927T005133 RECID=7 STAMP=923619353
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:15
channel ORA_DISK_1: starting datafile copy
input datafile file number=00005 name=/ora/app/oracle/oradata/oratest/pdbseed/system01.dbf
output file name=+DATA/ORATEST/3D098F4378AF394BE0532D0000C0C78E/DATAFILE/system.288.923619355 tag=TAG20160927T005133 RECID=8 STAMP=923619365
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=/ora/app/oracle/oradata/oratest/undotbs01.dbf
output file name=+DATA/ORATEST/DATAFILE/undotbs1.289.923619371 tag=TAG20160927T005133 RECID=9 STAMP=923619372
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=/ora/app/oracle/oradata/oratest/users01.dbf
output file name=+DATA/ORATEST/DATAFILE/users.290.923619373 tag=TAG20160927T005133 RECID=10 STAMP=923619374
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
channel ORA_DISK_1: starting datafile copy
input datafile file number=00010 name=/ora/app/oracle/oradata/oratest/poratest/poratest_users01.dbf
output file name=+DATA/ORATEST/3D0B2B62361C7521E0532D0000C0E40F/DATAFILE/users.291.923619375 tag=TAG20160927T005133 RECID=11 STAMP=923619375
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
Finished backup at 27-SEP-16

RMAN-06497: WARNING: control file is not current, control file AUTOBACKUP skipped

RMAN>

RMAN> recover database;

Starting recover at 27-SEP-16
using channel ORA_DISK_1

starting media recovery

archived log for thread 1 with sequence 29 is already on disk as file /ora/app/oracle/oradata/oratest/redo02.log
archived log file name=/ora/app/oracle/oradata/oratest/redo02.log thread=1 sequence=29
media recovery complete, elapsed time: 00:00:02
Finished recover at 27-SEP-16

RMAN>

RMAN> alter database open resetlogs;

Statement processed

RMAN>



SQL> select name from v$controlfile;

NAME
--------------------------------------------------------------------------------
+DATA/ORATEST/CONTROLFILE/current.282.923618939

SQL> select name from v$datafile;

NAME
--------------------------------------------------------------------------------
+DATA/ORATEST/DATAFILE/system.284.923619193
+DATA/ORATEST/DATAFILE/sysaux.283.923619095
+DATA/ORATEST/DATAFILE/undotbs1.289.923619371
+DATA/ORATEST/3D098F4378AF394BE0532D0000C0C78E/DATAFILE/system.288.923619355
+DATA/ORATEST/DATAFILE/users.290.923619373
+DATA/ORATEST/3D098F4378AF394BE0532D0000C0C78E/DATAFILE/sysaux.286.923619295
+DATA/ORATEST/3D0B2B62361C7521E0532D0000C0E40F/DATAFILE/system.287.923619339
+DATA/ORATEST/3D0B2B62361C7521E0532D0000C0E40F/DATAFILE/sysaux.285.923619259
+DATA/ORATEST/3D0B2B62361C7521E0532D0000C0E40F/DATAFILE/users.291.923619375

9 rows selected.

SQL>





SQL> select group#,member from v$logfile;

    GROUP#
----------
MEMBER
--------------------------------------------------------------------------------
3
/ora/app/oracle/oradata/oratest/redo03.log

2
/ora/app/oracle/oradata/oratest/redo02.log

1
/ora/app/oracle/oradata/oratest/redo01.log


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

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

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

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

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

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

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

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

SQL>
SQL> alter database drop group 2;
alter database drop group 2
                    *
ERROR at line 1:
ORA-01900: LOGFILE keyword expected


SQL> alter database drop logfile group 3
  2  ;

Database altered.

SQL> alter database drop logfile group 2;
alter database drop logfile group 2
*
ERROR at line 1:
ORA-01567: dropping log 2 would leave less than 2 log files for instance
oratest (thread 1)
ORA-00312: online log 2 thread 1: '/ora/app/oracle/oradata/oratest/redo02.log'


SQL> desc v$log;                                      
 Name   Null?    Type
 ----------------------------------------- -------- ----------------------------
 GROUP#    NUMBER
 THREAD#    NUMBER
 SEQUENCE#    NUMBER
 BYTES    NUMBER
 BLOCKSIZE    NUMBER
 MEMBERS    NUMBER
 ARCHIVED    VARCHAR2(3)
 STATUS    VARCHAR2(16)
 FIRST_CHANGE#    NUMBER
 FIRST_TIME    DATE
 NEXT_CHANGE#    NUMBER
 NEXT_TIME    DATE
 CON_ID    NUMBER

SQL> select bytes from v$log;

     BYTES
----------
  52428800
  52428800

SQL> alter database add logfile 3 '+DATA' SIZE 50M;
alter database add logfile 3 '+DATA' SIZE 50M
                           *
ERROR at line 1:
ORA-00933: SQL command not properly ended


SQL> alter database add logfile group 3 '+DATA' size 50m;

Database altered.

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

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

SQL> alter database drop logfile group 2;

Database altered.

SQL> alter database add logfile group 2 '+DATA' size 50m;

Database altered.

SQL> select group#,member from v$logfile;

    GROUP#
----------
MEMBER
--------------------------------------------------------------------------------
3
+DATA/ORATEST/ONLINELOG/group_3.292.923626399

2
+DATA/ORATEST/ONLINELOG/group_2.293.923626491

1
/ora/app/oracle/oradata/oratest/redo01.log


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 add logfile group 1 '+DATA' size 50m;

Database altered.

SQL> select group#,member from v$logfile;

    GROUP#
----------
MEMBER
--------------------------------------------------------------------------------
3
+DATA/ORATEST/ONLINELOG/group_3.292.923626399

2
+DATA/ORATEST/ONLINELOG/group_2.293.923626491

1
+DATA/ORATEST/ONLINELOG/group_1.294.923626637


SQL>