RMAN

Tablespace point in time recovery (TSPITR)

User Rating:  / 1
PoorBest 
Parent Category: Articles
Created on Tuesday, 19 July 2011 14:52
Last Updated on Tuesday, 24 July 2012 10:00
Published on Tuesday, 19 July 2011 14:52
Hits: 5532

Tablespace point in time recovery (TSPITR) all in 1.


With the below example we show what tablespace point in time recovery (TSPITR) can do for you and how easy it is.
We demonstrate this with the following scenario ( done with release 11.2.0.2 )

1) at t0 a schema owner stores his/her segment in a dedicated tablespace.( in this example test_tspitr )
2) at t1 (and every x days) there is a full hot database backup including that tablespace ( database operates in archivelog mode )
3) at t2 a logical error happens, other business data in other tablespaces is not impacted and for the business the database can' t be shutdown, "only" the content of the tablespace must be reset
4) at t3 the TSPITR in launched, an auxiliary instance is automatically created with only the required tablespaces (to restore), the content of the tablespace is exported and automatically imported in the original production database which was never been stopped.

 

 

1) (t0) Setup test scenario, tablesPace test_tspitr and schema owner



SQL> create tablespace test_tspitr datafile '/opt/oradata/SILVER/test_tspits.dbf' size 100M extent management local segment space management auto;

Tablespace created.

SQL> create user tspitr identified by tspitr default tablespace test_tspitr temporary tablespace temp;

User created.

SQL> grant create session, create table to tspitr;

Grant succeeded.

SQL> alter user tspitr quota unlimited on test_tspitr;

User altered.

SQL> grant create session, create table to tspitr;

Grant succeeded.

SQL> alter user tspitr quota unlimited on test_tspitr;

User altered.

SQL> connect tspitr/tspitr;
Connected.

SQL> create table T1 (col1 number);

Table created.

SQL> begin
2  for i in 1 .. 100 loop
3  insert into t1 values (i);
4  end loop;
5  end;
6  /

PL/SQL procedure successfully completed.

SQL> select table_name,tablespace_name from user_tables;

TABLE_NAME               TABLESPACE_NAME
------------------------------ ------------------------------
T1                   TEST_TSPITR




2) (t1) Full hot database backup are scheduled at regular time interval ( database operates in archivelog mode ).




RMAN> list backup of tablespace test_tspitr;


List of Backup Sets
===================


BS Key  Type LV Size       Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ ---------------
118     Full    164.78M    DISK        00:01:04     19-JUL-11      
BP Key: 118   Status: AVAILABLE  Compressed: YES  Tag: TAG20110719T110604
Piece Name: /opt/flash_recovery_area/backup/SILVER/DB_SILVER_48mhqs2k_1_1
List of Datafiles in backup set 118
File LV Type Ckp SCN    Ckp Time  Name
---- -- ---- ---------- --------- ----
5       Full 10927492   19-JUL-11 /opt/oradata/SILVER/test_tspits.dbf



3) (t2) a logical error happens


SQL> truncate table t1;

Table truncated.


4a) (t3) with logminer we find out what happens and at which SCN




SQL> begin
2  dbms_logmnr.add_logfile(logfilename=> '/opt/flash_recovery_area/SILVER/archivelog/2011_07_19/o1_mf_1_237_72bmh7l4_.arc');
3  end;
4  /

PL/SQL procedure successfully completed.


SQL> begin
2  dbms_logmnr.start_logmnr();
3  end;
4  /

PL/SQL procedure successfully completed.


SQL> select scn,start_scn,commit_scn,sql_redo,sql_undo from v$logmnr_contents where seg_owner='TSPITR' and seg_name='T1';

SCN  START_SCN COMMIT_SCN
---------- ---------- ----------
SQL_REDO
--------------------------------------------------------------------------------
SQL_UNDO
--------------------------------------------------------------------------------
10939574
truncate table t1;


 

 

 

4b) (t3) with RMAN we launch the TSPITR, note what happens automatically for us.



[oracle@pcguy ~]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Tue Jul 19 11:52:31 2011

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

