forked from microsoft/tigertoolbox
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathsetup.sql
3140 lines (2635 loc) · 117 KB
/
setup.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
--
-- © 2012 Microsoft. All Rights Reserved.
--
-- This script installs the stored procedures and functions invoked when a user opens the
-- Performance Dashboard reports. This script must be run against each SQL Server instance which
-- you plan to monitor via the reports.
--
-- Script must not be run in a transaction
SET IMPLICIT_TRANSACTIONS OFF
IF @@TRANCOUNT > 0 ROLLBACK TRAN
GO
-- Options that are saved with object definition
SET QUOTED_IDENTIFIER ON -- Required to call methods on XML type
SET ANSI_NULLS ON -- All queries use IS NULL check
go
use msdb
go
declare @Version nvarchar(100)
declare @MajorVer tinyint
declare @dec1 int
select @Version = convert(nvarchar(100), serverproperty('ProductVersion'))
select @dec1 = charindex('.', @Version)
select @MajorVer = convert(tinyint, substring(@Version, 1, @dec1 - 1))
if not (@MajorVer >= 10)
begin
RAISERROR('SETUP FAILED: This server does not meet the requirements (SQL 2008 or later) for running the Performance Dashboard Reports. This script will terminate and the required procedures will not be installed.', 18, 1)
end
GO
-- Prevent installs against SQL Azure (cross DB query limitation and DMV scoping)
if SERVERPROPERTY('Edition') = N'SQL Azure'
begin
RAISERROR('SETUP FAILED: SQL Azure is currently not supported by the Performance Dashboard Reports.', 18, 1);
-- On SQL Azure we can't raise a high enough severity error to abort execution of the script, so this will
-- unfortunately continue on past this point
end
go
if not exists (select * from sys.schemas where name = 'MS_PerfDashboard')
exec('create schema MS_PerfDashboard')
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.tblConfigValues'), 'IsUserTable') = 1
drop table MS_PerfDashboard.tblConfigValues
go
create table MS_PerfDashboard.tblConfigValues
(
Attribute varchar(60) not null PRIMARY KEY,
AttribValue sql_variant null
)
go
set nocount on;
go
-- NOTE: ReportVersion attribute must be synchronized with .RDL version
insert into MS_PerfDashboard.tblConfigValues (Attribute, AttribValue) values ('ReportVersion', '2012-01-31');
insert into MS_PerfDashboard.tblConfigValues (Attribute, AttribValue) values ('InstalledDate', GETDATE());
insert into MS_PerfDashboard.tblConfigValues (Attribute, AttribValue) values ('InstalledBy', SUSER_SNAME());
go
if object_id('MS_PerfDashboard.usp_CheckDependencies', 'P') is not null
drop procedure MS_PerfDashboard.usp_CheckDependencies
go
create procedure MS_PerfDashboard.usp_CheckDependencies
as
begin
declare @Version nvarchar(100)
declare @MajorVer tinyint, @MinorVer tinyint, @BuildNum smallint
declare @dec1 int, @dec2 int, @dec3 int
select @Version = convert(nvarchar(100), serverproperty('ProductVersion'))
select @dec1 = charindex('.', @Version)
select @MajorVer = convert(tinyint, substring(@Version, 1, @dec1 - 1));
select @MajorVer as major_version,
NULL as minor_version,
NULL as build_number,
convert(nvarchar(128), SERVERPROPERTY('MachineName')) +
CASE WHEN convert(nvarchar(128), SERVERPROPERTY('InstanceName')) IS NOT NULL THEN N'\' + convert(nvarchar(128), SERVERPROPERTY('InstanceName'))
ELSE N''
END as ServerInstance,
@Version as ProductVersion,
serverproperty('ProductLevel') as ProductLevel,
serverproperty('Edition') as Edition
if not (@MajorVer >= 10)
begin
RAISERROR('This server does not meet the requirements (SQL 2008 or later) for running the Performance Dashboard Reports. This server is running version %s', 18, 1, @Version)
end
end
go
grant execute on MS_PerfDashboard.usp_CheckDependencies to public
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_WaitTypeCategory'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_WaitTypeCategory
go
create function MS_PerfDashboard.fn_WaitTypeCategory(@wait_type nvarchar(60))
returns varchar(60)
as
begin
declare @category nvarchar(60)
select @category =
case
when @wait_type = N'SOS_SCHEDULER_YIELD' then N'CPU'
when @wait_type = N'THREADPOOL' then N'Worker Thread'
when @wait_type like N'LCK_M_%' then N'Lock'
when @wait_type like N'LATCH_%' then N'Latch'
when @wait_type like N'PAGELATCH_%' then N'Buffer Latch'
when @wait_type like N'PAGEIOLATCH_%' then N'Buffer IO'
when @wait_type like N'RESOURCE_SEMAPHORE_%' then N'Compilation'
when @wait_type like N'CLR_%' or @wait_type like N'SQLCLR%' then N'SQL CLR'
when @wait_type like N'DBMIRROR%' or @wait_type = N'MIRROR_SEND_MESSAGE' then N'Mirroring'
when @wait_type like N'XACT%' or @wait_type like N'DTC_%' or @wait_type like N'TRAN_MARKLATCH_%' or @wait_type like N'MSQL_XACT_%' or @wait_type = N'TRANSACTION_MUTEX' then N'Transaction'
when @wait_type like N'SLEEP_%' or @wait_type in(N'LAZYWRITER_SLEEP', N'SQLTRACE_BUFFER_FLUSH', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', N'SQLTRACE_WAIT_ENTRIES', N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'XE_DISPATCHER_WAIT', N'REQUEST_FOR_DEADLOCK_SEARCH', N'SLEEP_TASK', N'LOGMGR_QUEUE', N'ONDEMAND_TASK_QUEUE', N'CHECKPOINT_QUEUE', N'XE_TIMER_EVENT') then N'Idle'
when @wait_type like N'PREEMPTIVE_%' then N'Preemptive'
when @wait_type like N'BROKER_%' then N'Service Broker'
when @wait_type in (N'LOGMGR', N'LOGBUFFER', N'LOGMGR_RESERVE_APPEND', N'LOGMGR_FLUSH', N'WRITELOG') then N'Tran Log IO'
when @wait_type in (N'ASYNC_NETWORK_IO', N'NET_WAITFOR_PACKET') then N'Network IO'
when @wait_type in (N'CXPACKET', N'EXCHANGE') then N'Parallelism'
when @wait_type in (N'RESOURCE_SEMAPHORE', N'CMEMTHREAD', N'SOS_RESERVEDMEMBLOCKLIST') then N'Memory'
when @wait_type in (N'WAITFOR', N'WAIT_FOR_RESULTS', N'BROKER_RECEIVE_WAITFOR') then N'User Wait'
when @wait_type in (N'TRACEWRITE', N'SQLTRACE_LOCK', N'SQLTRACE_FILE_BUFFER', N'SQLTRACE_FILE_WRITE_IO_COMPLETION') then N'Tracing'
when @wait_type in (N'FT_RESTART_CRAWL', N'FULLTEXT GATHERER', N'MSSEARCH') then N'Full Text Search'
when @wait_type in (N'ASYNC_IO_COMPLETION', N'IO_COMPLETION', N'BACKUPIO', N'WRITE_COMPLETION') then N'Other Disk IO'
else N'Other'
end
return @category
end
go
GRANT EXECUTE ON MS_PerfDashboard.fn_WaitTypeCategory TO public
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_QueryTextFromHandle'), 'IsTableFunction') = 1
drop function MS_PerfDashboard.fn_QueryTextFromHandle
go
CREATE function MS_PerfDashboard.fn_QueryTextFromHandle(@handle varbinary(64), @statement_start_offset int, @statement_end_offset int)
RETURNS @query_text TABLE (database_id smallint, object_id int, encrypted bit, query_text nvarchar(max))
begin
if @handle is not null
begin
declare @start int, @end int
declare @dbid smallint, @objectid int, @encrypted bit
declare @batch nvarchar(max), @query nvarchar(max)
-- statement_end_offset is zero prior to beginning query execution (e.g., compilation)
select
@start = isnull(@statement_start_offset, 0),
@end = case when @statement_end_offset is null or @statement_end_offset = 0 then -1
else @statement_end_offset
end
select @dbid = t.dbid,
@objectid = t.objectid,
@encrypted = t.encrypted,
@batch = t.text
from sys.dm_exec_sql_text(@handle) as t
select @query = case
when @encrypted = cast(1 as bit) then N'encrypted text'
else ltrim(substring(@batch, @start / 2 + 1, case when (@end - @start) / 2 >= 0 then (@end - @start) / 2 else 1000 end))
end
-- Found internal queries (e.g., CREATE INDEX) with end offset of original batch that is
-- greater than the length of the internal query and thus returns nothing if we don't do this
if datalength(@query) = 0
begin
select @query = @batch
end
insert into @query_text (database_id, object_id, encrypted, query_text)
values (@dbid, @objectid, @encrypted, @query)
end
return
end
go
GRANT SELECT ON MS_PerfDashboard.fn_QueryTextFromHandle TO public
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_hexstrtovarbin'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_hexstrtovarbin
go
create function MS_PerfDashboard.fn_hexstrtovarbin(@input varchar(8000))
returns varbinary(8000)
as
begin
declare @result varbinary(8000)
if @input is not null
begin
declare @i int, @l int
select @result = 0x, @l = len(@input) / 2, @i = 2
while @i <= @l
begin
set @result = @result +
cast(cast(case lower(substring(@input, @i*2-1, 1))
when '0' then 0x00
when '1' then 0x10
when '2' then 0x20
when '3' then 0x30
when '4' then 0x40
when '5' then 0x50
when '6' then 0x60
when '7' then 0x70
when '8' then 0x80
when '9' then 0x90
when 'a' then 0xa0
when 'b' then 0xb0
when 'c' then 0xc0
when 'd' then 0xd0
when 'e' then 0xe0
when 'f' then 0xf0
end as tinyint) |
cast(case lower(substring(@input, @i*2, 1))
when '0' then 0x00
when '1' then 0x01
when '2' then 0x02
when '3' then 0x03
when '4' then 0x04
when '5' then 0x05
when '6' then 0x06
when '7' then 0x07
when '8' then 0x08
when '9' then 0x09
when 'a' then 0x0a
when 'b' then 0x0b
when 'c' then 0x0c
when 'd' then 0x0d
when 'e' then 0x0e
when 'f' then 0x0f
end as tinyint) as binary(1))
set @i = @i + 1
end
end
return @result
end
go
GRANT EXECUTE ON MS_PerfDashboard.fn_hexstrtovarbin TO public
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_DatediffMilliseconds'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_DatediffMilliseconds
go
create function MS_PerfDashboard.fn_DatediffMilliseconds(@start datetime, @end datetime)
returns bigint
as
begin
return (datediff(dd, @start, @end) * cast(86400000 as bigint) + datediff(ms, dateadd(dd, datediff(dd, @start, @end), @start), @end))
end
go
if object_id('MS_PerfDashboard.usp_Main_GetCPUHistory', 'P') is not null
drop procedure MS_PerfDashboard.usp_Main_GetCPUHistory
go
create procedure MS_PerfDashboard.usp_Main_GetCPUHistory
as
begin
declare @ms_now bigint
select @ms_now = ms_ticks from sys.dm_os_sys_info;
select top 15 record_id,
dateadd(ms, -1 * (@ms_now - [timestamp]), GetDate()) as EventTime,
SQLProcessUtilization,
SystemIdle,
100 - SystemIdle - SQLProcessUtilization as OtherProcessUtilization
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
end
go
grant execute on MS_PerfDashboard.usp_Main_GetCPUHistory to public
go
if object_id('MS_PerfDashboard.usp_Main_GetMiscInfo', 'P') is not null
drop procedure MS_PerfDashboard.usp_Main_GetMiscInfo
go
create procedure MS_PerfDashboard.usp_Main_GetMiscInfo
as
begin
select
(select count(*) from sys.traces) as running_traces,
(select count(*) from sys.databases) as number_of_databases,
(select count(*) from sys.dm_db_missing_index_group_stats) as missing_index_count,
(select waiting_tasks_count from sys.dm_os_wait_stats where wait_type = N'SQLCLR_QUANTUM_PUNISHMENT') as clr_quantum_waits,
(select count(*) from sys.dm_os_ring_buffers where ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR' and record like N'%<NonYieldSchedBegin>%') as non_yield_count,
(select cpu_count from sys.dm_os_sys_info) as number_of_cpus,
(select scheduler_count from sys.dm_os_sys_info) as number_of_schedulers,
(select COUNT(*) from sys.dm_xe_sessions) as number_of_xevent_sessions,
(select convert(varchar(30), AttribValue) from MS_PerfDashboard.tblConfigValues where Attribute = 'ReportVersion') as report_script_version
end
go
grant execute on MS_PerfDashboard.usp_Main_GetMiscInfo to public
go
if object_id('MS_PerfDashboard.usp_Main_GetSessionInfo', 'P') is not null
drop procedure MS_PerfDashboard.usp_Main_GetSessionInfo
go
create procedure MS_PerfDashboard.usp_Main_GetSessionInfo
as
begin
select count(*) as num_sessions,
sum(convert(bigint, s.total_elapsed_time)) as total_elapsed_time,
sum(convert(bigint, s.cpu_time)) as cpu_time,
case when sum(convert(bigint, s.total_elapsed_time)) - sum(convert(bigint, s.cpu_time)) > 0
then sum(convert(bigint, s.total_elapsed_time)) - sum(convert(bigint, s.cpu_time))
else 0
end as wait_time,
sum(convert(bigint, MS_PerfDashboard.fn_DatediffMilliseconds(login_time, getdate()))) - sum(convert(bigint, s.total_elapsed_time)) as idle_connection_time,
case when sum(s.logical_reads) > 0 then (sum(s.logical_reads) - isnull(sum(s.reads), 0)) / convert(float, sum(s.logical_reads))
else NULL
end as cache_hit_ratio
from sys.dm_exec_sessions s
where s.is_user_process = 0x1
end
go
grant execute on MS_PerfDashboard.usp_Main_GetSessionInfo to public
go
if object_id('MS_PerfDashboard.usp_Main_GetRequestInfo', 'P') is not null
drop procedure MS_PerfDashboard.usp_Main_GetRequestInfo
go
create procedure MS_PerfDashboard.usp_Main_GetRequestInfo
as
begin
select count(r.request_id) as num_requests,
sum(convert(bigint, r.total_elapsed_time)) as total_elapsed_time,
sum(convert(bigint, r.cpu_time)) as cpu_time,
case when sum(convert(bigint, r.total_elapsed_time)) - sum(convert(bigint, r.cpu_time)) > 0
then sum(convert(bigint, r.total_elapsed_time)) - sum(convert(bigint, r.cpu_time))
else 0
end as wait_time,
case when sum(r.logical_reads) > 0 then (sum(r.logical_reads) - isnull(sum(r.reads), 0)) / convert(float, sum(r.logical_reads))
else NULL
end as cache_hit_ratio
from sys.dm_exec_requests r
join sys.dm_exec_sessions s on r.session_id = s.session_id
where s.is_user_process = 0x1
end
go
grant execute on MS_PerfDashboard.usp_Main_GetRequestInfo to public
go
if object_id('MS_PerfDashboard.usp_Main_GetRequestWaits', 'P') is not null
drop procedure MS_PerfDashboard.usp_Main_GetRequestWaits
go
create procedure MS_PerfDashboard.usp_Main_GetRequestWaits
as
begin
SELECT
r.session_id,
MS_PerfDashboard.fn_WaitTypeCategory(r.wait_type) AS wait_category,
r.wait_type,
r.wait_time
FROM sys.dm_exec_requests AS r
INNER JOIN sys.dm_exec_sessions AS s ON r.session_id = s.session_id
WHERE r.wait_type IS NOT NULL
AND s.is_user_process = 0x1 -- TODO: parameterize
end
go
GRANT EXECUTE ON MS_PerfDashboard.usp_Main_GetRequestWaits TO public
go
if object_id('MS_PerfDashboard.usp_GetPageDetails', 'P') is not null
drop procedure MS_PerfDashboard.usp_GetPageDetails
go
create procedure MS_PerfDashboard.usp_GetPageDetails @wait_resource varchar(100)
as
begin
declare @database_id smallint, @file_id smallint, @page_no int
declare @t TABLE (ParentObject varchar(256), Object varchar(256), Field varchar(256), VALUE sql_variant)
declare @colon1 int, @colon2 int
select @colon1 = charindex(':', @wait_resource)
select @colon2 = charindex(':', @wait_resource, @colon1 + 1)
select @database_id = substring(@wait_resource, 1, @colon1 - 1)
select @file_id = substring(@wait_resource, @colon1 + 1, @colon2 - @colon1 - 1)
select @page_no = substring(@wait_resource, @colon2 + 1, 100)
BEGIN TRY
insert into @t exec sp_executesql N'dbcc page(@database_id, @file_id, @page_no) with tableresults', N'@database_id smallint, @file_id smallint, @page_no int', @database_id, @file_id, @page_no
END TRY
BEGIN CATCH
--do nothing
END CATCH
select @database_id as database_id,
quotename(db_name(@database_id)) as database_name,
@file_id as file_id,
@page_no as page_no,
convert(int, [Metadata: ObjectId]) as [object_id],
quotename(object_schema_name(convert(int, [Metadata: ObjectId]), @database_id)) + N'.' + quotename(object_name(convert(int, [Metadata: ObjectId]), @database_id)) as [object_name],
convert(smallint, [Metadata: IndexId]) as [index_id],
convert(int, [m_level]) as page_level,
case convert(int, [m_type])
when 1 then N'Data Page'
when 2 then N'Index Page'
when 3 then N'Text Mix Page'
when 4 then N'Text Tree Page'
when 8 then N'GAM Page'
when 9 then N'SGAM Page'
when 10 then N'IAM Page'
when 11 then N'PFS Page'
else convert(nvarchar(10), [m_type]) -- other types intentionally omitted
end as page_type
from (select * from @t where ParentObject = 'PAGE HEADER:' and
Field IN ('Metadata: ObjectId', 'Metadata: IndexId', 'm_objId (AllocUnitId.idObj)', 'm_level', 'm_type')) as x
pivot (min([VALUE]) for Field in ([Metadata: ObjectId], [Metadata: IndexId], [m_level], [m_type])) as z
end
go
GRANT EXECUTE ON MS_PerfDashboard.usp_GetPageDetails TO public
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.usp_GetPlanGuideDetails'), 'IsProcedure') = 1
drop procedure MS_PerfDashboard.usp_GetPlanGuideDetails
go
create procedure MS_PerfDashboard.usp_GetPlanGuideDetails @database_name nvarchar(128), @plan_guide_name nvarchar(128)
as
begin
if (LEFT(@database_name, 1) = N'[' and RIGHT(@database_name, 1) = N']')
begin
select @database_name = substring(@database_name, 2, len(@database_name) - 2)
end
if (LEFT(@plan_guide_name, 1) = N'[' and RIGHT(@plan_guide_name, 1) = N']')
begin
select @plan_guide_name = substring(@plan_guide_name, 2, len(@plan_guide_name) - 2)
end
if db_id(@database_name) is not null
begin
declare @cmd nvarchar(4000)
select @cmd = N'select * from [' + @database_name + N'].[sys].[plan_guides] where name = @P1'
exec sp_executesql @cmd, N'@P1 nvarchar(128)', @plan_guide_name
end
else
begin
-- return empty result set
select * from [sys].[plan_guides] where 0 = 1
end
end
go
grant execute on MS_PerfDashboard.usp_GetPlanGuideDetails to public
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.usp_TransformShowplanXMLToTable'), 'IsProcedure') = 1
drop procedure MS_PerfDashboard.usp_TransformShowplanXMLToTable
go
CREATE PROCEDURE MS_PerfDashboard.usp_TransformShowplanXMLToTable @plan_handle nvarchar(256), @stmt_start_offset int, @stmt_end_offset int, @fDebug bit = 0x0
AS
BEGIN
SET NOCOUNT ON
declare @plan nvarchar(max)
declare @dbid int, @objid int
declare @xml_plan xml
declare @error int
declare @output TABLE (
node_id int,
parent_node_id int,
relevant_xml_text nvarchar(max),
stmt_text nvarchar(max),
logical_op nvarchar(128),
physical_op nvarchar(128),
output_list nvarchar(max),
avg_row_size float,
est_cpu float,
est_io float,
est_rows float,
est_rewinds float,
est_rebinds float,
est_subtree_cost float,
warnings nvarchar(max))
BEGIN TRY
-- handle may be invalid now, or XML may be too deep to convert
select @dbid = p.dbid, @objid = p.objectid, @plan = p.query_plan from sys.dm_exec_text_query_plan(msdb.MS_PerfDashboard.fn_hexstrtovarbin(@plan_handle), @stmt_start_offset, @stmt_end_offset) as p
select @xml_plan = convert(xml, @plan)
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
insert into @output
select nd.node_id,
x.parent_node_id,
case when @fDebug = 0x1 then
case
when x.parent_node_id is null then @plan
else convert(nvarchar(max), x.plan_node)
end
else NULL
end as relevant_xml_text,
nd.stmt_text,
nd.logical_op,
nd.physical_op,
nd.output_list,
nd.avg_row_size,
nd.est_cpu,
nd.est_io,
nd.est_rows,
nd.est_rewinds,
nd.est_rebinds,
nd.est_subtree_cost,
nd.warnings
from (select
splan.row.query('.') as plan_node,
splan.row.value('../../@NodeId', 'int') as parent_node_id
from (select @xml_plan as query_plan) as p
cross apply p.query_plan.nodes('//sp:RelOp') as splan (row)) as x
outer apply MS_PerfDashboard.fn_ShowplanRowDetails(plan_node) as nd
order by isnull(parent_node_id, -1) asc
-- Statements such as WAITFOR, etc may not have a RelOp so just show the statement type if available
if @@rowcount = 0
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
insert into @output (stmt_text) select isnull(@xml_plan.value('(//@StatementType)[1]', 'nvarchar(max)'), N'Unknown Statement')
end
END TRY
BEGIN CATCH
select @error = ERROR_NUMBER()
-- select
-- cast(NULL as int) as node_id,
-- cast(NULL as int) as parent_node_id,
-- cast(NULL as nvarchar(max)) as relevant_xml_text,
-- cast(NULL as nvarchar(max)) as stmt_text,
-- cast(NULL as nvarchar(128)) as logical_op,
-- cast(NULL as nvarchar(128)) as physical_op,
-- cast(NULL as nvarchar(max)) as output_list,
-- cast(NULL as float) as avg_row_size,
-- cast(NULL as float) as est_cpu,
-- cast(NULL as float) as est_io,
-- cast(NULL as float) as est_rows,
-- cast(NULL as float) as est_rewinds,
-- cast(NULL as float) as est_rebinds,
-- cast(NULL as float) as est_subtree_cost,
-- cast(NULL as nvarchar(max)) as warnings
-- where 0 = 1
END CATCH
-- This may be an empty set if there was an exception caught above
SELECT
node_id,
parent_node_id,
relevant_xml_text,
stmt_text,
logical_op,
physical_op,
output_list,
avg_row_size,
est_cpu,
est_io,
est_rows,
est_rewinds,
est_rebinds,
est_subtree_cost,
warnings
FROM @output
END
go
grant execute on MS_PerfDashboard.usp_TransformShowplanXMLToTable to public
go
/*
*
* Helper procedures for building showplan output. These are called, indirectly, by MS_PerfDashboard.usp_TransformShowplanXMLToTable and because
* they belong to the same schema we do not need to grant EXECUTE permissions to users. They are not intended to be called directly as they require
* proper context within the showplan XML in order to return meaningful output.
*
*
*/
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildColumnReference'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildColumnReference
go
create function MS_PerfDashboard.fn_ShowplanBuildColumnReference(@node_data xml, @include_alias_or_table bit)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
declare @table nvarchar(256), @alias nvarchar(256), @column nvarchar(256)
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @alias = @node_data.value('(./sp:ColumnReference/@Alias)[1]', 'nvarchar(256)'),
@table = @node_data.value('(./sp:ColumnReference/@Table)[1]', 'nvarchar(256)'),
@column = @node_data.value('(./sp:ColumnReference/@Column)[1]', 'nvarchar(256)')
select @column = case when left(@column, 1) = N'[' and right(@column, 1) = N']' then @column else quotename(@column) end
if @include_alias_or_table = 0x1 and coalesce(@alias, @table) is not null
begin
select @alias = case when left(@alias, 1) = N'[' and right(@alias, 1) = N']' then @alias else quotename(@alias) end
select @table = case when left(@table, 1) = N'[' and right(@table, 1) = N']' then @table else quotename(@table) end
select @output = case
when @alias is not null then @alias
else @table
end + N'.' + @column
end
else
begin
select @output = @column
end
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildColumnReferenceList'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildColumnReferenceList
go
create function MS_PerfDashboard.fn_ShowplanBuildColumnReferenceList (@node_data xml, @include_alias_or_table bit)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
declare @count int, @ctr int
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = N'', @ctr = 1, @count = @node_data.value('count(./sp:ColumnReference)', 'int')
-- iterate over each element in the list
while @ctr <= @count
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @output + case when @ctr > 1 then N', ' else N'' end + MS_PerfDashboard.fn_ShowplanBuildColumnReference(@node_data.query('./sp:ColumnReference[position() = sql:variable("@ctr")]'), @include_alias_or_table)
select @ctr = @ctr + 1
end
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildDefinedValuesList'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildDefinedValuesList
go
create function MS_PerfDashboard.fn_ShowplanBuildDefinedValuesList (@node_data xml)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = convert(nvarchar(max), @node_data.query('for $val in /sp:DefinedValue
return concat(($val/sp:ColumnReference/@Column)[1], "=", ($val/sp:ScalarOperator/@ScalarString)[1], ",")'))
declare @len int
select @len = len(@output)
if (@len > 0)
begin
select @output = left(@output, @len - 1)
end
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildOrderBy'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildOrderBy
go
create function MS_PerfDashboard.fn_ShowplanBuildOrderBy (@node_data xml)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = convert(nvarchar(max), @node_data.query('for $col in /sp:OrderByColumn
return concat(if (($col/sp:ColumnReference/@Alias)[1] > "") then concat(($col/sp:ColumnReference/@Alias)[1], ".") else if (($col/sp:ColumnReference/@Table)[1] > "") then concat(($col/sp:ColumnReference/@Table)[1], ".") else "", string(($col/sp:ColumnReference/@Column)[1]), if ($col/@Ascending = 1) then " ASC" else " DESC", ",")'))
declare @len int
select @len = len(@output)
if (@len > 0)
begin
select @output = left(@output, @len - 1)
end
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildRowset'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildRowset
go
create function MS_PerfDashboard.fn_ShowplanBuildRowset (@node_data xml)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = MS_PerfDashboard.fn_ShowplanBuildObject(@node_data.query('./sp:Object'))
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildScalarExpression'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildScalarExpression
go
create function MS_PerfDashboard.fn_ShowplanBuildScalarExpression (@node_data xml)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
select @output = N''
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @node_data.value('(./sp:ScalarOperator/@ScalarString)[1]', 'nvarchar(max)')
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildScalarExpressionList'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildScalarExpressionList
go
create function MS_PerfDashboard.fn_ShowplanBuildScalarExpressionList (@node_data xml)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = convert(nvarchar(max), @node_data.query('for $op in ./sp:ScalarOperator
return concat(string($op/@ScalarString), ",")'))
declare @len int
select @len = len(@output)
if (@len > 0)
begin
select @output = left(@output, @len - 1)
end
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildScanRange'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildScanRange
go
create function MS_PerfDashboard.fn_ShowplanBuildScanRange (@node_data xml, @scan_type nvarchar(30))
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
set @output = N''
declare @count int, @ctr int
if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:RangeColumns') = 1)
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @ctr = 1, @count = @node_data.value('count(./sp:RangeColumns/sp:ColumnReference)', 'int')
while @ctr <= @count
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @output +
case when @ctr > 1 then N' AND ' else '' end + MS_PerfDashboard.fn_ShowplanBuildColumnReferenceList(@node_data.query('./sp:RangeColumns/sp:ColumnReference[position() = sql:variable("@ctr")]'), 0x1)
+ N' ' +
case UPPER(@scan_type)
when 'BINARY IS' then N'IS'
when 'EQ' then N'='
when 'GE' then N'>='
when 'GT' then N'>'
when 'IS' then N'IS'
when 'IS NOT' then N'IS NOT'
when 'IS NOT NULL' then N'IS NOT NULL'
when 'IS NULL' then N'IS NULL'
when 'LE' then N'<='
when 'LT' then N'<'
when 'NE' then N'<>'
end
+ N' '
+ MS_PerfDashboard.fn_ShowplanBuildScalarExpressionList(@node_data.query('./sp:RangeExpressions/sp:ScalarOperator[position() = sql:variable("@ctr")]'))
select @ctr = @ctr + 1
end
end
--if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:RangeExpressions') = 1)
--begin
-- ;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
-- select @output = @output + N'(RANGE: (' + MS_PerfDashboard.fn_ShowplanBuildScalarExpressionList(@node_data.query('./sp:RangeExpressions/*')) + N'))'
--end
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildSeekPredicates'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildSeekPredicates
go
create function MS_PerfDashboard.fn_ShowplanBuildSeekPredicates (@node_data xml)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
declare @count int, @ctr int
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = N'', @ctr = 1, @count = @node_data.value('count(./sp:SeekPredicates/sp:SeekPredicate)', 'int')
-- iterate over each element in the list
while @ctr <= @count
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @output + case when @ctr > 1 then N' AND ' else N'' end + MS_PerfDashboard.fn_ShowplanBuildSeekPredicate(@node_data.query('./sp:SeekPredicates/sp:SeekPredicate[position() = sql:variable("@ctr")]/*'))
select @ctr = @ctr + 1
end
return @output;
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildSeekPredicatesNew'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildSeekPredicatesNew
go
CREATE function [MS_PerfDashboard].[fn_ShowplanBuildSeekPredicatesNew] (@node_data xml)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
declare @count int, @ctr int
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = N'', @ctr = 1, @count = @node_data.value('count(./sp:SeekPredicates/sp:SeekPredicateNew)', 'int')
-- iterate over each element in the list
while @ctr <= @count
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @output + case when @ctr > 1 then N' AND ' else N'' end + MS_PerfDashboard.fn_ShowplanBuildSeekPredicate(@node_data.query('./sp:SeekPredicates/sp:SeekPredicateNew/sp:SeekKeys[position() = sql:variable("@ctr")]/*'))
select @ctr = @ctr + 1
end
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildSeekPredicate'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildSeekPredicate
go
create function MS_PerfDashboard.fn_ShowplanBuildSeekPredicate (@node_data xml)
returns nvarchar(max)
as
begin
declare @output nvarchar(max)
set @output = N''
if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:IsNotNull') = 1)
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @output + MS_PerfDashboard.fn_ShowplanBuildColumnReference(@node_data.query('./sp:IsNotNull/sp:ColumnReference'), 0x0) + N' IS NOT NULL'
end
if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:Prefix') = 1)
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @output + MS_PerfDashboard.fn_ShowplanBuildScanRange(@node_data.query('./sp:Prefix/*'), @node_data.value('(./sp:Prefix/@ScanType)[1]', 'nvarchar(100)'))
end
if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:StartRange') = 1)
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @output + case when datalength(@output) > 0 then N' AND ' else '' end + MS_PerfDashboard.fn_ShowplanBuildScanRange(@node_data.query('./sp:StartRange/*'), @node_data.value('(./sp:StartRange/@ScanType)[1]', 'nvarchar(100)'))
end
if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:EndRange') = 1)
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @output = @output + case when datalength(@output) > 0 then N' AND ' else '' end + MS_PerfDashboard.fn_ShowplanBuildScanRange(@node_data.query('./sp:EndRange/*'), @node_data.value('(./sp:EndRange/@ScanType)[1]', 'nvarchar(100)'))
end
return @output
end
go
if OBJECTPROPERTY(object_id('MS_PerfDashboard.fn_ShowplanBuildObject'), 'IsScalarFunction') = 1
drop function MS_PerfDashboard.fn_ShowplanBuildObject
go
create function MS_PerfDashboard.fn_ShowplanBuildObject (@node_data xml)
returns nvarchar(max)
as
begin
declare @object nvarchar(max)
set @object = N''
if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:Object/@Server') = 1)
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @object = @object + @node_data.value('(./sp:Object/@Server)[1]', 'nvarchar(128)') + N'.'
end
if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:Object/@Database') = 1)
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @object = @object + @node_data.value('(./sp:Object/@Database)[1]', 'nvarchar(128)') + N'.'
end
if (@node_data.exist('declare namespace sp="http://schemas.microsoft.com/sqlserver/2004/07/showplan"; ./sp:Object/@Schema') = 1)
begin
;WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS sp)
select @object = @object + @node_data.value('(./sp:Object/@Schema)[1]', 'nvarchar(128)') + N'.'
end