Performing database point-in-time recovery (DBPITR) when the recovery point is not definite

Algumas vezes, devido algum processo indevido, precisamos recuperar o banco de dados em um ponto no tempo não conhecido, e este artigo explorará como podemos proceder nessas situações.

Reconhecendo nosso laboratório:

[oracle@oel8 ~]$ rman target /
 
Recovery Manager: Release 18.0.0.0.0 - Production on Tue Aug 3 20:44:55 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

Fazendo o backup nosso de cada dia:

RMAN> BACKUP DATABASE;
 
Starting backup at 2021-08-03:20:46:57
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=72 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-03:20:46:58
channel ORA_DISK_1: finished piece 1 at 2021-08-03:20:47:23
piece handle=/oracle/fra/RMANDB/backupset/2021_08_03/o1_mf_nnndf_TAG20210803T204658_jjmoclj6_.bkp tag=TAG20210803T204658 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:25
Finished backup at 2021-08-03:20:47:23
 
Starting Control File and SPFILE Autobackup at 2021-08-03:20:47:23
piece handle=/oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079642843_jjmodcr6_.bkp comment=NONE
Finished Control File and SPFILE Autobackup at 2021-08-03:20:47:24

Temos uma tabela já criada no ambiente que será a nossa referência. Vamos coletar o horário atual, o considerando o TEMPO1:

RMAN> ALTER SYSTEM SWITCH LOGFILE;
 
Statement processed
 
RMAN> SELECT * FROM BSS.PITR;
 
DESCRICAO
--------------------------------------------------
PITR DO BRUNO
 
RMAN> SELECT TO_CHAR(SYSDATE,'YYYY-MM-DD:HH24:MI:SS') FROM DUAL;
 
