Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Script to get the list of users and permissions in a database


Script to get the list of users and permissions in a database

Author
Message
george sibbald
george sibbald
SSCertifiable
SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)

Group: General Forum Members
Points: 6328 Visits: 13687
..........which gives me another idea, use the cursor to insert into a temp table then select out of the table.

---------------------------------------------------------------------
Robin35
Robin35
SSC-Enthusiastic
SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)

Group: General Forum Members
Points: 145 Visits: 1069
george sibbald (4/11/2014)
there are two ways around this I can see - a simple workaround would be run the query so the output is in text mode, does that suit?? Also your SQL has an error in that it does not change database context in the loop, a use database statement needs to be part of the overall query, so that gives the following -

-- List out all users and user roles of all databases in a SQL Server instance
set nocount on
set quoted_identifier off
Declare @name varchar(100)
Declare @sqlstatement nvarchar(4000)
--move declare cursor into sql to be executed
Declare users_cursor CURSOR FOR Select name from sys.databases where database_id > 4

OPEN users_cursor
FETCH NEXT FROM users_cursor
INTO @name
WHILE @@FETCH_STATUS = 0
BEGIN
print 'Database ' + @name
set @sqlstatement = N'use [' + @name +']'+char(13)+N'select
convert(char(30),dp2.name) UserName,convert(char(20),dp2.type_desc) UserType, convert(char(20),dp.name) Role
FROM sys.database_principals dp
INNER JOIN sys.database_role_members drm ON dp.principal_id = drm.role_principal_id
INNER JOIN sys.database_principals dp2 ON drm.member_principal_id = dp2.principal_id
WHERE dp2.principal_id > 4 AND dp2.type <>'+'''R'''

exec sp_executesql @sqlstatement

FETCH NEXT FROM users_cursor --have to fetch again within loop
INTO @name
END
CLOSE users_cursor
DEALLOCATE users_cursor



An alternative is to use coalesce (built on the back of some SQL I cribbed from somewhere) This can have issues with collations. -

--===== Declare a variable to hold the command we're going to build
DECLARE @MyCmd nVARCHAR(MAX)
declare @name NVARCHAR(200)

--===== Build the command to interrogate every database as if we were using a cursor.
-- If you want to include report servers, we'll need to do those separately
-- because of collation problems with some of the names. You'd have this same
-- problem if you used a cursor to insert into one table.
SELECT @MyCmd = COALESCE(@MyCmd+' UNION ALL'+CHAR(10),'')
+ 'select '''+Name+''' AS DBName,convert(char(30),dp2.name) UserName,convert(char(20),dp2.type_desc) UserType, convert(char(20),dp.name) Role
FROM '+Name+'.sys.database_principals dp
INNER JOIN '+Name+'.sys.database_role_members drm ON dp.principal_id = drm.role_principal_id
INNER JOIN '+Name+'.sys.database_principals dp2 ON drm.member_principal_id = dp2.principal_id
WHERE dp2.principal_id > 4 AND dp2.type <>'+'''R'''
FROM Master.Sys.DataBases
WHERE DataBase_ID > 5
and name not like 'report%'


--===== Display, then execute the cursor
PRINT @MyCmd
EXEC (@MyCmd)



George, Thanks a lot. The second script with colation thing is working fine on our environment.....again thank you very much.....
george sibbald
george sibbald
SSCertifiable
SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)

Group: General Forum Members
Points: 6328 Visits: 13687
no problems, good to remind myself about it.

The where clause of database_id > 5 was to omit adventure_works for me, so ensure that value is what you want for your purposes

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