DB2 10.5 for Linux, UNIX, and Windows

MON_GET_HADR table function - Returns high availability disaster recovery (HADR) monitoring information

This function returns high availability disaster recovery (HADR) monitoring information.

Authorization

One of the following authorities is required to execute the routine:
  • EXECUTE privilege on the routine
  • DATAACCESS authority
  • DBADM authority
  • SQLADM authority

Default PUBLIC privilege

None

Syntax

Read syntax diagramSkip visual syntax diagram
>>-MON_GET_HADR--(--member--)----------------------------------><

The schema is SYSPROC.

Routine parameters

member
An input argument of type INTEGER that specifies a member number. Returned rows represent log streams being processed by the member. Specify -1 for the current database member, or -2 for all active database members. If the null value is specified, -1 is set implicitly.

Information returned

Table 1. Information returned for MON_GET_HADR
Column Name Data Type Description
HADR_ROLE VARCHAR(13) hadr_role - HADR Role monitor element
REPLAY_TYPE VARCHAR(9) replay_type - HADR replication type monitor element
HADR_SYNCMODE VARCHAR(10) hadr_syncmode - HADR Synchronization Mode monitor element
STANDBY_ID SMALLINT standby_id - Standby ID monitor element
LOG_STREAM_ID INTEGER log_stream_id - Log stream ID monitor element
HADR_STATE VARCHAR(23) hadr_state - HADR State monitor element
HADR_FLAGS VARCHAR(512) hadr_flags - HADR flags monitor element
PRIMARY_MEMBER_HOST VARCHAR(255) primary_member_host - Primary member host monitor element
PRIMARY_INSTANCE VARCHAR(128) primary_instance - Primary instance monitor element
PRIMARY_MEMBER SMALLINT primary_member - Primary member monitor element
STANDBY_MEMBER_HOST VARCHAR(255) standby_member_host - Standby member hostname monitor element
STANDBY_INSTANCE VARCHAR(128) standby_instance - Standby instance monitor element
STANDBY_MEMBER SMALLINT standby_member - Standby member monitor element
HADR_CONNECT_STATUS VARCHAR(12) hadr_connect_status - HADR Connection Status monitor element
HADR_CONNECT_STATUS_TIME TIMESTAMP hadr_connect_status_time - HADR connect status time monitor element
HEARTBEAT_INTERVAL BIGINT heartbeat_interval - Heartbeat interval monitor element
HADR_TIMEOUT BIGINT hadr_timeout - HADR Timeout monitor element
TIME_SINCE_LAST_RECV BIGINT time_since_last_recv - Time since last message received monitor element
PEER_WAIT_LIMIT BIGINT peer_wait_limit - Peer wait limit monitor element
LOG_HADR_WAIT_CUR BIGINT log_hadr_wait_cur - Current logger wait time monitor element
LOG_HADR_WAIT_TIME BIGINT log_hadr_wait_time - Total logger wait time monitor element
LOG_HADR_WAITS_TOTAL BIGINT log_hadr_waits_total - Total logger wait events monitor element
SOCK_SEND_BUF_REQUESTED BIGINT sock_send_buf_requested - Requested socket send buffer size monitor element
SOCK_SEND_BUF_ACTUAL BIGINT sock_send_buf_actual - Actual socket send buffer size monitor element
SOCK_RECV_BUF_REQUESTED BIGINT sock_recv_buf_requested - Requested socket receive buffer size monitor element
SOCK_RECV_BUF_ACTUAL BIGINT sock_recv_buf_actual - Actual socket receive buffer size monitor element
PRIMARY_LOG_FILE VARCHAR(12) primary_log_file - Primary log file monitor element
PRIMARY_LOG_PAGE BIGINT primary_log_page - Primary log page monitor element
PRIMARY_LOG_POS BIGINT primary_log_pos - Primary log position monitor element
PRIMARY_LOG_TIME TIMESTAMP primary_log_time - Primary log time monitor element
STANDBY_LOG_FILE VARCHAR(12) standby_log_file - Standby log file monitor element
STANDBY_LOG_PAGE BIGINT standby_log_page - Standby log page monitor element
STANDBY_LOG_POS BIGINT standby_log_pos - Standby log position monitor element
STANDBY_LOG_TIME TIMESTAMP standby_log_time - Standby log time monitor element
HADR_LOG_GAP BIGINT hadr_log_gap - HADR Log Gap monitor element
STANDBY_REPLAY_LOG_FILE VARCHAR(12) standby_replay_log_file - Standby replay log file monitor element
STANDBY_REPLAY_LOG_PAGE BIGINT standby_replay_log_page - Standby replay log page monitor element
STANDBY_REPLAY_LOG_POS BIGINT standby_replay_log_pos - Standby replay log position monitor element
STANDBY_REPLAY_LOG_TIME TIMESTAMP standby_replay_log_time - Standby replay log time monitor element
STANDBY_RECV_REPLAY_GAP BIGINT standby_recv_replay_gap - Standby receive replay gap monitor element
STANDBY_REPLAY_DELAY BIGINT standby_replay_delay - Standby replay delay monitor element
STANDBY_RECV_BUF_SIZE BIGINT standby_recv_buf_size - Standby receive buffer size monitor element
STANDBY_RECV_BUF_PERCENT DOUBLE standby_recv_buf_percent - Standby receive buffer percentage monitor element
STANDBY_SPOOL_LIMIT BIGINT standby_spool_limit - Standby spool limit monitor element
STANDBY_SPOOL_PERCENT DOUBLE standby_spool_percent - Standby spool percentage monitor element
PEER_WINDOW BIGINT peer_window - Peer window monitor element
PEER_WINDOW_END TIMESTAMP peer_window_end - Peer window end
TAKEOVER_APP_REMAINING_PRIMARY BIGINT takeover_app_remaining_primary - Applications remaining on primary monitor element
TAKEOVER_APP_REMAINING_STANDBY BIGINT takeover_app_remaining_standby - Applications remaining on standby monitor element
READS_ON_STANDBY_ENABLED CHAR(1) reads_on_standby_enabled - reads on standby enabled monitor element
STANDBY_REPLAY_ONLY_WINDOW_ACTIVE CHAR(1) standby_replay_only_window_active - Standby replay only window active monitor element
STANDBY_REPLAY_ONLY_WINDOW_START TIMESTAMP standby_replay_only_window_start - Replay only window start time monitor element
STANDBY_REPLAY_ONLY_WINDOW_TRAN_COUNT BIGINT standby_replay_only_window_tran_count - Replay only window transactions monitor element
HEARTBEAT_MISSED INTEGER heartbeat_missed - Heartbeats missed monitor element
HEARTBEAT_EXPECTED INTEGER heartbeat_expected - Heartbeats expected monitor element
STANDBY_ERROR_TIME TIMESTAMP standby_error_time - Standby error time monitor element

Usage notes

HADR pair view

Certain fields are applicable to primary or standby only. For example, PEER_WAIT_LIMIT is applicable only to primary, STANDBY_RECV_BUF_SIZE, STANDBY_SPOOL_LIMIT, READS_ON_STANDBY_ENABLED are applicable only to standby. When this kind of information is reported, the database currently in the role is used (which may be the remote database), rather than the local database. For example, PEER_WAIT_LIMIT seen on a standby database is the value configured on the primary database, not the local config of standby database (which will be used only when the standby turns into primary).

Information about remote database

Primary and standby exchange monitoring information via heartbeat messages. Therefore information about the remote database can be slightly out of date. See heartbeat interval (reported in table function) to estimate timeliness of information (network latency can add additional delay). If a database has never connected to its partner database since activation, information about remote database may be returned as SQL NULL to indicate "unknown".

Log shipping channel end points
The end points for a log shipping channel is uniquely identified by host, instance and member:
  • Primary side: PRIMARY_MEMBER_HOST, PRIMARY_INSTANCE, PRIMARY_MEMBER
  • Standby side: STANDBY_MEMBER_HOST, STANDBY_INSTANCE, STANDBY_MEMBER
Until a connection is made, end point information of remote end may not be available. When information not available, empty strings will be returned for host and instance names and zero returned for member ID. In addition when in a DB2® Enterprise Server Edition environment, 0 is always returned for the member ID.
Note on unit of time duration

