Oracle 19c Point in Time Recovery of a Table in Pluggable Database

In this post I am creating a scenario to recover a table data.

Point in time recovery:-

RMAN database point-in-time recovery (DBPITR) restores the database from RMAN backups.
RMAN will be consider all ( required ) backups (full, incremental, transactional) to restore or roll forward to the desire time.
Point in time recovery may be incomplete recovery because it does not use all the available archive logs files or completely recover all changes to your database.
If you want to recover your database to the exact date/time in the past, use RMAN point in time recovery.



Steps:


1) Enable Database in Archive mode.

mkdir -p /u01/app/oracle/product/19c/dbhome_1/dbs/arch

[oracle@dbserver ~]$ sqlplus '/as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 06:54:12 2023
Version 19.14.0.0.0

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


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.14.0.0.0

SQL> show pdbs

    CON_ID CON_NAME                       OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
         2 PDB$SEED                       READ ONLY  NO
         3 ORCLPDB                        READ WRITE NO

SQL> archive log list;
Database log mode              No Archive Mode
Automatic archival             Disabled
Archive destination            /u01/app/oracle/product/19c/dbhome_1/dbs/arch
Oldest online log sequence     15
Current log sequence           17
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.

Enabling Archive Mode Now.

SQL> startup mount;
ORACLE instance started.

Total System Global Area 4949277288 bytes
Fixed Size                  9144936 bytes
Variable Size             889192448 bytes
Database Buffers         4043309056 bytes
Redo Buffers                7630848 bytes
Database mounted.
SQL> alter database archivelog;

Database altered.

SQL> alter database open;

Database altered.

SQL> archive log list;
Database log mode              Archive Mode
Automatic archival             Enabled
Archive destination            /u01/app/oracle/product/19c/dbhome_1/dbs/arch
Oldest online log sequence     15
Next log sequence to archive   17
Current log sequence           17



2) Take a full database backup

[oracle@dbserver ~]$ rman target /

Recovery Manager: Release 19.0.0.0.0 - Production on Sat Jun 10 06:58:39 2023
Version 19.14.0.0.0

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

connected to target database: ORCL (DBID=1666823206)

RMAN> report schema;

using target database control file instead of recovery catalog
Report of database schema for database with db_unique_name ORCL

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    1000     SYSTEM               YES     /u01/app/oracle/oradata/ORCL/system01.dbf
3    830      SYSAUX               NO      /u01/app/oracle/oradata/ORCL/sysaux01.dbf
4    865      UNDOTBS1             YES     /u01/app/oracle/oradata/ORCL/undotbs01.dbf
5    360      PDB$SEED:SYSTEM      NO      /u01/app/oracle/oradata/ORCL/pdbseed/system01.dbf
6    440      PDB$SEED:SYSAUX      NO      /u01/app/oracle/oradata/ORCL/pdbseed/sysaux01.dbf
7    5        USERS                NO      /u01/app/oracle/oradata/ORCL/users01.dbf
8    200      PDB$SEED:UNDOTBS1    NO      /u01/app/oracle/oradata/ORCL/pdbseed/undotbs01.dbf
9    370      ORCLPDB:SYSTEM       NO      /u01/app/oracle/oradata/ORCL/orclpdb/system01.dbf
10   500      ORCLPDB:SYSAUX       NO      /u01/app/oracle/oradata/ORCL/orclpdb/sysaux01.dbf
11   200      ORCLPDB:UNDOTBS1     NO      /u01/app/oracle/oradata/ORCL/orclpdb/undotbs01.dbf
12   5        ORCLPDB:USERS        NO      /u01/app/oracle/oradata/ORCL/orclpdb/users01.dbf

List of Temporary Files
=======================
File Size(MB) Tablespace           Maxsize(MB) Tempfile Name
---- -------- -------------------- ----------- --------------------
1    98       TEMP                 32767       /u01/app/oracle/oradata/ORCL/temp01.dbf
2    89       PDB$SEED:TEMP        32767       /u01/app/oracle/oradata/ORCL/pdbseed/temp012023-06-09_08-53-10-571-AM.dbf
3    89       ORCLPDB:TEMP         32767       /u01/app/oracle/oradata/ORCL/orclpdb/temp01.dbf




