Category - RMAN

Recovering Tables and Table Partitions

Recovering Tables and Table Partitions

In this article we will practice to recover Table and Table partitions.

The RMAN RECOVER command enables you to recover tables and table partitions from RMAN backups.

Purpose of Recovering Tables and Table Partitions from RMAN Backups

RMAN enables you to recover one or more tables or table partitions to a specified point in time without affecting the remaining database objects.

Recovering tables and table partitions from RMAN backups is useful in the following scenarios:
=> You need to recover a very small number of tables to a particular point in time. In this situation,
      TSPITR is not the most effective solution because it moves all the objects in the tablespace to a specified point in time.
=> You need to recover tables that have been logically corrupted or have been dropped and purged.
=> Flashback Table is not possible because the desired point-in-time is older than available undo.
=> You want to recover data that is lost after a DDL operation modified the structure of tables,
        Using Flashback Table is not possible because a DDL was run on the tables between the desired point in time and the current time,
         Flashback Table cannot rewind tables through structural changes such as a truncate table operation.

RMAN Backups Required to Recover Tables and Table Partitions

To recover tables or table partitions, you need a full backup of undo, SYSTEM, SYSAUX, and the tablespace that contains the tables or table partitions.

To recover a table, all partitions that contain the dependent objects of the table must be included in the recovery set.
If the indexes or partitions for a table in tablespace tbs1 are contained in tablespace tbs2, 
then you can recover the table only if tablepsace tbs2 is also included in the recovery set.

About the Location of Auxiliary Database Files During RMAN Table Recovery

RMAN creates an auxiliary database that it uses during the process of recovering the specified tables or table partitions.

On the target host that is used to store data files for the auxiliary database, use one of the following techniques:

    AUXILIARY DESTINATION clause in the RECOVER command

    SET NEWNAME command

    Use a RUN block containing the RECOVER command and required SET NEWNAME commands that rename the data files.

About the Data Pump Export Dump File Used During RMAN Table Recovery

After recovering tables or table partitions to the specified point in time on the auxiliary database, 
RMAN creates a Data Pump export dump file that contains the recovered objects.
You can either specify a name and location for this dump file or allow RMAN to use a default name and location.

Use the DATAPUMP DESTINATION clause of the RECOVER command to specify the location in which the Data Pump export dump file is created.

Use the DUMP FILE clause of the RECOVER command to specify the name of the Data Pump export dump file.

About Importing Recovered Tables and Table Partitions into the Target Database

By default, RMAN imports the recovered tables or table partitions, which are stored in the export dump file, into the target database.
However, you can choose not to import the recovered tables or table partitions by using the NOTABLEIMPORT clause of the RESTORE command.

When NOTABLEIMPORT is used, RMAN recovers them to the specified point and then creates the export dump file. However, this dump file is not imported into the target database.
You must manually import this dump file into your target database, when required, by using the Data Pump Import utility.

Rename the Recovered Tables and Table Partitions

Use the REMAP TABLE clause to rename recovered tables or table partitions in the target database.

If the target database contains a table with the same name as that of the recovered table, 
RMAN displays an error message indicating that you must rename the recovered table by using the REMAP TABLE clause.

When you recover table partitions, each table partition is recovered into a separate table.
Use the REMAP TABLE clause to specify the table names into which each recovered partition must be imported.
If you do not explicitly specify table names, RMAN generates table names by concatenating the recovered table name and partition name.
The generated names are in the format tablename_partitionname. If a table with this name exists in the target database, then RMAN appends _1 to the name.
If this name too exists, then RMAN appends _2 to the name and so on.

About Recovering Tables and Partitions Into a New Schema


Recovering tables or table partitions into a different schema enables you to avoid name conflicts that may be caused by constraint, 
index, or trigger names that already existing in the source schema.


While recovering objects into a different schema, you can either retain their original names or rename them.|
You can rename tables and remap the schema in a single recovery operation.
For example, you can recover the HR.EMPLOYEES table either into the NEW_HR.EMPLOYEES table, the HR.NEW_EMPLOYEES table, or the NEW_HR.NEW_EMPLOYEES table.
The REMAP TABLE clause enables you to rename objects and recover them into a different schema.

During table recovery, use the REMAP TABLE clause of the RECOVER TABLE command to map the source schema to a new schema.
The new schema must exist in the target database before you perform the recovery.


