If a query is taking longer to run than normal, there’s a good chance it’s being blocked by something else. This is especially true when you’re doing something rediculously simple and SQL Server just sits there thinking. Symptoms of blocking problems include a trace of SQL:BatchCompleted and RPC:Completed with durations over 10 seconds comes back with results using less than a second of CPU time and very few reads and writes. Also, if you’re watching your wait stats, then you’ll start to see more waits that start with LCK_ than normal. Not the mention the overly obvious blocking found in your Running Processes
This query will show you the blocking currently occurring on your server.
SELECT tl.resource_type , database_name = DB_NAME(tl.resource_database_id) , assoc_entity_id = tl.resource_associated_entity_id , lock_req = tl.request_mode , waiter_sid = tl.request_session_id , wait_duration = wt.wait_duration_ms , wt.wait_type , waiter_batch = wait_st.text , waiter_stmt = substring(wait_st.text,er.statement_start_offset/2 + 1, abs(case when er.statement_end_offset = -1 then len(convert(nvarchar(max), wait_st.text)) * 2 else er.statement_end_offset end - er.statement_start_offset)/2 + 1) , waiter_host = es.host_name , waiter_user = es.login_name , blocker_sid = wt.blocking_session_id , blocker_stmt = block_st.text , blocker_host = block_es.host_name , blocker_user = block_es.login_name FROM sys.dm_tran_locks tl (nolock) INNER JOIN sys.dm_os_waiting_tasks wt (nolock) ON tl.lock_owner_address = wt.resource_address INNER JOIN sys.dm_os_tasks ot (nolock) ON tl.request_session_id = ot.session_id AND tl.request_request_id = ot.request_id AND tl.request_exec_context_id = ot.exec_context_id INNER JOIN sys.dm_exec_requests er (nolock) ON tl.request_session_id = er.session_id AND tl.request_request_id = er.request_id INNER JOIN sys.dm_exec_sessions es (nolock) ON tl.request_session_id = es.session_id LEFT JOIN sys.dm_exec_requests block_er (nolock) ON wt.blocking_session_id = block_er.session_id LEFT JOIN sys.dm_exec_sessions block_es (nolock) ON wt.blocking_session_id = block_es.session_id CROSS APPLY sys.dm_exec_sql_text(er.sql_handle) wait_st OUTER APPLY sys.dm_exec_sql_text(block_er.sql_handle) block_st
However, if you have time to watch your servers all the time and keep running that query then you’re overstaffed in a world that leans towards being understaffed. For way too many reasons to list here, throw the results of this into a table every minute. If someone says a query ran long and you see the server was waiting on locks, look here. If you want to be proactive and look for ways you can improve server performance, look here.
CREATE TABLE Blocking ( BlockingID BigInt Identity(1,1) NOT NULL , resource_type NVarChar(60) , database_name SysName , assoc_entity_id BigInt , lock_req NVarChar(60) , wait_spid Int , wait_duration_ms Int , wait_type NVarChar(60) , wait_batch NVarChar(max) , wait_stmt NVarChar(max) , wait_host SysName , wait_user SysName , block_spid Int , block_stmt NVarChar(max) , block_host SysName , block_user SysName , DateAdded datetime NOT NULL DEFAULT (GetDate()) ) GO CREATE UNIQUE CLUSTERED INDEX IX_Blocking_DateAdded_BlockingID_U_C ON Blocking ( DateAdded , BlockingID ) WITH (Fillfactor = 95) GO
So, now you know what your blocking problems are. So, how do you fix them? That’s a deeper dive than I’ll be doing now, but here’s they key words to look into:
- NOLOCK hint
- Query tuning
- Process timing
- Eliminate cursors
Every situation is going to be unique, and I can’t pretend like I can give you all the answers. Finding that there is an issue can be difficult enough, and those are the answers I can help with.
Related articles
- SQL Server Running Slow (simplesqlserver.com)
Filed under: Monitoring, SQL Server Tagged: Block, Blocking, dm_exec_sessions, dm_exec_sql_text, dm_os_tasks, dm_os_waiting_tasks, dm_tran_locks, Lock, monitoring, performance, Tuning, Wait Stats