SNAPBP_PART administrative view and SNAP_GET_BP_PART table function - Retrieve bufferpool_nodeinfo logical data group snapshot information
The SNAPBP_PART administrative view and the SNAP_GET_BP_PART table function return information about buffer pools from a bufferpool snapshot, in particular, the bufferpool_nodeinfo logical data group.
SNAPBP_PART administrative view
This administrative view allows you to retrieve bufferpool_nodeinfo logical data group snapshot information for the currently connected database.
Used with the MON_GET_BUFFERPOOL table function, the SNAPBP_PART administrative view provides the data equivalent to the GET SNAPSHOT FOR BUFFERPOOLS ON database-alias CLP command.
The schema is SYSIBMADM.
Refer to Table 1 for a complete list of information that can be returned.
Authorization
- SELECT privilege on the SNAPBP_PART administrative view
- CONTROL privilege on the SNAPBP_PART administrative view
- DATAACCESS authority
- DBADM authority
- SQLADM authority
- ACCESSCTRL authority
- SECADM authority
- EXECUTE privilege on the SNAP_GET_BP_PART table function
- DATAACCESS authority
- DBADM authority
- SQLADM authority
- SYSMON
- SYSCTRL
- SYSMAINT
- SYSADM
Default PUBLIC privilege
In a non-restrictive database, SELECT privilege is granted to PUBLIC when the view is automatically created.
Example
SELECT SUBSTR(DB_NAME,1,8) AS DB_NAME, SUBSTR(BP_NAME,1,15) AS BP_NAME,
BP_CUR_BUFFSZ, BP_NEW_BUFFSZ, BP_PAGES_LEFT_TO_REMOVE, BP_TBSP_USE_COUNT
FROM SYSIBMADM.SNAPBP_PART
DB_NAME BP_NAME BP_CUR_BUFFSZ BP_NEW_BUFFSZ ...
-------- --------------- -------------------- -------------------- ...
SAMPLE IBMDEFAULTBP 1000 1000 ...
SAMPLE IBMSYSTEMBP4K 16 16 ...
SAMPLE IBMSYSTEMBP8K 16 16 ...
SAMPLE IBMSYSTEMBP16K 16 16 ...
...
4 record(s) selected.
... BP_PAGES_LEFT_TO_REMOVE BP_TBSP_USE_COUNT
... ----------------------- --------------------
... 0 3
... 0 0
... 0 0
... 0 0
...
SNAP_GET_BP_PART table function
The SNAP_GET_BP_PART table function returns the same information as the SNAPBP_PART administrative view, but allows you to retrieve the information for a specific database on a specific database member, aggregate of all database members or all database members.
Used with the SNAP_GET_BP table function, the SNAP_GET_BP_PART table function provides the data equivalent to the GET SNAPSHOT FOR ALL BUFFERPOOLS CLP command.
Refer to Table 1 for a complete list of information that can be returned.
Syntax
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 for all bufferpools in all databases within the same instance as the currently connected database. member
- An optional input argument of type INTEGER that specifies a valid database member number. Specify -1 for the current database member, or -2 for an aggregate of all active database members. If dbname is not set to NULL and member is set to NULL, -1 is set implicitly for member. If this input option is not used, that is, only dbname is provided, data is returned from all active database members. An active database member is a member where the database is available for connection and use by applications.
If both dbname and member 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_BP_PART table function takes a snapshot for the currently connected database and database member number.
Authorization
- EXECUTE privilege on the SNAP_GET_BP_PART table function
- DATAACCESS authority
- SYSMON
- SYSCTRL
- SYSMAINT
- SYSADM
Default PUBLIC privilege
In a non-restrictive database, EXECUTE privilege is granted to PUBLIC when the function is automatically created.
Example
SELECT SUBSTR(DB_NAME,1,8) AS DB_NAME, SUBSTR(BP_NAME,1,15) AS BP_NAME,
BP_CUR_BUFFSZ, BP_NEW_BUFFSZ, BP_PAGES_LEFT_TO_REMOVE, BP_TBSP_USE_COUNT
FROM TABLE(SNAP_GET_BP_PART(CAST(NULL AS VARCHAR(128)),-1)) AS T
DB_NAME BP_NAME BP_CUR_BUFFSZ BP_NEW_BUFFSZ ...
-------- --------------- -------------------- -------------------- ...
SAMPLE IBMDEFAULTBP 250 250 ...
SAMPLE IBMSYSTEMBP4K 16 16 ...
SAMPLE IBMSYSTEMBP8K 16 16 ...
SAMPLE IBMSYSTEMBP16K 16 16 ...
SAMPLE IBMSYSTEMBP32K 16 16 ...
TESTDB IBMDEFAULTBP 250 250 ...
TESTDB IBMSYSTEMBP4K 16 16 ...
TESTDB IBMSYSTEMBP8K 16 16 ...
TESTDB IBMSYSTEMBP16K 16 16 ...
TESTDB IBMSYSTEMBP32K 16 16 ...
...
... BP_PAGES_LEFT_TO_REMOVE BP_TBSP_USE_COUNT
... ----------------------- --------------------
... 0 3
... 0 0
... 0 0
... 0 0
... 0 0
... 0 3
... 0 0
... 0 0
... 0 0
... 0 0
...
Information returned
Column name | Data type | Description or corresponding monitor element |
---|---|---|
SNAPSHOT_TIMESTAMP | TIMESTAMP | The date and time that the snapshot was taken. |
BP_NAME | VARCHAR(128) | bp_name - Buffer pool name |
DB_NAME | VARCHAR(128) | db_name - Database name |
BP_CUR_BUFFSZ | BIGINT | bp_cur_buffsz - current size of buffer pool |
BP_NEW_BUFFSZ | BIGINT | bp_new_buffsz - New buffer pool size |
BP_PAGES_LEFT_TO_REMOVE | BIGINT | bp_pages_left_to_remove - Number of pages left to remove |
BP_TBSP_USE_COUNT | BIGINT | bp_tbsp_use_count - Number of table spaces mapped to buffer pool |
DBPARTITIONNUM | SMALLINT | dbpartitionnum - Database partition number monitor element |
MEMBER | SMALLINT | member - Database member monitor element |