DEMONTRATIONS
=============

A=>Recovering Tables to a Specified Point in Time

We will be recovering DROPPED table from PITR. Below approach will be followed.

Step 1=> Create sample table as below

[oracle@racsetn1 DB_BKP]$ cat create_tbs.sql
create tablespace RMAN_TSPITR datafile '+DATA' size 500m;
create table TAB_TSPITR (data date) tablespace RMAN_TSPITR;
insert into TAB_TSPITR values (systimestamp);
insert into TAB_TSPITR values (systimestamp);
insert into TAB_TSPITR values (systimestamp);
insert into TAB_TSPITR values (systimestamp);
commit;
alter session set NLS_dATE_FORMAT='DD-MON-YYYY HH24:MI:SS';
select * from TAB_TSPITR;
[oracle@racsetn1 DB_BKP]$

SQL> alter session set NLS_dATE_FORMAT='DD-MON-YYYY HH24:MI:SS';

Session altered.

SQL> select * from TAB_TSPITR;

DATA
--------------------
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45

12 rows selected.

SQL>

Step2=> Take backup of database

[oracle@racsetn1 DB_BKP]$ rman target /

connected to target database: NTNT (DBID=3125572952)
RUN
{
sql 'ALTER SYSTEM ARCHIVE LOG CURRENT';
allocate channel CH01 type disk;
allocate channel CH02 type disk;
allocate channel CH03 type disk;
allocate channel CH04 type disk;
BACKUP as compressed backupset database FORMAT '/ora_home/bkp/DB_BKP/DB_FULL_backup_%U' plus archivelog  FORMAT '/ora_home/bkp/DB_BKP/%d_%T_%s_%p_ARCHIVE' ;
backup format '/ora_home/bkp/DB_BKP/BKP_cf_%d_%U_%t' current controlfile tag='backup_controlfile';
sql 'ALTER SYSTEM ARCHIVE LOG CURRENT';
sql 'ALTER SYSTEM ARCHIVE LOG CURRENT';
release channel CH01;
release channel CH02;
release channel CH03;
release channel CH04;
}

Step 3=> Drop table

[oracle@racsetn1 AUX_DEST]$ sqlplus ABHI_TEST/Oracle_4U

SQL> drop table TAB_TSPITR;

Table dropped.

Step 4=> Recover table using recover command as below.

[oracle@racsetn1 AUX_DEST]$ rman target /

connected to target database: NTNT (DBID=3125572952)

RMAN> run
{
recover table ABHI_TEST.TAB_TSPITR
until time "to_date('21-JAN-2023 20:33:00','DD-MON-YYYY HH24:MI:SS')"
AUXILIARY DESTINATION '/ora_home/bkp/AUX_DEST';
}

Starting recover at 21-JAN-23
using target database control file instead of recovery catalog
current log archived
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=404 instance=NTNT1 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
Tablespace UNDOTBS2

Creating automatic instance, with SID='Cssv'

initialization parameters used for automatic instance:
db_name=NTNT
db_unique_name=Cssv_pitr_NTNT
compatible=19.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/ora_home/app/oracle
_system_trig_enabled=FALSE
sga_target=2624M
processes=200
db_create_file_dest=/ora_home/bkp/AUX_DEST
log_archive_dest_1='location=/ora_home/bkp/AUX_DEST'
#No auxiliary parameter file used

starting up automatic instance NTNT

Oracle instance started

Total System Global Area    2751463160 bytes

