About Me

My photo
Bangalore, India
I am an Oracle Certified Professional working in SAP Labs. Everything written on my blog has been tested on my local environment, Please test before implementing or running in production. You can contact me at amit.rath0708@gmail.com.

Wednesday, August 7, 2013

How to perform Tablespace point in time recovery (TSPITR)

TSPITR abbreviates to Tablespace point in time recovery. Unlike DBPITR , it rewinds only specified tablespace to a earlier time and leaving the whole database in the current time. All changes made to the tablespace after the recovery time will be lost.

While doing TSPITR you have to be very cautious if you are doing it using control file because once you recovered your tablespace to a earlier time and its not fulfilled your requirement then there is no second chance for that. All backups related to that tablespace becomes invalid after TSPITR if using control file instead of recovery catalog. 

PFB Example to recover a table using Fully Automated TSPITR after truncate operation :-

Prerequisites :-

1.  If I want recovery to a particular time then I should have a Valid Backup available before that time to perform TSPITR.

2. Database has to be in Archive Log mode

C:\Users\NewAdmin>sqlplus

SQL*Plus: Release 11.2.0.1.0 Production on Tue Aug 6 23:43:01 2013

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

Enter user-name: /as sysdba

Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL> conn amit/amit
Connected.
SQL> create table amit
  2  (
  3  id number(12),
  4  name varchar2(12));

Table created.

SQL> insert into amit values ('&id','&name');
Enter value for id: 3242
Enter value for name: ffsdf
old   1: insert into amit values ('&id','&name')
new   1: insert into amit values ('3242','ffsdf')

1 row created.
.........

like this insert some rows in table

SQL> commit;

Commit complete.

SQL> select * from amit;

        ID NAME
---------- ------------
      3242 ffsdf
      4324 fdfdf
    324324 ssdfdsf
     43242 fsfdf/
     43242 ffewtew
   4324234 fsfegg

6 rows selected.

SQL> alter system switch logfile;

System altered.
SQL> select systimestamp from dual;

SYSTIMESTAMP
---------------------------------------------------------------------------
06-AUG-13 11.46.38.945000 PM +05:30

SQL> truncate table amit;

Table truncated.

SQL> commit;

Commit complete.

SQL> alter system switch logfile;

System altered.

SQL> select systimestamp from dual;

SYSTIMESTAMP
---------------------------------------------------------------------------
06-AUG-13 11.47.05.185000 PM +05:30

SQL>
SQL> exit
Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

C:\Users\NewAdmin>rman target /

Recovery Manager: Release 11.2.0.1.0 - Production on Tue Aug 6 23:47:21 2013

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

connected to target database: TEST (DBID=2120650031)

RMAN> recover tablespace amit until time "to_date('06-AUG-13 23:46:38','dd-mon-yy hh24:mi:ss')" auxiliary destination 'D:\backup';

Starting recover at 06-AUG-13
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=198 device type=DISK
RMAN-05026: WARNING: presuming following set of tablespaces applies to specified point-in-time

List of tablespaces expected to have UNDO segments
Tablespace SYSTEM
Tablespace UNDOTBS1

Creating automatic instance, with SID='ADAF'

initialization parameters used for automatic instance:
db_name=TEST
db_unique_name=ADAF_tspitr_TEST
compatible=11.2.0.0.0
db_block_size=8192
db_files=200
sga_target=280M
processes=50
db_create_file_dest=D:\backup
log_archive_dest_1='location=D:\backup'
#No auxiliary parameter file used

starting up automatic instance TEST

Oracle instance started

Total System Global Area     292278272 bytes

Fixed Size                     2175128 bytes
Variable Size                100667240 bytes
Database Buffers             184549376 bytes
Redo Buffers                   4886528 bytes
Automatic instance created
Running TRANSPORT_SET_CHECK on recovery set tablespaces
TRANSPORT_SET_CHECK completed successfully

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('06-AUG-13 23:46:38','dd-mon-yy hh24:mi:ss')";
# 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;';
}
executing Memory Script

executing command: SET until clause

Starting restore at 06-AUG-13
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 G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\AUTOBACKUP\2013_08_06\O1_MF_S_822784043_902F2NHM_.BKP
channel ORA_AUX_DISK_1: piece handle=G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\AUTOBACKUP\2013_08_06\O1_MF_S_822784043_902F2NHM_.BKP tag=TAG20130806T230723
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=D:\BACKUP\TEST\CONTROLFILE\O1_MF_902HTHRJ_.CTL
Finished restore at 06-AUG-13

