|
1 |
| -EXEC sp_WhoIsActive @get_transaction_info=1, @get_task_info=2, @get_locks=1, @get_avg_time=1, @get_additional_info=1,@find_block_leaders=1, @get_outer_command =1 --,@get_full_inner_text=1 |
2 |
| - ,@get_plans=2 |
3 |
| - --,@filter_type = 'session' ,@filter = '325' |
4 |
| - --,@filter_type = 'login' ,@filter = 'Contso\RichMedia' |
| 1 | +EXEC sp_WhoIsActive @get_outer_command = 1, @get_avg_time=1 ,@get_task_info=2 |
| 2 | + --,@find_block_leaders=1 , @get_additional_info=1, |
| 3 | + --,@get_transaction_info=1 , @get_task_info=2, @get_additional_info=1, |
| 4 | + --,@get_full_inner_text=1 |
| 5 | + --,@get_locks=1 |
| 6 | + --,@get_plans=1 |
| 7 | + --,@sort_order = '[CPU] DESC' |
| 8 | + --,@filter_type = 'login' ,@filter = 'Lab\adwivedi' |
| 9 | + --,@filter_type = 'program' ,@filter = 'Test-Parallelism.py' |
| 10 | + --,@filter_type = 'database' ,@filter = 'facebook' |
5 | 11 | --,@sort_order = '[reads] desc'
|
6 | 12 |
|
7 |
| --- EXEC sp_WhoIsActive @help = 1; |
8 |
| - |
9 |
| ---EXEC sp_healthcheck @p_getExecutionPlan = 1; |
10 |
| --- EXEC [dbo].[sp_HealthCheck] '?' |
11 |
| - |
| 13 | +--kill 814 with statusonly |
| 14 | + |
| 15 | + |
12 | 16 | /*
|
13 |
| -$instance = 'DbServerName'; |
14 |
| -$excelPath = "C:\Temp\$instance.xlsx"; |
15 |
| -$sqlQuery = @" |
16 |
| -exec sp_whoIsActive @get_plans=1, @get_full_inner_text=1, |
17 |
| - @get_transaction_info=1, @get_task_info=2, |
18 |
| - @get_locks=1, @get_avg_time=1, @get_additional_info=1, |
19 |
| - @find_block_leaders=1 |
20 |
| -"@; |
21 |
| -
|
22 |
| -Invoke-Sqlcmd -ServerInstance $instance -Query $sqlQuery | Export-Excel $excelPath -Show; |
23 |
| -*/ |
| 17 | +EXEC sp_WhoIsActive @filter_type = 'login' ,@filter = 'Lab\adwivedi' |
| 18 | + ,@output_column_list = '[session_id][percent_complete][sql_text][login_name][wait_info][blocking_session_id][start_time]' |
24 | 19 |
|
25 |
| -/* |
| 20 | +EXEC sp_WhoIsActive @filter_type = 'session' ,@filter = '174' |
| 21 | + ,@output_column_list = '[session_id][percent_complete][sql_text][login_name][wait_info][blocking_session_id][start_time]' |
26 | 22 |
|
27 |
| -select r.*, th.threads, st.text |
28 |
| - ,SUBSTRING(st.text, (r.statement_start_offset/2)+1, |
29 |
| - ((CASE r.statement_end_offset |
30 |
| - WHEN -1 THEN DATALENGTH(st.text) |
31 |
| - ELSE r.statement_end_offset |
32 |
| - END - r.statement_start_offset)/2) + 1) AS statement_text |
33 |
| - -- ,qp.query_plan |
34 |
| - --,cast(tp.query_plan as xml) as statement_query_plan |
35 |
| -
|
36 |
| -from sys.dm_exec_requests as r |
37 |
| - outer apply sys.dm_exec_sql_text(r.sql_handle) as st |
38 |
| - OUTER APPLY (select count(*) as threads from sys.dm_os_tasks as t where t.session_id = r.session_id) as th |
39 |
| - --outer apply sys.dm_exec_query_plan(r.plan_handle) as qp |
40 |
| - --OUTER APPLY sys.dm_exec_text_query_plan(r.plan_handle, r.statement_start_offset, r.statement_end_offset) as tp |
41 |
| - --where r.session_id = 325 |
42 |
| -
|
43 |
| -select * from sys.dm_os_tasks as t |
44 |
| - --where t.session_id = 325 |
45 |
| -*/ |
| 23 | +-- EXEC sp_WhoIsActive @destination_table = 'DBA.dbo.WhoIsActive_ResultSets' |
46 | 24 |
|
47 |
| -/* |
48 |
| -https://www.brentozar.com/archive/2014/11/many-cpus-parallel-query-using-sql-server/ |
49 | 25 | */
|
50 | 26 |
|
51 |
| -/* |
52 |
| -SELECT top 10 [srvName] = @@servername, DENSE_RANK()OVER(ORDER BY collection_Time ASC) AS CollectionBatch, [collection_time], [TimeInMinutes], [dd hh:mm:ss.mss], [session_id], [sql_text], [sql_command], [login_name], |
53 |
| - [wait_info], [tasks], [tran_log_writes], [CPU], [tempdb_allocations], [tempdb_current], [blocking_session_id], |
54 |
| - [blocked_session_count], [reads], [writes], [context_switches], [physical_io], [physical_reads], [query_plan], [locks], |
55 |
| - [used_memory], [status], [tran_start_time], [open_tran_count], [percent_complete], [host_name], [database_name], [program_name], |
56 |
| - [additional_info], [start_time], [login_time], [request_id] |
57 |
| - --sql_handle = additional_info.value('(/additional_info/sql_handle)[1]','varchar(500)'), |
58 |
| - ,query_hash = query_plan.value('(/ShowPlanXML/BatchSequence/Batch/Statements/StmtSimple/@QueryHash)[1]', 'varchar(500)') |
59 |
| - ,query_plan_hash = query_plan.value('(/ShowPlanXML/BatchSequence/Batch/Statements/StmtSimple/@QueryPlanHash)[1]', 'varchar(500)') |
60 |
| -FROM [DBA].[dbo].WhoIsActive_ResultSets AS r |
61 |
| -WHERE (CASE WHEN REPLACE(REPLACE(TRY_CONVERT(varchar(max),r.sql_text),char(10),''),char(13),'') like '%INSERT INTO DBO.![DELTA!_Music!_%' ESCAPE '!' THEN 1 ELSE 0 END) = 1 |
62 |
| -AND (CASE WHEN REPLACE(REPLACE(TRY_CONVERT(varchar(max),r.sql_text),char(10),''),char(13),'') like '%SELECT N.![ReleaseID!], N.![AlbumID!], N.![MediaFormatAttributeID!], N.![ProductFormAttributeID!]%' ESCAPE '!' THEN 1 ELSE 0 END) = 1 |
63 |
| ---AND [database_name] LIKE 'RoviMusicShipping_UK_%' |
64 |
| -ORDER BY [TimeInMinutes] desc |
| 27 | +/* Begin Code to find Resource Pool Scheduler Affinity */ |
| 28 | +if OBJECT_ID('tempdb..#resource_pool') is not null drop table #resource_pool; |
| 29 | +if OBJECT_ID('tempdb..#temp') is not null drop table #temp; |
| 30 | + |
| 31 | +create table #resource_pool (rpoolname sysname, scheduler_id int, cpu_id int); |
| 32 | +create table #temp (name sysname, pool_id int, scheduler_mask bigint); |
| 33 | + |
| 34 | +insert into #temp |
| 35 | +select rp.name,rp.pool_id,pa.scheduler_mask |
| 36 | +from sys.dm_resource_governor_resource_pools rp |
| 37 | +join sys.resource_governor_resource_pool_affinity pa on rp.pool_id=pa.pool_id |
| 38 | +where rp.pool_id>2; |
| 39 | + |
| 40 | +while((select count(1) from #temp) > 0) |
| 41 | +Begin |
| 42 | +declare @intvalue numeric,@rpoolname sysname |
| 43 | +declare @vsresult varchar(64) |
| 44 | +declare @inti numeric |
| 45 | +DECLARE @counter int=0 |
| 46 | +select @inti = 64, @vsresult = '' |
| 47 | +select top 1 @intvalue = scheduler_mask,@rpoolname = name from #temp |
| 48 | +while @inti>0 |
| 49 | + begin |
| 50 | + if(@intvalue %2 =1) |
| 51 | + BEGIN |
| 52 | + insert into #resource_pool(rpoolname,scheduler_id) values(@rpoolname,@counter) |
| 53 | + END |
| 54 | + select @intvalue = convert(bigint, (@intvalue / 2)), @inti=@inti-1 |
| 55 | + set @counter = @counter+1 |
| 56 | + end |
| 57 | + delete from #temp where name= @rpoolname |
| 58 | +End |
| 59 | + |
| 60 | + |
| 61 | +update rpl |
| 62 | +set rpl.cpu_id = dos.cpu_id |
| 63 | +from sys.dm_os_schedulers dos inner join #resource_pool rpl |
| 64 | +on dos.scheduler_id=rpl.scheduler_id |
| 65 | + |
| 66 | +insert into #resource_pool |
| 67 | +select 'REST' as rpoolname, dos.scheduler_id,dos.cpu_id from sys.dm_os_schedulers dos |
| 68 | +left join #resource_pool rpl on dos.scheduler_id = rpl.scheduler_id |
| 69 | +where rpl.scheduler_id is NULL and dos.status = 'VISIBLE ONLINE'; |
| 70 | + |
| 71 | +/* End Code to find Resource Pool Scheduler Affinity */ |
| 72 | + |
| 73 | +declare @object_name varchar(255); |
| 74 | +set @object_name = (case when @@SERVICENAME = 'MSSQLSERVER' then 'SQLServer' else 'MSSQL$'+@@SERVICENAME end); |
| 75 | +SELECT /* counter that require Fraction & Base */ |
| 76 | + 'Resource Pool CPU %' as RunningQuery, |
| 77 | + rtrim(fr.instance_name) as [Pool], |
| 78 | + [% CPU] = convert(numeric(20,1),case when bs.cntr_value <> 0 then (100*((fr.cntr_value*1.0)/bs.cntr_value)) else fr.cntr_value end), |
| 79 | + [% Assigned Schedulers] = convert(numeric(20,1),((rp.Scheduler_Count*1.0)/(select count(1) as cpu_counts from sys.dm_os_schedulers as dos where dos.status = 'VISIBLE ONLINE'))*100), |
| 80 | + [Assigned Schedulers] = rp.Scheduler_Count |
| 81 | +FROM sys.dm_os_performance_counters as fr |
| 82 | +OUTER APPLY |
| 83 | + ( SELECT * FROM sys.dm_os_performance_counters as bs |
| 84 | + WHERE bs.cntr_type = 1073939712 /* PERF_LARGE_RAW_BASE */ |
| 85 | + AND bs.[object_name] = fr.[object_name] |
| 86 | + AND ( REPLACE(LOWER(RTRIM(bs.counter_name)),' base','') = REPLACE(LOWER(RTRIM(fr.counter_name)),' ratio','') |
| 87 | + OR |
| 88 | + REPLACE(LOWER(RTRIM(bs.counter_name)),' base','') = LOWER(RTRIM(fr.counter_name)) |
| 89 | + ) |
| 90 | + AND bs.instance_name = fr.instance_name |
| 91 | + ) as bs |
| 92 | +OUTER APPLY ( SELECT COUNT(*) as Scheduler_Count FROM #resource_pool AS rp WHERE rp.rpoolname = rtrim(fr.instance_name) ) as rp |
| 93 | +WHERE fr.cntr_type = 537003264 /* PERF_LARGE_RAW_FRACTION */ |
| 94 | + and fr.cntr_value > 0.0 |
| 95 | + and |
| 96 | + ( |
| 97 | + ( fr.[object_name] like (@object_name+':Resource Pool Stats%') and fr.counter_name like 'CPU usage %' ) |
| 98 | + ) |
| 99 | +ORDER BY [% CPU] desc; |
| 100 | +go |
| 101 | + |
| 102 | + |
| 103 | +DECLARE @pool_name sysname --= 'REST'; |
| 104 | +;WITH T_Requests AS |
| 105 | +( |
| 106 | + SELECT [Pool], s.program_name, r.session_id, r.request_id |
| 107 | + FROM sys.dm_exec_requests r |
| 108 | + JOIN sys.dm_exec_sessions s ON s.session_id = r.session_id |
| 109 | + OUTER APPLY |
| 110 | + ( select rgrp.name as [Pool] |
| 111 | + from sys.resource_governor_workload_groups rgwg |
| 112 | + join sys.resource_governor_resource_pools rgrp ON rgwg.pool_id = rgrp.pool_id |
| 113 | + where rgwg.group_id = s.group_id |
| 114 | + ) rp |
| 115 | + WHERE s.is_user_process = 1 |
| 116 | + AND login_name NOT LIKE '%sqlexec%' |
| 117 | + AND (@pool_name is null or [Pool] = @pool_name ) |
| 118 | +) |
| 119 | +,T_Programs_Tasks_Total AS |
| 120 | +( |
| 121 | + SELECT [Pool], r.program_name, |
| 122 | + [active_request_counts] = COUNT(*), |
| 123 | + [num_tasks] = SUM(t.tasks) |
| 124 | + FROM T_Requests as r |
| 125 | + OUTER APPLY ( select count(*) AS tasks, count(distinct t.scheduler_id) as schedulers |
| 126 | + from sys.dm_os_tasks t where r.session_id = t.session_id and r.request_id = t.request_id |
| 127 | + ) t |
| 128 | + GROUP BY [Pool], r.program_name |
| 129 | +) |
| 130 | +,T_Programs_Schedulers AS |
| 131 | +( |
| 132 | + SELECT [Pool], r.program_name, [num_schedulers] = COUNT(distinct t.scheduler_id) |
| 133 | + FROM T_Requests as r |
| 134 | + JOIN sys.dm_os_tasks t |
| 135 | + ON t.session_id = r.session_id AND t.request_id = r.request_id |
| 136 | + GROUP BY [Pool], program_name |
| 137 | +) |
| 138 | +SELECT RunningQuery = (COALESCE(@pool_name,'ALL')+'-POOL/')+'Active Requests/program', |
| 139 | + ptt.[Pool], |
| 140 | + ptt.program_name, ptt.active_request_counts, ptt.num_tasks, ps.num_schedulers, |
| 141 | + [scheduler_percent] = case when @pool_name is not null then Floor(ps.num_schedulers * 100.0 / rp.Scheduler_Count) |
| 142 | + else Floor(ps.num_schedulers * 100.0 / (select count(*) from sys.dm_os_schedulers as os where os.status = 'VISIBLE ONLINE')) |
| 143 | + end |
| 144 | +FROM T_Programs_Tasks_Total as ptt |
| 145 | +JOIN T_Programs_Schedulers as ps |
| 146 | + ON ps.program_name = ptt.program_name |
| 147 | +OUTER APPLY ( SELECT COUNT(*) as Scheduler_Count FROM #resource_pool AS rp WHERE rp.rpoolname = ptt.[Pool] ) as rp |
| 148 | +ORDER BY [scheduler_percent] desc, active_request_counts desc, [num_tasks] desc; |
65 | 149 | GO
|
66 | 150 |
|
67 |
| -use DBA |
| 151 | +--OUTER APPLY ( SELECT * FROM #resource_pool AS rp WHERE rp.rpoolname = rtrim(fr.instance_name) ) as rp |
68 | 152 |
|
69 |
| -select r.collection_time, * from dba..WhoIsActive_ResultSets r |
70 |
| - where r.collection_time >= DATEADD(hour,-200,getdate()) |
71 |
| - and (CASE WHEN REPLACE(REPLACE(CONVERT(varchar(max),r.sql_text),char(10),''),char(13),'') like '%SELECT ![Program ID!], ![Keyword ID!], Weight, Delta%' ESCAPE '!' THEN 1 ELSE 0 END) = 1 |
72 |
| -AND (CASE WHEN REPLACE(REPLACE(CONVERT(varchar(max),r.sql_text),char(10),''),char(13),'') like '%JOIN Babel.dbo.ProviderMapping pm ON pm.ProviderValue = filter.id AND pm.ProviderID = 2 AND pm.ObjectTypeID = 2 AND pm.IsActive = 1%' ESCAPE '!' THEN 1 ELSE 0 END) = 1 |
73 |
| -ORDER BY [TimeInMinutes] desc |
| 153 | +/* |
| 154 | +DECLARE @pool_name sysname = 'REST'; |
| 155 | +SELECT [RunningQuery] = COALESCE(@pool_name+'-','ALL-')+'Pool/Schedulers/Program', |
| 156 | + des.program_name, |
| 157 | + [schedulers_used] = COUNT(DISTINCT der.scheduler_id), |
| 158 | + [schedulers_used_percent] = FLOOR(COUNT(DISTINCT der.scheduler_id)*100.0/(SELECT COUNT(1) FROM sys.dm_os_schedulers WHERE status = 'VISIBLE ONLINE')) |
| 159 | +FROM sys.dm_exec_sessions des |
| 160 | +INNER JOIN sys.dm_exec_requests der ON des.session_id = der.session_id |
| 161 | +INNER JOIN sys.resource_governor_workload_groups rgwg ON des.group_id = rgwg.group_id |
| 162 | +INNER JOIN sys.resource_governor_resource_pools rgrp ON rgwg.pool_id = rgrp.pool_id |
| 163 | +WHERE des.is_user_process = 1 |
| 164 | +AND des.login_name NOT LIKE '%sqlexec%' |
| 165 | +AND (@pool_name is null or rgrp.name = @pool_name ) |
| 166 | +GROUP BY des.program_name |
| 167 | +ORDER BY schedulers_used_percent DESC; |
74 | 168 | GO
|
75 | 169 | */
|
76 | 170 |
|
77 | 171 | /*
|
78 |
| -select DENSE_RANK()OVER(ORDER BY collection_Time ASC) AS CollectionBatch, [collection_time], |
79 |
| - COUNT(session_id) OVER(PARTITION BY collection_Time) AS Session_Counts, |
80 |
| - [TimeInMinutes], [dd hh:mm:ss.mss], [dd hh:mm:ss.mss (avg)], [session_id], [sql_text], [sql_command], [login_name], |
81 |
| - [wait_info], [tasks], [tran_log_writes], [CPU], [tempdb_allocations], [tempdb_current], [blocking_session_id], |
82 |
| - [blocked_session_count], [reads], [writes], [context_switches], [physical_io], [physical_reads], [query_plan], [locks], |
83 |
| - [used_memory], [status], [tran_start_time], [open_tran_count], [percent_complete], [host_name], [database_name], [program_name], |
84 |
| - [additional_info], [start_time], [login_time], [request_id] |
85 |
| -from dbo.WhoIsActive_ResultSets r |
86 |
| -where r.collection_time >= '2019-06-21 00:00:01.743' and r.collection_time <= '2019-06-22 00:00:01.743' |
87 |
| -order by collection_time asc |
88 |
| -
|
89 |
| -
|
| 172 | +SELECT [RunningQuery] = 'Active Request/login', |
| 173 | + s.login_name, |
| 174 | + [active_request_counts] = COUNT(*), |
| 175 | + [num_schedulers] = Count(distinct r.scheduler_id), |
| 176 | + [num_tasks] = SUM(t.tasks), |
| 177 | + [scheduler_percent] = Floor(Count(distinct r.scheduler_id) * 100.0 / (select count(*) from sys.dm_os_schedulers as os where os.status = 'VISIBLE ONLINE')) |
| 178 | +FROM sys.dm_exec_requests r |
| 179 | +JOIN sys.dm_exec_sessions s ON s.session_id = r.session_id |
| 180 | +OUTER APPLY (select count(*) AS tasks from sys.dm_os_tasks t where r.session_id = t.session_id and r.request_id = t.request_id) t |
| 181 | +WHERE s.is_user_process = 1 |
| 182 | + AND login_name NOT LIKE '%sqlexec%' |
| 183 | +GROUP BY s.login_name |
| 184 | +ORDER BY num_schedulers desc, [scheduler_percent] desc, active_request_counts desc ,[num_tasks] desc; |
90 | 185 | */
|
91 | 186 |
|
92 | 187 | /*
|
93 |
| -declare @p_DbName varchar(200) = 'Staging'; |
94 |
| -
|
95 |
| -;WITH t_results as |
96 |
| -( |
97 |
| - SELECT @p_DbName as dbName, * |
98 |
| - FROM [DBA]..[WhoIsActive_ResultSets] r |
99 |
| - WHERE r.database_name <> @p_DbName |
100 |
| - AND r.collection_time >= '2020-02-04 01:59:00.000' |
101 |
| - and r.collection_time <= '2020-02-04 04:46:13.417' |
102 |
| -) |
103 |
| ---SELECT * |
104 |
| -SELECT r.collection_time, r.session_id, r.sql_command, r.login_name, r.wait_info, r.blocked_session_count, r.reads, r.database_name, r.program_name, r.host_name |
105 |
| -from t_results as r |
106 |
| -WHERE r.locks.exist( '/Database[@name=sql:column("dbName")]') = 1; |
107 |
| -
|
| 188 | +select * |
| 189 | +from sys.dm_exec_sessions es |
| 190 | +join sys.dm_exec_requests er |
| 191 | +on er.session_id = es.session_id |
| 192 | +where login_name = '' |
| 193 | +
|
| 194 | +select rgwg.*, rgrp.* |
| 195 | +from sys.resource_governor_workload_groups rgwg |
| 196 | +join sys.resource_governor_resource_pools rgrp ON rgwg.pool_id = rgrp.pool_id |
108 | 197 | */
|
| 198 | + |
0 commit comments