Oracle18c-RMAN recovery through RESETLOGS

Description:- 

In this article we are going to see RMAN recovery through RESETLOGS.

Advantages of using Recovery Through Resetlogs feature:-

  • There is no need to perform a full backup after an incomplete recovery.
  • There is no need to recreate a new standby database after a failover operation.
  • You can take incremental backups based on full backups of a previous incarnation when you use RMAN.
  • Block media recovery can restore backups from parent incarnation backups and recover the corrupted blocks through a RESETLOGS operation.

Let’s start the Demo:-

Steps to perform RMAN recovery through RESETLOGS :-

To perform recovery through RESETLOGS you must have all archived logs generated after the most recent backup.

Step 1:- Check the log_archive format as ‘%r’

Oracle 10g introduces a new format specification for archived log files. This new format avoids overwriting archived redo log files with the same sequence number across incarnations.

SQL> show parameter log_archive_format
NAME                TYPE       VALUE
------------------ ----------- ----------------
log_archive_format string %t_%s_%r.dbf

The format specification of the log_archive_format string “%”r represents the resetlogs id. It will ensure that a unique name is constructed for the archived redo log file during RMAN restore and as well as restoring via SQL*plus auto recovery mode.

Note: The database would not start if you remove the %r from the log archive format specification.

INCARNATION:-

A database incarnation is created whenever you open the database with the RESETLOGS option.

The Current incarnation is the one in which the database is running at present.

The incarnation from which the current incarnation branched after a ALTER DATABASE OPEN RESETLOGS  was performed is called the Parent incarnation.

If you want to go back to some SCN which is not part of the Current database incarnation, we need to use the RESET DATABASE TO INCARNATION command as shown in the example below

Purpose of incarnations:-

An incarnation helps to identify redo streams which have the same SCN, but occurred at different points in time. This prevents the possibility of applying the wrong archive log file from a previous incarnation which could corrupt the database.

Suppose we are at incarnation 1 and are at SCN 100 in the database. I do a resetlogs and now the incarnation of the database becomes 2. Suppose we do another resetlogs and it so happens that the SCN at the time we did the resetlogs was also 100. Somewhere down the line later  we want to do a point in time recovery and want to recover the database until SCN 100. How does Oracle know which is the correct SCN and how far back in time should the database be rolled back to and which archive logs need to be applied?

This is where incarnations come in and we will see how we can set the database to a particular incarnation to enable RMAN to do a point in time recovery.

Step 2:-Let us check what the current incarnation of the database

[oracle@18c ~]$ rman target /

Recovery Manager: Release 18.0.0.0.0 - Production on Sat Aug 18 00:46:34 2018
Version 18.3.0.0.0

Copyright (c) 1982, 2018, Oracle and/or its affiliates. All rights reserved.

connected to target database: PROD18C (DBID=3984767297)

RMAN> LIST INCARNATION OF DATABASE;

using target database control file instead of recovery catalog

List of Database Incarnations
DB Key Inc Key DB Name DB ID STATUS Reset SCN Reset Time
------- ------- -------- ---------------- --- ---------- ----------
1 1 PROD18C 3984767297 PARENT 1 07-FEB-18
2 2 PROD18C 3984767297 PARENT 1477662 14-AUG-18
3 3 PROD18C 3984767297 PARENT 1585689 15-AUG-18
4 4 PROD18C 3984767297 PARENT 1694352 17-AUG-18
5 5 PROD18C 3984767297 PARENT 1694353 17-AUG-18
6 6 PROD18C 3984767297 PARENT 1695382 17-AUG-18
7 7 PROD18C 3984767297 PARENT 1697963 17-AUG-18
8 8 PROD18C 3984767297 CURRENT 1755525 17-AUG-18

Step 3:- Note the CURRENT_SCN of the database.

RMAN> select current_scn from v$database;

CURRENT_SCN
-----------
1759315

Step 4:-

Now, let us make a change in the database which we will then try to undo by restoring  and recovering the database to a point in time before the media failure or as in this case, a wrong transaction has happened.

