An Oracle Snapshot Standby Database allows to perform read-write operation on the standby database i.e., converting the physical standby to snapshot standby database. On the snapshot standby database we can do all types of testing or it can be used as a development database. Once testing is over we can convert the snapshot standby database back to physical standby database and any changes done to the snapshot standby will be reverted. A snapshot standby database receives and archives redo data but it does not apply the redo data from the primary database. FRA (Fast Recovery Area) using parameters db_recovery_file_dest and db_recovery_file_dest_size must be configured in physical standby database but it is not necessary to have flashback enabled.
Oracle Core DBA, Oracle EBS Apps DBA, Microsoft SQL Server DBA, Postgresql DBA, IBM DB2 DBA.
Tuesday, October 24, 2023
Convert Oracle DR Physical Standby DB To Snapshot Standby (Read Write Mode)
Snapshot Standby Database Architecture
1. Make sure flashback is on on standby database.
SQL> show parameter db_recovery
db_recovery_file_dest = +FRA
db_recovery_file_dest_size=222G
SQL> select flashback_on from v$database;
FLASHBACK_ON
------------------
NO
SQL> select open_mode from v$database;
OPEN_MODE
--------------------
READ ONLY WITH APPLY
SQL> alter database flashback on;
alter database flashback on
*
ERROR at line 1:
ORA-01153: an incompatible media recovery is active
SQL> recover managed standby database cancel;
Media recovery complete.
SQL> alter database flashback on;
Database altered.
SQL> select flashback_on from v$database;
FLASHBACK_ON
------------------
YES
SQL> alter database recover managed standby database using current logfile disconnect from session;
Database altered.
2. Check the configuration:
Check the configuration, if any issues are there, then fix it before proceeding further.
DGMGRL> show configuration
DGMGRL> validate database MYDBDR
DGMGRL> show configuration
Configuration - dg_config_mydb
Protection Mode: MaxPerformance
Members:
MYDB - Primary database
MYDBDR - Physical standby database
Fast-Start Failover: DISABLED
Configuration Status:
SUCCESS (status updated 6 seconds ago)
3. Convert physical to snapshot standby.
DGMGRL> convert database MYDBDR to snapshot standby;
Converting database "MYDBDR" to a Snapshot Standby database, please wait...
Database "MYDBDR" converted successfully
DGMGRL> show configuration
Configuration - dg_config_mydb
Protection Mode: MaxPerformance
Members:
MYDB - Primary database
MYDBDR - Snapshot standby database
Fast-Start Failover: DISABLED
Configuration Status:
SUCCESS (status updated 52 seconds ago)
SQL> select open_mode,database_role from v$database;
OPEN_MODE DATABASE_ROLE
READ WRITE SNAPSHOT STANDBY
Now the database is open in read write mode. So you can do any changes or testing on the database.
Once your activity is done, you can revert it back to physical standby using below command.
4. Convert snapshot standby back to physical standby
DGMGRL> convert database MYDBDR to physical standby;
Converting database "MYDBDR" to a Physical Standby database, please wait...
Operation requires a connection to database "ne"
Connecting ...
Connected to "MYDB"
Connected as SYSDBA.
Oracle Clusterware is restarting database "MYDBDR" ...
Connected to "MYDBDR"
Connected to "MYDBDR"
Continuing to convert database "MYDBDR" ...
Database "MYDBDR" converted successfully
DGMGRL> show configuration;
Configuration - dg_config_mydb
Protection Mode: MaxPerformance
Members:
MYDB - Primary database
MYDBDR - Physical standby database
Fast-Start Failover: DISABLED
Configuration Status:
SUCCESS (status updated 4 seconds ago)
Labels:
Oracle Dataguard
Subscribe to:
Posts (Atom)