Fixed Size                     8900344 bytes
Variable Size                570425344 bytes
Database Buffers            2164260864 bytes
Redo Buffers                   7876608 bytes
Automatic instance created

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('21-JAN-2023 20:33:00','DD-MON-YYYY 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 21-JAN-23
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=257 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 /ora_home/bkp/DB_BKP/BKP_cf_NTNT_331ih279_1_1_1126729961
channel ORA_AUX_DISK_1: piece handle=/ora_home/bkp/DB_BKP/BKP_cf_NTNT_331ih279_1_1_1126729961 tag=BACKUP_CONTROLFILE
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/ora_home/bkp/AUX_DEST/NTNT/controlfile/o1_mf_kwqzvl0s_.ctl
Finished restore at 21-JAN-23

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('21-JAN-2023 20:33:00','DD-MON-YYYY 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  4 to new;
set newname for clone datafile  5 to new;
set newname for clone datafile  3 to new;
set newname for clone tempfile  1 to new;
# switch all tempfiles
switch clone tempfile all;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile  1, 4, 5, 3;
 
switch clone datafile all;
}
executing Memory Script

executing command: SET until clause

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

renamed tempfile 1 to /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_temp_%u_.tmp in control file

Starting restore at 21-JAN-23
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 00005 to /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_undotbs2_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /ora_home/bkp/DB_BKP/DB_FULL_backup_2u1ih26d_1_1
channel ORA_AUX_DISK_1: piece handle=/ora_home/bkp/DB_BKP/DB_FULL_backup_2u1ih26d_1_1 tag=TAG20230121T203212
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
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 00003 to /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /ora_home/bkp/DB_BKP/DB_FULL_backup_2t1ih26c_1_1
channel ORA_AUX_DISK_1: piece handle=/ora_home/bkp/DB_BKP/DB_FULL_backup_2t1ih26c_1_1 tag=TAG20230121T203212
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 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 /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /ora_home/bkp/DB_BKP/DB_FULL_backup_2s1ih26c_1_1
channel ORA_AUX_DISK_1: piece handle=/ora_home/bkp/DB_BKP/DB_FULL_backup_2s1ih26c_1_1 tag=TAG20230121T203212
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:25
Finished restore at 21-JAN-23

datafile 1 switched to datafile copy
input datafile copy RECID=11 STAMP=1126730243 file name=/ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_system_kwqzwl88_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=12 STAMP=1126730243 file name=/ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_undotbs1_kwqzwl8q_.dbf
datafile 5 switched to datafile copy
input datafile copy RECID=13 STAMP=1126730243 file name=/ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_undotbs2_kwqzw22n_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=14 STAMP=1126730243 file name=/ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_sysaux_kwqzw33z_.dbf

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('21-JAN-2023 20:33:00','DD-MON-YYYY HH24:MI:SS')";
# online the datafiles restored or switched
sql clone "alter database datafile  1 online";
sql clone "alter database datafile  4 online";
sql clone "alter database datafile  5 online";
sql clone "alter database datafile  3 online";
# recover and open database read only
recover clone database tablespace  "SYSTEM", "UNDOTBS1", "UNDOTBS2", "SYSAUX";
sql clone 'alter database open read only';
}
executing Memory Script

executing command: SET until clause

sql statement: alter database datafile  1 online

sql statement: alter database datafile  4 online

sql statement: alter database datafile  5 online

sql statement: alter database datafile  3 online

Starting recover at 21-JAN-23
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 35 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_35.275.1126729957
archived log for thread 1 with sequence 36 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_36.274.1126729967
archived log for thread 1 with sequence 37 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_37.269.1126729977
archived log for thread 1 with sequence 38 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_38.267.1126730163
archived log for thread 2 with sequence 40 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_40.276.1126729957
archived log for thread 2 with sequence 41 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_41.270.1126729969
archived log for thread 2 with sequence 42 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_42.268.1126729977
archived log for thread 2 with sequence 43 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_43.266.1126730165
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_35.275.1126729957 thread=1 sequence=35
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_40.276.1126729957 thread=2 sequence=40
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_41.270.1126729969 thread=2 sequence=41
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_36.274.1126729967 thread=1 sequence=36
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_37.269.1126729977 thread=1 sequence=37
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_42.268.1126729977 thread=2 sequence=42
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_38.267.1126730163 thread=1 sequence=38
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_43.266.1126730165 thread=2 sequence=43
media recovery complete, elapsed time: 00:00:01
Finished recover at 21-JAN-23

sql statement: alter database open read only

contents of Memory Script:
{
   sql clone "create spfile from memory";
   shutdown clone immediate;
   startup clone nomount;
   sql clone "alter system set  control_files =
  ''/ora_home/bkp/AUX_DEST/NTNT/controlfile/o1_mf_kwqzvl0s_.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    2751463160 bytes

Fixed Size                     8900344 bytes
Variable Size                570425344 bytes
Database Buffers            2164260864 bytes
Redo Buffers                   7876608 bytes

sql statement: alter system set  control_files =   ''/ora_home/bkp/AUX_DEST/NTNT/controlfile/o1_mf_kwqzvl0s_.ctl'' comment= ''RMAN set'' scope=spfile

Oracle instance shut down

connected to auxiliary database (not started)
Oracle instance started

Total System Global Area    2751463160 bytes

Fixed Size                     8900344 bytes
Variable Size                570425344 bytes
Database Buffers            2164260864 bytes
Redo Buffers                   7876608 bytes

sql statement: alter database mount clone database

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('21-JAN-2023 20:33:00','DD-MON-YYYY HH24:MI:SS')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile  2 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile  2;
 
switch clone datafile all;
}
executing Memory Script

executing command: SET until clause

executing command: SET NEWNAME

Starting restore at 21-JAN-23
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=14 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 00002 to /ora_home/bkp/AUX_DEST/CSSV_PITR_NTNT/datafile/o1_mf_rman_tsp_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /ora_home/bkp/DB_BKP/DB_FULL_backup_2u1ih26d_1_1
channel ORA_AUX_DISK_1: piece handle=/ora_home/bkp/DB_BKP/DB_FULL_backup_2u1ih26d_1_1 tag=TAG20230121T203212
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 21-JAN-23

datafile 2 switched to datafile copy
input datafile copy RECID=16 STAMP=1126730342 file name=/ora_home/bkp/AUX_DEST/CSSV_PITR_NTNT/datafile/o1_mf_rman_tsp_kwr00fhq_.dbf

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('21-JAN-2023 20:33:00','DD-MON-YYYY HH24:MI:SS')";
# online the datafiles restored or switched
sql clone "alter database datafile  2 online";
# recover and open resetlogs
recover clone database tablespace  "RMAN_TSPITR", "SYSTEM", "UNDOTBS1", "UNDOTBS2", "SYSAUX" delete archivelog;
alter clone database open resetlogs;
}
executing Memory Script

executing command: SET until clause

sql statement: alter database datafile  2 online

Starting recover at 21-JAN-23
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 35 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_35.275.1126729957
archived log for thread 1 with sequence 36 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_36.274.1126729967
archived log for thread 1 with sequence 37 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_37.269.1126729977
archived log for thread 1 with sequence 38 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_38.267.1126730163
archived log for thread 2 with sequence 40 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_40.276.1126729957
archived log for thread 2 with sequence 41 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_41.270.1126729969
archived log for thread 2 with sequence 42 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_42.268.1126729977
archived log for thread 2 with sequence 43 is already on disk as file +FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_43.266.1126730165
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_35.275.1126729957 thread=1 sequence=35
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_40.276.1126729957 thread=2 sequence=40
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_41.270.1126729969 thread=2 sequence=41
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_36.274.1126729967 thread=1 sequence=36
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_37.269.1126729977 thread=1 sequence=37
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_42.268.1126729977 thread=2 sequence=42
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_1_seq_38.267.1126730163 thread=1 sequence=38
archived log file name=+FRA/NTNT/ARCHIVELOG/2023_01_21/thread_2_seq_43.266.1126730165 thread=2 sequence=43
media recovery complete, elapsed time: 00:00:02
Finished recover at 21-JAN-23

database opened

contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/ora_home/bkp/AUX_DEST''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/ora_home/bkp/AUX_DEST''";
}
executing Memory Script

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/ora_home/bkp/AUX_DEST''

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/ora_home/bkp/AUX_DEST''

Performing export of tables...
   EXPDP> Starting "SYS"."TSPITR_EXP_Cssv_nwnr":  
   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 "ABHI_TEST"."TAB_TSPITR"                    5.195 KB      12 rows
   EXPDP> Master table "SYS"."TSPITR_EXP_Cssv_nwnr" successfully loaded/unloaded
   EXPDP> ******************************************************************************
   EXPDP> Dump file set for SYS.TSPITR_EXP_Cssv_nwnr is:
   EXPDP>   /ora_home/bkp/AUX_DEST/tspitr_Cssv_88933.dmp
   EXPDP> Job "SYS"."TSPITR_EXP_Cssv_nwnr" successfully completed at Sat Jan 21 20:39:28 2023 elapsed 0 00:00:12
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_Cssv_ucqk" successfully loaded/unloaded
   IMPDP> Starting "SYS"."TSPITR_IMP_Cssv_ucqk":  
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
   IMPDP> . . imported "ABHI_TEST"."TAB_TSPITR"                    5.195 KB      12 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_Cssv_ucqk" successfully completed at Sat Jan 21 20:39:55 2023 elapsed 0 00:00:21
