Skip to content
Home » Oracle Database » Backup and Recovery » RMAN » How RMAN Restore Table

How RMAN Restore Table

Recover Table by RMAN

We have talked about how to restore a table from the recyclebin earlier. By using the feature of recyclebin, we can undo our dropping, just like nothing happened.

From 12c, we have one more option, that is, we can restore the table by RMAN. Precisely speaking, the course of action to restore a table in RMAN is actually using RECOVER statement in RMAN.

In this post, we'll talk about how to restore dropped tables from RMAN backups.

Drop Table Purge

First of all, we dropped and purged 2 tables on purpose.

SQL> show user
USER is "HR"
SQL> drop table t1 purge;

Table dropped.

SQL> drop table t2 purge;

Table dropped.

Make Auxiliary Destination

We should make sure that the directory used by the auxiliary instance does exist, if not, please make one. Here we create a directory in /tmp.

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

The directory is used by another instance temporarily, so it doesn't matter where it is.

Recover Table

To make it display precise date time during the execution, we should set NLS_DATE_FORMAT in RMAN.

RMAN> alter session set nls_date_format = 'YYYY-MM-DD HH24:MI:SS';

Statement processed

Let's see the final recover statement.

RMAN> recover table hr.t1, hr.t2 of pluggable database orclpdb until time "TO_DATE('2023-03-21 21:13:07', 'YYYY-MM-DD HH24:MI:SS')" auxiliary destination '/tmp/oracle/recover';

To compose a fulfilling RECOVER statement, we need to provide the following 4 information.

  • Qualified Table Name(s)
  • A qualified table name should be prefixed the schema name in order to identify the target.

    1. Single Table
    2. Single qualified table name should look like this:

      schema_name1.table_name1
    3. Multiple Tables
    4. Multiple tables can be specified and delimited by commas in the statement.

      schema_name1.table_name1, schema_name2.table_name2
  • Pluggable database (PDB)
  • If we're in a multitenant database, we need to specify which PDB should be used. For 19c and later releases, PDB is a very common practice, you'd better getting used to it.

  • Point in time
  • Since restoring table in RMAN is actually a recovering action which involves a point in time, so we have to provide it. To specify a point in time, we have 2 ways to do it.

    1. Relative Time
    2. In this case, we specified 30 minutes ago for convenience.

      SYSDATE-30/1440

      Such time expression is pretty easy to use.

    3. Absolute Time
    4. A point in time can be also specified by TO_DATE function.

      TO_DATE('2023-03-21 21:13:07', 'YYYY-MM-DD HH24:MI:SS')

      You need to pay more attention to the datetime format.

  • Auxiliary destination
  • This is a temporary place where it stores restored data files.

The execution result is as below.

Starting recover at 2023-03-21 23:21:28
using channel ORA_DISK_1
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 ORCLPDB:SYSTEM
Tablespace UNDOTBS1
Tablespace ORCLPDB:UNDOTBS1

Creating automatic instance, with SID='szye'

initialization parameters used for automatic instance:
db_name=ORCLCDB
db_unique_name=szye_pitr_orclpdb_ORCLCDB
compatible=19.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/u01/app/oracle
_system_trig_enabled=FALSE
sga_target=1088M
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 ORCLCDB

Oracle instance started

Total System Global Area    1140850392 bytes

Fixed Size                     9133784 bytes
Variable Size                301989888 bytes
Database Buffers             822083584 bytes
Redo Buffers                   7643136 bytes
Automatic instance created

