Hi Friends,
It’s a well-known fact that READ UNCOMMITTED Isolation Level in SQL Server allows dirty reads. In other words, if a transaction is running under READ UNCOMMITTED Isolation Level, it does not honor any locks held by any other transaction. Did is say ‘any’? Well there is a small exception or twist to this.
Let’s take an example:
In connection 1, execute the following query:
-- connection 1 USE ADVENTUREWORKS2012; go BEGIN TRANSACTION; ALTER TABLE Person.Person ADD Address2 nvarchar(100); --ROLLBACK TRANSACTION; GO
In connection 2 (another query windows), execute the following query:
-- connection 2 USE ADVENTUREWORKS2012; go SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; SELECT * FROM Person.Person WHERE LastName = 'BANSAL';
This query will wait. Note that this workload is running under READ UNCOMMITTED Isolation Level and thus should pass through but is being made to wait and no dirty read is possible. Why?
Because the previous query/transaction is holding schema modification lock on the object and the current (waiting query) needs Schema Stability lock.
See it for yourself. Run the following query in a new query window:
SELECT request_session_id ,resource_type ,resource_subtype ,resource_description ,resource_associated_entity_id ,request_mode ,request_status FROM sys.dm_tran_locks WHERE request_session_id IN (53,54) --Substitute your own SPID's here for sessions 1&2 ORDER BY request_session_id;
And check the output.
So, it is not completely true that READ UNCOMMITTED Isolation Level does not honor locks. It does, and this is just one of those scenarios.
Do share the post if you liked it. Thanks!
As far as I have understood both read uncommitted and the NOLOCK hint work so that they don’t do shared locks on the data, thus ignoring exlusive locks on that, but otherwise the queries will behave normally.