SQL Server Service Broker example on how to configure, send and receive messages

By:   |   Comments (10)   |   Related: > Service Broker


Problem

SQL Server 2008 and 2005 offer the Service Broker feature. In this tip we will go through the different components of service broker and step by step on how to setup Service Broker for a single database.

Solution

What is service broker? Service Broker is a process of sending and receiving guaranteed, asynchronous messages by using extensions to the Transact-SQL Data Manipulation Language (DML). Messages can be sent to a queue in the same database as the sender, to another database in the same SQL Server instance, or to another SQL Server instance either on the same server or on a remote server.

In this article we will cover these items:

  1. Configuring the Service Broker.
  2. Sending and Receiving Messages.

Configuring the Service Broker

To configure the service broker to send and receive messages between databases (either in local/remote instances), it needs a few components in place to start the service. These are listed below.

  1. Enable the Service Broker on the database
  2. Create valid Message Types.
  3. Create a Contract for the conversation.
  4. Create Queues for the Communication.
  5. Create Services for the Communication.

Note: For my test I've created a database named ServerBrokerTest, which I'm going to use in this article. I've used a single database to make this easy to understand. We can call it a single database conversation.

1. Enabling Service Broker

Service broker is a database level feature not an instance level. So it has to be enabled before starting the other configurations.

Use the following code to enable the Service Broker.

--Enabling service broker
USE master
ALTER DATABASE ServiceBrokerTest
SET ENABLE_BROKER; 

Enabling service broker option can be verified with the Is_Broker_Enabled column (set to true [1]) in sys.databases catalog view.

2. Create Valid Message Types

Service Broker needs specific Message Types to send and receive messages, which have to be created before the communication starts. The initiator (Sender/Requestor) and the target (Receiver/Reply) have to use the same Message Type or else the communication will fail. The most common used Message Type is WELL_FORMED_XML.

The following example code is used to create a Message Type in the same database for the Initiator (Requestor/Sender) and the Target (Reply/Receiver). Use the following code to create the Message Types.

