理解innodb buffer pool

时间:2025-04-21 18:35:13

今天组里有个同事说可以查看innodb buffer pool每个表和索引占的大小,为此我搜了下,还真有方法,记录下。

innodb buffer pool有几个目的:

  • 缓存数据--众所周知,这个占了buffer pool的大半空间
  • 缓存目录--数据字典
  • insert buffer
  • 排序的内部结构--比如自适应hash的结构或者一些行锁

1.buffer pool是怎样分配空间的?

SELECT engine,
count(*) as TABLES,
concat(round(sum(table_rows)/1000000,2),'M') rows,
concat(round(sum(data_length)/(1024*1024*1024),2),'G') DATA,
concat(round(sum(index_length)/(1024*1024*1024),2),'G') idx,
concat(round(sum(data_length+index_length)/(1024*1024*1024),2),'G') total_size,
round(sum(index_length)/sum(data_length),2) idxfrac
FROM information_schema.TABLES
WHERE table_schema not in ('mysql', 'performance_schema', 'information_schema')
GROUP BY engine
ORDER BY sum(data_length+index_length) DESC LIMIT 10;

得到的结果:

+--------+--------+----------+---------+--------+------------+---------+
| engine | TABLES | rows | DATA | idx | total_size | idxfrac |
+--------+--------+----------+---------+--------+------------+---------+
| InnoDB | 71608 | 1644.51M | 130.79G | 82.76G | 213.55G | 0.63 |
+--------+--------+----------+---------+--------+------------+---------+

2.获取buffer pool占的page个数:

select count(*) from information_schema.innodb_buffer_page;

结果:

+----------+
| count(*) |
+----------+
| 262142 |
+----------+

聪明的同学自己算下使用的buffer pool是多大吧。

3.获取page类型:

select
page_type as Page_Type,
sum(data_size)/1024/1024 as Size_in_MB
from information_schema.innodb_buffer_page
group by page_type
order by Size_in_MB desc;

结果:

+-------------------+--------------+
| Page_Type | Size_in_MB |
+-------------------+--------------+
| INDEX | 158.66378689 |
| UNKNOWN | 0.00000000 |
| TRX_SYSTEM | 0.00000000 |
| SYSTEM | 0.00000000 |
| FILE_SPACE_HEADER | 0.00000000 |
| IBUF_BITMAP | 0.00000000 |
| EXTENT_DESCRIPTOR | 0.00000000 |
| ALLOCATED | 0.00000000 |
| INODE | 0.00000000 |
| BLOB | 0.00000000 |
| UNDO_LOG | 0.00000000 |
| IBUF_FREE_LIST | 0.00000000 |
| IBUF_INDEX | 0.00000000 |
+-------------------+--------------+

从这里可以看到数据和索引占了buffer pool的大部分空间。也可以看出来这里有几种重要的页类型:

  • INDEX: B-Tree index
  • IBUF_INDEXInsert buffer index
  • UNKNOWN: not allocated / unknown state
  • TRX_SYSTEM: transaction system data

眼亮的同学可能会问,你上面不是说会缓存数据吗?怎么这里出来只有INDEX类型占多半buffer pool?数据哪里去了?数据在INDEX里!!!数据在聚簇索引的叶子节点上。

4.buffer pool里每个索引的使用

select
table_name as Table_Name, index_name as Index_Name,
count(*) as Page_Count, sum(data_size)/1024/1024 as Size_in_MB
from information_schema.innodb_buffer_page
group by table_name, index_name
order by Size_in_MB desc;

结果:

+--------------------------------------------+-----------------+------------+-------------+
| Table_Name | Index_Name | Page_Count | Size_in_MB |
+--------------------------------------------+-----------------+------------+-------------+
| `magento`.`core_url_rewrite` | PRIMARY | 2829 | 40.64266014 |
| `magento`.`core_url_rewrite` | FK_CORE_URL_... | 680 | 6.67517281 |
| `magento`.`catalog_product_entity_varchar` | PRIMARY | 449 | 6.41064930 |
| `magento`.`catalog_product_index_price` | PRIMARY | 440 | 6.29357910 |
| `magento`.`catalog_product_entity` | PRIMARY | 435 | 6.23898315 |
+--------------------------------------------+-----------------+------------+-------------+

5.一个典型的buffer pool使用监控:

理解innodb buffer pool

从这里图里我们可以看到buffer pool几乎是被填满的,另外预留了10%的空间用来做其他用途。

6.一般怎么设置buffer pool大小呢?

warm rows data size + warm indexes size (excl. clustered) + 20%

7.如何预热buffer pool?

在InnoDB上面执行select语句:

  • 对于聚簇索引来说,大多数情况通过SELECT COUNT(*) 加载到buffer pool中了。
  • 对于二级索引来说,要执行一些简单的语句来抓取全部数据,比如select * from tbname where 索引的第一列。或者select * from tbname force index(二级索引) where colname <>0.

另外,MySQL5.7支持动态修改buffer pool:

mysql> SET GLOBAL innodb_buffer_pool_size=size_in_bytes;

8.Dump & restore

在MySQL (5.6+), Percona Server (5.5.10+) or MariaDB (10.0+)可以通过以下配置把buffer pool里面的数据dump出来,并在启动的时候加载到内存中:

  • innodb_buffer_pool_dump_at_shutdown=ON
  • innodb_buffer_pool_load_at_startup=ON

参考资料:

https://michael.bouvy.net/blog/en/2015/01/18/understanding-mysql-innodb-buffer-pool-size/

http://www.speedemy.com/mysql/17-key-mysql-config-file-settings/innodb_buffer_pool_size/