As Oracle Data Guard came up with many advantages, One of its benefits is we can offload backup to Physical Standby Database.
We need to user Recover Catalog to offload backup to the standby database.
We will offload backup to the physical standby database in 3 stages and then we will test that backup by restoring it to another server.
- Creating Recovery Catalog
- Registering database in the recovery catalog.
- Taking the backup using Physical Standby.
- Restoring a backup to test.
Creating Recovery Catalog :
Step 1: Checking details of the database to be used for recovery catalog.
SQL> select name,open_mode from v$database; NAME OPEN_MODE --------- -------------------- DEMO READ WRITE
Step 2: Create tablespace in recovery catalog :
SQL> create tablespace ctl datafile '/u01/oracle/oradata/demo/ctl.dbf' size 200m; Tablespace created.
Step 3: Create the user to be used as recovery catalog owner :
SQL> create user ctl_db identified by ctl_db default tablespace ctl quota unlimited on ctl; User created.
Step 4: grant recovery_catalog_owner grant to a user.
SQL> grant recovery_catalog_owner to ctl_db; Grant succeeded.
Step 5: Add TNS entry of primary database and standby database in the server where recovery catalog database resides.
testdb = (DESCRIPTION = #(ADDRESS = (PROTOCOL = TCP)(HOST = localhost)(PORT = 1522)) (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.1.16)(PORT = 1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = testdb) ) ) std_testdb = (DESCRIPTION = #(ADDRESS = (PROTOCOL = TCP)(HOST = localhost)(PORT = 1522)) (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.1.10)(PORT = 1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = testdb) ) )
Step 6: Connect RMAN with target and catalog clause. target clause contains the primary database and catalog clause contains the catalog database
[oracle@localhost admin]$ rman target sys/oracle@testdb catalog ctl_db/ctl_db@demo Recovery Manager: Release 11.2.0.4.0 - Production on Wed May 23 23:39:58 2018 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: TESTDB (DBID=2756866105) connected to recovery catalog database
Step 7: Apply to create catalog command of RMAN to create recovery catalog.
RMAN> create catalog; recovery catalog created
In this stage recovery catalog is created, now we need to register the primary database.
Step 8: Register the primary database in the recovery catalog
RMAN> register database; database registered in recovery catalog starting full resync of recovery catalog full resync complete
Step 9: We can use report schema recovery catalog command to check the physical structure of the database.
RMAN> report schema; Report of database schema for database with db_unique_name TESTDB List of Permanent Datafiles =========================== File Size(MB) Tablespace RB segs Datafile Name ---- -------- -------------------- ------- ------------------------ 1 740 SYSTEM YES /u01/oracle/oradata/testdb/system01.dbf 2 540 SYSAUX NO /u01/oracle/oradata/testdb/sysaux01.dbf 3 50 UNDOTBS1 YES /u01/oracle/oradata/testdb/undotbs01.dbf 4 5 USERS NO /u01/oracle/oradata/testdb/users01.dbf List of Temporary Files ======================= File Size(MB) Tablespace Maxsize(MB) Tempfile Name ---- -------- -------------------- ----------- -------------------- 1 20 TEMP 32767 /u01/oracle/oradata/testdb/temp01.dbf
Step 10: List db_unique_name of database.
RMAN> list db_unique_name of database; List of Databases DB Key DB Name DB ID Database Role Db_unique_name ------- ------- ----------------- --------------- ------------------ 1 TESTDB 2756866105 PRIMARY TESTDB
Step 11: Configure the standby database to the recovery catalog.
RMAN> configure db_unique_name 'std_testdb' connect identifier 'std_testdb'; new RMAN configuration parameters: CONFIGURE DB_UNIQUE_NAME 'std_testdb' CONNECT IDENTIFIER 'std_testdb'; new RMAN configuration parameters are successfully stored starting full resync of recovery catalog full resync complete
Step 12: Now again check the database using list db_unique_name of database command.
RMAN> list db_unique_name of database; List of Databases DB Key DB Name DB ID Database Role Db_unique_name ------- ------- ----------------- --------------- ------------------ 1 TESTDB 2756866105 PRIMARY TESTDB 1 TESTDB 2756866105 STANDBY STD_TESTDB RMAN>
Our recovery catalog is ready in this stage. Now we will configure parameters and will take backup
Step 1: Configure controlfile autobackup on.
RMAN> configure controlfile autobackup on; new RMAN configuration parameters: CONFIGURE CONTROLFILE AUTOBACKUP ON; new RMAN configuration parameters are successfully stored starting full resync of recovery catalog full resync complete
Step 2: Now connect to the physical standby database as the target and connect to the catalog and take incremental level 0 or full backup
[oracle@localhost admin]$ rman target / catalog ctl_db/ctl_db@catalog Recovery Manager: Release 11.2.0.4.0 - Production on Thu May 24 00:44:29 2018 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: TESTDB (DBID=2756866105) connected to recovery catalog database RMAN> list db_unique_name of database; List of Databases DB Key DB Name DB ID Database Role Db_unique_name ------- ------- ----------------- --------------- ------------------ 1 TESTDB 2756866105 PRIMARY TESTDB 1 TESTDB 2756866105 STANDBY STD_TESTDB RMAN> backup incremental level 0 database; Starting backup at 24-MAY-18 allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=92 device type=DISK channel ORA_DISK_1: starting incremental level 0 datafile backup set channel ORA_DISK_1: specifying datafile(s) in backup set input datafile file number=00001 name=/u01/oracle/oradata/testdb/system01.dbf input datafile file number=00002 name=/u01/oracle/oradata/testdb/sysaux01.dbf input datafile file number=00003 name=/u01/oracle/oradata/testdb/undotbs01.dbf input datafile file number=00004 name=/u01/oracle/oradata/testdb/users01.dbf channel ORA_DISK_1: starting piece 1 at 24-MAY-18 channel ORA_DISK_1: finished piece 1 at 24-MAY-18 piece handle=/u01/oracle/fast_recovery_area/STD_TESTDB/backupset/2018_05_24/o1_mf_nnnd0_TAG20180524T004516_fjchg6bx_.bkp tag=TAG20180524T004516 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:01:05 Finished backup at 24-MAY-18 Starting Control File and SPFILE Autobackup at 24-MAY-18 piece handle=/u01/oracle/fast_recovery_area/STD_TESTDB/autobackup/2018_05_24/o1_mf_s_976315842_fjchjbqx_.bkp comment=NONE Finished Control File and SPFILE Autobackup at 24-MAY-18 RMAN>
Now we have successfully taken backup from standby database lets transfer it test server and test it.
Step 1: Transfer backup using rsync
[oracle@localhost fast_recovery_area]$ rsync -azvrh --progress STD_TESTDB/* 192.168.1.15:/u01/oracle/fast_recovery_area/STD_TESTDB/ oracle@192.168.1.15's password: sending incremental file list autobackup/ autobackup/2018_05_24/ autobackup/2018_05_24/o1_mf_s_976315842_fjchjbqx_.bkp 10.13M 100% 22.03MB/s 0:00:00 (xfer#1, to-check=2/7) backupset/ backupset/2018_05_24/ backupset/2018_05_24/o1_mf_nnnd0_TAG20180524T004516_fjchg6bx_.bkp 1.11G 100% 5.40MB/s 0:03:16 (xfer#2, to-check=0/7) onlinelog/ sent 265.03M bytes received 70 bytes 1.32M bytes/sec total size is 1.12G speedup is 4.23 [oracle@localhost fast_recovery_area]$
Step 2 : Create necessary directories on the test server so we can restore primary database backup here.
[oracle@localhost oracle]$ mkdir -p /u01/oracle/admin/testdb/adump [oracle@localhost oracle]$ mkdir -p /u01/arc/testdb/standbylog [oracle@localhost oracle]$ mkdir -p /u01/arc/testdb/stdby [oracle@localhost oracle]$ mkdir -p /u01/oracle/fast_recovery_area/testdb [oracle@localhost oracle]$ mkdir -p /u01/oracle/fast_recovery_area/STD_TESTDB
Step 3 : Check backup is arrived or not
[oracle@localhost oracle]$ cd /u01/oracle/fast_recovery_area/STD_TESTDB/ [oracle@localhost STD_TESTDB]$ ll total 12 drwxr-x--- 3 oracle oinstall 4096 May 24 00:46 autobackup drwxr-x--- 3 oracle oinstall 4096 May 24 00:45 backupset drwxr-x--- 2 oracle oinstall 4096 Apr 18 22:54 onlinelog
Step 4 : Connect to RMAN and follow the restore process.
Start database in the nomount stage :
[oracle@localhost STD_TESTDB]$ export ORACLE_SID=testdb [oracle@localhost STD_TESTDB]$ rman target / Recovery Manager: Release 11.2.0.4.0 - Production on Thu May 24 00:51:35 2018 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database (not started) RMAN> startup nomount Oracle instance started Total System Global Area 417546240 bytes Fixed Size 2253824 bytes Variable Size 331353088 bytes Database Buffers 79691776 bytes Redo Buffers 4247552 bytes
Step 5 : Restore spfile
RMAN> restore spfile to pfile '/u01/oracle/product/11.2.0/db_1/dbs/inittestdb.ora' from autobackup; Starting restore at 24-MAY-18 using channel ORA_DISK_1 recovery area destination: /u01/oracle/fast_recovery_area database name (or database unique name) used for search: TESTDB channel ORA_DISK_1: AUTOBACKUP /u01/oracle/fast_recovery_area/TESTDB/autobackup/2018_03_26/o1_mf_s_971803194_fckqm2mh_.bkp found in the recovery area AUTOBACKUP search with format "%F" not attempted because DBID was not set channel ORA_DISK_1: restoring spfile from AUTOBACKUP /u01/oracle/fast_recovery_area/TESTDB/autobackup/2018_03_26/o1_mf_s_971803194_fckqm2mh_.bkp channel ORA_DISK_1: SPFILE restore from AUTOBACKUP complete Finished restore at 24-MAY-18
Step 6 : Restore controlfile
RMAN> restore controlfile from autobackup; Starting restore at 24-MAY-18 using channel ORA_DISK_1 recovery area destination: /u01/oracle/fast_recovery_area database name (or database unique name) used for search: TESTDB channel ORA_DISK_1: AUTOBACKUP /u01/oracle/fast_recovery_area/TESTDB/autobackup/2018_03_26/o1_mf_s_971803194_fckqm2mh_.bkp found in the recovery area AUTOBACKUP search with format "%F" not attempted because DBID was not set channel ORA_DISK_1: restoring control file from AUTOBACKUP /u01/oracle/fast_recovery_area/TESTDB/autobackup/2018_03_26/o1_mf_s_971803194_fckqm2mh_.bkp channel ORA_DISK_1: control file restore from AUTOBACKUP complete output file name=/u01/oracle/oradata/testdb/control01.ctl output file name=/u01/oracle/oradata/testdb/control02.ctl Finished restore at 24-MAY-18 RMAN>
Step 7 : Mount database
RMAN> alter database mount; database mounted released channel: ORA_DISK_1 RMAN>
Step 8 : Now let us first check in sql session mounted database role
SQL> select name,open_mode,database_role from v$database; NAME OPEN_MODE DATABASE_ROLE --------- -------------------- ---------------- TESTDB MOUNTED PRIMARY
We can see here database role is primary . So a backup taken from physical standby in data guard broker works fine to restore as a primary database.
Now, we can go further for the restoration process.
Step 9 : Restore database
RMAN> restore database; Starting restore at 24-MAY-18 Starting implicit crosscheck backup at 24-MAY-18 allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=19 device type=DISK Crosschecked 1 objects Finished implicit crosscheck backup at 24-MAY-18 Starting implicit crosscheck copy at 24-MAY-18 using channel ORA_DISK_1 Finished implicit crosscheck copy at 24-MAY-18 searching for all files in the recovery area cataloging files... cataloging done List of Cataloged Files ======================= File Name: /u01/oracle/fast_recovery_area/TESTDB/autobackup/2018_03_26/o1_mf_s_971803194_fckqm2mh_.bkp using channel ORA_DISK_1 channel ORA_DISK_1: starting datafile backup set restore channel ORA_DISK_1: specifying datafile(s) to restore from backup set channel ORA_DISK_1: restoring datafile 00001 to /u01/oracle/oradata/testdb/system01.dbf channel ORA_DISK_1: restoring datafile 00002 to /u01/oracle/oradata/testdb/sysaux01.dbf channel ORA_DISK_1: restoring datafile 00003 to /u01/oracle/oradata/testdb/undotbs01.dbf channel ORA_DISK_1: restoring datafile 00004 to /u01/oracle/oradata/testdb/users01.dbf channel ORA_DISK_1: reading from backup piece /u01/oracle/fast_recovery_area/TESTDB/backupset/2018_03_26/o1_mf_nnndf_TAG20180326T171817_fckqj1xr_.bkp channel ORA_DISK_1: piece handle=/u01/oracle/fast_recovery_area/TESTDB/backupset/2018_03_26/o1_mf_nnndf_TAG20180326T171817_fckqj1xr_.bkp tag=TAG20180326T171817 channel ORA_DISK_1: restored backup piece 1 channel ORA_DISK_1: restore complete, elapsed time: 00:00:55 Finished restore at 24-MAY-18 RMAN>
Step 10 : Recover database
RMAN> recover database; Starting recover at 24-MAY-18 using channel ORA_DISK_1 starting media recovery media recovery complete, elapsed time: 00:00:00 Finished recover at 24-MAY-18 RMAN>
Stay tuned for More articles on Oracle DataGuard
Thank you for giving your valuable time to read the above information.
If you want to be updated with all our articles send us the Invitation or Follow us:
Telegram Channel : https://t.me/helporacle
Skant Gupta’s LinkedIn: www.linkedin.com/in/skantali/
Joel Perez’s LinkedIn: Joel Perez’s Profile
LinkedIn Group: Oracle Cloud DBAAS
Facebook Page: OracleHelp