Last active
June 16, 2017 08:16
-
-
Save mollwe/1588525 to your computer and use it in GitHub Desktop.
Drops all connections to a database. Returns number of dropped connections.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
use [master] | |
go | |
exec sp_dropallconnections N'dbname' | |
RESTORE DATABASE [dbname] FROM DISK = N'C:\dbname.bak' WITH FILE = 1, NOUNLOAD, STATS = 10 | |
GO |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
USE [master] | |
GO | |
SET ANSI_NULLS ON | |
GO | |
SET QUOTED_IDENTIFIER ON | |
GO | |
/* =============================================================================== ** | |
** Author: mollwe | |
** Create date: 2012-01-10 | |
** Description: Drops all connection to a database. Return number of dropped | |
** connections. Doesn't allow dropping connections to null and 'master' | |
** databases. It avoids dropping current connection. | |
** Uses kill, see http://msdn.microsoft.com/en-us/library/ms173730.aspx | |
** for more information about kill. | |
** | |
** Change list | |
** | |
** Date Author Comment | |
** ---------- ------------ ------------------------------------------------------ | |
** | |
** =============================================================================== */ | |
CREATE PROCEDURE [dbo].[sp_dropallconnections] | |
@dbname nvarchar(max) | |
AS | |
BEGIN | |
-- SET NOCOUNT ON added to prevent extra result sets from | |
-- interfering with SELECT statements. | |
SET NOCOUNT ON; | |
declare @droppedConnections int | |
set @droppedConnections = 0 | |
begin try | |
if(@dbname is null) raiserror('@dbname cannot be null', 18, 0) | |
if(@dbname = 'master') raiserror('@dbname cannot be ''master''', 18, 1) | |
declare @connections table ( | |
spid int, | |
ecid int, | |
status varchar(max), | |
loginname varchar(max), | |
hostname varchar(max), | |
blk bit, | |
dbname varchar(max), | |
cmd varchar(max), | |
request_id int | |
) | |
insert into @connections | |
exec sp_who | |
declare @spid int, @sql nvarchar(max) | |
declare c cursor for | |
select spid from @connections where dbname = @dbname | |
open c | |
fetch next from c into @spid | |
while @@fetch_status = 0 begin | |
set @sql = N'kill ' + convert(varchar, @spid) | |
print @sql | |
if(@spid != @@spid) begin | |
begin try | |
exec sp_executesql @sql | |
set @droppedConnections = @droppedConnections + 1 | |
print 'Done!' | |
end try | |
begin catch | |
print error_message() | |
end catch | |
end | |
else begin | |
print 'Failed to drop connection because it is the current connection!' | |
end | |
print '' | |
fetch next from c into @spid | |
end | |
close c | |
deallocate c | |
end try | |
begin catch | |
-- Raise an error with the details of the exception | |
declare @errmsg nvarchar(4000), @errseverity int, @errstate int | |
select @errmsg = error_message() + case | |
when error_procedure() is null then '' | |
else '(' + error_procedure() + ', line ' + cast(error_line() as varchar(5)) + ')' | |
end, | |
@errseverity = error_severity(), | |
@errstate = error_state() | |
raiserror(@errmsg, @errseverity, @errstate) | |
return -1 | |
end catch | |
return @droppedConnections | |
END |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment