Skip to content

Commit

Permalink
Broker poc (#246)
Browse files Browse the repository at this point in the history
* proof of concept for broker based procedure activation.

* poc with pre-set timers

* few tweaks to timers and added async execution

* added graceful conversation ending

* removed print as it floods errorlog when run via broker

* fixed wording

* improved conversation ending

* added proc to restart queues. should never be required but good to have just in case

* moved disk utilistaion collector to queue
  • Loading branch information
marcingminski committed Apr 6, 2021
1 parent db74946 commit 4a25335
Show file tree
Hide file tree
Showing 28 changed files with 432 additions and 3 deletions.
Expand Up @@ -2604,4 +2604,11 @@
<Property Name="ParentElementType" Value="SqlTable" />
<Property Name="NewName" Value="[interval_minutes]" />
</Operation>
<Operation Name="Rename Refactor" Key="047e1d58-6224-4f33-9d8f-e55e7210300c" ChangeDateTime="04/04/2021 12:37:32">
<Property Name="ElementName" Value="[dbo].[usp_sqlwatch_internal_exec_activated_invoke]" />
<Property Name="ElementType" Value="SqlProcedure" />
<Property Name="ParentElementName" Value="[dbo]" />
<Property Name="ParentElementType" Value="SqlSchema" />
<Property Name="NewName" Value="[usp_sqlwatch_internal_exec_activated_async]" />
</Operation>
</Operations>
28 changes: 28 additions & 0 deletions SqlWatch.Monitor/Project.SqlWatch.Database/SQLWATCH.sqlproj
Expand Up @@ -33,6 +33,9 @@
<DacVersion>3.0.0.0</DacVersion>
<DefaultCollation>Latin1_General_CI_AS</DefaultCollation>
<TargetFrameworkProfile />
<ServiceBrokerOption>EnableBroker</ServiceBrokerOption>
<Trustworthy>True</Trustworthy>
<EnableFullTextSearch>False</EnableFullTextSearch>
</PropertyGroup>
<PropertyGroup Condition=" '$(Configuration)|$(Platform)' == 'Release|AnyCPU' ">
<OutputPath>bin\Release\</OutputPath>
Expand Down Expand Up @@ -84,6 +87,8 @@
<Folder Include="Scripts\HotFixes" />
<Folder Include="Scripts\Data Migrations" />
<Folder Include="Scripts\Tools\SSIS Helpers" />
<Folder Include="dbo\Queues" />
<Folder Include="dbo\Services" />
</ItemGroup>
<ItemGroup>
<Build Include="dbo\Tables\sqlwatch_logger_snapshot_header.sql" />
Expand Down Expand Up @@ -325,6 +330,29 @@
<Build Include="dbo\Tables\sqlwatch_logger_hadr_database_replica_states.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_logger_hadr_database_replica_states.sql" />
<Build Include="dbo\Views\vw_sqlwatch_report_hadr_database_replica_states.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_exec_activated.sql" />
<Build Include="dbo\Tables\sqlwatch_config_activated_procedures.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_exec_activated_async.sql" />
<Build Include="dbo\Queues\sqlwatch_invoke_5s.sql" />
<Build Include="dbo\Queues\sqlwatch_invoke_1m.sql" />
<Build Include="dbo\Queues\sqlwatch_invoke_60m.sql" />
<Build Include="dbo\Queues\sqlwatch_invoke_10m.sql" />
<Build Include="dbo\Services\sqlwatch_invoke_10m.sql" />
<Build Include="dbo\Services\sqlwatch_invoke_1m.sql" />
<Build Include="dbo\Services\sqlwatch_invoke_5s.sql" />
<Build Include="dbo\Services\sqlwatch_invoke_60m.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_activation_10m.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_activation_1m.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_activation_5s.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_activation_60m.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_10m.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_1m.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_5s.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_60m.sql" />
<Build Include="dbo\Queues\sqlwatch_exec_async.sql" />
<Build Include="dbo\Services\sqlwatch_exec_async.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_activated_activation_async.sql" />
<Build Include="dbo\Procedures\usp_sqlwatch_internal_restart_queues.sql" />
<Build Include="dbo\Tables\sqlwatch_stage_ring_buffer.sql" />
<Build Include="dbo\Functions\ufn_sqlwatch_convert_datetimeoffset_to_local.sql" />
</ItemGroup>
Expand Down
Expand Up @@ -117,4 +117,9 @@ if (select case when @@VERSION like '%Express Edition%' then 1 else 0 end) = 0
-------------------------------------------------------------------------------------
-- Make Constraints Trusted Again
-------------------------------------------------------------------------------------
:r .\Scripts\Post-Deployment\Data-Fixes\Script.PostDeployment-FixNonTrustedConstraints.sql
:r .\Scripts\Post-Deployment\Data-Fixes\Script.PostDeployment-FixNonTrustedConstraints.sql

-------------------------------------------------------------------------------------
-- Retart queues
-------------------------------------------------------------------------------------
exec [dbo].[usp_sqlwatch_internal_restart_queues]
@@ -1,4 +1,4 @@
-- Generated by MsBuild Step - DO NOT EDIT
:setvar DacVersion "
3.1.0.37787
"
"
@@ -0,0 +1,4 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_10m]
AS
exec dbo.usp_sqlwatch_logger_agent_job_history
exec dbo.usp_sqlwatch_logger_procedure_stats
@@ -0,0 +1,12 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_1m]
AS