connected to target database: SILVER (DBID=2121303953)

RMAN> recover tablespace test_tspitr
2> until scn 10939570
3> auxiliary destination '/opt/oradata/TSPITR';

Starting recover at 19-JUL-11
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=15 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='tkjg'

initialization parameters used for automatic instance:
db_name=SILVER
db_unique_name=tkjg_tspitr_SILVER
compatible=11.2.0.0.0
db_block_size=8192
db_files=200
sga_target=280M
processes=50
db_create_file_dest=/opt/oradata/TSPITR
log_archive_dest_1='location=/opt/oradata/TSPITR'
#No auxiliary parameter file used


starting up automatic instance SILVER

Oracle instance started

Total System Global Area     292278272 bytes

Fixed Size                     2225872 bytes
Variable Size                100665648 bytes
Database Buffers             184549376 bytes
Redo Buffers                   4837376 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  scn 10939570;
# 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 19-JUL-11
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=59 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 /opt/flash_recovery_area/backup/SILVER/CT_SILVER_4cmhqs7f_1_1
channel ORA_AUX_DISK_1: piece handle=/opt/flash_recovery_area/backup/SILVER/CT_SILVER_4cmhqs7f_1_1 tag=TAG20110719T110935
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/opt/oradata/TSPITR/SILVER/controlfile/o1_mf_72boflgb_.ctl
Finished restore at 19-JUL-11

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  scn 10939570;
plsql <<<-- tspitr_2
declare
sqlstatement       varchar2(512);
offline_not_needed exception;
pragma exception_init(offline_not_needed, -01539);
begin
sqlstatement := 'alter tablespace '||  'TEST_TSPITR' ||' 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
"/opt/oradata/SILVER/test_tspits.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 TEST_TSPITR 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 /opt/oradata/TSPITR/SILVER/datafile/o1_mf_temp_%u_.tmp in control file

Starting restore at 19-JUL-11
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 00003 to /opt/oradata/TSPITR/SILVER/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00002 to /opt/oradata/TSPITR/SILVER/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /opt/flash_recovery_area/backup/SILVER/DB_SILVER_47mhqs0s_1_1
channel ORA_AUX_DISK_1: piece handle=/opt/flash_recovery_area/backup/SILVER/DB_SILVER_47mhqs0s_1_1 tag=TAG20110719T110604
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:01:05
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 /opt/oradata/TSPITR/SILVER/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00005 to /opt/oradata/SILVER/test_tspits.dbf
channel ORA_AUX_DISK_1: reading from backup piece /opt/flash_recovery_area/backup/SILVER/DB_SILVER_48mhqs2k_1_1
channel ORA_AUX_DISK_1: piece handle=/opt/flash_recovery_area/backup/SILVER/DB_SILVER_48mhqs2k_1_1 tag=TAG20110719T110604
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:56
Finished restore at 19-JUL-11

datafile 1 switched to datafile copy
input datafile copy RECID=5 STAMP=756907345 file name=/opt/oradata/TSPITR/SILVER/datafile/o1_mf_system_72boht3s_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=6 STAMP=756907345 file name=/opt/oradata/TSPITR/SILVER/datafile/o1_mf_undotbs1_72bofs0y_.dbf
datafile 2 switched to datafile copy
input datafile copy RECID=7 STAMP=756907345 file name=/opt/oradata/TSPITR/SILVER/datafile/o1_mf_sysaux_72bofry3_.dbf

