Миграция базы данных с NON-ASM к ASM

Источник: all-oracle

Рекомендовано для:
  • Oracle Database 10g R1
  • Oracle Database 10g R2
  • Oracle Database 11g R1
 

Эта статья посвящена переводу существующей базы данных к ASM. И является некой step-by-step инструкцией.

Шаг :1
Залогинтесь как SYSDBA и измените три параметра для controlfile, datafile и flash recovery area с опцией SPFILE.
Замечание: Имеется две дисковые группы, используется дисковая группа GRP2.

SQL> alter system set control_files='+DGRP2' scope=spfile;
System altered.

SQL> alter system set db_create_file_dest='+DGRP2' scope=spfile;
System altered.

SQL> alter system set db_recovery_file_dest='+DGRP2' scope=spfile;
System altered.

Шаг: 2 Перезапуск сервера баз данных, что бы параметры вступили в силу

 
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.

SQL> startup nomount
ORACLE instance started.
Total System Global Area 263639040 bytes
Fixed Size 1332552 bytes
Variable Size 218106552 bytes
Database Buffers 37748736 bytes
Redo Buffers 6451200 bytes

Шаг:3  Соединение с сеансом RMAN и восстановление управляющего файла на ASM системе.

C:\>RMAN target=sys
Recovery Manager: Release 11.1.0.6.0 - Production on Thu Apr 17 10:12:53 2008
Copyright (c) 1982, 2007, Oracle. All rights reserved.
target database Password:connected to target database: TEST (not mounted)

Restore Controlfile.
RMAN> restore controlfile from 'C:\app\ora11g\oradata\test\CONTROL01.ctl';
Starting restore at 17-APR-08using target database control file instead of recovery 
catalogallocated channel: ORA_DISK_1channel ORA_DISK_1: SID=151 
device type=DISK
channel ORA_DISK_1: copied control file copyoutput file 
name=+DGRP2/test/controlfile/current.256.652270419Finished restore at 17-APR-08

Шаг:4 Монтирование базы данных Oracle и получение резервной копии.

RMAN> alter database mount;
database mountedreleased channel: ORA_DISK_1
RMAN> backup as copy database format '+DGRP2';

Starting backup at 17-APR-08allocated channel: ORA_DISK_1channel ORA_DISK_1: 
SID=151 device type=DISKchannel ORA_DISK_1: starting datafile copyinput datafile 
file number=00001 name=C:\APP\ORA11G\ORADATA\TEST\SYSTEM01.DBFoutput 
file name=+DGRP2/test/datafile/system.257.652270565 tag=TAG20080417T101550 
RECID=1 STAMP=652270748channel ORA_DISK_1: datafile copy complete, elapsed 
time: 00:03:06channel ORA_DISK_1: starting datafile copyinput datafile file number=
00002 name=C:\APP\ORA11G\ORADATA\TEST\SYSAUX01.DBFoutput file 
name=+DGRP2/test/datafile/sysaux.258.652270761 tag=TAG20080417T101550 
RECID=2 STAMP=652270908channel ORA_DISK_1: datafile copy complete, 
elapsed time: 00:02:35channel ORA_DISK_1: starting datafile copyinput datafile 
file number=00003 name=C:\APP\ORA11G\ORADATA\TEST\UNDOTBS01.DBFoutput 
file name=+DGRP2/test/datafile/undotbs1.259.652270927 tag=TAG20080417T101550 
RECID=3 STAMP=652270952channel ORA_DISK_1: datafile copy complete, elapsed 
time: 00:00:35channel ORA_DISK_1: starting datafile copycopying current control 
fileoutput file name=+DGRP2/test/controlfile/backup.260.652270971 
tag=TAG20080417T101550 RECID=4 STAMP=652270975channel ORA_DISK_1: 
datafile copy complete, elapsed time: 00:00:07channel ORA_DISK_1: starting 
datafile copyinput datafile file number=00004 
name=C:\APP\ORA11G\ORADATA\TEST\USERS01.DBFoutput file 
name=+DGRP2/test/datafile/users.261.652270989 tag=TAG20080417T101550 
RECID=5 STAMP=652270991channel ORA_DISK_1: datafile copy complete, 
elapsed time: 00:00:03channel ORA_DISK_1: starting full datafile backup setchannel 
ORA_DISK_1: specifying datafile(s) in backup setincluding current SPFILE in backup 
setchannel ORA_DISK_1: starting piece 1 at 17-APR-08channel ORA_DISK_1: 
finished piece 1 at 17-APR-08piece handle=+DGRP2/test/backupset/2008_04_17
/nnsnf0_tag20080417t101550_0.262.652271003 tag=TAG20080417T101550 
comment=NONEchannel ORA_DISK_1: backup set complete, elapsed time: 
00:00:02Finished backup at 17-APR-08

RMAN> switch database to copy;

