DB2 Version 9.7 for Linux, UNIX, and Windows

SNAPTAB administrative view and SNAP_GET_TAB_V91 table function - Retrieve table logical data group snapshot information

The SNAPTAB administrative view and the SNAP_GET_TAB_V91 table function return snapshot information from the table logical data group.

Note: Beginning in Version 9.7 Fix Pack 5, the SNAPTAB administrative view and SNAP_GET_TAB_V91 table function are deprecated. You can use the table functions MON_GET_TABLESPACE, MON_GET_BUFFERPOOL, and MON_GET_TABLE, and the administrative view MON_BP_UTILIZATION to retrieve the information returned by these deprecated interfaces.

SNAPTAB administrative view

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

Used in conjunction with the SNAPTAB_REORG administrative view, the SNAPTAB administrative view returns equivalent information to the GET SNAPSHOT FOR TABLES 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 SNAPTAB administrative view
  • CONTROL privilege on the SNAPTAB administrative view
  • DATAACCESS authority
In addition, one of the following privileges or authorities is also required:
  • EXECUTE privilege on the SNAP_GET_TAB_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 the schema and name for all active tables.
SELECT SUBSTR(TABSCHEMA,1,8), SUBSTR(TABNAME,1,15) AS TABNAME, TAB_TYPE, 
   DBPARTITIONNUM FROM SYSIBMADM.SNAPTAB
The following example is a sample output from this query.
TABSCHEMA TABNAME         TAB_TYPE     DBPARTITIONNUM
--------- --------------- ------------ --------------
SYSTOOLS  HMON_ATM_INFO   USER_TABLE                0

  1 record selected.

SNAP_GET_TAB_V91 table function

The SNAP_GET_TAB_V91 table function returns the same information as the SNAPTAB 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_TAB_REORG table function, the SNAP_GET_TAB_V91 table function returns equivalent information to the GET SNAPSHOT FOR TABLES 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_TAB_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_TAB_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_TAB_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 active tables as an aggregate view for the currently connected database.
SELECT SUBSTR(TABSCHEMA,1,8) AS TABSCHEMA, SUBSTR(TABNAME,1,15) AS TABNAME, 
   TAB_TYPE, DBPARTITIONNUM FROM TABLE(SNAP_GET_TAB('',-2)) AS T
The following example is a sample output from this query.
TABSCHEMA TABNAME         TAB_TYPE      DBPARTITIONNUM
--------- --------------- ------------- --------------
SYSTOOLS  HMON_ATM_INFO   USER_TABLE                 -
JESSICAE  EMPLOYEE        USER_TABLE                 -

Information returned

Table 1. Information returned by the SNAPTAB administrative view and the SNAP_GET_TAB_V91 table function
Column name Data type Description or corresponding monitor element
SNAPSHOT_TIMESTAMP TIMESTAMP snapshot_timestamp - Snapshot timestamp monitor element
TABSCHEMA VARCHAR(128) table_schema - Table schema name
TABNAME VARCHAR(128) table_name - Table name
TAB_FILE_ID BIGINT table_file_id - Table file identification
TAB_TYPE VARCHAR(14) table_type - Table type . This interface returns a text identifier based on defines in sqlmon.h, and is one of:
  • USER_TABLE
  • DROPPED_TABLE
  • TEMP_TABLE
  • CATALOG_TABLE
  • REORG_TABLE
DATA_OBJECT_PAGES BIGINT data_object_pages - Data object pages
INDEX_OBJECT_PAGES BIGINT index_object_pages - Index object pages
LOB_OBJECT_PAGES BIGINT lob_object_pages - LOB object pages
LONG_OBJECT_PAGES BIGINT long_object_pages - Long object pages
XDA_OBJECT_PAGES BIGINT xda_object_pages - XDA Object Pages
ROWS_READ BIGINT rows_read - Rows read
ROWS_WRITTEN BIGINT rows_written - Rows written
OVERFLOW_ACCESSES BIGINT overflow_accesses - Accesses to overflowed records
PAGE_REORGS BIGINT page_reorgs - Page reorganizations
DBPARTITIONNUM SMALLINT The database partition from which the data was retrieved for this row.
TBSP_ID BIGINT tablespace_id - Table space identification
DATA_PARTITION_ID INTEGER data_partition_id - Data Partition identifier . For a non-partitioned table, this element will be NULL.