SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Query/ Procedure to Generate list of logins and the DB access and their roles


Query/ Procedure to Generate list of logins and the DB access and their roles

Author
Message
iamsrahul
iamsrahul
Valued Member
Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)

Group: General Forum Members
Points: 60 Visits: 23
Hi All

I have requirement where i need to generate a list of users who can login into the sql server 2000 and what are all the database they can access and their roles. I got some information from this link

http://www.sqlservercentral.com/articles/Administration/listofdatabaseuserswithdatabaseroles/1545/

After executing this I got a list of all users and their database access and roles. Then I realized something was missing. I used to login to sql server 2000 and execute sql statements. I am local system admin. I can see a login named Builtin\Administrator under security and this has access to all database as db_public and db_owner.

Here i have 2 questions
1. Why is Builtin\administrators not listed ? doest that mean that the procedure and query given in the link is wrong.
2. I can see certain users who has access to few of the databases. But these users are not in the login section under security. How can a user have access to database without a login ?


I would be extremely thankfull to you could clarify my queries.

Thanks in advance
Rahul
Lowell
Lowell
SSC Guru
SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)

Group: General Forum Members
Points: 68302 Visits: 40898
i think it's due to the query; do a select * from sysusers in any database. there's no Builtin\Administrators in that list.

the query is not showing implicit users who have access regardless of whether you added them or not; those users like sa get access because they are sysadmins, they do not need to be added to each db's sysusers list. It's just getting explicitly granted users and their permissions.

Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
iamsrahul
iamsrahul
Valued Member
Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)Valued Member (60 reputation)

Group: General Forum Members
Points: 60 Visits: 23
HI Lowell

Thanks a lot for your response. Whats the correct query to show all implicit users as well.

Thanking you
Rahul
smareano
smareano
Grasshopper
Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)

Group: General Forum Members
Points: 10 Visits: 290
If you found a solution for ...whats the correct query to show all implicit users as well...please post. Thanks
Lowell
Lowell
SSC Guru
SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)SSC Guru (68K reputation)

Group: General Forum Members
Points: 68302 Visits: 40898
well, i'd start with implicit users that come from windows groups:

select *
from master.sys.server_principals
where type_desc = 'WINDOWS_GROUP'



from there, for each name in the list, you can use a built in extended stored procedure which queries Active directory to enumerate all the users in the group

EXEC master..xp_logininfo
@acctname = 'disney\authenticatedusers', --an example windows group, where my domain is "disney"
@option = 'members' -- show group members

EXEC master..xp_logininfo
@acctname = 'Builtin\Administrators',
@option = 'members' -- show group members



Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
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