Commit 2556f709 authored by dwentzel's avatar dwentzel

ServiceBrokerEnable

parent 93109430
Contents of Repo
ServiceBrokerEnable.sql : http://www.davewentzel.com/content/service-broker-setup-routine. Setting up Service Broker can be daunting for
a SB noob. This script handles a lot of the confusion, especially around when to ENABLE_BROKER vs NEW_BROKER.
\ No newline at end of file
if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].ServiceBrokerEnable'))
drop proc [dbo].ServiceBrokerEnable
GO
SET ANSI_NULLS ON;
SET QUOTED_IDENTIFIER ON;
SET CONCAT_NULL_YIELDS_NULL ON;
SET ANSI_PADDING ON;
GO
CREATE PROC dbo.ServiceBrokerEnable
AS
BEGIN
DECLARE @dbname varchar(200) = DB_NAME()
DECLARE @is_broker_enabled bit
DECLARE @exec_str varchar(2000)
--SELECT @dbname
SELECT @is_broker_enabled = is_broker_enabled
FROM sys.databases
WHERE name = @dbname
--SELECT @is_broker_enabled
--select * from sys.databases
IF @is_broker_enabled = 0
BEGIN
PRINT 'SB is not enabled, enabling...'
DECLARE @Status sql_variant
SELECT @Status = DATABASEPROPERTYEX(DB_NAME(),'UserAccess')
--SELECT @Status
IF @Status <> 'SINGLE_USER'
BEGIN
SELECT @exec_str = 'ALTER DATABASE ' + @dbname + ' SET SINGLE_USER WITH ROLLBACK IMMEDIATE;'
PRINT @exec_str + '...'
EXEC (@exec_str)
END
SELECT @exec_str = 'ALTER DATABASE ' + @dbname + ' SET ENABLE_BROKER;'
PRINT @exec_str + '...'
BEGIN TRY
EXEC (@exec_str)
END TRY
BEGIN CATCH
--need to do this in case we have a backed up db on the same system as the source. This resets the ID,
--but also blows away all existing conversations without producing end dialog messages. Any route that
--references the old SB ID must be recreated.
SELECT @exec_str = 'ALTER DATABASE ' + @dbname + ' SET NEW_BROKER;'
PRINT @exec_str + '...'
EXEC (@exec_str)
END CATCH
--return the database to its previous state
IF @Status = 'MULTI_USER'
BEGIN
SELECT @exec_str = 'ALTER DATABASE ' + @dbname + ' SET MULTI_USER;'
PRINT @exec_str + '...'
EXEC (@exec_str)
END;
ELSE IF @Status = 'RESTRICTED_USER'
BEGIN
SELECT @exec_str = 'ALTER DATABASE ' + @dbname + ' SET RESTRICTED_USER;'
PRINT @exec_str + '...'
EXEC (@exec_str)
END;
END;
ELSE
BEGIN
PRINT 'SB is enabled, no work to do.'
END;
SELECT @exec_str = 'ALTER DATABASE ' + @dbname + ' SET TRUSTWORTHY ON;'
PRINT @exec_str + '...'
EXEC (@exec_str)
SELECT @exec_str = 'ALTER AUTHORIZATION ON DATABASE::' + @dbname + ' TO SA;'
PRINT @exec_str + '...'
EXEC (@exec_str)
--check the tickler
--since we possibly issued a SET NEW_BROKER we have to worry about tickling dying. SET NEW_BROKER clears all messages and conversations
--in all queues
--we first need to see if the Tickler procedure is available. We may be enabling SB before delivering the tickler and we don't need this failing.
IF EXISTS (select * from sys.objects where name = 'WL_ConfigureAll')
BEGIN
EXEC WL_ConfigureAll @Option = 'SETUP';
END;
END;
GO
GRANT EXECUTE ON dbo.ServiceBrokerEnable to SiemensUser
GO
--EXEC ServiceBrokerEnable;
GO
\ No newline at end of file
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment