Friday, August 1, 2014

Non Repeatable Reads Or Phantom Reads in SQL Server


Non-repeatable Reads occur when transaction1 in Session1 access/read the data and in Session2 other Transaction2 modify (Commit) the accessed Data.
When we again access/read same data in Session1 by Tranaction1 then we get different/modified value.

Phantom Reads occur when transaction1 in Session1 access/reads the range of data and in Session2 other Transaction2 modify (Insert/Delete) the accessed Data of given range.
Phantom Read is special case of Non-repeatable Reads.

Continuing the table structure from below link:
http://dineshbabuverma.blogspot.com/2014/07/read-committed-vs-repeatable-read-in.html

Let us Create table structure as we created in above link


if exists(SELECT * FROM SYS.OBJECTS WHERE NAME = 'Emp_Temp')
BEGIN
DROP TABLE Emp_Temp
END

if exists(SELECT * FROM SYS.OBJECTS WHERE NAME = 'Dept_TEMP')
BEGIN
DROP TABLE Dept_TEMP
END

CREATE TABLE Emp_Temp (EmpId int primary key,EmpName Varchar(100), DeptId int)
insert Emp_Temp values (1,'Allen',    6)
insert Emp_Temp values (2,'Defriez', 6)
insert Emp_Temp values (3,'Sean',    6)
insert Emp_Temp values (4,'Alex',    6)
insert Emp_Temp values (5,'Blex',    6)

CREATE TABLE Dept_TEMP (DeptId int Primary Key, DeptName varchar(100) , EmpCount int)
-- Now, in session 1 lock the Fourth row of table Emp_Temp
BEGIN TRAN
UPDATE Emp_Temp set EmpId = 4 where EmpId = 4

/* Now , in New session 2 run the following outer join at repeatable read isolation level:*/
set transaction isolation level repeatable read
select * from Emp_Temp e left outer join Dept_TEMP d on e.DeptId = d.deptid

/*This plan scans the first row from Emp_Temp, tries to join it with Dept_TEMP, finds there are no matching rows, and outputs a NULL extended row.
It then blocks waiting for session 1 to release the lock on the second row of Emp_Temp. Finally, in session 1, insert a new row into Dept_TEMP and release the lock:*/

INSERT Dept_TEMP values (6,'IT', 100)
COMMIT TRAN

-- Now go back to session2, we are getting below result set.
EmpId     EmpName      DeptId     DeptId      DeptName   EmpCount
1               Allen               6             NULL        NULL       NULL
2               Defriez            6             NULL        NULL       NULL
3               Sean               6              NULL        NULL       NULL
4               Alex                6              6                IT             100
5               Blex                6              6                 IT            100


/* This happens becuase we have selected info with Lower isolation(repeatable read) in session2
if we select this info with higer isolation(serializable) as below*/
set transaction isolation level Serializable
SELECT * FROM Emp_Temp e LEFT OUTER JOIN Dept_TEMP d on e.DeptId = d.deptid

-- it shows below error.
Msg 1205, Level 13, State 51, Line 10
Transaction (Process ID 56) was deadlocked on lock resources with another process and has been chosen as the deadlock victim. Rerun the transaction.

Note: I have explained above with respect to isolations levels.
Lets us Understand Non-repeatable Reads and Phantom Reads in very simple terms

Non-Repeatable Reads:
let us consider, we have Transaction1 in Session1 and Transaction2 in Session2

now in session1 by Transaction1 we have query.
 BEGIN TRAN
Select EmpName from Emp_Temp where EmpId= 2
COMMIT
Query Output.
 EmpName
 Defriez

now in session2 by Transaction2 we have query.
 BEGIN TRAN
Update Emp_Temp
SET EmpName=  'Jack' where EmpId = 2
 COMMIT
 Query Output.
(1 row(s) affected)

now go back in session1 by Transaction1 execute same Query
BEGIN TRAN
 Select EmpName from Emp_Temp where EmpId= 2
 COMMIT

Query Output.
 EmpName
 Jack
Note: Same query in session1 returning two different values  this we called Non-repeatable Reads

Phantom Reads:
now in session1 by Transaction1 we have select query with where clause specifying range of data.
 BEGIN TRAN
Select * from Emp_Temp where EmpId> = 2 and Empid < 5
COMMIT
Query Output.
EmpId EmpName DeptId
2 Jack 6
3 Sean 6
4 Alex 6

Now in session2 by Transaction2 we have query.
BEGIN TRAN
DELETE Emp_Temp
 where EmpId = 3 COMMIT
 Query Output.
(1 row(s) affected)

now go back in session1 by Transaction1 execute same Query
BEGIN TRAN
Select * from Emp_Temp where EmpId> = 2 and Empid < 5
 COMMIT
 Query Output:
EmpId EmpName DeptId
2 Jack 6
4 Alex 6

Note: Same query in session1 returning different number of records this we called Phantom Reads

Hope this mght have helped us to under the different between Non-repeatable Reads and Phantom Reads.

No comments :

Post a Comment