March 16, 2009 at 10:13 am
Is there a way to drop all users in a particular database instead of deleting each.
March 16, 2009 at 11:18 am
If you mean instead of deleting each individually, then you have 2 choices -
1) write a script
2) use the Object Explorer Details pane in SSMS to list the users, highlight those you want to delete, right click and select delete
It really depends on whether this is a one-off removal or for some repeated use.
I can expand on (1) if that is the direction you want to take.
March 16, 2009 at 11:30 am
I might suspect that the services are not started then. You want to use SQL tools, not the Windows ones to work with SQL Server.
Moving to SQL 2005 Admin
March 16, 2009 at 11:30 am
This sounds like something that would be fun, reduce work load, reduce phone calls. Wouldn't you want to enjoy this and delete them one by one :D:w00t:
March 16, 2009 at 11:42 am
i just slapped this together.
i'm using sp_revokeaccess instead of sp_dropuser, because the users might be orphaned and not tied to a login;
this yanks them out the way i expected:
[font="Courier New"]ALTER PROCEDURE sp_DeleteUsers(@DeleteThem INT = 0)
AS
BEGIN
DECLARE @username VARCHAR(64)
DECLARE c1 CURSOR FOR
SELECT name
FROM sysusers
WHERE name NOT IN('dbo','guest','INFORMATION_SCHEMA','sys','public')
AND LEFT(name,3) <> 'db_'
OPEN c1
FETCH next FROM c1 INTO @username
WHILE @@fetch_status <> -1
BEGIN
PRINT 'Dropping ' + @username
IF @DeleteThem <> 0
EXEC dbo.sp_revokedbaccess @username
FETCH next FROM c1 INTO @username
END
CLOSE c1
DEALLOCATE c1
END
[/font]
Lowell
March 16, 2009 at 12:04 pm
Lowell (3/16/2009)
i just slapped this together.i'm using sp_revokeaccess instead of sp_dropuser, because the users might be orphaned and not tied to a login;
this yanks them out the way i expected:
[font="Courier New"]ALTER PROCEDURE sp_DeleteUsers(@DeleteThem INT = 0)
AS
BEGIN
DECLARE @username VARCHAR(64)
DECLARE c1 CURSOR FOR
SELECT name
FROM sysusers
WHERE name NOT IN('dbo','guest','INFORMATION_SCHEMA','sys','public')
AND LEFT(name,3) <> 'db_'
OPEN c1
FETCH next FROM c1 INTO @username
WHILE @@fetch_status <> -1
BEGIN
PRINT 'Dropping ' + @username
IF @DeleteThem <> 0
EXEC dbo.sp_revokedbaccess @username
FETCH next FROM c1 INTO @username
END
CLOSE c1
DEALLOCATE c1
END
[/font]
Here is another way to do that:
declare @sql nvarchar(max)
set @sql = ''
SELECT @sql = @sql+
'
print ''Dropping '+name+'''
execute master.dbo.sp_revokedbaccess '''+name+'''
'
FROM
dbo.sysusers
WHERE
name NOT IN('dbo','guest','INFORMATION_SCHEMA','sys','public')
AND LEFT(name,3) <> 'db_'
order by
name
execute ( @sql )
May 20, 2011 at 3:18 am
Hi,
Thank you for posting the script.
But in my case when i execute the above script, it generate Drop statments for all users in given database along with the database role.
i.e it creates drop statment for user defined db role, which won't allow me to drop.
Is there any way to exclude user defined db role from users in the script?
DJSH
May 20, 2011 at 5:38 am
can't you just add to the WHERE statement to exclude items you don't want to include? like AND issqlrole = 0 or something?
Lowell
May 20, 2011 at 6:17 am
also you want to be using the sys.database_principals catalog view and not sysusers. This should be better
declare @sql nvarchar(max)
set @sql = ''
SELECT @sql = @sql+
'
print ''Dropping '+name+'''
execute master.dbo.sp_revokedbaccess '''+name+'''
'
FROM
sys.database_principals
WHERE
name NOT IN('dbo','guest','INFORMATION_SCHEMA','sys','public')
AND TYPE <> 'R'
order by
name
execute (@sql)
-----------------------------------------------------------------------------------------------------------
"Ya can't make an omelette without breaking just a few eggs" 😉
July 29, 2011 at 5:25 am
Or this - doesn't drop users who own a schema
declare @sql nvarchar(max)
set @sql = ''
SELECT @sql = @sql+
'
print ''Dropping '+name+'''
execute master.dbo.sp_revokedbaccess '''+name+'''
'
FROM
sys.database_principals
WHERE type <> 'R'
AND NOT EXISTS
(
SELECT 1
FROM sys.schemas s
WHERE s.principal_id = dp.principal_id
)
ORDER BY name
execute (@sql)
.. yes I know it was a couple of months back but I am using it today.
June 30, 2013 at 4:25 am
Hello,
You can find here an interesting script that works with all versions of sql server (2000, 2005, 2008, 2012):
http://sqlscripts.sql-assistance.com
It can be used to delete all users in a database, all users in a database except a list of users or it deletes just a list of users (the others remain untouched).
I hope it helps 🙂
July 2, 2013 at 7:49 am
Hi Everyone
I got a request to delete all the logins except service accounts. So is there any script for working on this?
I tried above one but there is no luck
Advance thanks for your help.
Thanks,
I’m nobody but still I’m somebody to someone………….
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply