Skip to content

Commit acbcdb7

Browse files
Add files via upload
1 parent 8196fdf commit acbcdb7

File tree

1 file changed

+244
-0
lines changed

1 file changed

+244
-0
lines changed

AzureSQLDB_Diagnostics.txt

+244
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,244 @@
1+
set nocount on
2+
--(0) - timestamp and metadata
3+
select sysdatetime()
4+
-- get Database name
5+
select db_name() as DatabaseName
6+
-- Get SLO Level
7+
select *
8+
from sys.database_service_objectives
9+
10+
11+
--(1)
12+
print '***When were Statistics last updated on all indexes? '
13+
select
14+
ObjectSchema = OBJECT_SCHEMA_NAME(s.object_id)
15+
,ObjectName = object_name(s.object_id)
16+
,StatsName = s.name
17+
,sp.last_updated
18+
,idx.rowcnt CurrentRowCnt
19+
,sp.rows RowCntWhenStatsTaken
20+
,sp.rows_sampled
21+
,sp.modification_counter
22+
from sys.stats s cross apply sys.dm_db_stats_properties(s.object_id,s.stats_id) sp
23+
join sys.objects o on s.object_id = o.object_id
24+
left join sys.sysindexes idx on idx.id = s.object_id and idx.indid in (0,1)
25+
where s.object_id>100 and o.schema_id!=4
26+
order by sp.last_updated asc
27+
28+
29+
--(2)
30+
print '***Get fragmentation info for all indexes above a certain size in the current database'
31+
-- Note: This could take some time on a very large database
32+
SELECT DB_NAME(database_id) AS [Database Name], OBJECT_NAME(ps.OBJECT_ID) AS [Object Name],
33+
i.name AS [Index Name], ps.index_id, ps.index_type_desc, ps.avg_fragmentation_in_percent,
34+
ps.fragment_count, ps.page_count, i.fill_factor, i.has_filter, i.filter_definition
35+
FROM sys.dm_db_index_physical_stats(DB_ID(),NULL, NULL, NULL ,'LIMITED') AS ps
36+
INNER JOIN sys.indexes AS i WITH (NOLOCK)
37+
ON ps.[object_id] = i.[object_id]
38+
AND ps.index_id = i.index_id
39+
WHERE database_id = DB_ID()
40+
AND page_count > 250
41+
ORDER BY avg_fragmentation_in_percent DESC OPTION (RECOMPILE);
42+
43+
--(3)
44+
print '***Index Read/Write stats (all tables in current DB) ordered by Reads'
45+
SELECT OBJECT_NAME(s.[object_id]) AS [ObjectName], i.name AS [IndexName], i.index_id,
46+
user_seeks + user_scans + user_lookups AS [Reads], s.user_updates AS [Writes],
47+
i.type_desc AS [IndexType], i.fill_factor AS [FillFactor], i.has_filter, i.filter_definition,
48+
s.last_user_scan, s.last_user_lookup, s.last_user_seek
49+
FROM sys.dm_db_index_usage_stats AS s WITH (NOLOCK)
50+
INNER JOIN sys.indexes AS i WITH (NOLOCK)
51+
ON s.[object_id] = i.[object_id]
52+
WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1
53+
AND i.index_id = s.index_id
54+
AND s.database_id = DB_ID()
55+
ORDER BY user_seeks + user_scans + user_lookups DESC OPTION (RECOMPILE); -- Order by reads
56+
57+
58+
--(4)
59+
print '***full rowset of sys.dm_db_file_space_usage'
60+
select * from sys.dm_db_file_space_usage
61+
go
62+
63+
print '***Table sizes'
64+
SELECT
65+
s.Name AS SchemaName,
66+
t.NAME AS TableName,
67+
p.rows AS RowCounts,
68+
SUM(a.total_pages) * 8 AS TotalSpaceKB,
69+
SUM(a.used_pages) * 8 AS UsedSpaceKB,
70+
(SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS UnusedSpaceKB
71+
FROM
72+
sys.tables t
73+
INNER JOIN
74+
sys.schemas s ON s.schema_id = t.schema_id
75+
INNER JOIN
76+
sys.indexes i ON t.OBJECT_ID = i.object_id
77+
INNER JOIN
78+
sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id
79+
INNER JOIN
80+
sys.allocation_units a ON p.partition_id = a.container_id
81+
WHERE
82+
t.NAME NOT LIKE 'dt%' -- filter out system tables for diagramming
83+
AND t.is_ms_shipped = 0
84+
AND i.OBJECT_ID > 255
85+
GROUP BY
86+
t.Name, s.Name, p.Rows
87+
ORDER BY
88+
s.Name, t.Name
89+
90+
go
91+
92+
sp_spaceused
93+
go
94+
95+
96+
-- (5)
97+
98+
99+
print '***missing indexes'
100+
101+
SELECT
102+
id.[object_id] AS [ObjectID]
103+
,id.[statement] AS [FullyQualifiedObjectName]
104+
,id.[equality_columns] AS [EqualityColumns]
105+
,id.[inequality_columns] AS [InEqualityColumns]
106+
,id.[included_columns] AS [IncludedColumns]
107+
,gs.[unique_compiles] AS [UniqueCompiles]
108+
,gs.[user_seeks] AS [UserSeeks]
109+
,gs.[user_scans] AS [UserScans]
110+
,gs.[last_user_seek] AS [LastUserSeekTime]
111+
,gs.[last_user_scan] AS [LastUserScanTime]
112+
,gs.[avg_total_user_cost] AS [AvgTotalUserCost]
113+
,gs.[avg_user_impact] AS [AvgUserImpact]
114+
,gs.[system_seeks] AS [SystemSeeks]
115+
,gs.[system_scans] AS [SystemScans]
116+
,gs.[last_system_seek] AS [LastSystemSeekTime]
117+
,gs.[last_system_scan] AS [LastSystemScanTime]
118+
,gs.[avg_total_system_cost] AS [AvgTotalSystemCost]
119+
,gs.[avg_system_impact] AS [AvgSystemImpact]
120+
,gs.[user_seeks] * gs.[avg_total_user_cost] * (gs.[avg_user_impact] * 0.01) AS [IndexAdvantage]
121+
,'CREATE INDEX [Missing_IXNC_' + OBJECT_NAME(id.[object_id]) + '_' + REPLACE(REPLACE(REPLACE(ISNULL(id.[equality_columns], ''), ', ', '_'), '[', ''), ']', '') + CASE
122+
WHEN id.[equality_columns] IS NOT NULL
123+
AND id.[inequality_columns] IS NOT NULL
124+
THEN '_'
125+
ELSE ''
126+
END + REPLACE(REPLACE(REPLACE(ISNULL(id.[inequality_columns], ''), ', ', '_'), '[', ''), ']', '') + '_' + LEFT(CAST(NEWID() AS [nvarchar](64)), 5) + ']' + ' ON ' + id.[statement] + ' (' + ISNULL(id.[equality_columns], '') + CASE
127+
WHEN id.[equality_columns] IS NOT NULL
128+
AND id.[inequality_columns] IS NOT NULL
129+
THEN ','
130+
ELSE ''
131+
END + ISNULL(id.[inequality_columns], '') + ')' + ISNULL(' INCLUDE (' + id.[included_columns] + ')', '') AS [ProposedIndex]
132+
,CAST(CURRENT_TIMESTAMP AS [smalldatetime]) AS [CollectionDate]
133+
FROM [sys].[dm_db_missing_index_group_stats] gs WITH (NOLOCK)
134+
INNER JOIN [sys].[dm_db_missing_index_groups] ig WITH (NOLOCK)
135+
ON gs.[group_handle] = ig.[index_group_handle]
136+
INNER JOIN [sys].[dm_db_missing_index_details] id WITH (NOLOCK)
137+
ON ig.[index_handle] = id.[index_handle]
138+
ORDER BY [IndexAdvantage] DESC
139+
OPTION (RECOMPILE); 
140+
141+
142+
-- (6)
143+
144+
print '***Get Average Waits for Database';
145+
WITH [Waits] AS
146+
    (SELECT
147+
        [wait_type],
148+
        [wait_time_ms] / 1000.0 AS [WaitS],
149+
        ([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS],
150+
        [signal_wait_time_ms] / 1000.0 AS [SignalS],
151+
        [waiting_tasks_count] AS [WaitCount],
152+
        100.0 * [wait_time_ms] / SUM ([wait_time_ms]) OVER() AS [Percentage],
153+
        ROW_NUMBER() OVER(ORDER BY [wait_time_ms] DESC) AS [RowNum]
154+
    FROM sys.dm_db_wait_stats
155+
    WHERE [wait_type] NOT IN (
156+
        N'BROKER_EVENTHANDLER',         N'BROKER_RECEIVE_WAITFOR',
157+
        N'BROKER_TASK_STOP',            N'BROKER_TO_FLUSH',
158+
        N'BROKER_TRANSMITTER',          N'CHECKPOINT_QUEUE',
159+
        N'CHKPT',                       N'CLR_AUTO_EVENT',
160+
        N'CLR_MANUAL_EVENT',            N'CLR_SEMAPHORE',
161+
        N'DBMIRROR_DBM_EVENT',          N'DBMIRROR_EVENTS_QUEUE',
162+
        N'DBMIRROR_WORKER_QUEUE',       N'DBMIRRORING_CMD',
163+
        N'DIRTY_PAGE_POLL',             N'DISPATCHER_QUEUE_SEMAPHORE',
164+
        N'EXECSYNC',                    N'FSAGENT',
165+
        N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX',
166+
        N'HADR_CLUSAPI_CALL',           N'HADR_FILESTREAM_IOMGR_IOCOMPLETION',
167+
        N'HADR_LOGCAPTURE_WAIT',        N'HADR_NOTIFICATION_DEQUEUE',
168+
        N'HADR_TIMER_TASK',             N'HADR_WORK_QUEUE',
169+
        N'KSOURCE_WAKEUP',              N'LAZYWRITER_SLEEP',
170+
        N'LOGMGR_QUEUE',                N'ONDEMAND_TASK_QUEUE',
171+
        N'PWAIT_ALL_COMPONENTS_INITIALIZED',
172+
        N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP',
173+
        N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP',
174+
        N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE',
175+
        N'SERVER_IDLE_CHECK',           N'SLEEP_BPOOL_FLUSH',
176+
        N'SLEEP_DBSTARTUP',             N'SLEEP_DCOMSTARTUP',
177+
        N'SLEEP_MASTERDBREADY',         N'SLEEP_MASTERMDREADY',
178+
        N'SLEEP_MASTERUPGRADED',        N'SLEEP_MSDBSTARTUP',
179+
        N'SLEEP_SYSTEMTASK',            N'SLEEP_TASK',
180+
        N'SLEEP_TEMPDBSTARTUP',         N'SNI_HTTP_ACCEPT',
181+
        N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH',
182+
        N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP',
183+
        N'SQLTRACE_WAIT_ENTRIES',       N'WAIT_FOR_RESULTS',
184+
        N'WAITFOR',                     N'WAITFOR_TASKSHUTDOWN',
185+
        N'WAIT_XTP_HOST_WAIT',          N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG',
186+
        N'WAIT_XTP_CKPT_CLOSE',         N'XE_DISPATCHER_JOIN',
187+
        N'XE_DISPATCHER_WAIT',          N'XE_TIMER_EVENT')
188+
    )
189+
SELECT
190+
    [W1].[wait_type] AS [WaitType],
191+
    CAST ([W1].[WaitS] AS DECIMAL (16, 2)) AS [Wait_S],
192+
    CAST ([W1].[ResourceS] AS DECIMAL (16, 2)) AS [Resource_S],
193+
    CAST ([W1].[SignalS] AS DECIMAL (16, 2)) AS [Signal_S],
194+
    [W1].[WaitCount] AS [WaitCount],
195+
    CAST ([W1].[Percentage] AS DECIMAL (5, 2)) AS [Percentage],
196+
    CAST (([W1].[WaitS] / [W1].[WaitCount]) AS DECIMAL (16, 4)) AS [AvgWait_S],
197+
    CAST (([W1].[ResourceS] / [W1].[WaitCount]) AS DECIMAL (16, 4)) AS [AvgRes_S],
198+
    CAST (([W1].[SignalS] / [W1].[WaitCount]) AS DECIMAL (16, 4)) AS [AvgSig_S]
199+
FROM [Waits] AS [W1]
200+
INNER JOIN [Waits] AS [W2]
201+
    ON [W2].[RowNum] <= [W1].[RowNum]
202+
GROUP BY [W1].[RowNum], [W1].[wait_type], [W1].[WaitS],
203+
    [W1].[ResourceS], [W1].[SignalS], [W1].[WaitCount], [W1].[Percentage]
204+
HAVING SUM ([W2].[Percentage]) - [W1].[Percentage] < 95; -- percentage threshold
205+
GO
206+
 
207+
208+
--(7) - Currently active queries
209+
print 'exec requests'
210+
select * from sys.dm_exec_requests
211+
212+
print 'exec sessions'
213+
select * from sys.dm_exec_sessions
214+
215+
--(8) - db stats
216+
print 'content of dm_db_resource_stats'
217+
select * from sys.dm_db_resource_stats
218+
219+
--(9)
220+
print 'current blocking and running batches'
221+
SELECT
222+
sql_text.[text],
223+
locks.[resource_type],
224+
locks.[resource_subtype],
225+
locks.[resource_description],
226+
locks.[resource_associated_entity_id],
227+
locks.[request_mode],
228+
locks.[request_status],
229+
ses.[login_name],
230+
ses.[original_login_name],
231+
ses.[login_time],
232+
ses.[host_name],
233+
ses.[program_name],
234+
ses.[last_request_start_time]
235+
FROM sys.dm_tran_locks locks
236+
JOIN sys.dm_exec_sessions ses
237+
ON locks.request_session_id = ses.session_id
238+
JOIN sys.sysprocesses pr
239+
ON ses.session_id = pr.spid
240+
CROSS APPLY sys.dm_exec_sql_text(pr.sql_handle) sql_text;
241+
242+
243+
--(0) - timestamp
244+
select sysdatetime()

0 commit comments

Comments
 (0)