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

Scripting out grants for 'sa', 'securityadmin' type rights Expand / Collapse
Author
Message
Posted Monday, August 20, 2012 11:16 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Yesterday @ 8:43 AM
Points: 1,201, Visits: 2,661
I am in the process of moving a database from SQL 2005 to 2008 and it has over 1,000 userids. I know how to script out the logins with sp_help_revlogin. My question is how do I script out above the database rights like who has 'sa' rights, 'security admin' type rights. I am sure there is a script to get this out of SQL Server but I cannot seem to find it.




Post #1347351
Posted Monday, August 20, 2012 2:08 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 12:26 PM
Points: 2,742, Visits: 2,953
This should do it

CREATE TABLE #srvroles(ServerRole VARCHAR(20), Membername VARCHAR(200), MEMBERSID VARBINARY(MAX))
GO

INSERT #srvroles EXEC sp_helpsrvrolemember

SELECT 'EXEC master..sp_addsrvrolemember @loginame = N'+''''+MemberName+''''+','+'@rolename = N'+''''+ServerRole+''''
FROM #srvroles
GO
DROP TABLE #srvroles

Post #1347465
Posted Monday, August 20, 2012 2:33 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 9:25 AM
Points: 7,070, Visits: 12,523
JeremyE (8/20/2012)
This should do it

CREATE TABLE #srvroles(ServerRole VARCHAR(20), Membername VARCHAR(200), MEMBERSID VARBINARY(MAX))
GO

INSERT #srvroles EXEC sp_helpsrvrolemember

SELECT 'EXEC master..sp_addsrvrolemember @loginame = N'+''''+MemberName+''''+','+'@rolename = N'+''''+ServerRole+''''
FROM #srvroles
GO
DROP TABLE #srvroles


That will give you Fixed Server Role memberships. You'll also need to consult the sys.server_permissions System View to gain the complete picture.

Edit: as a side note sp_addsrvrolemember was marked obsolete in SQL Server 2012 so if this code is going in your toolbox you may want to consider using ALTER SERVER ROLE instead on 2012 instances.


__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato

Believe you can and you're halfway there. --Theodore Roosevelt

Everything Should Be Made as Simple as Possible, But Not Simpler --Albert Einstein

The significant problems we face cannot be solved at the same level of thinking we were at when we created them. --Albert Einstein

1 apple is not exactly 1/8 of 8 apples. Because there are no absolutely identical apples. --Giordy
Post #1347477
Posted Tuesday, August 21, 2012 6:03 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Yesterday @ 8:43 AM
Points: 1,201, Visits: 2,661
Thanks a million gang.


Post #1347734
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse