-- ------------------------------------------------------------------------
-- AUTHOR: Mohammad Abdul Momin Arju
-- September 2010.
-- ------------------------------------------------------------------------
-- PURPOSE:
-- This script is used to troubleshoot Oracle Data Guard issues for
-- physical standby database.
-- ------------------------------------------------------------------------
-- DISCLAIMER:
-- This script is provided for educational purposes only.
-- Test it before you run in your production database.
-- ------------------------------------------------------------------------
-- Content of the Script
set echo off-- ARCHIVER can be STOPPED/STARTED/FAILED -
set feedback off
column timecol new_value timestamp
column spool_extension new_value suffix
select to_char(sysdate,'Mondd_hhmi') timecol,
'.out' spool_extension from sys.dual;
column output new_value dbname
select value || '_' output
from v$parameter where name = 'db_name';
spool dgdiag_phystby_&&dbname&×tamp&&suffix
set lines 200
set pagesize 35
set trim on
set trims on
alter session set nls_date_format = 'MON-DD-YYYY HH24:MI:SS';
set feedback on
select to_char(sysdate) time from dual;
set echo on
-- Archiver FAILED means archiver failed to archive a log last time but will try
-- again within 5 minutes
-- LOG_SWITCH_WAIT can be ARCHIVE LOG/CLEAR LOG/CHECKPOINT/NULL -
-- NULL means ALTER SYSTEM SWITCH LOGFILE is hung but there is room in the current online redo log
column host_name format a20 tru-- Select from v$database will give us the generic information about how this standby is
column version format a9 tru
select instance_name,host_name,version,archiver,log_switch_wait from v$instance;
-- setup. The database_role can be SNAPSHOT STANDBY/LOGICAL STANDBY/PHYSICAL STANDBY/PRIMARY
-- It should be standby for standby database. PROTECTION_MODE can be,
-- MAXIMUM PROTECTION - Database is running in maximized protection mode
-- MAXIMUM AVAILABILITY - Database is running in maximized availability mode
-- RESYNCHRONIZATION - Database is running in resynchronization mode
-- MAXIMUM PERFORMANCE - Database is running in maximized protection mode
-- UNPROTECTED - Database is unprotected (this normally occurs when the primary database is mounted and not open)
-- If protection_level is different than protection_mode then for some
-- reason the mode listed in protection_mode experienced a need to downgrade. Once the
-- error condition has been corrected the protection_level should match the protection_mode
-- after the next log switch.
column ROLE format a7 tru-- Force logging is not mandatory but is recommended. Supplemental logging should be enabled
select name,database_role,log_mode,controlfile_type,protection_mode,protection_level
from v$database;
-- on the standby if a logical standby is in the configuration. During normal
-- operations it is acceptable for SWITCHOVER_STATUS to be SESSIONS ACTIVE or NOT ALLOWED.
column force_logging format a13 tru-- This query produces a list of all archive destinations and shows if they are enabled,
column remote_archive format a14 tru
column dataguard_broker format a16 tru
select force_logging,remote_archive,supplemental_log_data_pk,supplemental_log_data_ui,
switchover_status,dataguard_broker from v$database;
-- what process is servicing that destination, if the destination is local or remote,
-- and if remote what the current mount ID is.
-- Status can be, VALID - Initialized and available
-- INACTIVE - No destination information
-- DEFERRED - Manually disabled by the user
-- ERROR - Error during open or copy
-- DISABLED - Disabled after error
-- BAD PARAM - Parameter has errors
-- ALTERNATE - Destination is in an alternate state
-- FULL - Exceeded quota size for the destination.
-- For a physical standby we should have at least one remote destination that points the primary set.
COLUMN destination FORMAT A35 WRAP-- If the protection mode of the standby is set to anything higher than max performance
column process format a10
column archiver format a10
column ID format 99
select dest_id "ID",destination,status,target,
archiver,schedule,process,mountid
from v$archive_dest;
-- then we need to make sure the remote destination that points to the primary is set
-- with the correct options else we will have issues during switchover.
select dest_id,process,transmit_mode,async_blocks,-- The following select will show any errors that occured the last time an attempt to
net_timeout,delay_mins,reopen_secs,register,binding
from v$archive_dest;
-- archive to the destination was attempted. If ERROR is blank and status is VALID then
-- the archive completed correctly.
column error format a80 tru-- Determine if any error conditions have been reached by querying the v$dataguard_status
select dest_id,status,error from v$archive_dest;
column message format a100-- The following query is ran to get the status of the Standby Redo Log's on the standby. If the
select message, timestamp
from v$dataguard_status
where severity in ('Error','Fatal')
order by timestamp;
-- primary is archiving with the LGWR process and SRL's are present (in the correct
-- number and size) then we should see a group# active.
select group#,sequence#,bytes,used,archived,status from v$standby_log;-- The above SRL's should match in number and in size with the Online Redo Log's returned below:
select group#,thread#,sequence#,bytes,archived,status from v$log;-- Query v$managed_standby to see the status of processes involved in the configuration.
select process,status,client_process,sequence#,block#,active_agents,known_agents-- Verify that the last sequence# received and the last sequence# applied to standby
from v$managed_standby;
-- database.
select al.thrd "Thread", almax "Last Seq Received", lhmax "Last Seq Applied"-- V$ARCHIVE_GAP displays information about archive gaps on a standby database.
from (select thread# thrd, max(sequence#) almax
from v$archived_log
where resetlogs_change#=(select resetlogs_change# from v$database)
group by thread#) al,
(select thread# thrd, max(sequence#) lhmax
from v$log_history
where first_time=(select max(first_time) from v$log_history)
group by thread#) lh
where al.thrd = lh.thrd;
-- This view can be used to find out the current archive gap that is blocking
-- recovery for the current recovery incarnation.
select * from v$archive_gap;-- It is always better to verify all non-default init parameters.
set numwidth 5
column name format a30 tru
column value format a50 wra
select name, value
from v$parameter
where isdefault = 'FALSE';
spool off
No comments:
Post a Comment