Hi Friends,
We know that SQL Server READ UNCOMMITTED Isolation level allows dirty read. That is, neither does it ask for locks nor does it honor locks held by other transactions. This is true in case of reading and writing data. But the story is different if another transaction has issued a DDL statement. Let us see.
In a query window, execute the following code:
-- connection 1 USE ADVENTUREWORKS2008; BEGIN TRANSACTION; ALTER TABLE Person.Person ADD Address2 nvarchar(100); --ROLLBACK TRANSACTION; GO
In another query window, read from the table under READ UNCOMMITTED isolation level.
USE ADVENTUREWORKS2008; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; SELECT * FROM Person.Person WHERE LastName = 'BANSAL';
And you will observe that the above transaction will wait indefinitely even though it is running under READ UNCOMMITTED isolation level.
In a new query window, say connection 3, observe the locks.
SELECT request_session_id ,resource_type ,resource_subtype ,resource_description ,resource_associated_entity_id ,request_mode ,request_status FROM sys.dm_tran_locks
Following is what you will observe (your session ids might be different)
Apart from number of locks being held by session 57 (which has issued the DDL statement), it has been granted the Sch-M (Schema Modification lock). And session 56 (running under READ UNCOMMITTED) isolation level waits.
ROLLBACK both the transactions.
You can see that READ UNCOMMITTED does honor locks.