SQLOSDMV’s Continue


sys.dm_os_waiting_tasks


One can run lots of interesting queries using this view.  You can even use this view to perform deadlock detection that is not resolvable by deadlock monitor, DM. For example if you have tasks waiting on external resources such as extended stored procedures and blocking others from running. This type of deadlock DM can’t detect but you can!


 



  1. Q. How many tasks are currently waiting?

 


select


count(*)


from


sys.dm_os_waiting_tasks


 


This query will give you an idea of how many tasks are waiting in the system. You can use this information to understand blocking characteristics of your load


 



  1. Q. How many tasks that assigned to a worker (thread/fiber) are waiting?

 


select


      count(*)


from


      sys.dm_os_waiting_tasks


where


      wait_type <> ‘THREADPOOL’


 


This query shows how many threads are actively running in the system. Latter on I will show how to find out if number of threads can be increased


 



  1. What are the tasks waiting on?

 


select


      wait_type,


      count (*)


from


      sys.dm_os_waiting_tasks


group by


      wait_type


order by


      count (*) desc


 


One can use this query to investigate possible bottlenceks of an active load. This query groups tasks by wait type – it can’t be directly use to identify the actual bottlenecks on the system. The query gives you an idea about the wait characteristics of your load


 



  1. Q. Does my load have an active resource bottleneck?

You can answer this question by looking at the resource address that tasks are blocked on.  Keep in mind that not all wait types have resource associated with them.


 


select


      resource_address,


      count (*)


from


      sys.dm_os_waiting_tasks


WHERE


      resource_address <> 0


group by


      resource_address


order by


      count (*) desc


 



  1. Q: Is my system can be possibly bottlenecked on I/O?

You can answer this question by looking at the wait type of tasks waiting on specifically you are interested in IO waits


 


select


      *


from


      sys.dm_os_waiting_tasks


where


      wait_duration_ms > 20 AND


      wait_type LIKE ‘%PAGEIOLATCH%’


 


You might want to change 20ms base on your I/O subsystem


 



  1. Q: Does my load have long waiting chains?

 


This information is particular interesting to understand if a single tasks, for example one that generated long I/O, blocks others. If this happens you will have a way to improve your scalability by figuring how to remove or minimize chain length.


 


WITH TaskChain (


waiting_task_address,


blocking_task_address,


ChainId,


Level)


AS


(


— Anchor member definition: use self join so that we output


— Only tasks that blocking others and remove dupliates


 SELECT DISTINCT


      A.waiting_task_address,


      A.blocking_task_address,


      A.waiting_task_address As ChainId,


    0 AS Level


FROM


      sys.dm_os_waiting_tasks as A


JOIN


      sys.dm_os_waiting_tasks as B


ON


      A.waiting_task_address = B.blocking_task_address


WHERE


      A.blocking_task_address IS NULL


UNION ALL


— Recursive member definition: Get to the next level waiting


— tasks


SELECT


      A.waiting_task_address,


      A.blocking_task_address,


      B.ChainId,


      Level + 1


from


      sys.dm_os_waiting_tasks AS A


JOIN


      TaskChain AS B


ON


      B.waiting_task_address = A.blocking_task_address


)


select


      waiting_task_address,


      blocking_task_address,


      ChainId,


      Level 


from


      TaskChain


order by


      ChainId


 


If there are no chains, your load is not CPU bound and you see long waits on THREADPOOL, you might improve your throughput by increasing a number of threads in the system.


 


Keep in mind that you can extend this query to perform your own deadlock detection.


 


You can also find out more information about each individual wait_type here


http://msdn2.microsoft.com/en-us/library/ms179984.aspx

Comments (1)

  1. Slava, you provide great information not provided anywhere else, I love your blog, and I’m eager to see what else you want to share around dmv’s: especially the wait stuff.

    What I terribly miss in SQLserver is wait information accumulated per session, and the possibility of wait information being traced.  Like this view, it shows only present waiting sessions, but there is no history, you cannot distinguish the (waitable) resource consuming sessions from ‘well behaving’ ones. Unless you take very frequent samples which can be a costly thing to do on busy systems.

    When will SqlServer take that next step and collect that waitinfo per session or batch (sqlserver seems to collect other info per batch also..)?

    good luck!

    Mario