Mudar localização datafile

Dúvidas, dicas e atualizações sobre o Treinamento Oracle Backup & Recovery.
Post Reply
abonacin

Mudar localização datafile

Post by abonacin »

Boa noite,

Resolvi mudar um datafile de lugar e aconteceu algo "estranho". Esse era o esperado?

Inicio:

Code: Select all

RMAN> report schema;

using target database control file instead of recovery catalog
Report of database schema for database with db_unique_name SDF

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    2000     SYSTEM               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_system_9qr0722b_.dbf
2    828      SYSAUX               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_sysaux_9qr07401_.dbf
3    728      UNDOTBS1             ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_undotbs1_9qr075hh_.dbf
4    128      USERS                ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_users_9qr0792z_.dbf
5    512      ZABBIX               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_zabbix_9tfqr8m3_.dbf



1ª Tentativa mudar datafile 4:
De "/u01/app/oracle/oradata/SDF/datafile/" para "/u01/app/oracle/oradata/SDF/"

Code: Select all

RMAN> run{
2> backup datafile 4;
3> sql 'alter tablespace users offline';
4> set newname for datafile 4 to '/u01/app/oracle/oradata/SDF/o1_mf_users_9qr0792z_.dbf';
5> restore datafile 4;
6> switch datafile 4;
7> recover datafile 4;
8> sql 'alter tablespace users online';
9> }

Starting backup at 27-AUG-14
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=45 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=00004 name=/u01/app/oracle/oradata/SDF/datafile/o1_mf_users_9qr0792z_.dbf
channel ORA_DISK_1: starting piece 1 at 27-AUG-14
channel ORA_DISK_1: finished piece 1 at 27-AUG-14
piece handle=/FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T203520_9zwtsr90_.bkp tag=TAG20140827T203520 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 27-AUG-14

sql statement: alter tablespace users offline

executing command: SET NEWNAME

Starting restore at 27-AUG-14
using channel ORA_DISK_1

channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_DISK_1: restoring datafile 00004 to /u01/app/oracle/oradata/SDF/o1_mf_users_9qr0792z_.dbf
channel ORA_DISK_1: reading from backup piece /FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T203520_9zwtsr90_.bkp
channel ORA_DISK_1: piece handle=/FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T203520_9zwtsr90_.bkp tag=TAG20140827T203520
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:03
Finished restore at 27-AUG-14

datafile 4 switched to datafile copy
input datafile copy RECID=9 STAMP=856730248 file name=/u01/app/oracle/oradata/SDF/datafile/o1_mf_users_9zwtxoc6_.dbf

Starting recover at 27-AUG-14
using channel ORA_DISK_1

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

Finished recover at 27-AUG-14

sql statement: alter tablespace users online


E para minha surpresa, nada mudou.

Code: Select all

RMAN> report schema;

Report of database schema for database with db_unique_name SDF

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    2000     SYSTEM               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_system_9qr0722b_.dbf
2    828      SYSAUX               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_sysaux_9qr07401_.dbf
3    728      UNDOTBS1             ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_undotbs1_9qr075hh_.dbf
4    128      USERS                ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_users_9zwtxoc6_.dbf
5    512      ZABBIX               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_zabbix_9tfqr8m3_.dbf


[oracle@aabsingdb01 ~]$ ls -l /u01/app/oracle/oradata/SDF/
total 131092
drwxr-xr-x. 2 oracle oinstall      4096 May 20 22:26 controlfile
drwxr-xr-x. 2 oracle oinstall      4096 Aug 27 20:48 datafile
drwxr-xr-x. 2 oracle oinstall      4096 May 21 09:12 onlinelog
[oracle@aabsingdb01 ~]$




Olhando com atenção, o switch não foi pro NEW NAME.

Code: Select all

datafile 4 switched to datafile copy
input datafile copy RECID=9 STAMP=856730248 file name=/u01/app/oracle/oradata/SDF/datafile/o1_mf_users_9zwtxoc6_.dbf

Pensei que fosse algo relacionado aos nomes atribuidos pelo Oracle OMF. Tentei com outro nome:


Code: Select all

RMAN> run{
2> backup datafile 4;
3> sql 'alter tablespace users offline';
4> set newname for datafile 4 to '/u01/app/oracle/oradata/SDF/users01.dbf';
5> restore datafile 4;
6> switch datafile 4;
7> recover datafile 4;
8> sql 'alter tablespace users online';
9> }

Starting backup at 27-AUG-14
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=46 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=00004 name=/u01/app/oracle/oradata/SDF/datafile/o1_mf_users_9zwtxoc6_.dbf
channel ORA_DISK_1: starting piece 1 at 27-AUG-14
channel ORA_DISK_1: finished piece 1 at 27-AUG-14
piece handle=/FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T204514_9zwvdbqq_.bkp tag=TAG20140827T204514 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 27-AUG-14

sql statement: alter tablespace users offline

executing command: SET NEWNAME

Starting restore at 27-AUG-14
using channel ORA_DISK_1

channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_DISK_1: restoring datafile 00004 to /u01/app/oracle/oradata/SDF/users01.dbf
channel ORA_DISK_1: reading from backup piece /FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T204514_9zwvdbqq_.bkp
channel ORA_DISK_1: piece handle=/FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T204514_9zwvdbqq_.bkp tag=TAG20140827T204514
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 27-AUG-14

