You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 
 
 
sql-tools/sql 队列.sql

200 lines
5.1 KiB

use master
go
drop database Inventory
go
Create database Inventory
go
use Inventory
go
Create table inventory
(
TitleId nvarchar(6) not null,
Quantity int not null,
primary key (TitleId,Quantity)
);
go
insert inventory values ('pc1001',100);
insert inventory values ('pc1002',200);
insert inventory values ('pc1003',300);
insert inventory values ('pc1004',400);
---------
exec sp_executesql N'SELECT
mt.name AS [Name],
''Server[@Name='' + quotename(CAST(serverproperty(N''Servername'') AS sysname),'''''''') + '']'' + ''/Database[@Name='' + quotename(db_name(),'''''''') + '']'' + ''/ServiceBroker'' + ''/MessageType[@Name='' + quotename(mt.name,'''''''') + '']'' AS [Urn],
mt.message_type_id AS [ID]
FROM
sys.service_message_types mt
WHERE
(CAST(case when mt.message_type_id < 65536 then 1 else 0 end AS bit)=@_msparam_0)
ORDER BY
[Name] ASC',N'@_msparam_0 nvarchar(4000)',@_msparam_0=N'0'
IF NOT EXISTS(SELECT * FROM sys.service_message_types WHERE name = '//saidao/types/perf')
BEGIN
Create Message Type [//saidao/types/perf]
END
IF NOT EXISTS(SELECT * FROM sys.service_message_types WHERE name = '//saidao/types/perf_response')
BEGIN
Create Message Type [//saidao/types/perf_response]
END
---
--创建合约
IF NOT EXISTS(SELECT * FROM sys.service_contracts WHERE name = '//saidao/contracts/perf_contract')
BEGIN
Create contract [//saidao/contracts/perf_contract]
(
[//saidao/types/perf] sent by initiator,
[//saidao/types/perf_response] sent by target
);
END
--创建队列与服务
IF NOT EXISTS(SELECT * FROM sys.service_queues WHERE name = 'perf_queue')
BEGIN
create queue [perf_queue];
create service [//saidao/services/perf]
on queue [perf_queue]
(
[//saidao/contracts/perf_contract]
);
END
--发送消息到消息队列中
use Inventory
go
--send message
begin transaction
declare @dialog_id uniqueidentifier
begin dialog conversation @dialog_id
from service [//saidao/services/perf]
to service '//saidao/services/perf'
on contract [//saidao/contracts/perf_contract]
with encryption = off;
send on conversation @dialog_id message type [//saidao/types/perf]
(
'<PerfUpdate>
<FromDate>pc1001</FromDate>
<ToDate>pc1001</ToDate>
<CompId>102</CompId>
</PerfUpdate>'
);
commit transaction;
--发送成功后,可以查询 inventory_queue
select conversation_handle, cast(message_body as xml) as conversation_body from [perf_queue]
--其中conversation_body 就是 我们发出的信息了。
-- 从 inventory queue 中获取信息并更新数据
use inventory
go
begin transaction
declare @dialog_id uniqueidentifier
declare @message_body xml
declare @amount int;
declare @title nvarchar(128);
receive
@dialog_id = conversation_handle,
@message_body = message_body
from [dbo].[perf_queue]
print 'handle is' + cast(@dialog_id as nvarchar(90))
print 'message body is' + cast(@message_body as nvarchar(max) )
if(@dialog_id is not null)
begin
set @amount = @message_body.value('(/InventoryUpdate/Quantity)[1]','int');
set @title = @message_body.value('(/InventoryUpdate/TitleId)[1]','nvarchar(100)');
print 'a:'+cast(@amount as nvarchar(100))
print 'b:'+@title;
Update inventory set Quantity = @amount where TitleId = @title;
end
end conversation @dialog_id;
commit transaction ;
--接下来做个自动监听功能,只要有信息发送到队列,相关队列,就可以自动执行功能.
--首先建立个存储过程,(把receive 中的那段代码拿过来就可以了)
use Inventory
go
--create procedure to receive message and update table
create proc InventoryProc as
begin transaction
declare @dialog_id uniqueidentifier
declare @message_body xml
declare @amount int;
declare @title nvarchar(128);
waitfor(
receive
@dialog_id = conversation_handle,
@message_body = message_body
from [dbo].[perf_queue]),timeout 50000;
print 'handle is' + cast(@dialog_id as nvarchar(90))
print 'message body is' + cast(@message_body as nvarchar(max) )
if(@dialog_id is not null)
begin
set @amount = @message_body.value('(/InventoryUpdate/Quantity)[1]','int');
set @title = @message_body.value('(/InventoryUpdate/TitleId)[1]','nvarchar(100)');
print 'a:'+cast(@amount as nvarchar(100))
print 'b:'+@title;
Update inventory set Quantity = @amount where TitleId = @title;
end
end conversation @dialog_id;
commit transaction;
go
--队列监听
alter queue [perf_queue]
with activation(
status = on,
procedure_name= InventoryProc,
max_queue_readers=2,
execute as self
);
go
完成后只要发送队列信息后就可以了
PS 我们定义了 两个队列 还有个 inventory client queue
这个队列保存的是成功或者error 提示用receive 方法也可以提取出来
复制代码 代码如下:
select message_type_name from [perf_queue]