DB2 Version 10.1 for Linux, UNIX, and Windows

SNAPLOCKWAIT administrative view and SNAP_GET_LOCKWAIT table function - Retrieve lockwait logical data group snapshot information

The SNAPLOCKWAIT administrative view and the SNAP_GET_LOCKWAIT table function return snapshot information about lock waits, in particular, the lockwait logical data group.

Depending on if you are using the administrative view or the table function, refer to one of the following sections:

SNAPLOCKWAIT administrative view

This administrative view allows you to retrieve lockwait logical data group snapshot information for the currently connected database.

Used with the SNAPLOCK administrative view, the SNAPLOCKWAIT administrative view provides information equivalent to the GET SNAPSHOT FOR LOCKS ON database-alias CLP command.

The schema is SYSIBMADM.

Refer to Table 1 for a complete list of information that can be returned.

Authorization

One of the following authorizations is required:
  • SELECT privilege on the SNAPLOCKWAIT administrative view
  • CONTROL privilege on the SNAPLOCKWAIT administrative view
  • DATAACCESS authority
One of the following is required to use the table function:
  • EXECUTE privilege on the SNAP_GET_LOCKWAIT table function
  • DATAACCESS authority
In addition, to access snapshot monitor data, one of the following authorities is also required:
  • SYSMON
  • SYSCTRL
  • SYSMAINT
  • SYSADM

Default PUBLIC privilege

In a non-restrictive database, SELECT privilege is granted to PUBLIC when the view is automatically created.

Example

Retrieve lock wait information for database member 0 for the currently connected database.
SELECT AGENT_ID, LOCK_MODE, LOCK_OBJECT_TYPE, AGENT_ID_HOLDING_LK,
   LOCK_MODE_REQUESTED FROM SYSIBMADM.SNAPLOCKWAIT 
   WHERE DBPARTITIONNUM = 0
The following is an example of output from this query.
AGENT_ID     LOCK_MODE LOCK_OBJECT_TYPE ...
--------...- --------- ---------------- ...
           7 IX        TABLE            ...
                                           
  1 record(s) selected.                    
Output from this query (continued).
... AGENT_ID_HOLDING_LK  LOCK_MODE_REQUESTED
... -------------------- -------------------
...                   12 IS                 

SNAP_GET_LOCKWAIT table function

The SNAP_GET_LOCKWAIT table function returns the same information as the SNAPLOCKWAIT administrative view, but allows you to retrieve the information for a specific database on a specific database member, aggregate of all database members or all database members.

Used with the SNAP_GET_LOCK table function, the SNAP_GET_LOCKWAIT table function provides information equivalent to the GET SNAPSHOT FOR LOCKS ON database-alias CLP command.

Refer to Table 1 for a complete list of information that can be returned.

Syntax

Read syntax diagramSkip visual syntax diagram
>>-SNAP_GET_LOCKWAIT--(--dbname--+----------+--)---------------><
                                 '-, member-'      

The schema is SYSPROC.

Table function parameters

dbname
An input argument of type VARCHAR(128) that specifies a valid database name in the same instance as the currently connected database. Specify a database name that has a directory entry type of either "Indirect" or "Home", as returned by the LIST DATABASE DIRECTORY command. Specify a null value or empty string to take the snapshot from the currently connected database.
member
An optional input argument of type INTEGER that specifies a valid database member number. Specify -1 for the current database member, or -2 for an aggregate of all active database members. If dbname is not set to NULL and member is set to NULL, -1 is set implicitly for member. If this input option is not used, that is, only dbname is provided, data is returned from all active database members. An active database member is a member where the database is available for connection and use by applications.

If both dbname and member are set to NULL, an attempt is made to read data from the file created by SNAP_WRITE_FILE procedure. Note that this file could have been created at any time, which means that the data might not be current. If a file with the corresponding snapshot API request type does not exist, then the SNAP_GET_LOCKWAIT table function takes a snapshot for the currently connected database and database member number.

Authorization

One of the following authorizations is required:
  • EXECUTE privilege on the SNAP_GET_LOCKWAIT table function
  • DATAACCESS authority
In addition, to access snapshot monitor data, one of the following authorities is also required:
  • SYSMON
  • SYSCTRL
  • SYSMAINT
  • SYSADM

Default PUBLIC privilege

In a non-restrictive database, EXECUTE privilege is granted to PUBLIC when the function is automatically created.

Example

Retrieve lock wait information for current database member for the currently connected database.
SELECT AGENT_ID, LOCK_MODE, LOCK_OBJECT_TYPE, AGENT_ID_HOLDING_LK,
   LOCK_MODE_REQUESTED FROM TABLE(SNAP_GET_LOCKWAIT('',-1)) AS T
The following is an example of output from this query.
AGENT_ID      LOCK_MODE  LOCK_OBJECT_TYPE   ...
--------...-- ---------- ------------------ ...
           12 X          ROW_LOCK           ...
                                               
