DB2 Version 10.1 for Linux, UNIX, and Windows

MON_GET_TABLE table function - get table metrics

The MON_GET_TABLE table function returns monitor metrics for one or more tables.

Syntax

Read syntax diagramSkip visual syntax diagram
>>-MON_GET_TABLE--(--tabschema--,--tabname--,--member--)-------><

The schema is SYSPROC.

Table function parameters

tabschema
An input argument of type VARCHAR(128) that specifies a valid table schema name in the currently connected database when calling this function. If the argument is null or an empty string, metrics are retrieved for all tables in all schemas in the database. If the argument is specified, metrics are only returned for tables in the specified schema.
tabname
An input argument of type VARCHAR(128) that specifies a valid table name in the currently connected database when calling this function. If the argument is null or an empty string, metrics are retrieved for all the tables in the database.
member
An input argument of type INTEGER that specifies a valid member in the same instance as the currently connected database when calling this function. Specify -1 for the current database member, or -2 for all active database members. If the NULL value is specified, -1 is set implicitly.

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

Example

List the activity on all tables accessed since the database was activated, aggregated across all database members, ordered by highest number of reads.

SELECT varchar(tabschema,20) as tabschema, 
       varchar(tabname,20) as tabname, 
       sum(rows_read) as total_rows_read, 
       sum(rows_inserted) as total_rows_inserted, 
       sum(rows_updated) as total_rows_updated, 
       sum(rows_deleted) as total_rows_deleted 
FROM TABLE(MON_GET_TABLE('','',-2)) AS t 
GROUP BY tabschema, tabname 
ORDER BY total_rows_read DESC

The following is an example of output from this query.

TABSCHEMA            TABNAME              TOTAL_ROWS_READ      ... 
-------------------- -------------------- -------------------- ... 
SYSIBM               SYSHISTO                              113 ... 
SYSIBM               SYSWORKL                               22 ... 
SYSIBM               SYSROUTI                               13 ... 
SYSIBM               SYSSERVI                               13 ... 
SYSIBM               SYSTHRES                                6 ... 
SYSIBM               SYSTABLE                                3 ... 
SYSIBM               SYSCONTE                                2 ... 
SYSIBM               SYSDBAUT                                2 ... 
SYSIBM               SYSEVENT                                2 ... 
SYSIBM               SYSPLAN                                 1 ... 
SYSIBM               SYSSURRO                                1 ... 
SYSIBM               SYSVERSI                                1 ... 
SYSIBM               SYSXMLST                                1 ... 
SYSIBM               SYSAUDIT                                0 ... 
SYSIBM               SYSROLEA                                0 ... 
SYSIBM               SYSROLES                                0 ... 
SYSIBM               SYSTASKS                                0 ... 
SYSIBM               SYSWORKA                                0 ... 
SYSIBM               SYSXMLPA                                0 ... 

  19 record(s) selected.

Output for query (continued).

... TOTAL_ROWS_INSERTED  TOTAL_ROWS_UPDATED   TOTAL_ROWS_DELETED  
... -------------------- -------------------- --------------------
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0
...                    0                    0                    0

Usage notes

The MON_GET_TABLE table function returns one row of data per database table and per database member. If range-partitioned tables are being used, one row is returned for each table partition per database member. No aggregation across database members is performed. However, aggregation can be achieved through SQL queries as shown in the example.

Metrics are returned only for tables accessed since the database was activated.

The metrics returned by this function are collected at two levels. Some metrics are always collected, while the collection of other metrics is controlled at the database level using the mon_obj_metrics configuration parameter. Refer to the descriptions provided in the following table to determine if any settings must be active for data to be collected for a particular metric.

Information returned

Table 1. Information returned for MON_GET_TABLE
Column Name Data Type Description
TABSCHEMA VARCHAR(128) table_schema - Table schema name
TABNAME VARCHAR(128) table_name - Table name
MEMBER SMALLINT member- Database member
TAB_TYPE VARCHAR(14) table_type - Table type
TAB_FILE_ID BIGINT table_file_id - Table file ID
DATA_PARTITION_ID INTEGER data_partition_id - Data partition identifier
TBSP_ID BIGINT tablespace_id - Table space identification
INDEX_TBSP_ID BIGINT index_tbsp_id - Index table space ID
LONG_TBSP_ID BIGINT long_tbsp_id - Long table space ID
TABLE_SCANS BIGINT table_scans - Table scans
ROWS_READ BIGINT rows_read - Rows read
ROWS_INSERTED BIGINT rows_inserted - Rows inserted
ROWS_UPDATED BIGINT rows_updated - Rows updated
ROWS_DELETED BIGINT rows_deleted - Rows deleted
OVERFLOW_ACCESSES BIGINT overflow_accesses - Accesses to overflowed records
OVERFLOW_CREATES BIGINT overflow_creates - Overflow creates
PAGE_REORGS BIGINT

