Oracle8i Standby Database Concepts and Administration Release 2 (8.1.6) Part Number A76995-01 |
|
This chapter describes how to perform typical maintenance operations on a standby database. It includes the following topics:
To prevent possible problems, you should be aware of events that affect a standby database and learn how to monitor them. Most changes to a primary database are automatically propagated to a standby database through archived redo logs and so require no user intervention. Nevertheless, some changes to a primary database require manual intervention at the standby site.
This section contains the following topics:
Table 4-1 indicates whether a command is normally propagated or requires extra administrative efforts to be fully propagated. It also describes how to respond to these events.
Primary Database Event | Detection at Primary Site | Detection at Standby Site | Response |
---|---|---|---|
Archiving errors |
remote file server (RFS) process trace file |
Create scripts to push or pull archived redo logs if errors occur or if performance is degraded. See Adding Tablespaces or Datafiles to the Primary Database. |
|
Thread events |
|
Thread events are automatically propagated through archived logs, so no extra action is necessary. |
|
Redo log changes |
N/A |
Redo log changes do not affect standby database unless a redo log is cleared or lost. In these cases, you must rebuild the standby database. See Creating the Standby Database Files.
Pre-clear the logs on the standby database with the |
|
Issue CREATE CONTROLFILE |
|
Database functions normally until it encounters redo depending on any parameter changes. |
Re-create the standby control file (see Refreshing the Standby Database Control File). Re-create the standby database if the primary database is opened RESETLOGS. |
Media recovery performed |
|
N/A |
Re-create the standby database if the RESETLOGS option is utilized. |
Tablespace status changes (made read/write or read-only, placed online or offline) |
Status changes are automatically propagated, so no response is necessary. Datafiles remain online. |
||
Add datafile or create tablespace |
Manually create datafile and restart recovery. See Adding Tablespaces or Datafiles to the Primary Database. |
||
Drop tablespace |
|
Remove datafile from operating system. |
|
Tablespace or datafile taken offline, or datafile is dropped offline |
The tablespace or datafile requires recovery when you attempt to bring it online. |
Datafiles remain online. The tablespace or datafile is fine after standby database activation. |
|
Rename datafile |
|
N/A |
N/A |
Unlogged or unrecoverable operations |
|
Unlogged changes are not propagated to the standby database. If you want to apply these changes, see Performing Direct Path Operations. |
|
Recovery progress |
|
Make sure the standby database is not following behind the primary database. |
|
Autoextend a datafile |
|
May cause operation to fail on standby database because it lacks disk space. |
Ensure that there is enough disk space for the expanded datafile. |
Issue OPEN RESETLOGS or CLEAR UNARCHIVED LOGFILES statements |
|
Standby database is invalidated. |
Rebuild the standby database. See Creating the Standby Database Files. |
Change initialization parameter |
|
May cause failure because of redo depending on the changed parameter. |
Dynamically change the standby parameter or shut down the standby database and edit the initialization parameter file. |
The following table lists two methods for gaining information about archived redo logs received by the standby site:
The simplest way to determine the most recent archived log received by the standby site is to query the V$ARCHIVED_LOG view. This view is only useful after the standby site has started receiving logs, because before that time the view is populated by old archived log records generated from the primary control file. For example, you can execute the following script (sample output included):
col name format a20 col thread# format 999 col sequence# format 999 col first_change# format 999999 col next_change# format 999999 SELECT thread#, sequence# AS "SEQ#", name, first_change# AS "FIRSTSCN", next_change# AS "NEXTSCN",archived, deleted,completion_time AS "TIME" FROM v$archived_log / SQL> @archived_script THREAD# SEQ# NAME FIRSTSCN NEXTSCN ARC DEL TIME ------- ---------- -------------------- ---------- ---------- --- --- --------- 1 947 /arc_dest/arc_1_947 33113 33249 YES NO 23-JUN-99
To see the progression of the archiving of redo logs to the standby site, set the LOG_ARCHIVE_TRACE parameter in the primary and standby initialization parameter files.
The trace files for a database are located in the directory specified by the USER_DUMP_DEST parameter in the initialization parameter file. Connect to the primary and standby instances using SQL*Plus and issue a SHOW statement to determine the location:
SQL> SHOW PARAMETER user_dump_dest NAME TYPE VALUE ------------------------------------ ------- ------------------------------ user_dump_dest string ?/rdbms/log
The format for the archiving trace parameter is as follows, where trace_level is an integer:
LOG_ARCHIVE_TRACE=trace_level
To enable, disable, or modify the LOG_ARCHIVE_TRACE parameter in a primary database, do one of the following:
To enable, disable, or modify the LOG_ARCHIVE_TRACE parameter in a standby database in read-only or recovery mode, issue the following SQL statement:
ALTER SYSTEM SET ...;
If managed recovery is active, then issue the ALTER SYSTEM statement from a different standby session so that it affects trace output generated by the remote file service (RFS) when the next archived log is received from the primary database. For example, enter:
SQL> ALTER SYSTEM SET log_archive_trace=32;
The integer values for the LOG_ARCHIVE_TRACE parameter represent levels of tracing data. In general, the higher the level, the more detailed the information. The following integer levels are available:
You can combine tracing levels by setting the value of the LOG_ARCHIVE_TRACE parameter to the sum of the individual levels. For example, setting the parameter to 3 generates level 1 and level 2 trace output.
Following are examples of the ARC0 trace data generated on the primary site by the archival of redo log 387 to two different destinations: the service STANDBY1 and the local directory /vobs/oracle/dbs
.
Level Corresponding entry content (sample) ----- -------------------------------- ( 1) ARC0: Begin archiving log# 1 seq# 387 thrd# 1 ( 4) ARC0: VALIDATE ( 4) ARC0: PREPARE ( 4) ARC0: INITIALIZE ( 4) ARC0: SPOOL ( 8) ARC0: Creating archive destination 2 : 'standby1' (16) ARC0: Issuing standby Create archive destination at 'standby1' ( 8) ARC0: Creating archive destination 1 : '/vobs/oracle/dbs/d1arc1_387.dbf' (16) ARC0: Archiving block 1 count 1 to : 'standby1' (16) ARC0: Issuing standby Archive of block 1 count 1 to 'standby1' (16) ARC0: Archiving block 1 count 1 to : '/vobs/oracle/dbs/d1arc1_387.dbf' ( 8) ARC0: Closing archive destination 2 : standby1 (16) ARC0: Issuing standby Close archive destination at 'standby1' ( 8) ARC0: Closing archive destination 1 : /vobs/oracle/dbs/d1arc1_387.dbf ( 4) ARC0: FINISH ( 2) ARC0: Archival success destination 2 : 'standby1' ( 2) ARC0: Archival success destination 1 : '/vobs/oracle/dbs/d1arc1_387.dbf' ( 4) ARC0: COMPLETE, all destinations archived (16) ARC0: ArchivedLog entry added: /vobs/oracle/dbs/d1arc1_387.dbf (16) ARC0: ArchivedLog entry added: standby1 ( 4) ARC0: ARCHIVED ( 1) ARC0: Completed archiving log# 1 seq# 387 thrd# 1 (32) Propagating archive 0 destination version 0 to version 2 Propagating archive 0 state version 0 to version 2 Propagating archive 1 destination version 0 to version 2 Propagating archive 1 state version 0 to version 2 Propagating archive 2 destination version 0 to version 1 Propagating archive 2 state version 0 to version 1 Propagating archive 3 destination version 0 to version 1 Propagating archive 3 state version 0 to version 1 Propagating archive 4 destination version 0 to version 1 Propagating archive 4 state version 0 to version 1 (64) ARCH: changing ARC0 KCRRNOARCH->KCRRSCHED ARCH: STARTING ARCH PROCESSES ARCH: changing ARC0 KCRRSCHED->KCRRSTART ARCH: invoking ARC0 ARC0: changing ARC0 KCRRSTART->KCRRACTIVE ARCH: Initializing ARC0 ARCH: ARC0 invoked ARCH: STARTING ARCH PROCESSES COMPLETE ARC0 started with pid=8 ARC0: Archival started
Following is the trace data generated by the RFS process on the standby site as it receives archived log 387 in directory /stby
and applies it to the standby database:
level trace output (sample) ---- ------------------ ( 4) RFS: Startup received from ARCH pid 9272 ( 4) RFS: Notifier ( 4) RFS: Attaching to standby instance ( 1) RFS: Begin archive log# 2 seq# 387 thrd# 1 (32) Propagating archive 5 destination version 0 to version 2 (32) Propagating archive 5 state version 0 to version 1 ( 8) RFS: Creating archive destination file: /stby/parc1_387.dbf (16) RFS: Archiving block 1 count 11 ( 1) RFS: Completed archive log# 2 seq# 387 thrd# 1 ( 8) RFS: Closing archive destination file: /stby/parc1_387.dbf (16) RFS: ArchivedLog entry added: /stby/parc1_387.dbf ( 1) RFS: Archivelog seq# 387 thrd# 1 available 04/02/99 09:40:53 ( 4) RFS: Detaching from standby instance ( 4) RFS: Shutdown received from ARCH pid 9272
Query the V$LOG_HISTORY view on the standby database, which records the latest log sequence number that has been applied. For example, issue the following query:
SQL> SELECT thread#, max(sequence#) AS "LAST_APPLIED_LOG" 2> FROM v$log_history 3> GROUP BY thread#; THREAD# LAST_APPLIED_LOG ------- ---------------- 1 967
In this example, the archived redo log with log sequence number 967 is the most recently applied log.
Typically, physical changes to the primary database require a manual response on the standby database. This section contains the following topics:
Adding a tablespace or datafile to the primary database generates redo that, when applied at the standby database, automatically adds the datafile name to the standby control file. If the standby database locates the file with the filename specified in the control file, then recovery continues. If the standby database is unable to locate a file with the filename specified in the control file, then recovery terminates.
Perform one of the following procedures to create a new datafile in the primary database and update the standby database. Note that if you do not want the new datafile in the standby database, you can take the datafile offline manually using the following syntax:
SQL> ALTER DATABASE DATAFILE 'filename' OFFLINE DROP;
t_db2.f
in tablespace tbs_2, issue:
SQL> CREATE TABLESPACE tbs_2 DATAFILE 't_db2.f' SIZE 2M;
SQL> STARTUP NOMOUNT pfile=/private1/stby/initSTANDBY.ora
If the standby database is currently in managed recovery mode, skip to step 4.
SQL> ALTER DATABASE MOUNT STANDBY DATABASE; SQL> RECOVER MANAGED STANDBY DATABASE;
SQL> ALTER SYSTEM SWITCH LOGFILE;
If the recovery process on the standby database tries to apply the redo containing the CREATE TABLESPACE statement, it stops because the new datafile does not exist on the standby site.
SQL> RECOVER MANAGED STANDBY DATABASE CANCEL;
Note that CREATE TABLESPACE redo adds the new filename to the standby control file. The following alert.log
entry is generated:
WARNING! Recovering datafile 2 from a fuzzy file. If not the current file it might be an online backup taken without entering the begin backup command. Successfully added datafile 2 to media recovery Datafile #2: '/private1/stby/t_db2.f'
SQL> ALTER DATABASE CREATE DATAFILE '/private1/stby/t_db2.f' AS '/private1/stby/t_db2.f';
SQL> RECOVER MANAGED STANDBY DATABASE;
Continue normal processing on the primary database. The primary and standby databases are now synchronized.
See Also:
For more information on offline datafile alterations, see Taking Datafiles in the Standby Database Offline. |
Datafile renames on your primary database do not take effect at the standby database until you refresh the standby database control file. To keep the datafiles at the primary and standby databases synchronized when you rename primary database datafiles, perform analogous operations on the standby database.
You can add redo log file groups or members to the primary database without affecting the standby database. Similarly, you can drop log file groups or members from the primary database without affecting your standby database. Enabling and disabling of threads at the primary database has no effect on the standby database.
Consider whether to keep the online redo log configuration the same at the primary and standby databases. Although differences in the online redo log configuration between the primary and standby databases do not affect the standby database functionality, they do affect the performance of the standby database after activation. For example, if the primary database has 10 redo logs and the standby database has 2, and you then activate the standby database so that it functions as the new primary database, the new primary database is forced to archive more frequently than the old primary database.
To prevent problems after standby activations, Oracle Corporation recommends keeping the online redo log configuration the same at the primary and standby databases. Note that when you enable a log file thread with the ALTER DATABASE ENABLE THREAD statement at the primary database, you must create a new control file for your standby database before activating it. See Refreshing the Standby Database Control File for procedures.
If you clear log files at the primary database by issuing the ALTER DATABASE CLEAR UNARCHIVED LOGFILE statement, or open the primary database using the RESETLOGS option, you invalidate the standby database. Because both of these operations reset the primary log sequence number to 1, you must re-create the standby database in order to be able to apply archived logs generated by the primary database. See Creating the Standby Database Files for the procedure. See Scenario 8: Re-Creating a Standby Database for additional information.
If you use the CREATE CONTROLFILE statement at the primary database to perform any of the following operations, you may invalidate the control file for the standby database:
Using the CREATE CONTROLFILE statement with the RESETLOGS option on your primary database will force the next open of the primary database to reset the online logs, thereby invalidating the standby database.
If you have invalidated the control file for the standby database, re-create the file using the procedures in Refreshing the Standby Database Control File.
You can take standby database datafiles offline as a means to support a subset of your primary database's datafiles. For example, you may decide not to recover the primary database's temporary tablespaces on the standby database.
Take the datafiles offline using the following statement on the standby database:
ALTER DATABASE DATAFILE 'filename' OFFLINE DROP;
If you execute this statement, then the tablespace containing the offline files must be dropped after opening the standby database.
When you perform a direct load originating from any of the following, the performance improvement applies only to the primary database (there is no corresponding recovery process performance improvement on the standby database):
The standby database recovery process continues to sequentially read and apply the redo information generated by the unrecoverable direct load.
Primary database processes using the UNRECOVERABLE option are not propagated to the standby database because these processes do not appear in the archived redo logs. If you perform an UNRECOVERABLE operation at the primary database and then recover the standby database, you do not receive error messages during recovery; instead, Oracle writes error messages in the standby database alert.log
file. The following error message is displayed:
26040, 00000, "Data block was loaded using the NOLOGGING option\n" //* Cause: Trying to access data in block that was loaded without //* redo generation using the NOLOGGING/UNRECOVERABLE option //* Action: Drop the object containing the block.
Although the error message recommends dropping the object that contains the block, do not perform this operation. Instead, perform any one of the following tasks:
For more details, see Taking Datafiles in the Standby Database Offline and Scenario 4: Recovering After the NOLOGGING Clause Was Specified.
See Also:
If you have performed UNRECOVERABLE operations on your primary database, determine whether a new backup is required.
SELECT unrecoverable_change#, to_char(unrecoverable_time, 'mm-dd-yyyy hh:mi:ss') FROM v$datafile;
The following steps describe how to refresh, or create a copy, of changes you have made to the primary database control file. Refresh the standby database control file after making major structural changes to the primary database, such as adding or dropping files.
SQL> RECOVER CANCEL # for manual recovery mode SQL> RECOVER MANAGED STANDBY DATABASE CANCEL # for managed recovery mode
SQL> SHUTDOWN IMMEDIATE
SQL> ALTER DATABASE CREATE STANDBY CONTROLFILE AS 'filename';
SQL> ALTER DATABASE MOUNT STANDBY DATABASE;
SQL> RECOVER STANDBY DATABASE # recovers using location for logs # specified in initialization parameter file SQL> RECOVER FROM 'location' STANDBY DATABASE # recovers from specified # location
After creating the standby database, you can clear standby database online redo logs to optimize performance by issuing the following statement, where integer refers to the number of the log group:
ALTER DATABASE CLEAR LOGFILE GROUP integer;
This statement optimizes standby activation because it is no longer necessary for Oracle to zero the logs at activation. Zeroing involves writing zeros to the entire contents of the redo log and then setting a new header to make the redo log look like it was when it was created. Zeroing occurs during a RESETLOGS operation.
If you clear the logs manually, Oracle realizes at activation that the logs already have zeros and skips the zeroing step. This optimization is important because it can take a long time to write zeros into all of the online logs. If you prefer not to perform this operation during maintenance, Oracle clears the online logs automatically during activation.
If necessary, you can back up your standby database, but not while the database is in manual or managed recovery mode. You must take the standby database out of managed recovery mode, make the backups, then resume managed recovery. You can make the backups when the database is shut down or in read-only mode.
The following table lists some advantages and disadvantages of these methods:
RECOVER MANAGED STANDBY DATABASE CANCEL # for managed recovery RECOVER CANCEL # for manual recovery
ALTER DATABASE OPEN READ ONLY
Minimize the time that the database is down. For example, to back up datafiles tbs11.f
, tbs12.f
, and tbs13.f
in tablespace TBS_1 on UNIX you might enter:
% cp /disk1/oracle/dbs/tbs11.f /disk2/backup/tbs11.bk % cp /disk1/oracle/dbs/tbs12.f /disk2/backup/tbs12.bk % cp /disk1/oracle/dbs/tbs13.f /disk2/backup/tbs13.bk
RECOVER MANAGED STANDBY DATABASE # for managed recovery RECOVER STANDBY DATABASE # for manual recovery
RECOVER MANAGED STANDBY DATABASE CANCEL # for managed recovery RECOVER CANCEL # for manual recovery
SHUTDOWN IMMEDIATE
tbs11.f
, tbs12.f
, and tbs13.f
in tablespace TBS_1 on UNIX you might enter:
% cp /disk1/oracle/dbs/tbs11.f /disk2/backup/tbs11.bk % cp /disk1/oracle/dbs/tbs12.f /disk2/backup/tbs12.bk % cp /disk1/oracle/dbs/tbs13.f /disk2/backup/tbs13.bk
STARTUP NOMOUNT pfile = initSTANDBY.ora
ALTER DATABASE MOUNT STANDBY DATABASE
RECOVER MANAGED STANDBY DATABASE # for managed recovery RECOVER STANDBY DATABASE # for manual recovery
|
![]() Copyright © 1996-2000, Oracle Corporation. All Rights Reserved. |
|