TO_CHAR(SYSDATE,'YY
-------------------
2021-08-03:20:49:39

Agora droparemos a tabela e coletaremos o TEMPO2:

RMAN> ALTER SYSTEM SWITCH LOGFILE;
 
Statement processed
 
RMAN> DROP TABLE BSS.PITR;
 
Statement processed
 
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-03:20:50:41

Imaginemos que o ponto no tempo escolhido para a recuperação seja o TEMPO2 (ou seja, aquele que já não tem a tabela no banco de dados). Realizando processo de restore/recover:

SHUTDOWN IMMEDIATE;
STARTUP NOMOUNT;
SET DBID <DBID>;
RESTORE CONTROLFILE FROM AUTOBACKUP;
ALTER DATABASE MOUNT;
RUN { SET UNTIL TIME '<YYYY-MM-DD:HH24:MI:SS>';
RESTORE DATABASE;
RECOVER DATABASE;}

Logs:

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    1610612016 bytes
 
Fixed Size                     8658224 bytes
Variable Size                520093696 bytes
Database Buffers            1073741824 bytes
Redo Buffers                   8118272 bytes
 
RMAN> SET DBID 3825250984;
 
executing command: SET DBID
 
RMAN> RESTORE CONTROLFILE FROM AUTOBACKUP;
 
Starting restore at 2021-08-03:20:53:51
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=38 device type=DISK
 
recovery area destination: /oracle/fra
database name (or database unique name) used for search: RMANDB
channel ORA_DISK_1: AUTOBACKUP /oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079642843_jjmodcr6_.bkp found in the recovery area
channel ORA_DISK_1: looking for AUTOBACKUP on day: 20210803
channel ORA_DISK_1: restoring control file from AUTOBACKUP /oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079642843_jjmodcr6_.bkp
channel ORA_DISK_1: control file restore from AUTOBACKUP complete
output file name=/oracle/dados/RMANDB/controlfile/o1_mf_h8nytrhd_.ctl
output file name=/oracle/fra/RMANDB/controlfile/o1_mf_h8nytrty_.ctl
Finished restore at 2021-08-03:20:53:52
 
RMAN> ALTER DATABASE MOUNT;
 
released channel: ORA_DISK_1
Statement processed
 
RMAN> RUN { SET UNTIL TIME '2021-08-03:20:50:41';
RESTORE DATABASE;
RECOVER DATABASE;}2> 3>
 
executing command: SET until clause
 
Starting restore at 2021-08-03:20:54:18
Starting implicit crosscheck backup at 2021-08-03:20:54:18
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=44 device type=DISK
Crosschecked 1 objects
Finished implicit crosscheck backup at 2021-08-03:20:54:18
 
Starting implicit crosscheck copy at 2021-08-03:20:54:18
using channel ORA_DISK_1
Finished implicit crosscheck copy at 2021-08-03:20:54:18
 
searching for all files in the recovery area
cataloging files...
cataloging done
 
List of Cataloged Files
=======================
File Name: /oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079642843_jjmodcr6_.bkp
 
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 00001 to /oracle/dados/RMANDB/datafile/o1_mf_system_h8nynqfx_.dbf
channel ORA_DISK_1: restoring datafile 00002 to /oracle/dados/RMANDB/datafile/ts_hipo_catalog.dbf
channel ORA_DISK_1: restoring datafile 00003 to /oracle/dados/RMANDB/datafile/o1_mf_sysaux_h8nyq35q_.dbf
channel ORA_DISK_1: restoring datafile 00004 to /oracle/dados/RMANDB/datafile/o1_mf_undotbs1_h8nyrjdr_.dbf
channel ORA_DISK_1: restoring datafile 00005 to /oracle/dados/RMANDB/datafile/ts_cortex_catalog.dbf
channel ORA_DISK_1: restoring datafile 00007 to /oracle/dados/RMANDB/datafile/o1_mf_users_h8nyrkn7_.dbf
channel ORA_DISK_1: reading from backup piece /oracle/fra/RMANDB/backupset/2021_08_03/o1_mf_nnndf_TAG20210803T204658_jjmoclj6_.bkp
channel ORA_DISK_1: piece handle=/oracle/fra/RMANDB/backupset/2021_08_03/o1_mf_nnndf_TAG20210803T204658_jjmoclj6_.bkp tag=TAG20210803T204658
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:55
Finished restore at 2021-08-03:20:55:13
 
Starting recover at 2021-08-03:20:55:14
using channel ORA_DISK_1
 
starting media recovery
 
archived log for thread 1 with sequence 2 is already on disk as file /oracle/dados/RMANDB/onlinelog/o1_mf_2_jjml062p_.log
archived log for thread 1 with sequence 3 is already on disk as file /oracle/dados/RMANDB/onlinelog/o1_mf_3_jjml0g5l_.log
archived log for thread 1 with sequence 4 is already on disk as file /oracle/dados/RMANDB/onlinelog/o1_mf_1_jjmkzz6r_.log
archived log file name=/oracle/archives/1_1_1079640180.dbf thread=1 sequence=1
archived log file name=/oracle/dados/RMANDB/onlinelog/o1_mf_2_jjml062p_.log thread=1 sequence=2
archived log file name=/oracle/dados/RMANDB/onlinelog/o1_mf_3_jjml0g5l_.log thread=1 sequence=3
archived log file name=/oracle/dados/RMANDB/onlinelog/o1_mf_1_jjmkzz6r_.log thread=1 sequence=4
media recovery complete, elapsed time: 00:00:01
Finished recover at 2021-08-03:20:55:15

O pulo do gato agora é abrirmos o banco de dados em READ ONLY para validar se o tempo definido na recuperação é o correto (ou seja, que nos habilite a recuperar a tabela dropada):

RMAN> ALTER DATABASE OPEN READ ONLY;
 
Statement processed
 
RMAN> SELECT * FROM BSS.PITR;
 
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of sql statement command at 08/03/2021 20:56:46
ORA-00942: table or view does not exist

Como o tempo definido não era o correto, vamos tentar com o TEMPO1:

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    1610612016 bytes
 
Fixed Size                     8658224 bytes
Variable Size                520093696 bytes
Database Buffers            1073741824 bytes
Redo Buffers                   8118272 bytes
 
RMAN> SET DBID 3825250984;
 
executing command: SET DBID
 
RMAN> RESTORE CONTROLFILE FROM AUTOBACKUP;
 
Starting restore at 2021-08-03:20:58:41
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=38 device type=DISK
 
recovery area destination: /oracle/fra
database name (or database unique name) used for search: RMANDB
channel ORA_DISK_1: AUTOBACKUP /oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079642843_jjmodcr6_.bkp found in the recovery area
channel ORA_DISK_1: looking for AUTOBACKUP on day: 20210803
channel ORA_DISK_1: restoring control file from AUTOBACKUP /oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079642843_jjmodcr6_.bkp
channel ORA_DISK_1: control file restore from AUTOBACKUP complete
output file name=/oracle/dados/RMANDB/controlfile/o1_mf_h8nytrhd_.ctl
output file name=/oracle/fra/RMANDB/controlfile/o1_mf_h8nytrty_.ctl
Finished restore at 2021-08-03:20:58:42
 
RMAN> ALTER DATABASE MOUNT;
 
released channel: ORA_DISK_1
Statement processed
 
RMAN> RUN { SET UNTIL TIME '2021-08-03:20:49:39';
RESTORE DATABASE;
RECOVER DATABASE;}2> 3>
 
executing command: SET until clause
 
Starting restore at 2021-08-03:20:59:08
Starting implicit crosscheck backup at 2021-08-03:20:59:08
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=44 device type=DISK
Crosschecked 1 objects
Finished implicit crosscheck backup at 2021-08-03:20:59:09
 
Starting implicit crosscheck copy at 2021-08-03:20:59:09
using channel ORA_DISK_1
Finished implicit crosscheck copy at 2021-08-03:20:59:09
 
searching for all files in the recovery area
cataloging files...
cataloging done
 
List of Cataloged Files
=======================
File Name: /oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079642843_jjmodcr6_.bkp
 
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 00001 to /oracle/dados/RMANDB/datafile/o1_mf_system_h8nynqfx_.dbf
channel ORA_DISK_1: restoring datafile 00002 to /oracle/dados/RMANDB/datafile/ts_hipo_catalog.dbf
channel ORA_DISK_1: restoring datafile 00003 to /oracle/dados/RMANDB/datafile/o1_mf_sysaux_h8nyq35q_.dbf
channel ORA_DISK_1: restoring datafile 00004 to /oracle/dados/RMANDB/datafile/o1_mf_undotbs1_h8nyrjdr_.dbf
channel ORA_DISK_1: restoring datafile 00005 to /oracle/dados/RMANDB/datafile/ts_cortex_catalog.dbf
channel ORA_DISK_1: restoring datafile 00007 to /oracle/dados/RMANDB/datafile/o1_mf_users_h8nyrkn7_.dbf
channel ORA_DISK_1: reading from backup piece /oracle/fra/RMANDB/backupset/2021_08_03/o1_mf_nnndf_TAG20210803T204658_jjmoclj6_.bkp
channel ORA_DISK_1: piece handle=/oracle/fra/RMANDB/backupset/2021_08_03/o1_mf_nnndf_TAG20210803T204658_jjmoclj6_.bkp tag=TAG20210803T204658
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:55
Finished restore at 2021-08-03:21:00:04
 
Starting recover at 2021-08-03:21:00:04
using channel ORA_DISK_1
 
starting media recovery
 
archived log for thread 1 with sequence 2 is already on disk as file /oracle/dados/RMANDB/onlinelog/o1_mf_2_jjml062p_.log
archived log file name=/oracle/archives/1_1_1079640180.dbf thread=1 sequence=1
archived log file name=/oracle/dados/RMANDB/onlinelog/o1_mf_2_jjml062p_.log thread=1 sequence=2
media recovery complete, elapsed time: 00:00:00
Finished recover at 2021-08-03:21:00:05

Como o banco em modo de leitura, constatamos que a tabela está lá, recuperada:

RMAN> ALTER DATABASE OPEN READ ONLY;
 
Statement processed
 
RMAN> SELECT * FROM BSS.PITR;
 
DESCRICAO
--------------------------------------------------
PITR DO BRUNO

Com isso, podemos concluir a recuperação abrindo o banco de dados em resetlogs:

RMAN> SHUTDOWN IMMEDIATE;
 
database closed
database dismounted
Oracle instance shut down
 
RMAN> STARTUP MOUNT;
 
connected to target database (not started)
Oracle instance started
database mounted
 
Total System Global Area    1610612016 bytes
 
Fixed Size                     8658224 bytes
Variable Size                520093696 bytes
Database Buffers            1073741824 bytes
Redo Buffers                   8118272 bytes
 
RMAN> ALTER DATABASE OPEN RESETLOGS;
 
Statement processed
 
RMAN> SELECT * FROM BSS.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.

Leave a Comment

Your email address will not be published.