Recuperar una Tabla de un Respaldo de RMAN en Oracle Multitenant

Introducción

Siendo un DBA te pueden solicitar recuperar sólo una tabla o un conjunto de tablas de una fecha previa evitando tocar cualquier otro objeto en nuestra base de datos.
Afortunadamente en las últimas versiones de Oracle podemos usar RMAN para directamente recuperar una sóla tabla automatizando así lo que antes hacíamos manualmente, o sea recuperar el tablespace que contenía nuestras tablas junto con los tablespaces del sistema en una instancia separada y entonces hacer export/import con datapump.
Probemos esta funcionalidad y revisemos los pasos que realiza.

Prerrequisitos

Contamos con una instancia Oracle 19c multitenant patodb con una base de datos pluggable taller corriendo en una Virtual Machine Instance en la Google Cloud Platform que ha estado siendo respaldada usando respaldos Incrementales.

Para los pasos previos de configuración de RMAN revisar la nota: Respaldar Bases de Datos Oracle con RMAN hacia un Disco Local.

Recuperar una Tabla con RMAN

En este ejemplo se nos pide recuperar la tabla pato.T3 reemplazando la existente y una copia de la tabla pato.T5 preservando la más actual en la base de datos pluggable taller hacía un día antes a las 9:00 a.m.

Para recuperar las tablas requeridas al punto en el tiempo deseado y renombrar una de las tablas necesitamos usar estas opciones:

  • recover table con la lista de las tablas
  • of pluggable database especificando la PDB a la que pertenecen las tablas
  • remap table para renombrar la tabla dentro del mismo esquema
  • auxiliary destination para el directorio de trabajo de este comando
  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'
  ;

Información de Respaldos

Antes de empezar necesitamos validar que tenemos respaldos full e incrementales disponibles para nuestro tablespace datosde la base de datos pluggable taller en los días previos:

[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>

En la salida encontramos un incremental level 0 full del fin de semana y dos respaldos diarios incremental level 1 previos al punto de recuperarción, entonces podemos proceder.

Preparar el Ambiente

Como la tabla T3 será reemplazada necesitamos eliminarla antes de la recuperación. No hacemos nada con la tabla T5 ya que vamos a conservarla.
Conéctemonos a la base de datos pluggable taller con el dueño del esquema pato para eliminar la tabla:

[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.

Y hay que crear el directorio auxiliar para procesar esta actividad:

[oracle@patoracle ~]$ mkdir -p /tmp/oracle/recover
[oracle@patoracle ~]$

Recuperar las Tablas Reemplazando y Renombrando

Conectémonos a RMAN y enviemos el comando:

[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

Primero el RMAN crea una instancia temporal para recuperar nuestros objectos sin tocar la base de datos original:

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

Entonces restaura los tablespaces del sistema tanto de la CDB raíz como de la PDB desde el respaldo full hacía la nueva instancia:

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

Y recupera los datos del sistema hacia nuestro punto en el tiempo aplicando todos los incrementales y los archive logs necesarios:

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

Despúes de eso el RMAN restaura y recupera el tablespace que contiene a nuestras tablas:

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

Finalmente exporta con data pump nuestras tablas:

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

Y las importa dentro de la base de datos real:

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>

Y eso es todo, tenemos nuestras tablas recuperadas.

Validar las Tablas Recuperadas

Ahora podemos acceder a nuestra base de datos pluggable taller para revisar que las tablas fueron recuperadas:

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>

¡Estas tablas aisladas fueron recuperadas al punto en el tiempo requerido y ningún otro objeto fue tocado!

Conclusión

Fuimos capaces de recuperar sólo algunas tablas en nuestra base de datos Oracle multitenant con las opciones de reemplazar y renombrar usando la funcionalidad de RMAN recover table.
Asímismo validamos que el proceso restaura y recupera el mínimo de tablespaces del sistema junto con el que contiene las tablas recuperadas y usa datapump para exportar los datos/metadatos requeridos y los importa hacia la base de datos original.