Per monitor table function convention, all MON_GET_HADR time duration fields use milliseconds as unit. For those fields reflecting a configuration parameter (such as HADR_TIMEOUT, HADR_PEER_WINDOW) whose unit in configuration is seconds, the number returned by MON_GET_HADR table function will be different from the number used in db2 get/update db cfg command, and the number returned by SYSIBMADM.DBCFG admin view or SYSPROC.DB_GET_CFG() table function. For example, for a 60 second HADR_TIMEOUT value, MON_GET_HADR will return 60000, while the configuration oriented interfaces will return 60. To convert the millisecond number to second, use column_name/1000 in your query.

Usage during takeover

During takeover, there may be a period when clients cannot connect to either primary or standby database. The recommended monitoring method during takeover is db2pd -hadr.

Column Order and Groups:
  1. Cluster level summary: HADR_ROLE, REPLAY_TYPE, HADR_SYNCMODE.
  2. Log stream level summary: STANDBY_ID, LOG_STREAM_ID, HADR_STATE
  3. Log shipping channel end points:
    1. Primary side: PRIMARY_MEMBER_HOST, PRIMARY_INSTANCE, PRIMARY_MEMBER
    2. Standby side: STANDBY_MEMBER_HOST, STANDBY_INSTANCE, STANDBY_MEMBER

      The end points uniquely identify an HADR log shipping channel in all scenarios. Host, instance or MEMBER_ID uniquely identifies a member.

  4. Connection details:
    1. Status: HADR_CONNECT_STATUS, HADR_CONNECT_STATUS_TIME
    2. Network timing: HEARTBEAT_INTERVAL, HADR_TIMEOUT, TIME_SINCE_LAST_RECV
    3. Logger wait timing: PEER_WAIT_LIMIT, LOG_HADR_WAIT_CUR, LOG_HADR_WAIT_TIME, LOG_HADR_WAITS_TOTAL
    4. TCP buffer size: SOCK_SEND_BUF_REQUESTED, SOCK_SEND_BUF_ACTUAL, SOCK_RECV_BUF_REQUESTED, SOCK_RECV_BUF_ACTUAL
  5. Log position details:
    1. Primary log position: PRIMARY_LOG_FILE, PRIMARY_LOG_PAGE, PRIMARY_LOG_POS, PRIMARY_LOG_TIME
    2. Standby log receive position: STANDBY_LOG_FILE, STANDBY_LOG_PAGE, STANDBY_LOG_POS, STANDBY_LOG_TIME
    3. Primary-standby log gap: HADR_LOG_GAP
    4. Standby log replay position: STANDBY_REPLAY_LOG_FILE, STANDBY_REPLAY_LOG_PAGE, STANDBY_REPLAY_LOG_POS, STANDBY_REPLAY_LOG_TIME
    5. Standby receive-replay gap: STANDBY_RECV_REPLAY_GAP
    6. Replay delay: STANDBY_REPLAY_DELAY
  6. Log buffer and spooling: STANDBY_RECV_BUF_SIZE, STANDBY_RECV_BUF_PERCENT, STANDBY_SPOOL_LIMIT
  7. Peer window: PEER_WINDOW, PEER_WINDOW_END
  8. Takeover: TAKEOVER_APP_REMAINING_PRIMARY, TAKEOVER_APP_REMAINING_STANDBY
  9. Reads on Standby: READS_ON_STANDBY_ENABLED, STANDBY_REPLAY_ONLY_WINDOW_ACTIVE, STANDBY_REPLAY_ONLY_WINDOW_START, STANDBY_REPLAY_ONLY_WINDOW_TRAN_COUNT

