Oracle Data Guard Concepts and Administration Release 2 (9.2) Part Number A96653-02 |
|
|
View PDF |
This chapter steps you through the process of creating a physical standby database. It includes the following main topics:
The discussions in this chapter assume that you specify initialization parameters in a server parameter file (SPFILE) instead of in a traditional text initialization parameter file (PFILE). See the Oracle9i Database Administrator's Guide for information about creating and using server parameter files.
See Also:
Oracle9i Data Guard Broker and the Oracle Data Guard Manager online help system for information about using the Data Guard Manager graphical user interface to automatically create a physical standby database |
Before you create a standby database you must first ensure that the primary database is properly configured.
Table 3-1 provides a checklist of the tasks that you perform on the primary database to prepare for physical standby database creation. There is also a reference to the section that describes the task in more detail.
Reference | Task |
---|---|
Place the primary database in FORCE LOGGING
mode after database creation using the following SQL statement:
SQL> ALTER DATABASE FORCE LOGGING;
This statement may take a considerable amount of time to complete, because it waits for all unlogged direct write I/O operations to finish.
Ensure that the primary database is in ARCHIVELOG mode, that automatic archiving is enabled, and that you have defined a local archiving destination.
Set the local archive destination using the following SQL statement:
SQL> ALTER SYSTEM SET LOG_ARCHIVE_DEST_1='LOCATION=/disk1/oracle/oradata/payroll 2> MANDATORY' SCOPE=BOTH;
See Also:
Oracle9i Database Administrator's Guide for a description of archiving and Chapter 11 and the Oracle9i Database Reference for information about initialization parameters |
This section describes the tasks you perform to create a physical standby database.
Table 3-2 provides a checklist of the tasks that you perform to create a physical standby database and the database or databases on which you perform each task. There is also a reference to the section that describes the task in more detail.
Reference | Task | Database |
---|---|---|
Primary |
||
Primary |
||
Primary |
||
Prepare the Initialization Parameter File to be Copied to the Standby Database |
Primary |
|
Primary |
||
Set Initialization Parameters on a Physical Standby Database |
Standby |
|
Standby |
||
Primary and Standby |
||
Standby |
||
Primary and Standby |
||
Standby |
||
Standby |
||
Standby |
||
Primary |
On the primary database, query the V$DATAFILE
view to list the files that will be used to create the physical standby database, as follows:
SQL> SELECT NAME FROM V$DATAFILE; NAME ---------------------------------------------------------------------------- /disk1/oracle/oradata/payroll/system01.dbf /disk1/oracle/oradata/payroll/undotbs01.dbf /disk1/oracle/oradata/payroll/cwmlite01.dbf . . .
On the primary database, perform the following steps to make a closed backup copy of the primary database.
Issue the following SQL*Plus statement to shut down the primary database:
SQL> SHUTDOWN IMMEDIATE;
Copy the datafiles that you identified in Section 3.2.1 to a temporary location using an operating system utility copy command. The following example uses the UNIX cp
command:
cp /disk1/oracle/oradata/payroll/system01.dbf /disk1/oracle/oradata/payroll/standby/system01.dbf
Copying the datafiles to a temporary location will reduce the amount of time that the primary database must remain shut down.
Issue the following SQL*Plus statement to restart the primary database:
SQL> STARTUP;
On the primary database, create the control file for the standby database, as shown in the following example:
SQL> ALTER DATABASE CREATE STANDBY CONTROLFILE AS 2> '/disk1/oracle/oradata/payroll/standby/payroll2.ctl';
The filename for the newly created standby control file must be different from the filename of the current control file of the primary database. The control file must also be created after the last time stamp for the backup datafiles.
Create a traditional text initialization parameter file from the server parameter file used by the primary database; a traditional text initialization parameter file can be copied to the standby location and modified. For example:
SQL> CREATE PFILE='/disk1/oracle/dbs/initpayroll2.ora' FROM SPFILE;
Later, in Section 3.2.11, you will convert this file back to a server parameter file after it is modified to contain the parameter values appropriate for use with the physical standby database.
On the primary system, use an operating system copy utility to copy the following binary files from the primary system to the standby system:
Although most of the initialization parameter settings in the text initialization parameter file that you copied from the primary system are also appropriate for the physical standby database, some modifications need to be made.
Example 3-1 shows the portion of the standby initialization parameter file where values were modified for the physical standby database. Parameter values that changed are shown in bold typeface.
. . . db_name=PAYROLL compatible=9.2.0.1.0 control_files='/disk1/oracle/oradata/payroll/standby/payroll2.ctl' log_archive_start=TRUE standby_archive_dest='/disk1/oracle/oradata/payroll/standby' db_file_name_convert=('/disk1/oracle/oradata/payroll/', '/disk1/oracle/oradata/payroll/standby/') log_file_name_convert=('/disk1/oracle/oradata/payroll/', '/disk1/oracle/oradata/payroll/standby/') log_archive_format=log%d_%t_%s.arc log_archive_dest_1=('LOCATION=/disk1/oracle/oradata/payroll/standby/') standby_file_management=AUTO remote_archive_enable=TRUE instance_name=PAYROLL2 # The following parameter is required only if the primary and standby databases # are located on the same system. lock_name_space=PAYROLL2 . . .
The following list provides a brief explanation about the parameter settings shown in Example 3-1:
db_name
- Not modified. The same name as the primary database.compatible
- Not modified. The same as the primary database, 9.2.0.1.0.control_files
- Specify the path name and filename for the standby control file.log_archive_start
- Not modified. The same as the setting for the primary database, TRUE
.standby_archive_dest
- Specify the location of the archived redo logs that will be received from the primary database.log_file_name_convert
- Specify the location of the primary database logs followed by the standby location of the logs. This parameter will convert the filename of the primary database log to the filenames of the standby log. If the standby database is on the same system as the primary database or if the directory structure where the logs are located on the standby site is different from the primary site then this parameter is required. See Section 3.2.1 for the location of the logs on the primary database.log_archive_format
- Specify the format for the archived redo logs using a DBID (%d), thread (%t), and sequence number (%s).log_archive_dest_1
- Specify the location where the redo logs are to be archived on the standby system. (If a switchover occurs and this instance becomes the primary database, then this parameter will specify the location where the online redo logs will be archived.)standby_file_management
- Set to AUTO
.remote_archive_enable
- Set to TRUE
.instance_name
- If this parameter is defined, specify a different value for the standby database than the primary database when the primary and standby databases reside on the same host.lock_name_space
- Specify the standby database instance name.
Use this parameter when you create the physical standby database on the same system as the primary database. Change the INSTANCE_NAME
parameter to a value other than its primary database value, and set this LOCK_NAME_SPACE
initialization parameter to the same value that you specified for the standby database INSTANCE_NAME
initialization parameter.
See Also:
Chapter 11 for a complete explanations of all the initialization parameters that can be used to modify a Data Guard environment |
If the standby system is running on a Windows system, use the ORADIM
utility to create a Windows Service. For example:
WINNT> oradim -NEW -SID payroll2 -STARTMODE manual
See Also:
Oracle9i Database Administrator's Guide for Windows for more information about using the ORADIM utility |
On both the primary and standby sites, use Oracle Net Manager to configure a listener for the respective databases. If you plan to manage the configuration using the Data Guard broker, you must configure the listener to use the TCP/IP protocol and statically register service information for each database using the SID for the database instance.
To restart the listeners (to pick up the new definitions), enter the following LSNRCTL utility commands on both the primary and standby systems:
% lsnrctl stop % lsnrctl start
Enable dead connection detection by setting the SQLNET.EXPIRE_TIME
parameter to 2 in the SQLNET.ORA
parameter file on the standby system. For example:
SQLNET.EXPIRE_TIME=2
On both the primary and standby systems, use Oracle Net Manager to create a network service name for the primary and standby databases that will be used by log transport services.
The Oracle Net service name must resolve to a connect descriptor that uses the same protocol, host address, port, and SID that you specified when you configured the listeners for the primary and standby databases. The connect descriptor must also specify that a dedicated server be used.
See Also:
Oracle9i Net Services Administrator's Guide and the Oracle9i Database Administrator's Guide |
On an idle standby database, use the SQL CREATE
statement to create a server parameter file for the standby database from the text initialization parameter file that was edited in Section 3.2.6. For example:
SQL> CREATE SPFILE FROM PFILE='initpayroll2.ora';
On the standby database, issue the following SQL statements to start and mount the database in standby mode:
SQL> STARTUP NOMOUNT; SQL> ALTER DATABASE MOUNT STANDBY DATABASE;
On the standby database, start log apply services as shown in the following example:
SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT FROM SESSION;
The example includes the DISCONNECT FROM SESSION
option so that log apply services run in a background session.
This section describes the minimum amount of work you must do on the primary database to set up and enable archiving to the physical standby database.
See Also:
Chapter 5 for information about log transport services and Chapter 12 for reference information about additional attributes you can set on the |
To configure archive logging from the primary database to the standby site the LOG_ARCHIVE_DEST_
n
and LOG_ARCHIVE_DEST_STATE_
n
parameters must be defined.
The following example sets the initialization parameters needed to enable archive logging to the standby site:
SQL> ALTER SYSTEM SET LOG_ARCHIVE_DEST_2='SERVICE=payroll2' SCOPE=BOTH; SQL> ALTER SYSTEM SET LOG_ARCHIVE_DEST_STATE_2=ENABLE SCOPE=BOTH;
Archiving of redo logs to the remote standby location does not occur until after a log switch. A log switch occurs, by default, when an online redo log becomes full. To force the current redo logs to be archived immediately, use the SQL ALTER SYSTEM
statement on the primary database. For example:
SQL> ALTER SYSTEM ARCHIVE LOG CURRENT;
Once you create the physical standby database and set up log transport services, you may want verify that database modifications are being successfully shipped from the primary database to the standby database.
To see the new archived redo logs that were received on the standby database, you should first identify the existing archived redo logs on the standby database, archive a few logs on the primary database, and then check the standby database again. The following steps show how to perform these tasks.
On the standby database, query the V$ARCHIVED_LOG
view to identify existing archived redo logs. For example:
SQL> SELECT SEQUENCE#, FIRST_TIME, NEXT_TIME 2 FROM V$ARCHIVED_LOG ORDER BY SEQUENCE#; SEQUENCE# FIRST_TIME NEXT_TIME ---------- ------------------ ------------------ 8 11-JUL-02 17:50:45 11-JUL-02 17:50:53 9 11-JUL-02 17:50:53 11-JUL-02 17:50:58 10 11-JUL-02 17:50:58 11-JUL-02 17:51:03 3 rows selected.
On the primary database, archive the current log using the following SQL statement:
SQL> ALTER SYSTEM ARCHIVE LOG CURRENT;
On the standby database, query the V$ARCHIVED_LOG
view to verify the redo log was received:
SQL> SELECT SEQUENCE#, FIRST_TIME, NEXT_TIME 2> FROM V$ARCHIVED_LOG ORDER BY SEQUENCE#; SEQUENCE# FIRST_TIME NEXT_TIME ---------- ------------------ ------------------ 8 11-JUL-02 17:50:45 11-JUL-02 17:50:53 9 11-JUL-02 17:50:53 11-JUL-02 17:50:58 10 11-JUL-02 17:50:58 11-JUL-02 17:51:03 11 11-JUL-02 17:51:03 11-JUL-02 18:34:11 4 rows selected.
The logs are now available for log apply services to apply redo data to the standby database.
On the standby database, query the V$ARCHIVED_LOG
view to verify the archived redo log was applied.
SQL> SELECT SEQUENCE#,APPLIED FROM V$ARCHIVED_LOG 2 ORDER BY SEQUENCE#; SEQUENCE# APP --------- --- 8 YES 9 YES 10 YES 11 YES
4 rows selected.
See Also:
Section 5.9, "Monitoring Redo Log Archival Information" and Section 6.5, "Monitoring Log Apply Services for Physical Standby Databases" for information about how to verify that both log transport services and log apply services are working correctly |