Simulate the wrong DML execution,

SQL> conn hari/oracle;
Connected.
SQL> select count(*) from emp;

COUNT(*)
----------
100000

SQL> delete from emp where rownum < 1001;

1000 rows deleted.

SQL> commit;

Commit complete.

SQL> select count(*) from emp;

COUNT(*)
----------
99000

Step 5:- Shutdown and mount the  database

SQL> shut immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.


SQL> startup mount;
ORACLE instance started.                                                Total System Global Area 1660943808 bytes
Fixed Size 8658368 bytes
Variable Size 1056964608 bytes
Database Buffers 587202560 bytes
Redo Buffers 8118272 bytes
Database mounted.

Step 6:- Now we will rollback the database to an SCN before the delete operation was performed.

[oracle@18c ~]$ rman target /

Recovery Manager: Release 18.0.0.0.0 - Production on Sat Aug 18 00:52:25 2018
Version 18.3.0.0.0

Copyright (c) 1982, 2018, Oracle and/or its affiliates. All rights reserved.

connected to target database: PROD18C (DBID=3984767297, not open)

RMAN> run
2> {
3> set until scn 1759315;
4> restore database;
5> recover database;
6> }

executing command: SET until clause

Starting restore at 18-AUG-18
using target database control file instead of recovery catalog
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 /u01/app/oracle/oradata/PROD18C/system01.dbf
channel ORA_DISK_1: restoring datafile 00002 to /u01/app/oracle/oradata/PROD18C/dbwrtbs02.dbf
channel ORA_DISK_1: restoring datafile 00003 to /u01/app/oracle/oradata/PROD18C/sysaux01.dbf
channel ORA_DISK_1: restoring datafile 00004 to /u01/app/oracle/oradata/PROD18C/undotbs01.dbf
channel ORA_DISK_1: restoring datafile 00005 to /u01/app/oracle/oradata/PROD18C/dbwrtbs01.dbf
channel ORA_DISK_1: restoring datafile 00007 to /u01/app/oracle/oradata/PROD18C/users01.dbf
channel ORA_DISK_1: reading from backup piece /u01/fra/PROD18C/backupset/2018_08_17/o1_mf_nnndf_TAG20180817T230028_fqg1knnf_.bkp
channel ORA_DISK_1: piece handle=/u01/fra/PROD18C/backupset/2018_08_17/o1_mf_nnndf_TAG20180817T230028_fqg1knnf_.bkp tag=TAG20180817T230028
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:01:25
Finished restore at 18-AUG-18

Starting recover at 18-AUG-18
using channel ORA_DISK_1

starting media recovery

archived log for thread 1 with sequence 28 is already on disk as file /u01/fra/PROD18C/archivelog/2018_08_17/o1_mf_1_28_fqg1m1qo_.arc
archived log file name=/u01/fra/PROD18C/archivelog/2018_08_17/o1_mf_1_28_fqg1m1qo_.arc thread=1 sequence=28
media recovery complete, elapsed time: 00:00:02
Finished recover at 18-AUG-18

RMAN> alter database open resetlogs;

Statement processed

Step 7:- After open resetlogs,check the table  count.

We can now see that the deleted rows have been recovered and the number of rows in the table is now the same as before the delete operation was performed.

SQL> select count(*) from hari.emp;

COUNT(*)
---------
100000

Step 8:- Now let us check what the incarnation of the database,

[oracle@18c ~]$ rman target /

Recovery Manager: Release 18.0.0.0.0 - Production on Sat Aug 18 01:56:59 2018
Version 18.3.0.0.0

Copyright (c) 1982, 2018, Oracle and/or its affiliates. All rights reserved.

connected to target database: PROD18C (DBID=3984767297)

RMAN> list incarnation of database;

using target database control file instead of recovery catalog

