mirror of
https://github.com/ckaczor/azuredatastudio.git
synced 2026-01-19 09:35:36 -05:00
Fix error displayed when insights files can't be found and fix server-report insights in dev build (#18635)
* Fix error * fix queries
This commit is contained in:
103
extensions/server-report/sql/all_db_space_used.sql
Normal file
103
extensions/server-report/sql/all_db_space_used.sql
Normal file
@@ -0,0 +1,103 @@
|
||||
--Source: https://gallery.technet.microsoft.com/scriptcenter/All-Databases-Data-log-a36da95d
|
||||
-- Use for a demo/sample purpose only. This query is not built-in to any product.
|
||||
|
||||
------------------------------Data file size----------------------------
|
||||
declare @dbsize table
|
||||
(Dbname nvarchar(128),
|
||||
file_Size_MB decimal(20,2)default (0),
|
||||
Space_Used_MB decimal(20,2)default (0),
|
||||
Free_Space_MB decimal(20,2) default (0))
|
||||
insert into @dbsize
|
||||
(Dbname,file_Size_MB,Space_Used_MB,Free_Space_MB)
|
||||
exec sp_MSforeachdb
|
||||
'use [?];
|
||||
select DB_NAME() AS DbName,
|
||||
sum(size)/128.0 AS File_Size_MB,
|
||||
sum(CAST(FILEPROPERTY(name, ''SpaceUsed'') AS INT))/128.0 as Space_Used_MB,
|
||||
SUM( size)/128.0 - sum(CAST(FILEPROPERTY(name,''SpaceUsed'') AS INT))/128.0 AS Free_Space_MB
|
||||
from sys.database_files where type=0 group by type'
|
||||
-------------------log size--------------------------------------
|
||||
declare @logsize table
|
||||
(Dbname nvarchar(128),
|
||||
Log_File_Size_MB decimal(20,2)default (0),
|
||||
log_Space_Used_MB decimal(20,2)default (0),
|
||||
log_Free_Space_MB decimal(20,2)default (0))
|
||||
insert into @logsize
|
||||
(Dbname,Log_File_Size_MB,log_Space_Used_MB,log_Free_Space_MB)
|
||||
exec sp_MSforeachdb
|
||||
'use [?];
|
||||
select DB_NAME() AS DbName,
|
||||
sum(size)/128.0 AS Log_File_Size_MB,
|
||||
sum(CAST(FILEPROPERTY(name, ''SpaceUsed'') AS INT))/128.0 as log_Space_Used_MB,
|
||||
SUM( size)/128.0 - sum(CAST(FILEPROPERTY(name,''SpaceUsed'') AS INT))/128.0 AS log_Free_Space_MB
|
||||
from sys.database_files where type=1 group by type'
|
||||
--------------------------------database free size
|
||||
declare @dbfreesize table
|
||||
(name nvarchar(128),
|
||||
database_size varchar(50),
|
||||
Freespace varchar(50)default (0.00))
|
||||
insert into @dbfreesize
|
||||
(name,database_size,Freespace)
|
||||
exec sp_MSforeachdb
|
||||
'use [?];SELECT database_name = db_name()
|
||||
,database_size = ltrim(str((convert(DECIMAL(15, 2), dbsize) + convert(DECIMAL(15, 2), logsize)) * 8192 / 1048576, 15, 2) + ''MB'')
|
||||
,''unallocated space'' = ltrim(str((
|
||||
CASE
|
||||
WHEN dbsize >= reservedpages
|
||||
THEN (convert(DECIMAL(15, 2), dbsize) - convert(DECIMAL(15, 2), reservedpages)) * 8192 / 1048576
|
||||
ELSE 0
|
||||
END
|
||||
), 15, 2) + '' MB'')
|
||||
FROM (
|
||||
SELECT dbsize = sum(convert(BIGINT, CASE
|
||||
WHEN type = 0
|
||||
THEN size
|
||||
ELSE 0
|
||||
END))
|
||||
,logsize = sum(convert(BIGINT, CASE
|
||||
WHEN type <> 0
|
||||
THEN size
|
||||
ELSE 0
|
||||
END))
|
||||
FROM sys.database_files
|
||||
) AS files
|
||||
,(
|
||||
SELECT reservedpages = sum(a.total_pages)
|
||||
,usedpages = sum(a.used_pages)
|
||||
,pages = sum(CASE
|
||||
WHEN it.internal_type IN (
|
||||
202
|
||||
,204
|
||||
,211
|
||||
,212
|
||||
,213
|
||||
,214
|
||||
,215
|
||||
,216
|
||||
)
|
||||
THEN 0
|
||||
WHEN a.type <> 1
|
||||
THEN a.used_pages
|
||||
WHEN p.index_id < 2
|
||||
THEN a.data_pages
|
||||
ELSE 0
|
||||
END)
|
||||
FROM sys.partitions p
|
||||
INNER JOIN sys.allocation_units a
|
||||
ON p.partition_id = a.container_id
|
||||
LEFT JOIN sys.internal_tables it
|
||||
ON p.object_id = it.object_id
|
||||
) AS partitions'
|
||||
-----------------------------------
|
||||
select TOP 10
|
||||
d.Dbname,
|
||||
--(file_size_mb + log_file_size_mb) as DBsize,
|
||||
--d.file_Size_MB,
|
||||
d.Space_Used_MB,
|
||||
--d.Free_Space_MB,
|
||||
--l.Log_File_Size_MB,
|
||||
l.log_Space_Used_MB--,
|
||||
--l.log_Free_Space_MB,
|
||||
--fs.Freespace as DB_Freespace
|
||||
from @dbsize d join @logsize l on d.Dbname=l.Dbname join @dbfreesize fs on d.Dbname=fs.name
|
||||
order by d.Space_Used_MB DESC
|
||||
19
extensions/server-report/sql/allocationContention.sql
Normal file
19
extensions/server-report/sql/allocationContention.sql
Normal file
@@ -0,0 +1,19 @@
|
||||
--SQL script to grab allocation contention from histogram
|
||||
Use tempdb
|
||||
DECLARE @target_data XML;
|
||||
SELECT @target_data = CAST(t.target_data AS XML)
|
||||
FROM sys.dm_xe_sessions AS s
|
||||
JOIN sys.dm_xe_session_targets AS t
|
||||
ON t.event_session_address = s.address
|
||||
WHERE s.name = N'PageContention' and t.target_name = N'histogram';
|
||||
|
||||
with wait_stats as
|
||||
(
|
||||
SELECT
|
||||
n.value('(value)[1]','bigint') AS id,
|
||||
n.value('(@count)[1]', 'bigint') AS [Count]
|
||||
FROM @target_data.nodes('//HistogramTarget/Slot') AS q(n)
|
||||
)
|
||||
|
||||
SELECT [dbo].[mapPageType](wait_stats.id), wait_stats.Count
|
||||
FROM wait_stats
|
||||
33
extensions/server-report/sql/backup_detail.sql
Normal file
33
extensions/server-report/sql/backup_detail.sql
Normal file
@@ -0,0 +1,33 @@
|
||||
declare @condition tinyint;
|
||||
SET @condition = 24;
|
||||
|
||||
select
|
||||
d.database_id as [Database ID],
|
||||
d.name as [Database],
|
||||
d.recovery_model_desc as [Recovery model],
|
||||
d.state_desc as [Database state],
|
||||
case
|
||||
when b.type = N'D' then N'Database'
|
||||
when b.type = N'I' then N'Differential Database'
|
||||
when b.type = N'L' then N'Log'
|
||||
when b.type = N'F' then N'File or Filegroup'
|
||||
when b.type = N'G' then N'Differental File'
|
||||
when b.type = N'P' then N'Partial'
|
||||
when b.type = N'Q' then N'Differential Partial'
|
||||
else NULL
|
||||
end
|
||||
as [Backup type],
|
||||
b.backup_start_date as [Backup start date],
|
||||
b.backup_finish_date as [Backup finish date],
|
||||
case
|
||||
when m.last_backup_time is null then 0 --N'No backup found'
|
||||
when datediff(hh, m.last_backup_time, getdate()) > @condition then 1 -- N'Older than 24hrs'
|
||||
else 2 --N'Within 24hrs'
|
||||
end as [Backup_Health]
|
||||
from sys.databases as d
|
||||
left join msdb..backupset as b on d.name = b.database_name
|
||||
left join (select bs.database_name, max(bs.backup_start_date) as last_backup_time
|
||||
from msdb..backupset as bs
|
||||
group by bs.database_name ) as m on d.name = m.database_name and b.backup_start_date = m.last_backup_time
|
||||
where b.backup_start_date is null or b.backup_start_date = m.last_backup_time
|
||||
order by d.database_id asc
|
||||
15
extensions/server-report/sql/backup_insight.sql
Normal file
15
extensions/server-report/sql/backup_insight.sql
Normal file
@@ -0,0 +1,15 @@
|
||||
declare @condition tinyint;
|
||||
SET @condition = 24;
|
||||
with
|
||||
backupInsight_cte (database_id, last_backup, health_check)
|
||||
as
|
||||
(
|
||||
select d.database_id, max(b.backup_start_date) AS last_backup, case when (datediff( hh , max(b.backup_start_date) , getdate()) < @condition) then 1 else 0 end as health_check
|
||||
from sys.databases as d left join msdb..backupset as b on d.name = b.database_name
|
||||
group by d.database_id
|
||||
)
|
||||
select
|
||||
sum(health_check) [Within 24hrs],
|
||||
sum(case when health_check = 0 AND last_backup IS NOT NULL then 1 else 0 end) [Older than 24hrs],
|
||||
sum(case when health_check = 0 AND last_backup IS NULL then 1 else 0 end) [No backup found]
|
||||
from backupInsight_cte
|
||||
12
extensions/server-report/sql/backup_size_trend.sql
Normal file
12
extensions/server-report/sql/backup_size_trend.sql
Normal file
@@ -0,0 +1,12 @@
|
||||
SELECT
|
||||
[database_name] AS "database",
|
||||
format(backup_start_date, 'yyyy-MM-dd') as date,
|
||||
--DATEPART(month,[backup_start_date]) AS "Month",
|
||||
AVG([backup_size]/1024/1024) AS "size MB"
|
||||
--AVG([compressed_backup_size]/1024/1024) AS "Compressed Backup Size MB",
|
||||
--AVG([backup_size]/[compressed_backup_size]) AS "Compression Ratio"
|
||||
from (SELECT TOP 100 *
|
||||
FROM msdb.dbo.backupset
|
||||
where [type] = 'D'
|
||||
ORDER BY backup_start_date DESC) AS recentbackups
|
||||
GROUP BY [database_name], format(backup_start_date, 'yyyy-MM-dd') --DATEPART(mm,[backup_start_date]);
|
||||
25
extensions/server-report/sql/cpumetric.sql
Normal file
25
extensions/server-report/sql/cpumetric.sql
Normal file
@@ -0,0 +1,25 @@
|
||||
-- source: https://sqlserverperformance.wordpress.com/2009/07/30/how-to-get-sql-server-cpu-utilization-from-a-query/
|
||||
-- Use for a demo/sample purpose only. This query is not built-in to any product.
|
||||
|
||||
DECLARE @ts_now bigint = (SELECT cpu_ticks/(cpu_ticks/ms_ticks)FROM sys.dm_os_sys_info);
|
||||
|
||||
SELECT Top(30) 'CPU%' as [label],
|
||||
DATEADD(ms, -1 * (@ts_now - [timestamp]), GETDATE()) AS [Event Time],
|
||||
SQLProcessUtilization AS [SQL Server Process CPU Utilization]
|
||||
-- SystemIdle AS [System Idle Process],
|
||||
-- 100 - SystemIdle - SQLProcessUtilization AS [Other Process CPU Utilization],
|
||||
FROM (
|
||||
SELECT record.value('(./Record/@id)[1]', 'int') AS record_id,
|
||||
record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int')
|
||||
AS [SystemIdle],
|
||||
record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]',
|
||||
'int')
|
||||
AS [SQLProcessUtilization], [timestamp]
|
||||
FROM (
|
||||
SELECT [timestamp], convert(xml, record) AS [record]
|
||||
FROM sys.dm_os_ring_buffers
|
||||
WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR'
|
||||
AND record LIKE '%<SystemHealth>%') AS x
|
||||
) AS y
|
||||
--ORDER BY record_id DESC;
|
||||
ORDER BY [Event Time] DESC;
|
||||
12
extensions/server-report/sql/db_size.sql
Normal file
12
extensions/server-report/sql/db_size.sql
Normal file
@@ -0,0 +1,12 @@
|
||||
with fs
|
||||
as
|
||||
(
|
||||
select database_id, type, size * 8.0 / 1024 size
|
||||
from sys.master_files
|
||||
)
|
||||
select
|
||||
name,
|
||||
(select sum(size) from fs where type = 0 and fs.database_id = db.database_id) DataFileSizeMB,
|
||||
(select sum(size) from fs where type = 1 and fs.database_id = db.database_id) LogFileSizeMB
|
||||
from sys.databases db
|
||||
where database_id > 4
|
||||
30
extensions/server-report/sql/memorybydb.sql
Normal file
30
extensions/server-report/sql/memorybydb.sql
Normal file
@@ -0,0 +1,30 @@
|
||||
-- source:https://www.mssqltips.com/sqlservertip/2393/determine-sql-server-memory-use-by-database-and-object/
|
||||
-- Use for a demo/sample purpose only. This query is not built-in to any product.
|
||||
|
||||
DECLARE @total_buffer INT;
|
||||
|
||||
SELECT @total_buffer = cntr_value
|
||||
FROM sys.dm_os_performance_counters
|
||||
WHERE RTRIM([object_name]) LIKE '%Buffer Manager'
|
||||
AND counter_name = 'Database Pages';
|
||||
|
||||
;WITH src AS
|
||||
(
|
||||
SELECT
|
||||
database_id, db_buffer_pages = COUNT_BIG(*)
|
||||
FROM sys.dm_os_buffer_descriptors
|
||||
--WHERE database_id BETWEEN 5 AND 32766
|
||||
GROUP BY database_id
|
||||
)
|
||||
SELECT TOP 10
|
||||
[db_name] = CASE [database_id] WHEN 32767
|
||||
THEN 'Resource DB'
|
||||
ELSE DB_NAME([database_id]) END,
|
||||
--db_buffer_pages,
|
||||
--db_buffer_MB = db_buffer_pages / 128,
|
||||
db_buffer_percent = CONVERT(DECIMAL(6,3),
|
||||
db_buffer_pages * 100.0 / @total_buffer)
|
||||
FROM src
|
||||
--ORDER BY db_buffer_MB DESC;
|
||||
order by db_buffer_percent DESC;
|
||||
|
||||
22
extensions/server-report/sql/metadataContention.sql
Normal file
22
extensions/server-report/sql/metadataContention.sql
Normal file
@@ -0,0 +1,22 @@
|
||||
--SQL script to grab metadata contention from histogram
|
||||
Use tempdb
|
||||
DECLARE @target_data XML;
|
||||
SELECT @target_data = CAST(t.target_data AS XML)
|
||||
FROM sys.dm_xe_sessions AS s
|
||||
JOIN sys.dm_xe_session_targets AS t
|
||||
ON t.event_session_address = s.address
|
||||
WHERE s.name = N'ObjectContention' and t.target_name = N'histogram';
|
||||
|
||||
with wait_stats as
|
||||
(
|
||||
SELECT
|
||||
n.value('(value)[1]','bigint') AS alloc_unit_id,
|
||||
n.value('(@count)[1]', 'bigint') AS [Count]
|
||||
FROM @target_data.nodes('//HistogramTarget/Slot') AS q(n)
|
||||
)
|
||||
|
||||
SELECT objects.id, SUM(objects.count) as [Count] FROM
|
||||
(SELECT [dbo].[isSystemTable](wait_stats.alloc_unit_id) AS id, wait_stats.Count AS [count]
|
||||
FROM wait_stats
|
||||
WHERE [dbo].[isSystemTable](wait_stats.alloc_unit_id) not in (0, 99)) AS objects
|
||||
GROUP BY objects.id
|
||||
80
extensions/server-report/sql/startEvent.sql
Normal file
80
extensions/server-report/sql/startEvent.sql
Normal file
@@ -0,0 +1,80 @@
|
||||
--Starts the XEvents sessions and creates the functions needed to find object id and give name to the page types
|
||||
BEGIN TRY
|
||||
IF NOT EXISTS (SELECT * FROM sys.dm_xe_sessions WHERE name = 'PageContention')
|
||||
BEGIN
|
||||
CREATE EVENT SESSION [PageContention] ON SERVER
|
||||
ADD EVENT latch_suspend_end(
|
||||
WHERE class = 28
|
||||
AND (page_type_id = 8
|
||||
OR page_type_id = 9
|
||||
OR page_type_id = 11))
|
||||
ADD TARGET package0.histogram(SET slots=16, filtering_event_name=N'latch_suspend_end', source=N'page_type_id', source_type=(0))
|
||||
ALTER EVENT SESSION [PageContention] ON SERVER
|
||||
STATE = START
|
||||
END
|
||||
IF NOT EXISTS (SELECT * FROM sys.dm_xe_sessions WHERE name = 'ObjectContention')
|
||||
BEGIN
|
||||
CREATE EVENT SESSION [ObjectContention] ON SERVER
|
||||
ADD EVENT latch_suspend_end(
|
||||
WHERE class = 28
|
||||
AND database_id = 2)
|
||||
ADD TARGET package0.histogram(SET slots=256, filtering_event_name=N'latch_suspend_end', source=N'page_alloc_unit_id', source_type=(0))
|
||||
ALTER EVENT SESSION [ObjectContention] ON SERVER
|
||||
STATE = START
|
||||
END
|
||||
SELECT 0 AS RESULTCODE
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
PRINT 'XEvent fields not supported'
|
||||
SELECT 1 AS RESULTCODE
|
||||
END CATCH
|
||||
GO
|
||||
|
||||
IF OBJECT_ID(N'[dbo].[isSystemTable]', N'FN') IS NOT NULL
|
||||
DROP FUNCTION [dbo].[isSystemTable]
|
||||
GO
|
||||
|
||||
CREATE FUNCTION [dbo].[isSystemTable] (@alloc bigint)
|
||||
RETURNS bigint
|
||||
|
||||
AS BEGIN
|
||||
|
||||
DECLARE @index BIGINT;
|
||||
DECLARE @objId BIGINT;
|
||||
|
||||
SELECT @index =
|
||||
CONVERT (BIGINT,
|
||||
CONVERT (FLOAT, @alloc)
|
||||
* (1 / POWER (2.0, 48))
|
||||
);
|
||||
SELECT @objId =
|
||||
CONVERT (BIGINT,
|
||||
CONVERT (FLOAT, @alloc - (@index * CONVERT (BIGINT, POWER (2.0, 48))))
|
||||
* (1 / POWER (2.0, 16))
|
||||
);
|
||||
|
||||
IF (@objId > 0 AND @objId <= 100 AND @index <= 255)
|
||||
return @objId
|
||||
|
||||
return 0
|
||||
|
||||
END
|
||||
GO
|
||||
|
||||
IF OBJECT_ID(N'[dbo].[mapPageType]', N'FN') IS NOT NULL
|
||||
DROP FUNCTION [dbo].[mapPageType]
|
||||
GO
|
||||
|
||||
CREATE FUNCTION [dbo].[mapPageType] (@pageTypeId bigint)
|
||||
RETURNS varchar(20)
|
||||
|
||||
AS BEGIN
|
||||
IF @pageTypeId = 8
|
||||
return 'GAM_PAGE'
|
||||
ELSE IF @pageTypeId = 9
|
||||
return 'SGAM_PAGE'
|
||||
ELSE IF @pageTypeId = 11
|
||||
return 'PFS_PAGE'
|
||||
return ''
|
||||
END
|
||||
GO
|
||||
4
extensions/server-report/sql/stopEvent.sql
Normal file
4
extensions/server-report/sql/stopEvent.sql
Normal file
@@ -0,0 +1,4 @@
|
||||
--Stops the XEvent Sessions
|
||||
DROP EVENT SESSION [PageContention] ON SERVER
|
||||
DROP EVENT SESSION [ObjectContention] ON SERVER
|
||||
SELECT 0 AS RESULTCODE
|
||||
33
extensions/server-report/sql/typeofContentions.sql
Normal file
33
extensions/server-report/sql/typeofContentions.sql
Normal file
@@ -0,0 +1,33 @@
|
||||
--SQL script to grab all contention
|
||||
Use tempdb
|
||||
DECLARE @pc XML;
|
||||
DECLARE @obj XML;
|
||||
|
||||
SELECT @pc = CAST(t.target_data AS XML)
|
||||
FROM sys.dm_xe_sessions AS s
|
||||
JOIN sys.dm_xe_session_targets AS t
|
||||
ON t.event_session_address = s.address
|
||||
WHERE s.name = N'PageContention' and t.target_name = N'histogram';
|
||||
|
||||
SELECT @obj = CAST(t.target_data AS XML)
|
||||
FROM sys.dm_xe_sessions AS s
|
||||
JOIN sys.dm_xe_session_targets AS t
|
||||
ON t.event_session_address = s.address
|
||||
WHERE s.name = N'ObjectContention' and t.target_name = N'histogram';
|
||||
|
||||
SELECT 'Metadata Contention' AS wait_type, SUM(obj.count) AS [Count]
|
||||
FROM (
|
||||
SELECT
|
||||
n.value('(value)[1]','bigint') AS alloc_unit_id,
|
||||
n.value('(@count)[1]', 'bigint') AS [count]
|
||||
FROM @obj.nodes('//HistogramTarget/Slot') AS q(n)
|
||||
) obj
|
||||
WHERE [dbo].[isSystemTable](obj.alloc_unit_id) not in (0, 99)
|
||||
UNION
|
||||
SELECT 'Allocation Contention' AS wait_type, SUM(pc.count) AS [Count]
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
n.value('(@count)[1]', 'bigint') AS [count]
|
||||
FROM @pc.nodes('//HistogramTarget/Slot') AS q(n)
|
||||
) pc
|
||||
95
extensions/server-report/sql/wait_resources.sql
Normal file
95
extensions/server-report/sql/wait_resources.sql
Normal file
@@ -0,0 +1,95 @@
|
||||
WITH [Waits] AS
|
||||
(
|
||||
SELECT wait_type, resource_description, count(resource_description) AS RESOURCE_USE, COUNT(*) AS TOTAL FROM sys.dm_os_waiting_tasks
|
||||
WHERE [wait_type] NOT IN (
|
||||
-- These wait types are almost 100% never a problem and so they are
|
||||
-- filtered out to avoid them skewing the results. Click on the URL
|
||||
-- for more information.
|
||||
N'BROKER_EVENTHANDLER', -- https://www.sqlskills.com/help/waits/BROKER_EVENTHANDLER
|
||||
N'BROKER_RECEIVE_WAITFOR', -- https://www.sqlskills.com/help/waits/BROKER_RECEIVE_WAITFOR
|
||||
N'BROKER_TASK_STOP', -- https://www.sqlskills.com/help/waits/BROKER_TASK_STOP
|
||||
N'BROKER_TO_FLUSH', -- https://www.sqlskills.com/help/waits/BROKER_TO_FLUSH
|
||||
N'BROKER_TRANSMITTER', -- https://www.sqlskills.com/help/waits/BROKER_TRANSMITTER
|
||||
N'CHECKPOINT_QUEUE', -- https://www.sqlskills.com/help/waits/CHECKPOINT_QUEUE
|
||||
N'CHKPT', -- https://www.sqlskills.com/help/waits/CHKPT
|
||||
N'CLR_AUTO_EVENT', -- https://www.sqlskills.com/help/waits/CLR_AUTO_EVENT
|
||||
N'CLR_MANUAL_EVENT', -- https://www.sqlskills.com/help/waits/CLR_MANUAL_EVENT
|
||||
N'CLR_SEMAPHORE', -- https://www.sqlskills.com/help/waits/CLR_SEMAPHORE
|
||||
N'CXCONSUMER', -- https://www.sqlskills.com/help/waits/CXCONSUMER
|
||||
|
||||
-- Maybe comment these four out if you have mirroring issues
|
||||
N'DBMIRROR_DBM_EVENT', -- https://www.sqlskills.com/help/waits/DBMIRROR_DBM_EVENT
|
||||
N'DBMIRROR_EVENTS_QUEUE', -- https://www.sqlskills.com/help/waits/DBMIRROR_EVENTS_QUEUE
|
||||
N'DBMIRROR_WORKER_QUEUE', -- https://www.sqlskills.com/help/waits/DBMIRROR_WORKER_QUEUE
|
||||
N'DBMIRRORING_CMD', -- https://www.sqlskills.com/help/waits/DBMIRRORING_CMD
|
||||
|
||||
N'DIRTY_PAGE_POLL', -- https://www.sqlskills.com/help/waits/DIRTY_PAGE_POLL
|
||||
N'DISPATCHER_QUEUE_SEMAPHORE', -- https://www.sqlskills.com/help/waits/DISPATCHER_QUEUE_SEMAPHORE
|
||||
N'EXECSYNC', -- https://www.sqlskills.com/help/waits/EXECSYNC
|
||||
N'FSAGENT', -- https://www.sqlskills.com/help/waits/FSAGENT
|
||||
N'FT_IFTS_SCHEDULER_IDLE_WAIT', -- https://www.sqlskills.com/help/waits/FT_IFTS_SCHEDULER_IDLE_WAIT
|
||||
N'FT_IFTSHC_MUTEX', -- https://www.sqlskills.com/help/waits/FT_IFTSHC_MUTEX
|
||||
|
||||
-- Maybe comment these six out if you have AG issues
|
||||
N'HADR_CLUSAPI_CALL', -- https://www.sqlskills.com/help/waits/HADR_CLUSAPI_CALL
|
||||
N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', -- https://www.sqlskills.com/help/waits/HADR_FILESTREAM_IOMGR_IOCOMPLETION
|
||||
N'HADR_LOGCAPTURE_WAIT', -- https://www.sqlskills.com/help/waits/HADR_LOGCAPTURE_WAIT
|
||||
N'HADR_NOTIFICATION_DEQUEUE', -- https://www.sqlskills.com/help/waits/HADR_NOTIFICATION_DEQUEUE
|
||||
N'HADR_TIMER_TASK', -- https://www.sqlskills.com/help/waits/HADR_TIMER_TASK
|
||||
N'HADR_WORK_QUEUE', -- https://www.sqlskills.com/help/waits/HADR_WORK_QUEUE
|
||||
|
||||
N'KSOURCE_WAKEUP', -- https://www.sqlskills.com/help/waits/KSOURCE_WAKEUP
|
||||
N'LAZYWRITER_SLEEP', -- https://www.sqlskills.com/help/waits/LAZYWRITER_SLEEP
|
||||
N'LOGMGR_QUEUE', -- https://www.sqlskills.com/help/waits/LOGMGR_QUEUE
|
||||
N'MEMORY_ALLOCATION_EXT', -- https://www.sqlskills.com/help/waits/MEMORY_ALLOCATION_EXT
|
||||
N'ONDEMAND_TASK_QUEUE', -- https://www.sqlskills.com/help/waits/ONDEMAND_TASK_QUEUE
|
||||
N'PARALLEL_REDO_DRAIN_WORKER', -- https://www.sqlskills.com/help/waits/PARALLEL_REDO_DRAIN_WORKER
|
||||
N'PARALLEL_REDO_LOG_CACHE', -- https://www.sqlskills.com/help/waits/PARALLEL_REDO_LOG_CACHE
|
||||
N'PARALLEL_REDO_TRAN_LIST', -- https://www.sqlskills.com/help/waits/PARALLEL_REDO_TRAN_LIST
|
||||
N'PARALLEL_REDO_WORKER_SYNC', -- https://www.sqlskills.com/help/waits/PARALLEL_REDO_WORKER_SYNC
|
||||
N'PARALLEL_REDO_WORKER_WAIT_WORK', -- https://www.sqlskills.com/help/waits/PARALLEL_REDO_WORKER_WAIT_WORK
|
||||
N'PREEMPTIVE_OS_FLUSHFILEBUFFERS', -- https://www.sqlskills.com/help/waits/PREEMPTIVE_OS_FLUSHFILEBUFFERS
|
||||
N'PREEMPTIVE_XE_GETTARGETSTATE', -- https://www.sqlskills.com/help/waits/PREEMPTIVE_XE_GETTARGETSTATE
|
||||
N'PWAIT_ALL_COMPONENTS_INITIALIZED', -- https://www.sqlskills.com/help/waits/PWAIT_ALL_COMPONENTS_INITIALIZED
|
||||
N'PWAIT_DIRECTLOGCONSUMER_GETNEXT', -- https://www.sqlskills.com/help/waits/PWAIT_DIRECTLOGCONSUMER_GETNEXT
|
||||
N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', -- https://www.sqlskills.com/help/waits/QDS_PERSIST_TASK_MAIN_LOOP_SLEEP
|
||||
N'QDS_ASYNC_QUEUE', -- https://www.sqlskills.com/help/waits/QDS_ASYNC_QUEUE
|
||||
N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP',
|
||||
-- https://www.sqlskills.com/help/waits/QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP
|
||||
N'QDS_SHUTDOWN_QUEUE', -- https://www.sqlskills.com/help/waits/QDS_SHUTDOWN_QUEUE
|
||||
N'REDO_THREAD_PENDING_WORK', -- https://www.sqlskills.com/help/waits/REDO_THREAD_PENDING_WORK
|
||||
N'REQUEST_FOR_DEADLOCK_SEARCH', -- https://www.sqlskills.com/help/waits/REQUEST_FOR_DEADLOCK_SEARCH
|
||||
N'RESOURCE_QUEUE', -- https://www.sqlskills.com/help/waits/RESOURCE_QUEUE
|
||||
N'SERVER_IDLE_CHECK', -- https://www.sqlskills.com/help/waits/SERVER_IDLE_CHECK
|
||||
N'SLEEP_BPOOL_FLUSH', -- https://www.sqlskills.com/help/waits/SLEEP_BPOOL_FLUSH
|
||||
N'SLEEP_DBSTARTUP', -- https://www.sqlskills.com/help/waits/SLEEP_DBSTARTUP
|
||||
N'SLEEP_DCOMSTARTUP', -- https://www.sqlskills.com/help/waits/SLEEP_DCOMSTARTUP
|
||||
N'SLEEP_MASTERDBREADY', -- https://www.sqlskills.com/help/waits/SLEEP_MASTERDBREADY
|
||||
N'SLEEP_MASTERMDREADY', -- https://www.sqlskills.com/help/waits/SLEEP_MASTERMDREADY
|
||||
N'SLEEP_MASTERUPGRADED', -- https://www.sqlskills.com/help/waits/SLEEP_MASTERUPGRADED
|
||||
N'SLEEP_MSDBSTARTUP', -- https://www.sqlskills.com/help/waits/SLEEP_MSDBSTARTUP
|
||||
N'SLEEP_SYSTEMTASK', -- https://www.sqlskills.com/help/waits/SLEEP_SYSTEMTASK
|
||||
N'SLEEP_TASK', -- https://www.sqlskills.com/help/waits/SLEEP_TASK
|
||||
N'SLEEP_TEMPDBSTARTUP', -- https://www.sqlskills.com/help/waits/SLEEP_TEMPDBSTARTUP
|
||||
N'SNI_HTTP_ACCEPT', -- https://www.sqlskills.com/help/waits/SNI_HTTP_ACCEPT
|
||||
N'SOS_WORK_DISPATCHER', -- https://www.sqlskills.com/help/waits/SOS_WORK_DISPATCHER
|
||||
N'SP_SERVER_DIAGNOSTICS_SLEEP', -- https://www.sqlskills.com/help/waits/SP_SERVER_DIAGNOSTICS_SLEEP
|
||||
N'SQLTRACE_BUFFER_FLUSH', -- https://www.sqlskills.com/help/waits/SQLTRACE_BUFFER_FLUSH
|
||||
N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', -- https://www.sqlskills.com/help/waits/SQLTRACE_INCREMENTAL_FLUSH_SLEEP
|
||||
N'SQLTRACE_WAIT_ENTRIES', -- https://www.sqlskills.com/help/waits/SQLTRACE_WAIT_ENTRIES
|
||||
N'VDI_CLIENT_OTHER', -- https://www.sqlskills.com/help/waits/VDI_CLIENT_OTHER
|
||||
N'WAIT_FOR_RESULTS', -- https://www.sqlskills.com/help/waits/WAIT_FOR_RESULTS
|
||||
N'WAITFOR', -- https://www.sqlskills.com/help/waits/WAITFOR
|
||||
N'WAITFOR_TASKSHUTDOWN', -- https://www.sqlskills.com/help/waits/WAITFOR_TASKSHUTDOWN
|
||||
N'WAIT_XTP_RECOVERY', -- https://www.sqlskills.com/help/waits/WAIT_XTP_RECOVERY
|
||||
N'WAIT_XTP_HOST_WAIT', -- https://www.sqlskills.com/help/waits/WAIT_XTP_HOST_WAIT
|
||||
N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', -- https://www.sqlskills.com/help/waits/WAIT_XTP_OFFLINE_CKPT_NEW_LOG
|
||||
N'WAIT_XTP_CKPT_CLOSE', -- https://www.sqlskills.com/help/waits/WAIT_XTP_CKPT_CLOSE
|
||||
N'XE_DISPATCHER_JOIN', -- https://www.sqlskills.com/help/waits/XE_DISPATCHER_JOIN
|
||||
N'XE_DISPATCHER_WAIT', -- https://www.sqlskills.com/help/waits/XE_DISPATCHER_WAIT
|
||||
N'XE_TIMER_EVENT' -- https://www.sqlskills.com/help/waits/XE_TIMER_EVENT
|
||||
)
|
||||
GROUP BY sys.dm_os_waiting_tasks.resource_description, wait_type
|
||||
)
|
||||
|
||||
SELECT [TASKS].[wait_type] AS [WaitType], [TASKS].[resource_description] as [Resource], 100.0 * [TASKS].[TOTAL] / SUM ([TASKS].[TOTAL]) OVER () AS [Percentage] FROM Waits AS TASKS GROUP BY [TASKS].[wait_type], [TASKS].[resource_description], [TASKS].[TOTAL]
|
||||
77
extensions/server-report/sql/waits_detail_paul_randal.sql
Normal file
77
extensions/server-report/sql/waits_detail_paul_randal.sql
Normal file
@@ -0,0 +1,77 @@
|
||||
-- SOURCE: https://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/
|
||||
-- Use for a demo/sample purpose only. This query is not built-in to any product.
|
||||
|
||||
WITH [Waits] AS
|
||||
(SELECT
|
||||
[wait_type],
|
||||
[wait_time_ms] / 1000.0 AS [WaitS],
|
||||
([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS],
|
||||
[signal_wait_time_ms] / 1000.0 AS [SignalS],
|
||||
[waiting_tasks_count] AS [WaitCount],
|
||||
100.0 * [wait_time_ms] / SUM ([wait_time_ms]) OVER() AS [Percentage],
|
||||
ROW_NUMBER() OVER(ORDER BY [wait_time_ms] DESC) AS [RowNum]
|
||||
FROM sys.dm_os_wait_stats
|
||||
WHERE [wait_type] NOT IN (
|
||||
N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR',
|
||||
N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH',
|
||||
N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE',
|
||||
N'CHKPT', N'CLR_AUTO_EVENT',
|
||||
N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE',
|
||||
|
||||
-- Maybe uncomment these four if you have mirroring issues
|
||||
N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE',
|
||||
N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD',
|
||||
|
||||
N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE',
|
||||
N'EXECSYNC', N'FSAGENT',
|
||||
N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX',
|
||||
|
||||
-- Maybe uncomment these six if you have AG issues
|
||||
N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION',
|
||||
N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE',
|
||||
N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE',
|
||||
|
||||
N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP',
|
||||
N'LOGMGR_QUEUE', N'MEMORY_ALLOCATION_EXT',
|
||||
N'ONDEMAND_TASK_QUEUE',
|
||||
N'PREEMPTIVE_OS_FLUSHFILEBUFFERS',
|
||||
N'PREEMPTIVE_XE_GETTARGETSTATE',
|
||||
N'PWAIT_ALL_COMPONENTS_INITIALIZED',
|
||||
N'PWAIT_DIRECTLOGCONSUMER_GETNEXT',
|
||||
N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', N'QDS_ASYNC_QUEUE',
|
||||
N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP',
|
||||
N'QDS_SHUTDOWN_QUEUE', N'REDO_THREAD_PENDING_WORK',
|
||||
N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE',
|
||||
N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH',
|
||||
N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP',
|
||||
N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY',
|
||||
N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP',
|
||||
N'SLEEP_SYSTEMTASK', N'SLEEP_TASK',
|
||||
N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT',
|
||||
N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH',
|
||||
N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP',
|
||||
N'SQLTRACE_WAIT_ENTRIES', N'VDI_CLIENT_OTHER', N'WAIT_FOR_RESULTS',
|
||||
N'WAITFOR', N'WAITFOR_TASKSHUTDOWN',
|
||||
N'WAIT_XTP_RECOVERY',
|
||||
N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG',
|
||||
N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN',
|
||||
N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT')
|
||||
AND [waiting_tasks_count] > 0
|
||||
)
|
||||
SELECT
|
||||
MAX ([W1].[wait_type]) AS [WaitType],
|
||||
CAST (MAX ([W1].[WaitS]) AS DECIMAL (16,2)) AS [Wait_S],
|
||||
CAST (MAX ([W1].[ResourceS]) AS DECIMAL (16,2)) AS [Resource_S],
|
||||
CAST (MAX ([W1].[SignalS]) AS DECIMAL (16,2)) AS [Signal_S],
|
||||
MAX ([W1].[WaitCount]) AS [WaitCount],
|
||||
CAST (MAX ([W1].[Percentage]) AS DECIMAL (5,2)) AS [Percentage],
|
||||
CAST ((MAX ([W1].[WaitS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgWait_S],
|
||||
CAST ((MAX ([W1].[ResourceS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgRes_S],
|
||||
CAST ((MAX ([W1].[SignalS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgSig_S],
|
||||
CAST ('https://www.sqlskills.com/help/waits/' + MAX ([W1].[wait_type]) as XML) AS [Help/Info URL]
|
||||
FROM [Waits] AS [W1]
|
||||
INNER JOIN [Waits] AS [W2]
|
||||
ON [W2].[RowNum] <= [W1].[RowNum]
|
||||
GROUP BY [W1].[RowNum]
|
||||
HAVING SUM ([W2].[Percentage]) - MAX( [W1].[Percentage] ) < 95; -- percentage threshold
|
||||
GO
|
||||
77
extensions/server-report/sql/waits_paul_randal.sql
Normal file
77
extensions/server-report/sql/waits_paul_randal.sql
Normal file
@@ -0,0 +1,77 @@
|
||||
-- SOURCE: https://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/
|
||||
-- Use for a demo/sample purpose only. This query is not built-in to any product.
|
||||
|
||||
WITH [Waits] AS
|
||||
(SELECT
|
||||
[wait_type],
|
||||
[wait_time_ms] / 1000.0 AS [WaitS],
|
||||
([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS],
|
||||
[signal_wait_time_ms] / 1000.0 AS [SignalS],
|
||||
[waiting_tasks_count] AS [WaitCount],
|
||||
100.0 * [wait_time_ms] / SUM ([wait_time_ms]) OVER() AS [Percentage],
|
||||
ROW_NUMBER() OVER(ORDER BY [wait_time_ms] DESC) AS [RowNum]
|
||||
FROM sys.dm_os_wait_stats
|
||||
WHERE [wait_type] NOT IN (
|
||||
N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR',
|
||||
N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH',
|
||||
N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE',
|
||||
N'CHKPT', N'CLR_AUTO_EVENT',
|
||||
N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE',
|
||||
|
||||
-- Maybe uncomment these four if you have mirroring issues
|
||||
N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE',
|
||||
N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD',
|
||||
|
||||
N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE',
|
||||
N'EXECSYNC', N'FSAGENT',
|
||||
N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX',
|
||||
|
||||
-- Maybe uncomment these six if you have AG issues
|
||||
N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION',
|
||||
N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE',
|
||||
N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE',
|
||||
|
||||
N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP',
|
||||
N'LOGMGR_QUEUE', N'MEMORY_ALLOCATION_EXT',
|
||||
N'ONDEMAND_TASK_QUEUE',
|
||||
N'PREEMPTIVE_OS_FLUSHFILEBUFFERS',
|
||||
N'PREEMPTIVE_XE_GETTARGETSTATE',
|
||||
N'PWAIT_ALL_COMPONENTS_INITIALIZED',
|
||||
N'PWAIT_DIRECTLOGCONSUMER_GETNEXT',
|
||||
N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', N'QDS_ASYNC_QUEUE',
|
||||
N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP',
|
||||
N'QDS_SHUTDOWN_QUEUE', N'REDO_THREAD_PENDING_WORK',
|
||||
N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE',
|
||||
N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH',
|
||||
N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP',
|
||||
N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY',
|
||||
N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP',
|
||||
N'SLEEP_SYSTEMTASK', N'SLEEP_TASK',
|
||||
N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT',
|
||||
N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH',
|
||||
N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP',
|
||||
N'SQLTRACE_WAIT_ENTRIES', N'VDI_CLIENT_OTHER', N'WAIT_FOR_RESULTS',
|
||||
N'WAITFOR', N'WAITFOR_TASKSHUTDOWN',
|
||||
N'WAIT_XTP_RECOVERY',
|
||||
N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG',
|
||||
N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN',
|
||||
N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT')
|
||||
AND [waiting_tasks_count] > 0
|
||||
)
|
||||
SELECT
|
||||
MAX ([W1].[wait_type]) AS [WaitType],
|
||||
--CAST (MAX ([W1].[WaitS]) AS DECIMAL (16,2)) AS [Wait_S],
|
||||
--CAST (MAX ([W1].[ResourceS]) AS DECIMAL (16,2)) AS [Resource_S],
|
||||
--CAST (MAX ([W1].[SignalS]) AS DECIMAL (16,2)) AS [Signal_S],
|
||||
--MAX ([W1].[WaitCount]) AS [WaitCount]--,
|
||||
CAST (MAX ([W1].[Percentage]) AS DECIMAL (5,2)) AS [Percentage]
|
||||
--CAST ((MAX ([W1].[WaitS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgWait_S],
|
||||
--CAST ((MAX ([W1].[ResourceS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgRes_S],
|
||||
--CAST ((MAX ([W1].[SignalS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgSig_S],
|
||||
--CAST ('https://www.sqlskills.com/help/waits/' + MAX ([W1].[wait_type]) as XML) AS [Help/Info URL]
|
||||
FROM [Waits] AS [W1]
|
||||
INNER JOIN [Waits] AS [W2]
|
||||
ON [W2].[RowNum] <= [W1].[RowNum]
|
||||
GROUP BY [W1].[RowNum]
|
||||
HAVING SUM ([W2].[Percentage]) - MAX( [W1].[Percentage] ) < 95; -- percentage threshold
|
||||
GO
|
||||
Reference in New Issue
Block a user