Wednesday 3 September 2014

How to Recover Drop tablespace


If a tablespace has been dropped, 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.

STEP 1: LET’S CREATE A TABLESPACE TEST_TBS FIRST:


SQL> create tablespace TEST_TBS DATAFILE '/u02/app/oracle/oradata/DEV/testtbs.dbf' size 200m;

 Tablespace created.

STEP 2: DELETE THIS TABLESPACE INCLUDING CONTENTS AND DATAFILES:

SQL> drop tablespace TEST_TBS including contents and datafiles;

Tablespace dropped.

STEP 3: NOW TRY TO RECOVER THE DROPPED TABLESPACE USING RMAN:

RMAN> recover tablespace TEST_TBS;

Starting recover at 18-JAN-13
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=43 device type=DISK
RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of recover command at 01/18/2013 20:43:24
RMAN-20202: Tablespace not found in the recovery catalog
RMAN-06019: could not translate tablespace name " TEST_TBS "


RMAN>

See the error - RMAN-20202: Tablespace not found in the recovery catalog

STEP 4: SO TO RECOVER THE 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 the 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.


STEP 5: LET’S CREATE THE SAME TABLESPACE AGAIN AND TAKE A FULL BACKUP OF DATABASE INCLUDING CONTROLFILE:

           
SQL> create tablespace TEST_TBS DATAFILE  
      '/u02/app/oracle/oradata/DEV/testtbs.dbf' size 200m;

           
Tablespace created.

STEP 6: NOW TAKE FULL DATABASE BACKUP:

RMAN> backup database format='/u02/rman_bkp/full_%u_%s_%p' plus archivelog;


Starting backup at 14-SEP-14
current log archived
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=20 device type=DISK
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=5 RECID=1 STAMP=858270813
input archived log thread=1 sequence=6 RECID=2 STAMP=858271143
input archived log thread=1 sequence=7 RECID=3 STAMP=858272123
input archived log thread=1 sequence=8 RECID=4 STAMP=858272525
input archived log thread=1 sequence=9 RECID=5 STAMP=858274111
channel ORA_DISK_1: starting piece 1 at 14-SEP-14
channel ORA_DISK_1: finished piece 1 at 14-SEP-14
piece handle=/u02/app/oracle/fast_recovery_area/DEV/backupset/2014_09_14/o1_mf_annnn_TAG20140914T172832_b1c0q897_.bkp tag=TAG20140914T172832 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:08
Finished backup at 14-SEP-14

Starting backup at 14-SEP-14
using channel ORA_DISK_1
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=/u02/app/oracle/oradata/DEV/system01.dbf
input datafile file number=00002 name=/u02/app/oracle/oradata/DEV/sysaux01.dbf
input datafile file number=00005 name=/u02/app/oracle/oradata/DEV/testtbs.dbf
input datafile file number=00003 name=/u02/app/oracle/oradata/DEV/undotbs01.dbf
input datafile file number=00004 name=/u02/app/oracle/oradata/DEV/users01.dbf
channel ORA_DISK_1: starting piece 1 at 14-SEP-14
channel ORA_DISK_1: finished piece 1 at 14-SEP-14
piece handle=/u02/rman_bkp/full_09pigeab_9_1 tag=TAG20140914T172842 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:09:35
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current control file in backup set
including current SPFILE in backup set
channel ORA_DISK_1: starting piece 1 at 14-SEP-14
channel ORA_DISK_1: finished piece 1 at 14-SEP-14
piece handle=/u02/rman_bkp/full_0apigesa_10_1 tag=TAG20140914T172842 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:03
Finished backup at 14-SEP-14

Starting backup at 14-SEP-14
current log archived
using channel ORA_DISK_1
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=10 RECID=6 STAMP=858274706
channel ORA_DISK_1: starting piece 1 at 14-SEP-14
channel ORA_DISK_1: finished piece 1 at 14-SEP-14
piece handle=/u02/app/oracle/fast_recovery_area/DEV/backupset/2014_09_14/o1_mf_annnn_TAG20140914T173826_b1c19tt6_.bkp tag=TAG20140914T173826 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:02
Finished backup at 14-SEP-14

RMAN> backup current controlfile;

Starting backup at 14-SEP-14
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current control file in backup set
channel ORA_DISK_1: starting piece 1 at 14-SEP-14
channel ORA_DISK_1: finished piece 1 at 14-SEP-14
piece handle=/u02/app/oracle/fast_recovery_area/DEV/backupset/2014_09_14/o1_mf_ncnnf_TAG20140914T174305_b1c1llw1_.bkp tag=TAG20140914T174305 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 14-SEP-14


STEP 7: DROP THE TABLESPACE TEST_TBS AGAIN AND WE WILL RECOVER IT AS BELOW:

SQL> drop tablespace TEST_TBS including contents and datafiles;

Tablespace dropped.

STEP 8: START THE DATABASE IN NOMOUNT STAGE AND RESTORE THE CONTROLFILE FROM BACKUP:
           
      SQL> startup nomount
            
ORACLE instance started.

                Total System Global Area  631914496 bytes
                Fixed Size                  1338364 bytes
                Variable Size             394265604 bytes
                Database Buffers          230686720 bytes
                Redo Buffers                5623808 bytes


