Till 11g, we were able to recover a tablespace from rman backup set. But in 12c , we can recover a dropped table from valid rman backup set, and db will be up and running during the recovery.
DEMO:
1. Check the row count of a table.
SQL> select count(*) from SCOTT.SALGRADE;
COUNT(*)
----------
5
2. Take a full rman backup:
run
{
allocate channel d1 type disk format ‘/u03/arch/TEST/BACKUP/rmn_%d_t%t_p%p’;
backup
incremental level 1
tag backup_level0
filesperset 1
(database)
plus archivelog ;
release channel d1;
}
3. Note down the current timestamp or scn.
SQL> select to_char(sysdate,’mm/dd/yyyy hh24:mi:ss’) current_time from dual;
CURRENT_TIME
——————-
08/09/2016 18:50:00
4. Now drop the table with purge.
drop table SCOTT.SALGRADE PURGE;
5 .Lets proceed with recover table with point in time.
recover table SCOTT.SALGRADE until time “to_date(’08/09/2016 18:49:40′,’mm/dd/yyyy hh24:mi:ss’)”
auxiliary destination ‘/u03/arch/TEST/BACKUP’
datapump destination ‘/u03/arch/TEST/BACKUP’;
auxiliary destination – Location where all the related files for auxiliary instance will be placed
datapump destination – Location where the export dump of the table will be placed
RMAN> recover table SCOTT.SALGRADE until time "to_date('08/09/2016 18:49:40','mm/dd/yyyy hh24:mi:ss')" auxiliary destination '/u03/arch/TEST/BACKUP';
Starting recover at 09-AUG-16
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=465 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='auqD'
initialization parameters used for automatic instance:
db_name=BBCRMDB2
db_unique_name=auqD_pitr_BBCRMDB2
compatible=12.1.0.2.0
db_block_size=8192
db_files=200
diagnostic_dest=/u01/app/oracle/admin/BBCRMDB2
_system_trig_enabled=FALSE
sga_target=2560M
processes=200
db_create_file_dest=/u03/arch/TEST/BACKUP
log_archive_dest_1='location=/u03/arch/TEST/BACKUP'
#No auxiliary parameter file used
starting up automatic instance BBCRMDB2
Oracle instance started
Total System Global Area 2684354560 bytes
Fixed Size 3704072 bytes
Variable Size 788536056 bytes
Database Buffers 1744830464 bytes
Redo Buffers 147283968 bytes
Automatic instance created
contents of Memory Script:
{
# set requested point in time
set until time "to_date('08/09/2016 18:49:40','mm/dd/yyyy 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';
}
executing Memory Script
executing command: SET until clause
Starting restore at 09-AUG-16
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=124 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 /u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450087_p1
channel ORA_AUX_DISK_1: piece handle=/u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450087_p1 tag=BACKUP_LEVEL0
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/u03/arch/TEST/BACKUP/BBCRMDB2/controlfile/o1_mf_ctmzvtt7_.ctl
Finished restore at 09-AUG-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 time "to_date('08/09/2016 18:49:40','mm/dd/yyyy hh24:mi:ss')";
# 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 /u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 09-AUG-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 00004 to /u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450071_p1
channel ORA_AUX_DISK_1: piece handle=/u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450071_p1 tag=BACKUP_LEVEL0
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:07
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 /u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450072_p1
channel ORA_AUX_DISK_1: piece handle=/u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450072_p1 tag=BACKUP_LEVEL0
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
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 /u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450080_p1
channel ORA_AUX_DISK_1: piece handle=/u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450080_p1 tag=BACKUP_LEVEL0
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
Finished restore at 09-AUG-16
datafile 1 switched to datafile copy
input datafile copy RECID=4 STAMP=919451198 file name=/u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_system_ctmzwcf2_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=5 STAMP=919451198 file name=/u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_undotbs1_ctmzw16p_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=6 STAMP=919451198 file name=/u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_sysaux_ctmzw8b4_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('08/09/2016 18:49:40','mm/dd/yyyy hh24:mi:ss')";
# 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 09-AUG-16
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 6981 is already on disk as file /u03/arch/TEST/1_6981_903455979.dbf
archived log for thread 1 with sequence 6982 is already on disk as file /u03/arch/TEST/1_6982_903455979.dbf
archived log file name=/u03/arch/TEST/1_6981_903455979.dbf thread=1 sequence=6981
archived log file name=/u03/arch/TEST/1_6982_903455979.dbf thread=1 sequence=6982
media recovery complete, elapsed time: 00:00:00
Finished recover at 09-AUG-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 =
''/u03/arch/TEST/BACKUP/BBCRMDB2/controlfile/o1_mf_ctmzvtt7_.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 3704072 bytes
Variable Size 805313272 bytes
Database Buffers 1728053248 bytes
Redo Buffers 147283968 bytes
sql statement: alter system set control_files = ''/u03/arch/TEST/BACKUP/BBCRMDB2/controlfile/o1_mf_ctmzvtt7_.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 3704072 bytes
Variable Size 805313272 bytes
Database Buffers 1728053248 bytes
Redo Buffers 147283968 bytes
sql statement: alter database mount clone database
contents of Memory Script:
{
# set requested point in time
set until time "to_date('08/09/2016 18:49:40','mm/dd/yyyy hh24:mi:ss')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile 6 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 6;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
executing command: SET NEWNAME
Starting restore at 09-AUG-16
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=124 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 00006 to /u03/arch/TEST/BACKUP/AUQD_PITR_BBCRMDB2/datafile/o1_mf_users_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450089_p1
channel ORA_AUX_DISK_1: piece handle=/u03/arch/TEST/BACKUP/rmn_BBCRMDB2_t919450089_p1 tag=BACKUP_LEVEL0
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 09-AUG-16
datafile 6 switched to datafile copy
input datafile copy RECID=8 STAMP=919451283 file name=/u03/arch/TEST/BACKUP/AUQD_PITR_BBCRMDB2/datafile/o1_mf_users_ctmzz27q_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('08/09/2016 18:49:40','mm/dd/yyyy hh24:mi:ss')";
# online the datafiles restored or switched
sql clone "alter database datafile 6 online";
# recover and open resetlogs
recover clone database tablespace "USERS", "SYSTEM", "UNDOTBS1", "SYSAUX" delete archivelog;
alter clone database open resetlogs;
}
executing Memory Script
executing command: SET until clause
sql statement: alter database datafile 6 online
Starting recover at 09-AUG-16
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 6981 is already on disk as file /u03/arch/TEST/1_6981_903455979.dbf
archived log for thread 1 with sequence 6982 is already on disk as file /u03/arch/TEST/1_6982_903455979.dbf
archived log file name=/u03/arch/TEST/1_6981_903455979.dbf thread=1 sequence=6981
archived log file name=/u03/arch/TEST/1_6982_903455979.dbf thread=1 sequence=6982
media recovery complete, elapsed time: 00:00:01
Finished recover at 09-AUG-16
database opened
contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u03/arch/TEST/BACKUP''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u03/arch/TEST/BACKUP''";
}
executing Memory Script
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u03/arch/TEST/BACKUP''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u03/arch/TEST/BACKUP''
Performing export of tables...
EXPDP> Starting "SYS"."TSPITR_EXP_auqD_axcp":
EXPDP> Estimate in progress using BLOCKS method...
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
EXPDP> Total estimation using BLOCKS method: 64 KB
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 "SCOTT"."SALGRADE" 5.953 KB 5 rows
EXPDP> Master table "SYS"."TSPITR_EXP_auqD_axcp" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_auqD_axcp is:
EXPDP> /u03/arch/TEST/BACKUP/tspitr_auqD_92806.dmp
EXPDP> Job "SYS"."TSPITR_EXP_auqD_axcp" successfully completed at Tue Aug 9 19:09:01 2016 elapsed 0 00:00:35
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_auqD_aDwq" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_auqD_aDwq":
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
IMPDP> . . imported "SCOTT"."SALGRADE" 5.953 KB 5 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_auqD_aDwq" successfully completed at Tue Aug 9 19:09:46 2016 elapsed 0 00:00:32
Import completed
Removing automatic instance
Automatic instance removed
auxiliary instance file /u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_temp_ctmzwv4k_.tmp deleted
auxiliary instance file /u03/arch/TEST/BACKUP/AUQD_PITR_BBCRMDB2/onlinelog/o1_mf_3_ctmzzhkh_.log deleted
auxiliary instance file /u03/arch/TEST/BACKUP/AUQD_PITR_BBCRMDB2/onlinelog/o1_mf_2_ctmzzhf9_.log deleted
auxiliary instance file /u03/arch/TEST/BACKUP/AUQD_PITR_BBCRMDB2/onlinelog/o1_mf_1_ctmzzh8y_.log deleted
auxiliary instance file /u03/arch/TEST/BACKUP/AUQD_PITR_BBCRMDB2/datafile/o1_mf_users_ctmzz27q_.dbf deleted
auxiliary instance file /u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_sysaux_ctmzw8b4_.dbf deleted
auxiliary instance file /u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_undotbs1_ctmzw16p_.dbf deleted
auxiliary instance file /u03/arch/TEST/BACKUP/BBCRMDB2/datafile/o1_mf_system_ctmzwcf2_.dbf deleted
auxiliary instance file /u03/arch/TEST/BACKUP/BBCRMDB2/controlfile/o1_mf_ctmzvtt7_.ctl deleted
auxiliary instance file tspitr_auqD_92806.dmp deleted
Finished recover at 09-AUG-16
5. Check whether table has been restored or not.
RMAN> select count(*) from "SCOTT"."SALGRADE"; using target database control file instead of recovery catalog COUNT(*) ---------- 5
There are few additional keywords which can be used with the recover command.
1. REMAP_TABLE – For restoring the table to a new name
recover table SCOTT.SALGRADE until time “to_date(’08/09/2016 18:49:40′,’mm/dd/yyyy hh24:mi:ss’)”
auxiliary destination ‘/u03/arch/TEST/BACKUP’
datapump destination ‘/u03/arch/TEST/BACKUP’
REMAP_TABLE ‘SCOTT’.’SALGRADE’:’SALGRADE_BKP’;
2. NOTABLEIMPORT: This will just generate the table dump from the backup set. It won’t import the dump.
recover table SCOTT.SALGRADE until time “to_date(’08/09/2016 18:49:40′,’mm/dd/yyyy hh24:mi:ss’)”
auxiliary destination ‘/u03/arch/TEST/BACKUP’
datapump destination ‘/u03/arch/TEST/BACKUP’
NOTABLEIMPORT;
COMMON ERRORS:
1. RMAN-04017: startup error description: ORA-00821: Specified value of sga_target 2560M is too small, needs to be at least 2608M
While starting the rman recovery if you are getting below error.
metalink id : Doc ID 1386218.1
RMAN-00571: =========================================================== RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS =============== RMAN-00571: =========================================================== RMAN-03002: failure of recover command at 08/10/2016 17:35:38 RMAN-04014: startup failed: ORA-01078: failure in processing system parameters RMAN-04017: startup error description: ORA-00821: Specified value of sga_target 2560M is too small, needs to be at least 2608M
Solution:
We need to start an auxiliary instance with higher sga value and start the recover.
auxiliary file details:
cat initaux.ora
db_name=TEST
db_unique_name=afnx_pitr_TEST
compatible=12.1.0.2.0
db_block_size=8192
db_files=200
diagnostic_dest=/oracle/app/oracle
_system_trig_enabled=FALSE
sga_target=8G
processes=200
db_create_file_dest=/tmp/TEST
log_archive_dest_1=’location=/tmp/TEST’
db_name – Name of the database, where we are doing recovery
db_unique_name – Any random instance name
Now run the recover table command as below:
run
{
configure channel DEVICE TYPE SBT parms ‘ENV=(NSR_SERVER=nwbss,NSR_CLIENT=db-host)’;
set auxiliary instance parameter file to ‘/tmp/initaux.ora’;
recover table ‘TESTDBA’.’TEST’ until time “to_date(’08/10/2016 12:00:00′,’mm/dd/yyyy hh24:mi:ss’)”
REMAP TABLE ‘STCDBA’.’TEST’:’TEST_PREV’;
}

Thank`s!
the option to change init parameters and parameter NOTABLEIMPORT was helpful for me!
Regards,
Roberto
Thanks very good article.
Hey,nice article..just a little correction..
instead of level 0 ,u mentioned level 1 in rman full backup.