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

Antes de entrar especificamente no assunto do artigo, é interessante expor o recurso interessante na tecnologia Oracle quanto à recuperação em um ponto no tempo específico. Podemos usufruir desse conceito a nível de database, tablespace ou tabela. A definição deste ponto pode ser usada como SCN, Log Sequence, Restore Point ou Tempo (SET UNTIL TIME). Como pré-requisito, o banco de dados deve estar rodando no modo Archivelog, e precisamos ter um backup do ambiente antes do SCN desejado. Quando realizamos o PITR, devemos abrir o banco de dados em RESETLOGS, e quando isso ocorre, temos:

  • Se os Online Redo Logs estão disponíveis, o CURRENT é “arquivado”;
  • Se os Online Redo Logs estão indisponíveis, eles são criados automaticamente;
  • É definido nos datafiles e redo logs o novo RESETLOGS SCN ;
  • O Database Incarnation é incrementado (quanto à este item, é bom expor que um restore deve ser realizado de backups que foram realizados com o mesmo incarnation).

Neste artigo, vamos simular uma situação de Database Point-in-time Recovery onde sabemos exatamente o momento no tempo que iremos usar na recuperação.

Reconhecendo o ambiente laboratório:

[oracle@oel8 ~]$ rman target /
 
Recovery Manager: Release 18.0.0.0.0 - Production on Tue Aug 3 19:23:38 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 um backup do nosso banco de dados:

RMAN> BACKUP DATABASE;
 
Starting backup at 2021-08-03:19:25:27
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=70 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:19:25:27
channel ORA_DISK_1: finished piece 1 at 2021-08-03:19:27:42
piece handle=/oracle/fra/RMANDB/backupset/2021_08_03/o1_mf_nnndf_TAG20210803T192527_jjmjlrmq_.bkp tag=TAG20210803T192527 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:02:15
Finished backup at 2021-08-03:19:27:42
 
Starting Control File and SPFILE Autobackup at 2021-08-03:19:27:43
piece handle=/oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079638063_jjmjq0bx_.bkp comment=NONE
Finished Control File and SPFILE Autobackup at 2021-08-03:19:27:46

Vamos criar um owner e tabela para termos o parâmetro de comparação com o ambiente que será recuperado:

RMAN> ALTER SYSTEM SWITCH LOGFILE;
 
Statement processed
 
RMAN> CREATE USER BSS IDENTIFIED BY oracle;
 
Statement processed
 
RMAN> GRANT DBA TO BSS;
 
Statement processed
 
RMAN> CREATE TABLE BSS.PITR (DESCRICAO VARCHAR2(50));
 
Statement processed
 
RMAN> INSERT INTO BSS.PITR (DESCRICAO) VALUES ('PITR DO BRUNO');
 
Statement processed
 
RMAN> COMMIT;
 
Statement processed

Depois disso, vamos coletar o dia e hora do nosso ambiente, que será usado no processo de recuperação:

RMAN> SELECT TO_CHAR(SYSDATE,'YYYY-MM-DD:HH24:MI:SS') FROM DUAL;
 
TO_CHAR(SYSDATE,'YY
-------------------
2021-08-03:19:32:31

Para reproduzir um problema que justifique a recuperação, vamos dropar nossa tabela de teste:

RMAN> ALTER SYSTEM SWITCH LOGFILE;
 
Statement processed
 
RMAN> DROP TABLE BSS.PITR;
 
Statement processed

Podemos baixar a instância e montar o banco de dados. Antes disso coleto o incarnation atual do banco para podermos comparar no final do processo:

RMAN> LIST INCARNATION;
 
 
List of Database Incarnations
DB Key  Inc Key DB Name  DB ID            STATUS  Reset SCN  Reset Time
------- ------- -------- ---------------- --- ---------- ----------
1       1       RMANDB   3825250984       PARENT  1          2018-02-07:19:20:08
2       2       RMANDB   3825250984       CURRENT 1477662    2020-04-05:21:44:14
 
RMAN> ALTER SYSTEM SWITCH LOGFILE;
 
Statement processed
 
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

De posse do ponto que queremos de recuperação, disparo o comando abaixo para o restore e recover do banco:

RUN { SET UNTIL TIME '2021-08-03:19:32:31'; 
        RESTORE DATABASE; 
        RECOVER DATABASE;}

Log de execução:

RMAN> RUN { SET UNTIL TIME '2021-08-03:19:32:31';
                RESTORE DATABASE;
                RECOVER DATABASE;}2> 3>
 
executing command: SET until clause
 
Starting restore at 2021-08-03:19:45:57
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=45 device type=DISK
 
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_TAG20210803T192527_jjmjlrmq_.bkp
channel ORA_DISK_1: piece handle=/oracle/fra/RMANDB/backupset/2021_08_03/o1_mf_nnndf_TAG20210803T192527_jjmjlrmq_.bkp tag=TAG20210803T192527
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:01:55
Finished restore at 2021-08-03:19:47:53
 
Starting recover at 2021-08-03:19:47:53
using channel ORA_DISK_1
 
starting media recovery
 
archived log for thread 1 with sequence 117 is already on disk as file /oracle/archives/1_117_1036964654.dbf
archived log for thread 1 with sequence 118 is already on disk as file /oracle/archives/1_118_1036964654.dbf
archived log file name=/oracle/archives/1_117_1036964654.dbf thread=1 sequence=117
media recovery complete, elapsed time: 00:00:01
Finished recover at 2021-08-03:19:47:54

Abrindo o banco de dados em RESETLOGS e validando se nossa tabela teste está recuperada:

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

E como era previsto, um novo incarnation foi incrementado:

RMAN> LIST INCARNATION OF DATABASE;
 
 
List of Database Incarnations
DB Key  Inc Key DB Name  DB ID            STATUS  Reset SCN  Reset Time
------- ------- -------- ---------------- --- ---------- ----------
1       1       RMANDB   3825250984       PARENT  1          2018-02-07:19:20:08
2       2       RMANDB   3825250984       PARENT  1477662    2020-04-05:21:44:14
3       3       RMANDB   3825250984       CURRENT 3085187    2021-08-03:19:49:35

Imaginemos que o desastre em si exigisse que também recuperássemos o controlfile. Podemos realizar a recuperação conforme exemplo abaixo (e por conta do restore do controlfile, é mister definirmos o DBID do banco):

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;}