-- execute async via broker:
exec [dbo].[usp_sqlwatch_internal_exec_activated_async] @procedure_name = 'dbo.usp_sqlwatch_internal_process_checks';
exec [dbo].[usp_sqlwatch_internal_exec_activated_async] @procedure_name = 'dbo.usp_sqlwatch_logger_hadr_database_replica_states';

-- execute in sequence:
exec dbo.usp_sqlwatch_logger_xes_waits
exec dbo.usp_sqlwatch_logger_xes_blockers
exec dbo.usp_sqlwatch_logger_xes_diagnostics
exec dbo.usp_sqlwatch_logger_xes_long_queries
@@ -0,0 +1,3 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_5s]
AS
exec dbo.usp_sqlwatch_logger_performance
@@ -0,0 +1,23 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_60m]
AS

--execute async via broker:
exec [dbo].[usp_sqlwatch_internal_exec_activated_async] @procedure_name = 'dbo.usp_sqlwatch_internal_retention';
exec [dbo].[usp_sqlwatch_internal_exec_activated_async] @procedure_name = 'dbo.usp_sqlwatch_internal_purge_deleted_items';

--execute in sequence:
exec dbo.usp_sqlwatch_internal_add_database;
exec dbo.usp_sqlwatch_internal_add_master_file;
exec dbo.usp_sqlwatch_internal_add_table;
exec dbo.usp_sqlwatch_internal_add_job;
exec dbo.usp_sqlwatch_internal_add_performance_counter;
exec dbo.usp_sqlwatch_internal_add_memory_clerk;
exec dbo.usp_sqlwatch_internal_add_wait_type;
exec dbo.usp_sqlwatch_internal_expand_checks;

exec dbo.usp_sqlwatch_logger_disk_utilisation;

--trends:
exec dbo.usp_sqlwatch_trend_perf_os_performance_counters @interval_minutes = 1, @valid_days = 7
exec dbo.usp_sqlwatch_trend_perf_os_performance_counters @interval_minutes = 5, @valid_days = 90
exec dbo.usp_sqlwatch_trend_perf_os_performance_counters @interval_minutes = 60, @valid_days = 720
@@ -0,0 +1,6 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_activation_10m]
AS
EXEC [dbo].[usp_sqlwatch_internal_exec_activated]
@queue = '[dbo].[sqlwatch_invoke_10m]',
@procedure_name = '[dbo].[usp_sqlwatch_internal_activated_10m]',
@timer = 600
@@ -0,0 +1,6 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_activation_1m]
AS
EXEC [dbo].[usp_sqlwatch_internal_exec_activated]
@queue = '[dbo].[sqlwatch_invoke_1m]',
@procedure_name = '[dbo].[usp_sqlwatch_internal_activated_1m]',
@timer = 60
@@ -0,0 +1,6 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_activation_5s]
AS
EXEC [dbo].[usp_sqlwatch_internal_exec_activated]
@queue = '[dbo].[sqlwatch_invoke_5s]',
@procedure_name = '[dbo].[usp_sqlwatch_internal_activated_5s]',
@timer = 5
@@ -0,0 +1,7 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_activation_60m]
AS

