Concepts of recovering tables and table partitions from RMAN backups:

 

Backups Required to Recover Tables and Table Partitions

Prior to recovering a table or table partition, you must perform a full backup of undo, SYSTEMSYSAUX, and the tablespace that contains the table or table partition.

To recover tables in a PDB, you need a backup of the root’s undo, SYSTEM, and SYSAUX tablespaces along with a backup of the PDB’s SYSTEM and SYSAUX tablespaces..

If the indexes or partitions for a table in tablespace tbs1 are contained in tablespace tbs2, then you can recover the table only if tablepsace tbs2 is also included in the recovery set. To recover a table, all partitions that contain the dependent objects of the table must be included in the recovery set.

Purpose of Recovering Tables and Table Partitions from RMAN Backups

RMAN enables you to recover one or more tables or table partitions to a specified point in time without affecting the remaining database objects. You can use previously-created RMAN backups to recover tables and table partitions to a specified point in time.

Recovering tables and table partitions from RMAN backups is useful in the following scenarios:

  • You need to recover a very small number of tables to a particular point in time. In this situation, TSPITR is not the most effective solution because it moves all the objects in the tablespace to a specified point in time.

  • You need to recover tables that have been logically corrupted or have been dropped and purged.

  • Flashback Table is not possible because the desired point-in-time is older than available undo.

  • You want to recover data that is lost after a DDL operation modified the structure of tables. Using Flashback Table is not possible because a DDL was run on the tables between the desired point in time and the current time. Flashback Table cannot rewind tables through structural changes such as a truncate table operation.

 

 

1) Create a table as below and make a note scn number:

SYS AS SYSDBA test >create table test.test1 tablespace "test" as select * from sys.obj$;

Table created.

SYS AS SYSDBA test >select current_scn from v$database;

CURRENT_SCN
-----------
1607764

SYS AS SYSDBA test >select current_scn from v$database;

CURRENT_SCN
-----------
1607792


1607941

2) Backup database:

connected to target database: TESTDB (DBID=2660866528)

RMAN> backup database;

Starting backup at 06-OCT-16
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=248 device type=DISK
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=/data01/oradata/test/test/system01.dbf
input datafile file number=00003 name=/data01/oradata/test/test/sysaux01.dbf
input datafile file number=00004 name=/data01/oradata/test/test/undotbs01.dbf
input datafile file number=00005 name=/data01/oradata/test/test/test01.ORA
input datafile file number=00006 name=/data01/oradata/test/test/users01.dbf
channel ORA_DISK_1: starting piece 1 at 06-OCT-16
channel ORA_DISK_1: finished piece 1 at 06-OCT-16
piece handle=/data01/oradata/test/backup/TEST_01rhmagh_1_1 tag=TAG20161006T130521 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
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 06-OCT-16
channel ORA_DISK_1: finished piece 1 at 06-OCT-16
piece handle=/data01/oradata/test/backup/TEST_02rhmah0_1_1 tag=TAG20161006T130521 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 06-OCT-16

3)

RMAN> list backup;


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


BS Key Type LV Size Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ ---------------
1 Full 1.33G DISK 00:00:07 06-OCT-16
BP Key: 1 Status: AVAILABLE Compressed: NO Tag: TAG20161006T130521
Piece Name: /data01/oradata/test/backup/TEST_01rhmagh_1_1
List of Datafiles in backup set 1
File LV Type Ckp SCN Ckp Time Name
---- -- ---- ---------- --------- ----
1 Full 1607936 06-OCT-16 /data01/oradata/test/test/system01.dbf
3 Full 1607936 06-OCT-16 /data01/oradata/test/test/sysaux01.dbf
4 Full 1607936 06-OCT-16 /data01/oradata/test/test/undotbs01.dbf
5 Full 1607936 06-OCT-16 /data01/oradata/test/test/test01.ORA
6 Full 1607936 06-OCT-16 /data01/oradata/test/test/users01.dbf

BS Key Type LV Size Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ ---------------
2 Full 9.64M DISK 00:00:01 06-OCT-16
BP Key: 2 Status: AVAILABLE Compressed: NO Tag: TAG20161006T130521
Piece Name: /data01/oradata/test/backup/TEST_02rhmah0_1_1
SPFILE Included: Modification time: 06-OCT-16
SPFILE db_unique_name: TEST
Control File Included: Ckp SCN: 1607941 Ckp time: 06-OCT-16


4) Drop the table:

SYS AS SYSDBA test >drop table test.test1;

Table dropped.

SYS AS SYSDBA test >exit
Disconnected from Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
/data01/oradata/test/backup$ pwd
/data01/oradata/test/backup
/data01/oradata/test/backup$ ls -lrt
total 1408940
-rw-r----- 1 oracle dba 1432625152 Oct 6 13:05 TEST_01rhmagh_1_1
-rw-r----- 1 oracle dba 10125312 Oct 6 13:05 TEST_02rhmah0_1_1

5) Recvoer table;


/data01/oradata/test/backup$ rman target /