Import completed

Removing automatic instance
Automatic instance removed
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_temp_kwqzxo9o_.tmp deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/CSSV_PITR_NTNT/onlinelog/o1_mf_4_kwr00nyl_.log deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/CSSV_PITR_NTNT/onlinelog/o1_mf_3_kwr00ny4_.log deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/CSSV_PITR_NTNT/onlinelog/o1_mf_2_kwr00nxn_.log deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/CSSV_PITR_NTNT/onlinelog/o1_mf_1_kwr00nwv_.log deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/CSSV_PITR_NTNT/datafile/o1_mf_rman_tsp_kwr00fhq_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_sysaux_kwqzw33z_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_undotbs2_kwqzw22n_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_undotbs1_kwqzwl8q_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_system_kwqzwl88_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/controlfile/o1_mf_kwqzvl0s_.ctl deleted
auxiliary instance file tspitr_Cssv_88933.dmp deleted
Finished recover at 21-JAN-23

RMAN> exit

Recovery Manager complete.

Step 5=> Verify TABLE as below.

[oracle@racsetn1 DB_BKP]$ sqlplus ABHI_TEST/Oracle_4U

SQL> alter session set NLS_dATE_FORMAT='DD-MON-YYYY HH24:MI:SS';

Session altered.

SQL> select * from TAB_TSPITR;

DATA
--------------------
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45

12 rows selected.

SQL>

As we can see table is recovered now !!!

B=>Recovering Tables with Different Name in Same Schema using REMAP TABLE to a Specified Point in Time

In this practice we will recover above mentioned tables with different name as below.

Step 1=> Let we drop above practiced table again.

[oracle@racsetn1 DB_BKP]$ sqlplus ABHI_TEST/Oracle_4U

SQL> drop table TAB_TSPITR;

Table dropped.

Step 2 => We will recover same table with Different name in same schema as below using REMAP TABLE

RMAN> run
{
recover table ABHI_TEST.TAB_TSPITR
until time "to_date('21-JAN-2023 20:33:00','DD-MON-YYYY HH24:MI:SS')"
AUXILIARY DESTINATION '/ora_home/bkp/AUX_DEST'
REMAP TABLE ABHI_TEST.TAB_TSPITR:ABHI_TEST.TAB_TSPITR_NEW;
}

...
....
....
.....

Performing export of tables...
   EXPDP> Starting "SYS"."TSPITR_EXP_rkdi_ewAy":  
   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 "ABHI_TEST"."TAB_TSPITR"                    5.195 KB      12 rows
   EXPDP> Master table "SYS"."TSPITR_EXP_rkdi_ewAy" successfully loaded/unloaded
   EXPDP> ******************************************************************************
   EXPDP> Dump file set for SYS.TSPITR_EXP_rkdi_ewAy is:
   EXPDP>   /ora_home/bkp/AUX_DEST/tspitr_rkdi_95686.dmp
   EXPDP> Job "SYS"."TSPITR_EXP_rkdi_ewAy" successfully completed at Sat Jan 21 20:52:14 2023 elapsed 0 00:00:14
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_rkdi_vifn" successfully loaded/unloaded
   IMPDP> Starting "SYS"."TSPITR_IMP_rkdi_vifn":  
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
   IMPDP> . . imported "ABHI_TEST"."TAB_TSPITR_NEW"                5.195 KB      12 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_rkdi_vifn" successfully completed at Sat Jan 21 20:52:40 2023 elapsed 0 00:00:21
Import completed

Removing automatic instance
Automatic instance removed
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_temp_kwr0omyf_.tmp deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/RKDI_PITR_NTNT/onlinelog/o1_mf_4_kwr0rjjv_.log deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/RKDI_PITR_NTNT/onlinelog/o1_mf_3_kwr0rjjf_.log deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/RKDI_PITR_NTNT/onlinelog/o1_mf_2_kwr0rjhx_.log deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/RKDI_PITR_NTNT/onlinelog/o1_mf_1_kwr0rjgz_.log deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/RKDI_PITR_NTNT/datafile/o1_mf_rman_tsp_kwr0r8wn_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_sysaux_kwr0n1ws_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_undotbs2_kwr0n0vy_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_undotbs1_kwr0njyp_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/datafile/o1_mf_system_kwr0njy7_.dbf deleted
auxiliary instance file /ora_home/bkp/AUX_DEST/NTNT/controlfile/o1_mf_kwr0mny7_.ctl deleted
auxiliary instance file tspitr_rkdi_95686.dmp deleted
Finished recover at 21-JAN-23

