Oracle Database Manual Switchover: A Comprehensive Guide
Database high availability is critical for enterprise applications. Oracle's Data Guard provides robust disaster recovery capabilities, including the ability to perform planned switchovers between primary and standby databases. This blog post walks through the process of manually switching over from a primary database (DC) to a standby database (DR) and then switching back.
Environment Details
- Primary Database (DC): testpri
- Standby Database (DR): testsby
Pre-Switchover Verification
Before initiating a switchover, it's essential to verify the current database state and ensure log shipping synchronization.
Step 1: Check Active Sessions
First, check for active database sessions that might be affected during the switchover: There should not be not active session, if there are any check with application team and kill those sessions.
set time on
col machine for a30
select MACHINE, count(*), status from v$session group by machine, status;
MACHINE COUNT(*) STATUS
------------------------------ --------- --------
db-client1.example.com 15 INACTIVE
db-client2.example.com 8 INACTIVE
application-server1.example.com 22 INACTIVE
monitoring-server.example.com 5 INACTIVE
select status, count(*) from v$session group by status;
STATUS COUNT(*)
---------- ---------
INACTIVE 50
Step 2: Verify Log Shipping Synchronization
Ensure that archived logs are being properly shipped and applied:
select SEQUENCE#, ARCHIVED, APPLIED from (
select SEQUENCE#, ARCHIVED, APPLIED
from v$archived_log
where to_date(COMPLETION_TIME) = to_Date(sysdate)
order by SEQUENCE# desc
) where rownum < 10;
SEQUENCE# ARC APPLIED
---------- --- -------
12345 YES YES
12344 YES YES
12343 YES YES
12342 YES YES
12341 YES YES
12340 YES YES
12339 YES YES
12338 YES YES
12337 YES YES
This indicates good synchronization as all logs are both archived and applied to the standby database.
Manual Switchover: DC to DR
Once you've confirmed the database status, you can proceed with the switchover process.
Step 1: Check Switchover Status at Primary (DC - testpri)
select switchover_status from v$database;
SWITCHOVER_STATUS
---------- -------
TO STANDBY
The status "TO STANDBY" confirms that the primary database is ready for switchover.
Step 2: Check Switchover Status at Standby (DR - testsby)
select switchover_status from v$database;
SWITCHOVER_STATUS
---------- -------
NOT ALLOWED
This status is normal for a standby database before initiating the switchover process.
Step 3: Initialize Switchover at Primary (DC - testpri)
alter database commit to switchover to standby with session shutdown;
---------- -------
Database altered.
Step 4: Verify Standby Is Ready (DR - testsby)
select switchover_status from v$database;
SWITCHOVER_STATUS
---------- -------
TO PRIMARY
The status "TO PRIMARY" indicates that the standby database is ready to assume the primary role.
Step 5: Shutdown and Restart Primary as Standby (DC - testpri)
shutdown immediate;
---------- -------
Database closed.
Database dismounted.
ORACLE instance shut down.
startup nomount;
---------- -------
ORACLE instance started.
Total System Global Area 4294967296 bytes
Fixed Size 8621184 bytes
Variable Size 1275068416 bytes
Database Buffers 3002344448 bytes
Redo Buffers 8933376 bytes
alter database mount standby database;
---------- -------
Database altered.
Step 6: Complete Role Transition at Standby (DR - testsby)
alter database commit to switchover to primary with session shutdown;
---------- -------
Database altered.
shutdown immediate;
---------- -------
Database closed.
Database dismounted.
ORACLE instance shut down.
startup;
---------- -------
ORACLE instance started.
Total System Global Area 4294967296 bytes
Fixed Size 8621184 bytes
Variable Size 1275068416 bytes
Database Buffers 3002344448 bytes
Redo Buffers 8933376 bytes
Database mounted.
Database opened.
Step 7: Configure New Standby (DC - testpri)
alter system set log_archive_dest_state_2=defer scope=both;
---------- -------
System altered.
alter database recover managed standby database disconnect from session;
---------- -------
Database altered.
Step 8: Enable Archive Log Destination on New Primary (DR - testsby)
alter system set log_archive_dest_state_2=enable scope=both;
---------- -------
System altered.
Step 9: Test Log Shipping Synchronization
Generate a new archive log on the new primary:
alter system switch logfile;
---------- -------
System altered.
Then verify log shipping on the new standby:
select SEQUENCE#, ARCHIVED, APPLIED from (
select SEQUENCE#, ARCHIVED, APPLIED
from v$archived_log
where to_date(COMPLETION_TIME) = to_Date(sysdate)
order by SEQUENCE# desc
) where rownum < 10;
SEQUENCE# ARC APPLIED
---------- --- -------
12346 YES YES
12345 YES YES
12344 YES YES
12343 YES YES
12342 YES YES
12341 YES YES
12340 YES YES
12339 YES YES
12338 YES YES
Switch Back: DR to DC
After operating with DR as your primary database for the necessary period, you may need to switch back to your original primary in DC.
Step 1: Check Switchover Status at Current Primary (DR - testsby)
select switchover_status from v$database;
SWITCHOVER_STATUS
---------- -------
TO STANDBY
Step 2: Convert Current Primary to Standby (DR - testsby)
alter database commit to switchover to standby with session shutdown;
---------- -------
Database altered.
shutdown immediate;
---------- -------
Database closed.
Database dismounted.
ORACLE instance shut down.
startup nomount;
---------- -------
ORACLE instance started.
Total System Global Area 4294967296 bytes
Fixed Size 8621184 bytes
Variable Size 1275068416 bytes
Database Buffers 3002344448 bytes
Redo Buffers 8933376 bytes
alter database mount standby database;
---------- -------
Database altered.
Step 3: Convert Current Standby to Primary (DC - testpri)
select switchover_status from v$database;
SWITCHOVER_STATUS
---------- -------
TO PRIMARY
alter database commit to switchover to primary;
---------- -------
Database altered.
shutdown immediate;
---------- -------
Database closed.
Database dismounted.
ORACLE instance shut down.
startup;
---------- -------
ORACLE instance started.
Total System Global Area 4294967296 bytes
Fixed Size 8621184 bytes
Variable Size 1275068416 bytes
Database Buffers 3002344448 bytes
Redo Buffers 8933376 bytes
Database mounted.
Database opened.
alter system set log_archive_dest_state_2=enable scope=both;
---------- -------
System altered.
Step 4: Configure New Standby (DR - testsby)
alter system set log_archive_dest_state_2=defer scope=both;
---------- -------
System altered.
alter database recover managed standby database disconnect from session;
---------- -------
Database altered.
Step 5: Test Log Shipping Synchronization
Generate a new archive log on the new primary:
alter system switch logfile;
---------- -------
System altered.
Verify log shipping on the new standby:
select SEQUENCE#, ARCHIVED, APPLIED from (
select SEQUENCE#, ARCHIVED, APPLIED
from v$archived_log
where to_date(COMPLETION_TIME) = to_Date(sysdate)
order by SEQUENCE# desc
) where rownum < 10;
SEQUENCE# ARC APPLIED
---------- --- -------
12350 YES YES
12349 YES YES
12348 YES YES
12347 YES YES
12346 YES YES
12345 YES YES
12344 YES YES
12343 YES YES
12342 YES YES
Best Practices for Database Switchover
-
Plan Maintenance Window: Schedule the switchover during a low-activity period to minimize impact.
-
Application Coordination: Notify application teams before switchover to ensure proper handling of database connections.
-
Verify Log Shipping: Always verify log shipping synchronization before and after the switchover process.
-
Document Procedure: Keep detailed records of each switchover, including timing and any issues encountered.
-
Post-Switchover Verification: Run application tests after switchover to verify functionality.
-
Monitor Alert Logs: Keep an eye on database alert logs throughout the process to catch any potential issues.
-
Database Parameters: Ensure that database parameters related to Data Guard are properly configured on both databases.
Oracle Database switchover provides a controlled method for transferring database roles with minimal downtime. When properly executed, this process ensures business continuity while allowing for planned maintenance activities. The step-by-step approach outlined in this guide should help database administrators perform switchover operations confidently and efficiently.
By having well-documented procedures and following best practices, your organization can maintain high availability and disaster recovery readiness while minimizing operational risks.
Comments
Post a Comment