Commit cc0b3da4 authored by dwentzel's avatar dwentzel

added GUIDs.sql

parent b1805300
/*
This is the source code for http://www.davewentzel.com/content/service-broker-demystified-set-enablebroker-vs-newbroker.
This covers how GUIDs work in Service Broker, especially when restoring databases.
*/
--basic setup
CREATE DATABASE SBTestOriginal
GO
ALTER DATABASE SBTestOriginal SET NEW_BROKER
GO
USE SBTestOriginal
GO
SELECT name, service_broker_guid 'GUID_when_db_created', is_broker_enabled
FROM sys.databases
WHERE name LIKE 'SBTest%'
GO
--create some SSB infrastructure and enqueue a message to it
CREATE QUEUE TestQ;
CREATE SERVICE TestSvc ON QUEUE TestQ ([DEFAULT]);
BEGIN TRANSACTION
DECLARE @h UNIQUEIDENTIFIER;
BEGIN DIALOG @h
FROM SERVICE [TestSvc]
TO SERVICE 'TestSvc', 'CURRENT DATABASE'
WITH ENCRYPTION = OFF;
SEND ON CONVERSATION @h ('My test message');
COMMIT;
SELECT convert(xml,message_body) ContentsOfTestQ from TestQ
--backup the new database and restore it as a COPY on the same instance
BACKUP DATABASE SBTestOriginal to disk = 'SBTest.bak' WITH INIT;
DECLARE @filename varchar(256), @filename2 varchar(256)
SELECT @filename = filename + '1', @filename2 = filename + '2' FROM sysfiles WHERE fileid = 1
RESTORE DATABASE SBTestNew FROM disk = 'SBTest.bak'
WITH MOVE 'SBTestOriginal' to @filename, MOVE 'SBTestOriginal_log' to @filename2, REPLACE;
GO
--note that the GUID has not changed, but SSB is disabled.
SELECT name, service_broker_guid 'GUID_after_restore', is_broker_enabled
FROM sys.databases
WHERE name LIKE 'SBTest%'
GO
--let's try to enable it
BEGIN TRY
ALTER DATABASE SBTestNew SET ENABLE_BROKER
END TRY
BEGIN CATCH
SELECT 'Oops...' AS FailedToEnableBroker
SELECT ERROR_NUMBER() AS Error
SELECT ERROR_MESSAGE() AS ErrorMessage
END CATCH
--instead we'll run SET NEW_BROKER and note the new GUID
--this is the same command that you would run to enable SSB
--the first time on a brand new database
ALTER DATABASE SBTestNew SET NEW_BROKER;
SELECT name, service_broker_guid 'GUID_after_NEW_BROKER', is_broker_enabled
FROM sys.databases
WHERE name LIKE 'SBTest%'
GO
--what happened to our message in TestQ in our new db? They are wiped clean and GONE.
USE SBTestNew
GO
SELECT convert(xml,message_body) ContentsOfTestQ from TestQ
select * from sys.transmission_queue
--but our Q is still there and active
select name, is_receive_enabled, is_enqueue_enabled
from sys.service_queues
where name = 'TestQ'
--basic cleanup
USE master;
GO
DROP DATABASE SBTestOriginal;
DROP DATABASE SBTestNew;
GO
......@@ -2,6 +2,7 @@ Service Broker Demystified Series
====================================
This folder contains the source code for my [Service Broker Demystified blog series](http://www.davewentzel.com/taxonomy/term/343).
`CaseSensitivity.sql` covers why some SSB objects are case-sensitive.
`contracts.sql` covers why contracts are not alterable
......@@ -11,6 +12,12 @@ This folder contains the source code for my [Service Broker Demystified blog ser
`encryption_errors.sql` and `encryption_errors2.sql` cover goofiness with encryption and how to work around it.
`GUIDs.sql` covers interesting aspects of SET NEW_BROKER vs ENABLE_BROKER.
......
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