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

Last call! Secure your stack and shape the future! Help dev teams across the globe navigate their software supply chain security challenges.

Modernize your data layer. Learn how to design cloud-native database architectures to meet the evolving demands of AI and GenAI workloads.

Releasing software shouldn't be stressful or risky. Learn how to leverage progressive delivery techniques to ensure safer deployments.

Avoid machine learning mistakes and boost model performance! Discover key ML patterns, anti-patterns, data strategies, and more.

Related

  • Fine-Tuning Performance, Resolving Common Issues in FinTech Application With MySQL
  • Optimizing Data Management: Migrating From AWS RDS MySQL to Snowflake
  • Common Mistakes to Avoid When Writing SQL Code
  • SQL Commands: A Brief Guide

Trending

  • How to Submit a Post to DZone
  • DZone's Article Submission Guidelines
  • Medallion Architecture: Why You Need It and How To Implement It With ClickHouse
  • Event-Driven Architectures: Designing Scalable and Resilient Cloud Solutions
  1. DZone
  2. Data Engineering
  3. Databases
  4. The Curious Case of Dead-End-Lock(Deadlock) | MySql

The Curious Case of Dead-End-Lock(Deadlock) | MySql

Reproduce Gap Lock and Solution to deadlock in MySql.

By 
Anuj Aneja user avatar
Anuj Aneja
·
Jul. 08, 21 · Analysis
Likes (2)
Comment
Save
Tweet
Share
7.9K Views

Join the DZone community and get the full member experience.

Join For Free

Usually, deadlocks are hard to debug, and often the main reason for the occurrence of deadlock is when a set of processes are in a wait state because each process is waiting for a resource that is held by some other waiting process. Therefore, all deadlocks involve conflicting resource needs by two or more processes.

Deadlock

Recently, in the Production system, we found a case wherein one of the API was getting a lot of failure of transactions due to deadlock. Strange thing was that it was not a total freeze deadlock of threads instead out of two conflicting transactions one was getting successfully completed.

After going through the logs and further analysis we conclude the following things:

NOTE: For finding the last deadlock details you can use “SHOW Innodb engine Status\G”. This is really helpful in identifying which two transactions and queries are giving us the deadlock condition.

  • Deadlock is occurring at the MYSQL level and
  • MYSQL is doing a deadlock resolution by killing one of the transactions.

Re-Production Steps

For better, understanding lets list down the steps to reproduce this kind of deadlock:

MySQL
 
CREATE TABLE `parent` (
  `id` int(10) unsigned NOT NULL AUTO_INCREMENT,
  `name` varchar(50) DEFAULT NULL,
  `created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  PRIMARY KEY (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=2 DEFAULT CHARSET=utf8;

CREATE TABLE `child` (
  `id` int(10) unsigned NOT NULL AUTO_INCREMENT,
  `name` varchar(50) DEFAULT NULL,
  `parent_id` int(10) unsigned DEFAULT NULL,
  `created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  PRIMARY KEY (`id`),
  KEY `parent_id` (`parent_id`),
  CONSTRAINT `child_ibfk_1` FOREIGN KEY (`parent_id`) REFERENCES `parent` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

Open two MYSQL command prompt and create two separate transaction as given below(step by step in order)

MySQL
 
Terminal 1(Transaction 1)
begin; -- Step 1
insert into parent values(1, 'example Order 1', now()); -- step 2
select * from parent p left join child c on c.parent_id=p.id where p.id=1 for update; -- Step 3 // Pessimistic lock
insert child(`name`, `parent_id`, `created_at`) values('child 1', 1, now()); -- Step 8 
ERROR 1213 (40001): Deadlock found when trying to get lock; try restarting transaction

Terminal 2(Transaction 2)
begin; -- Step 4
insert into parent values(2, 'example Order 2', now()); -- step 5
select * from parent p left join child c on p.id=c.parent_id where p.id=2 for update; -- Step 6
insert child(`name`, `parent_id`, `created_at`) values('child 1', 2, now()); -- Step 7 //Waiting for lock...
But, Successfully executed after Step 8....

Now, you have re-produced the deadlock scenario. Let’s understand the main reason behind the deadlock. Any guesses???

The main reason for Deadlock is Step 3 and Step 6. But, both queries are taking a lock on the different parent id? Strange isn’t it!!!

MySQL
 
select * from parent p left join child c on c.parent_id=p.id where p.id=1 for update; -- Step 3 // Pessimistic lock

select * from parent p left join child c on p.id=c.parent_id where p.id=2 for update; -- Step 6 // Pessimistic lock

In order to understand this. We need to understand Gap Lock.

Gap Lock:

A gap lock is a lock on a gap between index records, or a lock on the gap before the first or after the last index record.

In addition to foreign-key constraint checking and duplicate key checking, gap locking is enabled for searches and an index scan if the transaction isolation level is above Repeatable Read. (Default one in MYSQL).

This locking mechanism helps to prevent other transactions from inserting into the gap while the transaction reads the range. As a result, InnoDB can prevent Phantom-Read anomaly even if its transaction isolation level is Repeatable Read.


Gap Lock

Insert Intention Locks:-

An insert intention lock is a type of gap lock set by INSERT operations prior to row insertion. This lock signals the intent to insert in such a way that multiple transactions inserting into the same index gap need not wait for each other if they are not inserting at the same position within the gap.

MySQL
 
Terminal 1: Client A

CREATE TABLE child (id int(11) NOT NULL, PRIMARY KEY(id)) ENGINE=InnoDB;
INSERT INTO child (id) values (90),(102);

begin;//START TRANSACTION; 
SELECT * FROM child WHERE id > 100 FOR UPDATE; 

+-----+ | id | +-----+ | 102 | +-----+

Client B begins a transaction to insert a record into the gap. The transaction takes an insert intention lock while it waits to obtain an exclusive lock. i.e. Transaction 2(Terminal 2)- client B will wait.

MySQL
 
begin; //START TRANSACTION; 
INSERT INTO child (id) VALUES (101); // Waiting...

Now coming back to our old example:

  • In our case, Transaction 1(Step 3) is taking a Pessimistic lock on “p.id=1” but this query is taking a left join on the child table (parent_id) foreign key of parent.
  • As there is no record inserted into the child table for parent_id=1 so this above given query will take a gap lock on parent_id greater than the last index record in our case it is, all ids greater than 1. Which is making the Step 7 (Transaction 2) query go into the wait state. (insert into the child table, which is taking an `Insert intension lock`)
  • and Step 8(Transaction 8) is also doing a similar operation (insert into the child, which is taking an `insert intension lock`) which is also blocked. Fortunately, MYSQL has a deadlock detection & resolution process in place which kills one of the transactions.

Solution

We removed the join of the child table and it worked fine. Instead, we fetch the child in a separate query.

MySQL
 
select * from parent p where p.id=1 for update; — Step 3 // Pessimistic lock
select * from child c where c.parent_id=1; //Separate query…

References

https://dev.mysql.com/doc/refman/5.7/en/innodb-locking.html#innodb-gap-locks

https://www.brightbox.com/blog/2013/10/31/on-mysql-locks/

MySQL Database Threading Lock (computer science) Relational database

Opinions expressed by DZone contributors are their own.

Related

  • Fine-Tuning Performance, Resolving Common Issues in FinTech Application With MySQL
  • Optimizing Data Management: Migrating From AWS RDS MySQL to Snowflake
  • Common Mistakes to Avoid When Writing SQL Code
  • SQL Commands: A Brief Guide

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!