sp_server_diagnostics.sql 7.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106
  1. /*
  2. T-SQL script to fetch sp_server_diagnostics information from the System Health Sessions .XEL files stored in the SQL Server instance LOG folder.
  3. Note: This works only for SQL Server 2012 instances.
  4. Author: Amit Banerjee
  5. Contact details:
  6. Blog: www.troubleshootingsql.com
  7. Twitter: http://twitter.com/banerjeeamit
  8. Email: [email protected]
  9. DISCLAIMER:
  10. This Sample Code is provided for the purpose of illustration only and is not intended to be used in a production environment. THIS SAMPLE CODE AND ANY RELATED 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. We grant You a nonexclusive, royalty-free right to use and modify the Sample Code and to reproduce and distribute the object code form of the Sample Code, provided that You agree: (i) to not use Our name, logo, or trademarks to market Your software product in which the Sample Code is embedded; (ii) to include a valid copyright notice on Your software product in which the Sample Code is embedded; and (iii) to indemnify, hold harmless, and defend Us and Our suppliers from and against any claims or lawsuits, including attorneys’ fees, that arise or result from the use or distribution of the Sample Code.
  11. */
  12. SET NOCOUNT ON
  13. IF (SUBSTRING(CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)),1,CHARINDEX('.',CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)))-1) >= 11)
  14. BEGIN
  15. DECLARE @UTDDateDiff int
  16. SET @UTDDateDiff = DATEDIFF(mi,GETUTCDATE(),GETDATE())
  17. -- Fetch information about the XEL file location
  18. DECLARE @filename varchar(8000) ;
  19. SELECT @filename = CAST(target_data as XML).value('(/EventFileTarget/File/@name)[1]', 'varchar(8000)')
  20. FROM sys.dm_xe_session_targets
  21. WHERE target_name = 'event_file' and event_session_address = (select address from sys.dm_xe_sessions where name = 'system_health');
  22. SET @filename = SUBSTRING(@filename,1,CHARINDEX('system_health',@filename,1)-1) + '*.xel';
  23. -- Read the XEL files to get the System Health Session Data
  24. SELECT object_name,CAST(event_data as XML) as XMLData
  25. INTO #tbl_sp_server_diagnostics
  26. FROM sys.fn_xe_file_target_read_file(@filename, null, null, null)
  27. WHERE object_name = 'sp_server_diagnostics_component_result'
  28. SELECT
  29. DATEADD(mi,@UTDDateDiff,XMLData.value('(/event/@timestamp)[1]','datetime')) as EventTime,
  30. XMLData.value('(/event/data/text)[1]','varchar(255)') as Component,
  31. XMLData.value('(/event/data/text)[2]','varchar(255)') as [State]
  32. FROM #tbl_sp_server_diagnostics
  33. --WHERE XMLData.value('(/event/data/text)[2]','varchar(255)') <> 'CLEAN'
  34. ORDER BY EventTime DESC
  35. SELECT
  36. DATEADD(mi,@UTDDateDiff,XMLData.value('(/event/@timestamp)[1]','datetime')) as [Event Time],
  37. XMLData.value('(/event/data/text)[1]','varchar(255)') as Component,
  38. XMLData.value('(/event/data/value/system/@latchWarnings)[1]','bigint') as [Latch Warnings],
  39. XMLData.value('(/event/data/value/system/@isAccessViolationOccurred)[1]','bigint') as [Access Violations],
  40. XMLData.value('(/event/data/value/system/@nonYieldingTasksReported)[1]','bigint') as [Non Yields Reported],
  41. XMLData.value('(/event/data/value/system/@pageFaults)[1]','bigint') as [Page Faults],
  42. XMLData.value('(/event/data/value/system/@systemCpuUtilization)[1]','int') as [System CPU Utilization %],
  43. XMLData.value('(/event/data/value/system/@sqlCpuUtilization)[1]','int') as [SQL CPU Utilization %],
  44. XMLData.value('(/event/data/value/system/@BadPagesDetected)[1]','bigint') as [Bad Pages Detected],
  45. XMLData.value('(/event/data/value/system/@BadPagesFixed)[1]','bigint') as [Bad Pages Fixed]
  46. FROM #tbl_sp_server_diagnostics
  47. WHERE XMLData.value('(/event/data/text)[1]','varchar(255)') = 'SYSTEM'
  48. ORDER BY [Event Time] DESC
  49. SELECT
  50. DATEADD(mi,@UTDDateDiff,XMLData.value('(/event/@timestamp)[1]','datetime')) as [Event Time],
  51. XMLData.value('(/event/data/text)[1]','varchar(255)') as Component,
  52. XMLData.value('(/event/data/value/queryProcessing/@maxWorkers)[1]','bigint') as [Max Workers],
  53. XMLData.value('(/event/data/value/queryProcessing/@workersCreated)[1]','bigint') as [Workers Created],
  54. XMLData.value('(/event/data/value/queryProcessing/@workersIdle)[1]','bigint') as [Idle Workers],
  55. XMLData.value('(/event/data/value/queryProcessing/@pendingTasks)[1]','bigint') as [Pending Tasks],
  56. XMLData.value('(/event/data/value/queryProcessing/@hasUnresolvableDeadlockOccurred)[1]','int') as [Unresolvable Deadlock],
  57. XMLData.value('(/event/data/value/queryProcessing/@hasDeadlockedSchedulersOccurred)[1]','int') as [Deadlocked Schedulers]
  58. FROM #tbl_sp_server_diagnostics
  59. WHERE XMLData.value('(/event/data/text)[1]','varchar(255)') = 'QUERY_PROCESSING'
  60. ORDER BY [Event Time] DESC
  61. SELECT
  62. DATEADD(mi,@UTDDateDiff,XMLData.value('(/event/@timestamp)[1]','datetime')) as [Event Time],
  63. XMLData.value('(/event/data/text)[1]','varchar(255)') as Component,
  64. XMLData.value('(/event/data/value/resource/@outOfMemoryExceptions)[1]','bigint') as [OOM Exceptions],
  65. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[1]','bigint')/(1024*1024*1024) as [Available Physical Memory (GB)],
  66. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[3]','bigint')/(1024*1024*1024) as [Available Paging File (GB)],
  67. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[5]','int') as [Percent of Committed Memory in WS],
  68. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[6]','bigint') as [Page Faults],
  69. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[12]','bigint')/1024 as [VM Committed (MB)],
  70. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[13]','bigint')/(1024*1024) as [Locked Pages Allocated (GB)],
  71. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[14]','bigint')/(1024*1024) as [Large Pages Allocated (GB)],
  72. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[17]','bigint')/(1024*1024) as [Target Committed (GB)],
  73. XMLData.value('(/event/data/value/resource/memoryReport/entry/@value)[18]','bigint')/(1024*1024) as [Current Committed (GB)]
  74. FROM #tbl_sp_server_diagnostics
  75. WHERE XMLData.value('(/event/data/text)[1]','varchar(255)') = 'RESOURCE'
  76. ORDER BY [Event Time] DESC
  77. SELECT
  78. DATEADD(mi,@UTDDateDiff,XMLData.value('(/event/@timestamp)[1]','datetime')) as [Event Time],
  79. XMLData.value('(/event/data/text)[1]','varchar(255)') as Component,
  80. XMLData.value('(/event/data/value/ioSubsystem/@ioLatchTimeouts)[1]','bigint') as [IO Latch Timeouts],
  81. XMLData.value('(/event/data/value/ioSubsystem/@totalLongIos)[1]','bigint') as [Total Long IOs],
  82. XMLData.value('(/event/data/value/ioSubsystem/longestPendingRequests/pendingRequest/@filePath)[1]','varchar(8000)') as [Longest Pending Request File],
  83. XMLData.value('(/event/data/value/ioSubsystem/longestPendingRequests/pendingRequest/@duration)[1]','bigint') as [Longest Pending IO Duration]
  84. FROM #tbl_sp_server_diagnostics
  85. WHERE XMLData.value('(/event/data/text)[1]','varchar(255)') = 'IO_SUBSYSTEM'
  86. ORDER BY [Event Time] DESC
  87. DROP TABLE #tbl_sp_server_diagnostics
  88. END
  89. SET NOCOUNT OFF