11g Release 2 Tablespace Point In Time Recovery – recover from dropped tablespace
- Posted by Gavin Soorma
- On November 27, 2009
- 0 Comments
One of the good new features in 11g Release 2 is that it enables us to recover from a case of a dropped tablespace. TSPITR (tablespace point in time recovery) has been around in earlier releases, but we could not recover a dropped tablespace.
What 11gR2 does is that it peforms a fully automated RMAN managed TSPITR. It creates and starts the auxiliary instance and restores just the datafiles it requires – SYSTEM,SYSAUX,UNDO and the files pertaining to the dropped tablespace – in this case datafiles 1,2,3 and 7- in the location which we specify as the ‘Auxiliary Destination’. It will first perform a recovery of the tablespace on the auxiliary instance and then use Data Pump and Transportable Tablespace technology to extract and import the tablespace meta data into the original source database.
To illustrate this example we create a new tablespace MYEXAMPLE and create two tables MYSALES and MYCOSTS in this tablespace. We take a database backup and then drop the tablespace and then perform tablespace point in time recovery using RMAN.
Before dropping the tablespace we first note the SCN as we will use this SCN when we do the TSPITR. Note also that we are connected to a RMAN catalog as well although the documentation does state that we can perform TSPITR without a recovery catalog.
SQL> create tablespace myexample datafile '+DATA' size 200m; Tablespace created. SQL> create table mysales 2 tablespace myexample 3 as select * from sales; Table created. SQL> create table mycosts 2 tablespace myexample 3 as select * from costs; Table created. SQL> conn / as sysdba Connected. SQL> alter system switch logfile; System altered. SQL> select current_scn from v$database; CURRENT_SCN ----------- 1043322 SQL> drop tablespace myexample including contents and datafiles; Tablespace dropped.
RMAN> run { 2> set newname for datafile 7 to '+DATA'; 3> recover tablespace myexample 4> until scn 1043322 5> auxiliary destination '+DATA'; 6> } executing command: SET NEWNAME Starting recover at 27-NOV-09 allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=137 device type=DISK Creating automatic instance, with SID='qyBo' initialization parameters used for automatic instance: db_name=TESTDB db_unique_name=qyBo_tspitr_TESTDB compatible=11.2.0.0.0 db_block_size=8192 db_files=200 sga_target=280M processes=50 db_create_file_dest=+DATA log_archive_dest_1='location=+DATA' #No auxiliary parameter file used starting up automatic instance TESTDB Oracle instance started Total System Global Area 292278272 bytes Fixed Size 2212736 bytes Variable Size 100666496 bytes Database Buffers 184549376 bytes Redo Buffers 4849664 bytes Automatic instance created contents of Memory Script: { # set requested point in time set until scn 1043322; # restore the controlfile restore clone controlfile; # mount the controlfile sql clone 'alter database mount clone database'; # archive current online log sql 'alter system archive log current'; # avoid unnecessary autobackups for structural changes during TSPITR sql 'begin dbms_backup_restore.AutoBackupFlag(FALSE); end;'; # resync catalog resync catalog; } executing Memory Script executing command: SET until clause Starting restore at 27-NOV-09 allocated channel: ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: SID=81 device type=DISK channel ORA_AUX_DISK_1: starting datafile backup set restore channel ORA_AUX_DISK_1: restoring control file channel ORA_AUX_DISK_1: reading from backup piece +DATA/testdb/backupset/2009_11_27/ncsnf0_tag20091127t104307_0.502. 704025815 channel ORA_AUX_DISK_1: piece handle=+DATA/testdb/backupset/2009_11_27/ncsnf0_tag20091127t104307_0.502. 704025815 tag=TAG20091127T104307 channel ORA_AUX_DISK_1: restored backup piece 1 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:04 output file name=+DATA/testdb/controlfile/current.506.704033345 Finished restore at 27-NOV-09 sql statement: alter database mount clone database sql statement: alter system archive log current sql statement: begin dbms_backup_restore.AutoBackupFlag(FALSE); end; starting full resync of recovery catalog full resync complete contents of Memory Script: { # set requested point in time set until scn 1043322; # set destinations for recovery set and auxiliary set datafiles set newname for clone datafile 1 to new; set newname for clone datafile 3 to new; set newname for clone datafile 2 to new; set newname for clone tempfile 1 to new; set newname for datafile 7 to "+DATA"; # switch all tempfiles switch clone tempfile all; # restore the tablespaces in the recovery set and the auxiliary set restore clone datafile 1, 3, 2, 7; switch clone datafile all; } executing Memory Script executing command: SET until clause executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME renamed tempfile 1 to +DATA in control file Starting restore at 27-NOV-09 using channel ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: starting datafile backup set restore channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set channel ORA_AUX_DISK_1: restoring datafile 00001 to +DATA channel ORA_AUX_DISK_1: restoring datafile 00003 to +DATA channel ORA_AUX_DISK_1: restoring datafile 00002 to +DATA channel ORA_AUX_DISK_1: restoring datafile 00007 to +DATA channel ORA_AUX_DISK_1: reading from backup piece +DATA/testdb/backupset/2009_11_27/nnndf0_tag20091127t104307 ..... channel ORA_AUX_DISK_1: piece handle=+DATA/testdb/backupset/2009_11_27/nnndf0_tag20091127t104307_0.501. 704025789 tag=TAG200 ......... channel ORA_AUX_DISK_1: restored backup piece 1 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:26 Finished restore at 27-NOV-09 datafile 7 switched to datafile copy input datafile copy RECID=6 STAMP=704033380 file name=+DATA/testdb/datafile/myexample.512. 704033355 datafile 1 switched to datafile copy input datafile copy RECID=7 STAMP=704033380 file name=+DATA/testdb/datafile/system.511. 704033355 datafile 3 switched to datafile copy input datafile copy RECID=8 STAMP=704033380 file name=+DATA/testdb/datafile/undotbs1.513. 704033355 datafile 2 switched to datafile copy input datafile copy RECID=9 STAMP=704033380 file name=+DATA/testdb/datafile/sysaux.509. 704033355 contents of Memory Script: { # set requested point in time set until scn 1043322; # online the datafiles restored or switched sql clone "alter database datafile 1 online"; sql clone "alter database datafile 3 online"; sql clone "alter database datafile 2 online"; sql clone "alter database datafile 7 online"; # recover and open resetlogs recover clone database tablespace "MYEXAMPLE", "SYSTEM", "UNDOTBS1", "SYSAUX" delete archivelog; alter clone database open resetlogs; } executing Memory Script executing command: SET until clause sql statement: alter database datafile 1 online sql statement: alter database datafile 3 online sql statement: alter database datafile 2 online sql statement: alter database datafile 7 online Starting recover at 27-NOV-09 using channel ORA_AUX_DISK_1 starting media recovery archived log for thread 1 with sequence 10 is already on disk as file +DATA/testdb/archivelog/2009_11_27/..... archived log for thread 1 with sequence 11 is already on disk as file +DATA/testdb/archivelog/2009_11_27/..... archived log for thread 1 with sequence 12 is already on disk as file +DATA/testdb/archivelog/2009_11_27/ ...... archived log file name=+DATA/testdb/archivelog/2009_11_27/ .... archived log file name=+DATA/testdb/archivelog/2009_11_27/.... archived log file name=+DATA/testdb/archivelog/2009_11_27/.... media recovery complete, elapsed time: 00:00:01 Finished recover at 27-NOV-09 database opened contents of Memory Script: { # make read only the tablespace that will be exported sql clone 'alter tablespace MYEXAMPLE read only'; # create directory for datapump import sql "create or replace directory TSPITR_DIROBJ_DPDIR as '' +DATA''"; # create directory for datapump export sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as '' +DATA''"; } executing Memory Script sql statement: alter tablespace MYEXAMPLE read only sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''+DATA'' sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''+DATA'' Performing export of metadata... EXPDP> Starting "SYS"."TSPITR_EXP_qyBo": EXPDP> Processing object type TRANSPORTABLE_EXPORT/PLUGTS_BLK EXPDP> Processing object type TRANSPORTABLE_EXPORT/TABLE EXPDP> Processing object type TRANSPORTABLE_EXPORT/POST_INSTANCE/PLUGTS_BLK EXPDP> Master table "SYS"."TSPITR_EXP_qyBo" successfully loaded/unloaded EXPDP> ****************************************************************************** EXPDP> Dump file set for SYS.TSPITR_EXP_qyBo is: EXPDP> +DATA/tspitr_qybo_53647.dmp EXPDP> ****************************************************************************** EXPDP> Datafiles required for transportable tablespace MYEXAMPLE: EXPDP> +DATA/testdb/datafile/myexample.512.704033355 EXPDP> Job "SYS"."TSPITR_EXP_qyBo" successfully completed at 12:51:34 Export completed contents of Memory Script: { # shutdown clone before import shutdown clone immediate } executing Memory Script database closed database dismounted Oracle instance shut down Performing import of metadata... IMPDP> Master table "SYS"."TSPITR_IMP_qyBo" successfully loaded/unloaded IMPDP> Starting "SYS"."TSPITR_IMP_qyBo": IMPDP> Processing object type TRANSPORTABLE_EXPORT/PLUGTS_BLK IMPDP> Processing object type TRANSPORTABLE_EXPORT/TABLE IMPDP> Processing object type TRANSPORTABLE_EXPORT/POST_INSTANCE/PLUGTS_BLK IMPDP> Job "SYS"."TSPITR_IMP_qyBo" successfully completed at 12:51:49 Import completed contents of Memory Script: { # make read write and offline the imported tablespaces sql 'alter tablespace MYEXAMPLE read write'; sql 'alter tablespace MYEXAMPLE offline'; # enable autobackups after TSPITR is finished sql 'begin dbms_backup_restore.AutoBackupFlag(TRUE); end;'; # resync catalog resync catalog; } executing Memory Script sql statement: alter tablespace MYEXAMPLE read write sql statement: alter tablespace MYEXAMPLE offline sql statement: begin dbms_backup_restore.AutoBackupFlag(TRUE); end; starting full resync of recovery catalog full resync complete Removing automatic instance Automatic instance removed auxiliary instance file +DATA/testdb/tempfile/temp.518.704033385 deleted auxiliary instance file +DATA/testdb/onlinelog/group_3.517.704033385 deleted auxiliary instance file +DATA/testdb/onlinelog/group_2.515.704033383 deleted auxiliary instance file +DATA/testdb/onlinelog/group_1.514.704033383 deleted auxiliary instance file +DATA/testdb/datafile/sysaux.509.704033355 deleted auxiliary instance file +DATA/testdb/datafile/undotbs1.513.704033355 deleted auxiliary instance file +DATA/testdb/datafile/system.511.704033355 deleted auxiliary instance file +DATA/testdb/controlfile/current.506.704033345 deleted Finished recover at 27-NOV-09 RMAN>
Note: After the recovery is complete, we need to bring the tablespace and datafile online as well.
SQL> alter tablespace myexample online; Tablespace altered. SQL> alter database datafile '+DATA/testdb/datafile/myexample.512.704033355' online; Database altered. SQL> select file_name from dba_data_files where tablespace_name='MYEXAMPLE'; FILE_NAME -------------------------------------------------------------------------------- +DATA/testdb/datafile/myexample.512.704033355 SQL> select table_name from dba_tables 2 where tablespace_name='MYEXAMPLE'; TABLE_NAME ------------------------------ MYSALES MYCOSTS SQL> select count(*) from sh.mysales; COUNT(*) ---------- 918843
0 Comments