Recovery Manager: Release 12.1.0.2.0 - Production on Thu Oct 6 13:07:22 2016

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

connected to target database: TEST (DBID=2222672538)

RMAN> recover table chalasaniv.test1 until scn 1607941 auxiliary destination '/data01/oradata/test/backup';

Starting recover at 06-OCT-16
using target database control file instead of recovery catalog
current log archived
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=12 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='Dpdg'

initialization parameters used for automatic instance:
db_name=TEST
db_unique_name=Dpdg_pitr_TEST
compatible=12.1.0.2.0
db_block_size=8192
db_files=200
diagnostic_dest=/usr01/app/oracle
_system_trig_enabled=FALSE
sga_target=2560M
processes=200
db_create_file_dest=/data01/oradata/test/backup
log_archive_dest_1='location=/data01/oradata/test/backup'
#No auxiliary parameter file used


starting up automatic instance TEST

Oracle instance started

Total System Global Area 2684354560 bytes

Fixed Size 2928008 bytes
Variable Size 603980408 bytes
Database Buffers 2063597568 bytes
Redo Buffers 13848576 bytes
Automatic instance created

contents of Memory Script:
{
# set requested point in time
set until scn 1607941;
# 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';
}
executing Memory Script

executing command: SET until clause

Starting restore at 06-OCT-16
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=246 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 /data01/oradata/test/backup/TEST_02rhmah0_1_1
channel ORA_AUX_DISK_1: piece handle=/data01/oradata/test/backup/TEST_02rhmah0_1_1 tag=TAG20161006T130521
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/data01/oradata/test/backup/TEST/controlfile/o1_mf_czf175dj_.ctl
Finished restore at 06-OCT-16

sql statement: alter database mount clone database

sql statement: alter system archive log current

contents of Memory Script:
{
# set requested point in time
set until scn 1607941;
# set destinations for recovery set and auxiliary set datafiles
set newname for clone datafile 1 to new;
set newname for clone datafile 4 to new;
set newname for clone datafile 3 to new;
set newname for clone tempfile 1 to new;
# switch all tempfiles
switch clone tempfile all;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 1, 4, 3;

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

renamed tempfile 1 to /data01/oradata/test/backup/TEST/datafile/o1_mf_temp_%u_.tmp in control file

Starting restore at 06-OCT-16
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 /data01/oradata/test/backup/TEST/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /data01/oradata/test/backup/TEST/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /data01/oradata/test/backup/TEST/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /data01/oradata/test/backup/TEST_01rhmagh_1_1
channel ORA_AUX_DISK_1: piece handle=/data01/oradata/test/backup/TEST_01rhmagh_1_1 tag=TAG20161006T130521
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:15
Finished restore at 06-OCT-16

datafile 1 switched to datafile copy
input datafile copy RECID=4 STAMP=924527290 file name=/data01/oradata/test/backup/TEST/datafile/o1_mf_system_czf17cdq_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=5 STAMP=924527290 file name=/data01/oradata/test/backup/TEST/datafile/o1_mf_undotbs1_czf17cf8_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=6 STAMP=924527290 file name=/data01/oradata/test/backup/TEST/datafile/o1_mf_sysaux_czf17cf0_.dbf

contents of Memory Script:
{
# set requested point in time
set until scn 1607941;
# online the datafiles restored or switched
sql clone "alter database datafile 1 online";
sql clone "alter database datafile 4 online";
sql clone "alter database datafile 3 online";
# recover and open database read only
recover clone database tablespace "SYSTEM", "UNDOTBS1", "SYSAUX";
sql clone 'alter database open read only';
}
executing Memory Script

executing command: SET until clause

sql statement: alter database datafile 1 online

sql statement: alter database datafile 4 online

sql statement: alter database datafile 3 online

Starting recover at 06-OCT-16
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 13 is already on disk as file /log01/oradata/test/arch/1_13_924526107.dbf
archived log file name=/log01/oradata/test/arch/1_13_924526107.dbf thread=1 sequence=13
media recovery complete, elapsed time: 00:00:00
Finished recover at 06-OCT-16

sql statement: alter database open read only

contents of Memory Script:
{
sql clone "create spfile from memory";
shutdown clone immediate;
startup clone nomount;
sql clone "alter system set control_files =
''/data01/oradata/test/backup/TEST/controlfile/o1_mf_czf175dj_.ctl'' comment=
''RMAN set'' scope=spfile";
shutdown clone immediate;
startup clone nomount;
# mount database
sql clone 'alter database mount clone database';
}
executing Memory Script

sql statement: create spfile from memory

database closed
database dismounted
Oracle instance shut down

connected to auxiliary database (not started)
Oracle instance started

Total System Global Area 2684354560 bytes

Fixed Size 2928008 bytes
Variable Size 603980408 bytes
Database Buffers 2063597568 bytes
Redo Buffers 13848576 bytes

sql statement: alter system set control_files = ''/data01/oradata/test/backup/TEST/controlfile/o1_mf_czf175dj_.ctl'' comment= ''RMAN set'' scope=spfile

Oracle instance shut down

connected to auxiliary database (not started)
Oracle instance started

Total System Global Area 2684354560 bytes

Fixed Size 2928008 bytes
Variable Size 603980408 bytes
Database Buffers 2063597568 bytes
Redo Buffers 13848576 bytes

sql statement: alter database mount clone database

contents of Memory Script:
{
# set requested point in time
set until scn 1607941;
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile 5 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 5;

switch clone datafile all;
}
executing Memory Script

executing command: SET until clause

executing command: SET NEWNAME

Starting restore at 06-OCT-16
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=6 device type=DISK

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 00005 to /data01/oradata/test/backup/DPDG_PITR_TEST/datafile/o1_mf_test_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /data01/oradata/test/backup/TEST_01rhmagh_1_1
channel ORA_AUX_DISK_1: piece handle=/data01/oradata/test/backup/TEST_01rhmagh_1_1 tag=TAG20161006T130521
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 06-OCT-16

datafile 5 switched to datafile copy
input datafile copy RECID=8 STAMP=924527341 file name=/data01/oradata/test/backup/DPDG_PITR_TEST/datafile/o1_mf_test_czf19dn0_.dbf

contents of Memory Script:
{
# set requested point in time
set until scn 1607941;
# online the datafiles restored or switched
sql clone "alter database datafile 5 online";
# recover and open resetlogs
recover clone database tablespace "test", "SYSTEM", "UNDOTBS1", "SYSAUX" delete archivelog;
alter clone database open resetlogs;
}
executing Memory Script

executing command: SET until clause

sql statement: alter database datafile 5 online

Starting recover at 06-OCT-16
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 13 is already on disk as file /log01/oradata/test/arch/1_13_924526107.dbf
archived log file name=/log01/oradata/test/arch/1_13_924526107.dbf thread=1 sequence=13
media recovery complete, elapsed time: 00:00:00
Finished recover at 06-OCT-16

database opened

contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/data01/oradata/test/backup''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/data01/oradata/test/backup''";
}
executing Memory Script

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/data01/oradata/test/backup''

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/data01/oradata/test/backup''