datafile 4 switched to datafile copy
input datafile copy RECID=12 STAMP=856730716 file name=/u01/app/oracle/oradata/SDF/users01.dbf

Starting recover at 27-AUG-14
using channel ORA_DISK_1

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

Finished recover at 27-AUG-14

sql statement: alter tablespace users online


E agora o switch foi pro NEW NAME.


Code: Select all

RMAN> report schema;

Report of database schema for database with db_unique_name SDF

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    2000     SYSTEM               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_system_9qr0722b_.dbf
2    828      SYSAUX               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_sysaux_9qr07401_.dbf
3    728      UNDOTBS1             ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_undotbs1_9qr075hh_.dbf
4    128      USERS                ***     /u01/app/oracle/oradata/SDF/users01.dbf
5    512      ZABBIX               ***     /u01/app/oracle/oradata/SDF/datafile/o1_mf_zabbix_9tfqr8m3_.dbf


[oracle@aabsingdb01 ~]$ ls -l /u01/app/oracle/oradata/SDF/
total 131092
drwxr-xr-x. 2 oracle oinstall      4096 May 20 22:26 controlfile
drwxr-xr-x. 2 oracle oinstall      4096 Aug 27 20:48 datafile
drwxr-xr-x. 2 oracle oinstall      4096 May 21 09:12 onlinelog
-rw-r-----. 1 oracle oinstall 134225920 Aug 27 20:45 users01.dbf
[oracle@aabsingdb01 ~]$



Tentei novamente com outra tablespace:


Code: Select all

RMAN> run{
2> backup datafile 5;
3> sql 'alter tablespace ZABBIX offline';
4> set newname for datafile 5  to '/u01/app/oracle/oradata/SDF/o1_mf_zabbix_9tfqr8m3_.dbf';
5> restore datafile 5;
6> switch datafile 5;
7> recover datafile 5;
8> sql 'alter tablespace ZABBIX online';
9> }

Starting backup at 27-AUG-14
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00005 name=/u01/app/oracle/oradata/SDF/datafile/o1_mf_zabbix_9tfqr8m3_.dbf
channel ORA_DISK_1: starting piece 1 at 27-AUG-14
channel ORA_DISK_1: finished piece 1 at 27-AUG-14
piece handle=/FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T204803_9zwvkmb5_.bkp tag=TAG20140827T204803 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 27-AUG-14

sql statement: alter tablespace ZABBIX offline

executing command: SET NEWNAME

Starting restore at 27-AUG-14
using channel ORA_DISK_1

channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_DISK_1: restoring datafile 00005 to /u01/app/oracle/oradata/SDF/o1_mf_zabbix_9tfqr8m3_.dbf
channel ORA_DISK_1: reading from backup piece /FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T204803_9zwvkmb5_.bkp
channel ORA_DISK_1: piece handle=/FRA/SDF/backupset/2014_08_27/o1_mf_nnndf_TAG20140827T204803_9zwvkmb5_.bkp tag=TAG20140827T204803
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:07
Finished restore at 27-AUG-14

datafile 5 switched to datafile copy
input datafile copy RECID=15 STAMP=856730891 file name=/u01/app/oracle/oradata/SDF/datafile/o1_mf_zabbix_9zwvknfq_.dbf

Starting recover at 27-AUG-14
using channel ORA_DISK_1

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

Finished recover at 27-AUG-14

sql statement: alter tablespace ZABBIX online

RMAN>

[oracle@aabsingdb01 ~]$ ls -l /u01/app/oracle/oradata/SDF/
total 131092
drwxr-xr-x. 2 oracle oinstall      4096 May 20 22:26 controlfile
drwxr-xr-x. 2 oracle oinstall      4096 Aug 27 20:48 datafile
drwxr-xr-x. 2 oracle oinstall      4096 May 21 09:12 onlinelog
-rw-r-----. 1 oracle oinstall 134225920 Aug 27 20:45 users01.dbf
[oracle@aabsingdb01 ~]$



E não funcionou de novo. Pode isso Arnaldo?

portilho
Site Admin
Posts: 497
Joined: Wed May 29, 2013 8:51 am

Re: Mudar localização datafile

Post by portilho »

Olá!

Esta situação realmente ocorre por conta do OMF.

Veja o que diz a documentação:
Caution:
Do not rename an Oracle managed file. The database identifies an Oracle managed file based on its name. If you rename the file, the database is no longer able to recognize it as an Oracle managed file and will not manage the file accordingly.

Fonte: http://docs.oracle.com/database/121/ADM ... ADMIN11493

Veja que o diretório datafile faz parte da nomenclatura do OMF:
http://docs.oracle.com/database/121/ADM ... ADMIN11492

Se você quiser trocar a localização base (por exemplo, de "/u01/oradata" para "/u02/oradata") de um OMF, pode utilizar assim:
RMAN> SQL "ALTER TABLESPACE USERS OFFLINE";
RMAN> BACKUP AS COPY DATAFILE 4 FORMAT '/u02/oradata/';
RMAN> SWITCH DATAFILE 4 TO COPY;
RMAN> SQL "ALTER TABLESPACE USERS ONLINE";

Post Reply