Examples

  1. SELECT HADR_ROLE, STANDBY_ID, HADR_STATE, varchar(PRIMARY_MEMBER_HOST ,20)
       as PRIMARY_MEMBER_HOST, varchar(STANDBY_MEMBER_HOST ,20)
       as STANDBY_MEMBER_HOST from table(MON_GET_HADR(NULL))

    The following is an example of output from this query.

    HADR_ROLE     STANDBY_ID HADR_STATE              PRIMARY_MEMBER_HOST 
    ------------- ---------- ----------------------- --------------------
    PRIMARY                1 PEER                    hostP.ibm.com       
    PRIMARY                2 REMOTE_CATCHUP          hostP.ibm.com       
    PRIMARY                3 REMOTE_CATCHUP          hostP.ibm.com       
     
    STANDBY_MEMBER_HOST   
    --------------------  
    hostS1.ibm.com        
    hostS2.ibm.com        
    hostS3.ibm.com        
    
    3 record(s) selected.

    Query is issued to a primary database with 3 standbys in which 3 rows are returned. Each row represents a primary-standby log shipping channel. The HADR_ROLE column represents the role of the database to which the query is issued. Therefore it is PRIMARY on all rows.

  2. SELECT HADR_ROLE, STANDBY_ID, HADR_STATE, varchar(PRIMARY_MEMBER_HOST ,20)
       as PRIMARY_MEMBER_HOST, varchar(STANDBY_MEMBER_HOST ,20)
       as STANDBY_MEMBER_HOST from table(MON_GET_HADR(NULL))

    The following is an example of output from this query.

    HADR_ROLE     STANDBY_ID HADR_STATE              PRIMARY_MEMBER_HOST 
    ------------- ---------- ----------------------- --------------------
    STANDBY                0 PEER                    hostP.ibm.com       
     
    STANDBY_MEMBER_HOST  
    -------------------- 
    hostS1.ibm.com       
    
    1 record(s) selected.

    Query is issued to a standby database with reads on standby enabled. Standby only knows about its own primary. Only one row is returned even if the standby is part of a multiple standby system. STANDBY_ID is always zero when query is issued to a standby.

  3. The following example is for HADR in a DB2 pureScale® environment only. The environment for this example has three member clusters. On the primary, member 0 is assisting member 1. Standby member 0 is the replay member.
    • With member ID 0, the HADR information for log stream 0, and the assisted log stream (log stream 1) is output:

      SELECT LOG_STREAM_ID, PRIMARY_MEMBER, STANDBY_MEMBER, HADR_STATE, HADR_FLAGS
         FROM TABLE (MON_GET_HADR(0))
      
      LOG_STREAM_ID PRIMARY_MEMBER STANDBY_MEMBER HADR_STATE     HADR_FLAGS
      ------------- -------------- -------------- -------------- -----------------------
      0             0              0              PEER                    
      1             0              0              REMOTE_CATCHUP ASSISTED_REMOTE_CATCHUP
    • With member ID 1, the HADR information for log steam 1 is output:
      SELECT LOG_STREAM_ID, PRIMARY_MEMBER, STANDBY_MEMBER, HADR_STATE, HADR_FLAGS
         FROM TABLE (MON_GET_HADR(1))
      
      LOG_STREAM_ID PRIMARY_MEMBER STANDBY_MEMBER HADR_STATE      HADR_FLAGS
      ------------- -------------- -------------- --------------- ----------
      1             1              0              DISCONNECTED    
    • For log stream ID 2, the HADR information for log stream 2 is output:
      SELECT LOG_STREAM_ID, PRIMARY_MEMBER, STANDBY_MEMBER, HADR_STATE, HADR_FLAGS
         FROM TABLE (MON_GET_HADR(2))
      
      LOG_STREAM_ID PRIMARY_MEMBER STANDBY_MEMBER HADR_STATE     HADR_FLAGS
      ------------- -------------- -------------- -------------- ----------
      2             2              0              PEER           
    • When specifying -2 as member ID, HADR information on all log streams is reported. For assisted remote catchup, only the record from the assisting member is returned, and HADR_FLAGS indicates that it is in an assisted remote catchup state.
      SELECT LOG_STREAM_ID, PRIMARY_MEMBER, STANDBY_MEMBER, HADR_STATE, HADR_FLAGS
         FROM TABLE (MON_GET_HADR(-2))
      
      LOG_STREAM_ID PRIMARY_MEMBER STANDBY_MEMBER HADR_STATE       HADR_FLAGS
      ------------- -------------- -------------- ---------------- -----------------------
      0             0              0              PEER             
      1             0              0              REMOTE_CATCHUP   ASSISTED_REMOTE_CATCHUP
      2             2              0              PEER