RMAN Recovery - Recover dropped table

Steps to recover the table using RMAN backup :
Step 1 : User creation
  SQL> create user tesdb dentified by tesdb default tablespace users temporary tablespace temp profile default account unlock;

  User created.
Step 2 : Provide grant privileges and allocate quota for “tesdb” user
  SQL> grant create session, create table to tesdb; 
  Grant succeeded. 

  SQL> alter user tesdb quota 500M on users; 
  User altered.
Step 3: Table creation
  SQL> conn tesdb/tesdb 

  SQL> create table tes(id int,name varchar2(20));
  Table created.
  SQL> begin
    2  for i in 1..1000 loop
    3  insert into tes values(i,'aa');
    4  end loop;
    5  end;
    6  /

  PL/SQL procedure successfully completed.

  SQL> commit;

  Commit complete.

  SQL> select count(*) from tes;

    COUNT(*)
  ----------
        1000


  SQL>select to_char(sysdate,'dd-mm-yyyy hh24:mi:ss') "now" from dual ;        now
  -------------------
  02-03-2024 13:09:53
Step 4 : Ensure that database in ARCHIVELOG mode and take a whole database backup
  SQL> archive log list;
  Database log mode	       Archive Mode
  Automatic archival	       Enabled
  Archive destination	       USE_DB_RECOVERY_FILE_DEST
  Oldest online log sequence     1
  Next log sequence to archive   2
  Current log sequence	       2
Step 5 : Take a full backup of database and archivelog
  RMAN> backup format '/home/oracle/backup/df_%d_%T_s%s_p%p' filesperset=20 database plus archivelog 
                                                            format '/home/oracle/backup/al_%d_%T_s%s_p%p';
  Starting backup at 02-MAR-24
  current log archived
  using target database control file instead of recovery catalog
  allocated channel: ORA_DISK_1
  channel ORA_DISK_1: SID=262 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=1 RECID=1 STAMP=1162559215
  input archived log thread=1 sequence=2 RECID=2 STAMP=1162559434
  input archived log thread=1 sequence=3 RECID=3 STAMP=1162559459
  input archived log thread=1 sequence=4 RECID=4 STAMP=1162567333
  channel ORA_DISK_1: starting piece 1 at 02-MAR-24
  channel ORA_DISK_1: finished piece 1 at 02-MAR-24
  piece handle=/home/oracle/backup/al_DEV_20240302_s5_p1 tag=TAG20240302T152214 comment=NONE
  channel ORA_DISK_1: backup set complete, elapsed time: 00:00:03
  Finished backup at 02-MAR-24

  Starting backup at 02-MAR-24
  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/dev/system01.dbf
  input datafile file number=00003 name=/u01/app/oracle/oradata/dev/sysaux01.dbf
  input datafile file number=00004 name=/u01/app/oracle/oradata/dev/undotbs01.dbf
  input datafile file number=00007 name=/u01/app/oracle/oradata/dev/users01.dbf
  channel ORA_DISK_1: starting piece 1 at 02-MAR-24
  channel ORA_DISK_1: finished piece 1 at 02-MAR-24
  piece handle=/home/oracle/backup/df_DEV_20240302_s6_p1 tag=TAG20240302T152217 comment=NONE
  channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
  Finished backup at 02-MAR-24

  Starting backup at 02-MAR-24
  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=5 RECID=5 STAMP=1162567353
  channel ORA_DISK_1: starting piece 1 at 02-MAR-24
  channel ORA_DISK_1: finished piece 1 at 02-MAR-24
  piece handle=/home/oracle/backup/al_DEV_20240302_s7_p1 tag=TAG20240302T152233 comment=NONE
  channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
  Finished backup at 02-MAR-24

  Starting Control File and SPFILE Autobackup at 02-MAR-24
  piece handle=/u01/app/oracle/fast_recovery_area/dev/DEV/autobackup/2024_03_02/o1_mf_s_1162567355_ly5xq3bj_.bkp comment=NONE
  Finished Control File and SPFILE Autobackup at 02-MAR-24
