12c New Feature: RMAN Table Recovery


image-anykey

A other new feature in 12c is the possibility to restore a table with rman. In a pre 12c for example you will do a Tablespace Point In Time Recovery (TPITR) to create a auxiliary database and then export your table from there. In 12c the steps are the same, but you will need a single command for the operation. RMAN will create the auxiliary database and will do the export and import jobs for you. The Prerequisites for this operation are very simple. You need a 12c database in archivelog mode which is read write open.

This Feature is usefull for example:

  • If you have purged your table (no Flashback drop)
  • No undo data available
  • After a structural DDL change
  • If only small table is needed for restore

In detail the steps look like this:

  • RMAN uses backups that were previously created to recover tables and table partitions to a specified point in time. You must simply define a recover command with the following parameter:
    – Names of tables or table partitions to be recovered
    – Point in time to which the tables or table partitions need to be recovered
    – Whether the recovered tables or table partitions must be imported into the target database
  • RMAN use the input to recover the table.
  • RMAN use the best backup you have.
  • RMAN creates an auxiliary instance.
  • RMAN recovers your tables or table partitions, up to the specified point in time, into this auxiliary instance.
  • RMAN creates a Data Pump export dump file that contains the recovered objects.
  • RMAN imports the recovered objects into the target database.

You can use different Point in Time recovery options like SCN, Time or sequence number. You are also able to use a transform parameter for the import like REMAP TABLE or REMAP TABLESPACE. This feature works also for Pluggable Databases.

Here is a short example:

We create a test table under the HR Schema, then check for the SCN and delete the table. The goal is to recreate the table with RMAN.

create table hr.test_table (id number(8),name varchar2(50),now date) tablespace users;
insert into hr.test_table values (1,'First test',sysdate);
insert into hr.test_table values (2,'Second test',sysdate);
insert into hr.test_table values (3,'Thirdt test',sysdate);
commit;

Now make a Backup:

$ rman target /

Recovery Manager: Release 12.1.0.1.0 - Production on Mon Jul 1 22:10:53 2013

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

connected to target database: DB1211 (DBID=1666640222)

RMAN> backup tablespace users;

Starting backup at 01-JUL-13
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=13 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=00006 name=/u01/app/oracle/oradata/db1211/users01.dbf
channel ORA_DISK_1: starting piece 1 at 01-JUL-13
channel ORA_DISK_1: finished piece 1 at 01-JUL-13
piece handle=/u01/app/oracle/fast_recovery_area/DB1211/backupset/2013_07_01/o1_mf_nnndf_TAG20130701T221107_8x3rlw9w_.bkp tag=TAG20130701T221107 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 01-JUL-13

Check for the current SCN and delete the table:

SQL> @sel_scn

TIMESTAMP_TO_SCN(CURRENT_TIMESTAMP)
-----------------------------------
                2156535

SQL> drop table hr.test_table purge;

Table dropped.

Create a temporary work directory:

$ mkdir /u01/app/oracle/backup_test

And at last, recover the table back again:

Recovery Manager: Release 12.1.0.1.0 - Production on Mon Jul 1 22:30:06 2013

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

connected to target database: DB1211 (DBID=1666640222)

RMAN> RECOVER TABLE hr.test_table UNTIL SCN 2156535 AUXILIARY DESTINATION '/u01/app/oracle/backup_test';

Starting recover at 01-JUL-13
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=92 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='mgdo'

initialization parameters used for automatic instance:
db_name=DB1211
db_unique_name=mgdo_pitr_DB1211
compatible=12.1.0.0.0
db_block_size=8192
db_files=200
sga_target=1G
processes=80
diagnostic_dest=/u01/app/oracle
db_create_file_dest=/u01/app/oracle/backup_test
log_archive_dest_1='location=/u01/app/oracle/backup_test'
#No auxiliary parameter file used

starting up automatic instance DB1211

Oracle instance started

Total System Global Area    1068937216 bytes

Fixed Size                     2296576 bytes
Variable Size                293602560 bytes
Database Buffers             767557632 bytes
Redo Buffers                   5480448 bytes
Automatic instance created
contents of Memory Script:
{
# set requested point in time
set until  scn 2156535;
# 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 01-JUL-13
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=111 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 /u01/app/oracle/fast_recovery_area/DB1211/autobackup/2013_07_01/o1_mf_s_819670947_8x3s83hd_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/DB1211/autobackup/2013_07_01/o1_mf_s_819670947_8x3s83hd_.bkp tag=TAG20130701T222227
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/u01/app/oracle/backup_test/DB1211/controlfile/o1_mf_8x3spwds_.ctl
Finished restore at 01-JUL-13

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 2156535;
# 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 /u01/app/oracle/backup_test/DB1211/datafile/o1_mf_temp_%u_.tmp in control file

Starting restore at 01-JUL-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 /u01/app/oracle/backup_test/DB1211/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /u01/app/oracle/backup_test/DB1211/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/DB1211/backupset/2013_07_01/o1_mf_nnndf_TAG20130701T222030_8x3s4j7y_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/DB1211/backupset/2013_07_01/o1_mf_nnndf_TAG20130701T222030_8x3s4j7y_.bkp tag=TAG20130701T222030
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:01:35
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 /u01/app/oracle/backup_test/DB1211/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/DB1211/backupset/2013_07_01/o1_mf_nnndf_TAG20130701T222030_8x3s804p_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/DB1211/backupset/2013_07_01/o1_mf_nnndf_TAG20130701T222030_8x3s804p_.bkp tag=TAG20130701T222030
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
Finished restore at 01-JUL-13

datafile 1 switched to datafile copy
input datafile copy RECID=4 STAMP=819671526 file name=/u01/app/oracle/backup_test/DB1211/datafile/o1_mf_system_8x3sq40d_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=5 STAMP=819671526 file name=/u01/app/oracle/backup_test/DB1211/datafile/o1_mf_undotbs1_8x3st2py_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=6 STAMP=819671526 file name=/u01/app/oracle/backup_test/DB1211/datafile/o1_mf_sysaux_8x3sq3hp_.dbf

contents of Memory Script:
{
# set requested point in time
set until  scn 2156535;
# 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 01-JUL-13
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 25 is already on disk as file /u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_25_8x3s9p36_.arc
archived log for thread 1 with sequence 26 is already on disk as file /u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_26_8x3scvd1_.arc
archived log for thread 1 with sequence 27 is already on disk as file /u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_27_8x3sfhrl_.arc
archived log file name=/u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_25_8x3s9p36_.arc thread=1 sequence=25
archived log file name=/u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_26_8x3scvd1_.arc thread=1 sequence=26
archived log file name=/u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_27_8x3sfhrl_.arc thread=1 sequence=27
media recovery complete, elapsed time: 00:00:01
Finished recover at 01-JUL-13

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 =
  ''/u01/app/oracle/backup_test/DB1211/controlfile/o1_mf_8x3spwds_.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    1068937216 bytes

Fixed Size                     2296576 bytes
Variable Size                297796864 bytes
Database Buffers             763363328 bytes
Redo Buffers                   5480448 bytes

sql statement: alter system set  control_files =   ''/u01/app/oracle/backup_test/DB1211/controlfile/o1_mf_8x3spwds_.ctl'' comment= ''RMAN set'' scope=spfile

Oracle instance shut down

connected to auxiliary database (not started)
Oracle instance started

Total System Global Area    1068937216 bytes

Fixed Size                     2296576 bytes
Variable Size                297796864 bytes
Database Buffers             763363328 bytes
Redo Buffers                   5480448 bytes

sql statement: alter database mount clone database

contents of Memory Script:
{
# set requested point in time
set until  scn 2156535;
# 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 01-JUL-13
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=8 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 /u01/app/oracle/backup_test/MGDO_PITR_DB1211/datafile/o1_mf_users_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/DB1211/backupset/2013_07_01/o1_mf_nnndf_TAG20130701T222030_8x3s804p_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/DB1211/backupset/2013_07_01/o1_mf_nnndf_TAG20130701T222030_8x3s804p_.bkp tag=TAG20130701T222030
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
Finished restore at 01-JUL-13

datafile 6 switched to datafile copy
input datafile copy RECID=8 STAMP=819671588 file name=/u01/app/oracle/backup_test/MGDO_PITR_DB1211/datafile/o1_mf_users_8x3sw3dn_.dbf

contents of Memory Script:
{
# set requested point in time
set until  scn 2156535;
# 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 01-JUL-13
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 25 is already on disk as file /u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_25_8x3s9p36_.arc
archived log for thread 1 with sequence 26 is already on disk as file /u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_26_8x3scvd1_.arc
archived log for thread 1 with sequence 27 is already on disk as file /u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_27_8x3sfhrl_.arc
archived log file name=/u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_25_8x3s9p36_.arc thread=1 sequence=25
archived log file name=/u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_26_8x3scvd1_.arc thread=1 sequence=26
archived log file name=/u01/app/oracle/fast_recovery_area/DB1211/archivelog/2013_07_01/o1_mf_1_27_8x3sfhrl_.arc thread=1 sequence=27
media recovery complete, elapsed time: 00:00:02
Finished recover at 01-JUL-13

database opened

contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u01/app/oracle/backup_test''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u01/app/oracle/backup_test''";
}
executing Memory Script

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/app/oracle/backup_test''

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/app/oracle/backup_test''

Performing export of tables...
   EXPDP> Starting "SYS"."TSPITR_EXP_mgdo_vyuf":
   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> ORA-39127: unexpected error from call to export_string :=SYS.DBMS_TRANSFORM_EXIMP.INSTANCE_INFO_EXP('AQ$_ORDERS_QUEUETABLE_S','IX',1,1,'12.01.00.00.00',newblock)
ORA-00376: file 2 cannot be read at this time
ORA-01110: data file 2: '/u01/app/oracle/oradata/db1211/example01.dbf'
ORA-06512: at "SYS.DBMS_TRANSFORM_EXIMP", line 197
ORA-06512: at line 1
ORA-06512: at "SYS.DBMS_METADATA", line 9901
ORA-39127: unexpected error from call to export_string :=SYS.DBMS_TRANSFORM_EXIMP.INSTANCE_INFO_EXP('AQ$_STREAMS_QUEUE_TABLE_S','IX',1,1,'12.01.00.00.00',newblock)
ORA-00376: file 2 cannot be read at this time
ORA-01110: data file 2: '/u01/app/oracle/oradata/db1211/example01.dbf'
ORA-06512: at "SYS.DBMS_TRANSFORM_EXIMP", line 197
ORA-06512: at line 1
ORA-06512: at "SYS.DBMS_METADATA", line 9901
   EXPDP> . . exported "HR"."TEST_TABLE"                           5.984 KB       3 rows
   EXPDP> Master table "SYS"."TSPITR_EXP_mgdo_vyuf" successfully loaded/unloaded
   EXPDP> ******************************************************************************
   EXPDP> Dump file set for SYS.TSPITR_EXP_mgdo_vyuf is:
   EXPDP>   /u01/app/oracle/backup_test/tspitr_mgdo_83156.dmp
   EXPDP> Job "SYS"."TSPITR_EXP_mgdo_vyuf" completed with 2 error(s) at Mon Jul 1 22:34:31 2013 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_mgdo_vvcf" successfully loaded/unloaded
   IMPDP> Starting "SYS"."TSPITR_IMP_mgdo_vvcf":
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
   IMPDP> . . imported "HR"."TEST_TABLE"                           5.984 KB       3 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_mgdo_vvcf" successfully completed at Mon Jul 1 22:35:52 2013 elapsed 0 00:00:13
Import completed

Removing automatic instance
Automatic instance removed
auxiliary instance file /u01/app/oracle/backup_test/DB1211/datafile/o1_mf_temp_8x3stnrw_.tmp deleted
auxiliary instance file /u01/app/oracle/backup_test/MGDO_PITR_DB1211/onlinelog/o1_mf_3_8x3swv8p_.log deleted
auxiliary instance file /u01/app/oracle/backup_test/MGDO_PITR_DB1211/onlinelog/o1_mf_2_8x3swtpw_.log deleted
auxiliary instance file /u01/app/oracle/backup_test/MGDO_PITR_DB1211/onlinelog/o1_mf_1_8x3swtc2_.log deleted
auxiliary instance file /u01/app/oracle/backup_test/MGDO_PITR_DB1211/datafile/o1_mf_users_8x3sw3dn_.dbf deleted
auxiliary instance file /u01/app/oracle/backup_test/DB1211/datafile/o1_mf_sysaux_8x3sq3hp_.dbf deleted
auxiliary instance file /u01/app/oracle/backup_test/DB1211/datafile/o1_mf_undotbs1_8x3st2py_.dbf deleted
auxiliary instance file /u01/app/oracle/backup_test/DB1211/datafile/o1_mf_system_8x3sq40d_.dbf deleted
auxiliary instance file /u01/app/oracle/backup_test/DB1211/controlfile/o1_mf_8x3spwds_.ctl deleted
auxiliary instance file tspitr_mgdo_83156.dmp deleted
Finished recover at 01-JUL-13

Recovery Manager complete.
Advertisements

Kommentar verfassen

Trage deine Daten unten ein oder klicke ein Icon um dich einzuloggen:

WordPress.com-Logo

Du kommentierst mit Deinem WordPress.com-Konto. Abmelden / Ändern )

Twitter-Bild

Du kommentierst mit Deinem Twitter-Konto. Abmelden / Ändern )

Facebook-Foto

Du kommentierst mit Deinem Facebook-Konto. Abmelden / Ändern )

Google+ Foto

Du kommentierst mit Deinem Google+-Konto. Abmelden / Ändern )

Verbinde mit %s