Recover One Table from RMAN Backup on Oracle Multitenant
Introduction
As DBA you may be asked to recover just one table or a set of tables to a previous date avoiding to touch any other object in our database.
Fortunately in the last Oracle versions we can use RMAN to directly recover a single table
automating what we previously did manually, that is recover the tablespace containing our table along with the system tablespaces in a different instance and then export/import with datapump.
Let’s test this functionality and review the steps it performs.
Prerequisites
We have an Oracle 19c multitenant instance patodb
with one pluggable database taller
running in a Virtual Machine Instance on Google Cloud Platform that have been backed up using Incremental backups.
For more information on Incremental backups please check RMAN Incremental Backup Strategy for Oracle Database.
RMAN Recover Table
In this example we are requested to recover the table pato.T3
replacing the current one and a copy of the table pato.T5
preserving the latest on the pluggable database taller
to one day before at 9:00 a.m.
To recover the requested tables to the desired point in time and renaming one table we need to use these options:
recover table
with the list of tablesof pluggable database
specifying the PDB which the tables belong toremap table
for renaming the table in the same schemaauxiliary destination
for the working directory of this command
recover table pato.t3, pato.t5 of pluggable database taller
until time "to_date('2020-06-23:09:00:00', 'yyyy-mm-dd:hh24:mi:ss')"
remap table pato.t5:t5_old
auxiliary destination '/tmp/oracle/recover'
;
Backup Information
Before starting we need to validate there are full and incremental backups available for our tablespace datos
from the pluggable database taller
in the previous days:
[oracle@patoracle ~]$ rman target /
RMAN> list backup of tablespace taller:datos ;
List of Backup Sets
===================
BS Key Type LV Size Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ ---------------
26 Incr 0 122.59M DISK 00:00:17 21-JUN-20
BP Key: 26 Status: AVAILABLE Compressed: YES Tag: TAG20200621T010609
Piece Name: /rman/respaldo/PATODB_20200621_0uv391he.bkp
List of Datafiles in backup set 26
File LV Type Ckp SCN Ckp Time Abs Fuz SCN Sparse Name
---- -- ---- ---------- --------- ----------- ------ ----
17 0 Incr 2174545 21-JUN-20 NO /oradata/pdbs/taller/datos.dbf
BS Key Type LV Size Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ ---------------
32 Incr 1 5.04M DISK 00:00:08 22-JUN-20
BP Key: 32 Status: AVAILABLE Compressed: YES Tag: TAG20200622T010138
Piece Name: /rman/respaldo/PATODB_20200622_14v3blkd.bkp
List of Datafiles in backup set 32
File LV Type Ckp SCN Ckp Time Abs Fuz SCN Sparse Name
---- -- ---- ---------- --------- ----------- ------ ----
17 1 Incr 2215131 22-JUN-20 NO /oradata/pdbs/taller/datos.dbf
BS Key Type LV Size Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ ---------------
37 Incr 1 4.66M DISK 00:00:07 23-JUN-20
BP Key: 37 Status: AVAILABLE Compressed: YES Tag: TAG20200623T010218
Piece Name: /rman/respaldo/PATODB_20200623_19v3ea1l.bkp
List of Datafiles in backup set 37
File LV Type Ckp SCN Ckp Time Abs Fuz SCN Sparse Name
---- -- ---- ---------- --------- ----------- ------ ----
17 1 Incr 2266932 23-JUN-20 NO /oradata/pdbs/taller/datos.dbf
BS Key Type LV Size Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ ---------------
44 Incr 1 8.40M DISK 00:00:08 24-JUN-20
BP Key: 44 Status: AVAILABLE Compressed: YES Tag: TAG20200624T010156
Piece Name: /rman/respaldo/PATODB_20200624_1gv3guct.bkp
List of Datafiles in backup set 44
File LV Type Ckp SCN Ckp Time Abs Fuz SCN Sparse Name
---- -- ---- ---------- --------- ----------- ------ ----
17 1 Incr 2284222 24-JUN-20 NO /oradata/pdbs/taller/datos.dbf
RMAN>
In the output we found a weekend full incremental level 0
and two daily incremental level 1
backups previous to our point of recovery, so we can proceed.
Prepare Environment
As the table T3
will be replaced we need to drop it before recovering. We do nothing with the table T5
as we are going to preserve it.
Connect to the pluggable database taller
with the schema owner pato
to drop the table:
[oracle@patoracle ~]$ sqlplus /nolog
SQL*Plus: Release 19.0.0.0.0 - Production on Wed Jun 24 12:13:40 2020
Version 19.3.0.0.0
Copyright (c) 1982, 2019, Oracle. All rights reserved.
SQL> conn pato@taller
Enter password:
Connected.
SQL> drop table t3;
Table dropped.
And create the auxiliary directory needed to process this activity:
[oracle@patoracle ~]$ mkdir -p /tmp/oracle/recover
[oracle@patoracle ~]$
Recover Tables Replacing and Renaming
Connect to RMAN and issue the command:
[oracle@patoracle ~]$ rman target /
Recovery Manager: Release 19.0.0.0.0 - Production on Wed Jun 24 12:30:49 2020
Version 19.3.0.0.0
Copyright (c) 1982, 2019, Oracle and/or its affiliates. All rights reserved.
connected to target database: PATODB (DBID=1820073908)
RMAN> recover table pato.t3, pato.t5 of pluggable database taller
until time "to_date('2020-06-23:09:00:00', 'yyyy-mm-dd:hh24:mi:ss')"
remap table pato.t5:t5_old
auxiliary destination '/tmp/oracle/recover'
;
2> 3> 4> 5>
Starting recover at 24-JUN-20
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=48 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 UNDOTBS
First the RMAN creates a temporary instance to recover our objects without touching the original database:
Creating automatic instance, with SID='uamD'
initialization parameters used for automatic instance:
db_name=PATODB
db_unique_name=uamD_pitr_taller_PATODB
compatible=19.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/opt/oracle
_system_trig_enabled=FALSE
sga_target=1536M
processes=200
db_create_file_dest=/tmp/oracle/recover
log_archive_dest_1='location=/tmp/oracle/recover'
enable_pluggable_database=true
_clone_one_pdb_recovery=true
#No auxiliary parameter file used
starting up automatic instance PATODB
Oracle instance started
Total System Global Area 1610609688 bytes
Fixed Size 9135128 bytes
Variable Size 385875968 bytes
Database Buffers 1207959552 bytes
Redo Buffers 7639040 bytes
Automatic instance created
Then it restores the CDB root system tablespaces and the PDB taller system tablespaces from the full backup into the new instance:
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2020-06-23:09:00:00', 'yyyy-mm-dd: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 24-JUN-20
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=19 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 /rman/controlfile/c-1820073908-20200623-00.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/controlfile/c-1820073908-20200623-00.bkp tag=TAG20200623T010302
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/tmp/oracle/recover/PATODB/controlfile/o1_mf_hh73hfxw_.ctl
Finished restore at 24-JUN-20
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('2020-06-23:09:00:00', 'yyyy-mm-dd: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 13 to new;
set newname for clone datafile 3 to new;
set newname for clone datafile 14 to new;
set newname for clone datafile 15 to new;
set newname for clone tempfile 1 to new;
set newname for clone tempfile 4 to new;
# switch all tempfiles
switch clone tempfile all;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 1, 13, 3, 14, 15;
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 /tmp/oracle/recover/PATODB/datafile/o1_mf_temp_%u_.tmp in control file
renamed tempfile 4 to /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 24-JUN-20
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 /tmp/oracle/recover/PATODB/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00013 to /tmp/oracle/recover/PATODB/datafile/o1_mf_undotbs_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /tmp/oracle/recover/PATODB/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200621_0tv391g1.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200621_0tv391g1.bkp tag=TAG20200621T010609
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:56
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 00014 to /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00015 to /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200621_0uv391he.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200621_0uv391he.bkp tag=TAG20200621T010609
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:25
Finished restore at 24-JUN-20
datafile 1 switched to datafile copy
input datafile copy RECID=9 STAMP=1043929979 file name=/tmp/oracle/recover/PATODB/datafile/o1_mf_system_hh73hrvo_.dbf
datafile 13 switched to datafile copy
input datafile copy RECID=10 STAMP=1043929979 file name=/tmp/oracle/recover/PATODB/datafile/o1_mf_undotbs_hh73hrx2_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=11 STAMP=1043929979 file name=/tmp/oracle/recover/PATODB/datafile/o1_mf_sysaux_hh73hrwk_.dbf
datafile 14 switched to datafile copy
input datafile copy RECID=12 STAMP=1043929979 file name=/tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_system_hh73kl2j_.dbf
datafile 15 switched to datafile copy
input datafile copy RECID=13 STAMP=1043929979 file name=/tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_sysaux_hh73kl1t_.dbf
And it recovers the system data to our point in time applying all the incremental and archive logs needed:
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2020-06-23:09:00:00', 'yyyy-mm-dd:hh24:mi:ss')";
# online the datafiles restored or switched
sql clone "alter database datafile 1 online";
sql clone "alter database datafile 13 online";
sql clone "alter database datafile 3 online";
sql clone 'TALLER' "alter database datafile
14 online";
sql clone 'TALLER' "alter database datafile
15 online";
# recover and open database read only
recover clone database tablespace "SYSTEM", "UNDOTBS", "SYSAUX", "TALLER":"SYSTEM", "TALLER":"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 13 online
sql statement: alter database datafile 3 online
sql statement: alter database datafile 14 online
sql statement: alter database datafile 15 online
Starting recover at 24-JUN-20
using channel ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: starting incremental datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
destination for restore of datafile 00001: /tmp/oracle/recover/PATODB/datafile/o1_mf_system_hh73hrvo_.dbf
destination for restore of datafile 00013: /tmp/oracle/recover/PATODB/datafile/o1_mf_undotbs_hh73hrx2_.dbf
destination for restore of datafile 00003: /tmp/oracle/recover/PATODB/datafile/o1_mf_sysaux_hh73hrwk_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200622_13v3bljj.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200622_13v3bljj.bkp tag=TAG20200622T010138
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 incremental datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
destination for restore of datafile 00014: /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_system_hh73kl2j_.dbf
destination for restore of datafile 00015: /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_sysaux_hh73kl1t_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200622_14v3blkd.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200622_14v3blkd.bkp tag=TAG20200622T010138
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 incremental datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
destination for restore of datafile 00001: /tmp/oracle/recover/PATODB/datafile/o1_mf_system_hh73hrvo_.dbf
destination for restore of datafile 00013: /tmp/oracle/recover/PATODB/datafile/o1_mf_undotbs_hh73hrx2_.dbf
destination for restore of datafile 00003: /tmp/oracle/recover/PATODB/datafile/o1_mf_sysaux_hh73hrwk_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200623_18v3ea0r.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200623_18v3ea0r.bkp tag=TAG20200623T010218
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:15
channel ORA_AUX_DISK_1: starting incremental datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
destination for restore of datafile 00014: /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_system_hh73kl2j_.dbf
destination for restore of datafile 00015: /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_sysaux_hh73kl1t_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200623_19v3ea1l.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200623_19v3ea1l.bkp tag=TAG20200623T010218
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
starting media recovery
archived log for thread 1 with sequence 39 is already on disk as file /oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_39_hh36rngd_.arc
archived log for thread 1 with sequence 40 is already on disk as file /oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_40_hh42bo25_.arc
archived log for thread 1 with sequence 41 is already on disk as file /oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_41_hh42bsby_.arc
archived log for thread 1 with sequence 42 is already on disk as file /oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_42_hh4vcdgm_.arc
archived log file name=/oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_39_hh36rngd_.arc thread=1 sequence=39
archived log file name=/oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_40_hh42bo25_.arc thread=1 sequence=40
archived log file name=/oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_41_hh42bsby_.arc thread=1 sequence=41
archived log file name=/oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_42_hh4vcdgm_.arc thread=1 sequence=42
media recovery complete, elapsed time: 00:00:07
Finished recover at 24-JUN-20
sql statement: alter database open read only
contents of Memory Script:
{
sql clone 'alter pluggable database TALLER open read only';
}
executing Memory Script
sql statement: alter pluggable database TALLER 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 =
''/tmp/oracle/recover/PATODB/controlfile/o1_mf_hh73hfxw_.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 1610609688 bytes
Fixed Size 9135128 bytes
Variable Size 385875968 bytes
Database Buffers 1207959552 bytes
Redo Buffers 7639040 bytes
sql statement: alter system set control_files = ''/tmp/oracle/recover/PATODB/controlfile/o1_mf_hh73hfxw_.ctl'' comment= ''RMAN set'' scope=spfile
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 1610609688 bytes
Fixed Size 9135128 bytes
Variable Size 385875968 bytes
Database Buffers 1207959552 bytes
Redo Buffers 7639040 bytes
sql statement: alter database mount clone database
After that RMAN restores and recovers the tablespace containing our tables:
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2020-06-23:09:00:00', 'yyyy-mm-dd:hh24:mi:ss')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile 17 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 17;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
executing command: SET NEWNAME
Starting restore at 24-JUN-20
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=182 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 00017 to /tmp/oracle/recover/UAMD_PITR_TALLER_PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_datos_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200621_0uv391he.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200621_0uv391he.bkp tag=TAG20200621T010609
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:07
Finished restore at 24-JUN-20
datafile 17 switched to datafile copy
input datafile copy RECID=25 STAMP=1043930131 file name=/tmp/oracle/recover/UAMD_PITR_TALLER_PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_datos_hh73pvnj_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2020-06-23:09:00:00', 'yyyy-mm-dd:hh24:mi:ss')";
# online the datafiles restored or switched
sql clone 'TALLER' "alter database datafile
17 online";
# recover and open resetlogs
recover clone database tablespace "TALLER":"DATOS", "SYSTEM", "UNDOTBS", "SYSAUX", "TALLER":"SYSTEM", "TALLER":"SYSAUX" delete archivelog;
alter clone database open resetlogs;
}
executing Memory Script
executing command: SET until clause
sql statement: alter database datafile 17 online
Starting recover at 24-JUN-20
using channel ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: starting incremental datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
destination for restore of datafile 00017: /tmp/oracle/recover/UAMD_PITR_TALLER_PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_datos_hh73pvnj_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200622_14v3blkd.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200622_14v3blkd.bkp tag=TAG20200622T010138
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 incremental datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
destination for restore of datafile 00017: /tmp/oracle/recover/UAMD_PITR_TALLER_PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_datos_hh73pvnj_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /rman/respaldo/PATODB_20200623_19v3ea1l.bkp
channel ORA_AUX_DISK_1: piece handle=/rman/respaldo/PATODB_20200623_19v3ea1l.bkp tag=TAG20200623T010218
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
starting media recovery
archived log for thread 1 with sequence 39 is already on disk as file /oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_39_hh36rngd_.arc
archived log for thread 1 with sequence 40 is already on disk as file /oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_40_hh42bo25_.arc
archived log for thread 1 with sequence 41 is already on disk as file /oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_41_hh42bsby_.arc
archived log for thread 1 with sequence 42 is already on disk as file /oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_42_hh4vcdgm_.arc
archived log file name=/oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_39_hh36rngd_.arc thread=1 sequence=39
archived log file name=/oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_40_hh42bo25_.arc thread=1 sequence=40
archived log file name=/oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_41_hh42bsby_.arc thread=1 sequence=41
archived log file name=/oradata/recovery/PATODB/archivelog/2020_06_23/o1_mf_1_42_hh4vcdgm_.arc thread=1 sequence=42
media recovery complete, elapsed time: 00:00:04
Finished recover at 24-JUN-20
database opened
contents of Memory Script:
{
sql clone 'alter pluggable database TALLER open';
}
executing Memory Script
sql statement: alter pluggable database TALLER open
Finally it exports with data pump our tables:
contents of Memory Script:
{
# create directory for datapump import
sql 'TALLER' "create or replace directory
TSPITR_DIROBJ_DPDIR as ''
/tmp/oracle/recover''";
# create directory for datapump export
sql clone 'TALLER' "create or replace directory
TSPITR_DIROBJ_DPDIR as ''
/tmp/oracle/recover''";
}
executing Memory Script
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/tmp/oracle/recover''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/tmp/oracle/recover''
Performing export of tables...
EXPDP> Starting "SYS"."TSPITR_EXP_uamD_unzd":
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
EXPDP> Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
EXPDP> Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
EXPDP> . . exported "PATO"."T3" 4.152 MB 150001 rows
EXPDP> . . exported "PATO"."T5" 4.152 MB 150001 rows
EXPDP> Master table "SYS"."TSPITR_EXP_uamD_unzd" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_uamD_unzd is:
EXPDP> /tmp/oracle/recover/tspitr_uamD_87268.dmp
EXPDP> Job "SYS"."TSPITR_EXP_uamD_unzd" successfully completed at Wed Jun 24 12:38:04 2020 elapsed 0 00:00:51
Export completed
And import them into the real database:
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_uamD_sAEv" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_uamD_sAEv":
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
IMPDP> . . imported "PATO"."T3" 4.152 MB 150001 rows
IMPDP> . . imported "PATO"."T5_OLD" 4.152 MB 150001 rows
IMPDP> Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
IMPDP> Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
IMPDP> Job "SYS"."TSPITR_IMP_uamD_sAEv" successfully completed at Wed Jun 24 12:39:20 2020 elapsed 0 00:00:51
Import completed
Removing automatic instance
Automatic instance removed
auxiliary instance file /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_temp_hh73n568_.tmp deleted
auxiliary instance file /tmp/oracle/recover/PATODB/datafile/o1_mf_temp_hh73mpz0_.tmp deleted
auxiliary instance file /tmp/oracle/recover/UAMD_PITR_TALLER_PATODB/onlinelog/o1_mf_3_hh73qlrl_.log deleted
auxiliary instance file /tmp/oracle/recover/UAMD_PITR_TALLER_PATODB/onlinelog/o1_mf_2_hh73ql3d_.log deleted
auxiliary instance file /tmp/oracle/recover/UAMD_PITR_TALLER_PATODB/onlinelog/o1_mf_1_hh73ql1p_.log deleted
auxiliary instance file /tmp/oracle/recover/UAMD_PITR_TALLER_PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_datos_hh73pvnj_.dbf deleted
auxiliary instance file /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_sysaux_hh73kl1t_.dbf deleted
auxiliary instance file /tmp/oracle/recover/PATODB/A892DB8B7C6905DDE0533700800A80CD/datafile/o1_mf_system_hh73kl2j_.dbf deleted
auxiliary instance file /tmp/oracle/recover/PATODB/datafile/o1_mf_sysaux_hh73hrwk_.dbf deleted
auxiliary instance file /tmp/oracle/recover/PATODB/datafile/o1_mf_undotbs_hh73hrx2_.dbf deleted
auxiliary instance file /tmp/oracle/recover/PATODB/datafile/o1_mf_system_hh73hrvo_.dbf deleted
auxiliary instance file /tmp/oracle/recover/PATODB/controlfile/o1_mf_hh73hfxw_.ctl deleted
auxiliary instance file tspitr_uamD_87268.dmp deleted
Finished recover at 24-JUN-20
RMAN>
And that’s it, we have our tables recovered.
Validate Recovered Tables
Now we can access our pluggable database taller
to check the tables were recovered:
SQL> alter session set container = taller;
Session altered.
SQL> select max(d3) from pato.t3;
MAX(D3)
---------------------------------------------------------------------------
23-JUN-20 08.53.31.623657 AM
SQL> select max(d5) from pato.t5;
MAX(D5)
---------------------------------------------------------------------------
24-JUN-20 12.12.13.042780 PM
SQL> select max(d5) from pato.t5_old;
MAX(D5)
---------------------------------------------------------------------------
23-JUN-20 08.53.31.623694 AM
SQL>
Those single tables were recovered to the point in time requested and no other object were touched!
Conclusion
We were able to recover a single table in our Oracle multitenant database with replacing and renaming options using RMAN recover table functionality.
Also we validated the process is restoring and recovering the minimum system tablespaces along the one containing the recovered tables,
and using datapump to export the requested data/metadata and import it into the original database.