sql statement: alter database mount clone database

sql statement: alter system archive log current

sql statement: begin dbms_backup_restore.AutoBackupFlag(FALSE); end;

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('06-AUG-13 23:46:38','dd-mon-yy hh24:mi:ss')";
plsql <<<-- tspitr_2
declare
  sqlstatement       varchar2(512);
  offline_not_needed exception;
  pragma exception_init(offline_not_needed, -01539);
begin
  sqlstatement := 'alter tablespace '||  'AMIT' ||' offline immediate';
  krmicd.writeMsg(6162, sqlstatement);
  krmicd.execSql(sqlstatement);
exception
  when offline_not_needed then
    null;
end; >>>;
# 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  5 to
 "G:\APP\NEWADMIN\ORADATA\TEST\DATAFILE\AMIT01.DBF";
# switch all tempfiles
switch clone tempfile all;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile  1, 3, 2, 5;
switch clone datafile all;
}
executing Memory Script

executing command: SET until clause

sql statement: alter tablespace AMIT offline immediate

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

renamed tempfile 1 to D:\BACKUP\TEST\DATAFILE\O1_MF_TEMP_%U_.TMP in control file

Starting restore at 06-AUG-13
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 D:\BACKUP\TEST\DATAFILE\O1_MF_SYSTEM_%U_.DBF
channel ORA_AUX_DISK_1: restoring datafile 00003 to D:\BACKUP\TEST\DATAFILE\O1_MF_UNDOTBS1_%U_.DBF
channel ORA_AUX_DISK_1: restoring datafile 00002 to D:\BACKUP\TEST\DATAFILE\O1_MF_SYSAUX_%U_.DBF
channel ORA_AUX_DISK_1: restoring datafile 00005 to G:\APP\NEWADMIN\ORADATA\TEST\DATAFILE\AMIT01.DBF
channel ORA_AUX_DISK_1: reading from backup piece G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\BACKUPSET\2013_08_06\O1_MF_NNNDF_TAG20130806T230534_902DZ6YP_.BKP
channel ORA_AUX_DISK_1: piece handle=G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\BACKUPSET\2013_08_06\O1_MF_NNNDF_TAG20130806T230534_902DZ6YP_.BKP tag=TAG20130806T23053
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:02:25
Finished restore at 06-AUG-13

datafile 1 switched to datafile copy
input datafile copy RECID=4 STAMP=822787012 file name=D:\BACKUP\TEST\DATAFILE\O1_MF_SYSTEM_902HTTV8_.DBF
datafile 3 switched to datafile copy
input datafile copy RECID=5 STAMP=822787012 file name=D:\BACKUP\TEST\DATAFILE\O1_MF_UNDOTBS1_902HTV2W_.DBF
datafile 2 switched to datafile copy
input datafile copy RECID=6 STAMP=822787012 file name=D:\BACKUP\TEST\DATAFILE\O1_MF_SYSAUX_902HTTX3_.DBF

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('06-AUG-13 23:46:38','dd-mon-yy hh24:mi:ss')";
# 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  5 online";
# recover and open resetlogs
recover clone database tablespace  "AMIT", "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  5 online

Starting recover at 06-AUG-13
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 12 is already on disk as file G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_12_902F2JG8_.ARC
archived log for thread 1 with sequence 13 is already on disk as file G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_13_902HC6KM_.ARC
archived log for thread 1 with sequence 14 is already on disk as file G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_14_902HC88F_.ARC
archived log for thread 1 with sequence 15 is already on disk as file G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_15_902HCFM2_.ARC
archived log for thread 1 with sequence 16 is already on disk as file G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_16_902HDWNH_.ARC
archived log file name=G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_12_902F2JG8_.ARC thread=1 sequence=12
archived log file name=G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_13_902HC6KM_.ARC thread=1 sequence=13
archived log file name=G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_14_902HC88F_.ARC thread=1 sequence=14
archived log file name=G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_15_902HCFM2_.ARC thread=1 sequence=15
archived log file name=G:\APP\NEWADMIN\FLASH_RECOVERY_AREA\TEST\ARCHIVELOG\2013_08_06\O1_MF_1_16_902HDWNH_.ARC thread=1 sequence=16
media recovery complete, elapsed time: 00:00:06
Finished recover at 06-AUG-13

database opened

