Description:-
In this article we are going to see table recovery using RMAN backup.
Let’s start the Demo:-
Steps to recover the table using RMAN backup :-
Step 1:- User creation
SQL> create user hari identified by "oracle" default tablespace users temporary tablespace temp profile default account unlock;
User created.
Step 2:- Provide grant privileges and allocate quota for “hari” user
SQL> grant create session, create table to hari;
Grant succeeded.
SQL> alter user hari quota 500M on users;
User altered.
Step 3:- Table creation
SQL> conn hari/oracle
SQL> create table emp(id number);
Table created.
SQL> begin
for i in 1 .. 100000 loop
insert into emp values(i);
end loop;
end;
/
PL/SQL procedure successfully completed.
SQL> select count(*) from emp;
COUNT(*)
----------
100000
SQL> SELECT TO_CHAR (SYSDATE, 'MM-DD-YYYY HH24:MI:SS') "NOW" FROM DUAL;
NOW
---------------------
05-16-2019 02:21:27
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 /u01/ARC_BKP
Oldest online log sequence 1
Next log sequence to archive 3
Current log sequence 3
You can’t restore a table that hasn’t been backed up, even if it exists in current archive logs.
Take a full database backup
RMAN> backup database plus archivelog;
Starting backup at 16-MAY-19
current log archived
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=84 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=3 RECID=1 STAMP=1008270177
input archived log thread=1 sequence=8 RECID=2 STAMP=1008295179
input archived log thread=1 sequence=9 RECID=3 STAMP=1008377749
input archived log thread=1 sequence=10 RECID=4 STAMP=1008377864
input archived log thread=1 sequence=11 RECID=5 STAMP=1008377981
input archived log thread=1 sequence=12 RECID=6 STAMP=1008380832
channel ORA_DISK_1: starting piece 1 at 16-MAY-19
channel ORA_DISK_1: finished piece 1 at 16-MAY-19
piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/06u1ld2t_1_1 tag=TAG20190516T022429 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:03
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=8 STAMP=1008383068
channel ORA_DISK_1: starting piece 1 at 16-MAY-19
channel ORA_DISK_1: finished piece 1 at 16-MAY-19
piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/07u1ld30_1_1 tag=TAG20190516T022429 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
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=13 RECID=7 STAMP=1008382325
channel ORA_DISK_1: starting piece 1 at 16-MAY-19
channel ORA_DISK_1: finished piece 1 at 16-MAY-19
piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/08u1ld31_1_1 tag=TAG20190516T022429 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:03
Finished backup at 16-MAY-19
Starting backup at 16-MAY-19
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/DBWR/datafile/o1_mf_system_g91ppy2b_.dbf
input datafile file number=00003 name=/u01/app/oracle/oradata/DBWR/datafile/o1_mf_sysaux_g91pxgmq_.dbf
input datafile file number=00004 name=/u01/app/oracle/oradata/DBWR/datafile/o1_mf_undotbs1_g91q0521_.dbf
input datafile file number=00007 name=/u01/app/oracle/oradata/DBWR/datafile/o1_mf_users_g91q08bm_.dbf
channel ORA_DISK_1: starting piece 1 at 16-MAY-19
Step 4:- Ensure that database in ARCHIVELOG mode and take a whole database backupchannel ORA_DISK_1: finished piece 1 at 16-MAY-19
piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/09u1ld35_1_1 tag=TAG20190516T022437 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:01:28
Finished backup at 16-MAY-19
Starting backup at 16-MAY-19
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=2 RECID=9 STAMP=1008383167
channel ORA_DISK_1: starting piece 1 at 16-MAY-19
channel ORA_DISK_1: finished piece 1 at 16-MAY-19
piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/0au1ld5v_1_1 tag=TAG20190516T022607 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 16-MAY-19
Starting Control File and SPFILE Autobackup at 16-MAY-19
piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/c-1337475478-20190516-02 comment=NONE
Finished Control File and SPFILE Autobackup at 16-MAY-19
Step 5:- Drop the table
SQL> drop table hari.emp;
Table dropped.
SQL> select count(*) from hari.emp;
select count(*) from hari.emp
*
ERROR at line 1:
ORA-00942: table or view does not exist
Step 6:- Recover emp table
RMAN> recover table hari.emp until time "to_date('2019-05-16 02:21:27','yyyy-mm-dd:hh24:mi:ss')" auxiliary destination '/u01/ARC_BKP';
Starting recover at 16-MAY-19
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=75 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='bCxt'
initialization parameters used for automatic instance:
db_name=DBWR
db_unique_name=bCxt_pitr_DBWR
compatible=19.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/u01/app/oracle
_system_trig_enabled=FALSE
sga_target=1696M
processes=200
db_create_file_dest=/u01/ARC_BKP
log_archive_dest_1='location=/u01/ARC_BKP'
#No auxiliary parameter file used
starting up automatic instance DBWR
Oracle instance started
Total System Global Area 1778381832 bytes
Fixed Size 8897544 bytes
Variable Size 436207616 bytes
Database Buffers 1325400064 bytes
Redo Buffers 7876608 bytes
Automatic instance created
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2019-05-16 02:21:27','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 16-MAY-19
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=38 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/19.0.0/dbhome_1/dbs/c-1337475478-20190516-01
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/c-1337475478-20190516-01 tag=TAG20190516T021228
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:02
output file name=/u01/ARC_BKP/DBWR/controlfile/o1_mf_gfs181c5_.ctl
Finished restore at 16-MAY-19
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('2019-05-16 02:21:27','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 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 /u01/ARC_BKP/DBWR/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 16-MAY-19
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/ARC_BKP/DBWR/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /u01/ARC_BKP/DBWR/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /u01/ARC_BKP/DBWR/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19.0.0/dbhome_1/dbs/02u1l80c_1_1
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/02u1l80c_1_1 tag=TAG20190516T005748
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:01:17
Finished restore at 16-MAY-19
datafile 1 switched to datafile copy
input datafile copy RECID=4 STAMP=1008385328 file name=/u01/ARC_BKP/DBWR/datafile/o1_mf_system_gfs188yq_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=5 STAMP=1008385328 file name=/u01/ARC_BKP/DBWR/datafile/o1_mf_undotbs1_gfs18904_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=6 STAMP=1008385328 file name=/u01/ARC_BKP/DBWR/datafile/o1_mf_sysaux_gfs188yw_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2019-05-16 02:21:27','yyyy-mm-dd: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 16-MAY-19
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 11 is already on disk as file /u01/ARC_BKP/1_11_1003340442.dbf
archived log for thread 1 with sequence 1 is already on disk as file /u01/ARC_BKP/1_1_1008382323.dbf
archived log file name=/u01/ARC_BKP/1_11_1003340442.dbf thread=1 sequence=11
archived log file name=/u01/ARC_BKP/1_1_1008382323.dbf thread=1 sequence=1
media recovery complete, elapsed time: 00:00:09
Finished recover at 16-MAY-19
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 =
''/u01/ARC_BKP/DBWR/controlfile/o1_mf_gfs181c5_.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 1778381832 bytes
Fixed Size 8897544 bytes
Variable Size 436207616 bytes
Database Buffers 1325400064 bytes
Redo Buffers 7876608 bytes
sql statement: alter system set control_files = ''/u01/ARC_BKP/DBWR/controlfile/o1_mf_gfs181c5_.ctl'' comment= ''RMAN set'' scope=spfile
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 1778381832 bytes
Fixed Size 8897544 bytes
Variable Size 436207616 bytes
Database Buffers 1325400064 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('2019-05-16 02:21:27','yyyy-mm-dd: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 16-MAY-19
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=34 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 /u01/ARC_BKP/BCXT_PITR_DBWR/datafile/o1_mf_users_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/product/19.0.0/dbhome_1/dbs/02u1l80c_1_1
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/02u1l80c_1_1 tag=TAG20190516T005748
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:02
Finished restore at 16-MAY-19
datafile 7 switched to datafile copy
input datafile copy RECID=8 STAMP=1008385434 file name=/u01/ARC_BKP/BCXT_PITR_DBWR/datafile/o1_mf_users_gfs1g1cv_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2019-05-16 02:21:27','yyyy-mm-dd: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 16-MAY-19
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 11 is already on disk as file /u01/ARC_BKP/1_11_1003340442.dbf
archived log for thread 1 with sequence 1 is already on disk as file /u01/ARC_BKP/1_1_1008382323.dbf
archived log file name=/u01/ARC_BKP/1_11_1003340442.dbf thread=1 sequence=11
archived log file name=/u01/ARC_BKP/1_1_1008382323.dbf thread=1 sequence=1
media recovery complete, elapsed time: 00:00:02
Finished recover at 16-MAY-19
database opened
contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u01/ARC_BKP''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u01/ARC_BKP''";
}
executing Memory Script
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/ARC_BKP''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/ARC_BKP''
Performing export of tables...
EXPDP> Starting "SYS"."TSPITR_EXP_bCxt_cxwC":
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 "HARI"."EMP" 856.34 KB 100000 rows
EXPDP> Master table "SYS"."TSPITR_EXP_bCxt_cxwC" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_bCxt_cxwC is:
EXPDP> /u01/ARC_BKP/tspitr_bCxt_17369.dmp
EXPDP> Job "SYS"."TSPITR_EXP_bCxt_cxwC" successfully completed at Thu May 16 03:06:16 2019 elapsed 0 00:00:44
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_bCxt_wgam" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_bCxt_wgam":
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
IMPDP> . . imported "HARI"."EMP" 856.34 KB 100000 rows
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
IMPDP> Job "SYS"."TSPITR_IMP_bCxt_wgam" successfully completed at Thu May 16 03:06:48 2019 elapsed 0 00:00:11
Import completed
Removing automatic instance
Automatic instance removed
auxiliary instance file /u01/ARC_BKP/DBWR/datafile/o1_mf_temp_gfs1c8tp_.tmp deleted
auxiliary instance file /u01/ARC_BKP/BCXT_PITR_DBWR/onlinelog/o1_mf_3_gfs1gn78_.log deleted
auxiliary instance file /u01/ARC_BKP/BCXT_PITR_DBWR/onlinelog/o1_mf_2_gfs1g5qt_.log deleted
auxiliary instance file /u01/ARC_BKP/BCXT_PITR_DBWR/onlinelog/o1_mf_1_gfs1g5o4_.log deleted
auxiliary instance file /u01/ARC_BKP/BCXT_PITR_DBWR/datafile/o1_mf_users_gfs1g1cv_.dbf deleted
auxiliary instance file /u01/ARC_BKP/DBWR/datafile/o1_mf_sysaux_gfs188yw_.dbf deleted
auxiliary instance file /u01/ARC_BKP/DBWR/datafile/o1_mf_undotbs1_gfs18904_.dbf deleted
auxiliary instance file /u01/ARC_BKP/DBWR/datafile/o1_mf_system_gfs188yq_.dbf deleted
auxiliary instance file /u01/ARC_BKP/DBWR/controlfile/o1_mf_gfs181c5_.ctl deleted
auxiliary instance file tspitr_bCxt_17369.dmp deleted
Finished recover at 16-MAY-19
Step 7:- Check the table count
SQL> select count(*) from hari.emp;
COUNT(*)
---------
100000
Catch Me On:- Hariprasath Rajaram
Telegram:https://t.me/joinchat/I_f4DhGF_Zifr9YZvvMkRg
LinkedIn:https://www.linkedin.com/in/hari-prasath-aa65bb19/
Facebook:https://www.facebook.com/HariPrasathdba
FB Group:https://www.facebook.com/groups/894402327369506/
FB Page: https://www.facebook.com/dbahariprasath/?
Twitter: https://twitter.com/hariprasathdba