先看程序报错:
2017-06-12 21:18:40.856 [ForkJoinPool.commonPool-worker-12] ERROR com.jd.gms.maindata.accurate.service.impl.FixServiceImpl[51] - FixServiceImpl.fixSkuAttribute error java.lang.RuntimeException: org.springframework.dao.DeadlockLoserDataAccessException: ### Error updating database. Cause: com.mysql.jdbc.exceptions.jdbc4.MySQLTransactionRollbackException: Deadlock found when trying to get lock; try restarting transaction ### The error may involve SkuAttribute.draftInsert-Inline ### The error occurred while setting parameters ### SQL: insert into sku_1 ( sku_id, prop_type, com_att_id, com_att_val_id, val, source, category_id, version, created, modified ) values ( ?, ?, ?, ?, ?, ?, ?, ?, now(), now() ) ON DUPLICATE KEY UPDATE sku_id = ?, prop_type = ?, com_att_id = ?, com_att_val_id = ?, val = ?, source = ?, category_id = ?, version = ?, modified = now() ### Cause: com.mysql.jdbc.exceptions.jdbc4.MySQLTransactionRollbackException: Deadlock found when trying to get lock; |
---|
从报错信息可以看出有死锁,insert SQL导致,研发有些不理解,insert操作怎么会导致死锁?
我们都知道, insert into values存在X row record lock。
但后面的需要更加注意,对于存在auto_increment列,存在X lock在auto_increment列的index,特殊的表级AUTO-INC lock,如果insert产生duplicate-key错误,则在duplicate index record设置S lock,如果多个session插入同一行则可以产生deadlock。
官方文档对于insert 加锁说明:
Insert sets an exclusive lock on the inserted row. This lock is an index-record lock, not a next-key lock (that is, there is no gap lock) and does not prevent other sessions from inserting into the gap before the inserted row.Prior to inserting the row, a type of gap lock called an insertion intention gap lock is set. 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.If a duplicate-key error occurs, a shared lock on the duplicate index record is set. This use of a shared lock can result in deadlock should there be multiple sessions trying to insert the same row if another session already has an exclusive lock.
大概意思就是:insert会对插入成功的行加上排它锁,这个排它锁是个记录锁,而非next-key锁(也不是gap锁了),不会阻止其他并发的事务往这条记录之前插入记录。在插入之前,会先在插入记录所在的间隙加上一个插入意向gap锁,并发的事务可以对同一个gap加意向gap锁。如果insert 的事务出现了duplicate-key error ,事务会对duplicate index record加共享锁。这个共享锁在并发的情况下是会产生死锁的,比如有两个并发的insert都对要对同一条记录加共享锁,而此时这条记录又被其他事务加上了排它锁,排它锁的事务提交或者回滚后,两个并发的insert操作是会发生死锁。
先看下加锁的表结构,存在id主键和sku_id,prop_type,com_att_id,source的唯一索引:
CREATE TABLE `sku_1` (
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '自增',
`sku_id` bigint(20) NOT NULL,
`prop_type` tinyint(4) DEFAULT NULL,
`com_att_id` int(11) DEFAULT NULL,
`com_att_val_id` varchar(150) DEFAULT NULL,
`val` varchar(200) DEFAULT NULL,
`source` int(11) DEFAULT NULL,
`category_id` int(11) DEFAULT NULL,
`version` varchar(50) DEFAULT NULL,
`created` datetime DEFAULT NULL,
`modified` datetime DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `unique` (`sku_id`,`prop_type`,`com_att_id`,`source`)
) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8;
演示下insert 的事务出现了duplicate key error的情况:
步骤 | 事务1 | 事务2 | 事务3 |
---|---|---|---|
1 | mysql> begin; Query OK, 0 rows affected (0.00 sec) | mysql> begin; Query OK, 0 rows affected (0.00 sec) | mysql> begin; Query OK, 0 rows affected (0.00 sec) |
2 | mysql> insert into sku_1 (sku_id,prop_type,com_att_id,com_att_val_id,val,source,category_id,version,created,modified) values (9807755,4,3495,'8339','L',58,12004,'10000',now(),now()); Query OK, 1 row affected (0.04 sec) | ||
3 | mysql> insert into sku_1 (sku_id,prop_type,com_att_id,com_att_val_id,val,source,category_id,version,created,modified) values (9807755,4,3495,'8339','L',58,12004,'10000',now(),now()); 锁等待 | mysql> insert into sku_1 (sku_id,prop_type,com_att_id,com_att_val_id,val,source,category_id,version,created,modified) values (9807755,4,3495,'8339','L',58,12004,'10000',now(),now()); 锁等待 | |
4 | mysql> rollback; Query OK, 0 rows affected (0.00 sec) | ||
5 | mysql> insert into sku_1 (sku_id,prop_type,com_att_id,com_att_val_id,val,source,category_id,version,created,modified) values (9807755,4,3495,'8339','L',58,12004,'10000',now(),now()); Query OK, 1 row affected (37.17 sec) | mysql> insert into sku_1 (sku_id,prop_type,com_att_id,com_att_val_id,val,source,category_id,version,created,modified) values (9807755,4,3495,'8339','L',58,12004,'10000',now(),now()); ERROR 1213 (40001): Deadlock found when trying to get lock; try restarting transaction 死锁发生了 |
通过innodb_locks、innodb_lock_waits查看当前索引信息:
4475是事务1 ,4480和4481分别是事务2和3,从innodb_locks表中可以看出事务1是X记录锁,事务2和3是S记录锁,且这三个锁对应的是同样的记录,从innodb_lock_waits表可以看出事务2和事务3的S锁被事务1的X锁阻塞了。
当事务1 rollback后,事务2和事务3发生死锁。
通过show engine innodb status查看死锁日志如下:
从上面死锁日志,我们可以很容易理解死锁为何发生。事务1插入记录,事务2插入同一条记录,主键冲突,事务2将事务1的隐式锁转为显式锁,同时事务2向队列中加入一个s锁请求;
事务3同样也加入一个s锁请求;
当事务1回滚后,事务2和事务3获得s锁,但随后事务2和事务3又先后请求插入意向锁,因此锁队列为:
事务2(S GAP)<—事务3(S GAP)<—事务2(插入意向锁)<–事务3(插入意向锁)
事务3(S锁),事务2(X锁),事务3(X锁)形成死锁。这样的死锁不光出现在unique key,还包括primary key。
优化insert引起的死锁:
1、从程序逻辑上处理,尽量不要在高并发下同时insert一条数据
2、如果非特殊需求修改为非唯一索引
3、通过数据库连接池做分发处理
4、并发插入时,不在一个事务内进行再次事务提交 5、通过其他手段,如缓存方案,解决这个要并发插入的问题
6、改并发为串行执行