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 2023Version 19.14.0.0.0Copyright (c) 1982, 2021, Oracle. All rights reserved.Connected to:Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - ProductionVersion 19.14.0.0.0SQL> show pdbsCON_ID CON_NAME OPEN MODE RESTRICTED---------- ------------------------------ ---------- ----------2 PDB$SEED READ ONLY NO3 ORCLPDB READ WRITE NOSQL> archive log list;Database log mode No Archive ModeAutomatic archival DisabledArchive destination /u01/app/oracle/product/19c/dbhome_1/dbs/archOldest online log sequence 15Current log sequence 17SQL> 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 bytesFixed Size 9144936 bytesVariable Size 889192448 bytesDatabase Buffers 4043309056 bytesRedo Buffers 7630848 bytesDatabase mounted.SQL> alter database archivelog;Database altered.SQL> alter database open;Database altered.SQL> archive log list;Database log mode Archive ModeAutomatic archival EnabledArchive destination /u01/app/oracle/product/19c/dbhome_1/dbs/archOldest online log sequence 15Next log sequence to archive 17Current 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 2023Version 19.14.0.0.0Copyright (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 catalogReport of database schema for database with db_unique_name ORCLList of Permanent Datafiles===========================File Size(MB) Tablespace RB segs Datafile Name---- -------- -------------------- ------- ------------------------1 1000 SYSTEM YES /u01/app/oracle/oradata/ORCL/system01.dbf3 830 SYSAUX NO /u01/app/oracle/oradata/ORCL/sysaux01.dbf4 865 UNDOTBS1 YES /u01/app/oracle/oradata/ORCL/undotbs01.dbf5 360 PDB$SEED:SYSTEM NO /u01/app/oracle/oradata/ORCL/pdbseed/system01.dbf6 440 PDB$SEED:SYSAUX NO /u01/app/oracle/oradata/ORCL/pdbseed/sysaux01.dbf7 5 USERS NO /u01/app/oracle/oradata/ORCL/users01.dbf8 200 PDB$SEED:UNDOTBS1 NO /u01/app/oracle/oradata/ORCL/pdbseed/undotbs01.dbf9 370 ORCLPDB:SYSTEM NO /u01/app/oracle/oradata/ORCL/orclpdb/system01.dbf10 500 ORCLPDB:SYSAUX NO /u01/app/oracle/oradata/ORCL/orclpdb/sysaux01.dbf11 200 ORCLPDB:UNDOTBS1 NO /u01/app/oracle/oradata/ORCL/orclpdb/undotbs01.dbf12 5 ORCLPDB:USERS NO /u01/app/oracle/oradata/ORCL/orclpdb/users01.dbfList of Temporary Files=======================File Size(MB) Tablespace Maxsize(MB) Tempfile Name---- -------- -------------------- ----------- --------------------1 98 TEMP 32767 /u01/app/oracle/oradata/ORCL/temp01.dbf2 89 PDB$SEED:TEMP 32767 /u01/app/oracle/oradata/ORCL/pdbseed/temp012023-06-09_08-53-10-571-AM.dbf3 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-23current log archivedallocated channel: ORA_DISK_1channel ORA_DISK_1: SID=271 device type=DISKchannel ORA_DISK_1: starting archived log backup setchannel ORA_DISK_1: specifying archived log(s) in backup setinput archived log thread=1 sequence=17 RECID=1 STAMP=1139122744channel ORA_DISK_1: starting piece 1 at 10-JUN-23channel ORA_DISK_1: finished piece 1 at 10-JUN-23piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/011ub8ho_1_1_1 tag=TAG20230610T065904 comment=NONEchannel ORA_DISK_1: backup set complete, elapsed time: 00:00:01Finished backup at 10-JUN-23Starting backup at 10-JUN-23using channel ORA_DISK_1channel ORA_DISK_1: starting full datafile backup setchannel ORA_DISK_1: specifying datafile(s) in backup setinput datafile file number=00001 name=/u01/app/oracle/oradata/ORCL/system01.dbfinput datafile file number=00004 name=/u01/app/oracle/oradata/ORCL/undotbs01.dbfinput datafile file number=00003 name=/u01/app/oracle/oradata/ORCL/sysaux01.dbfinput datafile file number=00007 name=/u01/app/oracle/oradata/ORCL/users01.dbfchannel ORA_DISK_1: starting piece 1 at 10-JUN-23channel ORA_DISK_1: finished piece 1 at 10-JUN-23piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/021ub8hq_2_1_1 tag=TAG20230610T065906 comment=NONEchannel ORA_DISK_1: backup set complete, elapsed time: 00:00:35channel ORA_DISK_1: starting full datafile backup setchannel ORA_DISK_1: specifying datafile(s) in backup setinput datafile file number=00010 name=/u01/app/oracle/oradata/ORCL/orclpdb/sysaux01.dbfinput datafile file number=00009 name=/u01/app/oracle/oradata/ORCL/orclpdb/system01.dbfinput datafile file number=00011 name=/u01/app/oracle/oradata/ORCL/orclpdb/undotbs01.dbfinput datafile file number=00012 name=/u01/app/oracle/oradata/ORCL/orclpdb/users01.dbfchannel ORA_DISK_1: starting piece 1 at 10-JUN-23channel ORA_DISK_1: finished piece 1 at 10-JUN-23piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/031ub8it_3_1_1 tag=TAG20230610T065906 comment=NONEchannel ORA_DISK_1: backup set complete, elapsed time: 00:00:15channel ORA_DISK_1: starting full datafile backup setchannel ORA_DISK_1: specifying datafile(s) in backup setinput datafile file number=00006 name=/u01/app/oracle/oradata/ORCL/pdbseed/sysaux01.dbfinput datafile file number=00005 name=/u01/app/oracle/oradata/ORCL/pdbseed/system01.dbfinput datafile file number=00008 name=/u01/app/oracle/oradata/ORCL/pdbseed/undotbs01.dbfchannel ORA_DISK_1: starting piece 1 at 10-JUN-23channel ORA_DISK_1: finished piece 1 at 10-JUN-23piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/041ub8jc_4_1_1 tag=TAG20230610T065906 comment=NONEchannel ORA_DISK_1: backup set complete, elapsed time: 00:00:15Finished backup at 10-JUN-23Starting backup at 10-JUN-23current log archivedusing channel ORA_DISK_1channel ORA_DISK_1: starting archived log backup setchannel ORA_DISK_1: specifying archived log(s) in backup setinput archived log thread=1 sequence=18 RECID=2 STAMP=1139122811channel ORA_DISK_1: starting piece 1 at 10-JUN-23channel ORA_DISK_1: finished piece 1 at 10-JUN-23piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/051ub8js_5_1_1 tag=TAG20230610T070012 comment=NONEchannel ORA_DISK_1: backup set complete, elapsed time: 00:00:01Finished backup at 10-JUN-23Starting Control File and SPFILE Autobackup at 10-JUN-23piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/c-1666823206-20230610-00 comment=NONEFinished 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 2023Version 19.14.0.0.0Copyright (c) 1982, 2021, Oracle. All rights reserved.Connected to:Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - ProductionVersion 19.14.0.0.0SQL> show pdbsCON_ID CON_NAME OPEN MODE RESTRICTED---------- ------------------------------ ---------- ----------2 PDB$SEED READ ONLY NO3 ORCLPDB READ WRITE NOSQL> 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@orclpdbSQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 07:09:45 2023Version 19.14.0.0.0Copyright (c) 1982, 2021, Oracle. All rights reserved.Connected to:Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - ProductionVersion 19.14.0.0.0SQL> show userUSER is "HIMANSHU"SQL> create table emp(name varchar2(20));Table created.SQL> BEGINFOR k IN 1..1100 LOOPInsert into emp values('dummyuser');END LOOP;END;/ 2 3 4 5 6PL/SQL procedure successfully completed.SQL> commit;Commit complete.SQL> select count(*) from himanshu.emp;COUNT(*)----------1100
5) Check the current sequence number
archive log listDatabase log mode Archive ModeAutomatic archival EnabledArchive destination /u01/app/oracle/product/19c/dbhome_1/dbs/archOldest online log sequence 20Next log sequence to archive 22Current log sequence 22
rman target /RMAN> backup archivelog all;Starting backup at 10-JUN-23current log archivedusing channel ORA_DISK_1channel ORA_DISK_1: starting archived log backup setchannel ORA_DISK_1: specifying archived log(s) in backup setinput archived log thread=1 sequence=17 RECID=1 STAMP=1139122744input archived log thread=1 sequence=18 RECID=2 STAMP=1139122811input archived log thread=1 sequence=19 RECID=3 STAMP=1139125421input archived log thread=1 sequence=20 RECID=4 STAMP=1139125489input archived log thread=1 sequence=21 RECID=5 STAMP=1139125529channel ORA_DISK_1: starting piece 1 at 10-JUN-23channel ORA_DISK_1: finished piece 1 at 10-JUN-23piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/0d1ubb8p_13_1_1 tag=TAG20230610T074529 comment=NONEchannel ORA_DISK_1: backup set complete, elapsed time: 00:00:01Finished backup at 10-JUN-23Starting Control File and SPFILE Autobackup at 10-JUN-23piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/c-1666823206-20230610-02 comment=NONEFinished 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@orclpdbSQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 07:45:58 2023Version 19.14.0.0.0Copyright (c) 1982, 2021, Oracle. All rights reserved.Last Successful login time: Sat Jun 10 2023 07:42:16 +00:00Connected to:Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - ProductionVersion 19.14.0.0.0SQL> 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 2023Version 19.14.0.0.0Copyright (c) 1982, 2021, Oracle. All rights reserved.Connected to:Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - ProductionVersion 19.14.0.0.0SQL> 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:4121 2822244 07:44:4922 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 2023Version 19.14.0.0.0Copyright (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-23using target database control file instead of recovery catalogallocated channel: ORA_DISK_1channel ORA_DISK_1: SID=397 device type=DISKRMAN-05026: warning: presuming following set of tablespaces applies to specified point-in-timeList of tablespaces expected to have UNDO segmentsTablespace SYSTEMTablespace ORCLPDB:SYSTEMTablespace UNDOTBS1Tablespace ORCLPDB:UNDOTBS1Creating automatic instance, with SID='oxyo'initialization parameters used for automatic instance:db_name=ORCLdb_unique_name=oxyo_pitr_ORCLPDB_ORCLcompatible=19.0.0db_block_size=8192db_files=200diagnostic_dest=/u01/app/oracle_system_trig_enabled=FALSEsga_target=4720Mprocesses=200db_create_file_dest=/u01/app/backuplog_archive_dest_1='location=/u01/app/backup'enable_pluggable_database=true_clone_one_pdb_recovery=true#No auxiliary parameter file usedstarting up automatic instance ORCLOracle instance startedTotal System Global Area 4949277048 bytesFixed Size 9144696 bytesVariable Size 889192448 bytesDatabase Buffers 4043309056 bytesRedo Buffers 7630848 bytesAutomatic instance createdcontents of Memory Script:{# set requested point in timeset until time "to_date('2023-06-10 07:44:49','yyyy-mm-dd:hh24:mi:ss')";# restore the controlfilerestore clone controlfile;# mount the controlfilesql clone 'alter database mount clone database';# archive current online logsql 'alter system archive log current';}executing Memory Scriptexecuting command: SET until clauseStarting restore at 10-JUN-23allocated channel: ORA_AUX_DISK_1channel ORA_AUX_DISK_1: SID=9 device type=DISKchannel ORA_AUX_DISK_1: starting datafile backup set restorechannel ORA_AUX_DISK_1: restoring control filechannel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19c/dbhome_1/dbs/c-1666823206-20230610-00channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/c-1666823206-20230610-00 tag=TAG20230610T070013channel ORA_AUX_DISK_1: restored backup piece 1channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01output file name=/u01/app/backup/ORCL/controlfile/o1_mf_l88bvdn1_.ctlFinished restore at 10-JUN-23sql statement: alter database mount clone databasesql statement: alter system archive log currentcontents of Memory Script:{# set requested point in timeset until time "to_date('2023-06-10 07:44:49','yyyy-mm-dd:hh24:mi:ss')";# set destinations for recovery set and auxiliary set datafilesset 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 tempfilesswitch clone tempfile all;# restore the tablespaces in the recovery set and the auxiliary setrestore clone datafile 1, 9, 4, 11, 3, 10;switch clone datafile all;}executing Memory Scriptexecuting command: SET until clauseexecuting command: SET NEWNAMEexecuting command: SET NEWNAMEexecuting command: SET NEWNAMEexecuting command: SET NEWNAMEexecuting command: SET NEWNAMEexecuting command: SET NEWNAMEexecuting command: SET NEWNAMEexecuting command: SET NEWNAMErenamed tempfile 1 to /u01/app/backup/ORCL/datafile/o1_mf_temp_%u_.tmp in control filerenamed tempfile 3 to /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_temp_%u_.tmp in control fileStarting restore at 10-JUN-23using channel ORA_AUX_DISK_1channel ORA_AUX_DISK_1: starting datafile backup set restorechannel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup setchannel ORA_AUX_DISK_1: restoring datafile 00001 to /u01/app/backup/ORCL/datafile/o1_mf_system_%u_.dbfchannel ORA_AUX_DISK_1: restoring datafile 00004 to /u01/app/backup/ORCL/datafile/o1_mf_undotbs1_%u_.dbfchannel ORA_AUX_DISK_1: restoring datafile 00003 to /u01/app/backup/ORCL/datafile/o1_mf_sysaux_%u_.dbfchannel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19c/dbhome_1/dbs/081ubb5g_8_1_1channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/081ubb5g_8_1_1 tag=TAG20230610T074343channel ORA_AUX_DISK_1: restored backup piece 1channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:35channel ORA_AUX_DISK_1: starting datafile backup set restorechannel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup setchannel ORA_AUX_DISK_1: restoring datafile 00009 to /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_system_%u_.dbfchannel ORA_AUX_DISK_1: restoring datafile 00011 to /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_undotbs1_%u_.dbfchannel ORA_AUX_DISK_1: restoring datafile 00010 to /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_sysaux_%u_.dbfchannel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19c/dbhome_1/dbs/091ubb6j_9_1_1channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/091ubb6j_9_1_1 tag=TAG20230610T074343channel ORA_AUX_DISK_1: restored backup piece 1channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:25Finished restore at 10-JUN-23datafile 1 switched to datafile copyinput datafile copy RECID=10 STAMP=1139125935 file name=/u01/app/backup/ORCL/datafile/o1_mf_system_l88bvm9w_.dbfdatafile 9 switched to datafile copyinput datafile copy RECID=11 STAMP=1139125935 file name=/u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_system_l88bwxw6_.dbfdatafile 4 switched to datafile copyinput datafile copy RECID=12 STAMP=1139125935 file name=/u01/app/backup/ORCL/datafile/o1_mf_undotbs1_l88bvmb2_.dbfdatafile 11 switched to datafile copyinput datafile copy RECID=13 STAMP=1139125935 file name=/u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_undotbs1_l88bx3qp_.dbfdatafile 3 switched to datafile copyinput datafile copy RECID=14 STAMP=1139125935 file name=/u01/app/backup/ORCL/datafile/o1_mf_sysaux_l88bvmb8_.dbfdatafile 10 switched to datafile copyinput datafile copy RECID=15 STAMP=1139125935 file name=/u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_sysaux_l88bwpd6_.dbfcontents of Memory Script:{# set requested point in timeset until time "to_date('2023-06-10 07:44:49','yyyy-mm-dd:hh24:mi:ss')";# online the datafiles restored or switchedsql clone "alter database datafile 1 online";sql clone 'ORCLPDB' "alter database datafile9 online";sql clone "alter database datafile 4 online";sql clone 'ORCLPDB' "alter database datafile11 online";sql clone "alter database datafile 3 online";sql clone 'ORCLPDB' "alter database datafile10 online";# recover and open database read onlyrecover clone database tablespace "SYSTEM", "ORCLPDB":"SYSTEM", "UNDOTBS1", "ORCLPDB":"UNDOTBS1", "SYSAUX", "ORCLPDB":"SYSAUX";sql clone 'alter database open read only';}executing Memory Scriptexecuting command: SET until clausesql statement: alter database datafile 1 onlinesql statement: alter database datafile 9 onlinesql statement: alter database datafile 4 onlinesql statement: alter database datafile 11 onlinesql statement: alter database datafile 3 onlinesql statement: alter database datafile 10 onlineStarting recover at 10-JUN-23using channel ORA_AUX_DISK_1starting media recoveryarchived 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.dbfarchived 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.dbfarchived log file name=/u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_19_1139042473.dbf thread=1 sequence=19archived log file name=/u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_20_1139042473.dbf thread=1 sequence=20media recovery complete, elapsed time: 00:00:01Finished recover at 10-JUN-23sql statement: alter database open read onlycontents of Memory Script:{sql clone 'alter pluggable database ORCLPDB open read only';}executing Memory Scriptsql statement: alter pluggable database ORCLPDB open read onlycontents 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 databasesql clone 'alter database mount clone database';}executing Memory Scriptsql statement: create spfile from memorydatabase closeddatabase dismountedOracle instance shut downconnected to auxiliary database (not started)Oracle instance startedTotal System Global Area 4949277048 bytesFixed Size 9144696 bytesVariable Size 889192448 bytesDatabase Buffers 4043309056 bytesRedo Buffers 7630848 bytessql statement: alter system set control_files = ''/u01/app/backup/ORCL/controlfile/o1_mf_l88bvdn1_.ctl'' comment= ''RMAN set'' scope=spfileOracle instance shut downconnected to auxiliary database (not started)Oracle instance startedTotal System Global Area 4949277048 bytesFixed Size 9144696 bytesVariable Size 889192448 bytesDatabase Buffers 4043309056 bytesRedo Buffers 7630848 bytessql statement: alter database mount clone databasecontents of Memory Script:{# set requested point in timeset until time "to_date('2023-06-10 07:44:49','yyyy-mm-dd:hh24:mi:ss')";# set destinations for recovery set and auxiliary set datafilesset newname for datafile 12 to new;# restore the tablespaces in the recovery set and the auxiliary setrestore clone datafile 12;switch clone datafile all;}executing Memory Scriptexecuting command: SET until clauseexecuting command: SET NEWNAMEStarting restore at 10-JUN-23allocated channel: ORA_AUX_DISK_1channel ORA_AUX_DISK_1: SID=91 device type=DISKchannel ORA_AUX_DISK_1: starting datafile backup set restorechannel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup setchannel ORA_AUX_DISK_1: restoring datafile 00012 to /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_users_%u_.dbfchannel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19c/dbhome_1/dbs/091ubb6j_9_1_1channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19c/dbhome_1/dbs/091ubb6j_9_1_1 tag=TAG20230610T074343channel ORA_AUX_DISK_1: restored backup piece 1channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01Finished restore at 10-JUN-23datafile 12 switched to datafile copyinput datafile copy RECID=17 STAMP=1139125991 file name=/u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_users_l88bz6qw_.dbfcontents of Memory Script:{# set requested point in timeset until time "to_date('2023-06-10 07:44:49','yyyy-mm-dd:hh24:mi:ss')";# online the datafiles restored or switchedsql clone 'ORCLPDB' "alter database datafile12 online";# recover and open resetlogsrecover clone database tablespace "ORCLPDB":"USERS", "SYSTEM", "ORCLPDB":"SYSTEM", "UNDOTBS1", "ORCLPDB":"UNDOTBS1", "SYSAUX", "ORCLPDB":"SYSAUX" delete archivelog;alter clone database open resetlogs;}executing Memory Scriptexecuting command: SET until clausesql statement: alter database datafile 12 onlineStarting recover at 10-JUN-23using channel ORA_AUX_DISK_1starting media recoveryarchived 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.dbfarchived log file name=/u01/app/oracle/product/19c/dbhome_1/dbs/arch/1_20_1139042473.dbf thread=1 sequence=20media recovery complete, elapsed time: 00:00:00Finished recover at 10-JUN-23database openedcontents of Memory Script:{sql clone 'alter pluggable database ORCLPDB open';}executing Memory Scriptsql statement: alter pluggable database ORCLPDB opencontents of Memory Script:{# create directory for datapump importsql 'ORCLPDB' "create or replace directoryTSPITR_DIROBJ_DPDIR as ''/u01/app/backup''";# create directory for datapump exportsql clone 'ORCLPDB' "create or replace directoryTSPITR_DIROBJ_DPDIR as ''/u01/app/backup''";}executing Memory Scriptsql 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_DATAEXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICSEXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKEREXPDP> Processing object type TABLE_EXPORT/TABLE/TABLEEXPDP> . . exported "HIMANSHU"."EMP" 20.08 KB 1100 rowsEXPDP> Master table "SYS"."TSPITR_EXP_oxyo_tBbD" successfully loaded/unloadedEXPDP> ******************************************************************************EXPDP> Dump file set for SYS.TSPITR_EXP_oxyo_tBbD is:EXPDP> /u01/app/backup/tspitr_oxyo_62212.dmpEXPDP> Job "SYS"."TSPITR_EXP_oxyo_tBbD" successfully completed at Sat Jun 10 07:53:56 2023 elapsed 0 00:00:26Export completedcontents of Memory Script:{# shutdown clone before importshutdown clone abort}executing Memory ScriptOracle instance shut downPerforming import of tables...IMPDP> Master table "SYS"."TSPITR_IMP_oxyo_athq" successfully loaded/unloadedIMPDP> Starting "SYS"."TSPITR_IMP_oxyo_athq":IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLEIMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATAIMPDP> . . imported "HIMANSHU"."EMP_RESTORE" 20.08 KB 1100 rowsIMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICSIMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKERIMPDP> Job "SYS"."TSPITR_IMP_oxyo_athq" successfully completed at Sat Jun 10 07:54:27 2023 elapsed 0 00:00:23Import completedRemoving automatic instanceAutomatic instance removedauxiliary instance file /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_temp_l88bxnd5_.tmp deletedauxiliary instance file /u01/app/backup/ORCL/datafile/o1_mf_temp_l88bxlg4_.tmp deletedauxiliary instance file /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/onlinelog/o1_mf_3_l88bzb4c_.log deletedauxiliary instance file /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/onlinelog/o1_mf_2_l88bzb3y_.log deletedauxiliary instance file /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/onlinelog/o1_mf_1_l88bzb3k_.log deletedauxiliary instance file /u01/app/backup/OXYO_PITR_ORCLPDB_ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_users_l88bz6qw_.dbf deletedauxiliary instance file /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_sysaux_l88bwpd6_.dbf deletedauxiliary instance file /u01/app/backup/ORCL/datafile/o1_mf_sysaux_l88bvmb8_.dbf deletedauxiliary instance file /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_undotbs1_l88bx3qp_.dbf deletedauxiliary instance file /u01/app/backup/ORCL/datafile/o1_mf_undotbs1_l88bvmb2_.dbf deletedauxiliary instance file /u01/app/backup/ORCL/FDAFACE81836315CE055000017019382/datafile/o1_mf_system_l88bwxw6_.dbf deletedauxiliary instance file /u01/app/backup/ORCL/datafile/o1_mf_system_l88bvm9w_.dbf deletedauxiliary instance file /u01/app/backup/ORCL/controlfile/o1_mf_l88bvdn1_.ctl deletedauxiliary instance file tspitr_oxyo_62212.dmp deletedFinished 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@orclpdbSQL*Plus: Release 19.0.0.0.0 - Production on Sat Jun 10 07:58:51 2023Version 19.14.0.0.0Copyright (c) 1982, 2021, Oracle. All rights reserved.Last Successful login time: Sat Jun 10 2023 07:45:58 +00:00Connected to:Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - ProductionVersion 19.14.0.0.0SQL> select count(*) from emp;COUNT(*)----------0SQL> select count(*) from EMP_RESTORE;COUNT(*)----------1100SQL> insert into emp select * from EMP_RESTORE;1100 rows created.SQL> commit;Commit complete.SQL> select count(*) from emp;COUNT(*)----------1100
Post a Comment
Post a Comment