DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Please enter at least three characters to search
Refcards Trend Reports
Events Video Library
Refcards
Trend Reports

Events

View Events Video Library

Zones

Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks

Because the DevOps movement has redefined engineering responsibilities, SREs now have to become stewards of observability strategy.

Apache Cassandra combines the benefits of major NoSQL databases to support data management needs not covered by traditional RDBMS vendors.

The software you build is only as secure as the code that powers it. Learn how malicious code creeps into your software supply chain.

Generative AI has transformed nearly every industry. How can you leverage GenAI to improve your productivity and efficiency?

Related

  • Memory-Optimized Tables: Implementation Strategies for SQL Server
  • Useful System Table Queries in Relational Databases
  • Doris: Unifying SQL Dialects for a Seamless Data Query Ecosystem
  • Analyzing “java.lang.OutOfMemoryError: Failed to create a thread” Error

Trending

  • How to Merge HTML Documents in Java
  • Enhancing Business Decision-Making Through Advanced Data Visualization Techniques
  • Can You Run a MariaDB Cluster on a $150 Kubernetes Lab? I Gave It a Shot
  • AI Speaks for the World... But Whose Humanity Does It Learn From?
  1. DZone
  2. Data Engineering
  3. Databases
  4. What To Do When MySQL Runs Out of Memory: Troubleshooting Guide

What To Do When MySQL Runs Out of Memory: Troubleshooting Guide

In this article, I will show you how to use the new version of MySQL (5.7+) and how to troubleshoot MySQL memory allocation more easily.

By 
Alexander Rubin user avatar
Alexander Rubin
·
Jul. 03, 18 · Tutorial
Likes (7)
Comment
Save
Tweet
Share
29.4K Views

Join the DZone community and get the full member experience.

Join For Free

Troubleshooting crashes is never a fun task, especially if MySQL does not report the cause of the crash. For example, when MySQL runs out of memory. Peter Zaitsev wrote a blog post in 2012: Troubleshooting MySQL Memory Usage with a lot of useful tips. With the new versions of MySQL (5.7+) and performance_schema, we have the ability to troubleshoot MySQL memory allocation much more easily.

In this article, I will show you how to use it.

First of all, there are 3 major cases when MySQL will crash due to running out of memory:

  1. MySQL tries to allocate more memory than available because we specifically told it to do so. For example: you did not set innodb_buffer_pool_size correctly. This is very easy to fix
  2. There is some other process(es) on the server that allocates RAM. It can be the application (Java, Python, PHP), web server or even the backup (i.e. mysqldump). When the source of the problem is identified, it is straightforward to fix.
  3. Memory leaks in MySQL. This is a worst-case scenario, and we need to troubleshoot.

Where to Start Troubleshooting MySQL Memory Leaks

Here is what we can start with (assuming it is a Linux server):

Part 1: Linux OS and Config Check

1. Identify the crash by checking MySQL error log and Linux log file (i.e. /var/log/messages or /var/log/syslog). You may see an entry saying that OOM Killer killed MySQL. Whenever MySQL has been killed by OOM "dmesg" also shows details about the circumstances surrounding it.

2. Check the available RAM:

  •  free -g 

  •  cat /proc/meminfo 

3. Check what applications are using RAM: “top” or “htop” (see the resident vs virtual memory)

4. Check MySQL configuration: check /etc/my.cnf or in general /etc/my* (including /etc/mysql/* and other files). MySQL may be running with the different my.cnf ( run ps ax| grep mysql )

5. Run  vmstat 5 5 to see if the system is reading/writing via virtual memory and if it is swapping

6. For non-production environments, we can use other tools (like Valgrind, gdb, etc) to examine MySQL usage

Part 2: Checks Inside MySQL

Now we can check things inside MySQL to look for potential MySQL memory leaks.

MySQL allocates memory in tons of places, especially:

  • Table cache
  • Performance_schema (run: show engine performance_schema status and look at the last line). That may be the cause for the systems with a small amount of RAM, i.e. 1G or less
  • InnoDB (run  show engine innodb status and check the buffer pool section, memory allocated for buffer_pool and related caches)
  • Temporary tables in RAM (find all in-memory tables by running: select * from information_schema.tables where engine='MEMORY')
  • Prepared statements, when it is not deallocated (check the number of prepared commands via deallocate command by running show global status like  'Com_prepare_sql';show global status like 'Com_dealloc_sql')

The good news is, starting with MySQL 5.7, we have memory allocation in performance_schema. Here is how we can use it:

  1. First, we need to enable collecting memory metrics. Run:

UPDATE setup_instruments SET ENABLED = 'YES'
WHERE NAME LIKE 'memory/%';

2. Run the report from sys schema:

select event_name, current_alloc, high_alloc
from sys.memory_global_by_current_bytes
where current_count > 0;

3. Usually, this will give you the place in code when memory is allocated. It is usually self-explanatory. In some cases, we can search for bugs or we might need to check the MySQL source code.

For example, for the bug where memory was over-allocated in triggers ( https://bugs.mysql.com/bug.php?id=86821) the select shows:

mysql> select event_name, current_alloc, high_alloc from memory_global_by_current_bytes where current_count > 0;
+--------------------------------------------------------------------------------+---------------+-------------+
| event_name                                                                     | current_alloc | high_alloc  |
+--------------------------------------------------------------------------------+---------------+-------------+
| memory/innodb/buf_buf_pool                                                     | 7.29 GiB      | 7.29 GiB    |
| memory/sql/sp_head::main_mem_root                                              | 3.21 GiB      | 3.62 GiB    |
...

The largest chunk of RAM is usually the buffer pool but ~3G in stored procedures seems to be too high.

According to the MySQL source code documentation, sp_head represents one instance of a stored program, which might be of any type (stored procedure, function, trigger, event). In the above case, we have a potential memory leak.

In addition, we can get a total report for each higher level event if we want to see from the bird's eye what is eating memory:

mysql> select  substring_index(
    ->     substring_index(event_name, '/', 2),
    ->     '/',
    ->     -1
    ->   )  as event_type,
    ->   round(sum(CURRENT_NUMBER_OF_BYTES_USED)/1024/1024, 2) as MB_CURRENTLY_USED
    -> from performance_schema.memory_summary_global_by_event_name
    -> group by event_type
    -> having MB_CURRENTLY_USED>0;
+--------------------+-------------------+
| event_type         | MB_CURRENTLY_USED |
+--------------------+-------------------+
| innodb             |              0.61 |
| memory             |              0.21 |
| performance_schema |            106.26 |
| sql                |              0.79 |
+--------------------+-------------------+
4 rows in set (0.00 sec)

I hope these simple steps can help troubleshoot MySQL crashes due to running out of memory.

MySQL Memory (storage engine)

Published at DZone with permission of Alexander Rubin, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Related

  • Memory-Optimized Tables: Implementation Strategies for SQL Server
  • Useful System Table Queries in Relational Databases
  • Doris: Unifying SQL Dialects for a Seamless Data Query Ecosystem
  • Analyzing “java.lang.OutOfMemoryError: Failed to create a thread” Error

Partner Resources

×

Comments
Oops! Something Went Wrong

The likes didn't load as expected. Please refresh the page and try again.

ABOUT US

  • About DZone
  • Support and feedback
  • Community research
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Core Program
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 3343 Perimeter Hill Drive
  • Suite 100
  • Nashville, TN 37211
  • support@dzone.com

Let's be friends:

Likes
There are no likes...yet! 👀
Be the first to like this post!
It looks like you're not logged in.
Sign in to see who liked this post!