|
当 GreatSQL 数据库处于高并发高负载时,可能会发现 mysqld
进程的内存消耗远远超出设置的 innodb_buffer_pool_size
时,有时候甚至会高达甚至超过系统内存的90%,遇到这种问题时,心里经常会发慌,担心下一秒内存就会爆了发生 OOM,或者数据库hang死不响应。
本文和大家试着使用 GreatSQL 中的 sys schema
和 performance_schema
进行深入分析,找出内存消耗大户的源头,并尽可能解决问题。
下面是详细的排查方法和步骤。
先检查确认 mysqld
进程的内存具体消耗占用情况,做到心里有数,避免真的下一秒就发生 OOM 的问题:
$ free -htfree -ht total used free shared buff/cache availableMem: 30Gi 28Gi 240Mi 33Mi 2.0Gi 1.7GiSwap: 0B 0B 0BTotal: 30Gi 28Gi 240Mi$ ps aux | grep mysqldmysql 51931 23.0 89.8 32100800 29008060 ? Ssl Nov22 949:41 /data/apps/GreatSQL-8.0.32-26-Linux-glibc2.28-x86_64/bin/mysqld$ top -p $(pidof mysqld) -n 1top - 05:36:37 up 4 days, 4:06, 1 user, load average: 5.56, 8.70, 10.87Tasks: 1 total, 0 running, 1 sleeping, 0 stopped, 0 zombie%Cpu(s): 8.4 us, 1.7 sy, 0.0 ni, 86.6 id, 3.4 wa, 0.0 hi, 0.0 si, 0.0 stMiB Mem : 31553.3 total, 265.6 free, 29148.6 used, 2139.2 buff/cacheMiB Swap: 0.0 total, 0.0 free, 0.0 used. 1903.3 avail Mem PID USER PR NI VIRT RES SHR S %CPU %MEM TIME+ COMMAND 51931 mysql 20 0 30.6g 27.7g 4656 S 80.0 89.8 949:51.99 mysqld
在上述结果中重点关注几个指标:
看到 mysqld
进程当前内存消耗占比约 90%,还算可控,没到火烧眉毛的境地。
继续使用 pmap
查看 mysqld
进程中的内存分布情况:
$ pmap -x $(pidof mysqld) | sort -k3 -rn | head -n 20total kB 32100804 29029796 2901694000007f8a484d8000 5368992 5361664 5361664 rw--- [ anon ]00007f892533d000 4698892 4691952 4691952 rw--- [ anon ]00007f87e961e000 4564872 4556784 4556784 rw--- [ anon ]00007f86adbe0000 4296832 4290544 4290544 rw--- [ anon ]00007f86298bb000 1023252 1015792 1015792 rw--- [ anon ]00007f866c350000 979648 979632 979632 rw--- [ anon ]00007f87b8112000 719800 712688 712688 rw--- [ anon ]00007f89046d4000 451760 444400 444400 rw--- [ anon ]0000000005afc000 286800 282640 282640 rw--- [ anon ]00007f8ba7715000 200300 200276 200276 rw--- [ anon ]00007f8578000000 131072 131072 131072 rw--- [ anon ]00007f8570000000 131072 131072 131072 rw--- [ anon ]00007f8568000000 131072 131072 131072 rw--- [ anon ]00007f8560000000 131072 131072 131072 rw--- [ anon ]00007f8558000000 131072 131072 131072 rw--- [ anon ]00007f8550000000 131048 131048 131048 rw--- [ anon ]00007f8438000000 130668 130668 130668 rw--- [ anon ]00007f8b98000000 65536 65536 65536 rw--- [ anon ]00007f8b94000000 65536 65536 65536 rw--- [ anon ]
看到大量的匿名内存(anon)消耗较多内存,这可能是由以下几个原因引起的:
可以针对上述各个模块/维度做进一步排查分析。
greatsql> SHOW GLOBAL VARIABLES LIKE 'innodb_buffer_pool_size';+-------------------------+-------------+| Variable_name | Value |+-------------------------+-------------+| innodb_buffer_pool_size | 21474836480 |+-------------------------+-------------+greatsql> SHOW GLOBAL VARIABLES LIKE 'innodb_log_buffer_size';+------------------------+----------+| Variable_name | Value |+------------------------+----------+| innodb_log_buffer_size | 33554432 |+------------------------+----------+
从上面可见 IBP 设置为 20G,但是 mysqld
进程的内存占用为 27.7G,超过 IBP 较多,这可能是由于用户的 SQL 请求(比如效率较低的慢查询 SQL)其他模块或线程引起。还需要继续排查。
从 5.6.6 版本开始,Performance Schema 默认启用,是一个内置的性能诊断工具,用于实时监控和分析 GreatSQL 服务器的运行状态。它提供了详细的性能数据,包括 内存分配的全局视图、SQL 语句的执行时间、线程活动、锁等待等详细信息,帮助开发者和 DBA 识别和解决性能瓶颈。
使用 memory_summary_global_by_event_name
按模块查看内存分配情况:
greatsql> USE performance_schema;greatsql> SELECT EVENT_NAME, CURRENT_NUMBER_OF_BYTES_USED AS memory_bytes, CURRENT_NUMBER_OF_BYTES_USED / 1024 / 1024 AS memory_mbFROM performance_schema.memory_summary_global_by_event_nameWHERE CURRENT_NUMBER_OF_BYTES_USED > 0ORDER BY CURRENT_NUMBER_OF_BYTES_USED DESCLIMIT 10;+--------------------------------------------------------------------+--------------+----------------+| EVENT_NAME | memory_bytes | memory_mb |+--------------------------------------------------------------------+--------------+----------------+| memory/innodb/buf_buf_pool | 21957836800 | 20940.62500000 || memory/group_rpl/GCS_XCom::xcom_cache | 1070853221 | 1021.24521351 || memory/mysys/IO_CACHE | 84149952 | 80.25164795 || memory/performance_schema/events_statements_summary_by_digest | 42240000 | 40.28320313 || memory/innodb/log_buffer_memory | 33555440 | 32.00096130 || memory/innodb/ut0link_buf | 25165888 | 24.00006104 || memory/innodb/lock0lock | 22440096 | 21.40054321 || memory/sql/TABLE | 15646883 | 14.92203045 || memory/performance_schema/events_statements_history_long | 15040000 | 14.34326172 || memory/performance_schema/events_errors_summary_by_thread_by_error | 14561280 | 13.88671875 |+--------------------------------------------------------------------+--------------+----------------+10 rows in set (0.00 sec)
例如:
上面的查询结果表明,memory/innodb/buf_buf_pool
(IBP) 占用内存约 20G,memory/group_rpl/GCS_XCom::xcom_cache
(MGR XCom Cache) 占用内存约 1G,都是符合预期的。但是 memory/mysys/IO_CACHE
占用的内存较高,需要重点排查。
可以每间隔一段时间重复执行下面的 SQL 请求,观察各个模块的内存消耗变化,找出内存消耗增长较快的模块,它们可能就是导致 mysqld
进程消耗较大内存的“元凶”。
greatsql> USE performance_schema;greatsql> SELECT EVENT_NAME, SUM(SUM_NUMBER_OF_BYTES_ALLOC) / 1024 / 1024 AS total_memory_mbFROM performance_schema.memory_summary_global_by_event_nameGROUP BY EVENT_NAMEORDER BY SUM_NUMBER_OF_BYTES_ALLOC DESCLIMIT 10;+---------------------------------------------+------------------+| EVENT_NAME | total_memory_mb |+---------------------------------------------+------------------+| memory/innodb/memory | 3688428.98232269 || memory/mysys/MY_BITMAP::bitmap | 289065.08729172 || memory/group_rpl/transaction_data | 219301.70309544 || memory/group_rpl/Gcs_message_data::m_buffer | 219176.21560478 || memory/mysys/IO_CACHE | 102064.87601471 || memory/group_rpl/GCS_XCom::xcom_cache | 57685.34130669 || memory/sql/Log_event | 47153.59659863 || memory/group_rpl/write_set_encoded | 35822.83545971 || memory/innodb/buf_buf_pool | 20940.62500000 || memory/group_rpl/certification_data | 11146.79415703 |+---------------------------------------------+------------------+
结合前面各模块当前占用的内存情况,从上述查询结果综合分析看,较大概率应该就是 memory/mysys/IO_CACHE
模块消耗内存过大。
接着继续查看各线程内存占用情况,确认是否有个别线程(尤其是长连接线程)消耗了过多内存资源。使用 memory_summary_by_thread_by_event_name
查看各线程的内存分配,同时关联查询 threads
视图,可以显示各线程当前正在执行的 SQL 请求及其执行耗时:
-- 1. 查看各线程当前的内存分配情况greatsql> USE performance_schema;greatsql> SELECT m.EVENT_NAME, m.COUNT_ALLOC, m.CURRENT_NUMBER_OF_BYTES_USED AS mem_sum, (m.CURRENT_NUMBER_OF_BYTES_USED / 1024 / 1024.0) AS mem_sum_mb, t.NAME, t.TYPE, t.PROCESSLIST_ID, LEFT(t.PROCESSLIST_INFO, 10)FROM memory_summary_by_thread_by_event_name m JOIN threads t USING (THREAD_ID)WHERE t.PROCESSLIST_ID != CONNECTION_ID()ORDER BY m.CURRENT_NUMBER_OF_BYTES_USED descLIMIT 20;+-------------------------------+-------------+---------+------------+----------------------------------------------+------------+----------------+------------------------------+| EVENT_NAME | COUNT_ALLOC | mem_sum | mem_sum_mb | NAME | TYPE | PROCESSLIST_ID | LEFT(t.PROCESSLIST_INFO, 10) |+-------------------------------+-------------+---------+------------+----------------------------------------------+------------+----------------+------------------------------+| memory/innodb/memory | 13 | 21888 | 0.02087402 | thread/group_rpl/THD_applier_module_receiver | FOREGROUND | 12 | Group repl || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39893 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39894 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39895 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39896 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39897 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39898 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39899 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39900 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39901 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39902 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39903 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39904 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39905 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39906 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39907 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39908 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39909 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39910 | load data || memory/sql/THD::main_mem_root | 3 | 20576 | 0.01962280 | thread/sql/one_connection | FOREGROUND | 39911 | load data |+-------------------------------+-------------+---------+------------+----------------------------------------------+------------+----------------+------------------------------+-- 2. 查看各线程汇总的内存分配情况greatsql> SELECT m.EVENT_NAME, m.COUNT_ALLOC, m.SUM_NUMBER_OF_BYTES_ALLOC AS mem_sum, (m.SUM_NUMBER_OF_BYTES_ALLOC / 1024 / 1024.0) AS mem_sum_mb, t.NAME, t.TYPE, t.PROCESSLIST_ID, LEFT(t.PROCESSLIST_INFO, 10)FROM memory_summary_by_thread_by_event_name m JOIN threads t USING (THREAD_ID)WHERE t.PROCESSLIST_ID != CONNECTION_ID()ORDER BY m.SUM_NUMBER_OF_BYTES_ALLOC descLIMIT 20;+----------------------+-------------+-------------+----------------+----------------------------------------------+------------+----------------+------------------------------+| EVENT_NAME | COUNT_ALLOC | mem_sum | mem_sum_mb | NAME | TYPE | PROCESSLIST_ID | LEFT(t.PROCESSLIST_INFO, 10) |+----------------------+-------------+-------------+----------------+----------------------------------------------+------------+----------------+------------------------------+| memory/sql/Log_event | 818062681 | 36821553500 | 35115.76986313 | thread/group_rpl/THD_applier_module_receiver | FOREGROUND | 12 | Group repl || memory/innodb/memory | 258356 | 266640048 | 254.28776550 | thread/sql/one_connection | FOREGROUND | 40222 | load data || memory/innodb/memory | 255478 | 263811432 | 251.59018707 | thread/sql/one_connection | FOREGROUND | 40204 | load data || memory/innodb/memory | 217298 | 224575448 | 214.17183685 | thread/sql/one_connection | FOREGROUND | 40209 | load data || memory/innodb/memory | 212201 | 219160304 | 209.00755310 | thread/sql/one_connection | FOREGROUND | 40215 | load data || memory/innodb/memory | 209052 | 215978440 | 205.97309113 | thread/sql/one_connection | FOREGROUND | 40212 | load data || memory/innodb/memory | 203823 | 210364872 | 200.61957550 | thread/sql/one_connection | FOREGROUND | 40220 | load data || memory/innodb/memory | 201921 | 208627128 | 198.96233368 | thread/sql/one_connection | FOREGROUND | 40224 | load data || memory/innodb/memory | 195252 | 202055944 | 192.69556427 | thread/sql/one_connection | FOREGROUND | 40214 | load data || memory/innodb/memory | 193319 | 199526048 | 190.28286743 | thread/sql/one_connection | FOREGROUND | 40208 | load data || memory/innodb/memory | 192498 | 198820216 | 189.60973358 | thread/sql/one_connection | FOREGROUND | 40227 | load data || memory/innodb/memory | 191717 | 198099104 | 188.92202759 | thread/sql/one_connection | FOREGROUND | 40205 | load data || memory/innodb/memory | 191234 | 197764864 | 188.60327148 | thread/sql/one_connection | FOREGROUND | 40202 | load data || memory/innodb/memory | 190012 | 196401888 | 187.30343628 | thread/sql/one_connection | FOREGROUND | 40216 | load data || memory/innodb/memory | 189098 | 195217576 | 186.17398834 | thread/sql/one_connection | FOREGROUND | 40207 | load data || memory/innodb/memory | 188670 | 195084304 | 186.04689026 | thread/sql/one_connection | FOREGROUND | 40223 | load data || memory/innodb/memory | 187466 | 193563912 | 184.59693146 | thread/sql/one_connection | FOREGROUND | 40218 | load data || memory/innodb/memory | 187045 | 193354488 | 184.39720917 | thread/sql/one_connection | FOREGROUND | 40217 | load data || memory/innodb/memory | 186838 | 193196152 | 184.24620819 | thread/sql/one_connection | FOREGROUND | 40219 | load data || memory/innodb/memory | 186465 | 192576408 | 183.65517426 | thread/sql/one_connection | FOREGROUND | 40210 | load data |+----------------------+-------------+-------------+----------------+----------------------------------------------+------------+----------------+------------------------------+
从上面的查询结果可见,当前有较多的 LOAD DATA
请求正在运行,有可能是它们导致的内存占用较高的原因。
其中
排查分析道这里,基本上可以推断是由于有大量并发 LOAD DATA
导入数据请求导致 mysqld
内存占用较高。
相对于用 Performance Schema
排查分析,采用 sys schema
分析则更简单省事。接下来介绍如何利用 sys schema
分析。
GreatSQL sys schema
是一组视图、存储过程和函数的集合,它基于 performance_schema
提供了更易读和易用的性能数据汇总。sys schema
通过简化复杂的性能指标,帮助数据库管理员和开发人员快速诊断和优化 GreatSQL 的性能问题。
首先,查看当前全部内存分配情况:
greatsql> USE sys;greatsql> SELECT * FROM memory_global_total;+-----------------+| total_allocated |+-----------------+| 22.08 GiB |+-----------------+
在 IBP 设置为 20G 的前提下,从 memory_global_total
查询到的内存分配总数并没有超过太多,说明较大可能性是由于用户的 SQL 请求(比如效率较低的慢查询 SQL)或其他模块引起。
继续查询内存使用的全局分布情况:
greatsql> SELECT *FROM sys.memory_global_by_current_bytesLIMIT 20;+-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+| event_name | current_count | current_alloc | current_avg_alloc | high_count | high_alloc | high_avg_alloc |+-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+| memory/innodb/buf_buf_pool | 160 | 20.45 GiB | 130.88 MiB | 160 | 20.45 GiB | 130.88 MiB || memory/group_rpl/GCS_XCom::xcom_cache | 4295 | 1018.00 MiB | 242.71 KiB | 463303 | 1.13 GiB | 2.55 KiB || memory/mysys/IO_CACHE | 175 | 280.82 MiB | 1.60 MiB | 539 | 906.46 MiB | 1.68 MiB || memory/performance_schema/events_statements_summary_by_digest | 1 | 40.28 MiB | 40.28 MiB | 1 | 40.28 MiB | 40.28 MiB || memory/innodb/log_buffer_memory | 1 | 32.00 MiB | 32.00 MiB | 1 | 32.00 MiB | 32.00 MiB || memory/innodb/ut0link_buf | 2 | 24.00 MiB | 12.00 MiB | 2 | 24.00 MiB | 12.00 MiB || memory/innodb/lock0lock | 9893 | 21.40 MiB | 2.22 KiB | 9893 | 21.40 MiB | 2.22 KiB || memory/sql/TABLE | 5796 | 17.49 MiB | 3.09 KiB | 5798 | 17.50 MiB | 3.09 KiB || memory/performance_schema/events_statements_history_long | 1 | 14.34 MiB | 14.34 MiB | 1 | 14.34 MiB | 14.34 MiB || memory/performance_schema/events_errors_summary_by_thread_by_error | 257 | 13.89 MiB | 55.33 KiB | 257 | 13.89 MiB | 55.33 KiB || memory/performance_schema/events_statements_summary_by_thread_by_event_name | 1 | 13.66 MiB | 13.66 MiB | 1 | 13.66 MiB | 13.66 MiB || memory/innodb/memory | 7583 | 12.28 MiB | 1.66 KiB | 8812 | 16.80 MiB | 1.95 KiB || memory/performance_schema/file_instances | 4 | 11.00 MiB | 2.75 MiB | 4 | 11.00 MiB | 2.75 MiB || memory/performance_schema/events_statements_history_long.digest_text | 1 | 9.77 MiB | 9.77 MiB | 1 | 9.77 MiB | 9.77 MiB || memory/performance_schema/events_statements_summary_by_digest.digest_text | 1 | 9.77 MiB | 9.77 MiB | 1 | 9.77 MiB | 9.77 MiB || memory/performance_schema/events_statements_history_long.sql_text | 1 | 9.77 MiB | 9.77 MiB | 1 | 9.77 MiB | 9.77 MiB || memory/performance_schema/memory_summary_by_thread_by_event_name | 1 | 9.32 MiB | 9.32 MiB | 1 | 9.32 MiB | 9.32 MiB || memory/performance_schema/table_handles | 1 | 9.06 MiB | 9.06 MiB | 1 | 9.06 MiB | 9.06 MiB || memory/mysys/KEY_CACHE | 3 | 8.00 MiB | 2.67 MiB | 3 | 8.00 MiB | 2.67 MiB || memory/innodb/sync0arr | 3 | 7.03 MiB | 2.34 MiB | 3 | 7.03 MiB | 2.34 MiB |+-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+
在 sys schema
中,大部分视图都同时存储原始数据以及格式化后可读性更强的两种视图。所以上面的 SQL 查询还可以改成查询原始未格式化的视图:
greatsql> SELECT *FROM sys.x$memory_global_by_current_bytesLIMIT 20;+-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+-------------+----------------+| event_name | current_count | current_alloc | current_avg_alloc | high_count | high_alloc | high_avg_alloc |+-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+-------------+----------------+| memory/innodb/buf_buf_pool | 160 | 21957836800 | 137236480.0000 | 160 | 21957836800 | 137236480.0000 || memory/group_rpl/GCS_XCom::xcom_cache | 4068 | 1067435559 | 262398.1217 | 463303 | 1208663474 | 2608.7970 || memory/mysys/IO_CACHE | 126 | 206147792 | 1636093.5873 | 539 | 950487072 | 1763426.8497 || memory/performance_schema/events_statements_summary_by_digest | 1 | 42240000 | 42240000.0000 | 1 | 42240000 | 42240000.0000 || memory/innodb/log_buffer_memory | 1 | 33555440 | 33555440.0000 | 1 | 33555440 | 33555440.0000 || memory/innodb/ut0link_buf | 2 | 25165888 | 12582944.0000 | 2 | 25165888 | 12582944.0000 || memory/innodb/lock0lock | 9893 | 22440096 | 2268.2802 | 9893 | 22440096 | 2268.2802 || memory/sql/TABLE | 5796 | 18341476 | 3164.5059 | 5798 | 18351820 | 3165.1983 || memory/performance_schema/events_statements_history_long | 1 | 15040000 | 15040000.0000 | 1 | 15040000 | 15040000.0000 || memory/performance_schema/events_errors_summary_by_thread_by_error | 257 | 14561280 | 56658.6770 | 257 | 14561280 | 56658.6770 || memory/performance_schema/events_statements_summary_by_thread_by_event_name | 1 | 14321664 | 14321664.0000 | 1 | 14321664 | 14321664.0000 || memory/innodb/memory | 7562 | 12858512 | 1700.4115 | 8812 | 17615632 | 1999.0504 || memory/performance_schema/file_instances | 4 | 11534336 | 2883584.0000 | 4 | 11534336 | 2883584.0000 || memory/performance_schema/events_statements_history_long.digest_text | 1 | 10240000 | 10240000.0000 | 1 | 10240000 | 10240000.0000 || memory/performance_schema/events_statements_summary_by_digest.digest_text | 1 | 10240000 | 10240000.0000 | 1 | 10240000 | 10240000.0000 || memory/performance_schema/events_statements_history_long.sql_text | 1 | 10240000 | 10240000.0000 | 1 | 10240000 | 10240000.0000 || memory/performance_schema/memory_summary_by_thread_by_event_name | 1 | 9768960 | 9768960.0000 | 1 | 9768960 | 9768960.0000 || memory/performance_schema/table_handles | 1 | 9502720 | 9502720.0000 | 1 | 9502720 | 9502720.0000 || memory/mysys/KEY_CACHE | 3 | 8390864 | 2796954.6667 | 3 | 8390864 | 2796954.6667 || memory/innodb/sync0arr | 3 | 7373032 | 2457677.3333 | 3 | 7373032 | 2457677.3333 |+-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+-------------+----------------+
从上面两个查询结果可知,除了 IBP 和 MGR 之外,模块 memory/mysys/IO_CACHE
占用的内存最高,是重点分析排查对象。
查看 sys.memory_global_by_current_bytes
视图定义,可知它的原始数据来自 performance_schema
:
greatsql> SHOW CREATE VIEW sys.memory_global_by_current_bytes\G*************************** 1. row *************************** View: memory_global_by_current_bytes Create View: CREATE ALGORITHM=MERGE DEFINER=`mysql.sys`@`localhost` SQL SECURITY INVOKER VIEW `memory_global_by_current_bytes` (`event_name`,`current_count`,`current_alloc`,`current_avg_alloc`, `high_count`,`high_alloc`,`high_avg_alloc`) AS select `performance_schema`.`memory_summary_global_by_event_name`.`EVENT_NAME` AS `event_name`,`performance_schema`.`memory_summary_global_by_event_name`.`CURRENT_COUNT_USED` AS `current_count`,format_bytes(`performance_schema`.`memory_summary_global_by_event_name`.`CURRENT_NUMBER_OF_BYTES_USED`) AS `current_alloc`,format_bytes(ifnull((`performance_schema`.`memory_summary_global_by_event_name`.`CURRENT_NUMBER_OF_BYTES_USED` / nullif(`performance_schema`.`memory_summary_global_by_event_name`.`CURRENT_COUNT_USED`,0)),0)) AS `current_avg_alloc`,`performance_schema`.`memory_summary_global_by_event_name`.`HIGH_COUNT_USED` AS `high_count`,format_bytes(`performance_schema`.`memory_summary_global_by_event_name`.`HIGH_NUMBER_OF_BYTES_USED`) AS `high_alloc`,format_bytes(ifnull((`performance_schema`.`memory_summary_global_by_event_name`.`HIGH_NUMBER_OF_BYTES_USED` / nullif(`performance_schema`.`memory_summary_global_by_event_name`.`HIGH_COUNT_USED`,0)),0)) AS `high_avg_alloc` from `performance_schema`.`memory_summary_global_by_event_name` where (`performance_schema`.`memory_summary_global_by_event_name`.`CURRENT_NUMBER_OF_BYTES_USED` > 0) order by `performance_schema`.`memory_summary_global_by_event_name`.`CURRENT_NUMBER_OF_BYTES_USED` desccharacter_set_client: utf8mb4collation_connection: utf8mb4_0900_ai_ci
从 performance_schema
中读取源数据,并进行格式化处理,大大提升了可读性。同理,其他视图也如此。
查看各线程的内存使用详情:
-- 按历史总消耗内存排序-- 这里因为要按 total_allocated 列排序,所以查询原始视图greatsql> SELECT *FROM sys.x$memory_by_thread_by_current_bytesORDER BY total_allocated DESCLIMIT 20;+-----------+---------------------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+| thread_id | user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated |+-----------+---------------------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+| 57 | group_rpl/THD_applier_module_receiver | 87 | 62603 | 719.5747 | 21888 | 35248068439 || 33632 | root@localhost | 30 | 8592036 | 286401.2000 | 8388736 | 1450180050 || 45 | innodb/clone_gtid_thread | 5530 | 1916646 | 346.5906 | 1242184 | 328052882 || 34281 | root@localhost | 21 | 44051 | 2097.6667 | 20576 | 286781508 || 34273 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 274540679 || 34271 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 273058531 || 34282 | root@localhost | 21 | 44003 | 2095.3810 | 20576 | 272966254 || 34275 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 261564478 || 34274 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 240307573 || 34280 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 238306694 || 34284 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 235438640 || 34272 | root@localhost | 21 | 44051 | 2097.6667 | 20576 | 232405048 || 34283 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 226022807 || 34270 | root@localhost | 21 | 44051 | 2097.6667 | 20576 | 222124926 || 34277 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 216611682 || 34268 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 216088005 || 34269 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 215724518 || 34276 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 215354247 || 34286 | root@localhost | 20 | 43707 | 2185.3500 | 20576 | 214817414 || 34278 | root@localhost | 18 | 41387 | 2299.2778 | 20576 | 213726193 |+-----------+---------------------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+-- 按当前内存消耗排序-- 已默认按 current_allocated 排序,所以无需查询原始视图SELECT * FROM sys.memory_by_thread_by_current_bytes LIMIT 20;+-----------+---------------------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+| thread_id | user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated |+-----------+---------------------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+| 44680 | root@localhost | 91 | 16.21 MiB | 182.42 KiB | 16.00 MiB | 408.03 MiB || 45 | innodb/clone_gtid_thread | 5932 | 1.96 MiB | 346 bytes | 1.32 MiB | 327.43 MiB || 1 | sql/main | 4938 | 1.30 MiB | 276 bytes | 427.63 KiB | 8.61 MiB || 22 | innodb/log_writer_thread | 2347 | 293.38 KiB | 128 bytes | 293.38 KiB | 293.38 KiB || 63 | group_rpl/THD_mysql_thread | 208 | 182.98 KiB | 900 bytes | 130.20 KiB | 378.95 KiB || 57 | group_rpl/THD_applier_module_receiver | 87 | 61.14 KiB | 719 bytes | 21.38 KiB | 36.14 GiB || 59 | sql/replica_sql | 68 | 59.56 KiB | 896 bytes | 16.04 KiB | 129.57 KiB || 60 | sql/replica_worker | 31 | 44.04 KiB | 1.42 KiB | 16.04 KiB | 53.38 KiB || 45888 | root@localhost | 22 | 43.31 KiB | 1.97 KiB | 20.09 KiB | 312.29 MiB || 45897 | root@localhost | 22 | 43.31 KiB | 1.97 KiB | 20.09 KiB | 369.21 MiB || 45899 | root@localhost | 22 | 43.31 KiB | 1.97 KiB | 20.09 KiB | 315.29 MiB || 45905 | root@localhost | 22 | 43.31 KiB | 1.97 KiB | 20.09 KiB | 317.19 MiB || 45908 | root@localhost | 22 | 43.31 KiB | 1.97 KiB | 20.09 KiB | 307.82 MiB || 45890 | root@localhost | 21 | 43.02 KiB | 2.05 KiB | 20.09 KiB | 400.17 MiB || 45891 | root@localhost | 21 | 43.02 KiB | 2.05 KiB | 20.09 KiB | 336.53 MiB || 45886 | root@localhost | 21 | 43.02 KiB | 2.05 KiB | 20.09 KiB | 324.93 MiB || 45889 | root@localhost | 21 | 43.02 KiB | 2.05 KiB | 20.09 KiB | 303.29 MiB || 45907 | root@localhost | 21 | 43.02 KiB | 2.05 KiB | 20.09 KiB | 309.84 MiB || 45911 | root@localhost | 21 | 43.02 KiB | 2.05 KiB | 20.09 KiB | 308.27 MiB || 45919 | root@localhost | 21 | 42.97 KiB | 2.05 KiB | 20.09 KiB | 306.36 MiB |+-----------+---------------------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+
同样地,还可以和 performance_schema.threads
关联查询,就可以找到相应线程/会话中可能正在运行的 SQL 请求。
从查询结果明显可知,是由于当前有大量 root@localhost
连接会话执行 LOAD DATA
导入数据,这些会话占用了较多内存。
如果怀疑是某个用户的查询导致内存消耗过高,还可按用户分别统计:
greatsql> SELECT *FROM sys.memory_by_user_by_current_bytes;+-----------------+--------------------+-------------------+-------------------+-------------------+-----------------+| user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated |+-----------------+--------------------+-------------------+-------------------+-------------------+-----------------+| background | 13993 | 3.99 MiB | 298 bytes | 1.33 MiB | 40.07 GiB || root | 859 | 2.76 MiB | 3.29 KiB | 1.00 MiB | 3.95 TiB || event_scheduler | 3 | 16.27 KiB | 5.42 KiB | 16.04 KiB | 16.27 KiB |+-----------------+--------------------+-------------------+-------------------+-------------------+-----------------+
看到 root 用户历史上总消耗了 3.95 TB 内存,可见它的嫌疑最大。执行 SHOW PROCESSLIST
可以看到当前 root 用户在反复执行并发导入大量数据,这个原因造成了内存总消耗超过较大,等待导入完成后,自然就会回收释放。
综合以上两种分析方法和过程,基本上可以排查定位是什么原因导致 mysqld
进程占用过多内存。
InnoDB 模块可能消耗大量内存,以下参数需要关注:
分别检查确认这些参数设置情况:
greatsql> SHOW GLOBAL VARIABLES LIKE 'innodb%';
如果查询生成大量临时表,可能会占用内存。以下参数决定了临时表的大小和行为:
greatsql> SHOW GLOBAL VARIABLES LIKE 'tmp_table_size';greatsql> SHOW GLOBAL VARIABLES LIKE 'max_heap_table_size';
greatsql> SHOW GLOBAL STATUS LIKE 'Created_tmp%';
高并发会导致内存分配超标,尤其是以下参数:
复杂的排序、联接、子查询等操作会额外分配内存缓冲区,如果有较多的慢查询也表明可能存在一些消耗较多内存的查询请求,可以通过查询以下变量确认消耗:
greatsql> SHOW GLOBAL STATUS LIKE 'Sort_merge_passes';greatsql> SHOW GLOBAL STATUS LIKE 'Select_full_join';greatsql> SHOW GLOBAL STATUS LIKE 'Slow_queries';
表和源数据缓存 table_open_cache
和 table_definition_cache
也可能占用较多内存:
greatsql> SHOW VARIABLES LIKE 'table_open_cache';greatsql> SHOW VARIABLES LIKE 'table_definition_cache';
相信通过以上方法,基本上可以分析定位并解决 mysqld
进程内存占用异常的问题。
从上面的分析排查过程及思路中,也就知道了有哪些方法可以避免让 GreatSQL 在运行过程中消耗太多内存,以下是几条建议:
$ gdb --batch --pid `pidof mysqld` --ex 'call malloc_trim(0)'
重点做好上面这几点,基本上就能避免大部分容易造成 mysqld
消耗内存过多的情况,让 GreatSQL 运行的更丝滑平稳。
以上。
合作电话:010-64087828
社区邮箱:greatsql@greatdb.com