mirror of
https://github.com/ckaczor/azuredatastudio.git
synced 2026-01-23 01:25:38 -05:00
committed by
Karl Burtram
parent
0bd3e1b0e1
commit
209d7e48d8
19
samples/serverReports/src/sql/allocationContention.sql
Normal file
19
samples/serverReports/src/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
|
||||
22
samples/serverReports/src/sql/metadataContention.sql
Normal file
22
samples/serverReports/src/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
samples/serverReports/src/sql/startEvent.sql
Normal file
80
samples/serverReports/src/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
|
||||
use tempdb
|
||||
|
||||
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
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
PRINT 'XEvent fields not supported'
|
||||
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
|
||||
3
samples/serverReports/src/sql/stopEvent.sql
Normal file
3
samples/serverReports/src/sql/stopEvent.sql
Normal file
@@ -0,0 +1,3 @@
|
||||
--Stops the XEvent Sessions
|
||||
DROP EVENT SESSION [PageContention] ON SERVER
|
||||
DROP EVENT SESSION [ObjectContention] ON SERVER
|
||||
33
samples/serverReports/src/sql/typeofContentions.sql
Normal file
33
samples/serverReports/src/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
samples/serverReports/src/sql/wait_resources.sql
Normal file
95
samples/serverReports/src/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]
|
||||
Reference in New Issue
Block a user