RMAN> CONFIGURE CONTROLFILE AUTOBACKUP ON ;



RMAN> backup database plus archivelog;


Starting backup at 10-JUN-23
current log archived
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=271 device type=DISK
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=17 RECID=1 STAMP=1139122744
channel ORA_DISK_1: starting piece 1 at 10-JUN-23
channel ORA_DISK_1: finished piece 1 at 10-JUN-23
piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/011ub8ho_1_1_1 tag=TAG20230610T065904 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 10-JUN-23

Starting backup at 10-JUN-23
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00001 name=/u01/app/oracle/oradata/ORCL/system01.dbf
input datafile file number=00004 name=/u01/app/oracle/oradata/ORCL/undotbs01.dbf
input datafile file number=00003 name=/u01/app/oracle/oradata/ORCL/sysaux01.dbf
input datafile file number=00007 name=/u01/app/oracle/oradata/ORCL/users01.dbf
channel ORA_DISK_1: starting piece 1 at 10-JUN-23
channel ORA_DISK_1: finished piece 1 at 10-JUN-23
piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/021ub8hq_2_1_1 tag=TAG20230610T065906 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:35
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00010 name=/u01/app/oracle/oradata/ORCL/orclpdb/sysaux01.dbf
input datafile file number=00009 name=/u01/app/oracle/oradata/ORCL/orclpdb/system01.dbf
input datafile file number=00011 name=/u01/app/oracle/oradata/ORCL/orclpdb/undotbs01.dbf
input datafile file number=00012 name=/u01/app/oracle/oradata/ORCL/orclpdb/users01.dbf
channel ORA_DISK_1: starting piece 1 at 10-JUN-23
channel ORA_DISK_1: finished piece 1 at 10-JUN-23
piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/031ub8it_3_1_1 tag=TAG20230610T065906 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00006 name=/u01/app/oracle/oradata/ORCL/pdbseed/sysaux01.dbf
input datafile file number=00005 name=/u01/app/oracle/oradata/ORCL/pdbseed/system01.dbf
input datafile file number=00008 name=/u01/app/oracle/oradata/ORCL/pdbseed/undotbs01.dbf
channel ORA_DISK_1: starting piece 1 at 10-JUN-23
channel ORA_DISK_1: finished piece 1 at 10-JUN-23
piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/041ub8jc_4_1_1 tag=TAG20230610T065906 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
Finished backup at 10-JUN-23

Starting backup at 10-JUN-23
current log archived
using channel ORA_DISK_1
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=18 RECID=2 STAMP=1139122811
channel ORA_DISK_1: starting piece 1 at 10-JUN-23
channel ORA_DISK_1: finished piece 1 at 10-JUN-23
piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/051ub8js_5_1_1 tag=TAG20230610T070012 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 10-JUN-23

Starting Control File and SPFILE Autobackup at 10-JUN-23
piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/c-1666823206-20230610-00 comment=NONE
Finished Control File and SPFILE Autobackup at 10-JUN-23


3) I am creating a user himanshu in my PDB database.


[oracle@dbserver arch]$ sqlplus '/as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 07:02:23 2023
Version 19.14.0.0.0

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


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.14.0.0.0

SQL> show pdbs

    CON_ID CON_NAME                       OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
         2 PDB$SEED                       READ ONLY  NO
         3 ORCLPDB                        READ WRITE NO

SQL> alter session set container=ORCLPDB;

Session altered.

SQL> create user himanshu identified by oracle123;

User created.

SQL> grant connect,resource to himanshu;

Grant succeeded.

SQL> ALTER USER himanshu quota unlimited on users;

User altered.


4) Now lets connect to the new user and  create a table with some data.

[oracle@dbserver ~]$ sqlplus himanshu/oracle123@orclpdb

SQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 07:09:45 2023
Version 19.14.0.0.0

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


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.14.0.0.0

SQL> show user
USER is "HIMANSHU"
SQL> create table emp(name varchar2(20));

Table created.

SQL> BEGIN  
FOR k IN 1..1100 LOOP  
Insert into emp values('dummyuser');
END LOOP;  
END;
/  2    3    4    5    6  