Log de execução. Vemos que um erro RMAN-20207 é exibido ao tentar restaurar o banco de dados, pois o incarnation do backup é diferente do atual:

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:19:54:57
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_1079639397_jjml0or0_.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_1079639397_jjml0or0_.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:19:55:00
 
RMAN> ALTER DATABASE MOUNT;
 
released channel: ORA_DISK_1
Statement processed
 
RMAN> RUN { SET UNTIL TIME '2021-08-03:19:32:31';
                RESTORE DATABASE;
                RECOVER DATABASE;}2> 3>
 
executing command: SET until clause
 
Starting restore at 2021-08-03:19:56:19
Starting implicit crosscheck backup at 2021-08-03:19:56:19
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=44 device type=DISK
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of restore command at 08/03/2021 19:56:20
RMAN-20207: UNTIL TIME or RECOVERY WINDOW is before RESETLOGS time

Para resolver, resetamos o incarnation usado no backup, conforme abaixo:

RMAN> LIST INCARNATION;
 
 
List of Database Incarnations
DB Key  Inc Key DB Name  DB ID            STATUS  Reset SCN  Reset Time
------- ------- -------- ---------------- --- ---------- ----------
1       1       RMANDB   3825250984       PARENT  1          2018-02-07:19:20:08
2       2       RMANDB   3825250984       PARENT  1477662    2020-04-05:21:44:14
3       3       RMANDB   3825250984       CURRENT 3085187    2021-08-03:19:49:35
 
RMAN> reset database to incarnation 2;
 
Starting implicit crosscheck backup at 2021-08-03:20:00:55
released channel: ORA_DISK_1
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=44 device type=DISK
Crosschecked 2 objects
Finished implicit crosscheck backup at 2021-08-03:20:00:55
 
Starting implicit crosscheck copy at 2021-08-03:20:00:55
using channel ORA_DISK_1
Crosschecked 1 objects
Finished implicit crosscheck copy at 2021-08-03:20:00:56
 
searching for all files in the recovery area
cataloging files...
cataloging done
 
List of Cataloged Files
=======================
File Name: /oracle/fra/RMANDB/autobackup/2021_06_25/o1_mf_s_1076133020_jfc66f40_.bkp
File Name: /oracle/fra/RMANDB/autobackup/2021_08_03/o1_mf_s_1079639397_jjml0or0_.bkp
File Name: /oracle/fra/RMANDB/backupset/2021_06_25/o1_mf_nnndf_DUAL_jfc66cg0_.bkp
File Name: /oracle/fra/RMANDB/o1_mf_annnn_ARC_BS_jcy7sbrx_.bkp
 
database reset to incarnation 2

Recuperado com sucesso:

RMAN> RUN { SET UNTIL TIME '2021-08-03:19:32:31';
                RESTORE DATABASE;
                RECOVER DATABASE;}2> 3>
 
executing command: SET until clause
 
Starting restore at 2021-08-03:20:01:25
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_TAG20210803T192527_jjmjlrmq_.bkp
channel ORA_DISK_1: piece handle=/oracle/fra/RMANDB/backupset/2021_08_03/o1_mf_nnndf_TAG20210803T192527_jjmjlrmq_.bkp tag=TAG20210803T192527
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:02:20
 
Starting recover at 2021-08-03:20:02:20
using channel ORA_DISK_1
 
starting media recovery
 
archived log for thread 1 with sequence 117 is already on disk as file /oracle/archives/1_117_1036964654.dbf
archived log for thread 1 with sequence 118 is already on disk as file /oracle/archives/1_118_1036964654.dbf
archived log file name=/oracle/archives/1_117_1036964654.dbf thread=1 sequence=117
archived log file name=/oracle/archives/1_118_1036964654.dbf thread=1 sequence=118
media recovery complete, elapsed time: 00:00:01
Finished recover at 2021-08-03:20:02:21
 
RMAN> ALTER DATABASE OPEN RESETLOGS;
 
Statement processed

Nossa tabela está aí:

RMAN> SELECT * FROM BSS.PITR;
 
DESCRICAO
--------------------------------------------------
PITR DO BRUNO
 
RMAN> LIST INCARNATION;
 
 
List of Database Incarnations
DB Key  Inc Key DB Name  DB ID            STATUS  Reset SCN  Reset Time
------- ------- -------- ---------------- --- ---------- ----------
1       1       RMANDB   3825250984       PARENT  1          2018-02-07:19:20:08
2       2       RMANDB   3825250984       PARENT  1477662    2020-04-05:21:44:14
3       3       RMANDB   3825250984       ORPHAN  3085187    2021-08-03:19:49:35
4       4       RMANDB   3825250984       CURRENT 3085187    2021-08-03:20:03:00

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.