基于行版本控制的隔离级别示例
下列示例说明使用行版本控制的快照隔离事务和已提交读事务的行为差异。
注意: |
---|
查看下列示例之前,有必要了解基于行版本控制的隔离级别。请参阅了解基于行版本控制的隔离级别和使用基于行版本控制的隔离级别。 |
示例
A. 使用快照隔离
在此示例中,在快照隔离下运行的事务将读取数据,然后由另一事务修改此数据。快照事务不阻塞由其他事务执行的更新操作,它忽略数据的修改继续从版本化的行读取数据。但是,当快照事务尝试修改已由其他事务修改的数据时,快照事务将生成错误并终止。
在会话 1 上:
USE AdventureWorks;
GO
-- Enable snapshot isolation on the database.
ALTER DATABASE AdventureWorks
SET ALLOW_SNAPSHOT_ISOLATION ON;
GO
-- Start a snapshot transaction
SET TRANSACTION ISOLATION LEVEL SNAPSHOT;
GO
BEGIN TRANSACTION;
-- This SELECT statement will return
-- 48 vacation hours for the employee.
SELECT EmployeeID, VacationHours
FROM HumanResources.Employee
WHERE EmployeeID = 4;
在会话 2 上:
USE AdventureWorks;
GO
-- Start a transaction
BEGIN TRANSACTION;
-- Subtract a vacation day from employee 4.
-- Update is not blocked by session 1 since
-- under snapshot isolation shared locks are
-- not requested.
UPDATE HumanResources.Employee
SET VacationHours = VacationHours - 8
WHERE EmployeeID = 4;
-- Verify that the employee now has 40 vacation hours.
SELECT VacationHours
FROM HumanResources.Employee
WHERE EmployeeID = 4;
在会话 1 上:
-- Reissue the SELECT statement - this shows
-- the employee having 48 vacation hours. The
-- snapshot transaction is still reading data from
-- the versioned row.
SELECT EmployeeID, VacationHours
FROM HumanResources.Employee
WHERE EmployeeID = 4;
在会话 2 上:
-- Commit the transaction; this commits the data
-- modification.
COMMIT TRANSACTION;
GO
在会话 1 上:
-- Reissue the SELECT statement - this still
-- shows the employee having 48 vacation hours
-- even after the other transaction has committed
-- the data modification.
SELECT EmployeeID, VacationHours
FROM HumanResources.Employee
WHERE EmployeeID = 4;
-- Because the data has been modified outside of the
-- snapshot transaction, any further data changes to
-- that data by the snapshot transaction will cause
-- the snapshot transaction to fail. This statement
-- will generate a 3960 error and the transaction will
-- terminate.
UPDATE HumanResources.Employee
SET SickLeaveHours = SickLeaveHours - 8
WHERE EmployeeID = 4;
-- Undo the changes to the database from session 1.
-- This will not undo the change from session 2.
ROLLBACK TRANSACTION
GO
B. 使用通过行版本控制的已提交读
在此示例中,使用行版本控制的已提交读事务与其他事务并发运行。已提交读事务的行为与快照事务的行为有所不同。与快照事务相同的是,即使其他事务修改了数据,已提交读事务也将读取版本化的行。然而,与快照事务不同的是,已提交读将执行下列操作:
- 在其他事务提交数据更改后,读取修改的数据。
- 能够更新由其他事务修改的数据,而快照事务不能。
在会话 1 上:
USE AdventureWorks;
GO
-- Enable READ_COMMITTED_SNAPSHOT on the database.
-- For this statement to succeed, this session
-- must be the only connection to the AdventureWorks
-- database.
ALTER DATABASE AdventureWorks
SET READ_COMMITTED_SNAPSHOT ON;
GO
-- Start a read-committed transaction
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
GO
BEGIN TRANSACTION;
-- This SELECT statement will return
-- 48 vacation hours for the employee.
SELECT EmployeeID, VacationHours
FROM HumanResources.Employee
WHERE EmployeeID = 4;
在会话 2 上:
USE AdventureWorks;
GO
-- Start a transaction
BEGIN TRANSACTION;
-- Subtract a vacation day from employee 4.
-- Update is not blocked by session 1 since
-- under read-committed using row versioning shared locks are
-- not requested.
UPDATE HumanResources.Employee
SET VacationHours = VacationHours - 8
WHERE EmployeeID = 4;
-- Verify that the employee now has 40 vacation hours.
SELECT VacationHours
FROM HumanResources.Employee
WHERE EmployeeID = 4;
在会话 1 上:
-- Reissue the SELECT statement - this still shows
-- the employee having 48 vacation hours. The
-- read-committed transaction is still reading data
-- from the versioned row and the other transaction
-- has not committed the data changes yet.
SELECT EmployeeID, VacationHours
FROM HumanResources.Employee
WHERE EmployeeID = 4;
在会话 2 上:
-- Commit the transaction
COMMIT TRANSACTION;
GO
在会话 1 上:
-- Reissue the SELECT statement which now shows the
-- employee having 40 vacation hours. Being
-- read-committed, this transaction is reading the
-- committed data. This is different from snapshot
-- isolation which reads from the versioned row.
SELECT EmployeeID, VacationHours
FROM HumanResources.Employee
WHERE EmployeeID = 4;
-- This statement, which caused the snapshot transaction
-- to fail, will succeed with read-committed using row versioning.
UPDATE HumanResources.Employee
SET SickLeaveHours = SickLeaveHours - 8
WHERE EmployeeID = 4;
-- Undo the changes to the database from session 1.
-- This will not undo the change from session 2.
ROLLBACK TRANSACTION;
GO
请参阅
概念
了解基于行版本控制的隔离级别
选择基于行版本控制的隔离级别
事务(数据库引擎)
使用基于行版本控制的隔离级别