Step 6 : Drop the table
  SQL>  drop table tesdb.tes1;

  Table dropped.

  SQL> select count(*) from tesdb.tes1;
  select count(*) from tesdb.tes1
                            *
  ERROR at line 1:
  ORA-00942: table or view does not exist
Step 7 : Connect Rman utility recover table tesdb.tes1 using timestamp and specifying auxiliary destination
  RMAN> run
  2> {
  3> recover table TESDB.TES1 until time "to_date('03-02-2024 15:26:17','mm/dd/yyyy hh24:mi:ss')"
  4> auxiliary destination '/home/oracle/backup/';
  5> }

  Starting recover at 02-MAR-24
  using target database control file instead of recovery catalog
  current log archived
  allocated channel: ORA_DISK_1
  channel ORA_DISK_1: SID=266 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

  Creating automatic instance, with SID='dzvd'

  initialization parameters used for automatic instance:
  db_name=DEV
  db_unique_name=dzvd_pitr_DEV
  compatible=12.2.0
  db_block_size=8192
  db_files=200
  diagnostic_dest=/u01/app/oracle
  _system_trig_enabled=FALSE
  sga_target=680M
  processes=200
  db_create_file_dest=/home/oracle/backup/
  log_archive_dest_1='location=/home/oracle/backup/'
  #No auxiliary parameter file used


  starting up automatic instance DEV

  Oracle instance started

  Total System Global Area     713031680 bytes

  Fixed Size                     8624792 bytes
  Variable Size                201327976 bytes
  Database Buffers             494927872 bytes
  Redo Buffers                   8151040 bytes
  Automatic instance created

  contents of Memory Script:
  {
  # set requested point in time
  set until  time "to_date('03-02-2024 15:26:17','mm/dd/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 02-MAR-24
  allocated channel: ORA_AUX_DISK_1
  channel ORA_AUX_DISK_1: SID=162 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/dev/DEV/autobackup/
                                                                  2024_03_02/o1_mf_s_1162567355_ly5xq3bj_.bkp
  channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/dev/DEV/autobackup/2024_03_02/
                                                      o1_mf_s_1162567355_ly5xq3bj_.bkp tag=TAG20240302T152235
  channel ORA_AUX_DISK_1: restored backup piece 1
  channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
  output file name=/home/oracle/backup/DEV/controlfile/o1_mf_ly5y7hl6_.ctl
  Finished restore at 02-MAR-24

  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('03-02-2024 15:26:17','mm/dd/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  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, 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

  renamed tempfile 1 to /home/oracle/backup/DEV/datafile/o1_mf_temp_%u_.tmp in control file

  Starting restore at 02-MAR-24
  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 /home/oracle/backup/DEV/datafile/o1_mf_system_%u_.dbf
  channel ORA_AUX_DISK_1: restoring datafile 00004 to /home/oracle/backup/DEV/datafile/o1_mf_undotbs1_%u_.dbf
  channel ORA_AUX_DISK_1: restoring datafile 00003 to /home/oracle/backup/DEV/datafile/o1_mf_sysaux_%u_.dbf
  channel ORA_AUX_DISK_1: reading from backup piece /home/oracle/backup/df_DEV_20240302_s6_p1
  channel ORA_AUX_DISK_1: piece handle=/home/oracle/backup/df_DEV_20240302_s6_p1 tag=TAG20240302T152217
  channel ORA_AUX_DISK_1: restored backup piece 1
  channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:15
  Finished restore at 02-MAR-24

  datafile 1 switched to datafile copy
  input datafile copy RECID=4 STAMP=1162567902 file name=/home/oracle/backup/DEV/datafile/o1_mf_system_ly5y7po2_.dbf
  datafile 4 switched to datafile copy
  input datafile copy RECID=5 STAMP=1162567902 file name=/home/oracle/backup/DEV/datafile/o1_mf_undotbs1_ly5y7pom_.dbf
  datafile 3 switched to datafile copy
  input datafile copy RECID=6 STAMP=1162567902 file name=/home/oracle/backup/DEV/datafile/o1_mf_sysaux_ly5y7po8_.dbf

  contents of Memory Script:
  {
  # set requested point in time
  set until  time "to_date('03-02-2024 15:26:17','mm/dd/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  3 online";
  # recover and open database read only
  recover clone database tablespace  "SYSTEM", "UNDOTBS1", "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  3 online

  Starting recover at 02-MAR-24
  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/dev/
                                                                  DEV/archivelog/2024_03_02/o1_mf_1_5_ly5xq1cg_.arc
  archived log for thread 1 with sequence 6 is already on disk as file /u01/app/oracle/fast_recovery_area/dev/
                                                                  DEV/archivelog/2024_03_02/o1_mf_1_6_ly5y6lsl_.arc
  archived log file name=/u01/app/oracle/fast_recovery_area/dev/DEV/archivelog/2024_03_02/
                                                                  o1_mf_1_5_ly5xq1cg_.arc thread=1 sequence=5
  archived log file name=/u01/app/oracle/fast_recovery_area/dev/DEV/archivelog/2024_03_02/
                                                                  o1_mf_1_6_ly5y6lsl_.arc thread=1 sequence=6
  media recovery complete, elapsed time: 00:00:01
  Finished recover at 02-MAR-24

  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 = 
    ''/home/oracle/backup/DEV/controlfile/o1_mf_ly5y7hl6_.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     713031680 bytes

  Fixed Size                     8624792 bytes
  Variable Size                201327976 bytes
  Database Buffers             494927872 bytes
  Redo Buffers                   8151040 bytes

  sql statement: alter system set  control_files =   ''/home/oracle/backup/DEV/controlfile/
                                                          o1_mf_ly5y7hl6_.ctl'' comment= ''RMAN set'' scope=spfile

  Oracle instance shut down

  connected to auxiliary database (not started)
  Oracle instance started

  Total System Global Area     713031680 bytes

  Fixed Size                     8624792 bytes
  Variable Size                201327976 bytes
  Database Buffers             494927872 bytes
  Redo Buffers                   8151040 bytes

  sql statement: alter database mount clone database

  contents of Memory Script:
  {
  # set requested point in time
  set until  time "to_date('03-02-2024 15:26:17','mm/dd/yyyy hh24:mi:ss')";
  # set destinations for recovery set and auxiliary set datafiles
  set newname for datafile  7 to new;
  # restore the tablespaces in the recovery set and the auxiliary set
  restore clone datafile  7;
  
  switch clone datafile all;
  }
  executing Memory Script

  executing command: SET until clause

  executing command: SET NEWNAME

  Starting restore at 02-MAR-24
  allocated channel: ORA_AUX_DISK_1
  channel ORA_AUX_DISK_1: SID=179 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 00007 to /home/oracle/backup/DZVD_PITR_DEV/datafile/o1_mf_users_%u_.dbf
  channel ORA_AUX_DISK_1: reading from backup piece /home/oracle/backup/df_DEV_20240302_s6_p1
  channel ORA_AUX_DISK_1: piece handle=/home/oracle/backup/df_DEV_20240302_s6_p1 tag=TAG20240302T152217
  channel ORA_AUX_DISK_1: restored backup piece 1
  channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
  Finished restore at 02-MAR-24

  datafile 7 switched to datafile copy
  input datafile copy RECID=8 STAMP=1162567965 file name=/home/oracle/backup/DZVD_PITR_DEV/datafile/o1_mf_users_ly5yb3wz_.dbf

  contents of Memory Script:
  {
  # set requested point in time
  set until  time "to_date('03-02-2024 15:26:17','mm/dd/yyyy hh24:mi:ss')";
  # online the datafiles restored or switched
  sql clone "alter database datafile  7 online";
  # recover and open resetlogs
  recover clone database tablespace  "USERS", "SYSTEM", "UNDOTBS1", "SYSAUX" delete archivelog;
  alter clone database open resetlogs;
  }
  executing Memory Script

  executing command: SET until clause

  sql statement: alter database datafile  7 online

  Starting recover at 02-MAR-24
  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/dev/
                                                                    DEV/archivelog/2024_03_02/o1_mf_1_5_ly5xq1cg_.arc
  archived log for thread 1 with sequence 6 is already on disk as file /u01/app/oracle/fast_recovery_area/dev/
                                                                    DEV/archivelog/2024_03_02/o1_mf_1_6_ly5y6lsl_.arc
  archived log file name=/u01/app/oracle/fast_recovery_area/dev/DEV/archivelog/2024_03_02/
                                                                    o1_mf_1_5_ly5xq1cg_.arc thread=1 sequence=5
  archived log file name=/u01/app/oracle/fast_recovery_area/dev/DEV/archivelog/2024_03_02/
                                                                    o1_mf_1_6_ly5y6lsl_.arc thread=1 sequence=6
  media recovery complete, elapsed time: 00:00:01
  Finished recover at 02-MAR-24

  database opened

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

  sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/home/oracle/backup/''

  sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/home/oracle/backup/''

  Performing export of tables...
    EXPDP> Starting "SYS"."TSPITR_EXP_dzvd_ebef":  
    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/TABLE
    EXPDP> . . exported "TESDB"."TES1"                              21.48 KB    1500 rows
    EXPDP> Master table "SYS"."TSPITR_EXP_dzvd_ebef" successfully loaded/unloaded
    EXPDP> ******************************************************************************
    EXPDP> Dump file set for SYS.TSPITR_EXP_dzvd_ebef is:
    EXPDP>   /home/oracle/backup/tspitr_dzvd_18771.dmp
    EXPDP> Job "SYS"."TSPITR_EXP_dzvd_ebef" successfully completed at Sat Mar 2 15:34:15 2024 elapsed 0 00:01:08
  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_dzvd_oCoh" successfully loaded/unloaded
    IMPDP> Starting "SYS"."TSPITR_IMP_dzvd_oCoh":  
    IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
    IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
    IMPDP> . . imported "TESDB"."TES1"                              21.48 KB    1500 rows
    IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
    IMPDP> Job "SYS"."TSPITR_IMP_dzvd_oCoh" successfully completed at Sat Mar 2 15:34:45 2024 elapsed 0 00:00:10
  Import completed


  Removing automatic instance
  Automatic instance removed
  auxiliary instance file /home/oracle/backup/DEV/datafile/o1_mf_temp_ly5y8b29_.tmp deleted
  auxiliary instance file /home/oracle/backup/DZVD_PITR_DEV/onlinelog/o1_mf_3_ly5yb9ch_.log deleted
  auxiliary instance file /home/oracle/backup/DZVD_PITR_DEV/onlinelog/o1_mf_2_ly5yb80z_.log deleted
  auxiliary instance file /home/oracle/backup/DZVD_PITR_DEV/onlinelog/o1_mf_1_ly5yb7tz_.log deleted
  auxiliary instance file /home/oracle/backup/DZVD_PITR_DEV/datafile/o1_mf_users_ly5yb3wz_.dbf deleted
  auxiliary instance file /home/oracle/backup/DEV/datafile/o1_mf_sysaux_ly5y7po8_.dbf deleted
  auxiliary instance file /home/oracle/backup/DEV/datafile/o1_mf_undotbs1_ly5y7pom_.dbf deleted
  auxiliary instance file /home/oracle/backup/DEV/datafile/o1_mf_system_ly5y7po2_.dbf deleted
  auxiliary instance file /home/oracle/backup/DEV/controlfile/o1_mf_ly5y7hl6_.ctl deleted
  auxiliary instance file tspitr_dzvd_18771.dmp deleted
  Finished recover at 02-MAR-24

  RMAN> exit


  Recovery Manager complete.
Step 8 : Table tes1 has been recovered
  [oracle@sdbt ~]$ sqlplus / as sysdba

  SQL*Plus: Release 12.2.0.1.0 Production on Sat Mar 2 15:40:52 2024

  Copyright (c) 1982, 2016, Oracle.  All rights reserved.
  Connected to:
  Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
  
  SQL> select count(*) from tesdb.tes1;

    COUNT(*)
  ----------
        1500


(RMAN Recovery - Hot Cloning)