How to Setup Physical Standby Database using RMAN Backup Restore- Quick and Dirty way
Assumption:
It is assumed that you already have single instance database installed and configured and you want to setup physical standby database for this primary database to protect you data from disaster recovery etc.
Installation and configuration of a single instance database using ASM is explained in following posts
Here is the details of my Primary database for which I want to configure the Physical standby database.
Hosts and Databases Used in this Example | ||
DB_ROLE | PRIMARY | STANDBY |
HOST_NAME | test1 | test2 |
DB_UNIQUE_NAME | TST1TP | TST1TS |
DB_NAME | TST1T | TST1T |
Step1> Prepare your primary database to support physical standby database
- Put the database in Archivelog mode
SQL> alter system set log_archive_dest_1='location=/u01/dbatst1/stage/archive/';
System altered.
SQL> shut immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount;
ORACLE instance started.
Total System Global Area 2147483648 bytes
Fixed Size 8794848 bytes
Variable Size 1912605984 bytes
Database Buffers 218103808 bytes
Redo Buffers 7979008 bytes
Database mounted.
SQL> alter database archivelog;
Database altered.
SQL> alter database open;
Database altered.
SQL> archive log list;
Database log mode Archive Mode
Automatic archival Enabled
Archive destination USE_DB_RECOVERY_FILE_DEST
Oldest online log sequence 4146
Next log sequence to archive 4148
Current log sequence 4148
Check out How to Enable Archive Log Mode in Oracle Database for more details
Check out How to Enable Archive Log Mode in Oracle Database for more details
- Disabling Active Data Guard
SQL> alter system set "_query_on_physical"=FALSE scope=spfile;
System altered.
SQL> startup force;
ORACLE instance started.
Total System Global Area 2147483648 bytes
Fixed Size 8794848 bytes
Variable Size 1912605984 bytes
Database Buffers 218103808 bytes
Redo Buffers 7979008 bytes
Database mounted.
Database opened.
SQL> show parameter "_query_on_physical"
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
_query_on_physical boolean FALSE
- Activating Standby File Management
SQL> alter system set standby_file_management=AUTO scope=both;
System altered.
SQL> show parameter standby_file_management
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
standby_file_management string AUTO
- Enable forced logging
SQL> alter database force logging;
Database altered.
SQL> select force_logging from v$database;
FORCE_LOGGING
---------------------------------------
YES
Read more about force logging Check out Oracle Database Logging Mode and Enhancements in 18c
- Setting Unique name
DB_UNIQUE_NAME parameter of primary and standby database must be unique. As mentioned in the beginning itself I am using TST1TP as DB_UNIQUE_NAME for Primary database
SQL> alter system set db_unique_name='TST1TP' scope=spfile;
System altered.
SQL> startup force;
ORACLE instance started.
Total System Global Area 2147483648 bytes
Fixed Size 8794848 bytes
Variable Size 1912605984 bytes
Database Buffers 218103808 bytes
Redo Buffers 7979008 bytes
Database mounted.
Database opened.
SQL> show parameter unique
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
db_unique_name string TST1TP
Step2> On Standby Database Server (test2) Install oracle database Binaries - same Oracle version as Primary Database
For Step by step instruction navigate to Oracle 12c Database Software Only Installation in Silent Mode
Step3> Optionally if using ASM
Install and configure ASM and ASM Diskgroups. Steps are provided at Installing and Configuring Oracle Grid Infrastructure for Standalone Server in Silent Mode
Step4> Configure Oracle Network Files- Configuring TNSNAMES.ORA file
Configuring tnsnames.ora file
Prepare the tns entry for both primary as well as stanby and enter in $ORACLE_HOME/network/admin/tnsnames.ora file in both primary and physical stanby database servers
Prepare the tns entry for both primary as well as stanby and enter in $ORACLE_HOME/network/admin/tnsnames.ora file in both primary and physical stanby database servers
TST1TP =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP) (HOST = test1.oracle.com)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = TST1TP)
(UR = A)
)
)
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP) (HOST = test1.oracle.com)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = TST1TP)
(UR = A)
)
)
TST1TS =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP) (HOST = test2.oracle.com) (PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = TST1TS)
(UR = A)
)
)
Step5> Create pfile from Primary for standby(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP) (HOST = test2.oracle.com) (PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = TST1TS)
(UR = A)
)
)
SQL> create pfile='/u01/dbatst1/stage/initTST1TS.ora' from spfile;
File created.
Step6> Transfer the PFILE on Standby Server at $ORACLE_HOME/dbs
$ scp /u01/dbatst1/stage/initTST1TS.ora oracle@test2:/u01/app/oracle/12.2.0.1/dbp1/dbs/
Step7> Create standby controlfile
SQL> ALTER DATABASE CREATE STANDBY CONTROLFILE AS '/u01/dbatst1/stage/backup/stby.ctl';
Database altered.
Step8> Transfer Standby Controlfile on Standby Server
$scp /u01/dbatst1/stage/backup/stby.ctl oracle@test2:/u01/app/oracle/12.2.0.1/dbp1/dbs/
Step9> modify the Pfile on Standby Server as shown below
*.db_unique_name='TST1TS'
*.control_files='/u01/app/oracle/12.2.0.1/dbp1/dbs/stby.ctl'
Optionally
NOTE:-If you have different file system/ASM DISK GROUP structure between Primary and standby then modify the following parameter accordingly
db_create_file_dest='ASM_DISKGROUP OR FILESYSTEM'
db_create_online_log_dest_1='ASM_DISKGROUP OR FILESYSTEM'
db_create_online_log_dest_2='ASM_DISKGROUP OR FILESYSTEM'
Step10> Create Required directories on Standby Server
$ mkdir -p /u01/app/admin/TST1T/adump
Step11> On Standby Server Set Environment variables and start the instance
$ export ORACLE_HOME=/u01/app/oracle/12.2.0.1/dbp1
$ export ORACLE_SID=TST1T
$ export PATH=$ORACLE_HOME/bin:$PATH
$ sqlplus "/as sysdba"
SQL*Plus: Release 12.2.0.1.0 Production on Thu Jan 24 13:27:03 2019
Copyright (c) 1982, 2016, Oracle. All rights reserved.
Connected to an idle instance.
SQL> startup nomount;
ORACLE instance started.
Total System Global Area 2147483648 bytes
Fixed Size 8794848 bytes
Variable Size 1912605984 bytes
Database Buffers 218103808 bytes
Redo Buffers 7979008 bytes
Step12> create spfile from pfile
SQL> create spfile from pfile;
File created.
Step13> Restart the Standby database in mount mode
SQL> shut immediate;
ORA-01507: database not mounted
ORACLE instance shut down.
SQL> startup mount;
ORACLE instance started.
Total System Global Area 2147483648 bytes
Fixed Size 8794848 bytes
Variable Size 1912605984 bytes
Database Buffers 218103808 bytes
Redo Buffers 7979008 bytes
Database mounted.
Step14> Perform full Primary database backup inluding archivelogs
$rman target /
RMAN>run
{
ALLOCATE CHANNEL ch1 TYPE DISK MAXPIECESIZE 10G;
BACKUP
FORMAT '/u01/dbatst1/stage/backup/back_%U'
DATABASE
PLUS ARCHIVELOG
FORMAT '/u01/dbatst1/stage/backup/back_%U';
RELEASE CHANNEL ch1;
}
Step15> Transfer backup pieces on Standby Server
$ scp -r /u01/dbatst1/stage/backup oracle@test2:/u01/app/stage
Step16> Catalog the backup pieces : On Standby Server
$ rman target /
RMAN> catalog start with '/u01/app/stage/backup/';
using target database control file instead of recovery catalog
searching for all files that match the pattern /u01/app/stage/backup/
List of Files Unknown to the Database
=====================================
File Name: /u01/app/stage/backup/back_a5to514c_1_1
File Name: /u01/app/stage/backup/back_a6to514k_1_1
File Name: /u01/app/stage/backup/back_a8to515c_1_1
File Name: /u01/app/stage/backup/back_a7to5153_1_1
File Name: /u01/app/stage/backup/back_a4to514a_1_1
Do you really want to catalog the above files (enter YES or NO)? yes
cataloging files...
cataloging done
List of Cataloged Files
=======================
File Name: /u01/app/stage/backup/back_a5to514c_1_1
File Name: /u01/app/stage/backup/back_a6to514k_1_1
File Name: /u01/app/stage/backup/back_a8to515c_1_1
File Name: /u01/app/stage/backup/back_a7to5153_1_1
File Name: /u01/app/stage/backup/back_a4to514a_1_1
Step17>On Standby Restore database using restore database.
$ rman target /
RMAN> run
{
ALLOCATE CHANNEL ch1 TYPE DISK;
RESTORE DATABASE;
RELEASE CHANNEL ch1;
}
using target database control file instead of recovery catalog
allocated channel: ch1
channel ch1: SID=785 device type=DISK
Starting restore at 29-JAN-19
channel ch1: restoring datafile 00001
input datafile copy RECID=23 STAMP=998822543 file name=+DG_TEST_DATA/TST1TS/DATAFILE/system.273.998821513
destination for restore of datafile 00001: +DG_TST_DATA/TST1T/DATAFILE/system.274.990371801
channel ch1: copied datafile copy of datafile 00001
.................................................................
.................................................................
Finished restore at 29-JAN-19
released channel: ch1
Step 18: Transfer Primary database password file to standby databaseRMAN> run
{
ALLOCATE CHANNEL ch1 TYPE DISK;
RESTORE DATABASE;
RELEASE CHANNEL ch1;
}
using target database control file instead of recovery catalog
allocated channel: ch1
channel ch1: SID=785 device type=DISK
Starting restore at 29-JAN-19
channel ch1: restoring datafile 00001
input datafile copy RECID=23 STAMP=998822543 file name=+DG_TEST_DATA/TST1TS/DATAFILE/system.273.998821513
destination for restore of datafile 00001: +DG_TST_DATA/TST1T/DATAFILE/system.274.990371801
channel ch1: copied datafile copy of datafile 00001
.................................................................
.................................................................
Finished restore at 29-JAN-19
released channel: ch1
$ scp $ORACLE_HOME/dbs/orapwTST1T oracle@test2:$ORACLE_HOME/dbs/
Rename the password file to the standby database name.
NOTE: The password file name must match the instance name/SID used at the standby site, not the DB_NAME.
Step 19: Restart the Standby Database
$ sqlplus "/as sysdba"
SQL> startup mount force;
ORACLE instance started.
Total System Global Area 2147483648 bytes
Fixed Size 8794848 bytes
Variable Size 1912605984 bytes
Database Buffers 218103808 bytes
Redo Buffers 7979008 bytes
Database mounted.
Step 20: Configure Logshipping
On Primary Database
SQL> alter system set log_archive_dest_2='service=TST1TS';
System altered.
SQL> alter system set log_archive_dest_state_2=enable;
System altered.
SQL> alter system switch logfile;
System altered.
NOTE1:On Standby database server verify and ensure (using lsnrctl services command) that the Listener is listening for service 'TST1TS'
NOTE2:On Primary database server verify and ensure (using tnsping TST1TS ) that the TNSENTRY for 'TST1TS' exists
Step 21: On Standby Start Apply Process
Media recovery complete.
Step 22: Verify the Configuration of Standby database.
SQL> select name,DB_UNIQUE_NAME,open_mode,database_role from v$database;
NAME DB_UNIQUE_NAME OPEN_MODE DATABASE_ROLE
--------- ------------------------------ -------------------- ----------------
TST1T TST1TS MOUNTED PHYSICAL STANDBY
--------- ------------------------------ -------------------- ----------------
TST1T TST1TS MOUNTED PHYSICAL STANDBY
SQL> select PROCESS,STATUS,THREAD#,SEQUENCE# from v$managed_standby;
PROCESS STATUS THREAD# SEQUENCE#
--------- ------------ ---------- ----------
ARCH CONNECTED 0 0
DGRD ALLOCATED 0 0
DGRD ALLOCATED 0 0
ARCH CONNECTED 0 0
ARCH CONNECTED 0 0
ARCH CONNECTED 0 0
RFS IDLE 1 4522
RFS IDLE 0 0
RFS IDLE 0 0
RFS IDLE 0 0
RFS IDLE 0 0
--------- ------------ ---------- ----------
ARCH CONNECTED 0 0
DGRD ALLOCATED 0 0
DGRD ALLOCATED 0 0
ARCH CONNECTED 0 0
ARCH CONNECTED 0 0
ARCH CONNECTED 0 0
RFS IDLE 1 4522
RFS IDLE 0 0
RFS IDLE 0 0
RFS IDLE 0 0
RFS IDLE 0 0
PROCESS STATUS THREAD# SEQUENCE#
--------- ------------ ---------- ----------
MRP0 WAIT_FOR_LOG 1 4522
--------- ------------ ---------- ----------
MRP0 WAIT_FOR_LOG 1 4522
12 rows selected.
Switch a logfile on Primary and Verify the Status again
SQL> alter system switch logfile;
System altered.
SQL> /
SQL> alter system switch logfile;
System altered.
SQL> /
PROCESS STATUS THREAD# SEQUENCE#
--------- ------------ ---------- ----------
ARCH CONNECTED 0 0
DGRD ALLOCATED 0 0
DGRD ALLOCATED 0 0
ARCH CONNECTED 0 0
ARCH CONNECTED 0 0
ARCH CONNECTED 0 0
RFS IDLE 1 4523
RFS IDLE 0 0
RFS IDLE 0 0
RFS IDLE 0 0
RFS IDLE 0 0
--------- ------------ ---------- ----------
ARCH CONNECTED 0 0
DGRD ALLOCATED 0 0
DGRD ALLOCATED 0 0
ARCH CONNECTED 0 0
ARCH CONNECTED 0 0
ARCH CONNECTED 0 0
RFS IDLE 1 4523
RFS IDLE 0 0
RFS IDLE 0 0
RFS IDLE 0 0
RFS IDLE 0 0
PROCESS STATUS THREAD# SEQUENCE#
--------- ------------ ---------- ----------
MRP0 WAIT_FOR_LOG 1 4523
--------- ------------ ---------- ----------
MRP0 WAIT_FOR_LOG 1 4523
12 rows selected.
Comments
Post a Comment