Pages

Tuesday, 3 July 2012

SQL SERVER : The Scene Behind NOLOCK

I have heard many time people talking about the NOLOCK hint. Some of them says it improves the performance and some of them says it reduce the blocking and deadlock as it will not acquire any locks. Let us see what is happening when we use NOCLOCK table hint in queries.

Let us see a query with out NOLOCK table hint and analyse the lock acquired by that query.
SELECT *FROM Sales.SalesOrderHeader a CROSS JOIN Sales.SalesOrderHeader b

The lock acquired by this session can be easily found using the below query
SELECT ResourceName = CASE resource_type
            
WHEN 'database' THEN DB_NAME(resource_database_id)
            
WHEN 'object' THEN OBJECT_NAME(resource_associated_entity_id, resource_database_id)
            
ELSE ''
            
END,request_mode,
request_status, FROM sys.dm_tran_locksWHERE request_session_id = 53

While analyzing the result, we can see a shared lock on database level. That is nothing to do with the NOLOCK  hint. While opening a connection to the database, it will always take shared connection on database used by that connection to make sure that other sessions will not drop the database while in use.

Next we can see an Intent Shared(IS) lock on the table level.An intent lock indicates that SQL Server wants to acquire a shared (S) lock or exclusive (X) lock on some of the resources lower down in the hierarchy. For example, a shared intent lock placed at the table level means that a transaction intends on placing shared (S) locks on pages or rows within that table. Setting an intent lock at the table level prevents another transaction from subsequently acquiring an exclusive (X) lock on the table containing that page.This IS lock also make sure that this table will not be modified till the select statement complete the operation.Next you an see a shared lock on page. This is to make sure that the data in the page are not getting modified while reading the data.

Let us see how it will work along with an update statement.
BEGIN TRAN
UPDATE Sales.SalesOrderHeader SET status=5 WHERE SalesOrderID=43659

Now  run the select statement and lock analyzing script. We can see that the request for Share Lock on page  is in Wait status as it is conflicting with the Intent exclusive lock acquired by the update session on the page. This helps sql server to avoid the dirty read but it cause for blocking. You can see that the select statement is  blocked by the update statement.

Let us see the same with NOLOCK hint

SELECT *
FROM Sales.SalesOrderHeader a WITH (NOLOCK)
CROSS
JOIN Sales.SalesOrderHeader b WITH (NOLOCK)  

In this case we can see only shared schema lock on the table. It is not taking a shared lock on the page and this lead to a dirty read.The shared schema lock om table level is important to make to sure that the schema of the table is not getting changed while reading the data. Let us try this select statement after the update statement and still the select statement will run without blocking as it is not trying to acquire the shared lock on pages and it also cause for the dirty read.

The READ UNCOMMITTED isolation level also works in the same way. Instead of specifying the table hint for each table we can set the isolation level to READ UNCOMMITTED. Theoretically NOLOCK hint improve the performance slightly as it  need to acquires less lock compared with statement does not have a NOLOCK hint.Be careful with the usage of NOLOCK hint as it perform dirty read and may give undesired result.




If you liked this post, do like my page on FaceBook at http://www.facebook.com/practicalSqlDba








8 comments:

  1. Hi Nelson,
    Thanks for the article. I have been using the nolock hint for sometime. I wanted to use READ UNCOMMITTED isolation level and your article confirms this to be the same. Using it on an sp, do we need to reset the isolation level at the end of the sp?
    Also is there a function that we can use to check if the query returned a dirty read?

    Thanks,

    John

    ReplyDelete
    Replies
    1. Thank your for reading the article. It is a best practice to reset the isolation level at the end of procedure to avoid any surprises.I believe there is no function to check the dirty read,but the isolation level of the connection/session can be found in the DMV sys.dm_exec_sessions (transaction_isolation_level)

      Thanks
      Nelson

      Delete
  2. I like your simple, clear and concise style! I passed this on the our Developer group, for those who may be interested in this aspect of how SQL Server works.

    ReplyDelete
  3. Hi Nelson,
    Nice set of examples. It would be nice if you went one step further. Modify the the Select With (NoLock) by explictly begining a transaction.
    The run the select first, followed by the Update.
    Many people think the NoLock hint means the Select will not acquire locks and that is what reduces blocking. If you try my suggestion, I think you will see the Update query will be blocked by the Select.
    Ray.Herring--NoSpam--@Hotmail.com

    ReplyDelete
    Replies
    1. Thank you for reading the article. I have tried that while writing this article. What i did is, in one window I ran below query

      BEGIN TRAN
      SELECT *
      FROM Sales.SalesOrderHeader a WITH (NOLOCK)
      CROSS JOIN Sales.SalesOrderHeader b WITH (NOLOCK)

      Verified the locks , it acquired only a shared schema lock on the table.

      In another window I did an update on same table as below
      update Sales.SalesOrderHeader set DueDate='2008-04-12 00:00:00.100' where SalesOrderID= 67258

      it got executed successfully.

      Delete
  4. Nice, clear and to the point. READ UNCOMMITTED Isolation Level & NOLOCK hint though used for same purpose, NOLOCK do not need explicit TRANSACTIONS, where as to SET ISOLATION LEVELS you need to explicitly specify BEGIN TRAN.... END.

    ReplyDelete
    Replies
    1. Thank you for reading the article . No, To set the SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED , you do not have to explicitly start the transaction.
      In one session you can try
      BEGIN TRAN
      insert into NoLockSample values(1)

      In another session you can try
      SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED
      Go
      select * from NoLockSample

      and you will get the expected result.

      Delete