diff --git a/SQLWATCH Disk Utilisation Dashboard.pbit b/SQLWATCH Disk Utilisation Dashboard.pbit
new file mode 100644
index 00000000..12ff2840
Binary files /dev/null and b/SQLWATCH Disk Utilisation Dashboard.pbit differ
diff --git a/SQLWATCHDB/Properties/AssemblyInfo.cs b/SQLWATCHDB/Properties/AssemblyInfo.cs
index fe24ea46..8cb50171 100644
--- a/SQLWATCHDB/Properties/AssemblyInfo.cs
+++ b/SQLWATCHDB/Properties/AssemblyInfo.cs
@@ -19,5 +19,5 @@
// Build Number
// Revision
//
-[assembly: AssemblyVersion("1.0.*")]
-[assembly: AssemblyFileVersion("1.0.0.0")]
+[assembly: AssemblyVersion("1.1.*")]
+[assembly: AssemblyFileVersion("1.1.0.0")]
diff --git a/SQLWATCHDB/SQLWATCH.sqlproj b/SQLWATCHDB/SQLWATCH.sqlproj
index 29f081bf..af931ca5 100644
--- a/SQLWATCHDB/SQLWATCH.sqlproj
+++ b/SQLWATCHDB/SQLWATCH.sqlproj
@@ -29,6 +29,7 @@
CHECKSUM
True
True
+ 1.1.0.0
bin\Release\
@@ -95,6 +96,8 @@
+
+
diff --git a/SQLWATCHDB/Script.PostDeployment1.sql b/SQLWATCHDB/Script.PostDeployment1.sql
index efd9c8f2..b1769d63 100644
--- a/SQLWATCHDB/Script.PostDeployment1.sql
+++ b/SQLWATCHDB/Script.PostDeployment1.sql
@@ -835,6 +835,7 @@ if (select name from sysjobs where name = 'SQLWATCH-LOGGER-DISK-UTILISATION') is
@command=N'exec [dbo].[usp_logger_disk_utilisation]',
@database_name=@database,
@flags=0
+
EXEC msdb.dbo.sp_update_job @job_name=N'SQLWATCH-LOGGER-DISK-UTILISATION',
@enabled=1,
@start_step_id=1,
@@ -860,4 +861,56 @@ if (select name from sysjobs where name = 'SQLWATCH-LOGGER-DISK-UTILISATION') is
@active_end_date=99991231,
@active_start_time=437,
@active_end_time=235959, @schedule_id = @schedule_id OUTPUT
- end
\ No newline at end of file
+ end
+
+set @jobId = null
+declare @command nvarchar(4000)
+set @command = N'
+[datetime]$snapshot_time = (Invoke-SqlCmd -ServerInstance "' + @server + '" -Database ' + @database + ' -Query "select [snapshot_time]=max([snapshot_time])
+from [dbo].[sql_perf_mon_snapshot_header]
+where snapshot_type_id = 2").snapshot_time
+
+#https://msdn.microsoft.com/en-us/library/aa394515(v=vs.85).aspx
+#driveType 3 = Local disk
+Get-WMIObject Win32_Volume | ?{$_.DriveType -eq 3} | %{
+ $VolumeName = $_.Name
+ $VolumeLabel = $_.Label
+ $FileSystem = $_.Filesystem
+ $BlockSize = $_.BlockSize
+ $FreeSpace = $_.Freespace
+ $Capacity = $_.Capacity
+ $SnapshotTime = Get-Date $snapshot_time -format "yyyy-MM-dd HH:mm:ss.fff"
+ Invoke-SqlCmd -ServerInstance "' + @server + '" -Database ' + @database + ' -Query "
+ insert into [dbo].[logger_disk_utilisation_volume](
+ [volume_name]
+ ,[volume_label]
+ ,[volume_fs]
+ ,[volume_block_size_bytes]
+ ,[volume_free_space_bytes]
+ ,[volume_total_space_bytes]
+ ,[snapshot_type_id]
+ ,[snapshot_time])
+ values (''$VolumeName'',''$VolumeLabel'',''$FileSystem'',$BlockSize,$FreeSpace,$Capacity,2,''$SnapshotTime'')
+ "
+}'
+select @jobId = job_id from msdb.dbo.sysjobs where name = 'SQLWATCH-LOGGER-DISK-UTILISATION'
+if (select step_name from msdb.dbo.sysjobsteps
+where job_id = @jobId and step_name = 'Get-WMIObject Win32_Volume') is null
+ begin
+ EXEC msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Get-WMIObject Win32_Volume',
+ @step_id=2,
+ @cmdexec_success_code=0,
+ @on_success_action=1,
+ @on_success_step_id=0,
+ @on_fail_action=2,
+ @on_fail_step_id=0,
+ @retry_attempts=0,
+ @retry_interval=0,
+ @os_run_priority=0, @subsystem=N'PowerShell',
+ @command=@command,
+ @database_name=@database,
+ @flags=0
+ EXEC msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
+ end
+ EXEC msdb.dbo.sp_update_jobstep @job_id=@jobId, @step_id=1 ,@on_success_action=3
+
diff --git a/SQLWATCHDB/bin/Debug/SQLWATCH.dacpac b/SQLWATCHDB/bin/Debug/SQLWATCH.dacpac
index b681c316..0e997df9 100644
Binary files a/SQLWATCHDB/bin/Debug/SQLWATCH.dacpac and b/SQLWATCHDB/bin/Debug/SQLWATCH.dacpac differ
diff --git a/SQLWATCHDB/bin/Debug/SQLWATCHDB.dll b/SQLWATCHDB/bin/Debug/SQLWATCHDB.dll
index b49d23c5..0e91d033 100644
Binary files a/SQLWATCHDB/bin/Debug/SQLWATCHDB.dll and b/SQLWATCHDB/bin/Debug/SQLWATCHDB.dll differ
diff --git a/SQLWATCHDB/dbo/Procedures/usp_logger_disk_utilisation.sql b/SQLWATCHDB/dbo/Procedures/usp_logger_disk_utilisation.sql
index 9b73ee9e..cce6b29c 100644
--- a/SQLWATCHDB/dbo/Procedures/usp_logger_disk_utilisation.sql
+++ b/SQLWATCHDB/dbo/Procedures/usp_logger_disk_utilisation.sql
@@ -6,6 +6,7 @@ declare @snapshot_type tinyint = 2
declare @product_version nvarchar(128)
declare @product_version_major decimal(10,2)
declare @product_version_minor decimal(10,2)
+declare @sql varchar(max)
set @product_version = convert(nvarchar(128),serverproperty('productversion'));
select @product_version_major = substring(@product_version, 1,charindex('.', @product_version) + 1 )
@@ -21,16 +22,71 @@ values (@snapshot_time, @snapshot_type)
-- get sp_spaceused
--------------------------------------------------------------------------------------------------------------
declare @spaceused table (
- [database_name] nvarchar(128),
- [database_size] varchar(18),
- [unallocated_space] varchar(18),
- [reserved] varchar(18),
- [data] varchar(18),
- [index_size] varchar(18),
- [unused] varchar(18)
+ [database_name] nvarchar(128),
+ [database_size] varchar(18),
+ [unallocated_space] varchar(18),
+ [reserved] varchar(18),
+ [data] varchar(18),
+ [index_size] varchar(18),
+ [unused] varchar(18)
)
-insert into @spaceused
- exec sp_MSforeachdb 'use [?]; exec sp_spaceused @oneresultset = 1;'
+
+if @product_version_major >= 13
+/* since SQL 2016 Microsoft have improved sp_spaceused which now returns one recordset making it easier
+ to insert into tables */
+ begin
+ insert into @spaceused
+ exec sp_MSforeachdb 'use [?]; exec sp_spaceused @oneresultset = 1;'
+ end
+else
+ begin
+ /* pre 2016 however is not all that easy. sp_spaceused will return multiple resultsets making it impossible
+ to insert into a table. The below is more or less what sp_spaceused is doing */
+ insert into @spaceused
+ exec sp_MSforeachdb 'USE [?];
+ declare @id int
+ ,@type character(2)
+ ,@pages bigint
+ ,@dbname sysname
+ ,@dbsize bigint
+ ,@logsize bigint
+ ,@reservedpages bigint
+ ,@usedpages bigint
+ ,@rowCount bigint
+
+ select
+ @dbsize = sum(convert(bigint,case when status & 64 = 0 then size else 0 end))
+ , @logsize = sum(convert(bigint,case when status & 64 <> 0 then size else 0 end))
+ from dbo.sysfiles
+
+ select
+ @reservedpages = sum(a.total_pages),
+ @usedpages = sum(a.used_pages),
+ @pages = sum(
+ case
+ -- XML-Index and FT-Index and semantic index internal tables are not considered "data", but is part of "index_size"
+ when it.internal_type IN (202,204,207,211,212,213,214,215,216,221,222,236) then 0
+ when a.type <> 1 and p.index_id < 2 then a.used_pages
+ when p.index_id < 2 then a.data_pages
+ else 0
+ end
+ )
+ from sys.partitions p 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
+
+ select
+ database_name = db_name(),
+ database_size = ltrim(str((convert (dec (15,2),@dbsize) + convert (dec (15,2),@logsize))
+ * 8192 / 1048576,15,2) + '' MB''),
+ ''unallocated space'' = ltrim(str((case when @dbsize >= @reservedpages then
+ (convert (dec (15,2),@dbsize) - convert (dec (15,2),@reservedpages))
+ * 8192 / 1048576 else 0 end),15,2) + '' MB''),
+ reserved = ltrim(str(@reservedpages * 8192 / 1024.,15,0) + '' KB''),
+ data = ltrim(str(@pages * 8192 / 1024.,15,0) + '' KB''),
+ index_size = ltrim(str((@usedpages - @pages) * 8192 / 1024.,15,0) + '' KB''),
+ unused = ltrim(str((@reservedpages - @usedpages) * 8192 / 1024.,15,0) + '' KB'')
+ '
+ end
--------------------------------------------------------------------------------------------------------------
-- get log usage
diff --git a/SQLWATCHDB/dbo/Tables/logger_disk_utilisation_volume.sql b/SQLWATCHDB/dbo/Tables/logger_disk_utilisation_volume.sql
new file mode 100644
index 00000000..14877576
--- /dev/null
+++ b/SQLWATCHDB/dbo/Tables/logger_disk_utilisation_volume.sql
@@ -0,0 +1,15 @@
+CREATE TABLE [dbo].[logger_disk_utilisation_volume]
+(
+ [volume_name] nvarchar(255) not null,
+ [volume_label] nvarchar(255),
+ [volume_fs] varchar(255),
+ [volume_block_size_bytes] int,
+ [volume_free_space_bytes] bigint,
+ [volume_total_space_bytes] bigint,
+ [snapshot_time] datetime not null,
+ [snapshot_type_id] tinyint,
+ constraint PK_disk_util_vol primary key clustered (
+ snapshot_time, volume_name
+ ),
+ constraint FK_disk_util_vol_snapshot_header foreign key ([snapshot_time],[snapshot_type_id]) references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time],[snapshot_type_id]) on delete cascade
+)
diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_database.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_database.sql
index 7f12271c..8c2f663e 100644
--- a/SQLWATCHDB/dbo/Tables/sql_perf_mon_database.sql
+++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_database.sql
@@ -7,3 +7,5 @@
[database_name],[database_create_date]
)
)
+GO
+CREATE NONCLUSTERED INDEX idx_perf_mon_database_current ON [dbo].[sql_perf_mon_database]([database_current])
diff --git a/SQLWATCHDB/dbo/ufn_time_intervals.sql b/SQLWATCHDB/dbo/ufn_time_intervals.sql
new file mode 100644
index 00000000..04e57e41
--- /dev/null
+++ b/SQLWATCHDB/dbo/ufn_time_intervals.sql
@@ -0,0 +1,38 @@
+CREATE FUNCTION [dbo].[ufn_time_intervals]
+(
+ @snapshot_type_id tinyint = null,
+ @interval_minutes smallint = 15,
+ @report_window int = 4,
+ @report_end_time datetime = '2099-12-31'
+)
+RETURNS TABLE
+AS RETURN (
+ select
+ [spapshot_interval_start]
+ , [snapshot_interval_end] = dateadd(mi, @interval_minutes, [spapshot_interval_start])
+ , [first_snapshot_time] = MIN(i.snapshot_time)
+ , [last_snapshot_time] = MAX(i.snapshot_time)
+ , [snapshot_age_hours] = datediff(hour,dateadd(mi, @interval_minutes, [spapshot_interval_start]),GETDATE())
+ , [report_time_interval_minutes] = @interval_minutes
+ , s.[snapshot_type_id]
+ from [dbo].[sql_perf_mon_snapshot_header] s
+ inner join (
+ select
+ [snapshot_time]
+ , [spapshot_interval_start] = convert(datetime,dateadd(mi,(datediff(mi,0, [snapshot_time])/ @interval_minutes) * @interval_minutes,0))
+ , [report_time_interval_minutes] = @interval_minutes
+ , [snapshot_type_id]
+ from [dbo].[sql_perf_mon_snapshot_header]
+ where snapshot_type_id = isnull(@snapshot_type_id,snapshot_type_id)
+ and snapshot_time >= DATEADD(HOUR, -@report_window, @report_end_time)
+ and snapshot_time <= @report_end_time
+ ) i
+ on s.snapshot_time > [spapshot_interval_start]
+ and s.snapshot_time <= dateadd(mi, @interval_minutes, [spapshot_interval_start])
+ and i.[snapshot_type_id] = s.[snapshot_type_id]
+ where s.snapshot_type_id = isnull(@snapshot_type_id,s.snapshot_type_id)
+ and dateadd(mi, @interval_minutes, i.[spapshot_interval_start]) > DATEADD(HOUR, -@report_window, @report_end_time)
+ and dateadd(mi, @interval_minutes, i.[spapshot_interval_start]) <= @report_end_time
+ group by [spapshot_interval_start], s.snapshot_type_id
+ )
+GO
diff --git a/setup.sql b/setup.sql
deleted file mode 100644
index 33e09184..00000000
--- a/setup.sql
+++ /dev/null
@@ -1,1354 +0,0 @@
-------------------------------------------------------------------------------
--- SETUP SCRIPT
-------------------------------------------------------------------------------
-
---which database do you want this to be created?
-use [tempdb]
-go
-
-
--- setup objects:
-if object_id('[dbo].[sql_perf_mon_snapshot_header]') is null
- begin
- create table [dbo].[sql_perf_mon_snapshot_header] (
- [snapshot_time] datetime primary key
- )
- end
-go
-
-if object_id('[dbo].[sql_perf_mon_config_who_is_active_age]') is null
- begin
- create table [dbo].[sql_perf_mon_config_who_is_active_age] (
- [seconds] tinyint primary key
- )
- insert into [dbo].[sql_perf_mon_config_who_is_active_age]
- select 60
- end
-
-if object_id('[dbo].[sql_perf_mon_database]') is null
- begin
- create table [dbo].[sql_perf_mon_database] (
- [database_name] sysname primary key
- )
- insert into [dbo].[sql_perf_mon_database]
- select name from sys.Databases
- union all
- select 'mssqlsystemresource'
- end
-
-
-if object_id('[dbo].[sql_perf_mon_server]') is null
- begin
- create table [dbo].[sql_perf_mon_server] (
- [physical_name] sysname,
- [servername] sysname,
- [service_name] sysname,
- [local_net_address] varchar(50),
- [local_tcp_port] varchar(50)
- )
-
- insert into dbo.sql_perf_mon_server
- select convert(sysname,SERVERPROPERTY('ComputerNamePhysicalNetBIOS'))
- , convert(sysname,@@SERVERNAME), convert(sysname,@@SERVICENAME), convert(varchar(50),local_net_address), convert(varchar(50),local_tcp_port)
- FROM sys.dm_exec_connections WHERE session_id = @@spid
- end
-go
-
-if object_id('[dbo].[sql_perf_mon_file_stats]') is null
- begin
- create table [dbo].[sql_perf_mon_file_stats](
- [database_name] nvarchar(128) not null,
- [logical_file_name] sysname not null,
- [type_desc] nvarchar(60) not null,
- [logical_disk] varchar(255) not null,
- [num_of_reads] bigint not null,
- [num_of_bytes_read] bigint not null,
- [io_stall_read_ms] bigint not null,
- [num_of_writes] bigint not null,
- [num_of_bytes_written] bigint not null,
- [io_stall_write_ms] bigint not null,
- [size_on_disk_bytes] bigint not null,
- [snapshot_time] datetime foreign key references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time]) on delete cascade not null,
- constraint pk_sql_perf_mon_file_stats primary key clustered (
- [snapshot_time], [database_name], [logical_file_name], [type_desc]
- )
- )
- end
-go
-
-if object_id('[dbo].[sql_perf_mon_os_memory_clerks]') is null
- begin
- create table [dbo].[sql_perf_mon_os_memory_clerks] (
- [snapshot_time] datetime foreign key references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time]) on delete cascade not null,
- [total_kb] bigint,
- [allocated_kb] bigint,
- [total_kb_all_clerks] bigint,
- [clerk_name] varchar(255),
- [memory_available] int,
- constraint [pk_sql_perf_mon_os_memory_clerks] primary key (
- [snapshot_time], [clerk_name]
- )
- )
- end
-go
-
-if object_id('[dbo].[sql_perf_mon_wait_stats]') is null
- begin
- create table [dbo].[sql_perf_mon_wait_stats](
- [wait_type] nvarchar(60) not null,
- [waiting_tasks_count] bigint not null,
- [wait_time_ms] bigint not null,
- [max_wait_time_ms] bigint not null,
- [signal_wait_time_ms] bigint not null,
- [snapshot_time] datetime foreign key references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time]) on delete cascade not null,
- constraint [pk_sql_perf_mon_wait_stats] primary key (
- [snapshot_time] asc, [wait_type] asc
- )
- )
- end
-go
-
-if object_id('[dbo].[sql_perf_mon_perf_counters]') is null
- begin
- create table [dbo].[sql_perf_mon_perf_counters](
- [object_name] varchar(4000) not null,
- [instance_name] varchar(4000) not null,
- [counter_name] varchar(4000) not null,
- [cntr_value] bigint not null,
- [base_cntr_value] bigint null,
- [cntr_type] bigint not null,
- [snapshot_time] datetime foreign key references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time]) on delete cascade not null,
- constraint [pk_sql_perf_mon_perf_counters] primary key ([snapshot_time] asc, [object_name] asc, [counter_name] asc, [instance_name] asc)
- )
- end
-go
-
---migrate old and unused tables
-if object_id('[dbo].[sql_perf_mon_who_is_active]') is not null
- begin
- if (select count(*) from [dbo].[sql_perf_mon_who_is_active]) = 0
- begin
- drop table [dbo].[sql_perf_mon_who_is_active]
- end
- end
-
-if object_id('[dbo].[sql_perf_mon_who_is_active]') is null
- begin
- --schema generated by sp_who_is_active output:
- create table [dbo].[sql_perf_mon_who_is_active] ([snapshot_time] datetime foreign key references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time]) on delete cascade not null,[start_time] datetime NOT NULL,[session_id] smallint NOT NULL,[status] varchar(30) NOT NULL,[percent_complete] varchar(30) NULL,[host_name] nvarchar(128) NULL,[database_name] nvarchar(128) NULL,[program_name] nvarchar(128) NULL,[sql_text] xml NULL,[sql_command] xml NULL,[login_name] nvarchar(128) NOT NULL,[open_tran_count] varchar(30) NULL,[wait_info] nvarchar(4000) NULL,[blocking_session_id] smallint NULL,[blocked_session_count] varchar(30) NULL,[CPU] varchar(30) NULL,[used_memory] varchar(30) NULL,[tempdb_current] varchar(30) NULL,[tempdb_allocations] varchar(30) NULL,[reads] varchar(30) NULL,[writes] varchar(30) NULL,[physical_reads] varchar(30) NULL,[login_time] datetime NULL)
- create nonclustered index idx_whoisactive on [dbo].[sql_perf_mon_who_is_active] ([snapshot_time])
- end
-
-if object_id('[dbo].[sql_perf_mon_who_is_active_tmp]') is not null
- begin
- drop table [dbo].[sql_perf_mon_who_is_active_tmp]
- end
-
-if object_id('[dbo].[sql_perf_mon_who_is_active_tmp]') is null
- begin
- --schema generated by sp_who_is_active output:
- create table [dbo].[sql_perf_mon_who_is_active_tmp] ([snapshot_time] datetime not null,[start_time] datetime NOT NULL,[session_id] smallint NOT NULL,[status] varchar(30) NOT NULL,[percent_complete] varchar(30) NULL,[host_name] nvarchar(128) NULL,[database_name] nvarchar(128) NULL,[program_name] nvarchar(128) NULL,[sql_text] xml NULL,[sql_command] xml NULL,[login_name] nvarchar(128) NOT NULL,[open_tran_count] varchar(30) NULL,[wait_info] nvarchar(4000) NULL,[blocking_session_id] smallint NULL,[blocked_session_count] varchar(30) NULL,[CPU] varchar(30) NULL,[used_memory] varchar(30) NULL,[tempdb_current] varchar(30) NULL,[tempdb_allocations] varchar(30) NULL,[reads] varchar(30) NULL,[writes] varchar(30) NULL,[physical_reads] varchar(30) NULL,[login_time] datetime NULL)
- end
-
-
-if object_id('[dbo].[sql_perf_mon_config_perf_counters]') is null
- begin
- --create table to hold performance counters to collect.
- --the collection "on/off" switch is the [collect] column. 1= collect, 0= do not collect
- create table [dbo].[sql_perf_mon_config_perf_counters]
- (
- [object_name] nvarchar(256) not null,
- [instance_name] nvarchar(256) not null,
- [counter_name] nvarchar(256) not null,
- [base_counter_name] nvarchar(256) null,
- [collect] bit null,
- constraint pk_sql_perf_mon_config_perf_counters primary key (
- [object_name] , [instance_name], [counter_name]
- )
- );
- create nonclustered index idx_sql_perf_mon_perf_counters_types on dbo.[sql_perf_mon_config_perf_counters] ([collect]) include ([object_name],[instance_name],[counter_name],[base_counter_name])
-
- /* based on https://blogs.msdn.microsoft.com/dfurman/2015/04/02/collecting-performance-counter-values-from-a-sql-azure-database/ */
- insert into dbo.sql_perf_mon_config_perf_counters([collect],[object_name],[counter_name], [instance_name],[base_counter_name])
- values
- (0,'Access Methods','Forwarded Records/sec','',NULL)
- ,(1,'Access Methods','Full Scans/sec','',NULL)
- ,(1,'Access Methods','Page Splits/sec','',NULL)
- ,(1,'Access Methods','Pages Allocated/sec','',NULL)
- ,(0,'Access Methods','Table Lock Escalations/sec','',NULL)
- ,(1,'Access Methods','Index Searches/sec','',NULL)
- ,(1,'Access Methods','Page Deallocations/sec','',NULL)
- ,(1,'Access Methods','Page compression attempts/sec','',NULL)
- ,(1,'Access Methods','Pages compressed/sec','',NULL)
- ,(0,'Availability Replica','Bytes Received from Replica/sec','_Total',NULL)
- ,(0,'Availability Replica','Bytes Sent to Replica/sec','_Total',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000000ms & <000001ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000001ms & <000002ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000002ms & <000005ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000005ms & <000010ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000010ms & <000020ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000020ms & <000050ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000050ms & <000100ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000100ms & <000200ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000200ms & <000500ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000500ms & <001000ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=001000ms & <002000ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=002000ms & <005000ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=005000ms & <010000ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=010000ms & <020000ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=020000ms & <050000ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=050000ms & <100000ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=100000ms','CPU Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000000ms & <000001ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000001ms & <000002ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000002ms & <000005ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000005ms & <000010ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000010ms & <000020ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000020ms & <000050ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000050ms & <000100ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000100ms & <000200ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000200ms & <000500ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000500ms & <001000ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=001000ms & <002000ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=002000ms & <005000ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=005000ms & <010000ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=010000ms & <020000ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=020000ms & <050000ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=050000ms & <100000ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=100000ms','CPU Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000010ms & <000020ms','Elappsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000000ms & <000001ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000001ms & <000002ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000002ms & <000005ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000005ms & <000010ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000020ms & <000050ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000050ms & <000100ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000100ms & <000200ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000200ms & <000500ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000500ms & <001000ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=001000ms & <002000ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=002000ms & <005000ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=005000ms & <010000ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=010000ms & <020000ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=020000ms & <050000ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=050000ms & <100000ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=100000ms','Elapsed Time:Requests',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000000ms & <000001ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000001ms & <000002ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000002ms & <000005ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000005ms & <000010ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000010ms & <000020ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000020ms & <000050ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000050ms & <000100ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000100ms & <000200ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000200ms & <000500ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=000500ms & <001000ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=001000ms & <002000ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=002000ms & <005000ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=005000ms & <010000ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=010000ms & <020000ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=020000ms & <050000ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=050000ms & <100000ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Batch Resp Statistics','Batches >=100000ms','Elapsed Time:Total(ms)',NULL)
- ,(0,'Buffer Manager','Background writer pages/sec','',NULL)
- ,(1,'Buffer Manager','Buffer cache hit ratio','','Buffer cache hit ratio base ')
- ,(1,'Buffer Manager','Buffer cache hit ratio base','',NULL)
- ,(1,'Buffer Manager','Checkpoint pages/sec','',NULL)
- ,(1,'Buffer Manager','Lazy writes/sec','',NULL)
- ,(1,'Buffer Manager','Page reads/sec','',NULL)
- ,(1,'Buffer Manager','Readahead pages/sec','',NULL)
- ,(1,'Buffer Manager','Page lookups/sec','',NULL)
- ,(1,'Buffer Manager','Workfiles Created/sec','',NULL)
- ,(1,'Buffer Manager','Worktables Created/sec','',NULL)
- ,(1,'Buffer Manager','Free list stalls/sec','',NULL)
- ,(1,'Buffer Manager','Page writes/sec','',NULL)
- ,(1,'Buffer Node','Page life expectancy','000',NULL)
- ,(0,'Database Replica','File Bytes Received/sec','_Total',NULL)
- ,(0,'Database Replica','Log Bytes Received/sec','_Total',NULL)
- ,(0,'Database Replica','Log remaining for undo','_Total',NULL)
- ,(0,'Database Replica','Log Send Queue','_Total',NULL)
- ,(0,'Database Replica','Mirrored Write Transactions/sec','_Total',NULL)
- ,(0,'Database Replica','Recovery Queue','_Total',NULL)
- ,(0,'Database Replica','Redo blocked/sec','_Total',NULL)
- ,(0,'Database Replica','Redo Bytes Remaining','_Total',NULL)
- ,(0,'Database Replica','Redone Bytes/sec','_Total',NULL)
- ,(0,'Database Replica','Total Log requiring undo','_Total',NULL)
- ,(0,'Database Replica','Transaction Delay','_Total',NULL)
- ,(0,'Databases','Checkpoint duration','_Total',NULL)
- ,(0,'Databases','Group Commit Time/sec','_Total',NULL)
- ,(0,'Databases','Log Bytes Flushed/sec','_Total',NULL)
- ,(0,'Databases','Log Flush Waits/sec','_Total',NULL)
- ,(1,'Databases','Log Flushes/sec','_Total',NULL)
- ,(1,'Databases','Log Growths','_Total',NULL)
- ,(0,'Databases','Percent Log Used','<* !_Total>',NULL)
- ,(1,'Databases','Transactions/sec','<* !_Total>',NULL)
- ,(1,'Databases','Write Transactions/sec','_Total',NULL)
- ,(1,'Databases','Active Transactions','_Total',NULL)
- ,(1,'Databases','Log Truncations','_Total',NULL)
- ,(1,'Databases','Log Shrinks','_Total',NULL)
- ,(0,'Databases','Checkpoint duration','tempdb',NULL)
- ,(0,'Databases','Group Commit Time/sec','tempdb',NULL)
- ,(0,'Databases','Log Bytes Flushed/sec','tempdb',NULL)
- ,(0,'Databases','Log Flush Waits/sec','tempdb',NULL)
- ,(0,'Databases','Log Flushes/sec','tempdb',NULL)
- ,(0,'Databases','Log Growths','tempdb',NULL)
- ,(0,'Databases','Percent Log Used','tempdb',NULL)
- ,(0,'Databases','Transactions/sec','tempdb',NULL)
- ,(0,'Databases','Write Transactions/sec','tempdb',NULL)
- ,(1,'General Statistics','Active Temp Tables','',NULL)
- ,(0,'General Statistics','Logical Connections','',NULL)
- ,(1,'General Statistics','Logins/sec','',NULL)
- ,(0,'General Statistics','Logouts/sec','',NULL)
- ,(1,'General Statistics','Processes blocked','',NULL)
- ,(1,'General Statistics','User Connections','',NULL)
- ,(1,'General Statistics','Temp Tables Creation Rate','',NULL)
- ,(0,'HTTP Storage','Avg. Bytes/Read','<* !_Total>','Avg. Bytes/Read BASE ')
- ,(0,'HTTP Storage','Avg. Bytes/Read BASE','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Avg. Bytes/Transfer','<* !_Total>','Avg. Bytes/Transfer BASE ')
- ,(0,'HTTP Storage','Avg. Bytes/Transfer BASE','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Avg. Bytes/Write','<* !_Total>','Avg. Bytes/Write BASE ')
- ,(0,'HTTP Storage','Avg. Bytes/Write BASE','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Avg. microsec/Read','<* !_Total>','Avg. microsec/Read BASE ')
- ,(0,'HTTP Storage','Avg. microsec/Read BASE','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Avg. microsec/Read Comp','<* !_Total>','Avg. microsec/Read Comp BASE ')
- ,(0,'HTTP Storage','Avg. microsec/Read Comp BASE','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Avg. microsec/Transfer','<* !_Total>','Avg. microsec/Transfer BASE ')
- ,(0,'HTTP Storage','Avg. microsec/Transfer BASE','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Avg. microsec/Write','<* !_Total>','Avg. microsec/Write BASE ')
- ,(0,'HTTP Storage','Avg. microsec/Write BASE','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Avg. microsec/Write Comp','<* !_Total>','Avg. microsec/Write Comp BASE ')
- ,(0,'HTTP Storage','Avg. microsec/Write Comp BASE','<* !_Total>',NULL)
- ,(0,'HTTP Storage','HTTP Storage IO failed/sec','<* !_Total>',NULL)
- ,(0,'HTTP Storage','HTTP Storage IO retry/sec','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Outstanding HTTP Storage IO','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Read Bytes/Sec','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Reads/Sec','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Total Bytes/Sec','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Transfers/Sec','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Write Bytes/Sec','<* !_Total>',NULL)
- ,(0,'HTTP Storage','Writes/Sec','<* !_Total>',NULL)
- ,(1,'Latches','Latch Waits/sec','',NULL)
- ,(1,'Locks','Average Wait Time (ms)','_Total','Average Wait Time Base ')
- ,(1,'Locks','Average Wait Time Base','_Total',NULL)
- ,(0,'Locks','Lock Timeouts (timeout > 0)/sec','_Total',NULL)
- ,(1,'Locks','Number of Deadlocks/sec','_Total',NULL)
- ,(1,'Locks','Lock Requests/sec','_Total',NULL)
- ,(1,'Locks','Lock Waits/sec','_Total',NULL)
- ,(1,'Locks','Lock Timeouts/sec','_Total',NULL)
- ,(1,'Memory Manager','Memory Grants Outstanding','',NULL)
- ,(1,'Memory Manager','Memory Grants Pending','',NULL)
- ,(1,'Memory Manager','SQL Cache Memory (KB)','',NULL)
- ,(1,'Memory Manager','Stolen Server Memory (KB)','',NULL)
- ,(1,'Memory Manager','Target Server Memory (KB)','',NULL)
- ,(1,'Memory Manager','Total Server Memory (KB)','',NULL)
- ,(1,'Memory Manager','Connection Memory (KB)','',NULL)
- ,(1,'Memory Manager','Lock Memory (KB)','',NULL)
- ,(1,'Memory Manager','Optimizer Memory (KB)','',NULL)
- ,(0,'Plan Cache','Cache Hit Ratio','_Total','Cache Hit Ratio Base ')
- ,(0,'Plan Cache','Cache Hit Ratio Base','_Total',NULL)
- ,(0,'Plan Cache','Cache Object Counts','_Total',NULL)
- ,(0,'Resource Pool Stats','Active memory grant amount (KB)','internal',NULL)
- ,(0,'Resource Pool Stats','Active memory grants count','internal',NULL)
- ,(0,'Resource Pool Stats','Avg Disk Read IO (ms)','internal','Avg Disk Read IO (ms) Base ')
- ,(0,'Resource Pool Stats','Avg Disk Read IO (ms) Base','internal',NULL)
- ,(0,'Resource Pool Stats','Avg Disk Write IO (ms)','internal','Avg Disk Write IO (ms) Base ')
- ,(0,'Resource Pool Stats','Avg Disk Write IO (ms) Base','internal',NULL)
- ,(0,'Resource Pool Stats','Cache memory target (KB)','internal',NULL)
- ,(0,'Resource Pool Stats','Compile memory target (KB)','internal',NULL)
- ,(0,'Resource Pool Stats','CPU control effect %','internal',NULL)
- ,(0,'Resource Pool Stats','CPU delayed %','internal','CPU delayed % base ')
- ,(0,'Resource Pool Stats','CPU delayed % base','internal',NULL)
- ,(0,'Resource Pool Stats','CPU effective %','internal','CPU effective % base ')
- ,(0,'Resource Pool Stats','CPU effective % base','internal',NULL)
- ,(0,'Resource Pool Stats','CPU usage %','internal','CPU usage % base ')
- ,(0,'Resource Pool Stats','CPU usage % base','internal',NULL)
- ,(0,'Resource Pool Stats','CPU usage target %','internal',NULL)
- ,(0,'Resource Pool Stats','CPU violated %','internal',NULL)
- ,(0,'Resource Pool Stats','Disk Read Bytes/sec','internal',NULL)
- ,(0,'Resource Pool Stats','Disk Read IO Throttled/sec','internal',NULL)
- ,(0,'Resource Pool Stats','Disk Read IO/sec','internal',NULL)
- ,(0,'Resource Pool Stats','Disk Write Bytes/sec','internal',NULL)
- ,(0,'Resource Pool Stats','Disk Write IO Throttled/sec','internal',NULL)
- ,(0,'Resource Pool Stats','Disk Write IO/sec','internal',NULL)
- ,(0,'Resource Pool Stats','Max memory (KB)','internal',NULL)
- ,(0,'Resource Pool Stats','Memory grant timeouts/sec','internal',NULL)
- ,(0,'Resource Pool Stats','Memory grants/sec','internal',NULL)
- ,(0,'Resource Pool Stats','Pending memory grants count','internal',NULL)
- ,(0,'Resource Pool Stats','Query exec memory target (KB)','internal',NULL)
- ,(0,'Resource Pool Stats','Target memory (KB)','internal',NULL)
- ,(0,'Resource Pool Stats','Used memory (KB)','internal',NULL)
- ,(1,'SQL Errors','Errors/sec','_Total',NULL)
- ,(0,'SQL Errors','Errors/sec','DB Offline Errors',NULL)
- ,(0,'SQL Errors','Errors/sec','Kill Connection Errors',NULL)
- ,(0,'SQL Errors','Errors/sec','User Errors',NULL)
- ,(1,'SQL Statistics','Batch Requests/sec','',NULL)
- ,(1,'SQL Statistics','Failed Auto-Params/sec','',NULL)
- ,(0,'SQL Statistics','SQL Attention rate','',NULL)
- ,(1,'SQL Statistics','SQL Compilations/sec','',NULL)
- ,(1,'SQL Statistics','SQL Re-Compilations/sec','',NULL)
- ,(1,'SQL Statistics','Forced Parameterizations/sec','',NULL)
- ,(1,'SQL Statistics','Auto-Param Attempts/sec','',NULL)
- ,(0,'Transactions','Longest Transaction Running Time','',NULL)
- ,(0,'Transactions','Version Cleanup rate (KB/s)','',NULL)
- ,(0,'Transactions','Version Generation rate (KB/s)','',NULL)
- ,(1,'Transactions','Free Space in tempdb (KB)','',NULL)
- ,(1,'Wait Statistics','Log write waits','Average wait time (ms)',NULL)
- ,(1,'Wait Statistics','Network IO waits','Average wait time (ms)',NULL)
- ,(1,'Wait Statistics','Page IO latch waits','Average wait time (ms)',NULL)
- ,(1,'Wait Statistics','Page latch waits','Average wait time (ms)',NULL)
- ,(0,'Wait Statistics','Lock waits','Cumulative wait time (ms) per second',NULL)
- ,(0,'Wait Statistics','Memory grant queue waits','Cumulative wait time (ms) per second',NULL)
- ,(0,'Wait Statistics','Network IO waits','Cumulative wait time (ms) per second',NULL)
- ,(0,'Wait Statistics','Non-Page latch waits','Cumulative wait time (ms) per second',NULL)
- ,(1,'Wait Statistics','Page IO latch waits','Cumulative wait time (ms) per second',NULL)
- ,(1,'Wait Statistics','Page latch waits','Cumulative wait time (ms) per second',NULL)
- ,(0,'Wait Statistics','Wait for the worker','Cumulative wait time (ms) per second',NULL)
- ,(0,'Workload Group Stats','Active parallel threads','internal',NULL)
- ,(0,'Workload Group Stats','Active requests','internal',NULL)
- ,(0,'Workload Group Stats','Avg Disk msec/Read','internal','Disk msec/Read Base ')
- ,(0,'Workload Group Stats','Avg Disk msec/Write','internal','Disk msec/Write Base ')
- ,(0,'Workload Group Stats','Blocked tasks','internal',NULL)
- ,(0,'Workload Group Stats','CPU delayed %','internal','CPU delayed % base ')
- ,(0,'Workload Group Stats','CPU delayed % base','internal',NULL)
- ,(0,'Workload Group Stats','CPU effective %','internal','CPU effective % base ')
- ,(0,'Workload Group Stats','CPU effective % base','internal',NULL)
- ,(0,'Workload Group Stats','CPU usage %','internal','CPU usage % base ')
- ,(0,'Workload Group Stats','CPU usage % base','internal',NULL)
- ,(0,'Workload Group Stats','CPU violated %','internal',NULL)
- ,(0,'Workload Group Stats','Disk Read Bytes/sec','internal',NULL)
- ,(0,'Workload Group Stats','Disk Reads/sec','internal',NULL)
- ,(0,'Workload Group Stats','Disk Violations/sec','internal',NULL)
- ,(0,'Workload Group Stats','Disk Write Bytes/sec','internal',NULL)
- ,(0,'Workload Group Stats','Disk Writes/sec','internal',NULL)
- ,(0,'Workload Group Stats','Max request cpu time (ms)','internal',NULL)
- ,(0,'Workload Group Stats','Max request memory grant (KB)','internal',NULL)
- ,(0,'Workload Group Stats','Query optimizations/sec','internal',NULL)
- ,(0,'Workload Group Stats','Queued requests','internal',NULL)
- ,(0,'Workload Group Stats','Reduced memory grants/sec','internal',NULL)
- ,(0,'Workload Group Stats','Requests completed/sec','internal',NULL)
- ,(0,'Workload Group Stats','Suboptimal plans/sec','internal',NULL)
- ,(0,'Workload Group Stats','Disk msec/Read Base','internal',NULL)
- ,(0,'Workload Group Stats','Disk msec/Write Base','internal',NULL)
- ,(1,'Win32_PerfFormattedData_PerfOS_Processor','Processor Time %','SQL',NULL)
- ,(1,'Win32_PerfFormattedData_PerfOS_Processor','Idle Time %','SQL',NULL)
- ,(1,'Win32_PerfFormattedData_PerfOS_Processor','Processor Time %','System',NULL)
-
- end
-go
-
-if object_id('[dbo].[sql_perf_mon_config_wait_stats]') is null
- begin
- create table [dbo].[sql_perf_mon_config_wait_stats](
- [category_name] [nvarchar](40) not null,
- [wait_type] [nvarchar](45) primary key not null,
- [ignore] [bit] not null
- ) ;
-
- -- insert wait types
- insert into [dbo].[sql_perf_mon_config_wait_stats]
- values
- (N'Backup', N'BACKUP', 0)
- ,(N'Backup', N'BACKUP_CLIENTLOCK', 0)
- ,(N'Backup', N'BACKUP_OPERATOR', 0)
- ,(N'Backup', N'BACKUPBUFFER', 0)
- ,(N'Backup', N'BACKUPIO', 0)
- ,(N'Backup', N'BACKUPTHREAD', 0)
- ,(N'Backup', N'DISKIO_SUSPEND', 0)
- ,(N'Buffer I/O', N'ASYNC_DISKPOOL_LOCK', 0)
- ,(N'Buffer I/O', N'ASYNC_IO_COMPLETION', 0)
- ,(N'Buffer I/O', N'FCB_REPLICA_READ', 0)
- ,(N'Buffer I/O', N'FCB_REPLICA_WRITE', 0)
- ,(N'Buffer I/O', N'IO_COMPLETION', 0)
- ,(N'Buffer I/O', N'PAGEIOLATCH_DT', 0)
- ,(N'Buffer I/O', N'PAGEIOLATCH_EX', 0)
- ,(N'Buffer I/O', N'PAGEIOLATCH_KP', 0)
- ,(N'Buffer I/O', N'PAGEIOLATCH_NL', 0)
- ,(N'Buffer I/O', N'PAGEIOLATCH_SH', 0)
- ,(N'Buffer I/O', N'PAGEIOLATCH_UP', 0)
- ,(N'Buffer I/O', N'REPLICA_WRITES', 0)
- ,(N'Buffer Latch', N'PAGELATCH_DT', 0)
- ,(N'Buffer Latch', N'PAGELATCH_EX', 0)
- ,(N'Buffer Latch', N'PAGELATCH_KP', 0)
- ,(N'Buffer Latch', N'PAGELATCH_NL', 0)
- ,(N'Buffer Latch', N'PAGELATCH_SH', 0)
- ,(N'Buffer Latch', N'PAGELATCH_UP', 0)
- ,(N'Compilation', N'RESOURCE_SEMAPHORE_MUTEX', 0)
- ,(N'Compilation', N'RESOURCE_SEMAPHORE_QUERY_COMPILE', 0)
- ,(N'Compilation', N'RESOURCE_SEMAPHORE_SMALL_QUERY', 0)
- ,(N'Full Text Search', N'MSSEARCH', 0)
- ,(N'Full Text Search', N'SOAP_READ', 0)
- ,(N'Full Text Search', N'SOAP_WRITE', 0)
- ,(N'Idle', N'SERVER_IDLE_CHECK', 1)
- ,(N'Idle', N'ONDEMAND_TASK_QUEUE', 1)
- ,(N'Idle', N'SNI_HTTP_ACCEPT', 1)
- ,(N'Idle', N'SLEEP_BPOOL_FLUSH', 1)
- ,(N'Idle', N'SLEEP_DBSTARTUP', 1)
- ,(N'Idle', N'SLEEP_DCOMSTARTUP', 1)
- ,(N'Idle', N'SLEEP_MSDBSTARTUP', 1)
- ,(N'Idle', N'SLEEP_SYSTEMTASK', 1)
- ,(N'Idle', N'SLEEP_TASK', 1)
- ,(N'Idle', N'SLEEP_TEMPDBSTARTUP', 1)
- ,(N'Idle', N'WAIT_FOR_RESULTS', 1)
- ,(N'Idle', N'WAITFOR_TASKSHUTDOWN', 1)
- ,(N'Idle', N'SQLTRACE_BUFFER_FLUSH', 1)
- ,(N'Idle', N'TRACEWRITE', 1)
- ,(N'Idle', N'XE_DISPATCHER_WAIT', 1)
- ,(N'Idle', N'XE_TIMER_EVENT', 1)
- ,(N'Idle', N'REQUEST_FOR_DEADLOCK_SEARCH', 1)
- ,(N'Idle', N'RESOURCE_QUEUE', 1)
- ,(N'Idle', N'LOGMGR_QUEUE', 1)
- ,(N'Idle', N'KSOURCE_WAKEUP', 1)
- ,(N'Idle', N'LAZYWRITER_SLEEP', 1)
- ,(N'Idle', N'BROKER_EVENTHANDLER', 1)
- ,(N'Idle', N'BROKER_TRANSMITTER', 1)
- ,(N'Idle', N'CHECKPOINT_QUEUE', 1)
- ,(N'Idle', N'CHKPT', 1)
- ,(N'Idle', N'BROKER_RECEIVE_WAITFOR', 1)
- ,(N'Latch', N'DEADLOCK_ENUM_MUTEX', 0)
- ,(N'Latch', N'LATCH_DT', 0)
- ,(N'Latch', N'LATCH_EX', 0)
- ,(N'Latch', N'LATCH_KP', 0)
- ,(N'Latch', N'LATCH_NL', 0)
- ,(N'Latch', N'LATCH_SH', 0)
- ,(N'Latch', N'LATCH_UP', 0)
- ,(N'Latch', N'INDEX_USAGE_STATS_MUTEX', 0)
- ,(N'Latch', N'VIEW_DEFINITION_MUTEX', 0)
- ,(N'Lock', N'LCK_M_BU', 0)
- ,(N'Lock', N'LCK_M_IS', 0)
- ,(N'Lock', N'LCK_M_IU', 0)
- ,(N'Lock', N'LCK_M_IX', 0)
- ,(N'Lock', N'LCK_M_RIn_NL', 0)
- ,(N'Lock', N'LCK_M_RIn_S', 0)
- ,(N'Lock', N'LCK_M_RIn_U', 0)
- ,(N'Lock', N'LCK_M_RIn_X', 0)
- ,(N'Lock', N'LCK_M_RS_S', 0)
- ,(N'Lock', N'LCK_M_RS_U', 0)
- ,(N'Lock', N'LCK_M_RX_S', 0)
- ,(N'Lock', N'LCK_M_RX_U', 0)
- ,(N'Lock', N'LCK_M_RX_X', 0)
- ,(N'Lock', N'LCK_M_S', 0)
- ,(N'Lock', N'LCK_M_SCH_M', 0)
- ,(N'Lock', N'LCK_M_SCH_S', 0)
- ,(N'Lock', N'LCK_M_SIU', 0)
- ,(N'Lock', N'LCK_M_SIX', 0)
- ,(N'Lock', N'LCK_M_U', 0)
- ,(N'Lock', N'LCK_M_UIX', 0)
- ,(N'Lock', N'LCK_M_X', 0)
- ,(N'Logging', N'LOGBUFFER', 0)
- ,(N'Logging', N'LOGMGR', 0)
- ,(N'Logging', N'LOGMGR_FLUSH', 0)
- ,(N'Logging', N'LOGMGR_RESERVE_APPEND', 0)
- ,(N'Logging', N'WRITELOG', 0)
- ,(N'Memory', N'UTIL_PAGE_ALLOC', 0)
- ,(N'Memory', N'SOS_RESERVEDMEMBLOCKLIST', 0)
- ,(N'Memory', N'SOS_VIRTUALMEMORY_LOW', 0)
- ,(N'Memory', N'LOWFAIL_MEMMGR_QUEUE', 0)
- ,(N'Memory', N'RESOURCE_SEMAPHORE', 0)
- ,(N'Memory', N'CMEMTHREAD', 0)
- ,(N'Network I/O', N'NET_WAITFOR_PACKET', 0)
- ,(N'Network I/O', N'OLEDB', 0)
- ,(N'Network I/O', N'MSQL_DQ', 0)
- ,(N'Network I/O', N'DTC_STATE', 0)
- ,(N'Network I/O', N'DBMIRROR_SEND', 0)
- ,(N'Network I/O', N'ASYNC_NETWORK_IO', 0)
- ,(N'Other', N'ABR', 0)
- ,(N'Other', N'BROKER_REGISTERALLENDPOINTS', 0)
- ,(N'Other', N'BROKER_SHUTDOWN', 0)
- ,(N'Other', N'BROKER_TASK_STOP', 1)
- ,(N'Other', N'BAD_PAGE_PROCESS', 0)
- ,(N'Other', N'BROKER_CONNECTION_RECEIVE_TASK', 0)
- ,(N'Other', N'BROKER_ENDPOINT_STATE_MUTEX', 0)
- ,(N'Other', N'BUILTIN_HASHKEY_MUTEX', 0)
- ,(N'Other', N'CHECK_PRINT_RECORD', 0)
- ,(N'Other', N'BROKER_INIT', 0)
- ,(N'Other', N'BROKER_MASTERSTART', 0)
- ,(N'Other', N'CURSOR', 0)
- ,(N'Other', N'CURSOR_ASYNC', 0)
- ,(N'Other', N'DBMIRROR_WORKER_QUEUE', 0)
- ,(N'Other', N'DBMIRRORING_CMD', 0)
- ,(N'Other', N'DBTABLE', 0)
- ,(N'Other', N'DAC_INIT', 0)
- ,(N'Other', N'DBCC_COLUMN_TRANSLATION_CACHE', 0)
- ,(N'Other', N'DBMIRROR_DBM_EVENT', 0)
- ,(N'Other', N'DBMIRROR_DBM_MUTEX', 0)
- ,(N'Other', N'DBMIRROR_EVENTS_QUEUE', 0)
- ,(N'Other', N'DEADLOCK_TASK_SEARCH', 0)
- ,(N'Other', N'DEBUG', 0)
- ,(N'Other', N'DISABLE_VERSIONING', 0)
- ,(N'Other', N'DLL_LOADING_MUTEX', 0)
- ,(N'Other', N'DROPTEMP', 0)
- ,(N'Other', N'DUMP_LOG_COORDINATOR', 0)
- ,(N'Other', N'DUMP_LOG_COORDINATOR_QUEUE', 0)
- ,(N'Other', N'DUMPTRIGGER', 0)
- ,(N'Other', N'EC', 0)
- ,(N'Other', N'EE_PMOLOCK', 0)
- ,(N'Other', N'EE_SPECPROC_MAP_INIT', 0)
- ,(N'Other', N'ENABLE_VERSIONING', 0)
- ,(N'Other', N'ERROR_REPORTING_MANAGER', 0)
- ,(N'Other', N'FSAGENT', 1)
- ,(N'Other', N'FT_RESTART_CRAWL', 0)
- ,(N'Other', N'FT_RESUME_CRAWL', 0)
- ,(N'Other', N'FULLTEXT GATHERER', 0)
- ,(N'Other', N'GUARDIAN', 0)
- ,(N'Other', N'HTTP_ENDPOINT_COLLCREATE', 0)
- ,(N'Other', N'HTTP_ENUMERATION', 0)
- ,(N'Other', N'HTTP_START', 0)
- ,(N'Other', N'IMP_IMPORT_MUTEX', 0)
- ,(N'Other', N'IMPPROV_IOWAIT', 0)
- ,(N'Other', N'EXECUTION_PIPE_EVENT_INTERNAL', 0)
- ,(N'Other', N'FAILPOINT', 0)
- ,(N'Other', N'INTERNAL_TESTING', 0)
- ,(N'Other', N'IO_AUDIT_MUTEX', 0)
- ,(N'Other', N'KTM_ENLISTMENT', 0)
- ,(N'Other', N'KTM_RECOVERY_MANAGER', 0)
- ,(N'Other', N'KTM_RECOVERY_RESOLUTION', 0)
- ,(N'Other', N'MSQL_SYNC_PIPE', 0)
- ,(N'Other', N'MIRROR_SEND_MESSAGE', 0)
- ,(N'Other', N'MISCELLANEOUS', 0)
- ,(N'Other', N'MSQL_XP', 0)
- ,(N'Other', N'REQUEST_DISPENSER_PAUSE', 0)
- ,(N'Other', N'PARALLEL_BACKUP_QUEUE', 0)
- ,(N'Other', N'PRINT_ROLLBACK_PROGRESS', 0)
- ,(N'Other', N'QNMANAGER_ACQUIRE', 0)
- ,(N'Other', N'QPJOB_KILL', 0)
- ,(N'Other', N'QPJOB_WAITFOR_ABORT', 0)
- ,(N'Other', N'QRY_MEM_GRANT_INFO_MUTEX', 0)
- ,(N'Other', N'QUERY_ERRHDL_SERVICE_DONE', 0)
- ,(N'Other', N'QUERY_EXECUTION_INDEX_SORT_EVENT_OPEN', 0)
- ,(N'Other', N'QUERY_NOTIFICATION_MGR_MUTEX', 0)
- ,(N'Other', N'QUERY_NOTIFICATION_SUBSCRIPTION_MUTEX', 0)
- ,(N'Other', N'QUERY_NOTIFICATION_TABLE_MGR_MUTEX', 0)
- ,(N'Other', N'QUERY_NOTIFICATION_UNITTEST_MUTEX', 0)
- ,(N'Other', N'QUERY_OPTIMIZER_PRINT_MUTEX', 0)
- ,(N'Other', N'QUERY_REMOTE_BRICKS_DONE', 0)
- ,(N'Other', N'QUERY_TRACEOUT', 0)
- ,(N'Other', N'RECOVER_CHANGEDB', 0)
- ,(N'Other', N'REPL_CACHE_ACCESS', 0)
- ,(N'Other', N'REPL_SCHEMA_ACCESS', 0)
- ,(N'Other', N'SOSHOST_EVENT', 0)
- ,(N'Other', N'SOSHOST_INTERNAL', 0)
- ,(N'Other', N'SOSHOST_MUTEX', 0)
- ,(N'Other', N'SOSHOST_RWLOCK', 0)
- ,(N'Other', N'SOSHOST_SEMAPHORE', 0)
- ,(N'Other', N'SOSHOST_SLEEP', 0)
- ,(N'Other', N'SOSHOST_TRACELOCK', 0)
- ,(N'Other', N'SOSHOST_WAITFORDONE', 0)
- ,(N'Other', N'SHUTDOWN', 0)
- ,(N'Other', N'SOS_CALLBACK_REMOVAL', 0)
- ,(N'Other', N'SOS_DISPATCHER_MUTEX', 0)
- ,(N'Other', N'SOS_LOCALALLOCATORLIST', 0)
- ,(N'Other', N'SOS_OBJECT_STORE_DESTROY_MUTEX', 0)
- ,(N'Other', N'SOS_PROCESS_AFFINITY_MUTEX', 0)
- ,(N'Other', N'SNI_CRITICAL_SECTION', 0)
- ,(N'Other', N'SNI_HTTP_WAITFOR_0_DISCON', 0)
- ,(N'Other', N'SNI_LISTENER_ACCESS', 0)
- ,(N'Other', N'SNI_TASK_COMPLETION', 0)
- ,(N'Other', N'SEC_DROP_TEMP_KEY', 0)
- ,(N'Other', N'SEQUENTIAL_GUID', 0)
- ,(N'Other', N'VIA_ACCEPT', 0)
- ,(N'Other', N'SOS_STACKSTORE_INIT_MUTEX', 0)
- ,(N'Other', N'SOS_SYNC_TASK_ENQUEUE_EVENT', 0)
- ,(N'Other', N'SQLSORT_NORMMUTEX', 0)
- ,(N'Other', N'SQLSORT_SORTMUTEX', 0)
- ,(N'Other', N'WAITSTAT_MUTEX', 0)
- ,(N'Other', N'WCC', 0)
- ,(N'Other', N'WORKTBL_DROP', 0)
- ,(N'Other', N'SQLTRACE_LOCK', 0)
- ,(N'Other', N'SQLTRACE_SHUTDOWN', 0)
- ,(N'Other', N'SQLTRACE_WAIT_ENTRIES', 0)
- ,(N'Other', N'SRVPROC_SHUTDOWN', 0)
- ,(N'Other', N'TEMPOBJ', 0)
- ,(N'Other', N'THREADPOOL', 1)
- ,(N'Other', N'TIMEPRIV_TIMEPERIOD', 0)
- ,(N'Other', N'XE_TIMER_MUTEX', 0)
- ,(N'Other', N'XE_TIMER_TASK_DONE', 0)
- ,(N'Other', N'XE_BUFFERMGR_ALLPROCECESSED_EVENT', 0)
- ,(N'Other', N'XE_BUFFERMGR_FREEBUF_EVENT', 0)
- ,(N'Other', N'XE_DISPATCHER_JOIN', 0)
- ,(N'Other', N'XE_MODULEMGR_SYNC', 0)
- ,(N'Other', N'XE_OLS_LOCK', 0)
- ,(N'Other', N'XE_SERVICES_MUTEX', 0)
- ,(N'Other', N'XE_SESSION_CREATE_SYNC', 0)
- ,(N'Other', N'XE_SESSION_SYNC', 0)
- ,(N'Other', N'XE_STM_CREATE', 0)
- ,(N'Parallelism', N'EXCHANGE', 1)
- ,(N'Parallelism', N'EXECSYNC', 1)
- ,(N'Parallelism', N'CXPACKET', 1)
- ,(N'SQLCLR', N'CLR_AUTO_EVENT', 1)
- ,(N'SQLCLR', N'CLR_CRST', 0)
- ,(N'SQLCLR', N'CLR_JOIN', 0)
- ,(N'SQLCLR', N'CLR_MANUAL_EVENT', 1)
- ,(N'SQLCLR', N'CLR_MEMORY_SPY', 0)
- ,(N'SQLCLR', N'CLR_MONITOR', 0)
- ,(N'SQLCLR', N'CLR_RWLOCK_READER', 0)
- ,(N'SQLCLR', N'CLR_RWLOCK_WRITER', 0)
- ,(N'SQLCLR', N'CLR_SEMAPHORE', 0)
- ,(N'SQLCLR', N'CLR_TASK_START', 0)
- ,(N'SQLCLR', N'CLRHOST_STATE_ACCESS', 0)
- ,(N'SQLCLR', N'ASSEMBLY_LOAD', 0)
- ,(N'SQLCLR', N'FS_GARBAGE_COLLECTOR_SHUTDOWN', 0)
- ,(N'SQLCLR', N'SQLCLR_APPDOMAIN', 0)
- ,(N'SQLCLR', N'SQLCLR_ASSEMBLY', 0)
- ,(N'SQLCLR', N'SQLCLR_DEADLOCK_DETECTION', 0)
- ,(N'SQLCLR', N'SQLCLR_QUANTUM_PUNISHMENT', 0)
- ,(N'Transaction', N'TRAN_MARKLATCH_DT', 0)
- ,(N'Transaction', N'TRAN_MARKLATCH_EX', 0)
- ,(N'Transaction', N'TRAN_MARKLATCH_KP', 0)
- ,(N'Transaction', N'TRAN_MARKLATCH_NL', 0)
- ,(N'Transaction', N'TRAN_MARKLATCH_SH', 0)
- ,(N'Transaction', N'TRAN_MARKLATCH_UP', 0)
- ,(N'Transaction', N'TRANSACTION_MUTEX', 0)
- ,(N'Transaction', N'XACT_OWN_TRANSACTION', 0)
- ,(N'Transaction', N'XACT_RECLAIM_SESSION', 0)
- ,(N'Transaction', N'XACTLOCKINFO', 0)
- ,(N'Transaction', N'XACTWORKSPACE_MUTEX', 0)
- ,(N'Transaction', N'DTC_TMDOWN_REQUEST', 0)
- ,(N'Transaction', N'DTC_WAITFOR_OUTCOME', 0)
- ,(N'Transaction', N'MSQL_XACT_MGR_MUTEX', 0)
- ,(N'Transaction', N'MSQL_XACT_MUTEX', 0)
- ,(N'Transaction', N'DTC', 0)
- ,(N'Transaction', N'DTC_ABORT_REQUEST', 0)
- ,(N'Transaction', N'DTC_RESOLVE', 0)
- ,(N'User Waits', N'WAITFOR', 1)
- ,(N'Mirroring', N'DBMIRROR%', 1)
- ,(N'Availability Groups', N'HADR%', 1)
- ,(N'Replication', N'REPL%', 1);
-
-
- create nonclustered index idx_wait_stats on [dbo].[sql_perf_mon_config_wait_stats](wait_type)
- end
-go
-
-if object_id('[dbo].[sql_perf_mon_config_report_time_interval]') is null
- begin
- create table [dbo].[sql_perf_mon_config_report_time_interval] (
- [report_time_interval_minutes] tinyint
- )
- insert into [dbo].[sql_perf_mon_config_report_time_interval]([report_time_interval_minutes])
- select 5
- union
- select 15
- end
-
-
-if object_id('[dbo].[vw_sql_perf_mon_time_intervals]') is null
- exec ('create view [dbo].[vw_sql_perf_mon_time_intervals] as select dummy=''placeholder''')
-go
-
-alter view [dbo].[vw_sql_perf_mon_time_intervals] as
-select
- [spapshot_interval_start]
- , [snapshot_interval_end] = dateadd(mi, [report_time_interval_minutes], [spapshot_interval_start])
- , [first_snapshot_time] = MIN(i.snapshot_time)
- , [last_snapshot_time] = MAX(i.snapshot_time)
- , [snapshot_age_hours] = datediff(hour,dateadd(mi, [report_time_interval_minutes], [spapshot_interval_start]),GETDATE())
- , [report_time_interval_minutes]
-from [dbo].[sql_perf_mon_snapshot_header] s
-inner join (
- select
- [snapshot_time]
- , [spapshot_interval_start] = convert(datetime,dateadd(mi,(datediff(mi,0, [snapshot_time])/ ti.[report_time_interval_minutes]) * ti.[report_time_interval_minutes],0))
- , ti.[report_time_interval_minutes]
- from [dbo].[sql_perf_mon_snapshot_header]
- cross apply (
- select top 5 report_time_interval_minutes
- from [dbo].[sql_perf_mon_config_report_time_interval]
- order by report_time_interval_minutes
- ) ti
- ) i
- on s.snapshot_time > [spapshot_interval_start]
- and s.snapshot_time <= dateadd(mi, [report_time_interval_minutes], [spapshot_interval_start])
-group by [spapshot_interval_start], [report_time_interval_minutes]
-go
-
-if object_id('[dbo].[vw_sql_perf_mon_wait_stats_categorised]') is null
- exec ('create view [dbo].[vw_sql_perf_mon_wait_stats_categorised] as select dummy=''placeholder''')
-go
-
-alter view [dbo].[vw_sql_perf_mon_wait_stats_categorised] as
- select ws.* , category_name = case when ws.wait_type like 'PREEMPTIVE%' then 'PREEMPTIVE' else wt.category_name end , wt.ignore
- from [dbo].[sql_perf_mon_wait_stats] ws
- left join [dbo].[sql_perf_mon_config_wait_stats] wt
- on ws.wait_type LIKE wt.wait_type
-go
-
---------------------------------------------------------------------------------------------------------------
--- get process memory. table layout differes between different sql versions so we will take
--- dynamic approach and create table if it does not exists straight from results (select into)
---------------------------------------------------------------------------------------------------------------
-declare @sql nvarchar(4000)
-if object_id('[dbo].[sql_perf_mon_os_process_memory]') is null
- begin
- set @sql = 'select snapshot_time=convert(datetime,''' + convert(varchar(23),GETDATE(),121) + '''), * into dbo.sql_perf_mon_os_process_memory from sys.dm_os_process_memory where 1=2'
- exec sp_executesql @sql
- alter table [dbo].[sql_perf_mon_os_process_memory] alter column [snapshot_time] datetime not null
- alter table [dbo].[sql_perf_mon_os_process_memory] add primary key ([snapshot_time])
-
- alter table [dbo].[sql_perf_mon_os_process_memory] add constraint fk_sql_perf_mon_os_process_memory foreign key ([snapshot_time])
- references [dbo].[sql_perf_mon_snapshot_header] ([snapshot_time])
- on delete cascade
- end
-go
-
-
-if object_id('[dbo].[vw_sql_perf_mon_rep_mem_proc]') is null
- exec ('create view [dbo].[vw_sql_perf_mon_rep_mem_proc] as select dummy=''placeholder''')
-go
-
-alter view [dbo].[vw_sql_perf_mon_rep_mem_proc] as
- select
- [report_name] = 'process memory'
- ,[report_time] = s.[snapshot_interval_end]
- ,[Physical memory in use (MB)]=avg([physical_memory_in_use_kb]/1024)
- ,[Locked page allocations (MB)]=avg([locked_page_allocations_kb]/1024)
- ,[Page faults]=avg([page_fault_count])
- ,[Memory utilisation %]=avg([memory_utilization_percentage])
- ,s.[report_time_interval_minutes]
- from [dbo].[sql_perf_mon_os_process_memory] pm
- inner join [dbo].[vw_sql_perf_mon_time_intervals] s
- on pm.snapshot_time >= s.first_snapshot_time
- and pm.snapshot_time <= s.last_snapshot_time
- group by s.[snapshot_interval_end],s.[report_time_interval_minutes]
-go
-
-if object_id('[dbo].[vw_sql_perf_mon_rep_perf_counter]') is null
- exec ('create view [dbo].[vw_sql_perf_mon_rep_perf_counter] as select dummy=''placeholder''')
-go
-
-alter view [dbo].[vw_sql_perf_mon_rep_perf_counter] as
- select distinct
- [report_name] = 'Performance Counters'
- ,[report_time] = s.snapshot_interval_end
- ,[object_name] = rtrim(ltrim(pc.[object_name]))
- ,[instance_name] = rtrim(ltrim(isnull(pc.instance_name, '')))
- ,counter_name = rtrim(ltrim(pc.counter_name))
- ,[cntr_value] = convert(real,(
- case
- when sc.object_name = 'Batch Resp Statistics' then case when pc.cntr_value > fsc.cntr_value then cast((pc.cntr_value - fsc.cntr_value) as real) else 0 end -- delta absolute
- when pc.cntr_type = 65792 then isnull(pc.cntr_value,0) -- point-in-time
- when pc.cntr_type = 272696576 then case when (pc.cntr_value > fsc.cntr_value) then (pc.cntr_value - fsc.cntr_value) / cast(datediff(second,s.first_snapshot_time,s.last_snapshot_time) as real) else 0 end -- delta rate
- when pc.cntr_type = 537003264 then isnull(cast(100.0 as real) * pc.cntr_value / nullif(bc.cntr_value, 0),0) -- ratio
- when pc.cntr_type = 1073874176 then isnull(case when pc.cntr_value > fsc.cntr_value then isnull((pc.cntr_value - fsc.cntr_value) / nullif(bc.cntr_value - fsc.base_cntr_value, 0) / cast(datediff(second,s.first_snapshot_time,s.last_snapshot_time) as real), 0) else 0 end,0) -- delta ratio
- end))
- ,s.[report_time_interval_minutes]
- from dbo.sql_perf_mon_perf_counters as pc
- inner join [dbo].[vw_sql_perf_mon_time_intervals] s
- on pc.snapshot_time = s.last_snapshot_time
-
- inner join dbo.sql_perf_mon_config_perf_counters as sc
- on rtrim(pc.object_name) like '%' + sc.object_name
- and rtrim(pc.counter_name) = sc.counter_name
- and (rtrim(pc.instance_name) = sc.instance_name
- or (
- sc.instance_name = '<* !_total>'
- and rtrim(pc.instance_name) <> '_total'
- )
- )
- outer apply (
- select top (1) fsc.cntr_value,
- fsc.base_cntr_value
- from (
- select *
- from [dbo].[sql_perf_mon_perf_counters]
- where snapshot_time = s.first_snapshot_time
- ) as fsc
- where fsc.[object_name] = rtrim(pc.[object_name])
- and fsc.counter_name = rtrim(pc.counter_name)
- and fsc.instance_name = rtrim(pc.instance_name)
- ) as fsc
- outer apply (
- select top (1) pc2.cntr_value
- from [dbo].[sql_perf_mon_perf_counters] as pc2
- where snapshot_time = s.last_snapshot_time
- and pc2.cntr_type = 1073939712
- and pc2.object_name = pc.object_name
- and pc2.instance_name = pc.instance_name
- and rtrim(pc2.counter_name) = sc.base_counter_name
- ) as bc
- where -- exclude base counters
- pc.cntr_type in (65792,272696576,537003264,1073874176)
-go
-
-if not exists (select * from information_schema.routines where routine_name = 'sp_sql_perf_mon_logger')
- exec ('create proc [dbo].[sp_sql_perf_mon_logger] as select ''sp_sql_perf_mon_logger placeholder''')
-go
-
-alter procedure [dbo].[sp_sql_perf_mon_logger]
-as
-
-set nocount on;
-set transaction isolation level read uncommitted;
-
-declare @product_version nvarchar(128)
-declare @product_version_major decimal(10,2)
-declare @product_version_minor decimal(10,2)
-declare @sql_memory_mb int
-declare @os_memory_mb int
-declare @memory_available int
-declare @percent_idle_time real
-declare @percent_processor_time real
-declare @date_snapshot_current datetime
-declare @date_snapshot_previous datetime
-declare @sp_whoisactive_destination_table varchar(255)
-
-declare @sql nvarchar(4000)
-
- --------------------------------------------------------------------------------------------------------------
- -- detect which version of sql we are running as some dmvs are different in different versions of sql
- --------------------------------------------------------------------------------------------------------------
- set @product_version = convert(nvarchar(128),serverproperty('productversioN'));
-
- select
- @product_version_major = substring(@product_version, 1,charindex('.', @product_version) + 1 )
- ,@product_version_minor = parsename(convert(varchar(32), @product_version), 2);
-
- --------------------------------------------------------------------------------------------------------------
- -- get available memory on the server
- --------------------------------------------------------------------------------------------------------------
- select @sql_memory_mb = convert(int,value) from sys.configurations where name = 'max server memory (mb)'
-
- if @product_version_major < 11
- begin
- --sql < 2012
- exec sp_executesql N'select @osmemorymb=physical_memory_in_bytes/1024/1024 from sys.dm_os_sys_info', N'@osmemorymb int out', @os_memory_mb out
- end
- else
- begin
- exec sp_executesql N'select @osmemorymb=physical_memory_kb/1024 from sys.dm_os_sys_info', N'@osmemorymb int out', @os_memory_mb out
- end
-
- select @memory_available=min(memory_available) from (
- select memory_available=@sql_memory_mb
- union all
- select memory_available=@sql_memory_mb
- ) m
-
- --------------------------------------------------------------------------------------------------------------
- -- set the basics
- --------------------------------------------------------------------------------------------------------------
- select @date_snapshot_previous = max([snapshot_time])
- from [dbo].[sql_perf_mon_snapshot_header]
-
- set @date_snapshot_current = getdate();
- insert into [dbo].[sql_perf_mon_snapshot_header]
- values (@date_snapshot_current)
-
-
- --------------------------------------------------------------------------------------------------------------
- -- 1. get cpu
- --------------------------------------------------------------------------------------------------------------
- select
- @percent_processor_time=processutilization
- , @percent_idle_time=systemidle
- FROM (
- SELECT SystemIdle=record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int'),
- ProcessUtilization=record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int')
- FROM (
- SELECT TOP 1 CONVERT(xml, record) AS [record]
- FROM sys.dm_os_ring_buffers WITH (NOLOCK)
- WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR'
- AND record LIKE N'%%'
- ORDER BY [timestamp] DESC
- ) AS x
- ) AS y
- OPTION (RECOMPILE);
-
- --------------------------------------------------------------------------------------------------------------
- -- 2. get perfomance counters
- -- this is where it gets interesting. there are several types of performance counters identified by the cntr_type
- -- depending on the type, we may have to calculate deltas or deviation from the base.
-
- -- cntr_type description from:
- -- https://blogs.msdn.microsoft.com/psssql/2013/09/23/interpreting-the-counter-values-from-sys-dm_os_performance_counters/
- -- https://rtpsqlguy.wordpress.com/2009/08/11/sys-dm_os_performance_counters-explained/
-
- -- 65792 -> this counter value shows the last observed value directly. no calculation required.
- -- 537003264 and 1073939712 -> this is similar to the above 65792 but we must divide the results by the base
- --------------------------------------------------------------------------------------------------------------
-
- insert into dbo.sql_perf_mon_perf_counters
- select
- pc.[object_name]
- ,pc.instance_name
- ,pc.counter_name
- ,pc.cntr_value
- ,base_cntr_value=bc.cntr_value
- ,pc.cntr_type
- ,snapshot_time=@date_snapshot_current
- from (
- select * from sys.dm_os_performance_counters
- union all
- /* becuase we are only querying sql related performance counters (as only those are exposed through sql) we do not
- capture os performance counters such as cpu - hence we captured cpu from ringbuffer and now are going to
- make them look like real counter (othwerwise i would have to make up a name) */
- select
- [object_name] = 'win32_perfformatteddata_perfos_processor'
- ,[counter_name] = 'Processor Time %'
- ,[instance_name] = 'sql'
- ,[cntr_value] = @percent_processor_time
- ,[cntr_type] = 65792
- union all
- select
- [object_name] = 'win32_perfformatteddata_perfos_processor'
- ,[counter_name] = 'Idle Time %'
- ,[instance_name] = '_total'
- ,[cntr_value] = @percent_idle_time
- ,[cntr_type] = 65792
- union all
- select
- [object_name] = 'win32_perfformatteddata_perfos_processor'
- ,[counter_name] = 'Processor Time %'
- ,[instance_name] = 'system'
- ,[cntr_value] = (100-@percent_idle_time-@percent_processor_time)
- ,[cntr_type] = 65792
- ) pc
- inner join dbo.sql_perf_mon_config_perf_counters sc
- on rtrim(pc.[object_name]) like '%' + sc.[object_name]
- and pc.counter_name = sc.counter_name
- and (
- rtrim(pc.instance_name) = sc.instance_name
- or (
- sc.instance_name = '<* !_total>'
- and rtrim(pc.instance_name) <> '_total'
- )
- )
- outer apply (
- select pc2.cntr_value
- from sys.dm_os_performance_counters as pc2
- where pc2.cntr_type = 1073939712
- and pc2.[object_name] = pc.[object_name]
- and pc2.instance_name = pc.instance_name
- and rtrim(pc2.counter_name) = sc.base_counter_name
- ) bc
- where sc.collect = 1
- option (recompile)
-
- --------------------------------------------------------------------------------------------------------------
- -- get process memory
- --------------------------------------------------------------------------------------------------------------
- insert into dbo.sql_perf_mon_os_process_memory
- select snapshot_time=@date_snapshot_current, *
- from sys.dm_os_process_memory
-
- --------------------------------------------------------------------------------------------------------------
- -- get sql memory. dynamic again based on sql version
- --------------------------------------------------------------------------------------------------------------
- declare @dm_os_memory_clerks table (
- [type] varchar(60),
- memory_node_id smallint,
- single_pages_kb bigint,
- multi_pages_kb bigint,
- virtual_memory_reserved_kb bigint,
- virtual_memory_committed_kb bigint,
- awe_allocated_kb bigint,
- shared_memory_reserved_kb bigint,
- shared_memory_committed_kb bigint
- )
- if @product_version_major < 11
- begin
- insert into @dm_os_memory_clerks
- exec sp_executesql N'
- select
- type,
- memory_node_id as memory_node_id,
- -- see comment in the sys.dm_os_memory_nodes query (above) for more info on
- -- [single_pages_kb] and [multi_pages_kb].
- sum(single_pages_kb) as single_pages_kb,
- 0 as multi_pages_kb,
- sum(virtual_memory_reserved_kb) as virtual_memory_reserved_kb,
- sum(virtual_memory_committed_kb) as virtual_memory_committed_kb,
- sum(awe_allocated_kb) as awe_allocated_kb,
- sum(shared_memory_reserved_kb) as shared_memory_reserved_kb,
- sum(shared_memory_committed_kb) as shared_memory_committed_kb
- from sys.dm_os_memory_clerks
- group by type, memory_node_id
- option (recompile)
- '
- end
- else
- begin
- insert into @dm_os_memory_clerks
- exec sp_executesql N'
- select
- type,
- memory_node_id as memory_node_id,
- -- see comment in the sys.dm_os_memory_nodes query (above) for more info on
- -- [single_pages_kb] and [multi_pages_kb].
- sum(pages_kb) as single_pages_kb,
- 0 as multi_pages_kb,
- sum(virtual_memory_reserved_kb) as virtual_memory_reserved_kb,
- sum(virtual_memory_committed_kb) as virtual_memory_committed_kb,
- sum(awe_allocated_kb) as awe_allocated_kb,
- sum(shared_memory_reserved_kb) as shared_memory_reserved_kb,
- sum(shared_memory_committed_kb) as shared_memory_committed_kb
- from sys.dm_os_memory_clerks
- group by type, memory_node_id
- option (recompile)
- '
- end
-
- declare @memory_clerks table (
- [type] varchar(60),
- memory_node_id smallint,
- single_pages_kb bigint,
- multi_pages_kb bigint,
- virtual_memory_reserved_kb bigint,
- virtual_memory_committed_kb bigint,
- awe_allocated_kb bigint,
- shared_memory_reserved_kb bigint,
- shared_memory_committed_kb bigint,
- snapshot_time datetime,
- total_kb bigint
- )
- insert into @memory_clerks
- select
- mc.[type], mc.memory_node_id, mc.single_pages_kb, mc.multi_pages_kb, mc.virtual_memory_reserved_kb,
- mc.virtual_memory_committed_kb, mc.awe_allocated_kb, mc.shared_memory_reserved_kb, mc.shared_memory_committed_kb,
- snapshot_time = @date_snapshot_current,
- cast (mc.single_pages_kb as bigint)
- + mc.multi_pages_kb
- + (case when type <> 'MEMORYCLERK_SQLBUFFERPOOL' then mc.virtual_memory_committed_kb else 0 end)
- + mc.shared_memory_committed_kb as total_kb
- from @dm_os_memory_clerks as mc
-
- insert into dbo.sql_perf_mon_os_memory_clerks
- select
- snapshot_time =@date_snapshot_current,
- total_kb=sum(mc.total_kb),
- allocated_kb=sum(mc.single_pages_kb + mc.multi_pages_kb),
- --ta.total_kb_all_clerks,
- --mc.total_kb / convert(decimal, ta.total_kb_all_clerks) as percent_total_kb,
- sum(ta.total_kb_all_clerks) as total_kb_all_clerks,
- -- there are many memory clerks. we'll chart any that make up 5% of sql memory or more; less significant clerks will be lumped into an "other" bucket
- graph_type=case when mc.total_kb / convert(decimal, ta.total_kb_all_clerks) > 0.05 then mc.[type] else N'other' end
- ,memory_available=@memory_available
- from @memory_clerks as mc
- -- use a self-join to calculate the total memory allocated for each time interval
- join
- (
- select
- snapshot_time = @date_snapshot_current,
- sum (mc_ta.total_kb) as total_kb_all_clerks
- from @memory_clerks as mc_ta
- group by mc_ta.snapshot_time
- ) as ta on (mc.snapshot_time = ta.snapshot_time)
- group by mc.snapshot_time, case when mc.total_kb / convert(decimal, ta.total_kb_all_clerks) > 0.05 then mc.[type] else N'other' end
- --order by snapshot_time
- option (recompile)
-
- delete from @memory_clerks
-
- --------------------------------------------------------------------------------------------------------------
- -- file stats snapshot
- --------------------------------------------------------------------------------------------------------------
- insert into dbo.sql_perf_mon_file_stats
- select
- db_name (f.database_id) as [database_name], f.name as logical_file_name, f.type_desc,
- cast (case
- when left (ltrim (f.physical_name), 2) = '\\'
- then left (ltrim (f.physical_name), charindex ('\', ltrim (f.physical_name), charindex ('\', ltrim (f.physical_name), 3) + 1) - 1)
- when charindex ('\', ltrim(f.physical_name), 3) > 0
- then upper (left (ltrim (f.physical_name), charindex ('\', ltrim (f.physical_name), 3) - 1))
- else f.physical_name
- end as varchar(255)) as logical_disk,
- fs.num_of_reads, fs.num_of_bytes_read, fs.io_stall_read_ms, fs.num_of_writes, fs.num_of_bytes_written,
- fs.io_stall_write_ms, fs.size_on_disk_bytes,
- snapshot_time=@date_snapshot_current
- from sys.dm_io_virtual_file_stats (default, default) as fs
- inner join sys.master_files as f on fs.database_id = f.database_id and fs.[file_id] = f.[file_id]
-
- --------------------------------------------------------------------------------------------------------------
- -- wait stats snapshot
- --------------------------------------------------------------------------------------------------------------
- insert into [dbo].[sql_perf_mon_wait_stats]
- select [wait_type], [waiting_tasks_count], [wait_time_ms],[max_wait_time_ms], [signal_wait_time_ms], [snapshot_time]=@date_snapshot_current
- from sys.dm_os_wait_stats;
-
- --------------------------------------------------------------------------------------------------------------
- -- sp_whoisactive
- -- Please download and install The Great sp_whoisactive from http://whoisactive.com/ and thank Adam Machanic
- -- for the numerous times sp_whoisactive saved our backs.
-
- -- an alternative approach would be to use the SQL deadlock monitor and service broker to record blocking
- -- or deadlocked transactions into a table -- or XE to save to xml - but this could cause trouble parsing large
- -- xmls.
- --------------------------------------------------------------------------------------------------------------
- if object_id('master.dbo.sp_whoisactive') is not null
- begin
- truncate table [dbo].[sql_perf_mon_who_is_active_tmp]
- -- we are running WhoIsActive is very lightweight mode without any additional info and without execution plans
- set @sp_whoisactive_destination_table = quotename(db_name()) + '.[dbo].[sql_perf_mon_who_is_active_tmp]'
- exec dbo.sp_whoisactive
- @get_outer_command = 1
- ,@output_column_list = '[collection_time][start_time][session_id][status][percent_complete][host_name][database_name][program_name][sql_text][sql_command][login_name][open_tran_count][wait_info][blocking_session_id][blocked_session_count][CPU][used_memory][tempdb_current][tempdb_allocations][reads][writes][physical_reads][login_time]'
- ,@find_block_leaders = 1
- ,@destination_table = @sp_whoisactive_destination_table
-
- -- the insert to tmp then actual table approach is required mainly to use our
- -- snapshot_time and enforce referential integrity with the header table and
- -- to apply any additional filtering:
- insert into [dbo].[sql_perf_mon_who_is_active]
- select [snapshot_time] = @date_snapshot_current
- ,[start_time],[session_id],[status],[percent_complete],[host_name]
- ,[database_name],[program_name],[sql_text],[sql_command],[login_name]
- ,[open_tran_count],[wait_info],[blocking_session_id],[blocked_session_count]
- ,[CPU],[used_memory],[tempdb_current],[tempdb_allocations],[reads]
- ,[writes],[physical_reads],[login_time]
- from [dbo].[sql_perf_mon_who_is_active_tmp]
- -- exclude anything that has been running for less that the desired age in seconds (default 60)
- -- this parameterised so feel free to change it to your liking. To change parameter:
- -- update [dbo].[sql_perf_mon_config_who_is_active_age] set [seconds] = x
- where [start_time] < dateadd(s,(select [seconds]*-1.0 from [dbo].[sql_perf_mon_config_who_is_active_age]),getdate())
- -- unless its being blocked or is a blocker
- or [blocking_session_id] is not null or [blocked_session_count] > 0
- end
- else
- begin
- print 'sp_WhoIsActive not found.'
- end
-go
-
---retention procedure
-if not exists (select * from information_schema.routines where routine_name = 'sp_sql_perf_mon_retention')
-exec ('create proc [dbo].[sp_sql_perf_mon_retention] as select ''sp_sql_perf_mon_retention placeholder''')
-go
-
-alter procedure [dbo].[sp_sql_perf_mon_retention] (
- @retention_period_days smallint = 7,
- @batch_size smallint = 500
- )
-as
-set nocount on;
-declare @row_count int = 1
-
-while @row_count > 0
- begin
- begin tran
- delete top (@batch_size)
- from dbo.sql_perf_mon_snapshot_header with (readpast)
- where datediff(day,snapshot_time,getdate()) > @retention_period_days
- set @row_count = @@ROWCOUNT
- commit tran
- end
-go
-
---setup jobs
---we have to switch database to msdb but we also need to know which db jobs should run in so have to capture current database:
-declare @database varchar(255)
-declare @server nvarchar(255)
-set @database = DB_NAME()
-set @server = @@SERVERNAME
-
-USE [msdb]
-
-DECLARE @jobId BINARY(16)
-DECLARE @schedule_id int;
-
-if (select name from sysjobs where name = 'DBA-PERF-LOGGER') is null
- begin
- EXEC msdb.dbo.sp_add_job @job_name=N'DBA-PERF-LOGGER',
- @enabled=1,
- @notify_level_eventlog=0,
- @notify_level_email=2,
- @notify_level_page=2,
- @delete_level=0,
- @category_name=N'Data Collector',
- @owner_login_name=N'sa', @job_id = @jobId OUTPUT;
-
- EXEC msdb.dbo.sp_add_jobserver @job_name=N'DBA-PERF-LOGGER', @server_name = @server;
-
- EXEC msdb.dbo.sp_add_jobstep @job_name=N'DBA-PERF-LOGGER', @step_name=N'DBA-PERF-LOGGER',
- @step_id=1,
- @cmdexec_success_code=0,
- @on_success_action=1,
- @on_fail_action=2,
- @retry_attempts=0,
- @retry_interval=0,
- @os_run_priority=0, @subsystem=N'TSQL',
- @command=N'exec [dbo].[sp_sql_perf_mon_logger]',
- @database_name=@database,
- @flags=0;
-
- EXEC msdb.dbo.sp_update_job @job_name=N'DBA-PERF-LOGGER',
- @enabled=1,
- @start_step_id=1,
- @notify_level_eventlog=0,
- @notify_level_email=2,
- @notify_level_page=2,
- @delete_level=0,
- @description=N'',
- @category_name=N'Data Collector',
- @owner_login_name=N'sa',
- @notify_email_operator_name=N'',
- @notify_page_operator_name=N'';
-
- EXEC msdb.dbo.sp_add_jobschedule @job_name=N'DBA-PERF-LOGGER', @name=N'DBA-PERF-LOGGER',
- @enabled=1,
- @freq_type=4,
- @freq_interval=1,
- @freq_subday_type=4,
- @freq_subday_interval=1,
- @freq_relative_interval=0,
- @freq_recurrence_factor=1,
- @active_start_date=20180804,
- @active_end_date=99991231,
- @active_start_time=12,
- @active_end_time=235959, @schedule_id = @schedule_id OUTPUT;
- end
-
-if (select name from sysjobs where name = 'DBA-PERF-LOGGER-RETENTION') is null
- begin
- set @jobId = null
- EXEC msdb.dbo.sp_add_job @job_name=N'DBA-PERF-LOGGER-RETENTION',
- @enabled=1,
- @notify_level_eventlog=0,
- @notify_level_email=2,
- @notify_level_page=2,
- @delete_level=0,
- @category_name=N'Data Collector',
- @owner_login_name=N'sa', @job_id = @jobId OUTPUT;
-
- EXEC msdb.dbo.sp_add_jobserver @job_name=N'DBA-PERF-LOGGER-RETENTION', @server_name = @server;
-
- EXEC msdb.dbo.sp_add_jobstep @job_name=N'DBA-PERF-LOGGER-RETENTION', @step_name=N'DBA-PERF-LOGGER-RETENTION',
- @step_id=1,
- @cmdexec_success_code=0,
- @on_success_action=1,
- @on_fail_action=2,
- @retry_attempts=0,
- @retry_interval=0,
- @os_run_priority=0, @subsystem=N'TSQL',
- @command=N'exec dbo.sp_sql_perf_mon_retention',
- @database_name=@database,
- @flags=0;
-
- EXEC msdb.dbo.sp_update_job @job_name=N'DBA-PERF-LOGGER-RETENTION',
- @enabled=1,
- @start_step_id=1,
- @notify_level_eventlog=0,
- @notify_level_email=2,
- @notify_level_page=2,
- @delete_level=0,
- @description=N'',
- @category_name=N'Data Collector',
- @owner_login_name=N'sa',
- @notify_email_operator_name=N'',
- @notify_page_operator_name=N'';
-
- set @schedule_id = null
- EXEC msdb.dbo.sp_add_jobschedule @job_name=N'DBA-PERF-LOGGER-RETENTION', @name=N'DBA-PERF-LOGGER-RETENTION',
- @enabled=1,
- @freq_type=4,
- @freq_interval=1,
- @freq_subday_type=8,
- @freq_subday_interval=1,
- @freq_relative_interval=0,
- @freq_recurrence_factor=1,
- @active_start_date=20180804,
- @active_end_date=99991231,
- @active_start_time=20,
- @active_end_time=235959, @schedule_id = @schedule_id OUTPUT
- end
-
-if @@trancount > 0
- commit