diff --git a/SQLWATCHDB/SQLWATCH.sqlproj b/SQLWATCHDB/SQLWATCH.sqlproj index 2ac1a977..2abf2b7a 100644 --- a/SQLWATCHDB/SQLWATCH.sqlproj +++ b/SQLWATCHDB/SQLWATCH.sqlproj @@ -90,6 +90,7 @@ + diff --git a/SQLWATCHDB/Script.PostDeployment1.sql b/SQLWATCHDB/Script.PostDeployment1.sql index 81a4b2f4..1c827f24 100644 --- a/SQLWATCHDB/Script.PostDeployment1.sql +++ b/SQLWATCHDB/Script.PostDeployment1.sql @@ -621,6 +621,17 @@ if (select count(*) from [dbo].[sql_perf_mon_config_report_time_interval]) = 0 -------------------------------------------------------------------------------------- -- -------------------------------------------------------------------------------------- +if (select count(*) from [dbo].[sql_perf_mon_config_snapshot_type]) = 0 + begin + insert into [dbo].[sql_perf_mon_config_snapshot_type] + values (1, 'Performance', 7), + (2, 'Growth', 365) + end + +-------------------------------------------------------------------------------------- +-- +-------------------------------------------------------------------------------------- + --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: diff --git a/SQLWATCHDB/bin/Debug/SQLWATCH.dacpac b/SQLWATCHDB/bin/Debug/SQLWATCH.dacpac index 21474340..017e64ed 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 b245821f..d3c0e280 100644 Binary files a/SQLWATCHDB/bin/Debug/SQLWATCHDB.dll and b/SQLWATCHDB/bin/Debug/SQLWATCHDB.dll differ diff --git a/SQLWATCHDB/dbo/Procedures/sp_sql_perf_mon_logger.sql b/SQLWATCHDB/dbo/Procedures/sp_sql_perf_mon_logger.sql index a24f09a7..00cb72b1 100644 --- a/SQLWATCHDB/dbo/Procedures/sp_sql_perf_mon_logger.sql +++ b/SQLWATCHDB/dbo/Procedures/sp_sql_perf_mon_logger.sql @@ -51,10 +51,11 @@ declare @sql nvarchar(4000) -------------------------------------------------------------------------------------------------------------- select @date_snapshot_previous = max([snapshot_time]) from [dbo].[sql_perf_mon_snapshot_header] + where snapshot_type_id = 1 set @date_snapshot_current = getdate(); insert into [dbo].[sql_perf_mon_snapshot_header] - values (@date_snapshot_current) + values (@date_snapshot_current, 1) -------------------------------------------------------------------------------------------------------------- @@ -98,6 +99,7 @@ declare @sql nvarchar(4000) ,base_cntr_value=bc.cntr_value ,pc.cntr_type ,snapshot_time=@date_snapshot_current + , 1 from ( select * from sys.dm_os_performance_counters union all @@ -150,7 +152,7 @@ declare @sql nvarchar(4000) -- get process memory -------------------------------------------------------------------------------------------------------------- insert into dbo.sql_perf_mon_os_process_memory - select snapshot_time=@date_snapshot_current, * + select snapshot_time=@date_snapshot_current, * , 1 from sys.dm_os_process_memory -------------------------------------------------------------------------------------------------------------- @@ -245,6 +247,7 @@ declare @sql nvarchar(4000) -- 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 + , 1 from @memory_clerks as mc -- use a self-join to calculate the total memory allocated for each time interval join @@ -277,13 +280,14 @@ declare @sql nvarchar(4000) 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 + , 1 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 + select [wait_type], [waiting_tasks_count], [wait_time_ms],[max_wait_time_ms], [signal_wait_time_ms], [snapshot_time]=@date_snapshot_current, 1 from sys.dm_os_wait_stats; -------------------------------------------------------------------------------------------------------------- -- sp_whoisactive @@ -312,7 +316,7 @@ declare @sql nvarchar(4000) ,[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] + ,[writes],[physical_reads],[login_time], 1 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: diff --git a/SQLWATCHDB/dbo/Procedures/sp_sql_perf_mon_retention.sql b/SQLWATCHDB/dbo/Procedures/sp_sql_perf_mon_retention.sql index b63006e0..44fc5c83 100644 --- a/SQLWATCHDB/dbo/Procedures/sp_sql_perf_mon_retention.sql +++ b/SQLWATCHDB/dbo/Procedures/sp_sql_perf_mon_retention.sql @@ -1,5 +1,6 @@ CREATE PROCEDURE [dbo].[sp_sql_perf_mon_retention]( - @retention_period_days smallint = 7, + --this is only kept for backward compatibility so we dont have to change existing jobs for now: + @retention_period_days smallint = 7, @batch_size smallint = 500 ) as @@ -9,10 +10,18 @@ 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 + delete top (@batch_size) + from dbo.sql_perf_mon_snapshot_header + where exists ( + select sh.[snapshot_time], sh.snapshot_type_id, st.snapshot_retention_days + from dbo.sql_perf_mon_snapshot_header sh + inner join [dbo].[sql_perf_mon_config_snapshot_type] st + on sh.[snapshot_type_id] = st.[snapshot_type_id] + where datediff(day,sh.snapshot_time,getdate()) > st.snapshot_retention_days + and dbo.sql_perf_mon_snapshot_header.[snapshot_time] = sh.[snapshot_time] + and dbo.sql_perf_mon_snapshot_header.snapshot_type_id = sh.snapshot_type_id + ) + set @row_count = @@ROWCOUNT commit tran end go \ No newline at end of file diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_config_snapshot_header_type.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_config_snapshot_header_type.sql new file mode 100644 index 00000000..1c64d8a1 --- /dev/null +++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_config_snapshot_header_type.sql @@ -0,0 +1,6 @@ +CREATE TABLE [dbo].[sql_perf_mon_config_snapshot_type] +( + [snapshot_type_id] tinyint NOT NULL PRIMARY KEY, + [snapshot_type_desc] varchar(255) not null, + [snapshot_retention_days] smallint not null, +) diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_file_stats.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_file_stats.sql index af53b08d..c71ca675 100644 --- a/SQLWATCHDB/dbo/Tables/sql_perf_mon_file_stats.sql +++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_file_stats.sql @@ -11,7 +11,9 @@ [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, + [snapshot_time] datetime not null, + [snapshot_type_id] tinyint not null default 1 , + constraint fk_sql_perf_mon_file_stats_snapshot_header foreign key ([snapshot_time],[snapshot_type_id]) references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time],[snapshot_type_id]) on delete cascade , constraint pk_sql_perf_mon_file_stats primary key clustered ( [snapshot_time], [database_name], [logical_file_name], [type_desc] ) diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_os_memory_clerks.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_os_memory_clerks.sql index 830fec8a..72a5e78b 100644 --- a/SQLWATCHDB/dbo/Tables/sql_perf_mon_os_memory_clerks.sql +++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_os_memory_clerks.sql @@ -1,11 +1,13 @@ 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, + [snapshot_time] datetime not null, [total_kb] bigint, [allocated_kb] bigint, [total_kb_all_clerks] bigint, [clerk_name] varchar(255), [memory_available] int, + [snapshot_type_id] tinyint not null default 1 , + constraint fk_sql_perf_mon_os_memory_clerks_snapshot_header foreign key ([snapshot_time],[snapshot_type_id]) references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time],[snapshot_type_id]) on delete cascade , constraint [pk_sql_perf_mon_os_memory_clerks] primary key ( [snapshot_time], [clerk_name] ) diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_os_process_memory.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_os_process_memory.sql index bdf47df1..b8f002b6 100644 --- a/SQLWATCHDB/dbo/Tables/sql_perf_mon_os_process_memory.sql +++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_os_process_memory.sql @@ -13,15 +13,10 @@ [available_commit_limit_kb] [bigint] NOT NULL, [process_physical_memory_low] [bit] NOT NULL, [process_virtual_memory_low] [bit] NOT NULL, -PRIMARY KEY CLUSTERED -( - [snapshot_time] ASC -)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] -) ON [PRIMARY] -GO -ALTER TABLE [dbo].[sql_perf_mon_os_process_memory] WITH CHECK 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 -GO -ALTER TABLE [dbo].[sql_perf_mon_os_process_memory] CHECK CONSTRAINT [fk_sql_perf_mon_os_process_memory] + [snapshot_type_id] tinyint not null default 1 , + constraint fk_sql_perf_mon_os_process_memory_snapshot_header foreign key ([snapshot_time],[snapshot_type_id]) references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time],[snapshot_type_id]) on delete cascade , + constraint pk_sql_perf_mon_os_process_memory primary key clustered ( + [snapshot_time] ASC + ) +) GO diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_perf_counters.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_perf_counters.sql index 899e6b4c..4497c2a5 100644 --- a/SQLWATCHDB/dbo/Tables/sql_perf_mon_perf_counters.sql +++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_perf_counters.sql @@ -6,6 +6,8 @@ [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, + [snapshot_time] datetime not null, + [snapshot_type_id] tinyint not null default 1 , + constraint fk_sql_perf_mon_perf_counters_snapshot_header foreign key ([snapshot_time],[snapshot_type_id]) references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time],[snapshot_type_id]) on delete cascade , constraint [pk_sql_perf_mon_perf_counters] primary key ([snapshot_time] asc, [object_name] asc, [counter_name] asc, [instance_name] asc) ) diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_snapshot_header.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_snapshot_header.sql index 1827b38d..5e23dc17 100644 --- a/SQLWATCHDB/dbo/Tables/sql_perf_mon_snapshot_header.sql +++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_snapshot_header.sql @@ -1,4 +1,12 @@ CREATE TABLE [dbo].[sql_perf_mon_snapshot_header] ( - [snapshot_time] datetime primary key + [snapshot_time] datetime, + [snapshot_type_id] tinyint not null default 1 foreign key references dbo.[sql_perf_mon_config_snapshot_type]([snapshot_type_id]), + CONSTRAINT pk_snapshot PRIMARY KEY ( + [snapshot_time],[snapshot_type_id] + ) ) +go + +create nonclustered index idx_snapshot_type_id on [dbo].[sql_perf_mon_snapshot_header]([snapshot_type_id]) +go \ No newline at end of file diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_wait_stats.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_wait_stats.sql index 9d5263a8..14cc096c 100644 --- a/SQLWATCHDB/dbo/Tables/sql_perf_mon_wait_stats.sql +++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_wait_stats.sql @@ -5,7 +5,9 @@ [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, + [snapshot_time] datetime not null, + [snapshot_type_id] tinyint not null default 1 , + constraint fk_sql_perf_mon_wait_stats_snapshot_header foreign key ([snapshot_time],[snapshot_type_id]) references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time],[snapshot_type_id]) on delete cascade , constraint [pk_sql_perf_mon_wait_stats] primary key ( [snapshot_time] asc, [wait_type] asc ) diff --git a/SQLWATCHDB/dbo/Tables/sql_perf_mon_who_is_active.sql b/SQLWATCHDB/dbo/Tables/sql_perf_mon_who_is_active.sql index 258fc3f5..ec713a10 100644 --- a/SQLWATCHDB/dbo/Tables/sql_perf_mon_who_is_active.sql +++ b/SQLWATCHDB/dbo/Tables/sql_perf_mon_who_is_active.sql @@ -1,3 +1,9 @@ -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 table [dbo].[sql_perf_mon_who_is_active] ( + [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, + [snapshot_type_id] tinyint not null default 1 , + constraint fk_sql_perf_mon_who_is_active_snapshot_header foreign key ([snapshot_time],[snapshot_type_id]) references [dbo].[sql_perf_mon_snapshot_header]([snapshot_time],[snapshot_type_id]) on delete cascade , + ) go create nonclustered index idx_whoisactive on [dbo].[sql_perf_mon_who_is_active] ([snapshot_time])