DB2 Version 9.7 for Linux, UNIX, and Windows

SNAPTBSP administrative view and SNAP_GET_TBSP_V91 table function - Retrieve table space logical data group snapshot information

The SNAPTBSP administrative view and the SNAP_GET_TBSP_V91 table function return snapshot information from the table space logical data group.

SNAPTBSP administrative view

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

Used in conjunction with the SNAPTBSP_PART, SNAPTBSP_QUIESCER, SNAPTBSP_RANGE, SNAPCONTAINER administrative views, the SNAPTBSP administrative view returns 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 administrative view
  • CONTROL privilege on the SNAPTBSP administrative view
  • DATAACCESS authority
In addition, one of the following privileges or authorities is also required:
  • EXECUTE privilege on the SNAP_GET_TBSP_V91 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 a list of table spaces on the catalog database partition for the currently connected database.
SELECT SUBSTR(TBSP_NAME,1,30) AS TBSP_NAME, TBSP_ID, TBSP_TYPE, 
   TBSP_CONTENT_TYPE FROM SYSIBMADM.SNAPTBSP WHERE DBPARTITIONNUM = 1
The following example is a sample output from this query.
TBSP_NAME  TBSP_ID     TBSP_TYPE  TBSP_CONTENT_TYPE
---------- -------...- ---------- -----------------
TEMPSPACE1           1 SMS        SYSTEMP 
USERSPACE1           2 DMS        LONG 

2 record(s) selected. 

SNAP_GET_TBSP_V91 table function