contents of Memory Script:
{
# set requested point in time
set until  time "TO_DATE('2023-03-21 21:13:07', '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 2023-03-21 23:21:45
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=244 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/ORCLCDB/autobackup/2023_03_21/o1_mf_s_1132089121_l1noh1ho_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/ORCLCDB/autobackup/2023_03_21/o1_mf_s_1132089121_l1noh1ho_.bkp tag=TAG20230321T211201
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/ORCLCDB/controlfile/o1_mf_l1nx2bnj_.ctl
Finished restore at 2023-03-21 23:21:47

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('2023-03-21 21:13:07', '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  9 to new;
set newname for clone datafile  4 to new;
set newname for clone datafile  11 to new;
set newname for clone datafile  3 to new;
set newname for clone datafile  10 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, 9, 4, 11, 3, 10;

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

executing command: SET NEWNAME

renamed tempfile 1 to /tmp/oracle/recover/ORCLCDB/datafile/o1_mf_temp_%u_.tmp in control file
renamed tempfile 3 to /tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_temp_%u_.tmp in control file

Starting restore at 2023-03-21 23:21:52
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/ORCLCDB/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /tmp/oracle/recover/ORCLCDB/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /tmp/oracle/recover/ORCLCDB/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/ORCLCDB/backupset/2023_03_21/o1_mf_nnndf_TAG20230321T211102_l1nof7gn_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/ORCLCDB/backupset/2023_03_21/o1_mf_nnndf_TAG20230321T211102_l1nof7gn_.bkp tag=TAG20230321T211102
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:25
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 /tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00011 to /tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00010 to /tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/ORCLCDB/AA736F65D66215CCE053992AA8C08959/backupset/2023_03_21/o1_mf_nnndf_TAG20230321T211102_l1nog0p2_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/ORCLCDB/AA736F65D66215CCE053992AA8C08959/backupset/2023_03_21/o1_mf_nnndf_TAG20230321T211102_l1nog0p2_.bkp tag=TAG20230321T211102
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:15
Finished restore at 2023-03-21 23:22:34

datafile 1 switched to datafile copy
input datafile copy RECID=10 STAMP=1132096954 file name=/tmp/oracle/recover/ORCLCDB/datafile/o1_mf_system_l1nx2l47_.dbf
datafile 9 switched to datafile copy
input datafile copy RECID=11 STAMP=1132096954 file name=/tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_system_l1nx3cgf_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=12 STAMP=1132096954 file name=/tmp/oracle/recover/ORCLCDB/datafile/o1_mf_undotbs1_l1nx2l4g_.dbf
datafile 11 switched to datafile copy
input datafile copy RECID=13 STAMP=1132096954 file name=/tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_undotbs1_l1nx3cgg_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=14 STAMP=1132096954 file name=/tmp/oracle/recover/ORCLCDB/datafile/o1_mf_sysaux_l1nx2l4c_.dbf
datafile 10 switched to datafile copy
input datafile copy RECID=15 STAMP=1132096954 file name=/tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_sysaux_l1nx3cgc_.dbf

contents of Memory Script:
{
# set requested point in time
set until  time "TO_DATE('2023-03-21 21:13:07', 'YYYY-MM-DD HH24:MI:SS')";
# online the datafiles restored or switched
sql clone "alter database datafile  1 online";
sql clone 'ORCLPDB' "alter database datafile
 9 online";
sql clone "alter database datafile  4 online";
sql clone 'ORCLPDB' "alter database datafile
 11 online";
sql clone "alter database datafile  3 online";
sql clone 'ORCLPDB' "alter database datafile
 10 online";
# recover and open database read only
recover clone database tablespace  "SYSTEM", "ORCLPDB":"SYSTEM", "UNDOTBS1", "ORCLPDB":"UNDOTBS1", "SYSAUX", "ORCLPDB":"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  9 online

sql statement: alter database datafile  4 online

sql statement: alter database datafile  11 online

sql statement: alter database datafile  3 online

sql statement: alter database datafile  10 online

Starting recover at 2023-03-21 23:22:35
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 5 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCLCDB/archivelog/2023_03_21/o1_mf_1_5_l1nogzhy_.arc
archived log for thread 1 with sequence 6 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCLCDB/archivelog/2023_03_21/o1_mf_1_6_l1nozbhf_.arc
archived log file name=/u01/app/oracle/fast_recovery_area/ORCLCDB/archivelog/2023_03_21/o1_mf_1_5_l1nogzhy_.arc thread=1 sequence=5
archived log file name=/u01/app/oracle/fast_recovery_area/ORCLCDB/archivelog/2023_03_21/o1_mf_1_6_l1nozbhf_.arc thread=1 sequence=6
media recovery complete, elapsed time: 00:00:00
Finished recover at 2023-03-21 23:22:38

sql statement: alter database open read only

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

sql statement: alter pluggable database  ORCLPDB 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/ORCLCDB/controlfile/o1_mf_l1nx2bnj_.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    1140850392 bytes

Fixed Size                     9133784 bytes
Variable Size                301989888 bytes
Database Buffers             822083584 bytes
Redo Buffers                   7643136 bytes

sql statement: alter system set  control_files =   ''/tmp/oracle/recover/ORCLCDB/controlfile/o1_mf_l1nx2bnj_.ctl'' comment= ''RMAN set'' scope=spfile

Oracle instance shut down

connected to auxiliary database (not started)
Oracle instance started

Total System Global Area    1140850392 bytes

Fixed Size                     9133784 bytes
Variable Size                301989888 bytes
Database Buffers             822083584 bytes
Redo Buffers                   7643136 bytes

sql statement: alter database mount clone database

contents of Memory Script:
{
# set requested point in time
set until  time "TO_DATE('2023-03-21 21:13:07', 'YYYY-MM-DD HH24:MI:SS')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile  13 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile  13;

switch clone datafile all;
}
executing Memory Script

executing command: SET until clause

executing command: SET NEWNAME

Starting restore at 2023-03-21 23:23:57
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=91 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 00013 to /tmp/oracle/recover/SZYE_PITR_ORCLPDB_ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_example_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/ORCLCDB/AA736F65D66215CCE053992AA8C08959/backupset/2023_03_21/o1_mf_nnndf_TAG20230321T211102_l1nog0p2_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/ORCLCDB/AA736F65D66215CCE053992AA8C08959/backupset/2023_03_21/o1_mf_nnndf_TAG20230321T211102_l1nog0p2_.bkp tag=TAG20230321T211102
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
Finished restore at 2023-03-21 23:24:01

datafile 13 switched to datafile copy
input datafile copy RECID=17 STAMP=1132097041 file name=/tmp/oracle/recover/SZYE_PITR_ORCLPDB_ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_example_l1nx6gdt_.dbf

contents of Memory Script:
{
# set requested point in time
set until  time "TO_DATE('2023-03-21 21:13:07', 'YYYY-MM-DD HH24:MI:SS')";
# online the datafiles restored or switched
sql clone 'ORCLPDB' "alter database datafile
 13 online";
# recover and open resetlogs
recover clone database tablespace  "ORCLPDB":"EXAMPLE", "SYSTEM", "ORCLPDB":"SYSTEM", "UNDOTBS1", "ORCLPDB":"UNDOTBS1", "SYSAUX", "ORCLPDB":"SYSAUX" delete archivelog;
alter clone database open resetlogs;
}
executing Memory Script

executing command: SET until clause

sql statement: alter database datafile  13 online

Starting recover at 2023-03-21 23:24:01
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 5 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCLCDB/archivelog/2023_03_21/o1_mf_1_5_l1nogzhy_.arc
archived log for thread 1 with sequence 6 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCLCDB/archivelog/2023_03_21/o1_mf_1_6_l1nozbhf_.arc
archived log file name=/u01/app/oracle/fast_recovery_area/ORCLCDB/archivelog/2023_03_21/o1_mf_1_5_l1nogzhy_.arc thread=1 sequence=5
archived log file name=/u01/app/oracle/fast_recovery_area/ORCLCDB/archivelog/2023_03_21/o1_mf_1_6_l1nozbhf_.arc thread=1 sequence=6
media recovery complete, elapsed time: 00:00:01
Finished recover at 2023-03-21 23:24:04

database opened

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

sql statement: alter pluggable database  ORCLPDB open

contents of Memory Script:
{
# create directory for datapump import
sql 'ORCLPDB' "create or replace directory
TSPITR_DIROBJ_DPDIR as ''
/tmp/oracle/recover''";
# create directory for datapump export
sql clone 'ORCLPDB' "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_szye_yhcw":
   EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
   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> . . exported "HR"."T1"                                   17.08 KB     107 rows
   EXPDP> . . exported "HR"."T2"                                   17.08 KB     107 rows
   EXPDP> Master table "SYS"."TSPITR_EXP_szye_yhcw" successfully loaded/unloaded
   EXPDP> ******************************************************************************
   EXPDP> Dump file set for SYS.TSPITR_EXP_szye_yhcw is:
   EXPDP>   /tmp/oracle/recover/tspitr_szye_29116.dmp
   EXPDP> Job "SYS"."TSPITR_EXP_szye_yhcw" successfully completed at Tue Mar 21 23:25:41 2023 elapsed 0 00:00:47
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_szye_gBrA" successfully loaded/unloaded
   IMPDP> Starting "SYS"."TSPITR_IMP_szye_gBrA":
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
   IMPDP> . . imported "HR"."T1"                                   17.08 KB     107 rows
   IMPDP> . . imported "HR"."T2"                                   17.08 KB     107 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_szye_gBrA" successfully completed at Tue Mar 21 23:26:47 2023 elapsed 0 00:00:54
Import completed


Removing automatic instance
Automatic instance removed
auxiliary instance file /tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_temp_l1nx42b9_.tmp deleted
auxiliary instance file /tmp/oracle/recover/ORCLCDB/datafile/o1_mf_temp_l1nx3z8b_.tmp deleted
auxiliary instance file /tmp/oracle/recover/SZYE_PITR_ORCLPDB_ORCLCDB/onlinelog/o1_mf_3_l1nx6nk1_.log deleted
auxiliary instance file /tmp/oracle/recover/SZYE_PITR_ORCLPDB_ORCLCDB/onlinelog/o1_mf_2_l1nx6n96_.log deleted
auxiliary instance file /tmp/oracle/recover/SZYE_PITR_ORCLPDB_ORCLCDB/onlinelog/o1_mf_1_l1nx6n87_.log deleted
auxiliary instance file /tmp/oracle/recover/SZYE_PITR_ORCLPDB_ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_example_l1nx6gdt_.dbf deleted
auxiliary instance file /tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_sysaux_l1nx3cgc_.dbf deleted
auxiliary instance file /tmp/oracle/recover/ORCLCDB/datafile/o1_mf_sysaux_l1nx2l4c_.dbf deleted
auxiliary instance file /tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_undotbs1_l1nx3cgg_.dbf deleted
auxiliary instance file /tmp/oracle/recover/ORCLCDB/datafile/o1_mf_undotbs1_l1nx2l4g_.dbf deleted
auxiliary instance file /tmp/oracle/recover/ORCLCDB/AA736F65D66215CCE053992AA8C08959/datafile/o1_mf_system_l1nx3cgf_.dbf deleted
auxiliary instance file /tmp/oracle/recover/ORCLCDB/datafile/o1_mf_system_l1nx2l47_.dbf deleted
auxiliary instance file /tmp/oracle/recover/ORCLCDB/controlfile/o1_mf_l1nx2bnj_.ctl deleted
auxiliary instance file tspitr_szye_29116.dmp deleted
Finished recover at 2023-03-21 23:26:51

RMAN>

Check Result

Let's query the same table in the same session of the user.

SQL> select count(*) cnt from t1;

       CNT
----------
       107

SQL> select count(*) cnt from t2;

       CNT
----------
       107

Marvelous! But it seems to be a very costly to save tables in such a lengthy way, especially when the database is big.

I would say, if there's any chance to restore tables form the recyclebin, then don't restore it by RMAN.

Leave a Reply

Your email address will not be published. Required fields are marked *