在MVCC中,讀操作可以分成兩類:快照讀 (snapshot read)與當(dāng)前讀 (current read)。 快照讀,讀取的是記錄的可見版本 (有可能是歷史版本),不用加鎖。當(dāng)前讀,讀取的是記錄的最新版本,并且對返回的記錄,都會加上鎖,保證在事務(wù)結(jié)束前,這條數(shù)據(jù)都是最新版本。
-- 基本操作 --
-- 查詢事務(wù)隔離級別,默認(rèn)是RR
show variables like '%isolation%';
-- 設(shè)置事務(wù)隔離級別為RC
set session transaction isolation level read committed;
-- 數(shù)據(jù)初始化 --
begin;
drop table if exists user;
CREATE TABLE `user` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`email` varchar(64) NOT NULL,
`age` int(11) NOT NULL,
`address` varchar(64) NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `uniq_email` (`email`),
KEY `idx_age` (`age`)
);
insert into user (email, age, address) values ("test1@elsef.com", 18, "address1");
insert into user (email, age, address) values ("test2@elsef.com", 20, "address2");
insert into user (email, age, address) values ("test3@elsef.com", 20, "address3");
commit;
select * from user;
-- 一、trx_id示例
begin;
SELECT TRX_ID FROM INFORMATION_SCHEMA.INNODB_TRX WHERE TRX_MYSQL_THREAD_ID = CONNECTION_ID();
select * from user;
SELECT TRX_ID FROM INFORMATION_SCHEMA.INNODB_TRX WHERE TRX_MYSQL_THREAD_ID = CONNECTION_ID();
SHOW ENGINE INNODB STATUS;
update user set age = 22 where id = 3;
-- 查詢事務(wù)id
SELECT TRX_ID FROM INFORMATION_SCHEMA.INNODB_TRX WHERE TRX_MYSQL_THREAD_ID = CONNECTION_ID();
-- INNODB 引擎狀態(tài)
SHOW ENGINE INNODB STATUS;
commit;
-- 二、可重復(fù)讀、不可重復(fù)讀示例
-- session1
set session transaction isolation level read committed;
begin;
-- session2
set session transaction isolation level repeatable read;
begin;
-- session1
select * from user;
-- session2
select * from user;
-- session3
begin;
insert into user (email, age, address) values ("test4@elsef.com", 30, "address4");
commit;
-- session1 這里因為是RC,所以可以讀到trx3提交的新數(shù)據(jù),這里如果是證明不可重復(fù)讀的話應(yīng)該使用update而不是insert
select * from user;
commit;
-- session2 這里因為是RR,所以不會讀到trx3提交的新數(shù)據(jù)
select * from user;
commit;
-- 三、快照讀幻讀示例
-- session1
set session transaction isolation level repeatable read;
begin;
-- 這里使用快照讀
select * from user;
-- session2
begin;
insert into user (email, age, address) values ("test4@elsef.com", 30, "address4");
commit;
select * from user;
-- session1
select * from user; -- 這里讀不到test4@的數(shù)據(jù),因為是RR
-- 這里發(fā)生了幻讀
insert into user (email, age, address) values ("test4@elsef.com", 30, "address4"); -- 插入失敗因為email唯一索引沖突
commit;
-- 四、當(dāng)前讀幻讀示例
-- RC
-- session1
set session transaction isolation level read committed;
begin;
-- 這里會對所有滿足條件的age=20的記錄加鎖,因為是RC,所以沒有GAP鎖
delete from user where age = 20;
select * from user;
-- session2
set session transaction isolation level read committed;
begin;
-- 因為trx1沒有加GAP鎖,所以之類可以插入age=20的記錄
insert into user (email, age, address) values ("test4@elsef.com", 20, "address4");
select * from user; -- 可以查到4條數(shù)據(jù),可以讀到trx1的刪除數(shù)據(jù),因為是RC,trx1未提交所以沒影響trx2
commit;
-- session1
select * from user; -- 可以讀到trx2新插入的數(shù)據(jù),雖然trx1是當(dāng)前讀,但是并未添加相應(yīng)的next-key鎖,沒有阻止trx2的新數(shù)據(jù)插入
commit;
--RR
-- session1
set session transaction isolation level repeatable read;
begin;
delete from user where age = 20;
select * from user;
-- session2
begin;
-- 這里會阻塞,因為trx1在age=20周圍加了GAP鎖
-- 非唯一索引,首先,通過索引定位到第一條滿足查詢條件的記錄,加記錄上的X鎖,加GAP上的GAP鎖,然后加主鍵聚簇索引上的記錄X鎖;
-- 然后讀取下一條,重復(fù)進(jìn)行。直至進(jìn)行到第一條不滿足條件的記錄,此時,不需要加記錄X鎖,但是仍舊需要加GAP鎖,最后返回結(jié)束。
insert into user (email, age, address) values ("test4@elsef.com", 20, "address4");
-- 直到超時,ERROR 1205 (HY000): Lock wait timeout exceeded; try restarting transaction
-- 此時如果查詢可以看到3條記錄
commit;
-- session1
-- 此時只能看到1條記錄,另外兩條被刪除了
select * from user;
commit;
-- 唯一索引+RC
-- session1
set session transaction isolation level read committed;
begin;
delete from user where email = "test3@elsef.com";
-- session2
begin;
-- 可以讀到,因為trx1是RC
select * from user where email = "test3@elsef.com";
-- 嘗試更新這個記錄的age,會阻塞直到超時,因為email是唯一索引已經(jīng)被trx1鎖住了,同時也會在對應(yīng)的主鍵索引上加鎖
-- 注意這里操作的id=3就是trx1中操作的email的同一行記錄
update user set age = 40 where id = 3;
-- session1
commit;
-- session2
commit;
-- 無索引+RC
-- session1
set session transaction isolation level read committed;
begin;
-- 由于address字段無索引,所以Innodb會對所有行進(jìn)行加鎖,由MySQL server進(jìn)行判斷并釋放鎖
delete from user where address = "address3";
-- session2
set session transaction isolation level read committed;
begin;
-- 這一行會成功,因為這一行沒有加鎖(先加了后釋放了)
update user set age = 10 where address = "address2";
-- 這一行同樣會被阻塞,原因是它已經(jīng)被trx1的語句加了鎖了,全部符合條件的都加鎖了
update user set age = 10 where address = "address3";
-- session1
commit;
-- session2
commit;
-- 非唯一索引+RR
-- session1
set session transaction isolation level repeatable read;
begin;
delete from user where age = 20;
-- session2
set session transaction isolation level repeatable read;
begin;
-- 這里會阻塞,因為trx1中已經(jīng)鎖住了age=20的記錄以及加上了GAP鎖,所以這里18已經(jīng)落入鎖區(qū)間
insert into user (email, age, address) values ("test4@elsef.com", 18, "address4");
-- session1
commit;
-- session2
commit;
-- 無索引RR
-- session1
set session transaction isolation level repeatable read;
begin;
-- 沒有索引,那么會鎖上表中的所有記錄,同時會鎖上主鍵索引上的所有GAP,杜絕所有的并發(fā)更新操作
delete from user where address = "address3";
-- session2
set session transaction isolation level repeatable read;
begin;
-- 這里會阻塞,原因是主鍵已經(jīng)被加上了GAP鎖,所以新的插入不能執(zhí)行成功
insert into user (email, age, address) values ("test4@elsef.com", 18, "address4");
-- session1
commit;
-- session2
commit;
-- 死鎖 簡單示例
-- session1
begin;
delete from user where id = 1;
-- session2
begin;
delete from user where id = 3;
-- session1
delete from user where id = 3;
-- seession2
-- 這里MySQL判斷發(fā)生了死鎖,中斷了一個trx
-- ERROR 1213 (40001): Deadlock found when trying to get lock; try restarting transaction
delete from user where id = 1;
-- session1
rollback;
-- session2;
rollback;
-- 五、死鎖 insert示例
drop table if exists t1;
begin;
create table t1 (
`id` bigint not null auto_increment,
primary key (`id`)
);
insert into t1 values(1);
insert into t1 values(5);
commit;
select * from t1;
-- session1
begin;
insert into t1 values (2);
-- sessioin2
begin;
-- 這里會阻塞
insert into t1 values (2);
-- session3
begin;
-- 這里會阻塞
insert into t1 values (2);
-- session1;
-- 此時回滾,trx2和trx3收到通知,MySQL自動中斷一個trx,因為發(fā)生了死鎖
-- ERROR 1213 (40001): Deadlock found when trying to get lock; try restarting transaction
rollback;
--session2;
rollback;
--session3;
rollback;
以上就是這篇文章的全部內(nèi)容了,希望本文的內(nèi)容對大家的學(xué)習(xí)或者工作具有一定的參考學(xué)習(xí)價值,如果有疑問大家可以留言交流,謝謝大家對腳本之家的支持。