page_reorgs - Page reorganizations

DATA_OBJECT_L_PAGES BIGINT data_object_l_pages - Logical data object pages
LOB_OBJECT_L_PAGES BIGINT lob_object_l_pages - Logical LOB object pages
LONG_OBJECT_L_PAGES BIGINT long_object_l_pages - Logical Long object pages
INDEX_OBJECT_L_PAGES BIGINT index_object_l_pages - Logical index object pages
XDA_OBJECT_L_PAGES BIGINT xda_object_l_pages - Logical XDA object pages
DBPARTITIONNUM SMALLINT dbpartitionnum - Database partition number
NO_CHANGE_UPDATES BIGINT no_change_updates - Number of no change row updates
LOCK_WAIT_TIME BIGINT lock_wait_time - Time waited on locks
LOCK_WAIT_TIME_GLOBAL BIGINT lock_wait_time_global - Lock wait time global
LOCK_WAITS BIGINT lock_waits - Lock waits
LOCK_WAITS_GLOBAL BIGINT lock_waits_global - Lock waits global
LOCK_ESCALS BIGINT lock_escals - Number of lock escalations
LOCK_ESCALS_GLOBAL BIGINT lock_escals_global - Number of global lock escalations
DIRECT_WRITES BIGINT direct_writes - Direct writes to database
DIRECT_WRITE_REQS BIGINT direct_write_reqs - Direct write requests
DIRECT_READS BIGINT direct_reads - Direct reads from database
DIRECT_READ_REQS BIGINT direct_read_reqs - Direct read requests
OBJECT_DATA_L_READS BIGINT object_data_l_reads - Buffer pool data logical reads for a table
OBJECT_DATA_P_READS BIGINT object_data_p_reads - Buffer pool data physical reads for a table
OBJECT_DATA_GBP_L_READS BIGINT object_data_gbp_l_reads - Group buffer pool data logical reads for a table
OBJECT_DATA_GBP_P_READS BIGINT object_data_gbp_p_reads - Group buffer pool data physical reads for a table
OBJECT_DATA_GBP_INVALID_PAGES BIGINT object_data_gbp_invalid_pages - Group buffer pool invalid data pages for a table
OBJECT_DATA_LBP_PAGES_FOUND BIGINT object_data_lbp_pages_found - Local buffer pool found data pages for a table
OBJECT_DATA_GBP_INDEP_PAGES_FOUND_IN_LBP BIGINT object_data_gbp_indep_pages_found_in_lbp - Group buffer pool independent data pages found in local buffer pool
OBJECT_XDA_L_READS BIGINT object_xda_l_reads - Buffer pool XDA data logical reads for a table
OBJECT_XDA_P_READS BIGINT object_xda_p_reads - Buffer pool XDA data physical reads for a table
OBJECT_XDA_GBP_L_READS BIGINT object_xda_gbp_l_reads - Group buffer pool XDA data logical read requests for a table
OBJECT_XDA_GBP_P_READS BIGINT object_xda_gbp_p_reads - Group buffer pool XDA data physical read requests for a table
OBJECT_XDA_GBP_INVALID_PAGES BIGINT object_xda_gbp_invalid_pages - Group buffer pool invalid XDA data pages for a table
OBJECT_XDA_LBP_PAGES_FOUND BIGINT object_xda_lbp_pages_found - Local buffer pool XDA data pages found for a table
OBJECT_XDA_GBP_INDEP_PAGES_FOUND_IN_LBP BIGINT object_xda_gbp_indep_pages_found_in_lbp - Group buffer pool XDA independent pages found in local buffer pool
NUM_PAGE_DICT_BUILT BIGINT num_page_dict_built - Number of page-level compression dictionaries created or re-created