STEP 9: NEXT WE NEED TO RESTORE CONTROLFILE FROM BACKUP WHICH CONTAINS METADATA OF TABLESPACE TEST_TBS:

           
[oracle@dev rman_bkp]$ rman target /

Recovery Manager: Release 11.2.0.3.0 - Production on Sun Sep 14 18:02:51 2014

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

connected to target database: DEV (not mounted)

RMAN> restore controlfile from '/u02/app/oracle/fast_recovery_area/DEV/backupset/2014_09_14/o1_mf_ncnnf_TAG20140914T174305_b1c1llw1_.bkp';
RMAN>

Starting restore at 14-SEP-14
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=18 device type=DISK

channel ORA_DISK_1: restoring control file
channel ORA_DISK_1: restore complete, elapsed time: 00:00:08
output file name=/u02/app/oracle/oradata/DEV/control01.ctl
output file name=/u02/app/oracle/fast_recovery_area/DEV/control02.ctl
Finished restore at 14-SEP-14

Now restored controlfile contains the metadata of dropped Tablespace TEST_TBS.

           
RMAN> report schema ;

Report of database schema for database with db_unique_name DEV

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    710      SYSTEM               ***     /u02/app/oracle/oradata/DEV/system01.dbf
2    560      SYSAUX               ***     /u02/app/oracle/oradata/DEV/sysaux01.dbf
3    85       UNDOTBS1             ***     /u02/app/oracle/oradata/DEV/undotbs01.dbf
4    5        USERS                ***     /u02/app/oracle/oradata/DEV/users01.dbf
5    200      TEST_TBS             ***     /u02/app/oracle/oradata/DEV/testtbs.dbf

List of Temporary Files
=======================
File Size(MB) Tablespace           Maxsize(MB) Tempfile Name
---- -------- -------------------- ----------- --------------------
1    29       TEMP                 32767       /u02/app/oracle/oradata/DEV/temp01.dbf

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

Sun Sep 14 17:43:36 2014
drop tablespace test_tbs including contents and datafiles
Deleted file /u02/app/oracle/oradata/DEV/testtbs.dbf
Completed: drop tablespace test_tbs including contents and datafiles.

STEP 10: 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
{
set UNTIL TIME "to_date('2014-09-14 17:38:25','YYYY-MM-DD HH24:MI:SS')";
restore database;
recover database;
}2> 3> 4> 5> 6>

executing command: SET until clause

Starting restore at 14-SEP-14
Starting implicit crosscheck backup at 14-SEP-14
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=18 device type=DISK
Crosschecked 8 objects
Finished implicit crosscheck backup at 14-SEP-14

Starting implicit crosscheck copy at 14-SEP-14
using channel ORA_DISK_1
Finished implicit crosscheck copy at 14-SEP-14

searching for all files in the recovery area
cataloging files...
cataloging done

List of Cataloged Files
=======================
File Name: /u02/app/oracle/fast_recovery_area/DEV/backupset/2014_09_14/o1_mf_ncnnf_TAG20140914T174305_b1c1llw1_.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 /u02/app/oracle/oradata/DEV/system01.dbf
channel ORA_DISK_1: restoring datafile 00002 to /u02/app/oracle/oradata/DEV/sysaux01.dbf
channel ORA_DISK_1: restoring datafile 00003 to /u02/app/oracle/oradata/DEV/undotbs01.dbf
channel ORA_DISK_1: restoring datafile 00004 to /u02/app/oracle/oradata/DEV/users01.dbf
channel ORA_DISK_1: restoring datafile 00005 to /u02/app/oracle/oradata/DEV/testtbs.dbf
channel ORA_DISK_1: reading from backup piece /u02/rman_bkp/full_09pigeab_9_1


channel ORA_DISK_1: piece handle=/u02/rman_bkp/full_09pigeab_9_1 tag=TAG20140914T172842
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:10:46
Finished restore at 14-SEP-14

Starting recover at 14-SEP-14
using channel ORA_DISK_1

starting media recovery

archived log for thread 1 with sequence 10 is already on disk as file /u02/app/oracle/fast_recovery_area/DEV/archivelog/2014_09_14/o1_mf_1_10_b1c19t3z_.arc
archived log file name=/u02/app/oracle/fast_recovery_area/DEV/archivelog/2014_09_14/o1_mf_1_10_b1c19t3z_.arc thread=1 sequence=10
media recovery complete, elapsed time: 00:00:03
Finished recover at 14-SEP-14


RMAN>
RMAN> alter database open resetlogs;

database opened

STEP 11: NOW CHECK THE RESTORED TABLESPACE:

           
SQL> select file_name,bytes from dba_data_files where
          tablespace_name='TEST_TBS’

FILE_NAME                                        LESPACE     STATUS
---------------------------------------------------------------------------------------------------------
/u02/app/oracle/oradata/DEV/testtbs.db             TEST_TBS   AVAILABLE 

     


I hope this article helped you. Your suggestions/feedback are most welcome.

Keep learning... Have a great day!!!



1 comment: