Sunday 26 January 2014

Restore a table's specific partition to a specific point in time

The ability to restore a specific Table/partition is new in 12c.

The procedures are analogous to the tablespace Point In Time recovery (PITR) of 11g.
Table/partition point-in-time restore can be considered an evolution of tablespace PITR.
This procedure is indicated for cases where:
  • Only a few tables need PITR but they are in a tablespace which contains many other tables.
  • Execution of DDL on the table or the lack of UNDO prevents use of FLASHBACK TABLE.

 About table/partition PITR

  • Available for CDBs and non-cdbs.
  • Uses an auxiliary instance to recover the specified tables to specified point.
  • Uses available backups/archive logs to achieve PITR.
  • Uses a data pump dump to optionally export the recovered tablespace or tables back to the target database.

Scenario

A CDB called CDB1 contains a PDB called SALESPDB.
The PDB has a partitioned table called sales.
This is a point-in-time recovery to a specific SCN, 495664950.

It has these partitions.

SQL> select table_owner, table_name, partition_name
from dba_tab_partitions where table_name='SALES';
  2 
TABLE_OWNER          TABLE_NAME           PARTITION_NAME
-------------------- -------------------- --------------------
SALESADMIN           SALES                P2010
SALESADMIN           SALES                P2011
SALESADMIN           SALES                P2012
SALESADMIN           SALES                P2013

SQL> select count(*) from salesadmin.sales partition(p2010);

  COUNT(*)
----------
       364

It will be recovered as a new table named P2010, to another tablespace called TS_RECOVERY.

The partition P2010 will be truncated at the below SCN, to simulate the data loss.


SQL> select current_scn from v$database;

CURRENT_SCN
-----------
  495664950
 


SQL> alter table salesadmin.sales truncate partition p2010;

Table truncated.
 


Using RMAN to restore the table


The RMAN syntax for the point-in-time recovery of the table partition is :

recover table salesadmin.sales:p2010
   of pluggable database salespdb
    until scn 495664950
    remap tablespace salespdb:ts_recov
     auxiliary destination '/u01/app/oracle/oradata/tmp';


controlfile backup checkpoint scn   : 1470397
restore point scn                            : 495664950
partition restore target tablespace : TS_RECOV
partition restore target schema      : SALESADMIN
partition restore destination table  : P2010



Precautions:
  • Ensure backups of cdb, controlfile, are available for an scn earlier than recovery point.
  • Ensure that archive logs are available to recover data upto the desired point.
  • Ensure enough disk space is available for auxiliary instance and the recovery operation.
  • Ensure that table owner has enough quota in destination tablespace for the restored partitions.
  • An auxiliary destination must be specified otherwise the command will fail.


The main steps executed in the rman-generated memory scripts are

  1. Auxiliary instance creation and startup in nomount mode
  2. Memory script to restore a suitable controlfile from a backup and mount it
  3. Restoring the system files of the CDB and PDB – auxiliary set (system,sysaux,undo)
  4. Memory script to perform media recovery of the auxiliary set to scn 495664950.
  5. Restart the auxiliary instance with an spfile and mount it.
  6. Restore datafile 9, which contains the actual user data which needs to be recovered
  7. Performing media recovery on the auxiliary data files and opens the auxiliary instance.
  8. Open the PDB, create data pump directory objects in target as well as auxiliary.
  9. Shut down the auxiliary instance and start export/import job.
  10. The remainder of the document shows the RMAN recover table session highlights its actions

The remainder of the document shows the RMAN recover table session highlights its actions

Recovery Manager: Release 12.1.0.1.0 - Production on Mon Jan 27 12:24:19 2014

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

connected to target database: CDB1 (DBID=801127382)

RMAN> recover table salesadmin.sales:p2010
   of pluggable database salespdb
    until scn 495664950
    remap tablespace salespdb:ts_recov
     auxiliary destination '/u01/app/oracle/oradata/tmp';
2> 3> 4> 5>

Auxiliary instance creation and startup in nomount mode


Starting recover at 27-JAN-14
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=27 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='kxnv'

initialization parameters used for automatic instance:
db_name=CDB1
db_unique_name=kxnv_pitr_salespdb_CDB1
compatible=12.1.0.0.0
db_block_size=8192
db_files=200
sga_target=1G
processes=80
diagnostic_dest=/u01/app/oracle
db_16k_cache_size=128M
db_create_file_dest=/u01/app/oracle/oradata/tmp
log_archive_dest_1='location=/u01/app/oracle/oradata/tmp'
enable_pluggable_database=true
_clone_one_pdb_recovery=true
#No auxiliary parameter file used



starting up automatic instance CDB1

Oracle instance started

Total System Global Area    1068937216 bytes

Fixed Size                     2296576 bytes
Variable Size                251659520 bytes
Database Buffers             809500672 bytes
Redo Buffers                   5480448 bytes
Automatic instance created


Memory script to restore a suitable controlfile from a backup and mount it


contents of Memory Script:
{
# set requested point in time
set until  scn 495664950;
# 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 27-JAN-14
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=75 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/CDB1/autobackup/2014_01_27/o1_mf_s_837947651_9gcmr5xn_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/CDB1/autobackup/2014_01_27/o1_mf_s_837947651_9gcmr5xn_.bkp tag=TAG20140127T111411
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/oradata/tmp/CDB1/controlfile/o1_mf_9gcqw1mm_.ctl
Finished restore at 27-JAN-14

sql statement: alter database mount clone database

sql statement: alter system archive log current

Restoring the system files of the CDB and PDB - auxiliary set only (system,sysaux,undo)


contents of Memory Script:
{
# set requested point in time
set until  scn 495664950;
# set destinations for recovery set and auxiliary set datafiles
set newname for clone datafile  1 to new;
set newname for clone datafile  5 to new;
set newname for clone datafile  3 to new;
set newname for clone datafile  7 to new;
set newname for clone datafile  8 to new;
set newname for clone tempfile  1 to new;
set newname for clone tempfile  3 to new;
# switch all tempfiles
switch clone tempfile all;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile  1, 5, 3, 7, 8;
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
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
renamed tempfile 1 to /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_temp_%u_.tmp in control file
renamed tempfile 3 to /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_temp_%u_.tmp in control file

Starting restore at 27-JAN-14
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/oradata/tmp/CDB1/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00005 to /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/CDB1/backupset/2014_01_27/o1_mf_nnndf_TAG20140127T110930_9gcmhckh_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/CDB1/backupset/2014_01_27/o1_mf_nnndf_TAG20140127T110930_9gcmhckh_.bkp tag=TAG20140127T110930
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:02:46
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 00007 to /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00008 to /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/CDB1/E8B1D5DF593A7F63E0436801A8C0DFEC/backupset/2014_01_27/o1_mf_nnndf_TAG20140127T110930_9gcmln77_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/CDB1/E8B1D5DF593A7F63E0436801A8C0DFEC/backupset/2014_01_27/o1_mf_nnndf_TAG20140127T110930_9gcmln77_.bkp tag=TAG20140127T110930
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:01:15
Finished restore at 27-JAN-14

datafile 1 switched to datafile copy
input datafile copy RECID=13 STAMP=837952121 file name=/u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_system_9gcqw98r_.dbf
datafile 5 switched to datafile copy
input datafile copy RECID=14 STAMP=837952121 file name=/u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_undotbs1_9gcqw96p_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=15 STAMP=837952121 file name=/u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_sysaux_9gcqw98n_.dbf
datafile 7 switched to datafile copy
input datafile copy RECID=16 STAMP=837952121 file name=/u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_system_9gcr1gbf_.dbf
datafile 8 switched to datafile copy
input datafile copy RECID=17 STAMP=837952121 file name=/u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_sysaux_9gcr1gbd_.dbf

Memory script to perform media recovery of the auxiliary set data files to scn 495664950


contents of Memory Script:
{
# set requested point in time
set until  scn 495664950;
# online the datafiles restored or switched
sql clone "alter database datafile  1 online";
sql clone "alter database datafile  5 online";
sql clone "alter database datafile  3 online";
sql clone 'SALESPDB' "alter database datafile
 7 online";
sql clone 'SALESPDB' "alter database datafile
 8 online";
# recover and open database read only
recover clone database tablespace  "SYSTEM", "UNDOTBS1", "SYSAUX", "SALESPDB":"SYSTEM", "SALESPDB":"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  5 online
sql statement: alter database datafile  3 online
sql statement: alter database datafile  7 online
sql statement: alter database datafile  8 online

Starting recover at 27-JAN-14
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 237 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2014_01_27/o1_mf_1_237_9gcn8mqb_.arc
archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2014_01_27/o1_mf_1_237_9gcn8mqb_.arc thread=1 sequence=237
media recovery complete, elapsed time: 00:00:01
Finished recover at 27-JAN-14

sql statement: alter database open read only

 

Restart the auxiliary instance with an spfile and mount it.


contents of Memory Script:
{
sql clone 'alter pluggable database  SALESPDB open read only';
}
executing Memory Script

sql statement: alter pluggable database  SALESPDB 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/oradata/tmp/CDB1/controlfile/o1_mf_9gcqw1mm_.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                255853824 bytes
Database Buffers             805306368 bytes
Redo Buffers                   5480448 bytes

sql statement: alter system set  control_files =   ''/u01/app/oracle/oradata/tmp/CDB1/controlfile/o1_mf_9gcqw1mm_.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                255853824 bytes
Database Buffers             805306368 bytes
Redo Buffers                   5480448 bytes

sql statement: alter database mount clone database


Restore datafile 9, which contains the actual user data which needs to be recovered


contents of Memory Script:
{
# set requested point in time
set until  scn 495664950;
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile  9 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile  9;
switch clone datafile all;
}
executing Memory Script

executing command: SET until clause

executing command: SET NEWNAME

Starting restore at 27-JAN-14
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=11 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 00009 to /u01/app/oracle/oradata/tmp/KXNV_PITR_SALESPDB_CDB1/datafile/o1_mf_salespdb_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/CDB1/E8B1D5DF593A7F63E0436801A8C0DFEC/backupset/2014_01_27/o1_mf_nnndf_TAG20140127T110930_9gcmln77_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/CDB1/E8B1D5DF593A7F63E0436801A8C0DFEC/backupset/2014_01_27/o1_mf_nnndf_TAG20140127T110930_9gcmln77_.bkp tag=TAG20140127T110930
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:07
Finished restore at 27-JAN-14

datafile 9 switched to datafile copy
input datafile copy RECID=19 STAMP=837952172 file name=/u01/app/oracle/oradata/tmp/KXNV_PITR_SALESPDB_CDB1/datafile/o1_mf_salespdb_9gcr55b5_.dbf


Performing media recovery on the auxiliary data files and open the aux CDB database


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

executing command: SET until clause

sql statement: alter database datafile  9 online

Starting recover at 27-JAN-14
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 237 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2014_01_27/o1_mf_1_237_9gcn8mqb_.arc
archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2014_01_27/o1_mf_1_237_9gcn8mqb_.arc thread=1 sequence=237
media recovery complete, elapsed time: 00:00:00
Finished recover at 27-JAN-14

database opened

Opening the auxiliary instance PDB


contents of Memory Script:
{
sql clone 'alter pluggable database  SALESPDB open';
}
executing Memory Script

sql statement: alter pluggable database  SALESPDB open

Creating the directory objects in the target and auxiliary instance

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

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

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

Exporting the recovered data to a .dmp file

Performing export of tables...
   EXPDP> Starting "SYS"."TSPITR_EXP_kxnv_Ewvl": 
   EXPDP> Estimate in progress using BLOCKS method...
   EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
   EXPDP> Total estimation using BLOCKS method: 8 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 "SALESADMIN"."SALES":"P2010"                12.62 KB     364 rows
   EXPDP> Master table "SYS"."TSPITR_EXP_kxnv_Ewvl" successfully loaded/unloaded
   EXPDP> ******************************************************************************
   EXPDP> Dump file set for SYS.TSPITR_EXP_kxnv_Ewvl is:
   EXPDP>   /u01/app/oracle/oradata/tmp/tspitr_kxnv_86390.dmp
   EXPDP> Job "SYS"."TSPITR_EXP_kxnv_Ewvl" successfully completed at Mon Jan 27 12:30:59 2014 elapsed 0 00:00:41
Export completed


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

Oracle instance shut down

Importing the data back to the target database according to the remaps specified


Performing import of tables...
   IMPDP> Master table "SYS"."TSPITR_IMP_kxnv_fnzi" successfully loaded/unloaded
   IMPDP> Starting "SYS"."TSPITR_IMP_kxnv_fnzi": 
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
   IMPDP> . . imported "SALESADMIN"."SALES_P2010"                  12.62 KB     364 rows
   IMPDP> Job "SYS"."TSPITR_IMP_kxnv_fnzi" successfully completed at Mon Jan 27 12:31:16 2014 elapsed 0 00:00:09
Import completed


Cleaning up the auxiliary instance

Removing automatic instance
Automatic instance removed
auxiliary instance file /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_temp_9gcr4b9f_.tmp deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_temp_9gcr3xfk_.tmp deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/KXNV_PITR_SALESPDB_CDB1/onlinelog/o1_mf_2_9gcr5jkh_.log deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/KXNV_PITR_SALESPDB_CDB1/onlinelog/o1_mf_1_9gcr5fxm_.log deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/KXNV_PITR_SALESPDB_CDB1/datafile/o1_mf_salespdb_9gcr55b5_.dbf deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_sysaux_9gcr1gbd_.dbf deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_system_9gcr1gbf_.dbf deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_sysaux_9gcqw98n_.dbf deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_undotbs1_9gcqw96p_.dbf deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/CDB1/datafile/o1_mf_system_9gcqw98r_.dbf deleted
auxiliary instance file /u01/app/oracle/oradata/tmp/CDB1/controlfile/o1_mf_9gcqw1mm_.ctl deleted
auxiliary instance file tspitr_kxnv_86390.dmp deleted
Finished recover at 27-JAN-14

RMAN>
   
 

The restore operation leaves the recovered partition in a table named SALES_P2010 by default, leaving the original table and rest of the database as-is.


[oracle@laboms ~]$ sqlplus salesadmin/oracle@SALESPDB

SQL*Plus: Release 12.1.0.1.0 Production on Mon Jan 27 13:15:01 2014

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

Last Successful login time: Mon Jan 27 2014 13:04:07 +08:00

Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics, Real Application Testing
and Unified Auditing options

SQL> select count(*) from salesadmin.sales_p2010;

  COUNT(*)
----------
       364

SQL> select count(*) from salesadmin.sales partition(p2010);

  COUNT(*)
----------
         0

SQL>




No comments:

Post a Comment