Get all the domain and SQL users from an instance, per database

  • Hello,

    For SQL 2k5, 2K8 and 2K8R2, I need a T-SQL query to get all the users listed in:

    SSMS => "Instance" => "DB" => "Security" => "Users" Except 'dbo','guest','sys','INFORMATION_SCHEMA' for all the users databases of my instances. I hope it's clear enough 🙂

    I guess I have to use sp_MSForEachDB but I can't find myself query that returns just what I want. I have always too much informations/users in the resultset...

    Anyone has had to write it once ?

    Thanks in advance.

    Regards.

    Franck.

  • this should get you what you want per database (without excluding any users)

    select name from sys.database_principals

    where type in ('S','G','U')

    give it a try with sp_msforeachdb and post back if you are still having issues.

    Bob
    -----------------------------------------------------------------------------
    How to post to get the best help[/url]

  • First of all, thanks for your reply.

    This:

    exec sp_MSforeachdb 'select name

    from sys.database_principals

    where type in (''S'',''G'',''U'')

    and name not in (''dbo'',''guest'',''sys'',''INFORMATION_SCHEMA'',''##MS_PolicyEventProcessingLogin##'')'

    Always give me 2 results for all the databases, per instance, though I've a lot more users mapped to my DB's.

    To be clear, on instance A, i've the users 1,2,3,4,5 mapped to different databases in the instance.

    On instance B, i've the users 6,7,8,9,10 mapped to the different databases.

    The resultset of instance A is:

    DB1: 1,2

    DB2: 1,2

    DB3: 1,2

    .

    .

    .

    Though user 4 and 5 have also access to DB1 and DB2... for example.

    On instance B:

    DB1: 7,8

    DB2: 7,8

    DB3: 7,8

    .

    .

    .

    Though user 9 and 10 have also access to DB1 and DB2... for example.

    I don't know if it's normal...

    I hope this message is clear enough :-).

    Franck.

  • you have to qualify the database in the query with a ?. you can also load the result into a table to make them searchable

    CREATE TABLE #tmp(dbname VARCHAR(256),username VARCHAR(256))

    INSERT #tmp EXEC sp_MSforeachdb 'select ''?'',name

    from [?].sys.database_principals

    where type in (''S'',''G'',''U'')

    and name not in (''dbo'',''guest'',''sys'',''INFORMATION_SCHEMA'',''##MS_PolicyEventProcessingLogin##'')'

    SELECT *

    FROM #tmp

    Bob
    -----------------------------------------------------------------------------
    How to post to get the best help[/url]

  • Hey, this looks like what i was expecting to get !

    Thanks a lot 🙂 !

  • Hi,

    I would not rely too much on sp_MSforeachdb because it might skip one or several databases on a busy server.

    Also I would not skip dbo either, dbo can be mapped to a login other than sa therefore, when it happens you want to know about it.

    Please find below the query I use to get all the databases users:

    DECLARE @SQLCMDDBUser NVARCHAR(MAX)

    IF object_id('tempdb..#DBUserTable','U') IS not NULL DROP TABLE #DBUserTable

    CREATE TABLE #DBUserTable

    ([ServerName] [sysname] NOT NULL,

    [DBName] [sysname] NOT NULL,

    [UserName] [sysname] NOT NULL,

    [MappedLogin] [nvarchar](128) NULL,

    [UserType] [nvarchar](60) NOT NULL,

    [CreateDate] [datetime] NULL,

    [ModifyDate] [datetime] NULL,

    [IsOrphan] [int] NOT NULL)

    SELECT @SQLCMDDBUser=coalesce(@SQLCMDDBUser,'') + CHAR(13) + CHAR(10) + ' use ' + QUOTENAME([name]) + ';

    INSERT INTO #DBUserTable

    SELECT

    @@ServerName As ServerName,

    DB_NAME() As DBName,

    DP.name As UserName,

    SP.name As MappedLogin,

    DP.type_desc AS UserType,

    DP.create_date As CreateDate,

    DP.modify_date As ModifyDate,

    Case

    WHEN SP.sid Is Null THEN 1

    ELSE 0

    END As IsOrphan

    FROM ' + QUOTENAME([name]) + '.sys.database_principals DP LEFT JOIN master.sys.server_principals SP ON DP.sid = SP.sid

    WHERE

    DB_Name() NOT IN (''model'',''tempdb'') AND

    DP.type NOT IN (''R'')AND

    DP.is_fixed_role <> 1 AND

    DP.sid NOT IN (0x01,0x00) AND

    DP.sid IS NOT NULL AND

    DP.name NOT LIKE ''##%''

    ORDER BY DBName,UserName;' FROM master.sys.databases WHERE name NOT IN ('tempdb','model') AND state_desc = 'ONLINE' ORDER BY name

    EXECUTE(@SQLCMDDBUser)

    SELECT * FROM #DBUserTable

    DROP TABLE #DBUserTable

    Regards.

  • I played with all the scripts on this page and have looked before for something like this. This is beautiful.

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply