RMAN – Restore de Tabela Oracle
Neste artigo, será mostrado como utilizar a new feature Oracle 12C, o restore a nível de tabela totalmente realizado pelo RMAN. Este processo consiste em utilizar o mesmo controlfile do Banco de Dados target para clona-lo em um Banco de Dados auxiliar e assim recuperar apenas as tablespaces necessárias para realizar o restore da tabela. Esta parte, era possível de se realizar na versão 11 do Oracle, o que foi incorporado ao RMAN na versão 12C, foi o export e o import da tabela, isso, em versões anteriores do Banco e Dados tinha que ser feito manualmente pelo próprio DBA.
Vamos a atividade em si.
- Conectando com o usuário do Banco de Dados
# su - oracle
- Criando e exportando a variável ORACLE_SID
$ export ORACLE_SID=orcl
- Conectando ao Banco de Dados
$ sqlplus / as sysdba;
SQL*Plus: Release 12.1.0.2.0 Production on Sat Aug 15 20:58:03 2015
Copyright (c) 1982, 2014, Oracle. All rights reserved.
Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
- Verificando conteúdo da tabela que será deletada.
SQL> select * from teste.teste_rman;
COL1 COL2
---------- ----------
reg_1a reg_1b
reg_2a reg_2b
reg_3a reg_3b
reg_4a reg_4b
reg_5a reg_5b
- Excluindo a tabela que será posteriormente restaurada.
SQL> drop table teste.teste_rman cascade constraints;
Table dropped.
- Fazendo o shutdown do Banco de Dados
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
- Saindo do SQLPLUS
SQL> exit
Disconnected from Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
- Conectando-se ao RMAN
$ rman target
/
Recovery Manager: Release 12.1.0.2.0 - Production on Sat Aug 15 21:23:18 2015
Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved.
connected to target database (not started)
- Realizando o resrtore da tabela
RMAN> RECOVER TABLE teste.teste_rman UNTIL TIME "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')" AUXILIARY DESTINATION '/u01/aux';
Starting recover at 15-AUG-15
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of recover command at 08/15/2015 21:23:20
RMAN-06403: could not obtain a fully authorized session
ORA-01034: ORACLE not available
ORA-27101: shared memory realm does not exist
Linux-x86_64 Error: 2: No such file or directory
Additional information: 3640
Additional information: 644371931
A mensagem acima, indica que o Banco de Dados não está disponível.
- Realizando o startup do Banco de Dados em modo nomount
RMAN> startup nomount;
Oracle instance started
Total System Global Area 339738624 bytes
Fixed Size 2924112 bytes
Variable Size 260047280 bytes
Database Buffers 71303168 bytes
Redo Buffers 5464064 bytes
- Realizando o restore da tabela
RMAN> RECOVER TABLE teste.teste_rman UNTIL TIME "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')" AUXILIARY DESTINATION '/u01/aux';
Starting recover at 15-AUG-15
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of recover command at 08/15/2015 21:23:45
ORA-01507: database not mounted
A mensagem acima relata que o Banco de Dados não está montado
- Montando o Banco de Dados
RMAN> alter database mount;
using target database control file instead of recovery catalog
Statement processed
- Realizando o restore da tabela
RMAN> RECOVER TABLE teste.teste_rman UNTIL TIME "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')" AUXILIARY DESTINATION '/u01/aux';
Starting recover at 15-AUG-15
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of recover command at 08/15/2015 21:24:13
RMAN-05010: target database must be opened in READ WRITE mode for Tablespace Point-in-Time Recovery
A mensagem acima relata que o Banco de Dados deve estar aberto para executar a atividade do Restore.
- Abrindo o Banco de Dados
RMAN> alter database open;
Statement processed
- Realizando o restore da tabela
RMAN> RECOVER TABLE teste.teste_rman UNTIL TIME "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')" AUXILIARY DESTINATION '/u01/aux';
Starting recover at 15-AUG-15
using channel ORA_DISK_1
RMAN-05026: WARNING: presuming following set of tablespaces applies to specified Point-in-Time
List of tablespaces expected to have UNDO segments
Tablespace SYSTEM
Tablespace UNDOTBS1
Creating automatic instance, with SID='qway'
initialization parameters used for automatic instance:
db_name=ORCL
db_unique_name=qway_pitr_ORCL
compatible=12.1.0.2.0
db_block_size=8192
db_files=200
diagnostic_dest=/u01/app/oracle
_system_trig_enabled=FALSE
sga_target=324M
processes=200
db_create_file_dest=/u01/aux
log_archive_dest_1='location=/u01/aux'
#No auxiliary parameter file used
starting up automatic instance ORCL
Oracle instance started
Total System Global Area 339738624 bytes
Fixed Size 2924208 bytes
Variable Size 130023760 bytes
Database Buffers 201326592 bytes
Redo Buffers 5464064 bytes
Automatic instance created
contents of Memory Script:
{
# set requested point in time
set until time "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')";
# restore the controlfile
restore clone controlfile;
# mount the controlfile
sql clone 'alter database mount clone database';
# archive current online log
sql 'alter system archive log current';
}
executing Memory Script
executing command: SET until clause
Starting restore at 15-AUG-15
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=24 device type=DISK
channel ORA_AUX_DISK_1: starting datafile backup set restore
channel ORA_AUX_DISK_1: restoring control file
channel ORA_AUX_DISK_1: reading from backup piece /backup/autobackup/c-1411380092-20150815-00
channel ORA_AUX_DISK_1: piece handle=/backup/autobackup/c-1411380092-20150815-00 tag=TAG20150815T202502
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/u01/aux/ORCL/controlfile/o1_mf_bwzpow0s_.ctl
Finished restore at 15-AUG-15
sql statement: alter database mount clone database
sql statement: alter system archive log current
contents of Memory Script:
{
# set requested point in time
set until time "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')";
# set destinations for recovery set and auxiliary set datafiles
set newname for clone datafile 1 to new;
set newname for clone datafile 4 to new;
set newname for clone datafile 3 to new;
set newname for clone tempfile 1 to new;
# switch all tempfiles
switch clone tempfile all;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 1, 4, 3;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
renamed tempfile 1 to /u01/aux/ORCL/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 15-AUG-15
using channel ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: starting datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_AUX_DISK_1: restoring datafile 00001 to /u01/aux/ORCL/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /u01/aux/ORCL/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /u01/aux/ORCL/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /backup/repositorio/0aqemgpa_1_1
channel ORA_AUX_DISK_1: piece handle=/backup/repositorio/0aqemgpa_1_1 tag=TAG20150815T202306
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:03:16
Finished restore at 15-AUG-15
datafile 1 switched to datafile copy
input datafile copy RECID=4 STAMP=887837910 file name=/u01/aux/ORCL/datafile/o1_mf_system_bwzpp32y_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=5 STAMP=887837910 file name=/u01/aux/ORCL/datafile/o1_mf_undotbs1_bwzpp36g_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=6 STAMP=887837910 file name=/u01/aux/ORCL/datafile/o1_mf_sysaux_bwzpp36d_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')";
# online the datafiles restored or switched
sql clone "alter database datafile 1 online";
sql clone "alter database datafile 4 online";
sql clone "alter database datafile 3 online";
# recover and open database read only
recover clone database tablespace "SYSTEM", "UNDOTBS1", "SYSAUX";
sql clone 'alter database open read only';
}
executing Memory Script
executing command: SET until clause
sql statement: alter database datafile 1 online
sql statement: alter database datafile 4 online
sql statement: alter database datafile 3 online
Starting recover at 15-AUG-15
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 5 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCL/archivelog/2015_08_15/o1_mf_1_5_bwzln715_.arc
archived log file name=/u01/app/oracle/fast_recovery_area/ORCL/archivelog/2015_08_15/o1_mf_1_5_bwzln715_.arc thread=1 sequence=5
media recovery complete, elapsed time: 00:00:03
Finished recover at 15-AUG-15
sql statement: alter database open read only
contents of Memory Script:
{
sql clone "create spfile from memory";
shutdown clone immediate;
startup clone nomount;
sql clone "alter system set control_files =
''/u01/aux/ORCL/controlfile/o1_mf_bwzpow0s_.ctl'' comment=
''RMAN set'' scope=spfile";
shutdown clone immediate;
startup clone nomount;
# mount database
sql clone 'alter database mount clone database';
}
executing Memory Script
sql statement: create spfile from memory
database closed
database dismounted
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 339738624 bytes
Fixed Size 2924208 bytes
Variable Size 130023760 bytes
Database Buffers 201326592 bytes
Redo Buffers 5464064 bytes
sql statement: alter system set control_files = ''/u01/aux/ORCL/controlfile/o1_mf_bwzpow0s_.ctl'' comment= ''RMAN set'' scope=spfile
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 339738624 bytes
Fixed Size 2924208 bytes
Variable Size 130023760 bytes
Database Buffers 201326592 bytes
Redo Buffers 5464064 bytes
sql statement: alter database mount clone database
contents of Memory Script:
{
# set requested point in time
set until time "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile 6 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 6;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
executing command: SET NEWNAME
Starting restore at 15-AUG-15
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=22 device type=DISK
channel ORA_AUX_DISK_1: starting datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_AUX_DISK_1: restoring datafile 00006 to /u01/aux/QWAY_PITR_ORCL/datafile/o1_mf_users_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /backup/repositorio/0aqemgpa_1_1
channel ORA_AUX_DISK_1: piece handle=/backup/repositorio/0aqemgpa_1_1 tag=TAG20150815T202306
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 15-AUG-15
datafile 6 switched to datafile copy
input datafile copy RECID=8 STAMP=887837969 file name=/u01/aux/QWAY_PITR_ORCL/datafile/o1_mf_users_bwzpy0fv_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "TO_DATE('14/08/2015 10:33:39','DD/MM/RRRR HH24:MI:SS')";
# online the datafiles restored or switched
sql clone "alter database datafile 6 online";
# recover and open resetlogs
recover clone database tablespace "USERS", "SYSTEM", "UNDOTBS1", "SYSAUX" delete archivelog;
alter clone database open resetlogs;
}
executing Memory Script
executing command: SET until clause
sql statement: alter database datafile 6 online
Starting recover at 15-AUG-15
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 5 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCL/archivelog/2015_08_15/o1_mf_1_5_bwzln715_.arc
archived log file name=/u01/app/oracle/fast_recovery_area/ORCL/archivelog/2015_08_15/o1_mf_1_5_bwzln715_.arc thread=1 sequence=5
media recovery complete, elapsed time: 00:00:00
Finished recover at 15-AUG-15
database opened
contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u01/aux''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u01/aux''";
}
executing Memory Script
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/aux''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/aux''
Performing export of tables...
EXPDP> Starting "SYS"."TSPITR_EXP_qway_fdBr":
EXPDP> Estimate in progress using BLOCKS method...
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
EXPDP> Total estimation using BLOCKS method: 64 KB
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
EXPDP> . . exported "TESTE"."TESTE_RMAN" 5.570 KB 5 rows
EXPDP> Master table "SYS"."TSPITR_EXP_qway_fdBr" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_qway_fdBr is:
EXPDP> /u01/aux/tspitr_qway_41529.dmp
EXPDP> Job "SYS"."TSPITR_EXP_qway_fdBr" successfully completed at Sat Aug 15 21:41:57 2015 elapsed 0 00:01:14
Export completed
contents of Memory Script:
{
# shutdown clone before import
shutdown clone abort
}
executing Memory Script
Oracle instance shut down
Performing import of tables...
IMPDP> Master table "SYS"."TSPITR_IMP_qway_bsfs" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_qway_bsfs":
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
IMPDP> . . imported "TESTE"."TESTE_RMAN" 5.570 KB 5 rows
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
IMPDP> Job "SYS"."TSPITR_IMP_qway_bsfs" successfully completed at Sat Aug 15 21:43:20 2015 elapsed 0 00:00:59
Import completed
Removing automatic instance
Automatic instance removed
auxiliary instance file /u01/aux/ORCL/datafile/o1_mf_temp_bwzpwf2z_.tmp deleted
auxiliary instance file /u01/aux/QWAY_PITR_ORCL/onlinelog/o1_mf_3_bwzpybjg_.log deleted
auxiliary instance file /u01/aux/QWAY_PITR_ORCL/onlinelog/o1_mf_2_bwzpy67x_.log deleted
auxiliary instance file /u01/aux/QWAY_PITR_ORCL/onlinelog/o1_mf_1_bwzpy290_.log deleted
auxiliary instance file /u01/aux/QWAY_PITR_ORCL/datafile/o1_mf_users_bwzpy0fv_.dbf deleted
auxiliary instance file /u01/aux/ORCL/datafile/o1_mf_sysaux_bwzpp36d_.dbf deleted
auxiliary instance file /u01/aux/ORCL/datafile/o1_mf_undotbs1_bwzpp36g_.dbf deleted
auxiliary instance file /u01/aux/ORCL/datafile/o1_mf_system_bwzpp32y_.dbf deleted
auxiliary instance file /u01/aux/ORCL/controlfile/o1_mf_bwzpow0s_.ctl deleted
auxiliary instance file tspitr_qway_41529.dmp deleted
Finished recover at 15-AUG-15
Saindo da Ferramenta RMAN
RMAN> exit
Pronto!!!
Restore da tabela concluído.