Udostępnij za pośrednictwem


Row Versioning-based Isolation Level Example

The following examples show the differences in behavior between snapshot isolation transactions and read-committed transactions that use row versioning.

Note

It is important to understand row versioning-based isolation levels before reviewing the following examples. See Understanding Row Versioning-Based Isolation Levels and Using Row Versioning-based Isolation Levels.

Examples

A. Working with snapshot isolation

In this example, a transaction running under snapshot isolation reads data that is then modified by another transaction. The snapshot transaction does not block the update operation executed by the other transaction, and it continues to read data from the versioned row, ignoring the data modification. However, when the snapshot transaction attempts to modify the data that has already been modified by the other transaction, the snapshot transaction generates an error and is terminated.

On session 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;

On session 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;

On session 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;

On session 2:

-- Commit the transaction; this commits the data
-- modification.
COMMIT TRANSACTION;
GO

On session 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. Working with read-committed using row versioning

In this example, a read-committed transaction using row versioning runs concurrently with another transaction. The read-committed transaction behaves differently than a snapshot transaction. Like a snapshot transaction, the read-committed transaction will read versioned rows even after the other transaction has modified data. However, unlike a snapshot transaction, the read-committed transaction will:

  • Read the modified data after the other transaction commits the data changes.
  • Be able to update the data modified by the other transaction where the snapshot transaction could not.

On session 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;

On session 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;

On session 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;

On session 2:

-- Commit the transaction
COMMIT TRANSACTION;
GO

On session 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

See Also

Concepts

Understanding Row Versioning-Based Isolation Levels
Choosing Row Versioning-based Isolation Levels
Transactions (Database Engine)
Using Row Versioning-based Isolation Levels

Other Resources

Row Versioning-based Isolation Levels in the Database Engine

Help and Information

Getting SQL Server 2005 Assistance