Skip to content

Commit

Permalink
configurable baselines
Browse files Browse the repository at this point in the history
  • Loading branch information
marcingminski committed Apr 8, 2021
1 parent 25036d3 commit 7abde20
Show file tree
Hide file tree
Showing 7 changed files with 195 additions and 34 deletions.
Expand Up @@ -2625,4 +2625,11 @@
<Property Name="ParentElementType" Value="SqlSchema" />
<Property Name="NewName" Value="[sqlwatch_exec]" />
</Operation>
<Operation Name="Rename Refactor" Key="8d1c3af4-6405-4f81-82a4-124fedeab4c0" ChangeDateTime="04/08/2021 11:03:00">
<Property Name="ElementName" Value="[dbo].[sqlwatch_meta_retention]" />
<Property Name="ElementType" Value="SqlTable" />
<Property Name="ParentElementName" Value="[dbo]" />
<Property Name="ParentElementType" Value="SqlSchema" />
<Property Name="NewName" Value="[sqlwatch_meta_baseline]" />
</Operation>
</Operations>
2 changes: 2 additions & 0 deletions SqlWatch.Monitor/Project.SqlWatch.Database/SQLWATCH.sqlproj
Expand Up @@ -344,6 +344,8 @@
<Build Include="dbo\Services\sqlwatch_exec.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_broker_diagnostics.sql" />
<Build Include="dbo\Tables\sqlwatch_config_baseline.sql" />
<Build Include="dbo\Tables\sqlwatch_meta_baseline.sql" />
<Build Include="dbo\Tables\sqlwatch_meta_snapshot_header_baseline.sql" />
</ItemGroup>
<ItemGroup>
<PostDeploy Include="Script.PostDeployment1.sql" />
Expand Down
@@ -1,4 +1,4 @@
-- Generated by MsBuild Step - DO NOT EDIT
:setvar DacVersion "
3.1.0.21269
3.1.0.23812
"
@@ -1,37 +1,6 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_retention]
as

/*
-------------------------------------------------------------------------------------------------------------------
Procedure:
usp_sqlwatch_internal_retention
Description:
Process retention of each snapshot based on the snapshot_retention_days.
Deleting from the header [sqlwatch_logger_snapshot_header] will also delete from child tables through cascade
action. To avoid blowing transaction logs we have running batches of 500 rows by default. This can be adjusted
by passing different batch size as a parameter. This procedure should run every hour so there is never too
much to delete. Do not leave this to run once a day or once a week, the more often it runs the less it will do.
Average execution does not exceed few seconds.
Parameters
N/A
Author:
Marcin Gminski
Change Log:
1.0 2019-08 - Marcin Gminski, Initial version
1.1 2019-11-29 - Marcin Gminski, Ability to only leave most recent snapshot with -1 retention
1.2 2019-12-07 - Marcin Gminski, Added retention of the action queue
1.3 2019-12-09 - Marcin Gminski, build deletion keys out of the loop to improve loop performance and reduce contention
1.4 2019-12-31 - Marcin Gminski, changed hardcoded to configurable retention periods for non-logger tables,
replaced input parameters with global config
1.5 2020-02-18 - Marcin Gminski, fixed an issue where retention would not be correctly applied due to null variables,
code cleanse
1.6 2020-05-13 - Marcin Gminski, batch up app_log retention
-------------------------------------------------------------------------------------------------------------------
*/
set nocount on;
set xact_abort on;

Expand All @@ -40,7 +9,8 @@ declare @snapshot_type_id tinyint,
@row_count int,
@action_queue_retention_days_failed smallint,
@action_queue_retention_days_success smallint,
@application_log_retention_days smallint
@application_log_retention_days smallint,
@sql_instance varchar(32) = dbo.ufn_sqlwatch_get_servername();

select @batch_size = [dbo].[ufn_sqlwatch_get_config_value](6, null)
select @action_queue_retention_days_failed = [dbo].[ufn_sqlwatch_get_config_value](3, null)
Expand Down Expand Up @@ -94,6 +64,12 @@ while @row_count > 0
and h.sql_instance = c.sql_instance
and h.snapshot_type_id = c.snapshot_type_id

-- do not remove baseline snapshots:
where h.snapshot_time not in (
select snapshot_time
from [dbo].[sqlwatch_meta_snapshot_header_baseline]
)

set @row_count = @@ROWCOUNT
print 'Deleted ' + convert(varchar(max),@row_count) + ' records from [dbo].[sqlwatch_logger_snapshot_header]'
commit tran
Expand Down Expand Up @@ -123,7 +99,7 @@ while @row_count > 0

set @snapshot_type_id = 1 --Performance Counters
delete from [dbo].[sqlwatch_trend_perf_os_performance_counters]
where sql_instance = @@SERVERNAME
where sql_instance = @sql_instance
and getutcdate() > valid_until
Print 'Deleted ' + convert(varchar(max),@@ROWCOUNT) + ' records from [dbo].[sqlwatch_trend_perf_os_performance_counters]'

Expand Down
@@ -0,0 +1,131 @@
CREATE TABLE [dbo].[sqlwatch_config_baseline]
(
baseline_id smallint not null identity(1,1),
baseline_start datetime2(0) not null,
baseline_end datetime2(0) not null,
[is_default] bit not null,
[comments] varchar(max) null,

constraint pk_sqlwatch_config_baseline
primary key clustered (baseline_id)

)
go

