Activating the Standby Database – Switchover Method
The main advantage of a graceful switchover is that it avoids the resetlogs operation. By avoiding the resetlogs operation, the source database can resume its role as the standby database almost immediately with no data loss. Another feature to a graceful switchover is that it does not invalidate previous backups.
1. Prerequisites :-
There is no loss of any archive logs that haven’t been (yet) applied to the standby database.
2. Set job_queue_processes value to 0 in both (PRIMARY and STANDBY) (ABCD02 & ABCD03)
SQL>SHOW PARAMETER JOB_QUEUE_PROCESS
NAME TYPE VALUE
———————————— ———– ————-
job_queue_processes integer 10
SQL> ALTER SYSTEM SET JOB_QUEUE_PROCESSES=0 scope=both;
3. In PRIMARY database check the database role. (ABCD02 server)
SQL> select NAME,DATABASE_ROLE,GUARD_STATUS,SWITCHOVER_STATUS, SWITCHOVER#,OPEN_MODE,PROTECTION_MODE from v$database;
NAME DATABASE_ROLE GUARD_S SWITCHOVER_STATUS SWITCHOVER# OPEN_MODE PROTECTION_MODE
——— —————- ——- ——————– ———– ———- ——————–
AIRMAN PRIMARY NONE SESSIONS ACTIVE 4106602309 READ WRITE MAXIMUM PERFORMANCE
4. In STANDBY database check the database role. (ABCD03 server)
SQL> select NAME,DATABASE_ROLE,GUARD_STATUS,SWITCHOVER_STATUS, SWITCHOVER#,OPEN_MODE,PROTECTION_MODE from v$database;
NAME DATABASE_ROLE GUARD_S SWITCHOVER_STATUS SWITCHOVER# OPEN_MODE PROTECTION_MODE
——— —————- ——- ——————– ———– ———- ——————–
AIRMAN PHYSICAL STANDBY NONE SESSIONS ACTIVE 4106602309 MOUNTED MAXIMUM PERFORMANCE
5. Shutdown the PRIMARY database. (ABCD02 server)
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
6. Open the PRIMARY database in RESTRICTED mode. (ABCD02 server)
SQL> startup restrict
ORACLE instance started.
Total System Global Area 252777660 bytes
Fixed Size 451772 bytes
Variable Size 218103808 bytes
Database Buffers 33554432 bytes
Redo Buffers 667648 bytes
Database mounted.
Database opened.
7. Archive the current log on the PRIMARY database. (ABCD02 server)
SQL> alter system archive log current;
System altered.
8. Make sure the primary database and standby database are in sync. On both the primary and standby instances, issue the following. (ABCD02 & ABCD03)
SQL> select thread#, max (sequence#) from v$archived_log where APPLIED=’YES’ group by thread#;
THREAD# MAX(SEQUENCE#)
———- ————–
1 1934
Now, compare the results and make sure the Thread and Sequence # are the same. If the standby instance is ahead by 1 or none, you are in sync.
9. Initiate the switchover on the PRIMARY database. (ABCD02)
SQL> ALTER DATABASE COMMIT TO SWITCHOVER TO PHYSICAL STANDBY WITH SESSION SHUTDOWN;
10. Once the step above has completed, log on to the STANDBY database and issues the following command. (ABCD03)
SQL> ALTER DATABASE COMMIT TO SWITCHOVER TO PRIMARY;
11. Immediately return to the FORMER PRIMARY database and issue a shutdown and mount the NEW STANDBY database. (ABCD02 server)
SQL> shutdown immediate
SQL> startup mount;
12. On the NEW PRIMARY/OLD STANDBY, you can now open the database as the PRIMARY database. (ABCD03 server)
SQL> alter database open;
Database opened.
13. Verify the new STANDBY’S status. (ABCD02 server)
SQL> select name, database_role from v$database;
NAME DATABASE_ROLE
——— —————-
PHYSICAL STANDBY
14. Set job_queue_processes value to 10 in both (PRIMARY and STANDBY) (ABCD02 & ABCD03)
SQL>SHOW PARAMETER JOB_QUEUE_PROCESS
NAME TYPE VALUE
———————————— ———– ————-
job_queue_processes integer 0
SQL> ALTER SYSTEM SET JOB_QUEUE_PROCESSES=10 scope=both;
15. Put the NEW STANDBY/FORMER PRIMARY database into managed recovery mode. (ABCD02)
SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT FROM SESSION;
Database altered.
16. Test the communications for archive by performing a log switch. (ABCD03 server)
SQL> alter system switch logfile;
System altered.
SQL> alter system switch logfile;
System altered.
Now check whether these logs are applying in the NEW STANDBY and also check the listener status.
17. On the NEW PRIMARY database instance, take a backup if possible. (ABCD03 server)
Switch back from SZB location (ABCD03) to KJ location orginal primary sever (ABCD02)
Switch back to Orginal Primary Database – Switchover Method
1. Prerequisites :-
There is no loss of any archive logs that haven’t been (yet) applied to the standby database.
2. Set job_queue_processes value to 0 in both (PRIMARY and STANDBY) (ABCD02 & ABCD03)
SQL>SHOW PARAMETER JOB_QUEUE_PROCESS
NAME TYPE VALUE
———————————— ———– ————-
job_queue_processes integer 10
SQL> ALTER SYSTEM SET JOB_QUEUE_PROCESSES=0 scope=both;
3. In New PRIMARY database check the database role. (ABCD03 server)
SQL> select NAME,DATABASE_ROLE,GUARD_STATUS,SWITCHOVER_STATUS, SWITCHOVER#,OPEN_MODE,PROTECTION_MODE from v$database;
NAME DATABASE_ROLE GUARD_S SWITCHOVER_STATUS SWITCHOVER# OPEN_MODE PROTECTION_MODE
——— —————- ——- ——————– ———– ———- ——————–
AIRMAN PRIMARY NONE SESSIONS ACTIVE 4106602309 READ WRITE MAXIMUM PERFORMANCE
4. In New STANDBY database check the database role. (ABCD02 server)
SQL> select NAME,DATABASE_ROLE,GUARD_STATUS,SWITCHOVER_STATUS, SWITCHOVER#,OPEN_MODE,PROTECTION_MODE from v$database;
NAME DATABASE_ROLE GUARD_S SWITCHOVER_STATUS SWITCHOVER# OPEN_MODE PROTECTION_MODE
——— —————- ——- ——————– ———– ———- ——————–
AIRMAN PHYSICAL STANDBY NONE SESSIONS ACTIVE 4106602309 MOUNTED MAXIMUM PERFORMANCE
5. Shutdown the New PRIMARY database. (ABCD03 server)
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
6. Open the New PRIMARY database in RESTRICTED mode. (ABCD03 server)
SQL> startup restrict
ORACLE instance started.
Total System Global Area 252777660 bytes
Fixed Size 451772 bytes
Variable Size 218103808 bytes
Database Buffers 33554432 bytes
Redo Buffers 667648 bytes
Database mounted.
Database opened.
7. Archive the current log on the New PRIMARY database. (ABCD03 server)
SQL> alter system archive log current;
System altered.
8. Make sure the primary database and standby database are in sync. On both the primary and standby instances, issue the following. (ABCD02 & ABCD03)
SQL> select thread#, max (sequence#) from v$archived_log where APPLIED=’YES’ group by thread#;
THREAD# MAX(SEQUENCE#)
———- ————–
1 1934
Now, compare the results and make sure the Thread and Sequence # are the same. If the standby instance is ahead by 1 or none, you are in sync.
9. Initiate the switchover on the New PRIMARY database. (ABCD03)
SQL> ALTER DATABASE COMMIT TO SWITCHOVER TO PHYSICAL STANDBY WITH SESSION SHUTDOWN;
10. Once the step above has completed, log on to the New STANDBY database/Orginal Primary and issues the following command. (ABCD02)
SQL> ALTER DATABASE COMMIT TO SWITCHOVER TO PRIMARY;
11. Immediately return to the FORMER PRIMARY database/Orginal STANDBY and issue a shutdown and mount the Orginal STANDBY database. (ABCD03 server)
SQL> shutdown immediate
SQL> startup mount;
12. On the Orginal PRIMARY/OLD STANDBY, you can now open the database as the PRIMARY database. (ABCD02 server)
SQL> alter database open;
Database opened.
13. Verify the orginal STANDBY’S status. (ABCD03 server)
SQL> select name, database_role from v$database;
NAME DATABASE_ROLE
——— —————-
PHYSICAL STANDBY
14. Set job_queue_processes value to 10 in both (PRIMARY and STANDBY) (ABCD02 & ABCD03)
SQL>SHOW PARAMETER JOB_QUEUE_PROCESS
NAME TYPE VALUE
———————————— ———– ————-
job_queue_processes integer 0
SQL> ALTER SYSTEM SET JOB_QUEUE_PROCESSES=10 scope=both;
15. Put the Orginal STANDBY/FORMER PRIMARY database into managed recovery mode. (ABCD03)
SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT FROM SESSION;
Database altered.
16. Test the communications for archive by performing a log switch. (ABCD02 server)
SQL> alter system switch logfile;
System altered.
SQL> alter system switch logfile;
System altered.
Now check whether these logs are applying in the Orginal STANDBY and also check the listener status.
17. On the Orginal PRIMARY database instance, take a backup if possible. (ABCD02 server)