datafile 1 switched to datafile copy "+DGRP2/test/datafile/system.257.652270565"
datafile 2 switched to datafile copy "+DGRP2/test/datafile/sysaux.258.652270761"
datafile 3 switched to datafile copy "+DGRP2/test/datafile/undotbs1.259.652270927"
datafile 4 switched to datafile copy "+DGRP2/test/datafile/users.261.652270989"

Шаг:5 Снова соединяемся с sqlplus и выполняем неполное восстановление

C:\>sqlplus sys/oracle as sysdba
SQL*Plus: Release 11.1.0.6.0 - Production on Thu Apr 17 10:26:24 2008
Copyright (c) 1982, 2007, Oracle. All rights reserved.
Connected to:Oracle Database 11g Enterprise Edition Release 11.1.0.6.0 - ProductionWith 
the Partitioning, OLAP, Data Mining and REAL Application Testing options

SQL> recover database using backup controlfile until cancel;
ORA-00279: change 1071679 generated at 04/17/2008 10:11:10 needed for thread 
1ORA-00289: suggestion : +DGRP2ORA-15173: entry 'ARCHIVELOG' does not exist 
in directory 'TEST'ORA-00280: 
change 1071679 for thread 1 is in sequence #14
Specify log: {=suggested filename AUTO CANCEL}
CANCEL
Media recovery cancelled.

Шаг:6  Открываем базу данных с опцией RESETLOGS.

SQL> alter database open resetlogs;
Database altered.

Шаг:7 Удаляем старые временные файлы и создаем новые в существующем табличном пространстве

 
SQL> alter database tempfile 'c:\app\ora11g\oradata\test\temp01.dbf' 
    2 drop including datafiles;
Database altered.

SQL> alter tablespace temp add tempfile size 512m 
    2 autoextend on next 250m maxsize unlimited;
Tablespace altered.

SQL> select tablespace_name, file_name, bytes from dba_temp_files;
TABLESPACE_NAME FILE_NAME                               BYTES
--------------- --------------------------------------- ----------
TEMP            +DGRP2/test/tempfile/temp.266.536870912 652271571

Шаг:8 Пересоздаем все  redolog group на дисковой группе ASM

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

GROUP# MEMBER                                BYTES
------ ------------------------------------- --------- 
3      C:\APP\ORA11G\ORADATA\TEST\REDO03.LOG 52428800
2      C:\APP\ORA11G\ORADATA\TEST\REDO02.LOG 52428800
1      C:\APP\ORA11G\ORADATA\TEST\REDO01.LOG 52428800

SQL> select group#,status from v$log;
GROUP#     STATUS
---------- ---------------- 
1          CURRENT 
2          UNUSED 
3          UNUSED

SQL> alter system switch logfile;
System altered.

SQL> alter system switch logfile;
System altered.

SQL> select group#,status from v$log;
GROUP#     STATUS
---------- ---------------- 
1          ACTIVE 
2          ACTIVE 
3          CURRENT

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 test (thread 1)ORA-00312: online LOG 1 
thread 1: 'C:\APP\ORA11G\ORADATA\TEST\REDO01.LOG'

When you get above error message then set checkpoint with below command.

SQL> alter system checkpoint global;
System altered.

SQL> alter database drop logfile group 1;
Database altered.

SQL> alter database add logfile group 1 size 10m;
Database altered.

SQL> alter system checkpoint global;
System altered.

SQL> alter database drop logfile group 2;
Database altered.

SQL> alter database add logfile group 2 size 10m;
Database altered.

SQL> alter system checkpoint global;
System altered.

SQL> alter database drop logfile group 3;
Database altered.

SQL> alter database add logfile group 3 size 10m;
Database altered.

SQL> column member format a30

SQL> select a.group#, a.member, b.bytes 
2 from v$logfile a, v$log b where a.group# = b.group#;
GROUP#               MEMBER                   BYTES
---------- ------------------------------ ---------- 
3         +DGRP2/test/onlinelog/group_3. 10485760 277.652273117
2         +DGRP2/test/onlinelog/group_2. 10485760 274.652273019
1         +DGRP2/test/onlinelog/group_1. 10485760 271.652272977
1         +DGRP2/test/onlinelog/group_1. 10485760 272.652272979
2         +DGRP2/test/onlinelog/group_2. 10485760 275.652273021
3         +DGRP2/test/onlinelog/group_3. 10485760 278.652273119
6 rows selected.

Шаг:9 Пересоздаем SPFILE на дисковой группе ASM

SQL> create pfile='c:\initTEST.ora' from spfile;
File created.
SQL> create spfile='+DGRP2/spfileTEST.ora' from pfile='c:\initTEST.ora';
File created.

Шаг:10 Удаляем старые резервные копии RMAN

RMAN> delete noprompt force copy;


Страница сайта http://test.interface.ru
Оригинал находится по адресу http://test.interface.ru/home.asp?artId=20546