• Home
  • DBA Scripts
    • Oracle Scripts
    • SQL Server Scripts
  • Knowledge Base
    • Oracle Database
    • MS SQL Server
    • MongoDB
    • MariaDB
  • Troubleshoot
    • Oracle Database Issues
    • SQL Server Issues
  • Interview Questions
    • AWS Interview Questions
    • Oracle DBA Interview Questions
    • SQL Server Interview Questions
  • Courses
    • Oracle Database
    • Oracle DBA L1
    • Oracle DBA L2
    • Oracle DBA L3
  • Home
  • DBA Scripts
    • Oracle Scripts
    • SQL Server Scripts
  • Knowledge Base
    • Oracle Database
    • MS SQL Server
    • MongoDB
    • MariaDB
  • Troubleshoot
    • Oracle Database Issues
    • SQL Server Issues
  • Interview Questions
    • AWS Interview Questions
    • Oracle DBA Interview Questions
    • SQL Server Interview Questions
  • Courses
    • Oracle Database
    • Oracle DBA L1
    • Oracle DBA L2
    • Oracle DBA L3
home/Knowledge Base/Oracle Database/Oracle 18c Database/Table recovery using RMAN Backup – Oracle 18c
Popular Search:Oracle, SQL Server, MongoDB

Table recovery using RMAN Backup – Oracle 18c

173 views 0 September 12, 2019 admin

Description:

In this article we are going to see table recovery using RMAN backup.

Steps to recover the table using RMAN backup

Step 1:- User creation

SQL> create user dborg identified by "oracle" default tablespace users temporary tablespace temp profile default account unlock

User created.

Step 2:- Provide grant privileges and allocate quota for  “dborg” user

SQL> grant create session, create table to dborg ;

Grant succeeded.

SQL> alter user dborg quota 500M on users ;

User altered.

Step 3:- Table creation

SQL> conn dborg/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
-------------------
08-14-2018 21:53:42


Step 4:- Ensure that database in ARCHIVELOG mode and take a whole database backup

SQL> archive log list
Database log mode No Archive Mode
Automatic archival Disabled
Archive destination /u01/app/oracle/product/18.0.0/dbhome_1/dbs/arch
Oldest online log sequence 2
Current log sequence 4
SQL> shut immediate
Database closed.
Database dismounted.
ORACLE instance shut down.

SQL> startup mount
ORACLE instance started.

Total System Global Area 1660943808 bytes
Fixed Size 8658368 bytes
Variable Size 1056964608 bytes
Database Buffers 587202560 bytes
Redo Buffers 8118272 bytes
Database mounted.

SQL> alter database archivelog;

Database altered.

SQL> archive log list
Database log mode Archive Mode
Automatic archival Enabled
Archive destination /u01/app/oracle/product/18.0.0/dbhome_1/dbs/arch
Oldest online log sequence 2
Next log sequence to archive 4
Current log sequence 4


SQL> alter database open;

Database altered.

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 14-AUG-18
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=4 RECID=1 STAMP=984173730
input archived log thread=1 sequence=5 RECID=2 STAMP=984173864
input archived log thread=1 sequence=6 RECID=3 STAMP=984173913
input archived log thread=1 sequence=7 RECID=4 STAMP=984174371
input archived log thread=1 sequence=8 RECID=5 STAMP=984174523
channel ORA_DISK_1: starting piece 1 at 14-AUG-18
channel ORA_DISK_1: finished piece 1 at 14-AUG-18
piece handle=/u01/fra/PROD18C/backupset/2018_08_14/o1_mf_annnn_TAG20180814T214843_fq6073xg_.bkp tag=TAG20180814T214843 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:03
Finished backup at 14-AUG-18

Starting backup at 14-AUG-18
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/PROD18C/system01.dbf
input datafile file number=00003 name=/u01/app/oracle/oradata/PROD18C/sysaux01.dbf
input datafile file number=00004 name=/u01/app/oracle/oradata/PROD18C/undotbs01.dbf
input datafile file number=00007 name=/u01/app/oracle/oradata/PROD18C/users01.dbf
channel ORA_DISK_1: starting piece 1 at 14-AUG-18
channel ORA_DISK_1: finished piece 1 at 14-AUG-18
piece handle=/u01/fra/PROD18C/backupset/2018_08_14/o1_mf_nnndf_TAG20180814T214847_fq60774d_.bkp tag=TAG20180814T214847 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:45
Finished backup at 14-AUG-18

Starting backup at 14-AUG-18
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=9 RECID=6 STAMP=984174572
channel ORA_DISK_1: starting piece 1 at 14-AUG-18
channel ORA_DISK_1: finished piece 1 at 14-AUG-18
piece handle=/u01/fra/PROD18C/backupset/2018_08_14/o1_mf_annnn_TAG20180814T214932_fq608ndg_.bkp tag=TAG20180814T214932 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 14-AUG-18

Starting Control File and SPFILE Autobackup at 14-AUG-18
piece handle=/u01/fra/PROD18C/autobackup/2018_08_14/o1_mf_s_984174573_fq608owz_.bkp comment=NONE
Finished Control File and SPFILE Autobackup at 14-AUG-18