List of Database Incarnations
DB Key Inc Key DB Name DB ID STATUS Reset SCN Reset Time
------- ------- -------- ---------------- --- ------
1 1 PROD18C 3984767297 PARENT 1 07-FEB-18
2 2 PROD18C 3984767297 PARENT 1477662 14-AUG-18
3 3 PROD18C 3984767297 PARENT 1585689 15-AUG-18
4 4 PROD18C 3984767297 PARENT 1694352 17-AUG-18
5 5 PROD18C 3984767297 PARENT 1694353 17-AUG-18
6 6 PROD18C 3984767297 PARENT 1695382 17-AUG-18
7 7 PROD18C 3984767297 PARENT 1697963 17-AUG-18
8 8 PROD18C 3984767297 PARENT 1755525 17-AUG-18
9 9 PROD18C 3984767297 CURRENT 1759316 18-AUG-18

The current incarnation of the database is 9 and since we have recovered the database until SCN 1759315, the RESET SCN has been set to the SCN 1759316.

The alert log file has lines below:

Incomplete Recovery applied until change 1759315 time 08/18/2018 00:47:43
2018-08-18T00:54:25.879829+05:30
Media Recovery Complete (prod18c)
Completed: alter database recover logfile '/u01/fra/PROD18C/archivelog/2018_08_17/o1_mf_1_28_fqg1m1qo_.arc'
2018-08-18T00:54:54.747977+05:30
alter database open resetlogs
2018-08-18T00:54:54.777271+05:30
RESETLOGS after incomplete recovery UNTIL CHANGE 1759315 time 08/18/2018 00:47:43
2018-08-18T00:54:55.507838+05:30
NET (PID:36995): Archived Log entry 65 added for T-1.S-1 ID 0xed877f00 LAD:1
Resetting resetlogs activation ID 3985080064 (0xed877f00)

Step 9:- Now let us make another delete from the emp  table.

SQL> conn hari/oracle;
Connected.
SQL> select count(*) from emp;

COUNT(*)
----------
100000

SQL> delete from emp where rownum < 10001;

10000 rows deleted.

SQL> commit;

Commit complete.

SQL> select count(*) from emp;

COUNT(*)
---------
90000

Step 10:- Now, let us shutdown the database, startup and mount it and try the same incomplete recovery which we tried earlier until the SCN 1759315

[oracle@18c ]$ rman target /

Recovery Manager: Release 18.0.0.0.0 - Production on Sat Aug 18 02:08:25 2018
Version 18.3.0.0.0

Copyright (c) 1982, 2018, Oracle and/or its affiliates. All rights reserved.

connected to target database: PROD18C (DBID=3984767297, not open)

RMAN> run
{
set until scn 1759315;
restore database;
recover database;
}2> 3> 4> 5> 6>

executing command: SET until clause

Starting restore at 18-AUG-18
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=45 device type=DISK
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of restore command at 08/18/2018 02:08:50
RMAN-20208: UNTIL CHANGE is before RESETLOGS change
  • We get the error RMAN-20208 because since the current incarnation of the database is 9 and we trying to go to an SCN before this incarnation.
  • So how do we go back to SCN 1759315 ?
  • For this to happen, we need to change the current incarnation (9) of the database to an older incarnation (8). The SCN 1759315 was present during the incarnation 8.
  • After resetting the incarnation to 8, we now see that the restore the database.

Step 11:- Reset incarnation of database.

RMAN> reset database to incarnation 8;

database reset to incarnation 8

Step 12:- Set the SCN number of incarnation 8 and try to restore & recover the database

RMAN> run
{
set until scn 1759315;
restore database;
recover database;
}2> 3> 4> 5> 6>

executing command: SET until clause

