SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Kill Active connections


Kill Active connections

Author
Message
abmore
abmore
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1307 Visits: 931
Comments posted to this topic are about the item Kill Active connections
JP de Jong-202059
JP de Jong-202059
SSC Veteran
SSC Veteran (226 reputation)SSC Veteran (226 reputation)SSC Veteran (226 reputation)SSC Veteran (226 reputation)SSC Veteran (226 reputation)SSC Veteran (226 reputation)SSC Veteran (226 reputation)SSC Veteran (226 reputation)

Group: General Forum Members
Points: 226 Visits: 172
Hi

This is quicker:
alter database [db_name] set single_user with rollback immediate
go
anand.ramanan
anand.ramanan
SSC Journeyman
SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)

Group: General Forum Members
Points: 83 Visits: 70
the original script might kill connections that are active, what about new incoming connections, they will still be created.

With the set single_user also it is not possible to achieve the desired results, for e.g. in a farm environment where you have 10 web front ends connecting to a single sql cluster instance.
Chadwick-788357
Chadwick-788357
SSC-Enthusiastic
SSC-Enthusiastic (160 reputation)SSC-Enthusiastic (160 reputation)SSC-Enthusiastic (160 reputation)SSC-Enthusiastic (160 reputation)SSC-Enthusiastic (160 reputation)SSC-Enthusiastic (160 reputation)SSC-Enthusiastic (160 reputation)SSC-Enthusiastic (160 reputation)

Group: General Forum Members
Points: 160 Visits: 170
Thanks for the script. It's useful for me.
gorthog
gorthog
Old Hand
Old Hand (330 reputation)Old Hand (330 reputation)Old Hand (330 reputation)Old Hand (330 reputation)Old Hand (330 reputation)Old Hand (330 reputation)Old Hand (330 reputation)Old Hand (330 reputation)

Group: General Forum Members
Points: 330 Visits: 167
Here is a variation of the kill script that can be used on any database whether or not it is the current database. To use, set the @dbname variable to the name of the database where the connections are to be killed.


declare @dbname sysname, @spid int, @cnt int, @sql varchar(2048)

set @dbname = 'targetDB'

select @spid = min(spid), @cnt = count(*)
from master.dbo.sysprocesses
where dbid = db_id(@dbname) and spid != @@spid

print @dbname + ' connection process(es) to kill: ' + rtrim(@cnt)

while @spid is not null
begin
print 'kill connection process ' + rtrim(@spid)
set @sql = 'kill ' + rtrim(@spid)
exec(@sql)
select @spid = min(spid), @cnt = count(*)
from master.dbo.sysprocesses
where dbid = db_id(@dbname)
and spid != @@spid
end

print 'done'


tflooder
tflooder
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 209
This script will save me a lot of time when restoring test databases. It's simply and replaces a process I was doing manually.
Thanks.
Jason Carlson
Jason Carlson
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 145
I agree, I think the ALTER DATABASE <databaseName> SET SINGLE_USER WITH ROLLBACK IMMEDIATE is more elegant and precludes the risk of active connections occurring while the cursor is killing the ones it knew about at the time the cursor was opened.



Michael Valentine Jones
Michael Valentine Jones
SSCertifiable
SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)

Group: General Forum Members
Points: 7468 Visits: 11793
Setting the database to single user do not prevent someone from making a connection. It just kills the current connections, and prevent users from making more than one new connection.

If all you need to do is get everyone out of the database to do a restore, this will do it:
use master
alter database [db_name] set offline with rollback immediate


tflooder
tflooder
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 209
use master
alter database [db_name] set offline with rollback immediate

I will try this next time I replace a test DB with a copy of production. Makes sense.

Does a restore automatically set the database online? I'll test when I try it.
anand.ramanan
anand.ramanan
SSC Journeyman
SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)

Group: General Forum Members
Points: 83 Visits: 70
After setting a db to offline it wont be available for a restore, however, you put all statements in a single transaction

--Step1
alter database <dbname>
set offline
with rollback immediate -- this is the part that kills the connections

--Step2
alter database <dbname> set online

restore database <dbname> <restore parameters>

[b]Credit: This was actually given to me by an on call DBA. Nice alternative instead of having to shutdown IIS on all my web servers to do a db restore./b]
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search