From time to time I am asked to provide an "access" list for a database or server. I have various scripts lying around the place and I cobble something together as needed but I have never got around to putting something comprehensive together until today.
Sure, you can Google for a solution to save the bother of having to type, but in doing so I never found something that did exactly what I wanted.
Today I found something that got me started by a chap called Mangal Pardeshi but there were a couple of problems with it, 1) it didn't like databases with - or _ in the name and 2) it only covered database roles and not server roles.
So with thanks to Mangal, I have reworked his stored procedure (so it is just a query) and you can use it below (with the usual caveats):
---
Sure, you can Google for a solution to save the bother of having to type, but in doing so I never found something that did exactly what I wanted.
Today I found something that got me started by a chap called Mangal Pardeshi but there were a couple of problems with it, 1) it didn't like databases with - or _ in the name and 2) it only covered database roles and not server roles.
So with thanks to Mangal, I have reworked his stored procedure (so it is just a query) and you can use it below (with the usual caveats):
/********************************************************************************************
Name
: dbo.List_DBRoles.sql
Author
: Mangal Pardeshi / Paul Hewson
Purpose : Show all database role
membership, amended version that includes Server Roles also
Date
: 27 Jan 2014
********************************************************************************************/
-- Show Server roles
SELECT member.NAME AS MemberName
,Max(CASE ROLE.NAME WHEN 'sysadmin' THEN '1' ELSE '0' END) AS sysadmin
,Max(CASE ROLE.NAME WHEN 'processadmin' THEN '1' ELSE '0' END) AS processadmin
,Max(CASE ROLE.NAME WHEN 'dbcreator' THEN '1' ELSE '0' END) AS dbcreator
,Max(CASE ROLE.NAME WHEN 'securityadmin' THEN '1' ELSE '0' END) AS securityadmin
,Max(CASE ROLE.NAME WHEN 'setupadmin' THEN '1' ELSE '0' END) AS setupadmin
,Max(CASE ROLE.NAME WHEN 'diskadmin' THEN '1' ELSE '0' END) AS diskadmin
,Max(CASE ROLE.NAME WHEN 'bulkadmin' THEN '1' ELSE '0' END) AS bulkadmin
,Max(CASE ROLE.NAME WHEN 'serveradmin' THEN '1' ELSE '0' END) AS serveradmin
FROM sys.server_role_members
INNER JOIN sys.server_principals AS
ROLE
ON sys.server_role_members.role_principal_id = ROLE.principal_id
INNER JOIN sys.server_principals AS
member
ON sys.server_role_members.member_principal_id =
member.principal_id
--LEFT OUTER join #DBRoles
--ON member.name =
#DBRoles.UserName
GROUP BY
member.NAME
,Role.NAME
-- Show database roles
DECLARE @database NVARCHAR(128)
DECLARE @user VARCHAR(20)
DECLARE @dbo CHAR(1)
DECLARE @access CHAR(1)
DECLARE @security CHAR(1)
DECLARE @ddl CHAR(1)
DECLARE @datareader CHAR(1)
DECLARE @datawriter CHAR(1)
DECLARE @denyread CHAR(1)
DECLARE @denywrite CHAR(1)
DECLARE @dbname VARCHAR(200)
DECLARE @mSql1 VARCHAR(8000)
IF EXISTS (SELECT 1 FROM tempdb..sysobjects WHERE id=OBJECT_ID('tempdb..#DBRoles')) DROP TABLE #DBRoles
CREATE TABLE #DBROLES (
DBName SYSNAME NOT NULL
,UserName SYSNAME NOT NULL
,db_owner VARCHAR(3) NOT NULL
,db_accessadmin VARCHAR(3) NOT NULL
,db_securityadmin VARCHAR(3) NOT NULL
,db_ddladmin VARCHAR(3) NOT NULL
,db_datareader VARCHAR(3) NOT NULL
,db_datawriter VARCHAR(3) NOT NULL
,db_denydatareader VARCHAR(3) NOT NULL
,db_denydatawriter VARCHAR(3) NOT NULL
--,sysadmin BIT DEFAULT(0)
--,securityadmin BIT DEFAULT(0)
--,serveradmin BIT DEFAULT(0)
--,setupadmin BIT DEFAULT(0)
--,processadmin BIT DEFAULT(0)
--,diskadmin BIT DEFAULT(0)
--,dbcreator BIT DEFAULT(0)
--,bulkadmin BIT DEFAULT(0)
,PollDate DATETIME NOT NULL DEFAULT getdate()
)
DECLARE DBName_Cursor CURSOR
FOR
SELECT NAME
FROM master.dbo.sysdatabases
WHERE NAME NOT IN (
'msdb'
,'tempdb'
,'model'
,'master'
)
ORDER BY NAME
OPEN DBName_Cursor
FETCH NEXT
FROM DBName_Cursor
INTO @dbname
WHILE @@FETCH_STATUS = 0
BEGIN
SET @mSQL1 = ' INSERT INTO #DBROLES
(DBName, UserName, db_owner, db_accessadmin,
db_securityadmin, db_ddladmin,
db_datareader, db_datawriter, db_denydatareader, db_denydatawriter )
SELECT
' + '''' + '['+ @dbName +']' + '''' + ' as DBName ,UserName, '
+ CHAR(13) +
'Max(CASE RoleName
WHEN ''db_owner'' THEN ''1'' ELSE ''0'' END) AS db_owner,
Max(CASE RoleName WHEN ''db_accessadmin ''
THEN ''1'' ELSE ''0'' END) AS db_accessadmin,
Max(CASE RoleName WHEN ''db_securityadmin''
THEN ''1'' ELSE ''0'' END) AS db_securityadmin,
Max(CASE RoleName WHEN ''db_ddladmin'' THEN
''1'' ELSE ''0'' END) AS db_ddladmin,
Max(CASE RoleName WHEN ''db_datareader''
THEN ''1'' ELSE ''0'' END) AS db_datareader,
Max(CASE RoleName WHEN ''db_datawriter''
THEN ''1'' ELSE ''0'' END) AS db_datawriter,
Max(CASE RoleName WHEN
''db_denydatareader'' THEN ''1'' ELSE ''0'' END) AS db_denydatareader,
Max(CASE RoleName WHEN
''db_denydatawriter'' THEN ''1'' ELSE ''0'' END) AS db_denydatawriter
FROM (
SELECT b.name as USERName, c.name as
RoleName
FROM ' + '['+ @dbName +']' + '.dbo.sysmembers a ' +
CHAR(13) +
' JOIN ' + '['+ @dbName +']' + '.dbo.sysusers b ' + CHAR(13) +
' on a.memberuid =
b.uid
JOIN
' + '['+ @dbName +']' + '.dbo.sysusers c
on a.groupuid = c.uid )s
GROUP BY UserName
ORDER BY UserName'
--Print @mSql1
EXECUTE (@mSql1)
FETCH NEXT
FROM DBName_Cursor
INTO @dbname
END
CLOSE DBName_Cursor
DEALLOCATE DBName_Cursor
SELECT *
FROM #DBRoles
ORDER BY DBName, UserName
---
Comments
Post a Comment