contents of Memory Script:
{
# set requested point in time
set until  scn 10939570;
# 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  "TEST_TSPITR", "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 19-JUL-11
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 237 is already on disk as file /opt/flash_recovery_area/SILVER/archivelog/2011_07_19/o1_mf_1_237_72bmh7l4_.arc
channel ORA_AUX_DISK_1: starting archived log restore to default destination
channel ORA_AUX_DISK_1: restoring archived log
archived log thread=1 sequence=236
channel ORA_AUX_DISK_1: reading from backup piece /opt/flash_recovery_area/backup/SILVER/AL_SILVER_4bmhqs7d_1_1
channel ORA_AUX_DISK_1: piece handle=/opt/flash_recovery_area/backup/SILVER/AL_SILVER_4bmhqs7d_1_1 tag=TAG20110719T110933
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
archived log file name=/opt/oradata/TSPITR/1_236_751381589.dbf thread=1 sequence=236
channel clone_default: deleting archived log(s)
archived log file name=/opt/oradata/TSPITR/1_236_751381589.dbf RECID=319 STAMP=756907347
archived log file name=/opt/flash_recovery_area/SILVER/archivelog/2011_07_19/o1_mf_1_237_72bmh7l4_.arc thread=1 sequence=237
media recovery complete, elapsed time: 00:00:08
Finished recover at 19-JUL-11

database opened

contents of Memory Script:
{
# make read only the tablespace that will be exported
sql clone 'alter tablespace  TEST_TSPITR read only';
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/opt/oradata/TSPITR''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/opt/oradata/TSPITR''";
}
executing Memory Script

sql statement: alter tablespace  TEST_TSPITR read only

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/opt/oradata/TSPITR''

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/opt/oradata/TSPITR''

Performing export of metadata...
EXPDP> Starting "SYS"."TSPITR_EXP_tkjg":  
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_tkjg" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_tkjg is:
EXPDP>   /opt/oradata/TSPITR/tspitr_tkjg_32318.dmp
EXPDP> ******************************************************************************
EXPDP> Datafiles required for transportable tablespace TEST_TSPITR:
EXPDP>   /opt/oradata/SILVER/test_tspits.dbf
EXPDP> Job "SYS"."TSPITR_EXP_tkjg" successfully completed at 12:04:01
Export completed


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

database closed
database dismounted
Oracle instance shut down

sql statement: drop tablespace  TEST_TSPITR including contents keep datafiles

Performing import of metadata...
IMPDP> Master table "SYS"."TSPITR_IMP_tkjg" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_tkjg":  
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_tkjg" successfully completed at 12:04:23
Import completed


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

sql statement: alter tablespace  TEST_TSPITR read write

sql statement: alter tablespace  TEST_TSPITR offline

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

Removing automatic instance
Automatic instance removed
auxiliary instance file /opt/oradata/TSPITR/SILVER/datafile/o1_mf_temp_72bol2pk_.tmp deleted
auxiliary instance file /opt/oradata/TSPITR/SILVER/onlinelog/o1_mf_3_72bol0gf_.log deleted
auxiliary instance file /opt/oradata/TSPITR/SILVER/onlinelog/o1_mf_2_72bokz76_.log deleted
auxiliary instance file /opt/oradata/TSPITR/SILVER/onlinelog/o1_mf_1_72bokxh1_.log deleted
auxiliary instance file /opt/oradata/TSPITR/SILVER/datafile/o1_mf_sysaux_72bofry3_.dbf deleted
auxiliary instance file /opt/oradata/TSPITR/SILVER/datafile/o1_mf_undotbs1_72bofs0y_.dbf deleted
auxiliary instance file /opt/oradata/TSPITR/SILVER/datafile/o1_mf_system_72boht3s_.dbf deleted
auxiliary instance file /opt/oradata/TSPITR/SILVER/controlfile/o1_mf_72boflgb_.ctl deleted
Finished recover at 19-JUL-11

 


5) (t4) We test whether the contents of the table t1 has been restored



[oracle@pcguy oradata]$ sqlplus tspitr/tspitr

SQL*Plus: Release 11.2.0.2.0 Production on Tue Jul 19 12:21:57 2011

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


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

SQL> select count(*) from t1;
select count(*) from t1
*
ERROR at line 1:
ORA-00376: file 5 cannot be read at this time
ORA-01110: data file 5: '/opt/oradata/SILVER/test_tspits.dbf'


SQL> connect / as sysdba
Connected.
SQL> alter tablespace test_tspitr online;

Tablespace altered.

SQL> connect tspitr/tspitr
Connected.
SQL> select count(*) from t1;

COUNT(*)
----------
100