Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Asynchronous SP execution via Service Broker Expand / Collapse
Author
Message
Posted Monday, February 17, 2014 5:39 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Monday, July 21, 2014 5:35 AM
Points: 69, Visits: 565
Hi all,

I'm looking at implementing Service Broker to resolve some performance issues in one of our applications where certain long running processes hold up the front end UI for users.

So far, I've successfully set up the steps in Service Broker for the message types, queues etc and that's working fine. What I want to do now though is in the message reply at the end, call another stored procedure which will take up to a minute or two to run, but without that impacting the return of the message reply and ending the conversation. I've added a segment of code below to show how I'm trying to do the final reply and end the conversation.

-- Receive reply and end conversation

DECLARE @ReceivedReplyMessage NVARCHAR(100);
DECLARE @ReceivedReplyHandle UNIQUEIDENTIFIER;

BEGIN TRANSACTION;

WAITFOR
( RECEIVE TOP(1)
@ReceivedReplyHandle = conversation_handle,
@ReceivedReplyMessage = message_body
FROM InitiatorCalculationsQueue
), TIMEOUT 1000;

Select
@ReceivedReplyMessage
-- T-SQL statement for running SP
EXEC SomeLongRunningSP

-- end T-SQL
END CONVERSATION @ReceivedReplyHandle;

SELECT @ReceivedReplyMessage AS ReceivedReplyMessage;

COMMIT TRANSACTION;
GO

So basically the application calls an SP which generates the initiator message and sends it off. Service Broker than accepts that, sends an acknowledgement back, calls the external stored procedure and then ends the conversation, so that the front end application can continue to work as soon as it gets the acknowledgement/reply while the database runs the Stored Procedure.

Does that make sense, or have I missed something obvious?

Post #1542062
Posted Monday, February 17, 2014 7:04 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, August 26, 2014 4:51 AM
Points: 1,854, Visits: 3,451
Hi

There are some issues and things you need to consider with this approach:

Since Service Broker honors transactions, the first acknowledge message will not be delivered until the transaction is committed, and since you run SomeLongRunningSP inside the same transaction as the RECEIVE statement the message will no be delivered until the sproc has completed.
I would just trust SQL Server with delivery once the initiator message has been sent (and by that I don't mean delivered at the target) and the transaction has committed. Make sure you monitor sys.transmission_queue for delivery failures. You should also set up monitoring of the status of the queues in case they are disabled (due to poison message detection). It happend a lot for me in the beginning.

What happens if execution of SomeLongRunningSP fails? You should not rollback the transaction and reread the message becuase this could lead to poison message detection and disabling of the queue. I've usually implemented retry logic by setting up a retry table together with BEGIN CONVERSATION TIMER. Monitor the retry table to detect any failures.
Database mail uses this kind of logic.

Do you need to inform the client when the sproc execution is completed?
Post #1542102
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse