Pages

Wednesday, July 3, 2019

RECOVERY_SCENARIO : Recovery of a dropped tablespace

Recovery of a dropped tablespace

To recover from a case of a dropped tablespace, the Tablespace Point In Time Recovery (TSPITR) method cannot be used.

When you drop a tablespace, the controlfile will then no longer have any records of the tablespace which has been dropped. Attempts to use the RMAN RECOVER TABLESPACE command will return the RMAN error RMAN-06019 – “could not translate tablespace name” as shown below.

SQL> drop tablespace rman10 including contents and datafiles;

Tablespace dropped.

testdb:/u01/oracle/diag/rdbms/apex/apex/trace> rman target /

Recovery Manager: Release 10.2.0.4.0 - Production on Mon Aug 3 11:53:58 2009

Copyright (c) 1982, 2007, Oracle.  All rights reserved.

connected to target database: TESTDB (DBID=2469552796)

RMAN> restore tablespace rman10;

Starting restore at 03-AUG-09
using target database control file instead of recovery catalog
allocated channel: ORA_SBT_TAPE_1
channel ORA_SBT_TAPE_1: sid=141 devtype=SBT_TAPE
channel ORA_SBT_TAPE_1: Data Protection for Oracle: version 5.5.1.0
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=140 devtype=DISK
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of restore command at 08/03/2009 11:54:11
RMAN-20202: tablespace not found in the recovery catalog

So to recover from a dropped tablespace, we have two options:

1)      Do a point in time recovery of the whole database until the time the tablespace was dropped.
2)      Create a clone of the database from a valid backup, export the required tables from the tablespace which has been dropped, recreate the tablespace and then import the tables from the clone.

The first option will require an outage of the entire database and the entire database will be rolled back in tine in order to recover the tablespace. The second option can be peformed online, but we will need to factor in the disk space requirements to create a clone of the database from which the tablespace has been dropped.

Let us examine the first option using the example shown below:

In this example, CONTROLFILE AUTOBACKUP has been turned on and Flashback has been enabled for the database.
With Flashback enabled, the db_recovery_file_dest will have a sub-directory ‘autobackup’ as shown below for each day

ttestdb:/u02/oradata/testdb/TESTDB/autobackup/2009_08_03> ls -lrt
total 63040
-rw-r-----    1 oracle   dba         6455296 Aug  3 10:22 o1_mf_s_693915680_57dlgcqh_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 11:49 o1_mf_s_693920955_57dqkw0j_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 13:28 o1_mf_s_693926889_57dxcbdx_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 14:18 o1_mf_s_693928526_57f094n9_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 14:20 o1_mf_s_693930026_57f0fbo2_.bkp

When we drop the tablespace we are changing the structure of the database and since controlfile autobackup has been turned on, we see another backup file has been created in the autobackup location in the flash recovery area on disk.

SQL> drop tablespace arul including contents and datafiles;

Tablespace dropped.

SQL> quit
Disconnected from Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
testdb:/u02/oradata/testdb/TESTDB/autobackup/2009_08_03> ls -lrt
total 75648
-rw-r-----    1 oracle   dba         6455296 Aug  3 10:22 o1_mf_s_693915680_57dlgcqh_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 11:49 o1_mf_s_693920955_57dqkw0j_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 13:28 o1_mf_s_693926889_57dxcbdx_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 14:18 o1_mf_s_693928526_57f094n9_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 14:20 o1_mf_s_693930026_57f0fbo2_.bkp
-rw-r-----    1 oracle   dba         6455296 Aug  3 14:38 o1_mf_s_693931114_57f1hbmo_.bkp

We then shutdown the database, startup in nomount mode and attempt to restore the controlfile from autobackup.

The most recent controlfile autobackup has been restored, but since this has been taken after the tablespace was dropped, the tablespace which has been dropped (ARUL) is not referenced in the control file that we just restored. If we try to restore and recover the database, the dropped tablespace will not be restored.

SQL> startup nomount;
ORACLE instance started.

Total System Global Area  264241152 bytes
Fixed Size                  2083304 bytes
Variable Size             142607896 bytes
Database Buffers          113246208 bytes
Redo Buffers                6303744 bytes

RMAN> restore controlfile from autobackup;

Starting restore at 03-AUG-09
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=156 devtype=DISK

recovery area destination: /u02/oradata/testdb/
database name (or database unique name) used for search: TESTDB
channel ORA_DISK_1: autobackup found in the recovery area
channel ORA_DISK_1: autobackup found: /u02/oradata/testdb/TESTDB/autobackup/2009_08_03/o1_mf_s_693931114_57f1hbmo_.bkp
channel ORA_DISK_1: control file restore from autobackup complete
output filename=/u02/oradata/testdb/control01.ctl
output filename=/u02/oradata/testdb/control02.ctl
output filename=/u02/oradata/testdb/control03.ctl
Finished restore at 03-AUG-09

RMAN> alter database mount;

database mounted
released channel: ORA_DISK_1

RMAN> report schema;
...

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    1230     SYSTEM               ***     /u02/oradata/testdb/system01.dbf
2    1700     UNDOTBS1             ***     /u02/oradata/testdb/undotbs01.dbf
3    370      SYSAUX               ***     /u02/oradata/testdb/sysaux01.dbf
4    280      USERS                ***     /u02/oradata/backup/bkp.04klgv2b
5    131      EXAMPLE              ***     /u02/oradata/testdb/example01.dbf
6    150      USERS                ***     /u02/oradata/backup/bkp.06klgv3k
9    100      USERS                ***     /u02/oradata/backup/bkp.08klgv4i


We will need to restore a backup of the controlfile which contains records for the tablespace ARUL. We use the RESTORE CONTROLFILE FROM command to restore a specific controlfile autobackup.

RMAN>  restore controlfile from '/u02/oradata/testdb/TESTDB/autobackup/2009_08_03/o1_mf_s_693930026_57f0fbo2_.bkp';

Starting restore at 03-AUG-09
using channel ORA_DISK_1

channel ORA_DISK_1: restoring control file
channel ORA_DISK_1: restore complete, elapsed time: 00:00:02
output filename=/u02/oradata/testdb/control01.ctl
output filename=/u02/oradata/testdb/control02.ctl
output filename=/u02/oradata/testdb/control03.ctl
Finished restore at 03-AUG-09

RMAN> report schema;
.....

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    1230     SYSTEM               ***     /u02/oradata/testdb/system01.dbf
2    1700     UNDOTBS1             ***     /u02/oradata/testdb/undotbs01.dbf
3    370      SYSAUX               ***     /u02/oradata/testdb/sysaux01.dbf
4    280      USERS                ***     /u02/oradata/backup/bkp.04klgv2b
5    131      EXAMPLE              ***     /u02/oradata/testdb/example01.dbf
6    150      USERS                ***     /u02/oradata/backup/bkp.06klgv3k
7    0        ARUL                 ***     /u02/oradata/testdb/arul01.dbf
9    100      USERS                ***     /u02/oradata/backup/bkp.08klgv4i


The alert log will also show the time when the tablespace was dropped. We can also see that a controlfile autobackup has taken place after the tablespace was dropped.

drop tablespace arul including contents and datafiles
Mon Aug  3 14:38:34 2009
Deleted file /u02/oradata/testdb/arul01.dbf
Starting control autobackup
Control autobackup written to DISK device
        handle '/u02/oradata/testdb/TESTDB/autobackup/2009_08_03/o1_mf_s_693931114_57f1hbmo_.bkp'
Completed: drop tablespace arul including contents and datafiles


Now that we know the time the tablespace was dropped, we can do a point in time recovery of the DATABASE in order to recover the tablespace which has been dropped.

RMAN> run {
2> set until time "to_date('03-AUG-2009 14:38:00','DD-MON-YYYY HH24:Mi:SS')";
3> restore database;
4> recover database;
5> }

executing command: SET until clause
using target database control file instead of recovery catalog

Starting restore at 03-AUG-09
allocated channel: ORA_SBT_TAPE_1
channel ORA_SBT_TAPE_1: sid=159 devtype=SBT_TAPE
channel ORA_SBT_TAPE_1: Data Protection for Oracle: version 5.5.1.0
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=155 devtype=DISK

channel ORA_DISK_1: restoring datafile 00004
input datafile copy recid=14 stamp=693929215 filename=/u02/oradata/testdb/users01.dbf
destination for restore of datafile 00004: /u02/oradata/backup/bkp.04klgv2b
channel ORA_SBT_TAPE_1: starting datafile backupset restore
channel ORA_SBT_TAPE_1: specifying datafile(s) to restore from backup set
restoring datafile 00001 to /u02/oradata/testdb/system01.dbf
restoring datafile 00002 to /u02/oradata/testdb/undotbs01.dbf
restoring datafile 00003 to /u02/oradata/testdb/sysaux01.dbf
restoring datafile 00005 to /u02/oradata/testdb/example01.dbf
restoring datafile 00007 to /u02/oradata/testdb/arul01.dbf
channel ORA_SBT_TAPE_1: reading from backup piece 0gkloo6p_1_1
channel ORA_DISK_1: copied datafile copy of datafile 00004
output filename=/u02/oradata/backup/bkp.04klgv2b recid=21 stamp=693932732
channel ORA_DISK_1: restoring datafile 00006
input datafile copy recid=13 stamp=693929146 filename=/u02/oradata/testdb/users02.dbf
destination for restore of datafile 00006: /u02/oradata/backup/bkp.06klgv3k
channel ORA_DISK_1: copied datafile copy of datafile 00006
output filename=/u02/oradata/backup/bkp.06klgv3k recid=23 stamp=693932755
channel ORA_DISK_1: restoring datafile 00009
input datafile copy recid=10 stamp=693929108 filename=/u02/oradata/testdb/users03.dbf
destination for restore of datafile 00009: /u02/oradata/backup/bkp.08klgv4i
channel ORA_DISK_1: copied datafile copy of datafile 00009
output filename=/u02/oradata/backup/bkp.08klgv4i recid=26 stamp=693932809
channel ORA_SBT_TAPE_1: restored backup piece 1
piece handle=0gkloo6p_1_1 tag=TAG20090803T113241
channel ORA_SBT_TAPE_1: restore complete, elapsed time: 00:02:40
Finished restore at 03-AUG-09

Starting recover at 03-AUG-09
using channel ORA_SBT_TAPE_1
using channel ORA_DISK_1

starting media recovery

archive log thread 1 sequence 8 is already on disk as file /u02/oradata/testdb/arch/arch.8.1.693662800.log
archive log thread 1 sequence 9 is already on disk as file /u02/oradata/testdb/arch/arch.9.1.693662800.log
archive log thread 1 sequence 10 is already on disk as file /u02/oradata/testdb/arch/arch.10.1.693662800.log
archive log thread 1 sequence 1 is already on disk as file /u02/oradata/testdb/redo01.log
archive log thread 1 sequence 2 is already on disk as file /u02/oradata/testdb/redo02.log
archive log filename=/u02/oradata/testdb/arch/arch.8.1.693662800.log thread=1 sequence=8
archive log filename=/u02/oradata/testdb/arch/arch.9.1.693662800.log thread=1 sequence=9
archive log filename=/u02/oradata/testdb/arch/arch.10.1.693662800.log thread=1 sequence=10
archive log filename=/u02/oradata/testdb/redo01.log thread=1 sequence=1
archive log filename=/u02/oradata/testdb/redo02.log thread=1 sequence=2
media recovery complete, elapsed time: 00:00:06
Finished recover at 03-AUG-09

RMAN>

RMAN> alter database open resetlogs;

database opened

We can now see that the tablespace which has been dropped has been recovered

SQL> select file_name,bytes from dba_data_files where
  2  tablespace_name='ARUL';

FILE_NAME
--------------------------------------------------------------------------------
     BYTES
----------
/u02/oradata/testdb/arul01.dbf
  37748736

No comments:

Post a Comment