--Create Message Types for Request and Reply messages
USE ServiceBrokerTest
-- For Request
CREATE MESSAGE TYPE
[//SBTest/SBSample/RequestMessage]
VALIDATION=WELL_FORMED_XML;
-- For Reply
CREATE MESSAGE TYPE
[//SBTest/SBSample/ReplyMessage]
VALIDATION=WELL_FORMED_XML; 

3. Create a Contract for the Conversation

Service Broker requires a contract to send and receive messages in a single or between multiple databases. The contract will ensurewhich Message Type is going to be used to send and receive messages between the Initiator (Requestor/Sender) and the Target (Reply/Receiver). Use the following code to create the contract.

--Create Contract for the Conversation 
USE ServiceBrokerTest
CREATE CONTRACT [//SBTest/SBSample/SBContract]
(
[//SBTest/SBSample/RequestMessage]
SENT BY INITIATOR 
,[//SBTest/SBSample/ReplyMessage]
SENT BY TARGET 
);

4. Create Queues for the Communication

The Service Broker Queue is a Message Storage container which is used to keep the messages while sending and receiving. The below code creates two queues, one is the Initiator (Requester/Sender) and the other is Target (Receiver/Replier). Queues will be used by the Service Broker Services.

Use the following code is to create the Queues.

USE ServiceBrokerTest 
--Create Queue for the Initiator
CREATE QUEUE SBInitiatorQueue; 
--Create Queue for the Target
CREATE QUEUE SBTargetQueue; 

5. Create Services for the Communication

The Service Broker Services route the Messages to the specific Queues. The Service and Queue are bonded to each other. When the Initiator or the Target send a Message, the service will route the messages to the appropriate Queues.

Use the following code to create the Service Broker Service.

--Create Service for the Target and the Initiator.
USE ServiceBrokerTest 
--Create Service for the Initiator.
CREATE SERVICE [//SBTest/SBSample/SBInitiatorService]
ON QUEUE SBInitiatorQueue; 
--Create Service for the Target.
CREATE SERVICE [//SBTest/SBSample/SBTargetService] 
ON QUEUE SBTargetQueue
([//SBTest/SBSample/SBContract]); 

Note: In the above code I've not specified the Contract name for the Initiator Service, but I specified for the Target Service, which means if no Contact name is specified on a Service then the Service can only initiate conversations but no other Services can use that service as a Target (Reply/Receiver).

Sending and Receiving Messages

In this section, I'll describe how to Send (Request - from the Initiator) and Reply (from the Target) and Receive a message between the Initiator and the Target. We can understand the conversation cycle between the Initiator and Target.

Sending Message to Target

The following code sends a request message from the Initiator to the Target. The code can be split into three parts.

  1. Determine the Services and contract.
  2. Prepare the Message
  3. Send the Message.

Sending a message is a single transaction, which includes all 3 items above.

--Sending a Request Message to the Target
USE ServiceBrokerTest 
DECLARE @InitDlgHandle UNIQUEIDENTIFIER
DECLARE @RequestMessage VARCHAR(1000) 
BEGIN TRAN 
--Determine the Initiator Service, Target Service and the Contract 
BEGIN DIALOG @InitDlgHandle
FROM SERVICE
[//SBTest/SBSample/SBInitiatorService]
TO SERVICE
'//SBTest/SBSample/SBTargetService'
ON CONTRACT
[//SBTest/SBSample/SBContract]
WITH ENCRYPTION=OFF; 
--Prepare the Message
SELECT @RequestMessage = N'<RequestMessage> Send a Message to Target </RequestMessage>'; 
--Send the Message
SEND ON CONVERSATION @InitDlgHandle 
MESSAGE TYPE
[//SBTest/SBSample/RequestMessage]
(@RequestMessage);
SELECT @RequestMessage AS SentRequestMessage;
COMMIT TRAN 

Note: TO SERVICE needs to be specified in the single quotes because it is case sensitive, service broker uses a byte-by-byte comparison with the Target service name. The above code will give the below result set.

SentRequestMessage
<RequestMessage> Send a Message to Target </RequestMessage> 

Receiving and Sending Message to Initiator

The following code receives a message from the Initiator and sends a Reply message to it.

--Receiving a Message and sending a Reply from the Target 
USE ServiceBrokerTest 
DECLARE @TargetDlgHandle UNIQUEIDENTIFIER
DECLARE @ReplyMessage VARCHAR(1000)
DECLARE @ReplyMessageName Sysname 
BEGIN TRAN; 
--Receive message from Initiator
RECEIVE TOP(1)
@TargetDlgHandle=Conversation_Handle
,@ReplyMessage=Message_Body
,@ReplyMessageName=Message_Type_Name
FROM SBTargetQueue; 
SELECT @ReplyMessage AS ReceivedRequestMessage; 
-- Confirm and Send a reply
IF @ReplyMessageName=N'//SBTest/SBSample/RequestMessage'
BEGIN
DECLARE @RplyMsg VARCHAR(1000)
SELECT @RplyMsg =N'<RplyMsg> Send a Message to Initiator</RplyMsg>'; 
SEND ON CONVERSATION @TargetDlgHandle
MESSAGE TYPE
[//SBTest/SBSample/ReplyMessage]
(@RplyMsg);
END CONVERSATION @TargetDlgHandle;
END 
SELECT @RplyMsg AS SentReplyMessage; 
COMMIT TRAN;

The above will give two result sets as below, 1 is received message from the Initiator and 2 is the sent message to the Initiator from the Target.

ReceivedRequestMessage
<RequestMessage> Send a Message to Target </RequestMessage>
SentReplyMessage
<RplyMsg> Send a Message to Initiator</RplyMsg>

Receiving a Reply Message from the Target

The below code receives a reply message from the Target.

--Receiving Reply Message from the Target.
USE ServiceBrokerTest 
DECLARE @InitiatorReplyDlgHandle UNIQUEIDENTIFIER
DECLARE @ReplyReceivedMessage VARCHAR(1000) 
BEGIN TRAN; 
RECEIVE TOP(1)
@InitiatorReplyDlgHandle=Conversation_Handle
,@ReplyReceivedMessage=Message_Body
FROM SBInitiatorQueue; 
END CONVERSATION @InitiatorReplyDlgHandle; 
SELECT @ReplyReceivedMessage AS ReceivedRepliedMessage; 
COMMIT TRAN; 

Below is the output of the above transaction, which confirms that the reply message received from the Target.

ReceivedRepliedMessage
<RplyMsg> Send a Message to Initiator</RplyMsg>

That is pretty much all there is to setting up Service Broker and sending and receiving some simple messages.

Some Useful Catalog Views

The following catalog views are helpful to check the usage of the Service Broker Objects.

--Checking the usage of the Messages, Contracts and Queues using System views.
USE ServiceBrokerTest 
SELECT * FROM sys.service_contract_message_usages 
SELECT * FROM sys.service_contract_usages
SELECT * FROM sys.service_queue_usages 

I hope this article has taught you how to configure the Service Broker in single database and start the conversation cycle between the Initiator and Target. Conversation between databases also has the same steps, but the initiator and the target will be two different databases and the services and queues have to be created in both of the databases.

Next Steps

Review these other tips related to Service Broker



sql server categories

sql server webinars

subscribe to mssqltips

sql server tutorials

sql server white papers

next tip



About the author
MSSQLTips author Jayakumar Krishnan Jayakumar Krishnan's bio is coming soon...

This author pledges the content of this article is based on professional experience and not AI generated.

View all my tips



Comments For This Article




Friday, May 31, 2019 - 4:51:38 PM - John Resler Back To Top (81283)

 Admittedly I'm using SQL Server 2016 but I am receiving an error from this line of code:

[//SBTest/SBSample/SBInitiatorService]

TO SERVICE

Msg 208, Level 16, State 72, Line 44

Invalid object name '//SBTest/SBSample/SBInitiatorService'.

I am unsure which object has been misnamed but I suspect that is the problem? Or is this an object that's been renamed since the writing of this article?

Thanks for your help.


Thursday, March 13, 2014 - 6:45:09 AM - Nandakumar Back To Top (29739)

Excellent ....


Friday, January 24, 2014 - 5:57:25 AM - satya Back To Top (28212)

 

 

Hi this is very useful and very nice thanks friend


Friday, July 26, 2013 - 2:47:45 PM - marc Back To Top (26030)

Thank you, this is a fantastic tutorial.


Thursday, July 11, 2013 - 2:36:06 PM - wpkf Back To Top (25803)

Thanks for the examples. Make me get clearer picture.


Friday, June 28, 2013 - 5:17:11 PM - Janus Knudsen Back To Top (25622)

Actually a real example of using a conversation 2-ways, very nice :) Many other examples seem to forget to reply, well... should I say all others :)

 

 


Monday, October 15, 2012 - 5:32:32 AM - dinesh Back To Top (19922)

to produce a reult as 1 without entering numeric values in select statement

Select Exp($);


Friday, March 30, 2012 - 9:57:41 AM - Sergey Back To Top (16712)

Block of T-SQL in "Receiving a Reply Message from the Target" doesn't properly work. I catch only error "Msg 8418, Level 16, State 1, Line 11 conversation handle is missing. Specify a conversation handle." Also i cann't delete services, queues and contract

 


Wednesday, March 9, 2011 - 3:59:01 AM - soheil bijavar Back To Top (13154)

hi

that so usefull and simple so thanks dear friend


Thursday, September 24, 2009 - 9:44:11 AM - John Zacharkan Back To Top (4087)

Excellent job, very helpful I've passed this on to the team here. Thank you for taking the time to do this.















get free sql tips
agree to terms