Over a million developers have joined DZone.
{{announcement.body}}
{{announcement.title}}

How well does your table fit in your innodb buffer pool ?

DZone's Guide to

How well does your table fit in your innodb buffer pool ?

· Database Zone
Free Resource

Learn how to create flexible schemas in a relational database using SQL for JSON.

Understanding how well your tables and indexes fit to buffer pool are often very helpful to understand why some queries are IO bound and others not - it may be because the tables and indexes they are accessing are not in cache, for example being washed away by other queries. MySQL Server does not provide any information of this type, Percona Server however adds number of tables to Information Schema which makes this information possible. It is just few queries away:
mysql> SELECT `schema` AS table_schema,innodb_sys_tables.name AS table_name,innodb_sys_indexes.name AS index_name,cnt,dirty,hashed,round(cnt*100/index_size,2) fit_pct   FROM (SELECT index_id,count(*) cnt,sum(dirty=1) dirty ,sum(hashed=1) hashed FROM innodb_buffer_pool_pages_index GROUP BY index_id) bp JOIN innodb_sys_indexes ON id=index_id JOIN innodb_sys_tables ON table_id=innodb_sys_tables.id JOIN innodb_index_stats ON innodb_index_stats.table_name=innodb_sys_tables.name AND innodb_sys_indexes.name=innodb_index_stats.index_name AND innodb_index_stats.table_schema=innodb_sys_tables.schema  ORDER BY cnt DESC LIMIT 20;
+--------------+--------------+--------------+------+-------+--------+---------+
| table_schema | table_name | index_name | cnt | dirty | hashed | fit_pct
+--------------+--------------+--------------+------+-------+--------+---------+
| test | a | c | 7976 | 0 | 0 | 13.73
| test | a | PRIMARY | 59 | 0 | 0 | 0.08
| sbtest | sbtest#P#p1 | PRIMARY | 22 | 0 | 0 | 22.68
| sbtest | sbtest#P#p0 | PRIMARY | 22 | 0 | 0 | 22.68
| sbtest | sbtest#P#p2 | PRIMARY | 21 | 0 | 0 | 21.65
| sbtest | sbtest#P#p3 | PRIMARY | 18 | 0 | 0 | 18.56
| sbtest | sbtest#P#p3 | k | 4 | 0 | 0 | 100.00
| sbtest | sbtest#P#p2 | k | 4 | 0 | 0 | 100.00
| sbtest | sbtest#P#p1 | k | 4 | 0 | 0 | 100.00
| sbtest | sbtest#P#p0 | k | 4 | 0 | 0 | 100.00
| stats | TABLES | PRIMARY | 2 | 0 | 0 | 66.67
| stats | TABLES | TABLE_SCHEMA | 1 | 0 | 0 | 100.00
| percona | transactions | PRIMARY | 1 | 0 | 0 | 100.00
+--------------+--------------+--------------+------+-------+--------+---------+
13 rows IN SET (0.04 sec)

This query shows information about how many pages are in buffer pool for given table (cnt), how many of them are dirty (dirty), and what is the percentage of index fits in memory (fit_pct)
For illustration purposes I've created one table with partitions to show you will have the real "physical" table name which identifies table down to partition, which is very helpful for analyzes of your
access to partitions - you can actually check if your "hot" partitions really end up in the cache and "cold" are out of the cache, or is something happening which pushes them away from the cache.

You can use this feature to tune buffer pool invalidation strategy, for example play with innodb_old_blocks_pct and innodb_old_blocks_time actually observing data stored in buffer pool rather than using some form of temporary measures.

I often check these stats during warmup to see what is really getting warmed up first as well as how buffer pool is affected by batch jobs, alter tables, optimize table etc - the lasting impact these may have on system performance is often caused by impact they have on buffer pool which may take hours to recover.

This tool can be also helpful for capacity planning/performance management. In many cases you would learn you need a certain fit to buffer pool for tables/indexes for reasonable performance, you may try to count it too but it may be pretty hard as there are a lot of variables, including page fill factors etc.


Create flexible schemas using dynamic columns for semi-structured data. Learn how.

Topics:

Published at DZone with permission of Peter Zaitsev, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

THE DZONE NEWSLETTER

Dev Resources & Solutions Straight to Your Inbox

Thanks for subscribing!

Awesome! Check your inbox to verify your email so you can start receiving the latest in tech news and resources.

X

{{ parent.title || parent.header.title}}

{{ parent.tldr }}

{{ parent.urlSource.name }}