Starting restore at 18-AUG-18
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 /u01/app/oracle/oradata/PROD18C/system01.dbf
channel ORA_DISK_1: restoring datafile 00002 to /u01/app/oracle/oradata/PROD18C/dbwrtbs02.dbf
channel ORA_DISK_1: restoring datafile 00003 to /u01/app/oracle/oradata/PROD18C/sysaux01.dbf
channel ORA_DISK_1: restoring datafile 00004 to /u01/app/oracle/oradata/PROD18C/undotbs01.dbf
channel ORA_DISK_1: restoring datafile 00005 to /u01/app/oracle/oradata/PROD18C/dbwrtbs01.dbf
channel ORA_DISK_1: restoring datafile 00007 to /u01/app/oracle/oradata/PROD18C/users01.dbf
channel ORA_DISK_1: reading from backup piece /u01/fra/PROD18C/backupset/2018_08_17/o1_mf_nnndf_TAG20180817T230028_fqg1knnf_.bkp
channel ORA_DISK_1: piece handle=/u01/fra/PROD18C/backupset/2018_08_17/o1_mf_nnndf_TAG20180817T230028_fqg1knnf_.bkp tag=TAG20180817T230028
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:55
Finished restore at 18-AUG-18

Starting recover at 18-AUG-18
using channel ORA_DISK_1

starting media recovery

archived log for thread 1 with sequence 28 is already on disk as file /u01/fra/PROD18C/archivelog/2018_08_17/o1_mf_1_28_fqg1m1qo_.arc
archived log for thread 1 with sequence 1 is already on disk as file /u01/fra/PROD18C/archivelog/2018_08_18/o1_mf_1_1_fqg886t8_.arc
archived log file name=/u01/fra/PROD18C/archivelog/2018_08_17/o1_mf_1_28_fqg1m1qo_.arc thread=1 sequence=28
archived log file name=/u01/fra/PROD18C/archivelog/2018_08_18/o1_mf_1_1_fqg886t8_.arc thread=1 sequence=1
media recovery complete, elapsed time: 00:00:02
Finished recover at 18-AUG-18

Step 13:- Open the database using resetlogs option

Now we open the database with the ALTER DATABASE OPEN RESETOGS command and see that a new incarnation key (10) has been allocated to the database as the CURRENT incarnation and the previous incarnation (8) has become an ORPHAN incarnation.

SQL> alter database open resetlogs;

Database altered.

The incarnation key 10 now is the CURRENT incarnation of the database, and incarnations 9 become ORPHAN.

RMAN> list incarnation of database;

using target database control file instead of recovery catalog

List of Database Incarnations
DB Key Inc Key DB Name DB ID STATUS Reset SCN Reset Time
------- ------- -------- ---------------- --- ---------- ------
1 1 PROD18C 3984767297 PARENT 1 07-FEB-18
2 2 PROD18C 3984767297 PARENT 1477662 14-AUG-18
3 3 PROD18C 3984767297 PARENT 1585689 15-AUG-18
4 4 PROD18C 3984767297 PARENT 1694352 17-AUG-18
5 5 PROD18C 3984767297 PARENT 1694353 17-AUG-18
6 6 PROD18C 3984767297 PARENT 1695382 17-AUG-18
7 7 PROD18C 3984767297 PARENT 1697963 17-AUG-18
8 8 PROD18C 3984767297 PARENT 1755525 17-AUG-18
9 9 PROD18C 3984767297 ORPHAN 1759316 18-AUG-18
10 10 PROD18C 3984767297 CURRENT 1759316 18-AUG-18

Step 14:- Check the CURRENT_SCN and recovered table count. 

SQL> select current_scn from v$database;

CURRENT_SCN
------------
1760007
SQL> select count(*) from hari.emp;

COUNT(*)
----------
100000

The table recovered to the previous incarnation successfully and a new incarnation has been created.

Catch Me On:- Hariprasath Rajaram

Telegram:https://t.me/joinchat/I_f4DhGF_Zifr9YZvvMkRg
LinkedIn:https://www.linkedin.com/in/hari-prasath-aa65bb19/
Facebook:https://www.facebook.com/HariPrasathdba
FB Group:https://www.facebook.com/groups/894402327369506/
FB Page: https://www.facebook.com/dbahariprasath/?
Twitter: https://twitter.com/hariprasathdba

Leave a Reply

Your email address will not be published. Required fields are marked *