RMAN> exit

Step 3=> Verify data as below.
Recovery Manager complete.
[oracle@racsetn1 DB_BKP]$ sqlplus ABHI_TEST/Oracle_4U

SQL> select table_name from user_tables;

TABLE_NAME
--------------------------------------------------------------------------------
TX_ITL
FLASH_REWIND_RESETLOG
ITL_TEST
TEST_ENQ
TAB_TSPITR_NEW

SQL>  alter session set NLS_dATE_FORMAT='DD-MON-YYYY HH24:MI:SS';

Session altered.

SQL> select * from TAB_TSPITR_NEW;

DATA
--------------------
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 19:44:46
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:02:50
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45
21-JAN-2023 20:03:45

12 rows selected.

SQL>

Hence this is recovered with new name !!!

C=>Recovering Tables Having Prtitions

In this practice we will be recovering partitioned tables as below.

Step 1=> Create dummy partitioned table and Insert data

SQL> CREATE TABLE sales_range_partition (
    product_id       NUMBER(6),
    customer_id      NUMBER,
    channel_id       CHAR(1),
    promo_id         NUMBER(6),
    sale_date        DATE,
    quantity_sold    INTEGER,
    amount_sold      NUMBER(10,2)
)
PARTITION BY RANGE (sale_date)
(  
   PARTITION sales_q1_2014 VALUES LESS THAN (TO_DATE('01-APR-2014','dd-MON-yyyy')),
   PARTITION sales_q2_2014 VALUES LESS THAN (TO_DATE('01-JUL-2014','dd-MON-yyyy')),
   PARTITION sales_q3_2014 VALUES LESS THAN (TO_DATE('01-OCT-2014','dd-MON-yyyy')),
   PARTITION sales_q4_2014 VALUES LESS THAN (TO_DATE('01-JAN-2015','dd-MON-yyyy'))
); 

Table created.

SQL>
INSERT INTO sales_range_partition VALUES (1001,100,'A',150,'10-FEB-2014',500,2000);
INSERT INTO sales_range_partition VALUES (1002,110,'B',180,'15-JUN-2014',100,1000);
INSERT INTO sales_range_partition VALUES (1001,100,'A',150,'20-AUG-2014',500,2000);
COMMIT;

SELECT * FROM sales_range_partition;SQL>

1 row created.

SQL>
1 row created.

SQL>
1 row created.

Commit complete.

SQL> SQL>
PRODUCT_ID CUSTOMER_ID C   PROMO_ID SALE_DATE QUANTITY_SOLD AMOUNT_SOLD
---------- ----------- - ---------- --------- ------------- -----------
      1001       100 A    150 10-FEB-14        500       2000
      1002       110 B    180 15-JUN-14        100       1000
      1001       100 A    150 20-AUG-14        500       2000

SQL>


Step 2=> Take database backup

[oracle@racsetn1 DB_BKP]$ rman target /

Recovery Manager: Release 19.0.0.0.0 - Production on Sat Jan 21 21:00:16 2023
Version 19.3.0.0.0

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

connected to target database: NTNT (DBID=3125572952)

RMAN> RUN
{
sql 'ALTER SYSTEM ARCHIVE LOG CURRENT';
allocate channel CH01 type disk;
allocate channel CH02 type disk;
allocate channel CH03 type disk;
allocate channel CH04 type disk;
BACKUP as compressed backupset database FORMAT '/ora_home/bkp/DB_BKP/DB_FULL_backup_%U' plus archivelog  FORMAT '/ora_home/bkp/DB_BKP/%d_%T_%s_%p_ARCHIVE' ;
backup format '/ora_home/bkp/DB_BKP/BKP_cf_%d_%U_%t' current controlfile tag='backup_controlfile';
sql 'ALTER SYSTEM ARCHIVE LOG CURRENT';
sql 'ALTER SYSTEM ARCHIVE LOG CURRENT';
release channel CH01;
release channel CH02;
release channel CH03;
release channel CH04;
}

Step 3=> INsert few more records and note timing.

[oracle@racsetn1 DB_BKP]$ sqlplus ABHI_TEST/Oracle_4U

