Em algumas situações, recuperar uma tablespace pode representar um esforço grande, caso o número de tabelas que precisamos recuperar seja pequena. Nesses casos, podemos usufruir do recurso de recover table através do RMAN. Nos bastidores, o Oracle cria um ambiente auxiliar, restaurando apenas as tabelas desejadas, e realiza um export via Data Pump dos objetos desejados. De forma opcional, onde decidimos no momento da emissão do comando, podemos importar os objetos no banco de dados com os nomes originais ou importá-los em owners,tablespace ou nomes diferentes. Como limitação, não conseguimos usar este processo em tabelas que pertencem ao owner SYS e nas tablespaces SYSTEM e SYSAUX, além de objetos com constraints NOT NULL não conseguirem ser recuperados usando a opção de REMAP.
Obviamente as cláusulas do comando devem ser consultadas na documentação oficial da Oracle, mas podemos ter uma referência nas tabelas abaixo:
Cláusula | Descrição |
AUXILIARY DESTINATION | Informa o local onde o ambiente auxiliar (e suas estruturas) serão criados |
UNTIL [SEQUENCE | SCN | TIME] | Informa o ponto no tempo para a recuperação |
Cláusula | Descrição |
DUMP FILE DATAPUMP DESTINATION | Nome e destino do dump que será gerado. O padrão é: tspitr_<SID>-of-clone_<n>.dmp |
NOTABLEIMPORT | Opção para não importar automaticamente o dump no banco target |
REMAP TABLE | Renomeia as tabelas no banco target |
REMAP TABLESPACE | Hospeda as tabelas em tablespaces diferentes da original |
Uma vez exposta a parte teórica mínima, vamos aplicar na prática um exemplo do recurso. Reconhecendo nosso laboratório:
[oracle@oel8 ~]$ rman target /
Recovery Manager: Release 18.0.0.0.0 - Production on Tue Aug 10 20:05:00 2021
Version 18.13.0.0.0
Copyright (c) 1982, 2018, Oracle and/or its affiliates. All rights reserved.
connected to target database: RMANDB (DBID=3825250984)
RMAN> SELECT NAME,OPEN_MODE,LOG_MODE FROM V$DATABASE;
using target database control file instead of recovery catalog
NAME OPEN_MODE LOG_MODE
--------- -------------------- ------------
RMANDB READ WRITE ARCHIVELOG
RMAN> REPORT SCHEMA;
Report of database schema for database with db_unique_name RMANDB
List of Permanent Datafiles
===========================
File Size(MB) Tablespace RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1 880 SYSTEM YES /oracle/dados/RMANDB/datafile/o1_mf_system_h8nynqfx_.dbf
2 120 TS_HIPO_CATALOG NO /oracle/dados/RMANDB/datafile/ts_hipo_catalog.dbf
3 730 SYSAUX NO /oracle/dados/RMANDB/datafile/o1_mf_sysaux_h8nyq35q_.dbf
4 305 UNDOTBS1 YES /oracle/dados/RMANDB/datafile/o1_mf_undotbs1_h8nyrjdr_.dbf
5 200 TS_CORTEX_CATALOG NO /oracle/dados/RMANDB/datafile/ts_cortex_catalog.dbf
7 16 USERS NO /oracle/dados/RMANDB/datafile/o1_mf_users_h8nyrkn7_.dbf
List of Temporary Files
=======================
File Size(MB) Tablespace Maxsize(MB) Tempfile Name
---- -------- -------------------- ----------- --------------------
1 69 TEMP 32767 /oracle/dados/RMANDB/datafile/o1_mf_temp_h8nyvt1f_.tmp
Realizando o backup do banco de dados:
RMAN> BACKUP DATABASE;
Starting backup at 2021-08-10:20:06:04
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=88 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=00001 name=/oracle/dados/RMANDB/datafile/o1_mf_system_h8nynqfx_.dbf
input datafile file number=00003 name=/oracle/dados/RMANDB/datafile/o1_mf_sysaux_h8nyq35q_.dbf
input datafile file number=00004 name=/oracle/dados/RMANDB/datafile/o1_mf_undotbs1_h8nyrjdr_.dbf
input datafile file number=00005 name=/oracle/dados/RMANDB/datafile/ts_cortex_catalog.dbf
input datafile file number=00002 name=/oracle/dados/RMANDB/datafile/ts_hipo_catalog.dbf
input datafile file number=00007 name=/oracle/dados/RMANDB/datafile/o1_mf_users_h8nyrkn7_.dbf
channel ORA_DISK_1: starting piece 1 at 2021-08-10:20:06:04
channel ORA_DISK_1: finished piece 1 at 2021-08-10:20:07:09
piece handle=/oracle/fra/RMANDB/backupset/2021_08_10/o1_mf_nnndf_TAG20210810T200604_jk61lwvf_.bkp tag=TAG20210810T200604 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:01:05
Finished backup at 2021-08-10:20:07:09
Starting Control File and SPFILE Autobackup at 2021-08-10:20:07:09
piece handle=/oracle/fra/RMANDB/autobackup/2021_08_10/o1_mf_s_1080245229_jk61nygr_.bkp comment=NONE
Finished Control File and SPFILE Autobackup at 2021-08-10:20:07:12
Nossa tabela de referência:
RMAN> SELECT * FROM BSS.PITR;
DESCRICAO
--------------------------------------------------
PITR DO BRUNO
Coletando o horário antes de provocar a remoção da nossa tabela:
RMAN> ALTER SYSTEM SWITCH LOGFILE;
Statement processed
RMAN> SELECT TO_CHAR(SYSDATE,'YYYY-MM-DD:HH24:MI:SS') FROM DUAL;
TO_CHAR(SYSDATE,'YY
-------------------
2021-08-10:20:09:25
RMAN> ALTER SYSTEM SWITCH LOGFILE;
Statement processed
Realizando o DROP da nossa tabela:
RMAN> DROP TABLE BSS.PITR;
Statement processed
Como o RMAN criará automaticamente uma instância auxiliar no processo, precisamos definir um diretório que hospede as estruturas que serão criadas. O meu diretório foi criado conforme abaixo:
[oracle@oel8 oracle]$ pwd
/oracle
[oracle@oel8 oracle]$ mkdir TABLE_PITR
[oracle@oel8 oracle]$ cd TABLE_PITR/
[oracle@oel8 TABLE_PITR]$ pwd
/oracle/TABLE_PITR
Apenas para fins didáticos, vou realizar um remap_table para um novo novo de tabela. E com um único comando RMAN, disparamos a recuperação de nossa tabela:
[oracle@oel8 TABLE_PITR]$ rman target /
Recovery Manager: Release 18.0.0.0.0 - Production on Tue Aug 10 20:16:18 2021
Version 18.13.0.0.0
Copyright (c) 1982, 2018, Oracle and/or its affiliates. All rights reserved.
connected to target database: RMANDB (DBID=3825250984)
RMAN> RECOVER TABLE BSS.PITR UNTIL TIME "to_date('2021-08-10:20:09:25','YYYY-MM-DD:HH24:MI:SS')" AUXILIARY DESTINATION '/oracle/TABLE_PITR' REMAP TABLE 'BSS'.'PITR': 'BSS'.'TABLE_PITR';
Starting recover at 2021-08-10:20:16:31
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=70 device type=DISK
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='Fvbg'
initialization parameters used for automatic instance:
db_name=RMANDB
db_unique_name=Fvbg_pitr_RMANDB
compatible=18.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/oracle/18.0.0/base
_system_trig_enabled=FALSE
sga_target=1536M
processes=200
db_create_file_dest=/oracle/TABLE_PITR
log_archive_dest_1='location=/oracle/TABLE_PITR'
#No auxiliary parameter file used
starting up automatic instance RMANDB
Oracle instance started
Total System Global Area 1610612016 bytes
Fixed Size 8658224 bytes
Variable Size 402653184 bytes
Database Buffers 1191182336 bytes
Redo Buffers 8118272 bytes
Automatic instance created
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2021-08-10:20:09:25','YYYY-MM-DD: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 2021-08-10:20:16:51
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=39 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 /oracle/fra/RMANDB/autobackup/2021_08_10/o1_mf_s_1080245229_jk61nygr_.bkp
channel ORA_AUX_DISK_1: piece handle=/oracle/fra/RMANDB/autobackup/2021_08_10/o1_mf_s_1080245229_jk61nygr_.bkp tag=TAG20210810T200709
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
output file name=/oracle/TABLE_PITR/RMANDB/controlfile/o1_mf_jk6274vr_.ctl
Finished restore at 2021-08-10:20:16:55
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('2021-08-10:20:09:25','YYYY-MM-DD: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 /oracle/TABLE_PITR/RMANDB/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 2021-08-10:20:17:02
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 /oracle/TABLE_PITR/RMANDB/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /oracle/TABLE_PITR/RMANDB/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /oracle/TABLE_PITR/RMANDB/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /oracle/fra/RMANDB/backupset/2021_08_10/o1_mf_nnndf_TAG20210810T200604_jk61lwvf_.bkp
channel ORA_AUX_DISK_1: piece handle=/oracle/fra/RMANDB/backupset/2021_08_10/o1_mf_nnndf_TAG20210810T200604_jk61lwvf_.bkp tag=TAG20210810T200604
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:02:06
Finished restore at 2021-08-10:20:19:08
datafile 1 switched to datafile copy
input datafile copy RECID=49 STAMP=1080245948 file name=/oracle/TABLE_PITR/RMANDB/datafile/o1_mf_system_jk627gxj_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=50 STAMP=1080245948 file name=/oracle/TABLE_PITR/RMANDB/datafile/o1_mf_undotbs1_jk627h2x_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=51 STAMP=1080245948 file name=/oracle/TABLE_PITR/RMANDB/datafile/o1_mf_sysaux_jk627h2j_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2021-08-10:20:09:25','YYYY-MM-DD: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 2021-08-10:20:19:09
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 6 is already on disk as file /oracle/archives/1_6_1079643731.dbf
archived log for thread 1 with sequence 7 is already on disk as file /oracle/archives/1_7_1079643731.dbf
archived log file name=/oracle/archives/1_6_1079643731.dbf thread=1 sequence=6
archived log file name=/oracle/archives/1_7_1079643731.dbf thread=1 sequence=7
media recovery complete, elapsed time: 00:00:01
Finished recover at 2021-08-10:20:19:11
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 =
''/oracle/TABLE_PITR/RMANDB/controlfile/o1_mf_jk6274vr_.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 1610612016 bytes
Fixed Size 8658224 bytes
Variable Size 402653184 bytes
Database Buffers 1191182336 bytes
Redo Buffers 8118272 bytes
sql statement: alter system set control_files = ''/oracle/TABLE_PITR/RMANDB/controlfile/o1_mf_jk6274vr_.ctl'' comment= ''RMAN set'' scope=spfile
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 1610612016 bytes
Fixed Size 8658224 bytes
Variable Size 402653184 bytes
Database Buffers 1191182336 bytes
Redo Buffers 8118272 bytes
sql statement: alter database mount clone database
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2021-08-10:20:09:25','YYYY-MM-DD:HH24:MI:SS')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile 7 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 7;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
executing command: SET NEWNAME
Starting restore at 2021-08-10:20:20:18
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=34 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 00007 to /oracle/TABLE_PITR/FVBG_PITR_RMANDB/datafile/o1_mf_users_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /oracle/fra/RMANDB/backupset/2021_08_10/o1_mf_nnndf_TAG20210810T200604_jk61lwvf_.bkp
channel ORA_AUX_DISK_1: piece handle=/oracle/fra/RMANDB/backupset/2021_08_10/o1_mf_nnndf_TAG20210810T200604_jk61lwvf_.bkp tag=TAG20210810T200604
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 2021-08-10:20:20:19
datafile 7 switched to datafile copy
input datafile copy RECID=53 STAMP=1080246019 file name=/oracle/TABLE_PITR/FVBG_PITR_RMANDB/datafile/o1_mf_users_jk62flj7_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2021-08-10:20:09:25','YYYY-MM-DD:HH24:MI:SS')";
# online the datafiles restored or switched
sql clone "alter database datafile 7 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 7 online
Starting recover at 2021-08-10:20:20:19
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 6 is already on disk as file /oracle/archives/1_6_1079643731.dbf
archived log for thread 1 with sequence 7 is already on disk as file /oracle/archives/1_7_1079643731.dbf
archived log file name=/oracle/archives/1_6_1079643731.dbf thread=1 sequence=6
archived log file name=/oracle/archives/1_7_1079643731.dbf thread=1 sequence=7
media recovery complete, elapsed time: 00:00:01
Finished recover at 2021-08-10:20:20:21
database opened
contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/oracle/TABLE_PITR''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/oracle/TABLE_PITR''";
}
executing Memory Script
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/oracle/TABLE_PITR''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/oracle/TABLE_PITR''
Performing export of tables...
EXPDP> Starting "SYS"."TSPITR_EXP_Fvbg_dEen":
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
EXPDP> . . exported "BSS"."PITR" 5.070 KB 1 rows
EXPDP> Master table "SYS"."TSPITR_EXP_Fvbg_dEen" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_Fvbg_dEen is:
EXPDP> /oracle/TABLE_PITR/tspitr_Fvbg_51439.dmp
EXPDP> Job "SYS"."TSPITR_EXP_Fvbg_dEen" successfully completed at Tue Aug 10 20:20:59 2021 elapsed 0 00:00:22
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_Fvbg_Bugd" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_Fvbg_Bugd":
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
IMPDP> . . imported "BSS"."TABLE_PITR" 5.070 KB 1 rows
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
IMPDP> Job "SYS"."TSPITR_IMP_Fvbg_Bugd" successfully completed at Tue Aug 10 20:21:16 2021 elapsed 0 00:00:07
Import completed
Removing automatic instance
Automatic instance removed
auxiliary instance file /oracle/TABLE_PITR/RMANDB/datafile/o1_mf_temp_jk62ckfk_.tmp deleted
auxiliary instance file /oracle/TABLE_PITR/FVBG_PITR_RMANDB/onlinelog/o1_mf_3_jk62fq15_.log deleted
auxiliary instance file /oracle/TABLE_PITR/FVBG_PITR_RMANDB/onlinelog/o1_mf_2_jk62fofb_.log deleted
auxiliary instance file /oracle/TABLE_PITR/FVBG_PITR_RMANDB/onlinelog/o1_mf_1_jk62fods_.log deleted
auxiliary instance file /oracle/TABLE_PITR/FVBG_PITR_RMANDB/datafile/o1_mf_users_jk62flj7_.dbf deleted
auxiliary instance file /oracle/TABLE_PITR/RMANDB/datafile/o1_mf_sysaux_jk627h2j_.dbf deleted
auxiliary instance file /oracle/TABLE_PITR/RMANDB/datafile/o1_mf_undotbs1_jk627h2x_.dbf deleted
auxiliary instance file /oracle/TABLE_PITR/RMANDB/datafile/o1_mf_system_jk627gxj_.dbf deleted
auxiliary instance file /oracle/TABLE_PITR/RMANDB/controlfile/o1_mf_jk6274vr_.ctl deleted
auxiliary instance file tspitr_Fvbg_51439.dmp deleted
Finished recover at 2021-08-10:20:21:19
O resultado da recuperação está aí:
RMAN> SELECT * FROM BSS.TABLE_PITR;
DESCRICAO
--------------------------------------------------
PITR DO BRUNO
Obs: Este procedimento foi criado pelo senhor Ahmed Baraka (www.ahmedbaraka.com) e foi apenas reproduzido por mim em um laboratório pessoal para fins de aprendizado.