Loginless In Seattle

  • Comments posted to this topic are about the item Loginless In Seattle

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

  • Hi Orlando,

    Nice article. However, I'm going to disagree with your method of looking at the length of the sid to determine whether this is a loginless user, or an orphaned user.

    In SQL 2012, the sys.database_principals catalog view was expanded to carry a few additional columns, including the authorization_type (and corresponding authorization_type_desc). If authorization_type = 0 (for authorization_type_desc = "NONE"), then this is a loginless user.

    Prior to SQL 2012, these columns did not exist. To check for loginless users, perform a LEFT JOIN to sys.sql_logins, which exists since 2005.

    Here's a quick example:

    IF NOT EXISTS (SELECT 1 FROM sys.server_principals WHERE name = 'monkey')

    CREATE LOGIN monkey WITH PASSWORD = 'monkey';

    GO

    CREATE USER monkey FROM LOGIN monkey;

    CREATE USER donkey WITHOUT LOGIN;

    -- SQL 2012 has the authentication_type & authentication_type_desc columns.

    SELECT name,

    type,

    type_desc,

    authentication_type,

    authentication_type_desc

    FROM sys.database_principals

    WHERE name IN ('donkey', 'monkey');

    -- prior to SQL 2012, you can left join to sys.sql_logins

    SELECT sp.name,

    sp.type,

    sp.type_desc,

    CASE WHEN sl.name IS NULL AND sp.type = 'S' THEN 0

    WHEN sp.type = 'S' THEN 2

    WHEN sp.type LIKE '[UG]' THEN 3

    END AS authentication_type, -- ignoring contained database users

    CASE WHEN sl.name IS NULL AND sp.type = 'S' THEN 'NONE'

    WHEN sp.type = 'S' THEN 'INSTANCE'

    WHEN sp.type LIKE '[UG]' THEN 'WINDOWS'

    END AS authentication_type_desc

    FROM sys.database_principals sp

    LEFT JOIN sys.sql_logins sl ON sp.sid = sl.sid

    WHERE sp.name IN ('donkey', 'monkey');

    GO

    DROP USER monkey;

    DROP USER donkey;

    DROP LOGIN monkey;

    Reference for sys.sql_logins: http://msdn.microsoft.com/en-us/library/ms174355.aspx

    Wayne
    Microsoft Certified Master: SQL Server 2008
    Author - SQL Server T-SQL Recipes


    If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
    Links:
    For better assistance in answering your questions
    Performance Problems
    Common date/time routines
    Understanding and Using APPLY Part 1 & Part 2

  • Thanks for having a look Wayne and for the nod. Also, congrats on recently becoming an MCM! That's an amazing accomplishment.

    I agree that using sys.sql_logins is a cleaner way to differentiate a Loginless User from a User linked to a Login but what I found when researching how to do this in my environment is that using the instance-level views only held up in the case when the User had not yet been orphaned. The scenario I tried to address in the article was to find Users that were presently orphaned meaning I needed a way to omit Loginless Users from the resultset.

    Consider this test case to see why I went after the SID:

    USE YourDatabaseName;

    GO

    IF NOT EXISTS (SELECT 1 FROM sys.server_principals WHERE name = 'monkey')

    CREATE LOGIN monkey WITH PASSWORD = 'monkey', CHECK_POLICY = OFF;

    GO

    CREATE USER monkey FROM LOGIN monkey;

    CREATE USER donkey WITHOUT LOGIN;

    -- run the query you showed as "prior to SQL 2012, you can left join to sys.sql_logins" to see what types of users these are

    SELECT dp.name,

    dp.type,

    dp.type_desc,

    CASE WHEN sl.name IS NULL AND dp.type = 'S' THEN 0

    WHEN dp.type = 'S' THEN 2

    WHEN dp.type LIKE '[UG]' THEN 3

    END AS authentication_type, -- ignoring contained database users

    CASE WHEN sl.name IS NULL AND dp.type = 'S' THEN 'NONE'

    WHEN dp.type = 'S' THEN 'INSTANCE'

    WHEN dp.type LIKE '[UG]' THEN 'WINDOWS'

    END AS authentication_type_desc

    FROM sys.database_principals dp

    LEFT JOIN sys.sql_logins sl ON dp.sid = sl.sid

    WHERE dp.name IN ('donkey', 'monkey');

    -- looks good, we can tell that monkey is a user with a Login and donkey

    -- is a Loginless User

    -- now let's orphan monkey

    DROP LOGIN monkey;

    -- run the same query again

    SELECT dp.name,

    dp.type,

    dp.type_desc,

    CASE WHEN sl.name IS NULL AND dp.type = 'S' THEN 0

    WHEN dp.type = 'S' THEN 2

    WHEN dp.type LIKE '[UG]' THEN 3

    END AS authentication_type, -- ignoring contained database users

    CASE WHEN sl.name IS NULL AND dp.type = 'S' THEN 'NONE'

    WHEN dp.type = 'S' THEN 'INSTANCE'

    WHEN dp.type LIKE '[UG]' THEN 'WINDOWS'

    END AS authentication_type_desc

    FROM sys.database_principals dp

    LEFT JOIN sys.sql_logins sl ON dp.sid = sl.sid

    WHERE dp.name IN ('donkey', 'monkey');

    -- according to the query monkey and donkey both look to be orphaned however we know that

    -- donkey is a loginless user and monkey used to have a login but was recently orphaned

    DROP USER monkey;

    DROP USER donkey;

    GO

    What I found was that as soon as the User was orphaned, i.e. when the Login was dropped, the metadata changed to my disadvantage making it impossible to differentiate a Loginless User from a regular, now-orphaned User:

    This behavior is was what pushed me towards deriving the information based on the length of the SID.

    I do like that there is a cleaner experience in SQL 2012. Thank you for bringing these new columns to my attention. I must admit that at the current shop I work almost exclusively with 2008 R2 with only some 2005 and a couple 2012 instances coming online soon so the method is targeted at 2005 and 2008 R2. I tested the method in the article on SQL 2012 and it seemed to hold up but if and when I am in a shop with only SQL 2012 I would probably switch to leverage the new columns. Here is what I came up with, adapted from what you shared:

    -- SQL 2012

    SELECT dp.name,

    dp.type,

    dp.type_desc,

    dp.authentication_type,

    dp.authentication_type_desc,

    sp.name

    FROM sys.database_principals dp

    LEFT JOIN sys.server_principals sp ON dp.sid = sp.sid

    WHERE dp.authentication_type_desc = N'INSTANCE'

    AND sp.name IS NULL;

    I tested the above query on regular and partially contained databases and it seemed to work well, although I did not do anything that could be considered exhaustive. The thing that seems to make this method hold up is that after dropping the Login the value of authentication_type_desc remains equal to 'INSTANCE'.

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

  • Orlando,

    Thanks.

    As much as I dislike using the length of the SID to differentiate orphaned users from loginless users, even MS in this blog post says that the only way to do so is by looking at the SID length. (sigh) I'm sure glad that this has been simplified in SQL 2012...

    Wayne
    Microsoft Certified Master: SQL Server 2008
    Author - SQL Server T-SQL Recipes


    If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
    Links:
    For better assistance in answering your questions
    Performance Problems
    Common date/time routines
    Understanding and Using APPLY Part 1 & Part 2

  • quite an informative article, thanks Orlando.

  • Nice informative article Orlando! Thanks!!

  • Sifiso, Rajeev, thanks for the positive feedback!

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

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

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