The InnoDB
INFORMATION_SCHEMA buffer pool tables provide
buffer pool status information and metadata about the pages within
the InnoDB buffer pool. The tables were
introduced in MySQL 5.6.2 and later backported to MySQL 5.5 (in
MySQL 5.5.28) and MySQL 5.1 (in MySQL 5.1.66).
The InnoDB
INFORMATION_SCHEMA buffer pool tables include
those listed below:
mysql> SHOW TABLES FROM INFORMATION_SCHEMA LIKE 'INNODB_BUFFER%'; +-----------------------------------------------+ | Tables_in_INFORMATION_SCHEMA (INNODB_BUFFER%) | +-----------------------------------------------+ | INNODB_BUFFER_PAGE_LRU | | INNODB_BUFFER_PAGE | | INNODB_BUFFER_POOL_STATS | +-----------------------------------------------+
Table Overview
INNODB_BUFFER_PAGE: Holds information about each page in theInnoDBbuffer pool.INNODB_BUFFER_PAGE_LRU: Holds information about the pages in theInnoDBbuffer pool, in particular how they are ordered in the LRU list that determines which pages to evict from the buffer pool when it becomes full. TheINNODB_BUFFER_PAGE_LRUtable has the same columns as theINNODB_BUFFER_PAGEtable, except that theINNODB_BUFFER_PAGE_LRUtable has anLRU_POSITIONcolumn instead of aBLOCK_IDcolumn.INNODB_BUFFER_POOL_STATS: Provides buffer pool status information. Much of the same information is provided bySHOW ENGINE INNODB STATUSoutput, or may be obtained usingInnoDBbuffer pool server status variables.
Querying the INNODB_BUFFER_PAGE
table or INNODB_BUFFER_PAGE_LRU
table can introduce significant performance overhead. Do not
query these tables on a production system unless you are aware
of the performance impact that your query may have, and have
determined it to be acceptable. To avoid impacting performance,
reproduce the issue you want to investigate on a test instance
and run your queries on the test instance.
Example 14.2 Querying System Data in the INNODB_BUFFER_PAGE Table
This query provides an approximate count of pages that contain
system data by excluding pages where the
TABLE_NAME value is either
NULL or includes a slash /
or period . in the table name, which
indicates a user-defined table.
SELECT COUNT(*) FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE WHERE TABLE_NAME IS NULL OR (INSTR(TABLE_NAME, '/') = 0 AND INSTR(TABLE_NAME, '.') = 0); +----------+ | COUNT(*) | +----------+ | 381 | +----------+
This query returns the approximate number of pages that contain system data, the total number of buffer pool pages, and an approximate percentage of pages that contain system data.
SELECT (SELECT COUNT(*) FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE WHERE TABLE_NAME IS NULL OR (INSTR(TABLE_NAME, '/') = 0 AND INSTR(TABLE_NAME, '.') = 0) ) AS system_pages, ( SELECT COUNT(*) FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE ) AS total_pages, ( SELECT ROUND((system_pages/total_pages) * 100) ) AS system_page_percentage; +--------------+-------------+------------------------+ | system_pages | total_pages | system_page_percentage | +--------------+-------------+------------------------+ | 381 | 8192 | 5 | +--------------+-------------+------------------------+
The type of system data in the buffer pool can be determined by
querying the PAGE_TYPE value. For example,
the following query returns eight distinct
PAGE_TYPE values among the pages that contain
system data:
mysql> SELECT DISTINCT PAGE_TYPE FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE WHERE TABLE_NAME IS NULL OR (INSTR(TABLE_NAME, '/') = 0 AND INSTR(TABLE_NAME, '.') = 0); +-------------------+ | PAGE_TYPE | +-------------------+ | IBUF_BITMAP | | SYSTEM | | INDEX | | UNDO_LOG | | FILE_SPACE_HEADER | | UNKNOWN | | INODE | | EXTENT_DESCRIPTOR | +-------------------+
Example 14.3 Querying User Data in the INNODB_BUFFER_PAGE Table
This query provides an approximate count of pages containing
user data by counting pages where the
TABLE_NAME value is NOT
NULL.
mysql> SELECT COUNT(*) FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE WHERE TABLE_NAME IS NOT NULL; +----------+ | COUNT(*) | +----------+ | 7811 | +----------+
This query returns the approximate number of pages that contain user data, the total number of buffer pool pages, and an approximate percentage of pages that contain user data.
mysql> SELECT (SELECT COUNT(*) FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE WHERE TABLE_NAME IS NOT NULL AND (INSTR(TABLE_NAME, '/') > 0 OR INSTR(TABLE_NAME, '.') > 0) ) AS user_pages, ( SELECT COUNT(*) FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE ) AS total_pages, ( SELECT ROUND((user_pages/total_pages) * 100) ) AS user_page_percentage; +------------+-------------+----------------------+ | user_pages | total_pages | user_page_percentage | +------------+-------------+----------------------+ | 7811 | 8192 | 95 | +------------+-------------+----------------------+
This query identifies user-defined tables with pages in the buffer pool:
mysql> SELECT DISTINCT TABLE_NAME FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE WHERE TABLE_NAME IS NOT NULL AND (INSTR(TABLE_NAME, '/') > 0 OR INSTR(TABLE_NAME, '.') > 0); +---------------------+ | TABLE_NAME | +---------------------+ | employees/salaries | | employees/employees | +---------------------+
Example 14.4 Querying Index Data in the INNODB_BUFFER_PAGE Table
For information about index pages, query the
INDEX_NAME column using the name of the
index. For example, the following query returns the number of
pages and total data size of pages for the
emp_no index that is defined on the
employees.salaries table:
mysql> SELECT INDEX_NAME, COUNT(*) AS Pages, ROUND(SUM(IF(COMPRESSED_SIZE = 0, 16384, COMPRESSED_SIZE))/1024/1024) AS 'Total Data (MB)' FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE WHERE INDEX_NAME='emp_no' AND TABLE_NAME = 'employees/salaries'; +------------+-------+-----------------+ | INDEX_NAME | Pages | Total Data (MB) | +------------+-------+-----------------+ | emp_no | 1244 | 19 | +------------+-------+-----------------+
This query returns the number of pages and total data size of
pages for all indexes defined on the
employees.salaries table:
mysql> SELECT INDEX_NAME, COUNT(*) AS Pages, ROUND(SUM(IF(COMPRESSED_SIZE = 0, 16384, COMPRESSED_SIZE))/1024/1024) AS 'Total Data (MB)' FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE WHERE TABLE_NAME = 'employees/salaries' GROUP BY INDEX_NAME; +------------+-------+-----------------+ | INDEX_NAME | Pages | Total Data (MB) | +------------+-------+-----------------+ | emp_no | 1244 | 19 | | PRIMARY | 6086 | 95 | +------------+-------+-----------------+
Example 14.5 Querying LRU_POSITION Data in the INNODB_BUFFER_PAGE_LRU Table
The INNODB_BUFFER_PAGE_LRU table
holds information about the pages in the
InnoDB buffer pool, in particular how they
are ordered that determines which pages to evict from the buffer
pool when it becomes full. The definition for this page is the
same as for INNODB_BUFFER_PAGE,
except this table has an LRU_POSITION column
instead of a BLOCK_ID column.
This query counts the number of positions at a specific location
in the LRU list occupied by pages of the
employees.employees table.
mysql> SELECT COUNT(LRU_POSITION) FROM INFORMATION_SCHEMA.INNODB_BUFFER_PAGE_LRU WHERE TABLE_NAME='employees/employees' AND LRU_POSITION < 3072; +---------------------+ | COUNT(LRU_POSITION) | +---------------------+ | 481 | +---------------------+
Example 14.6 Querying the INNODB_BUFFER_POOL_STATS Table
The INNODB_BUFFER_POOL_STATS table
provides information similar to
SHOW ENGINE INNODB
STATUS and InnoDB buffer pool
status variables.
mysql> SELECT * FROM information_schema.INNODB_BUFFER_POOL_STATS \G
*************************** 1. row ***************************
POOL_ID: 0
POOL_SIZE: 8192
FREE_BUFFERS: 1
DATABASE_PAGES: 7942
OLD_DATABASE_PAGES: 2911
MODIFIED_DATABASE_PAGES: 0
PENDING_DECOMPRESS: 0
PENDING_READS: 0
PENDING_FLUSH_LRU: 0
PENDING_FLUSH_LIST: 0
PAGES_MADE_YOUNG: 8358
PAGES_NOT_MADE_YOUNG: 0
PAGES_MADE_YOUNG_RATE: 0
PAGES_MADE_NOT_YOUNG_RATE: 0
NUMBER_PAGES_READ: 7045
NUMBER_PAGES_CREATED: 12382
NUMBER_PAGES_WRITTEN: 15790
PAGES_READ_RATE: 0
PAGES_CREATE_RATE: 0
PAGES_WRITTEN_RATE: 0
NUMBER_PAGES_GET: 28731589
HIT_RATE: 0
YOUNG_MAKE_PER_THOUSAND_GETS: 0
NOT_YOUNG_MAKE_PER_THOUSAND_GETS: 0
NUMBER_PAGES_READ_AHEAD: 2934
NUMBER_READ_AHEAD_EVICTED: 23
READ_AHEAD_RATE: 0
READ_AHEAD_EVICTED_RATE: 0
LRU_IO_TOTAL: 0
LRU_IO_CURRENT: 0
UNCOMPRESS_TOTAL: 0
UNCOMPRESS_CURRENT: 0
For comparison,
SHOW ENGINE INNODB
STATUS output and InnoDB buffer
pool status variable output is shown below, based on the same
data set.
For more information about
SHOW ENGINE INNODB
STATUS output, see
Section 14.20.3, “InnoDB Standard Monitor and Lock Monitor Output”.
mysql> SHOW ENGINE INNODB STATUS \G ... ---------------------- BUFFER POOL AND MEMORY ---------------------- Total memory allocated 137363456; in additional pool allocated 0 Dictionary memory allocated 71426 Buffer pool size 8192 Free buffers 1 Database pages 7942 Old database pages 2911 Modified db pages 0 Pending reads 0 Pending writes: LRU 0, flush list 0, single page 0 Pages made young 8358, not young 0 0.00 youngs/s, 0.00 non-youngs/s Pages read 7045, created 12382, written 15790 0.00 reads/s, 0.00 creates/s, 0.00 writes/s No buffer pool page gets since the last printout Pages read ahead 0.00/s, evicted without access 0.00/s, Random read ahead 0.00/s LRU len: 7942, unzip_LRU len: 0 I/O sum[0]:cur[0], unzip sum[0]:cur[0] ...
For status variable descriptions, see Section 5.1.7, “Server Status Variables”.
mysql> SHOW STATUS LIKE 'Innodb_buffer%'; +---------------------------------------+-----------+ | Variable_name | Value | +---------------------------------------+-----------+ | Innodb_buffer_pool_pages_data | 7942 | | Innodb_buffer_pool_bytes_data | 130121728 | | Innodb_buffer_pool_pages_dirty | 0 | | Innodb_buffer_pool_bytes_dirty | 0 | | Innodb_buffer_pool_pages_flushed | 15790 | | Innodb_buffer_pool_pages_free | 1 | | Innodb_buffer_pool_pages_misc | 249 | | Innodb_buffer_pool_pages_total | 8192 | | Innodb_buffer_pool_read_ahead_rnd | 0 | | Innodb_buffer_pool_read_ahead | 2934 | | Innodb_buffer_pool_read_ahead_evicted | 23 | | Innodb_buffer_pool_read_requests | 28731589 | | Innodb_buffer_pool_reads | 4112 | | Innodb_buffer_pool_wait_free | 0 | | Innodb_buffer_pool_write_requests | 11965146 | +---------------------------------------+-----------+