PL/SQL procedure successfully completed.

SQL> commit;

Commit complete.

SQL> select count(*) from himanshu.emp;

  COUNT(*)
----------
      1100




5) Check the current sequence number


 archive log list
Database log mode              Archive Mode
Automatic archival             Enabled
Archive destination            /u01/app/oracle/product/19c/dbhome_1/dbs/arch
Oldest online log sequence     20
Next log sequence to archive   22
Current log sequence           22


rman target /

RMAN> backup archivelog all;

Starting backup at 10-JUN-23
current log archived
using channel ORA_DISK_1
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=17 RECID=1 STAMP=1139122744
input archived log thread=1 sequence=18 RECID=2 STAMP=1139122811
input archived log thread=1 sequence=19 RECID=3 STAMP=1139125421
input archived log thread=1 sequence=20 RECID=4 STAMP=1139125489
input archived log thread=1 sequence=21 RECID=5 STAMP=1139125529
channel ORA_DISK_1: starting piece 1 at 10-JUN-23
channel ORA_DISK_1: finished piece 1 at 10-JUN-23
piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/0d1ubb8p_13_1_1 tag=TAG20230610T074529 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 10-JUN-23

Starting Control File and SPFILE Autobackup at 10-JUN-23
piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/c-1666823206-20230610-02 comment=NONE
Finished Control File and SPFILE Autobackup at 10-JUN-23



6) Lets delete the data from the table EMP that we created.

[oracle@dbserver ~]$ sqlplus himanshu/oracle123@orclpdb

SQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 07:45:58 2023
Version 19.14.0.0.0

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

Last Successful login time: Sat Jun 10 2023 07:42:16 +00:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.14.0.0.0

SQL> delete from himanshu.emp;

1100 rows deleted.

SQL> commit;

Commit complete.

SQL> select count(*) from himanshu.emp;

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


7) Now let's identify the log sequence timestamp.

[oracle@dbserver ~]$ sqlplus '/as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 07:48:00 2023
Version 19.14.0.0.0

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


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.14.0.0.0

SQL> select sequence#,first_change#, to_char(first_time,'HH24:MI:SS') from v$log order by 3;

 SEQUENCE# FIRST_CHANGE# TO_CHAR(
---------- ------------- --------
        20       2822185 07:43:41
        21       2822244 07:44:49
        22       2822303 07:45:29


8) As per previous execution we know the table was deleted at 7:45 Hrs so we need to restore it before that, which is sequence 21.



Make a temporary folder.

mkdir -p /u01/app/backup

[oracle@dbserver ~]$ rman target /

Recovery Manager: Release 19.0.0.0.0 - Production on Sat Jun 10 07:50:53 2023
Version 19.14.0.0.0

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

connected to target database: ORCL (DBID=1666823206)

RMAN> recover table himanshu.emp of pluggable database ORCLPDB until time "to_date('2023-06-10 07:44:49','yyyy-mm-dd:hh24:mi:ss')" auxiliary destination '/u01/app/backup' REMAP TABLE 'HIMANSHU'.'EMP':'EMP_RESTORE';

Starting recover at 10-JUN-23
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=397 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 ORCLPDB:SYSTEM
Tablespace UNDOTBS1
Tablespace ORCLPDB:UNDOTBS1

Creating automatic instance, with SID='oxyo'

initialization parameters used for automatic instance:
db_name=ORCL
db_unique_name=oxyo_pitr_ORCLPDB_ORCL
compatible=19.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/u01/app/oracle
_system_trig_enabled=FALSE
sga_target=4720M
processes=200
db_create_file_dest=/u01/app/backup
log_archive_dest_1='location=/u01/app/backup'
enable_pluggable_database=true
_clone_one_pdb_recovery=true
#No auxiliary parameter file used


starting up automatic instance ORCL

Oracle instance started

Total System Global Area    4949277048 bytes

