I realized that I’d fixed an issue with my sys.dm_os_waiting_tasks script to correctly parse out the parallelism nodeId from the resource_description column (as newer versions include more info after the nodeId=X info) but I never blogged the update. Here it is for your use(and all other references have been updated to point to this post).
Enjoy!
(Note that ‘text’ on one line does not have delimiters because that messes up the code formatting plugin):
/*============================================================================
File: WaitingTasks.sql
Summary: Snapshot of waiting tasks
SQL Server Versions: 2005 onward
------------------------------------------------------------------------------
Written by Paul S. Randal, SQLskills.com
(c) 2019, SQLskills.com. All rights reserved.
For more scripts and sample code, check out
http://www.SQLskills.com
You may alter this code for your own *non-commercial* purposes. You may
republish altered code as long as you include this copyright and give due
credit, but you must obtain prior permission before blogging this code.
THIS CODE AND INFORMATION ARE PROVIDED "AS IS" WITHOUT WARRANTY OF
ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED
TO THE IMPLIED WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A
PARTICULAR PURPOSE.
============================================================================*/
SELECT
[owt].[session_id] AS [SPID],
[owt].[exec_context_id] AS [Thread],
[ot].[scheduler_id] AS [Scheduler],
[owt].[wait_duration_ms] AS [wait_ms],
[owt].[wait_type],
[owt].[blocking_session_id] AS [Blocking SPID],
[owt].[resource_description],
CASE [owt].[wait_type]
WHEN N'CXPACKET' THEN
SUBSTRING ( -- earlier versions don't have anything after the nodeID...
[owt].[resource_description],
CHARINDEX (N'nodeId=', [owt].[resource_description]) + 7,
CHARINDEX (N' tid=', [owt].[resource_description] + ' tid=') -
CHARINDEX (N'nodeId=', [owt].[resource_description]) - 7
)
ELSE NULL
END AS [Node ID],
[eqmg].[dop] AS [DOP],
[er].[database_id] AS [DBID],
CAST ('https://www.sqlskills.com/help/waits/' + [owt].[wait_type] as XML) AS [Help/Info URL],
[eqp].[query_plan],
[est].text
FROM sys.dm_os_waiting_tasks [owt]
INNER JOIN sys.dm_os_tasks [ot] ON
[owt].[waiting_task_address] = [ot].[task_address]
INNER JOIN sys.dm_exec_sessions [es] ON
[owt].[session_id] = [es].[session_id]
INNER JOIN sys.dm_exec_requests [er] ON
[es].[session_id] = [er].[session_id]
FULL JOIN sys.dm_exec_query_memory_grants [eqmg] ON
[owt].[session_id] = [eqmg].[session_id]
OUTER APPLY sys.dm_exec_sql_text ([er].[sql_handle]) [est]
OUTER APPLY sys.dm_exec_query_plan ([er].[plan_handle]) [eqp]
WHERE
[es].[is_user_process] = 1
ORDER BY
[owt].[session_id],
[owt].[exec_context_id];
GO
4 thoughts on “Updated sys.dm_os_waiting_tasks script to correctly parse nodeId”
Very cool script, found my lack of memory issue. PC has 16 GB of RAM
An alter index , create index , even a DBCC CHECKDB would run for 2 minutes or 5 seconds then Disk I/O slowed right down to ZERO.