Step 5:- Drop the table

SQL> drop table dborg.emp;

Table dropped.

SQL> select * from dborg.emp;

no rows selected.

Step 6:- Recover  emp table

RMAN> recover table dborg.emp until time "to_date('2018-08-14 21:53:42','yyyy-mm-dd:hh24:mi:ss')" auxiliary destination '/u01/fra';

Starting recover at 14-AUG-18
using target database control file instead of recovery catalog
current log archived
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=72 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='sAyh'
initialization parameters used for automatic instance:
db_name=PROD18C
db_unique_name=sAyh_pitr_PROD18C
compatible=18.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/u01/app/oracle
_system_trig_enabled=FALSE
sga_target=1584M
processes=200
db_create_file_dest=/u01/fra
log_archive_dest_1='location=/u01/fra'
#No auxiliary parameter file used
starting up automatic instance PROD18C
Oracle instance started
Total System Global Area 1660943808 bytes
Fixed Size 8658368 bytes
Variable Size 419430400 bytes
Database Buffers 1224736768 bytes
Redo Buffers 8118272 bytes
Automatic instance created
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2018-08-14 21:53:42','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 14-AUG-18
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=8 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/fra/PROD18C/autobackup/2018_08_14/o1_mf_s_984174811_fq60j3or_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/fra/PROD18C/autobackup/2018_08_14/o1_mf_s_984174811_fq60j3or_.bkp tag=TAG20180814T215331
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/fra/PROD18C/controlfile/o1_mf_fq60txkl_.ctl
Finished restore at 14-AUG-18

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('2018-08-14 21:53:42','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/fra/PROD18C/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 14-AUG-18
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/fra/PROD18C/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /u01/fra/PROD18C/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /u01/fra/PROD18C/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/fra/PROD18C/backupset/2018_08_14/o1_mf_nnndf_TAG20180814T215243_fq60gmvn_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/fra/PROD18C/backupset/2018_08_14/o1_mf_nnndf_TAG20180814T215243_fq60gmvn_.bkp tag=TAG20180814T215243
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:01:17
Finished restore at 14-AUG-18
datafile 1 switched to datafile copy
input datafile copy RECID=4 STAMP=984175242 file name=/u01/fra/PROD18C/datafile/o1_mf_system_fq60v51s_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=5 STAMP=984175242 file name=/u01/fra/PROD18C/datafile/o1_mf_undotbs1_fq60v52y_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=6 STAMP=984175242 file name=/u01/fra/PROD18C/datafile/o1_mf_sysaux_fq60v52l_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2018-08-14 21:53:42','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 14-AUG-18
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 11 is already on disk as file /u01/fra/PROD18C/archivelog/2018_08_14/o1_mf_1_11_fq60j1vs_.arc
archived log for thread 1 with sequence 12 is already on disk as file /u01/fra/PROD18C/archivelog/2018_08_14/o1_mf_1_12_fq60t0xc_.arc
archived log file name=/u01/fra/PROD18C/archivelog/2018_08_14/o1_mf_1_11_fq60j1vs_.arc thread=1 sequence=11
archived log file name=/u01/fra/PROD18C/archivelog/2018_08_14/o1_mf_1_12_fq60t0xc_.arc thread=1 sequence=12
media recovery complete, elapsed time: 00:00:01
Finished recover at 14-AUG-18
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/fra/PROD18C/controlfile/o1_mf_fq60txkl_.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 1660943808 bytes
Fixed Size 8658368 bytes
Variable Size 419430400 bytes
Database Buffers 1224736768 bytes
Redo Buffers 8118272 bytes
sql statement: alter system set control_files = ''/u01/fra/PROD18C/controlfile/o1_mf_fq60txkl_.ctl'' comment= ''RMAN set'' scope=spfile
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 1660943808 bytes
Fixed Size 8658368 bytes
Variable Size 419430400 bytes
Database Buffers 1224736768 bytes
Redo Buffers 8118272 bytes
sql statement: alter database mount clone database
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2018-08-14 21:53:42','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 14-AUG-18
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/fra/SAYH_PITR_PROD18C/datafile/o1_mf_users_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/fra/PROD18C/backupset/2018_08_14/o1_mf_nnndf_TAG20180814T215243_fq60gmvn_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/fra/PROD18C/backupset/2018_08_14/o1_mf_nnndf_TAG20180814T215243_fq60gmvn_.bkp tag=TAG20180814T215243
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
Finished restore at 14-AUG-18
datafile 7 switched to datafile copy
input datafile copy RECID=8 STAMP=984175357 file name=/u01/fra/SAYH_PITR_PROD18C/datafile/o1_mf_users_fq6112n9_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2018-08-14 21:53:42','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 14-AUG-18
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 11 is already on disk as file /u01/fra/PROD18C/archivelog/2018_08_14/o1_mf_1_11_fq60j1vs_.arc
archived log for thread 1 with sequence 12 is already on disk as file /u01/fra/PROD18C/archivelog/2018_08_14/o1_mf_1_12_fq60t0xc_.arc
archived log file name=/u01/fra/PROD18C/archivelog/2018_08_14/o1_mf_1_11_fq60j1vs_.arc thread=1 sequence=11
archived log file name=/u01/fra/PROD18C/archivelog/2018_08_14/o1_mf_1_12_fq60t0xc_.arc thread=1 sequence=12
media recovery complete, elapsed time: 00:00:00
Finished recover at 14-AUG-18
database opened
contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u01/fra''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/u01/fra''";
}
executing Memory Script
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/fra''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/u01/fra''