1 record(s) selected.                          
Output from this query (continued).
... AGENT_ID_HOLDING_LK  LOCK_MODE_REQUESTED
... -------------------- -------------------
...                    7 X                  

Usage note

To see lock wait information, you must first turn on the default LOCK monitor switch in the database manager configuration. To have the change take effect immediately explicitly attach to the instance using CLP and then issue the CLP command:
  UPDATE DATABASE MANAGER CONFIGURATION CLP USING DFT_MON_LOCK ON
The default setting can also be turned on through the ADMIN_CMD stored procedure. For example:
CALL SYSPROC.ADMIN_CMD('update dbm cfg using DFT_MON_LOCK ON')

If the ADMIN_CMD stored procedure is used or if the clp command is used without having previously attached to the instance, the instance must be recycled before the change takes effect.

Information returned

Table 1. Information returned by the SNAPLOCKWAIT administrative view and the SNAP_GET_LOCKWAIT table function
Column name Data type Description or corresponding monitor element
SNAPSHOT_TIMESTAMP TIMESTAMP The date and time that the snapshot was taken.
AGENT_ID BIGINT agent_id - Application handle (agent ID)
SUBSECTION_NUMBER BIGINT ss_number - Subsection number
LOCK_MODE VARCHAR(10) lock_mode - Lock mode . This interface returns a text identifier based on the defines in sqlmon.h and is one of:
  • IN
  • IS
  • IX
  • NON (if no lock)
  • NS
  • NW
  • S
  • SIX
  • U
  • X
  • Z
LOCK_OBJECT_TYPE VARCHAR(18) lock_object_type - Lock object type waited on . This interface returns a text identifier based on the defines in sqlmon.h and is one of:
  • AUTORESIZE_LOCK
  • AUTOSTORAGE_LOCK
  • BLOCK_LOCK
  • EOT_LOCK
  • INPLACE_REORG_LOCK
  • INTERNAL_LOCK
  • INTERNALB_LOCK
  • INTERNALC_LOCK
  • INTERNALJ_LOCK
  • INTERNALL_LOCK
  • INTERNALO_LOCK
  • INTERNALQ_LOCK
  • INTERNALP_LOCK
  • INTERNALS_LOCK
  • INTERNALT_LOCK
  • INTERNALV_LOCK
  • KEYVALUE_LOCK
  • ROW_LOCK
  • SYSBOOT_LOCK
  • TABLE_LOCK
  • TABLE_PART_LOCK
  • TABLESPACE_LOCK
  • XML_PATH_LOCK
AGENT_ID_HOLDING_LK BIGINT agent_id_holding_lock - Agent ID holding lock
LOCK_WAIT_START_TIME TIMESTAMP lock_wait_start_time - Lock wait start timestamp
LOCK_MODE_REQUESTED VARCHAR(10) lock_mode_requested - Lock mode requested . This interface returns a text identifier based on the defines in sqlmon.h and is one of:
  • IN
  • IS
  • IX
  • NON (if no lock)
  • NS
  • NW
  • S
  • SIX
  • U
  • X
  • Z
LOCK_ESCALATION SMALLINT lock_escalation - Lock escalation
TABNAME VARCHAR(128) table_name - Table name
TABSCHEMA VARCHAR(128) table_schema - Table schema name
TBSP_NAME VARCHAR(128) tablespace_name - Table space name
APPL_ID_HOLDING_LK VARCHAR(128) appl_id_holding_lk - Application ID holding lock
LOCK_ATTRIBUTES VARCHAR(128) lock_attributes - Lock attributes . This interface returns a text identifier based on the defines in sqlmon.h. If there are no locks, the text identifier is NONE, otherwise, it is any combination of the following separated by a '+' sign:
  • ALLOW_NEW
  • DELETE_IN_BLOCK
  • ESCALATED
  • INSERT
  • NEW_REQUEST
  • RR
  • RR_IN_BLOCK
  • UPDATE_DELETE
  • WAIT_FOR_AVAIL
LOCK_CURRENT_MODE VARCHAR(10) lock_current_mode - Original lock mode before conversion . This interface returns a text identifier based on the defines in sqlmon.h and is one of:
  • IN
  • IS
  • IX
  • NON (if no lock)
  • NS
  • NW
  • S
  • SIX
  • U
  • X
  • Z
LOCK_NAME VARCHAR(32) lock_name - Lock name
LOCK_RELEASE_FLAGS BIGINT lock_release_flags - Lock release flags .
DATA_PARTITION_ID INTEGER data_partition_id - Data Partition identifier . For a non-partitioned table, this element is NULL.
DBPARTITIONNUM SMALLINT dbpartitionnum - Database partition number monitor element
MEMBER SMALLINT member - Database member monitor element