CREATE UNIQUE INDEX idx_sqlwatch_config_baseline_default
ON [dbo].[sqlwatch_config_baseline] ([is_default])
WHERE [is_default] = 1
GO

CREATE UNIQUE INDEX idx_sqlwatch_config_baseline_dates
ON [dbo].[sqlwatch_config_baseline] (baseline_start, baseline_end)
GO

create trigger trg_sqlwatch_config_baseline_meta_add
on [dbo].[sqlwatch_config_baseline]
for insert
as
begin
declare @sql_instance varchar(32) = dbo.ufn_sqlwatch_get_servername();

insert into [dbo].[sqlwatch_meta_baseline] (sql_instance, baseline_id, baseline_start, baseline_end, [is_default], [comments], [date_updated])
select @sql_instance
, inserted.baseline_id
, inserted.baseline_start
, inserted.baseline_end
, inserted.is_default
, inserted.comments
, GETUTCDATE()
from inserted

--SQL Server does not support per-row triggers but we have to iterate through every inserted row here to load header based on baseline dates.
--Whilst cusors in triggers are genearally bad approach, this will not be run very often as the baselines should never change often.

declare @baseline_start datetime2(0),
@baseline_end datetime2(0),
@baseline_id smallint

declare cur_insert cursor for

select baseline_id, baseline_start, baseline_end
from inserted

open cur_insert
fetch next from cur_insert
into @baseline_id, @baseline_start, @baseline_end

while @@FETCH_STATUS = 0
begin

insert into [dbo].[sqlwatch_meta_snapshot_header_baseline] with (tablock) (
baseline_id
, snapshot_time
, sql_instance
)
select distinct @baseline_id, snapshot_time, @sql_instance
from dbo.sqlwatch_logger_snapshot_header h
where sql_instance = @sql_instance
and snapshot_time between @baseline_start and @baseline_end

fetch next from cur_insert
into @baseline_id, @baseline_start, @baseline_end
end

close cur_insert
deallocate cur_insert
end
go

create trigger trg_sqlwatch_config_baseline_meta_remove
on [dbo].[sqlwatch_config_baseline]
for delete
as
begin
declare @sql_instance varchar(32) = dbo.ufn_sqlwatch_get_servername();

delete m
from [dbo].[sqlwatch_meta_baseline] m
inner join deleted d
on m.baseline_id = d.baseline_id
and m.sql_instance = @sql_instance

end
go

create trigger trg_sqlwatch_config_baseline_meta_update
on [dbo].[sqlwatch_config_baseline]
instead of update
as
begin

--updating baseline dates will not be supported, only the default flag and comments
--to update baseline dates we need to remove and recreate the baseline so we can ring fence new data set

if exists (
select *
from inserted i
inner join deleted d
on d.baseline_id = i.baseline_id
and (
d.baseline_start <> i.baseline_start
or d.baseline_end <> i.baseline_end
)
)
begin
raiserror('Changes to the baseline dates are not allowed. To modify baseline dates create new baseline and delete the old one.', 16,1);
end
else
begin
declare @sql_instance varchar(32) = dbo.ufn_sqlwatch_get_servername();

update m
set is_default = i.is_default,
comments = i.comments

from [dbo].[sqlwatch_meta_baseline] m
inner join inserted i
on m.baseline_id = i.baseline_id
and m.sql_instance = @sql_instance
end
end
go
@@ -0,0 +1,27 @@
CREATE TABLE [dbo].[sqlwatch_meta_baseline]
(
[baseline_id] smallint not null,
sql_instance varchar(32) not null,
baseline_start datetime2(0) not null,
baseline_end datetime2(0) not null,
[is_default] bit not null,
[comments] varchar(max) null,
[date_updated] datetime not null,

constraint pk_sqlwatch_meta_baseline primary key clustered (
[baseline_id], sql_instance
),

constraint fk_sqlwatch_meta_retention_sql_instance foreign key (sql_instance)
references dbo.sqlwatch_config_sql_instance ([sql_instance]) on delete cascade
)
GO

CREATE UNIQUE INDEX idx_sqlwatch_meta_retention_default
ON [dbo].[sqlwatch_meta_baseline] (sql_instance, [is_default])
WHERE [is_default] = 1
GO

CREATE UNIQUE INDEX idx_sqlwatch_meta_baseline_dates
ON [dbo].[sqlwatch_meta_baseline] (baseline_start, baseline_end, sql_instance)
GO
@@ -0,0 +1,18 @@
CREATE TABLE [dbo].[sqlwatch_meta_snapshot_header_baseline]
(
[baseline_id] smallint not null,
[snapshot_time] datetime2(0) not null,
[sql_instance] varchar(32) not null,

constraint pk_sqlwatch_meta_snapshot_header_baseline
primary key clustered ([baseline_id], [snapshot_time], [sql_instance]),

constraint fk_sqlwatch_meta_snapshot_header_baseline_meta
foreign key ([baseline_id], [sql_instance])
references dbo.sqlwatch_meta_baseline ([baseline_id], [sql_instance]) on delete cascade
)
go

create index idx_sqlwatch_meta_snapshot_header_baseline_1
on [dbo].[sqlwatch_meta_snapshot_header_baseline] ([snapshot_time])
go

0 comments on commit 7abde20

Please sign in to comment.