EXEC [dbo].[usp_sqlwatch_internal_exec_activated]
@queue = '[dbo].[sqlwatch_invoke_60m]',
@procedure_name = '[dbo].[usp_sqlwatch_internal_activated_60m]',
@timer = 3600
@@ -0,0 +1,6 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_activated_activation_async]
AS

EXEC [dbo].[usp_sqlwatch_internal_exec_activated]
@queue = '[dbo].[sqlwatch_exec_async]',
@procedure_name = null
@@ -0,0 +1,126 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_exec_activated]
@queue nvarchar(128),
@procedure_name nvarchar(128) = null,
@timer int = null
as
begin
set nocount on;

if @timer is null and @queue not like '%sqlwatch_exec_async%'
begin
-- no timer given but queue given, assume we're specifying queue other than the exec async and we should have a timer
Print 'Timer must be specified for queues other than [dbo].[sqlwatch_exec_async]'
return
end



declare @conversation_handle uniqueidentifier,
@message_type_name nvarchar(128),
@message_body xml,
@error_number int,
@error_message nvarchar(max),
@this_procedure_name nvarchar(128),
@sql nvarchar(max),
@sql_params nvarchar(max)

begin try;

set @this_procedure_name = OBJECT_NAME(@@PROCID);

-- get items from our queue
set @sql = '
receive top(1)
@conversation_handle_out = [conversation_handle]
, @message_type_name_out = [message_type_name]
, @message_body_out = cast([message_body] as xml)
from ' + @queue;

set @sql_params = N'@conversation_handle_out uniqueidentifier OUT, @message_type_name_out nvarchar(128) OUT, @message_body_out xml OUT';

exec sp_executesql
@sql
, @sql_params
, @conversation_handle_out = @conversation_handle OUT
, @message_type_name_out = @message_type_name OUT
, @message_body_out = @message_body OUT

-- if procedure not passed, parse the message body and extract the procedure name.
-- this will only work if we have put a message out that contains the body.
-- this will not work for timer based conversations as they don't carry the payload.
if @procedure_name is null
begin
set @procedure_name = @message_body.value('(//procedure/name)[1]', 'nvarchar(128)');
end

if @conversation_handle is not null and @procedure_name is not null
begin
--put out another timer for timed messages, otherwise just execute async:
if @message_type_name = N'http://schemas.microsoft.com/SQL/ServiceBroker/DialogTimer'
begin
if @timer is not null
begin
begin conversation timer (@conversation_handle) timeout = @timer;
end
else
begin
Print 'Message of type DialogTimer must have a @timer'
return
end
end


begin try
exec @procedure_name;
end try
begin catch
select @error_number = ERROR_NUMBER(),
@error_message = ERROR_MESSAGE()

if @@TRANCOUNT > 0
begin
rollback
end
end conversation @conversation_handle
raiserror(N'Error whilst executing SQLWATCH Procedure %s: %i: %s', 16, 10, @procedure_name, @error_number, @error_message);
end catch

if @message_type_name = N'http://schemas.microsoft.com/SQL/ServiceBroker/Error'
begin
-- we should get the error content from the broker here and output to the errorlog
select
@error_message = @message_body.value ('(/Error/Description)[1]', 'nvarchar(4000)')
, @error_number = @message_body.value ('(/Error/Code)[1]', 'int')
print 'The converstaion ' + convert(varchar(max),@conversation_handle) + ' has returned an error (' + convert(varchar(10),@error_number) + ') ' + @error_message

