List orphaned users from all databases

  • Comments posted to this topic are about the item List orphaned users from all databases

    James Howard

  • So I expanded a little on your original script by creating the create and drop statements. The create statements are commented out but are there in case you delete a user that you really wanted.

    /*************************************************

    ** Purpose: To return database users (for each db) orphaned from any login.

    ** Created By: James Howard

    ** Created On: 03 DEC 09

    ** Modified By: Bob Cole

    ** Modified On: 29 Dec 09 - Added script to render create and drop statements.

    ** The create statements are commented out but are there in case you delete a

    ** user that you really wanted.

    *************************************************/

    --create a temp table to store the results

    CREATE TABLE #temp (

    DatabaseName NVARCHAR(50),

    UserName NVARCHAR(50)

    )

    --create statement to run on each database

    declare @sql nvarchar(500)

    SET @sql='select ''?'' as DBName

    , name AS UserName

    from [?]..sysusers

    where (sid is not null and sid <> 0x0)

    and suser_sname(sid) is null and

    (issqlrole <> 1) AND

    (isapprole <> 1) AND

    (name <> ''INFORMATION_SCHEMA'') AND

    (name <> ''guest'') AND

    (name <> ''sys'') AND

    (name <> ''dbo'') AND

    (name <> ''system_function_schema'')

    order by name

    '

    --insert the results from each database to temp table

    INSERT INTO #temp

    exec SP_MSforeachDB @sql

    --return results

    --SELECT * FROM #temp

    SELECT 'USE ' + DatabaseName + CHAR(10)

    + '--GO ' + CHAR(10)

    + '--CREATE USER ' + UserName + ' WITHOUT LOGIN WITH DEFAULT_SCHEMA=[' + UserName + ']' + CHAR(10)

    + '--GO ' + CHAR(10)

    + '' + CHAR(10)

    + 'IF EXISTS (SELECT * FROM sys.database_principals WHERE name = N''' + UserName + ''')' + CHAR(10)

    + 'BEGIN' + CHAR(10)

    + 'DROP SCHEMA [' + UserName + ']' + CHAR(10)

    + 'DROP USER [' + UserName + ']' + CHAR(10)

    + 'END'

    + 'GO' + CHAR(10)

    + '' + CHAR(10)

    + '--------------------------------------------------------------------------------' + CHAR(10)

    + '' + CHAR(10)

    FROM #temp

    DROP TABLE #temp

    ----------------------------------------------------------------------------

  • Good thinking Bob, thanks!

    James Howard

  • cute script, but fails with error:

    "Msg 8152, Level 16, State 13, Line 1

    String or binary data would be truncated."

    there is also another much shorter script for this (which actually works):

    EXEC sp_MSforeachdb @command1='use ?

    select db_name();

    exec ?.dbo.sp_change_users_login ''Report'';'

  • Hi,

    When I run this to find out the users... the results page are returned as error. which is below

    Msg 2812, Level 16, State 62, Line 31

    Could not find stored procedure 'SP_MSforeachDB'.

    (0 row(s) affected)

  • The script does not take into account Database Users that were created without a login, a.k.a. loginless users.

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • smokin_bob (12/29/2009)


    So I expanded a little on your original script by creating the create and drop statements. The create statements are commented out but are there in case you delete a user that you really wanted.

    /*************************************************

    ** Purpose: To return database users (for each db) orphaned from any login.

    ** Created By: James Howard

    ** Created On: 03 DEC 09

    ** Modified By: Bob Cole

    ** Modified On: 29 Dec 09 - Added script to render create and drop statements.

    ** The create statements are commented out but are there in case you delete a

    ** user that you really wanted.

    *************************************************/

    --create a temp table to store the results

    CREATE TABLE #temp (

    DatabaseName NVARCHAR(50),

    UserName NVARCHAR(50)

    )

    --create statement to run on each database

    declare @sql nvarchar(500)

    SET @sql='select ''?'' as DBName

    , name AS UserName

    from [?]..sysusers

    where (sid is not null and sid <> 0x0)

    and suser_sname(sid) is null and

    (issqlrole <> 1) AND

    (isapprole <> 1) AND

    (name <> ''INFORMATION_SCHEMA'') AND

    (name <> ''guest'') AND

    (name <> ''sys'') AND

    (name <> ''dbo'') AND

    (name <> ''system_function_schema'')

    order by name

    '

    --insert the results from each database to temp table

    INSERT INTO #temp

    exec SP_MSforeachDB @sql

    --return results

    --SELECT * FROM #temp

    SELECT 'USE ' + DatabaseName + CHAR(10)

    + '--GO ' + CHAR(10)

    + '--CREATE USER ' + UserName + ' WITHOUT LOGIN WITH DEFAULT_SCHEMA=[' + UserName + ']' + CHAR(10)

    + '--GO ' + CHAR(10)

    + '' + CHAR(10)

    + 'IF EXISTS (SELECT * FROM sys.database_principals WHERE name = N''' + UserName + ''')' + CHAR(10)

    + 'BEGIN' + CHAR(10)

    + 'DROP SCHEMA [' + UserName + ']' + CHAR(10)

    + 'DROP USER [' + UserName + ']' + CHAR(10)

    + 'END'

    + 'GO' + CHAR(10)

    + '' + CHAR(10)

    + '--------------------------------------------------------------------------------' + CHAR(10)

    + '' + CHAR(10)

    FROM #temp

    DROP TABLE #temp

    ----------------------------------------------------------------------------

    + CHAR(10) is missing from the END statement. I'm going to post a corrected and enhanced version.

  • This version fixes the small mistake of the last and outputs the database name and username along with the drop statement to make it easier to see the users per database and have the drop statement available if required

    /*************************************************

    ** Purpose: To return database users (for each db) orphaned from any login.

    ** Created By: James Howard

    ** Created On: 03 DEC 09

    ** Modified By: Bob Cole

    ** Modified On: 29 Dec 09 - Added script to render create and drop statements.

    ** The create statements are commented out but are there in case you delete a

    ** user that you really wanted.

    ** Modified By: Matt Bryant

    ** Modified On: 22 Apr 15 - Fixed a small issue with the create and drop statement

    ** missing a carriage return and combined the results of the first incarnation.

    *************************************************/

    --create a temp table to store the results

    CREATE TABLE #temp (

    DatabaseName NVARCHAR(50),

    UserName NVARCHAR(50)

    )

    --create statement to run on each database

    declare @sql nvarchar(500)

    SET @sql='select ''?'' as DBName

    , name AS UserName

    from [?]..sysusers

    where (sid is not null and sid <> 0x0)

    and suser_sname(sid) is null and

    (issqlrole <> 1) AND

    (isapprole <> 1) AND

    (name <> ''INFORMATION_SCHEMA'') AND

    (name <> ''guest'') AND

    (name <> ''sys'') AND

    (name <> ''dbo'') AND

    (name <> ''system_function_schema'')

    order by name

    '

    --insert the results from each database to temp table

    INSERT INTO #temp

    exec SP_MSforeachDB @sql

    --return results

    --SELECT * FROM #temp

    SELECT *,'USE ' + DatabaseName + CHAR(10)

    + '--GO ' + CHAR(10)

    + '--CREATE USER ' + UserName + ' WITHOUT LOGIN WITH DEFAULT_SCHEMA=[' + UserName + ']' + CHAR(10)

    + '--GO ' + CHAR(10)

    + '' + CHAR(10)

    + 'IF EXISTS (SELECT * FROM sys.database_principals WHERE name = N''' + UserName + ''')' + CHAR(10)

    + 'BEGIN' + CHAR(10)

    + 'DROP SCHEMA [' + UserName + ']' + CHAR(10)

    + 'DROP USER [' + UserName + ']' + CHAR(10)

    + 'END' + CHAR(10)

    + 'GO' + CHAR(10)

    + '' + CHAR(10)

    + '--------------------------------------------------------------------------------' + CHAR(10)

    + '' + CHAR(10) AS [Drop Statement]

    FROM #temp

    DROP TABLE #temp

  • matthew.hudsonbryan (4/22/2015)


    This version fixes the small mistake of the last and outputs the database name and username along with the drop statement to make it easier to see the users per database and have the drop statement available if required...<truncated>

    Hi Matthew,

    Thank you for taking the time to contribute an improvement to the script posted in the article, presumably from you picking it up and using it for your own admin needs. I posted on this thread in 2013 so received an email when you posted your comment. So that you are not sideswiped by the script and also to let other readers of this thread know not to use this script as-is, or even any close derivation of it, know that it has some major flaws that need to be addressed.

    Here are some things you should consider:

    1. the script still does not take into account Loginless Users so if you use this script as-is you have a chance of dropping a valid user: more reading[/url]

    2. the script uses sysusers, a compatibility view, and should be updated to use sys.database_principals: more reading

    3. the script uses undocumented proc sp_MSForEachDB which has gaping holes in it so be careful using it: more reading

    4. the script does not considers users in contained databases where the database manages the authentication: more reading

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

Viewing 9 posts - 1 through 8 (of 8 total)

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