Performing export of tables...
EXPDP> Starting "SYS"."TSPITR_EXP_Dpdg_gbqu":
EXPDP> Estimate in progress using BLOCKS method...
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
EXPDP> Total estimation using BLOCKS method: 12 MB
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
EXPDP> . . exported "CHALASANIV"."TEST1" 9.638 MB 91516 rows
EXPDP> Master table "SYS"."TSPITR_EXP_Dpdg_gbqu" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_Dpdg_gbqu is:
EXPDP> /data01/oradata/test/backup/tspitr_Dpdg_36937.dmp
EXPDP> Job "SYS"."TSPITR_EXP_Dpdg_gbqu" successfully completed at Thu Oct 6 13:09:21 2016 elapsed 0 00:00:12
Export completed


contents of Memory Script:
{
# shutdown clone before import
shutdown clone abort
}
executing Memory Script

Oracle instance shut down

Performing import of tables...
IMPDP> Master table "SYS"."TSPITR_IMP_Dpdg_bqxl" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_Dpdg_bqxl":
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
IMPDP> . . imported "CHALASANIV"."TEST1" 9.638 MB 91516 rows
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
IMPDP> Job "SYS"."TSPITR_IMP_Dpdg_bqxl" successfully completed at Thu Oct 6 13:09:29 2016 elapsed 0 00:00:02
Import completed


Removing automatic instance
Automatic instance removed
auxiliary instance file /data01/oradata/test/backup/TEST/datafile/o1_mf_temp_czf17w5l_.tmp deleted
auxiliary instance file /data01/oradata/test/backup/DPDG_PITR_TEST/onlinelog/o1_mf_3_czf19glv_.log deleted
auxiliary instance file /data01/oradata/test/backup/DPDG_PITR_TEST/onlinelog/o1_mf_2_czf19ggr_.log deleted
auxiliary instance file /data01/oradata/test/backup/DPDG_PITR_TEST/onlinelog/o1_mf_1_czf19gbp_.log deleted
auxiliary instance file /data01/oradata/test/backup/DPDG_PITR_TEST/datafile/o1_mf_test_czf19dn0_.dbf deleted
auxiliary instance file /data01/oradata/test/backup/TEST/datafile/o1_mf_sysaux_czf17cf0_.dbf deleted
auxiliary instance file /data01/oradata/test/backup/TEST/datafile/o1_mf_undotbs1_czf17cf8_.dbf deleted
auxiliary instance file /data01/oradata/test/backup/TEST/datafile/o1_mf_system_czf17cdq_.dbf deleted
auxiliary instance file /data01/oradata/test/backup/TEST/controlfile/o1_mf_czf175dj_.ctl deleted
auxiliary instance file tspitr_Dpdg_36937.dmp deleted
Finished recover at 06-OCT-16

RMAN> exit