Labels

Thursday, December 29, 2011

Concurrency Control with rowversion

Pessimistic concurrency means locking the data at the row, page, or table level and don't allow anyone to modify it until the target user is done modifying and saving it back to the database. Trouble with this method: it may take a few minutes for the target user to update a record during which other users may be prevented from doing their work (locked out from the table). If the target user called away for a meeting for example in the middle of data entry, you need to unlock the table by a timeout mechanism in order to prevent disruption to data access by other users.
Optimistic concurrency means reading a record in a table and displaying it for the target user, but not locking it. Other users can read and modify the record at anytime while the target user is performing the manual update on the computer screen. When the target user releases the record for database update you need to check if someone changed it in between the initial read and the release (like 1-5 minutes). Usually this is not a problem due to the work distribution among staff, nevertheless you have to program for it to avoid conflicting updates and damage to database integrity.
Assume you are a developer and developing a program in Visual Basic to update the name and address table of customers. There will be 100 staff member who can perform this application function. How can you be sure that while target staff A typing in the change, staff X is not changing the same row?
Here is what you do:     


1. Read the name and address table including the timestamp. You display the info to the user for update and save the timestamp.
2. Certain amount of time later, like 2 minutes, the user presses the submit button after changes were typed in.
3. You open a transaction with Begin Transaction
4. You read the timestamp of the name and address row
5. You compare the current timestamp to the saved timestamp.
6. If the timestamps are same, you update the row and commit the transaction
7. If timestamps are different, you roll back the transaction and notify the user about the fact that the data was changed by someone else. You can let the user decide what to do or follow the appropriate company business rule for data entry conflict resolution.

This is pretty common practice in multi user environment. The alternate would be to examine a datetime column, or the entire row which is more processing intensive.
The following example shows timestamp (rowversion in SQL Server 2008) in action:
-- SQL Server 2008 T-SQL Code
USE tempdb;  
-- SQL create table for Concurrency Checking demo

CREATE TABLE Celebrity (
  CelebrityID INT    IDENTITY    PRIMARY KEY,
  FirstName   VARCHAR(25),
  LastName    VARCHAR(30),
  VERSIONSTAMP  ROWVERSION)
GO
           
-- SQL insert - populate table
INSERT Celebrity (FirstName, LastName)
VALUES
('Jessica', 'Simpson'),
('Nick', 'Carter'),
('Stevie', 'Brock'),
('Christina', 'Aguilera'),
('Frank','Sinatra'),
('Doris','Day'),
('Elvis', 'Presley')
GO            

SELECT * FROM Celebrity
GO 
/* Results
CelebrityID FirstName   LastName    VERSIONSTAMP
1           Jessica     Simpson     0x0000000000000876
2           Nick        Carter      0x0000000000000877
3           Stevie      Brock       0x0000000000000878
4           Christina   Aguilera    0x0000000000000879
5           Frank       Sinatra     0x000000000000087A
6           Doris       Day         0x000000000000087B
7           Elvis       Presley     0x000000000000087C
*/
           
-- SQL update demo: SOMEONE UPDATED RECORD since it was read

CREATE TABLE #Semaphore (ID int identity(1,1) primary key,
                          StartVersion bigint,
                          PK int)
DECLARE @MyKey int

INSERT INTO #Semaphore (StartVersion, PK)
SELECT  VERSIONSTAMP, 1
FROM Celebrity WHERE CelebrityID=1

SELECT @MyKey = SCOPE_IDENTITY() 

-- SIMULATION: somebody else updating the same record

UPDATE Celebrity
SET    FirstName = 'Celine',
       LastName = 'Dion'
WHERE  CelebrityID = 

-- We are attempting to update.

BEGIN TRANSACTION

IF (SELECT StartVersion
    FROM   #Semaphore
    WHERE  ID = @MyKey) = (SELECT VERSIONSTAMP
                           FROM   Celebrity
                           WHERE  CelebrityID = 1)

  BEGIN
    UPDATE Celebrity
    SET    FirstName = 'Lindsay',
           LastName = 'Lohan'
    WHERE  CelebrityID =   

    COMMIT TRANSACTION
  END
ELSE 
     BEGIN
    ROLLBACK TRANSACTION
    PRINT 'ROLLBACK - UPDATE CONFLICT'
    RAISERROR ('Celebrity update conflict.',10,0)
  END

DELETE #Semaphore WHERE ID = @MyKey
SELECT * FROM   Celebrity

GO
/* CelebrityID    FirstName   LastName    VERSIONSTAMP
1           Celine      Dion        0x000000000000087D
2           Nick        Carter      0x0000000000000877
3           Stevie      Brock       0x0000000000000878
4           Christina   Aguilera    0x0000000000000879
5           Frank       Sinatra     0x000000000000087A
6           Doris       Day         0x000000000000087B
7           Elvis       Presley     0x000000000000087C
*/

-- SQL UPDATE with NO CONFLICT
DECLARE @MyKey int

INSERT INTO #Semaphore (StartVersion, PK)
SELECT  VERSIONSTAMP, 1
FROM Celebrity WHERE CelebrityID=1

SELECT @MyKey = SCOPE_IDENTITY() 

-- We are trying to update.
BEGIN TRANSACTION

IF (SELECT StartVersion
    FROM   #Semaphore
    WHERE  ID = @MyKey) = (SELECT VERSIONSTAMP
                           FROM   Celebrity
                           WHERE  CelebrityID = 1)
  BEGIN

    UPDATE Celebrity
    SET    FirstName = 'Lindsay',
           LastName = 'Lohan'
    WHERE  CelebrityID =  

    COMMIT TRANSACTION

 END
ELSE
  BEGIN
    ROLLBACK TRANSACTION
    PRINT 'ROLLBACK - UPDATE CONFLICT'
    RAISERROR ('Celebrity update conflict.',10,0)
  END

DELETE #Semaphore WHERE ID = @MyKey
SELECT * FROM   Celebrity
GO
/*
CelebrityID FirstName   LastName    VERSIONSTAMP
1           Lindsay     Lohan       0x000000000000087E
2           Nick        Carter      0x0000000000000877
3           Stevie      Brock       0x0000000000000878
4           Christina   Aguilera    0x0000000000000879
5           Frank       Sinatra     0x000000000000087A
6           Doris       Day         0x000000000000087B
7           Elvis       Presley     0x000000000000087C
*/

-- Cleanup
DROP TABLE #Semaphore
DROP TABLE Celebrity


No comments:

Post a Comment