Skip to main content

Script to show all database and server roles and their members

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):

/********************************************************************************************
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

Popular posts from this blog

SAN performance testing using SQLIO

Introduction This document describes how to use Microsoft’s SQLIO to test disk/SAN performance. It is biased towards SQL Server – which uses primarily 64KB and 8KB data pages so I am running the tests using those cluster sizes, however, other sizes can be specified.  Download SQLIO from https://www.microsoft.com/en-gb/download/details.aspx?id=20163   SQLIO is a command line tool with no GUI so you need to open a command prompt at  C:\Program Files (x86)\SQLIO  after you have installed it. Configuration First of all edit param.txt so that you create the test file we will be using. The file needs to be bigger than the combined RAID and on-board disk caches. In this case we are using a 50GB file. The “ 2”  refers to the number of threads to use when testing, you don’t need to change this now. The “ 0x0”  value indicates that all CPUs should be used, which you probably don’t want to change either, “ #”  is a comment. The o...

How to configure the SSAS service to use a Domain Account

NB Updating SPNs in AD is not for the faint hearted plus I got inconsistent results from different servers. Do so at your own risk! If you need the SSAS account on a SQL Server to use a domain account rather than the local “virtual” account “NT Service\MSSQLServerOLAPService”. You may think you just give the account login permissions to the server, perhaps give it sysadmin SQL permissions too. However, if you try and connect to SSAS  remotely  you may get this error: Authentication failed. (Microsoft.AnalysisService.AdomdClient) The target principal name is incorrect (Microsoft.AnalysisService.AdomdClient) From Microsoft: “A Service Principle Name (SPN) uniquely identifies a service instance in an Active Directory domain when Kerberos is used to mutually authenticate client and service identities. An SPN is associated with the logon account under which the service instance runs. For client applications connecting to Analysis Services via Kerberos authentic...

The AcquireConnection method call to the connection manager failed with error code 0xC0202009

I had one of those annoying problems with executing a SSIS package that took up most of the morning today (and a couple of hours yesterday) where you get an error which many people have had, but none of their solutions work. I guess it is such a generic error code it can relate to many different issues hence dozens of different (wrong) suggestions. What confused matters was that although it completed successfully in SSDT, it failed when being validated on our newly created SSISDB Catalog. I didn't know whether it was a problem with the package and/or its parameters or the SSISDB Catalog installation or Environment. If you haven't set up an Integration Services Catalog (a new feature of SQL 2012) yet I definitely think it is worth looking at. I found an excellent guide here that takes you through it all. In our case we had two connection managers, the source was a table in a SQL Server 2012 database and the destination a table in an Access 2010 database. The server with the ...