SQL> INSERT INTO sales_range_partition VALUES (1001,100,'A',150,'10-MAR-2014',500,2000);

INSERT INTO sales_range_partition VALUES (1002,110,'B',180,'15-MAY-2014',100,1000);
INSERT INTO sales_range_partition VALUES (1001,100,'A',150,'20-SEP-2014',500,2000);

COMMIT;

Commit complete.

SQL> SQL>

PRODUCT_ID CUSTOMER_ID C   PROMO_ID SALE_DATE QUANTITY_SOLD AMOUNT_SOLD
---------- ----------- - ---------- --------- ------------- -----------
      1001       100 A    150 10-FEB-14        500       2000
      1001       100 A    150 10-MAR-14        500       2000
      1002       110 B    180 15-JUN-14        100       1000
      1002       110 B    180 15-MAY-14        100       1000
      1001       100 A    150 20-AUG-14        500       2000
      1001       100 A    150 20-SEP-14        500       2000

6 rows selected.

SQL> select systimestamp from dual;

SYSTIMESTAMP
---------------------------------------------------------------------------
21-JAN-23 09.04.07.068730 PM +05:30

SQL>
INSERT INTO sales_range_partition VALUES (1001,100,'X',150,'10-MAR-2014',500,2000);
INSERT INTO sales_range_partition VALUES (1002,110,'X',180,'15-MAY-2014',100,1000);
INSERT INTO sales_range_partition VALUES (1001,100,'X',150,'20-SEP-2014',500,2000);

Commit complete.

SQL> SELECT * FROM sales_range_partition;

PRODUCT_ID CUSTOMER_ID C   PROMO_ID SALE_DATE QUANTITY_SOLD AMOUNT_SOLD
---------- ----------- - ---------- --------- ------------- -----------
      1001       100 A    150 10-FEB-14        500       2000
      1001       100 A    150 10-MAR-14        500       2000
      1001       100 X    150 10-MAR-14        500       2000
      1002       110 B    180 15-JUN-14        100       1000
      1002       110 B    180 15-MAY-14        100       1000
      1002       110 X    180 15-MAY-14        100       1000
      1001       100 A    150 20-AUG-14        500       2000
      1001       100 A    150 20-SEP-14        500       2000
      1001       100 X    150 20-SEP-14        500       2000

9 rows selected.


Step 4=> Drop 1 partition as below.

[oracle@racsetn1 DB_BKP]$ sqlplus ABHI_TEST/Oracle_4U

SQL> alter table sales_range_partition drop partition sales_q1_2014;

Table altered.

SQL> SELECT * FROM sales_range_partition;

PRODUCT_ID CUSTOMER_ID C   PROMO_ID SALE_DATE QUANTITY_SOLD AMOUNT_SOLD
---------- ----------- - ---------- --------- ------------- -----------
      1002       110 B    180 15-JUN-14        100       1000
      1002       110 B    180 15-MAY-14        100       1000
      1002       110 X    180 15-MAY-14        100       1000
      1001       100 A    150 20-AUG-14        500       2000
      1001       100 A    150 20-SEP-14        500       2000
      1001       100 X    150 20-SEP-14        500       2000

6 rows selected.

SQL> exit

Step 5=> Start table partition recovery as below.

RMAN> run
{
recover table ABHI_TEST.sales_range_partition:sales_q1_2014
until time "to_date('21-JAN-2023 21:04:00','DD-MON-YYYY HH24:MI:SS')"
AUXILIARY DESTINATION '/ora_home/bkp/AUX_DEST';
}

Step 6=> Post recovery check values as below.

[oracle@racsetn1 DB_BKP]$ sqlplus ABHI_TEST/Oracle_4U

SQL>  SELECT * FROM sales_range_partition;

PRODUCT_ID CUSTOMER_ID C   PROMO_ID SALE_DATE QUANTITY_SOLD AMOUNT_SOLD
---------- ----------- - ---------- --------- ------------- -----------
      1002       110 B    180 15-JUN-14        100       1000
      1002       110 B    180 15-MAY-14        100       1000
      1002       110 X    180 15-MAY-14        100       1000
      1001       100 A    150 20-AUG-14        500       2000
      1001       100 A    150 20-SEP-14        500       2000
      1001       100 X    150 20-SEP-14        500       2000

6 rows selected.

SQL>

Our table partitiones is recovered now.