DB2 Version 9.7 for Linux, UNIX, and Windows

SNAPDB_MEMORY_POOL administrative view and SNAP_GET_DB_MEMORY_POOL table function - Retrieve database level memory usage information

The SNAPDB_MEMORY_POOL administrative view and the SNAP_GET_DB_MEMORY_POOL table function return information about memory usage at the database level for UNIX platforms only.

Note: Starting in Version 9.7 Fix Pack 5, the SNAPDB_MEMORY_POOL administrative view and SNAP_GET_DB_MEMORY_POOL table function have been deprecated and replaced by the MON_GET_MEMORY_POOL table function - get memory pool information and MON_GET_MEMORY_SET table function - get memory set information.

SNAPDB_MEMORY_POOL administrative view

This administrative view allows you to retrieve database level memory usage information for the currently connected database.

Used with the SNAPDB, SNAPDETAILLOG, SNAPHADR and SNAPSTORAGE_PATHS administrative views, the SNAPDB_MEMORY_POOL administrative view provides information equivalent to the GET SNAPSHOT FOR DATABASE 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 SNAPDB_MEMORY_POOL administrative view
  • CONTROL privilege on the SNAPDB_MEMORY_POOL administrative view
  • DATAACCESS authority
In addition, one of the following privileges or authorities is also required:
  • EXECUTE privilege on the SNAP_GET_DB_MEMORY_POOL 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 memory pools and their current size for the currently connected database, SAMPLE.
SELECT POOL_ID, POOL_CUR_SIZE FROM SYSIBMADM.SNAPDB_MEMORY_POOL
The following example is a sample output from this query.
POOL_ID       POOL_CUR_SIZE
------------- --------------------
UTILITY                      32768
PACKAGE_CACHE               475136
CAT_CACHE                    65536
BP                         2097152
BP                         1081344
BP                          540672
BP                          278528
BP                          147456
BP                           81920
LOCK_MGR                    294912
DATABASE                   3833856
OTHER                            0

  12 record(s) selected.

SNAP_GET_DB_MEMORY_POOL table function

The SNAP_GET_DB_MEMORY_POOL table function returns the same information as the SNAPDB_MEMORY_POOL 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_DB_V95, SNAP_GET_DETAILLOG_V91, SNAP_GET_HADR and SNAP_GET_STORAGE_PATHS table functions, the SNAP_GET_DB_MEMORY_POOL table function provides information equivalent to the GET SNAPSHOT FOR ALL DATABASES 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_DB_MEMORY_POOL--(--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 an empty string to take the snapshot from the currently connected database. Specify a NULL value to take the snapshot from all databases within the same instance as 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_DB_MEMORY_POOL 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_DB_MEMORY_POOL 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 memory pools and their current size for all databases.
SELECT SUBSTR(DB_NAME,1,8) AS DB_NAME, POOL_ID, POOL_CUR_SIZE 
   FROM TABLE(SNAPSHOT_GET_DB_MEMORY_POOL
   (CAST(NULL AS VARCHAR(128)), -1)) AS T
The following example is a sample output from this query.
DB_NAME  POOL_ID        POOL_CUR_SIZE 
-------- -------------- --------------------
TESTDB   UTILITY                       65536
TESTDB   PACKAGE_CACHE                851968
TESTDB   CAT_CACHE                     65536
TESTDB   BP                         35913728
TESTDB   BP                           589824
TESTDB   BP                           327680
TESTDB   BP                           196608
TESTDB   BP                           131072
TESTDB   SHARED_SORT                   65536
TESTDB   LOCK_MGR                   10092544
TESTDB   DATABASE                    4980736
TESTDB   OTHER                        196608
SAMPLE   UTILITY                       65536
SAMPLE   PACKAGE_CACHE                655360
SAMPLE   CAT_CACHE                    131072
SAMPLE   BP                          4325376
SAMPLE   BP                           589824
SAMPLE   BP                           327680
SAMPLE   BP                           196608
SAMPLE   BP                           131072
SAMPLE   SHARED_SORT                       0
SAMPLE   LOCK_MGR                     655360
SAMPLE   DATABASE                    4653056
SAMPLE   OTHER                        196608

24 record(s) selected.

Information returned

Table 1. Information returned by the SNAPDB_MEMORY_POOL administrative view and the SNAP_GET_DB_MEMORY_POOL table function
Column name Data type Description or corresponding monitor element
SNAPSHOT_TIMESTAMP TIMESTAMP snapshot_timestamp - Snapshot timestamp monitor element
DB_NAME VARCHAR(128) db_name - Database name
POOL_ID VARCHAR(14) pool_id - Memory pool identifier . This interface returns a text identifier based on defines in sqlmon.h, and is one of:
  • APP_GROUP
  • APPL_CONTROL
  • APPLICATION
  • BP
  • CAT_CACHE
  • DATABASE
  • DFM
  • FCMBP
  • IMPORT_POOL
  • LOCK_MGR
  • MONITOR
  • OTHER
  • PACKAGE_CACHE
  • QUERY
  • SHARED_SORT
  • SORT
  • STATEMENT
  • STATISTICS
  • UTILITY
POOL_SECONDARY_ID VARCHAR(32) pool_secondary_id - Memory pool secondary identifier
POOL_CUR_SIZE BIGINT pool_cur_size - Current size of memory pool
POOL_WATERMARK BIGINT pool_watermark - Memory pool watermark
POOL_CONFIG_SIZE BIGINT pool_config_size - Configured size of memory pool
DBPARTITIONNUM SMALLINT The database partition from which the data was retrieved for this row.