contents of Memory Script:
{
# make read only the tablespace that will be exported
sql clone 'alter tablespace  AMIT read only';
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
D:\backup''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
D:\backup''";
}
executing Memory Script

sql statement: alter tablespace  AMIT read only

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''D:\backup''

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''D:\backup''

Performing export of metadata...
   EXPDP> Starting "SYS"."TSPITR_EXP_ADAF":
   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_ADAF" successfully loaded/unloaded
   EXPDP> ******************************************************************************
   EXPDP> Dump file set for SYS.TSPITR_EXP_ADAF is:
   EXPDP>   D:\BACKUP\TSPITR_ADAF_54021.DMP
   EXPDP> ******************************************************************************
   EXPDP> Datafiles required for transportable tablespace AMIT:
   EXPDP>   G:\APP\NEWADMIN\ORADATA\TEST\DATAFILE\AMIT01.DBF
   EXPDP> Job "SYS"."TSPITR_EXP_ADAF" successfully completed at 23:59:45
Export completed

contents of Memory Script:
{
# shutdown clone before import
shutdown clone immediate
# drop target tablespaces before importing them back
sql 'drop tablespace  AMIT including contents keep datafiles';
}
executing Memory Script

database closed
database dismounted
Oracle instance shut down

sql statement: drop tablespace  AMIT including contents keep datafiles

Performing import of metadata...
   IMPDP> Master table "SYS"."TSPITR_IMP_ADAF" successfully loaded/unloaded
   IMPDP> Starting "SYS"."TSPITR_IMP_ADAF":
   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_ADAF" successfully completed at 00:00:17
Import completed

contents of Memory Script:
{
# make read write and offline the imported tablespaces
sql 'alter tablespace  AMIT read write';
sql 'alter tablespace  AMIT offline';
# enable autobackups after TSPITR is finished
sql 'begin dbms_backup_restore.AutoBackupFlag(TRUE); end;';
}
executing Memory Script

sql statement: alter tablespace  AMIT read write

sql statement: alter tablespace  AMIT offline

sql statement: begin dbms_backup_restore.AutoBackupFlag(TRUE); end;

Removing automatic instance
Automatic instance removed
auxiliary instance file D:\BACKUP\TEST\DATAFILE\O1_MF_TEMP_902J05F7_.TMP deleted
auxiliary instance file D:\BACKUP\TEST\ONLINELOG\O1_MF_3_902HZY45_.LOG deleted
auxiliary instance file D:\BACKUP\TEST\ONLINELOG\O1_MF_2_902HZVTN_.LOG deleted
auxiliary instance file D:\BACKUP\TEST\ONLINELOG\O1_MF_1_902HZSHD_.LOG deleted
auxiliary instance file D:\BACKUP\TEST\DATAFILE\O1_MF_SYSAUX_902HTTX3_.DBF deleted
auxiliary instance file D:\BACKUP\TEST\DATAFILE\O1_MF_UNDOTBS1_902HTV2W_.DBF deleted
auxiliary instance file D:\BACKUP\TEST\DATAFILE\O1_MF_SYSTEM_902HTTV8_.DBF deleted
auxiliary instance file D:\BACKUP\TEST\CONTROLFILE\O1_MF_902HTHRJ_.CTL deleted
Finished recover at 07-AUG-13

RMAN> exit

Recovery Manager complete.

C:\Users\NewAdmin>sqlplus

SQL*Plus: Release 11.2.0.1.0 Production on Wed Aug 7 00:05:18 2013

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

Enter user-name: /as sysdba

Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL> conn amit/amit
Connected.

SQL> select count(1) from amit;
select count(1) from amit
                     *
ERROR at line 1:
ORA-00376: file 5 cannot be read at this time
ORA-01110: data file 5: 'G:\APP\NEWADMIN\ORADATA\TEST\DATAFILE\AMIT01.DBF'

##############AFTER TSPITR you have to manually make your tablespace online###############

SQL> alter tablespace amit online;

Tablespace altered.

SQL> select * from amit;

        ID NAME
---------- ------------
      3242 ffsdf
      4324 fdfdf
    324324 ssdfdsf
     43242 fsfdf/
     43242 ffewtew
   4324234 fsfegg

6 rows selected.

Table has been successfully recovered using TSPITR. 

Please note that if you have hands on in using TSPITR only then use it for recovery in Production database.

If possible Always preferred Flashback feature ahead of TSPITR.

Related Articles :-
How to perform DBPITR

I hope this article helped you.

Regards,
Amit Rath

No comments:

Post a Comment