Performing export of tables...
EXPDP> Starting "SYS"."TSPITR_EXP_sAyh_zwzh":
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 "DBORG"."EMP" 873.1 KB 100000 rows
EXPDP> Master table "SYS"."TSPITR_EXP_sAyh_zwzh" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_sAyh_zwzh is:
EXPDP> /u01/fra/tspitr_sAyh_75879.dmp
EXPDP> Job "SYS"."TSPITR_EXP_sAyh_zwzh" successfully completed at Tue Aug 14 22:06:43 2018 elapsed 0 00:02:52
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_sAyh_zBwj" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_sAyh_zBwj":
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
IMPDP> . . imported "DBORG"."EMP" 873.1 KB 100000 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_sAyh_zBwj" successfully completed at Tue Aug 14 22:07:30 2018 elapsed 0 00:00:35
Import completed

Removing automatic instance
Automatic instance removed
auxiliary instance file /u01/fra/PROD18C/datafile/o1_mf_temp_fq60xs6s_.tmp deleted
auxiliary instance file /u01/fra/SAYH_PITR_PROD18C/onlinelog/o1_mf_3_fq611jxw_.log deleted
auxiliary instance file /u01/fra/SAYH_PITR_PROD18C/onlinelog/o1_mf_2_fq6118dc_.log deleted
auxiliary instance file /u01/fra/SAYH_PITR_PROD18C/onlinelog/o1_mf_1_fq61189k_.log deleted
auxiliary instance file /u01/fra/SAYH_PITR_PROD18C/datafile/o1_mf_users_fq6112n9_.dbf deleted
auxiliary instance file /u01/fra/PROD18C/datafile/o1_mf_sysaux_fq60v52l_.dbf deleted
auxiliary instance file /u01/fra/PROD18C/datafile/o1_mf_undotbs1_fq60v52y_.dbf deleted
auxiliary instance file /u01/fra/PROD18C/datafile/o1_mf_system_fq60v51s_.dbf deleted
auxiliary instance file /u01/fra/PROD18C/controlfile/o1_mf_fq60txkl_.ctl deleted
auxiliary instance file tspitr_sAyh_75879.dmp deleted
Finished recover at 14-AUG-18

Step 7:- Check the table count

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

COUNT(*)
---------
100000

Was this helpful?

Yes  No
Related Articles
  • Backup & Restoring Databases on Oracle Cloud Service
  • dbaascli – Oracle Database Cloud Service
  • Oracle 18c New Initialization Parameters
Leave A Comment Cancel reply

Oracle 18c Database
  • Table recovery using RMAN Backup – Oracle 18c
  • Backup & Restoring Databases on Oracle Cloud Service
  • dbaascli – Oracle Database Cloud Service
  • Oracle 18c New Initialization Parameters
Popular Articles
  • Upgrade Oracle Database from 11.2.0.3 to 12.1.0.2
  • Upgrading MariaDB on Windows
  • Oracle DBA Basic Interview Questions Part A
  • Purging Oracle Sysaux Tablespace
  • Client – Server Architecture
KB Categories
  • Oracle Database
    • Oracle RAC
    • Oracle ASM
    • Oracle GoldenGate
    • Oracle Tuning
    • Oracle 11g Database
    • Oracle Database Upgrade
    • Oracle 12c Database
    • ALL KB Oracle
    • Oracle 18c Database
    • Oracle Standby Database
  • MongoDB
  • MS SQL Server
  • MySQL
  • Interview Questions
    • AWS Interview Questions
    • Oracle DBA Interview Questions
    • SQL Server Interview Questions
  • MariaDB
Database Organization

Database Organization (DB ORG) is knowledge base for DBA to learn and execute the fundamental of different databases under one website. DB ORG is a non-profit initiative. ORACLE, MS SQL Server, MongoDB, MariaDB, Couchbase

Join Our Community
  • KnowledgeBase
  • Documentation
  • Troubleshoot
  • FAQ
Information Links
  • About DBOrg
  • Licenses
  • Terms
  • Privacy Policy
Contact Us
    DB ORG - Database Administration,
    Knowledge Base for DBA
    Mail: support@databaseorg.com
    WhatsApp: (+91) 9306440957
    Monday to Friday: EST - 11:30 AM to 06:30 PM (IST - 9:00 PM to 4:00 AM)
  • © 2023 Database Organization - DB ORG. All Rights Reserved.

Popular Search:Oracle, SQL Server, MongoDB

WhatsApp DB Org