DB2 Version 9.7 for Linux, UNIX, and Windows

SNAPTBSP_QUIESCER administrative view and SNAP_GET_TBSP_QUIESCER table function - Retrieve quiescer table space snapshot information

The SNAPTBSP_QUIESCER administrative view and the SNAP_GET_TBSP_QUIESCER table function return information about quiescers from a table space snapshot.

SNAPTBSP_QUIESCER administrative view

This administrative view allows you to retrieve quiescer table space snapshot information for the currently connected database.

Used with the SNAPTBSP, SNAPTBSP_PART, SNAPTBSP_RANGE, SNAPCONTAINER administrative views, the SNAPTBSP_QUIESCER administrative view provides information equivalent to the GET SNAPSHOT FOR TABLESPACES 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 SNAPTBSP_QUIESCER administrative view
  • CONTROL privilege on the SNAPTBSP_QUIESCER administrative view
  • DATAACCESS authority
In addition, one of the following privileges or authorities is also required:
  • EXECUTE privilege on the SNAP_GET_TBSP_QUIESCER table function
  • DATAACCESS authority
In addition, to access snapshot monitor data, one of the following authorities is also required:
  • SYSMON
  • SYSCTRL
  • SYSMAINT
  • SYSADM

Example

Retrieve information about the quiesced table spaces for all database partitions for the currently connected database.
SELECT SUBSTR(TBSP_NAME, 1, 10) AS TBSP_NAME, QUIESCER_TS_ID, 
   QUIESCER_OBJ_ID, QUIESCER_AUTH_ID, QUIESCER_AGENT_ID, 
   QUIESCER_STATE, DBPARTITIONNUM 
   FROM SYSIBMADM.SNAPTBSP_QUIESCER ORDER BY DBPARTITIONNUM
The following example is a sample output from this query.
TBSP_NAME  QUIESCER_TS_ID     QUIESCER_OBJ_ID     QUIESCER_AUTH_ID     ..
---------- --------------...- ---------------...- ----------------...- ..
USERSPACE1                  2                   5 SWALKTY              ..
USERSPACE1                  2                   5 SWALKTY              ..

  2 record(s) selected.
Output from this query (continued).
... QUIESCER_AGENT_ID    QUIESCER_STATE DBPARTITIONNUM
... -------------------- -------------- --------------
...                    0 EXCLUSIVE                   0
...                65983 EXCLUSIVE                   1

Example: Determine the range partitioned table names

If the table is range-partitioned and kept in quiesced state, the different values for table space ID and table ID are represented than in SYSCAT.TABLES. These IDs will appear as the unsigned short representation. In order to find the quiesced table name, you need to find the signed short representation first by calculating the table space ID that is subtracting 65536 (the maximum value) from QEUIESCER_TS_ID and then use this table space ID to locate the quiesced tables. (The actual table space ID can be found in SYSCAT.DATAPARTITIONS for each range partition in the table).
SELECT SUBSTR(TBSP_NAME, 1, 10) AS TBSP_NAME, 
  CASE WHEN QUIESCER_TS_ID = 65530 
    THEN QUIESCER_TS_ID - 65536  
    ELSE QUIESCER_TS_ID END as tbspaceid, 
  CASE WHEN QUIESCER_TS_ID = 65530 
    THEN QUIESCER_OBJ_ID - 65536 
    ELSE QUIESCER_OBJ_ID END as tableid 
  FROM SYSIBMADM.SNAPTBSP_QUIESCER 
  ORDER BY DBPARTITIONNUM
The following example is a sample output from this query.
TBSP_NAME     TBSPACEID    TABLEID
------------- ------------ --------
TABDATA       -6           -32768
DATAMART      -6           -32765
SMALL         5            17

  3 record(s) selected.
Use the given TBSPACEID and TABLEID provided from the preceding query to find the table schema and name from SYSCAT.TABLES.
SELECT CHAR(tabschema, 10)tabschema, CHAR(tabname,15)tabname 
  FROM SYSCAT.TABLES 
  WHERE tbspaceid = -6 AND tableid in (-32768,-32765)