Fixed Size                     9144696 bytes
Variable Size                889192448 bytes
Database Buffers            4043309056 bytes
Redo Buffers                   7630848 bytes
Automatic instance created

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('2023-06-10 07:44:49','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 10-JUN-23
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=9 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/product/19c/dbhome_1/dbs/c-1666823206-20230610-00
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/c-1666823206-20230610-00 tag=TAG20230610T070013
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/u01/app/backup/ORCL/controlfile/o1_mf_l88bvdn1_.ctl
Finished restore at 10-JUN-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('2023-06-10 07:44:49','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 /u01/app/backup/ORCL/datafile/o1_mf_temp_%u_.tmp in control file
renamed tempfile 3 to /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_temp_%u_.tmp in control file

Starting restore at 10-JUN-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 00001 to /u01/app/backup/ORCL/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /u01/app/backup/ORCL/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /u01/app/backup/ORCL/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19c/dbhome_1/dbs/081ubb5g_8_1_1
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/081ubb5g_8_1_1 tag=TAG20230610T074343
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:35
channel ORA_AUX_DISK_1: starting datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_AUX_DISK_1: restoring datafile 00009 to /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00011 to /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00010 to /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19c/dbhome_1/dbs/091ubb6j_9_1_1
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/091ubb6j_9_1_1 tag=TAG20230610T074343
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:25
Finished restore at 10-JUN-23

datafile 1 switched to datafile copy
input datafile copy RECID=10 STAMP=1139125935 file name=/u01/app/backup/ORCL/datafile/o1_mf_system_l88bvm9w_.dbf
datafile 9 switched to datafile copy
input datafile copy RECID=11 STAMP=1139125935 file name=/u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_system_l88bwxw6_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=12 STAMP=1139125935 file name=/u01/app/backup/ORCL/datafile/o1_mf_undotbs1_l88bvmb2_.dbf
datafile 11 switched to datafile copy
input datafile copy RECID=13 STAMP=1139125935 file name=/u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_undotbs1_l88bx3qp_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=14 STAMP=1139125935 file name=/u01/app/backup/ORCL/datafile/o1_mf_sysaux_l88bvmb8_.dbf
datafile 10 switched to datafile copy
input datafile copy RECID=15 STAMP=1139125935 file name=/u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_sysaux_l88bwpd6_.dbf

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('2023-06-10 07:44:49','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 10-JUN-23
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 19 is already on disk as file /u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_19_1139042473.dbf
archived log for thread 1 with sequence 20 is already on disk as file /u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_20_1139042473.dbf
archived log file name=/u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_19_1139042473.dbf thread=1 sequence=19
archived log file name=/u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_20_1139042473.dbf thread=1 sequence=20
media recovery complete, elapsed time: 00:00:01
Finished recover at 10-JUN-23

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 = 
  ''/u01/app/backup/ORCL/controlfile/o1_mf_l88bvdn1_.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    4949277048 bytes

Fixed Size                     9144696 bytes
Variable Size                889192448 bytes
Database Buffers            4043309056 bytes
Redo Buffers                   7630848 bytes

sql statement: alter system set  control_files =   ''/u01/app/backup/ORCL/controlfile/o1_mf_l88bvdn1_.ctl'' comment= ''RMAN set'' scope=spfile

Oracle instance shut down

connected to auxiliary database (not started)
Oracle instance started

Total System Global Area    4949277048 bytes

Fixed Size                     9144696 bytes
Variable Size                889192448 bytes
Database Buffers            4043309056 bytes
Redo Buffers                   7630848 bytes

sql statement: alter database mount clone database

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('2023-06-10 07:44:49','yyyy-mm-dd:hh24:mi:ss')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile  12 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile  12;
 
switch clone datafile all;
}
executing Memory Script

executing command: SET until clause

executing command: SET NEWNAME

Starting restore at 10-JUN-23
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 00012 to /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_users_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19c/dbhome_1/dbs/091ubb6j_9_1_1
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/091ubb6j_9_1_1 tag=TAG20230610T074343
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 10-JUN-23

datafile 12 switched to datafile copy
input datafile copy RECID=17 STAMP=1139125991 file name=/u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_users_l88bz6qw_.dbf

contents of Memory Script:
{
# set requested point in time
set until  time "to_date('2023-06-10 07:44:49','yyyy-mm-dd:hh24:mi:ss')";
# online the datafiles restored or switched
sql clone 'ORCLPDB' "alter database datafile 
 12 online";
# recover and open resetlogs
recover clone database tablespace  "ORCLPDB":"USERS", "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  12 online

Starting recover at 10-JUN-23
using channel ORA_AUX_DISK_1

starting media recovery

archived log for thread 1 with sequence 20 is already on disk as file /u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_20_1139042473.dbf
archived log file name=/u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_20_1139042473.dbf thread=1 sequence=20
media recovery complete, elapsed time: 00:00:00
Finished recover at 10-JUN-23

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 ''
/u01/app/backup''";
# create directory for datapump export
sql clone 'ORCLPDB' "create or replace directory 
TSPITR_DIROBJ_DPDIR as ''
/u01/app/backup''";
}
executing Memory Script

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/app/backup''

sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/app/backup''

Performing export of tables...
   EXPDP> Starting "SYS"."TSPITR_EXP_oxyo_tBbD":  
   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 "HIMANSHU"."EMP"                            20.08 KB    1100 rows
   EXPDP> Master table "SYS"."TSPITR_EXP_oxyo_tBbD" successfully loaded/unloaded
   EXPDP> ******************************************************************************
   EXPDP> Dump file set for SYS.TSPITR_EXP_oxyo_tBbD is:
   EXPDP>   /u01/app/backup/tspitr_oxyo_62212.dmp
   EXPDP> Job "SYS"."TSPITR_EXP_oxyo_tBbD" successfully completed at Sat Jun 10 07:53:56 2023 elapsed 0 00:00:26
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_oxyo_athq" successfully loaded/unloaded
   IMPDP> Starting "SYS"."TSPITR_IMP_oxyo_athq":  
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
   IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
   IMPDP> . . imported "HIMANSHU"."EMP_RESTORE"                    20.08 KB    1100 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_oxyo_athq" successfully completed at Sat Jun 10 07:54:27 2023 elapsed 0 00:00:23
Import completed


Removing automatic instance
Automatic instance removed
auxiliary instance file /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_temp_l88bxnd5_.tmp deleted
auxiliary instance file /u01/app/backup/ORCL/datafile/o1_mf_temp_l88bxlg4_.tmp deleted
auxiliary instance file /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/onlinelog/o1_mf_3_l88bzb4c_.log deleted
auxiliary instance file /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/onlinelog/o1_mf_2_l88bzb3y_.log deleted
auxiliary instance file /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/onlinelog/o1_mf_1_l88bzb3k_.log deleted
auxiliary instance file /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_users_l88bz6qw_.dbf deleted
auxiliary instance file /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_sysaux_l88bwpd6_.dbf deleted
auxiliary instance file /u01/app/backup/ORCL/datafile/o1_mf_sysaux_l88bvmb8_.dbf deleted
auxiliary instance file /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_undotbs1_l88bx3qp_.dbf deleted
auxiliary instance file /u01/app/backup/ORCL/datafile/o1_mf_undotbs1_l88bvmb2_.dbf deleted
auxiliary instance file /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_system_l88bwxw6_.dbf deleted
auxiliary instance file /u01/app/backup/ORCL/datafile/o1_mf_system_l88bvm9w_.dbf deleted
auxiliary instance file /u01/app/backup/ORCL/controlfile/o1_mf_l88bvdn1_.ctl deleted
auxiliary instance file tspitr_oxyo_62212.dmp deleted
Finished recover at 10-JUN-23



9) Table restore has been done successfully. Now we can insert back the data to original table.

[oracle@dbserver ~]$ sqlplus himanshu/oracle123@orclpdb

SQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 07:58:51 2023
Version 19.14.0.0.0

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

Last Successful login time: Sat Jun 10 2023 07:45:58 +00:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.14.0.0.0

SQL> select count(*) from emp;

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

SQL> select count(*) from EMP_RESTORE;

  COUNT(*)
----------
      1100



SQL> insert into emp select * from EMP_RESTORE;

1100 rows created.

SQL> commit;

Commit complete.

SQL> select count(*) from emp;

  COUNT(*)
----------
      1100






If you like please follow and comment