end conversation @conversation_handle
end

if (
@message_type_name = N'http://schemas.microsoft.com/SQL/ServiceBroker/EndDialog'
or @message_type_name = N'DEFAULT'
)
begin
end conversation @conversation_handle
end
end
else
begin
if @@TRANCOUNT > 0
begin
rollback
end
--raiserror(N'Variable @procedure_name in %s is null', 10, 10, @this_procedure_name);
end
end try
begin catch
select @error_number = ERROR_NUMBER(),
@error_message = ERROR_MESSAGE()

if @@TRANCOUNT > 0
begin
rollback;
end
raiserror(N'Error whilst executing SQLWATCH Procedure %s: %i: %s', 16, 10, @this_procedure_name, @error_number, @error_message);
end catch
end
@@ -0,0 +1,21 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_exec_activated_async]
@procedure_name nvarchar(128)
as

declare @conversation_handle uniqueidentifier,
@xmlBody xml;

set @xmlBody = (
select @procedure_name as [name]
for xml path('procedure')
, type);

begin dialog conversation @conversation_handle
from service sqlwatch_exec_async
to service N'sqlwatch_exec_async', N'current database'
with encryption = off,
lifetime = 60;

send on conversation @conversation_handle (@xmlBody);


Expand Up @@ -288,7 +288,7 @@ SET ANSI_WARNINGS OFF
@snapshot_time_new = @snapshot_time_action OUTPUT,
@snapshot_type_id = @snapshot_type_id_action

Print 'Processing actions for check.'
--Print 'Processing actions for check.'
end

fetch next from cur_actions
Expand Down
@@ -0,0 +1,63 @@
CREATE PROCEDURE [dbo].[usp_sqlwatch_internal_restart_queues]
as

declare @sql varchar(max) = '';

-- disable all queues:
select @sql = @sql + 'ALTER QUEUE ' + name + ' WITH STATUS = OFF;' + char(10)
from sys.service_queues
where name like 'sqlwatch%'

exec (@sql)

waitfor delay '00:00:05'

-- clean up all conversations:
-- Stop and clean all sqlwatch conversations in the database.
-- Whilst this is not normally recommended as it may abrubtly stopped all conversations, it is safe here as we have stopped all queues above.
set @sql = ''
select @sql = @sql + '
end conversation ''' + convert(varchar(max),conversation_handle) + ''' WITH CLEANUP;'
from sys.conversation_endpoints
where far_service like 'sqlwatch%'

exec (@sql)

waitfor delay '00:00:05'

--restart queues
select @sql = @sql + 'ALTER QUEUE ' + name + ' WITH STATUS = ON;' + char(10)
from sys.service_queues
where name like 'sqlwatch%'

exec (@sql)

waitfor delay '00:00:05'

--reseed timer queues
declare @conversation_handle uniqueidentifier;

begin dialog conversation @conversation_handle
from service sqlwatch_invoke_5s
to service N'sqlwatch_invoke_5s', N'current database'
with encryption = off;
begin conversation timer (@conversation_handle) timeout = 5;

begin dialog conversation @conversation_handle
from service sqlwatch_invoke_1m
to service N'sqlwatch_invoke_1m', N'current database'
with encryption = off;
begin conversation timer (@conversation_handle) timeout = 60;

begin dialog conversation @conversation_handle
from service sqlwatch_invoke_10m
to service N'sqlwatch_invoke_10m', N'current database'
with encryption = off;
begin conversation timer (@conversation_handle) timeout = 600;

begin dialog conversation @conversation_handle
from service sqlwatch_invoke_60m
to service N'sqlwatch_invoke_60m', N'current database'
with encryption = off;
begin conversation timer (@conversation_handle) timeout = 3600;

0 comments on commit 4a25335

Please sign in to comment.