The following example is a sample output from this query.
TABSCHEMA    TABNAME
------------ --------
SAMP         ORDERS_RP
SAMP         ORDERS_DMART

  2 record(s) selected.
SELECT CHAR(tabschema, 10)tabschema, CHAR(tabname,15)tabname 
  FROM SYSCAT.TABLES 
  WHERE tbspaceid = 5 AND tableid = 17
The following example is a sample output from this query.
TABSCHEMA    TABNAME
------------ --------
SAMP         NATION

  1 record(s) selected.

SNAP_GET_TBSP_QUIESCER table function

The SNAP_GET_TBSP_QUIESCER table function returns the same information as the SNAPTBSP_QUIESCER administrative view, but allows you to retrieve the information for a specific database on a specific database partition, aggregate of all database partitions or all database partitions.

Used with the SNAP_GET_TBSP_V91, SNAP_GET_TBSP_PART_V91, SNAP_GET_TBSP_RANGE, SNAP_GET_CONTAINER_V91 table functions, the SNAP_GET_TBSP_QUIESCER table function provides information equivalent to the GET SNAPSHOT FOR TABLESPACES 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_TBSP_QUIESCER--(--dbname--+------------------+--)--><
                                      '-, dbpartitionnum-'      

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 NULL or empty string to take the snapshot from the currently connected database.
dbpartitionnum
An optional input argument of type INTEGER that specifies a valid database partition number. Specify -1 for the current database partition, or -2 for an aggregate of all active database partitions. If dbname is not set to NULL and dbpartitionnum is set to NULL, -1 is set implicitly for dbpartitionnum. If this input option is not used, that is, only dbname is provided, data is returned from all active database partitions. An active database partition is a partition where the database is available for connection and use by applications.

If both dbname and dbpartitionnum 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_TBSP_QUIESCER table function takes a snapshot for the currently connected database and database partition number.

Authorization

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

Example

Retrieve information about the quiesced table spaces for database partition 1 for the currently connected database.
SELECT SUBSTR(TBSP_NAME, 1, 10) AS TBSP_NAME, QUIESCER_TS_ID, 
   QUIESCER_OBJ_ID, QUIESCER_AUTH_ID, QUIESCER_AGENT_ID, 
   QUIESCER_STATE, DBPARTITIONNUM 
   FROM TABLE( SYSPROC.SNAP_GET_TBSP_QUIESCER( '', 1)) AS T
The following example is a sample output from this query.
TBSP_NAME  QUIESCER_TS_ID     QUIESCER_OBJ_ID     QUIESCER_AUTH_ID     ...
---------- --------------...- ---------------...- ----------------...- ...
USERSPACE1                  2                   5 SWALKTY              ...

  1 record(s) selected.                                                     
Output from this query (continued).
... QUIESCER_AGENT_ID    QUIESCER_STATE DBPARTITIONNUM
... -------------------- -------------- --------------
...                65983 EXCLUSIVE                   1

Information returned

Table 1. Information returned by the SNAPTBSP_QUIESCER administrative view and the SNAP_GET_TBSP_QUIESCER table function
Column name Data type Description or corresponding monitor element
SNAPSHOT_TIMESTAMP TIMESTAMP snapshot_timestamp - Snapshot timestamp monitor element
TBSP_NAME VARCHAR(128) tablespace_name - Table space name
QUIESCER_TS_ID BIGINT quiescer_ts_id - Quiescer table space identification
QUIESCER_OBJ_ID BIGINT quiescer_obj_id - Quiescer object identification
QUIESCER_AUTH_ID VARCHAR(128) quiescer_auth_id - Quiescer user authorization identification
QUIESCER_AGENT_ID BIGINT quiescer_agent_id - Quiescer agent identification
QUIESCER_STATE VARCHAR(14) quiescer_state - Quiescer state . This interface returns a text identifier based on defines in sqlutil.h and is one of:
  • EXCLUSIVE
  • UPDATE
  • SHARE
DBPARTITIONNUM SMALLINT The database partition from which the data was retrieved for this row.