Setup:
Primary Site
|
Standby Site
| |
Hostname
|
dgaskmpri01
|
dgaskmsby01
|
Database Name
|
orcl
|
orcl
|
Database Unique Name
|
orcl
|
sbyorcl
|
Net Service Name
|
orcl
|
sbyorcl
|
Prepared By SRI
Prepared By SRI
Primary Site Preparation :
1. Enable Database Force Logging
2. Create SRL (Standby Redo Logs)
3. Modify Init.ora parameters
4. Enable Archiving
5. Backup Primary Database
6. Create a controlfile for Standby Database
7. Create a init.ora file for Standby Database
8. Configure listener.ora and tnsnames.ora
9. Copy backups and configuration files to Standby Server
Standby Site Preparation :
1. Create a remote login password file ( if it is not copied from primary site )
2. Create a directory structure
3. Modify the init.ora parameter file
4. Configure listener.ora and tnsnames.ora
5. Verify connectivity
Creating Physical Standby Database :
1. Start the physical Standby Database
2. Keep it in recovery
Verifications
Primary Site Preparation :
1. Enable Database Force Logging:
SQL> select FORCE_LOGGING from v$database;
SQL> ALTER DATABASE FORCE LOGGING;
2. Create SRL ( Standby Redo Logs):
You need to create SRL with the same size or greater size as of the online redo logs and also the number of SRLs should be one greater than the online redologs.
SQL> select name,user from v$database;
NAME USER
--------- ------------------------------
ORCL SYS
SQL> col group# for 9999
SQL> col member for a50
SQL> set linesize 120
SQL> select name,user from v$database;
NAME USER
--------- ------------------------------
ORCL SYS
SQL> select GROUP#,THREAD#,MEMBERS,BYTES FROM V$LOG;
GROUP# THREAD# MEMBERS BYTES
------ ---------- ---------- ----------
1 1 1 52428800
2 1 1 52428800
3 1 1 52428800
SQL> select group#,member from v$logfile;
GROUP# MEMBER
------ --------------------------------------------------
3 /home/oracle/app/oracle/oradata/orcl/redo03.log
2 /home/oracle/app/oracle/oradata/orcl/redo02.log
1 /home/oracle/app/oracle/oradata/orcl/redo01.log
SQL> SELECT GROUP#, BYTES FROM V$STANDBY_LOG;
no rows selected
SQL> ALTER DATABASE ADD STANDBY LOGFILE ('/home/oracle/app/oracle/oradata/orcl/s_redo01.log') SIZE 52428800;
Database altered.
SQL> ALTER DATABASE ADD STANDBY LOGFILE ('/home/oracle/app/oracle/oradata/orcl/s_redo02.log') SIZE 52428800;
Database altered.
SQL> SELECT GROUP#, BYTES FROM V$STANDBY_LOG;
GROUP# BYTES
------ ----------
4 52428800
5 52428800
SQL> ALTER DATABASE ADD STANDBY LOGFILE ('/home/oracle/app/oracle/oradata/orcl/s_redo03.log') SIZE 52428800;
Database altered.
SQL> ALTER DATABASE ADD STANDBY LOGFILE ('/home/oracle/app/oracle/oradata/orcl/s_redo04.log') SIZE 52428800;
Database altered.
SQL> SELECT GROUP#, BYTES FROM V$STANDBY_LOG;
GROUP# BYTES
------ ----------
4 52428800
5 52428800
6 52428800
7 52428800
SQL>
3. Modify the init.ora parameters:
Modify the init.ora parameters on the primary database side to reflect the following values. If you are using spfile, you can add these parameter online without shutting down the primary database.
DB_NAME=orcl
DB_UNIQUE_NAME=orcl
LOG_ARCHIVE_CONFIG='DG_CONFIG=(orcl,sbyorcl)'LOG_ARCHIVE_DEST_1='LOCATION=/home/oracle/app/oracle/flash_recovery_area/orcl/ VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=orcl'LOG_ARCHIVE_DEST_2='SERVICE=sbyorcl ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=sbyorcl'LOG_ARCHIVE_DEST_STATE_1=ENABLE
LOG_ARCHIVE_DEST_STATE_2=ENABLE
REMOTE_LOGIN_PASSWORDFILE=EXCLUSIVE
LOG_ARCHIVE_FORMAT=%t_%s_%r.arc
LOG_ARCHIVE_MAX_PROCESSES=30
FAL_SERVER=sbyorcl
DB_FILE_NAME_CONVERT='sbyorcl','orcl'LOG_FILE_NAME_CONVERT='/home/oracle/app/oracle/flash_recovery_area/sbyorcl/','/home/oracle/app/oracle/flash_recovery_area/orcl/'STANDBY_FILE_MANAGEMENT=AUTO
4. Enable Archiving :
Make sure that your database is running in archive log mode. Because in a physical standby setup all the redologs generated on the primary database will be transferred to standby site and applied to the standby database.
SQL> shut immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> STARTUP MOUNT;
ORACLE instance started.
Total System Global Area 456146944 bytes
Fixed Size 1344840 bytes
Variable Size 381684408 bytes
Database Buffers 67108864 bytes
Redo Buffers 6008832 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 /home/oracle/app/oracle/flash_recovery_area/orcl/
Oldest online log sequence 360
Next log sequence to archive 362
Current log sequence 362
SQL>
5. Backup Primary Database :
In this demo I am using cold backup of the primary database. There are various other options like RMAN duplicate from active database to create physical standby database without even having the primary database backup in 11g. But in this article I am showing setup without RMAN and using simple sql commands.Create a temporary directory (/tmp/askm/) on primary server and copy all the controlfile,online redolog files and database files to this location after shutting down the database.
6. Create a controlfile for Standby Database:
SQL> startup mount
ORACLE instance started.
Total System Global Area 456146944 bytes
Fixed Size 1344840 bytes
Variable Size 381684408 bytes
Database Buffers 67108864 bytes
Redo Buffers 6008832 bytes
Database mounted.
SQL> ALTER DATABASE CREATE STANDBY CONTROLFILE AS '/tmp/askm/s_control01.ctl';
Database altered.
SQL> ALTER DATABASE OPEN;
Database altered.
7. Create a init.ora file for Standby Database:
SQL> CREATE PFILE='/tmp/askm/initsbyorcl.ora' FROM SPFILE;
File created.
8. Configure listener.ora and tnsnames.ora:
[oracle@dgaskmpri01 admin]$ cat listener.ora
LISTENER_PRI =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1525))
)
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = dgaskmpri01.localdomain)(PORT = 1525))
)
)
SID_LIST_LISTENER_PRI =
(SID_LIST =
(SID_DESC =
(ORACLE_HOME = /home/oracle/app/oracle/product/11.2.0/dbhome_2)
(SID_NAME = orcl)
)
)
[oracle@dgaskmpri01 admin]$ cat tnsnames.ora
orcl =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = dgaskmpri01.localdomain)(PORT = 1525))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SID=orcl)
)
)
sbyorcl =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = dgaskmsby01.localdomain)(PORT = 1525))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SID=sbyorcl)
)
)
[oracle@dgaskmpri01 admin]$
9. Copy backups and configuration files to Standby Server:
Create a temporary directory(/tmp/askm) on standby server and copy coldbackup, init.ora, password file(orapwsbyorcl) and standby controlfile (s_control01.ctl) from primary server to standby server.
Standby Site Preparation :
1. Create a remote login password file ( if it is not copied from primary site )
Copy the password file /tmp/askm/orapwsbyorcl to $ORACLE_HOME/dbs
2. Create a directory structure
If you are using a different directory structure on the standby server, they you need to create all the directories on the standby site.
Then copy coldbackup to the appropriate locations on the standby server. Also copy init.ora to $ORACLE_HOME/dbs location.
[oracle@dgaskmsby01]$ mkdir /home/oracle/app/oracle/oradata/sbyorcl/
[oracle@dgaskmsby01]$ mkdir /home/oracle/app/oracle/flash_recovery_area/sbyorcl/
[oracle@dgaskmsby01]$ cd $ORACLE_HOME/dbs
[oracle@dgaskmsby01 dbs]$ cd /home/oracle/app/oracle/oradata/sbyorcl/
[oracle@dgaskmsby01 sbyorcl]$ cp /tmp/askm/*.dbf .
[oracle@dgaskmsby01 sbyorcl]$ cp /tmp/askm/*.log .
[oracle@dgaskmsby01 sbyorcl]$ cp /tmp/askm/s_control01.ctl .
[oracle@dgaskmsby01 sbyorcl]$ cp /tmp/askm/s_control01.ctl /home/oracle/app/oracle/flash_recovery_area/sbyorcl/s_control02.ctl
[oracle@dgaskmsby01 sbyorcl]$ cp /tmp/askm/initsbyorcl.ora $ORACLE_HOME/dbs
3. Modify the init.ora parameter file
Modify the initsbyorcl.ora file to reflect the following initialization parameters
DB_NAME=orcl
DB_UNIQUE_NAME=sbyorcl
LOG_ARCHIVE_CONFIG='DG_CONFIG=(orcl,sbyorcl)'CONTROL_FILES='/home/oracle/app/oracle/oradata/sbyorcl/s_control01.ctl', '/home/oracle/app/oracle/flash_recovery_area/sbyorcl/s_control02.ctl'DB_FILE_NAME_CONVERT='orcl','sbyorcl'LOG_FILE_NAME_CONVERT='/home/oracle/app/oracle/flash_recovery_area/orcl/','/home/oracle/app/oracle/flash_recovery_area/sbyorcl/'LOG_ARCHIVE_FORMAT=%t_%s_%r.arc
LOG_ARCHIVE_DEST_1='LOCATION=/home/oracle/app/oracle/flash_recovery_area/sbyorcl/ VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=sbyorcl'LOG_ARCHIVE_DEST_2='SERVICE=orcl ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=orcl'LOG_ARCHIVE_DEST_STATE_1=ENABLE
LOG_ARCHIVE_DEST_STATE_2=ENABLE
REMOTE_LOGIN_PASSWORDFILE=EXCLUSIVE
STANDBY_FILE_MANAGEMENT=AUTO
FAL_SERVER=orcl
4. Configure listener.ora and tnsnames.ora:
[oracle@dgaskmsby01 admin]$ cat listener.ora
LISTENER_SBY =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1525))
)
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = dgaskmsby01.localdomain)(PORT = 1525))
)
)
SID_LIST_LISTENER_SBY =
(SID_LIST =
(SID_DESC =
(ORACLE_HOME = /home/oracle/app/oracle/product/11.2.0/dbhome_2)
(SID_NAME = sbyorcl)
)
)
[oracle@dgaskmsby01 admin]$ cat tnsnames.ora
orcl =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = dgaskmpri01.localdomain)(PORT = 1525))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SID=orcl)
)
)
sbyorcl =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = dgaskmsby01.localdomain)(PORT = 1525))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SID=sbyorcl)
)
)
[oracle@dgaskmsby01 admin]$
5. Verify connectivity
On Primary Server:[oracle@dgaskmpri01]$ lsnrctl stop LISTENER_PRIOn Standby Server:
[oracle@dgaskmpri01]$ lsnrctl start LISTENER_PRI
[oracle@dgaskmpri01]$ tnsping orcl
[oracle@dgaskmpri01]$ tnsping sbyorcl
[oracle@dgaskmpri01]$ sqlplus sys/xxxxx@orcl
[oracle@dgaskmpri01]$ sqlplus sys/xxxxx@sbyorcl
[oracle@dgaskmsby01]$ lsnrctl stop LISTENER_SBYCreating Physical Standby Database :
[oracle@dgaskmsby01]$ lsnrctl start LISTENER_SBY
[oracle@dgaskmsby01]$ tnsping orcl
[oracle@dgaskmsby01]$ tnsping sbyorcl
[oracle@dgaskmsby01]$ sqlplus sys/xxxxx@orcl
[oracle@dgaskmsby01]$ sqlplus sys/xxxxx@sbyorcl
1. Start the physical Standby Database:
SQL> startup mount
ORACLE instance started.
Total System Global Area 456146944 bytes
Fixed Size 1344840 bytes
Variable Size 381684408 bytes
Database Buffers 67108864 bytes
Redo Buffers 6008832 bytes
Database mounted.
SQL>
2. Keep it in recovery:
SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE USING CURRENT LOGFILE DISCONNECT FROM SESSION;
Verifications :
On Standby:SELECT SEQUENCE#, FIRST_TIME, NEXT_TIME FROM V$ARCHIVED_LOG ORDER BY SEQUENCE#;
On Primary :
Do some redo log switchesSQL> ALTER SYSTEM SWITCH LOGFILE;On Standby:
Verify that the recent archived log file is shifted to standby side and applied with the following commands.
SQL> SELECT SEQUENCE#, FIRST_TIME, NEXT_TIME FROM V$ARCHIVED_LOG ORDER BY SEQUENCE#;
SQL> SELECT SEQUENCE#,APPLIED FROM V$ARCHIVED_LOG ORDER BY SEQUENCE#;
Other Useful Information:
To verify all the init.ora parameter in a single command:
egrep -i "DB_NAME|DB_UNIQUE_NAME|LOG_ARCHIVE_CONFIG|CONTROL_FILES|LOG_ARCHIVE_DEST_1|LOG_ARCHIVE_DEST_2|LOG_ARCHIVE_DEST_STATE_1|LOG_ARCHIVE_DEST_STATE_2|REMOTE_LOGIN_PASSWORDFILE|LOG_ARCHIVE_FORMAT|LOG_ARCHIVE_MAX_PROCESSES|FAL_SERVER|DB_FILE_NAME_CONVERT|LOG_FILE_NAME_CONVERT|STANDBY_FILE_MANAGEMENT" <specify init.ora parameter file>To Cancel the Standby Recovery Mode:
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE CANCEL;Useful commands To Troubleshoot:
select message from v$dataguard_status where dest_id = 2;To Verify Recover Process On Standby:
select archived_thread#, archived_seq#, applied_thread#, applied_seq# from v$archive_dest_status;
select registrar, creator, thread#, sequence#, first_change#, next_change# from v$archived_log;
select thread#, sequence#, first_change#, next_change# from v$log_history;
select thread#, sequence# from v$log where status='CURRENT'; = > On PrimaryReferences :
select thread#, sequence#, status from v$managed_standby where process='MRP0'; = > On Standby
http://download.oracle.com/docs/cd/E11882_01/server.112/e25608/create_ps.htm#i63561
MOS ID : 249703.1
Hope It Helps
SRI
+ comments + 7 comments
Excellent work. Thanks.
Thank you
Hi Anna,
Its really very nice and clear. Appreciate your efforts and thanks for ur postings.
Best Regards
Sridhar
Tq :-)
See this link...
[...]Creating A Physical Standby Database (11gR2) « Oracle Technologies Blog[...]...
Hi! I've got one problem. I did everything as you told above but I still have my switchover_status NOT ALLOWED on primary database. What could be an issue?
Excellent blog..Thanks for the clear steps...
Post a Comment
Thank you for visiting our site and leaving your valuable comment.