The SNAP_GET_TBSP_V91 table function returns the same information as the SNAPTBSP 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 in conjunction with the SNAP_GET_TBSP_PART_V91, SNAP_GET_TBSP_QUIESCER, SNAP_GET_TBSP_RANGE, SNAP_GET_CONTAINER_V91 table functions, the SNAP_GET_TBSP_V91 table function returns 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_V91--(--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_V91 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_V91 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 a list of table spaces for all database partitions for the currently connected database.
SELECT SUBSTR(TBSP_NAME,1,10) AS TBSP_NAME, TBSP_ID, TBSP_TYPE, 
   TBSP_CONTENT_TYPE, DBPARTITIONNUM FROM TABLE(SNAP_GET_TBSP_V91('')) AS T
The following example is a sample output from this query.
TBSP_NAME  TBSP_ID     TBSP_TYPE  TBSP_CONTENT_TYPE DBPARTITIONNUM
---------- -------...- ---------- ----------------- --------------
TEMPSPACE1           1 SMS        SYSTEMP                        1
USERSPACE1           2 DMS        LONG                           1
SYSCATSPAC           0 DMS        ANY                            0
TEMPSPACE1           1 SMS        SYSTEMP                        0
USERSPACE1           2 DMS        LONG                           0
SYSTOOLSPA           3 DMS        LONG                           0
TEMPSPACE1           1 SMS        SYSTEMP                        2
USERSPACE1           2 DMS        LONG                           2

  8 record(s) selected. 

Information returned

Table 1. Information returned by the SNAPTBSP administrative view and the SNAP_GET_TBSP_V91 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
TBSP_ID BIGINT tablespace_id - Table space identification
TBSP_TYPE VARCHAR(10) tablespace_type - Table space type . This interface returns a text identifier based on defines in sqlutil.h, and is one of:
  • DMS
  • SMS
TBSP_CONTENT_TYPE VARCHAR(10) tablespace_content_type - Table space contents type . This interface returns a text identifier based on defines in sqlmon.h, and is one of:
  • ANY
  • LARGE
  • SYSTEMP
  • USRTEMP
TBSP_PAGE_SIZE BIGINT tablespace_page_size - Table space page size
TBSP_EXTENT_SIZE BIGINT tablespace_extent_size - Table space extent size
TBSP_PREFETCH_SIZE BIGINT tablespace_prefetch_size - Table space prefetch size
TBSP_CUR_POOL_ID BIGINT tablespace_cur_pool_id - Buffer pool currently being used
TBSP_NEXT_POOL_ID BIGINT tablespace_next_pool_id - Buffer pool that will be used at next startup
FS_CACHING SMALLINT fs_caching - File system caching
POOL_DATA_L_READS BIGINT pool_data_l_reads - Buffer pool data logical reads
POOL_DATA_P_READS BIGINT pool_data_p_reads - Buffer pool data physical reads
POOL_TEMP_DATA_L_READS BIGINT pool_temp_data_l_reads - Buffer pool temporary data logical reads
POOL_TEMP_DATA_P_READS BIGINT pool_temp_data_p_reads - Buffer pool temporary data physical reads
POOL_ASYNC_DATA_READS BIGINT pool_async_data_reads - Buffer pool asynchronous data reads
POOL_DATA_WRITES BIGINT pool_data_writes - Buffer pool data writes
POOL_ASYNC_DATA_WRITES BIGINT pool_async_data_writes - Buffer pool asynchronous data writes
POOL_INDEX_L_READS BIGINT pool_index_l_reads - Buffer pool index logical reads
POOL_INDEX_P_READS BIGINT pool_index_p_reads - Buffer pool index physical reads
POOL_TEMP_INDEX_L_READS BIGINT pool_temp_index_l_reads - Buffer pool temporary index logical reads
POOL_TEMP_INDEX_P_READS BIGINT pool_temp_index_p_reads - Buffer pool temporary index physical reads
POOL_ASYNC_INDEX_READS BIGINT pool_async_index_reads - Buffer pool asynchronous index reads
POOL_INDEX_WRITES BIGINT pool_index_writes - Buffer pool index writes
POOL_ASYNC_INDEX_WRITES BIGINT pool_async_index_writes - Buffer pool asynchronous index writes
POOL_XDA_L_READS BIGINT pool_xda_l_reads - Buffer Pool XDA Data Logical Reads
POOL_XDA_P_READS BIGINT pool_xda_p_reads - Buffer Pool XDA Data Physical Reads
POOL_XDA_WRITES BIGINT pool_xda_writes - Buffer Pool XDA Data Writes
POOL_ASYNC_XDA_READS BIGINT pool_async_xda_reads - Buffer Pool Asynchronous XDA Data Reads
POOL_ASYNC_XDA_WRITES BIGINT pool_async_xda_writes - Buffer Pool Asynchronous XDA Data Writes
POOL_TEMP_XDA_L_READS BIGINT pool_temp_xda_l_reads - Buffer Pool Temporary XDA Data Logical Reads
POOL_TEMP_XDA_P_READS BIGINT pool_temp_xda_p_reads - Buffer Pool Temporary XDA Data Physical Reads monitor element
POOL_READ_TIME BIGINT pool_read_time - Total buffer pool physical read time
POOL_WRITE_TIME BIGINT pool_write_time - Total buffer pool physical write time
POOL_ASYNC_READ_TIME BIGINT pool_async_read_time - Buffer pool asynchronous read time
POOL_ASYNC_WRITE_TIME BIGINT pool_async_write_time - Buffer pool asynchronous write time

POOL_ASYNC_DATA_
   READ_REQS

BIGINT pool_async_data_read_reqs - Buffer pool asynchronous read requests

POOL_ASYNC_INDEX_
   READ_REQS

BIGINT pool_async_index_read_reqs - Buffer pool asynchronous index read requests

POOL_ASYNC_XDA_
   READ_REQS

BIGINT pool_async_xda_read_reqs - Buffer Pool Asynchronous XDA Read Requests
POOL_NO_VICTIM_BUFFER BIGINT pool_no_victim_buffer - Buffer pool no victim buffers
DIRECT_READS BIGINT direct_reads - Direct reads from database
DIRECT_WRITES BIGINT direct_writes - Direct writes to database
DIRECT_READ_REQS BIGINT direct_read_reqs - Direct read requests
DIRECT_WRITE_REQS BIGINT direct_write_reqs - Direct write requests
DIRECT_READ_TIME BIGINT direct_read_time - Direct read time
DIRECT_WRITE_TIME BIGINT direct_write_time - Direct write time
FILES_CLOSED BIGINT files_closed - Database files closed
UNREAD_PREFETCH_PAGES BIGINT unread_prefetch_pages - Unread prefetch pages
TBSP_REBALANCER_MODE VARCHAR(10) tablespace_rebalancer_mode - Rebalancer mode . This interface returns a text identifier based on defines in sqlmon.h, and is one of:
  • NO_REBAL
  • FWD_REBAL
  • REV_REBAL
TBSP_USING_AUTO_STORAGE SMALLINT tablespace_using_auto_storage - Table space enabled for automatic storage
TBSP_AUTO_RESIZE_ENABLED SMALLINT tablespace_auto_resize_enabled - Table space automatic resizing enabled
DBPARTITIONNUM SMALLINT The database partition from which the data was retrieved for this row.