Posts tagged Logins

Sql Server and SSPI handshake failed error hell

The infamous SSPI Failed error strikes again!

One of our SQL servers was generating these errors for “some” Windows logins but not all.

Error: 17806, Severity: 20, State: 2.

SSPI handshake failed with error code 0x8009030c while establishing a connection with integrated security; the connection has been closed. [CLIENT: 192.168.1.1]

Error: 18452, Severity: 14, State: 1.

Login failed for user ”. The user is not associated with a trusted SQL Server connection. [CLIENT: 192.168.1.1]

After exhausting all of the normal troubleshooting for this error (accounts locked, disabled, Sql Service accts, bad connection strings, SPN’s, etc.) I spent the next few hours learning more about the way SQL handles authentication requests than I had ever wanted to know.

The Scenario –

A couple of separate individual Windows ID’s started generating these errors while attempting connections, all other windows logins were working properly. The connections were initially happening through applications, but also occurred through sqlcmd. When logged in to the server locally with the offending ID’s the connections to SQL would succeed.

The Troubleshooting process –

Check all the regular SSPI issues, I wont bore you with the details as they are easily searchable

  • A relatively easy way of checking the “easy” authentication issues If possible/appropriate is to log into the SQL Server locally with the offending ID and fire up sqlcmd and connect to the server via sqlcmd –Sservername,port –E  (by specifying the port you force TCP/IP instead of LPC, thereby forcing the network into the equation)

Verify whether the login is trying to use NTLM or Kerberos (many ways to do this but simplest is to see if there are any other KERBEROS connections on the machine)

  • SELECT DISTINCT auth_scheme FROM sys.dm_exec_connections
  • If Kerberos is in use, there are a few additional things to verify related to SPN’s, since only NTLM was in use on this server I skipped that

Determine if the accounts were excluded from connecting to the machine through the network through a group policy or some other AD setting

After all of these checked out OK, I began to try and figure out what the error code 0x8009030c meant, turns out, its fairly obvious what the description is : sec_e_logon_denied.  This description was so helpful I thought about making this server into a boat anchor but, luckily for my employer the server room is located many miles away and has armed guards.

Since I knew we could logon locally to the SQL Server with the ID that SQL was rejecting with logon denied something else was trying to make my life miserable.

We didn’t have logon failure security auditing turned on so, I had no way of getting a better error description, As luck would have it though this would prove instrumental in finding the root cause. To get a better error message, I found this handy KB article detailing steps needed to put net logon into debug mode.

Say hello to my new best friend!  — nltest.exe

After downloading nltest & using it to enable netlogon debugging on the SQL Server, I got this slightly better message in the netlogon.log file

06/15 14:15:39 [LOGON] SamLogon: Network logon of DOMAIN\USER from Laptop Entered

06/15 14:15:39 [CRITICAL] NlPrintRpcDebug: Couldn’t get EEInfo for I_NetLogonSamLogonEx: 1761 (may be legitimate for 0xc0000064)

06/15 14:15:39 [LOGON] SamLogon: Network logon of DOMAIN\USER from Laptop Returns 0xC0000064

The error code 0XC0000064 maps to “NO_SUCH_USER”

Since I was currently logged in to the server with the ID that was returning no such user, something else was obviously wrong, and luckily at this point I knew it wasn’t SQL.

Running “set log” on the server revealed that a local DC (call it DC1) was servicing the local logon request.

After asking our AD guys about DC1 and its synchronization status, as well as whether the user actually existed there, everything still looked OK.

After looking around a bit more I discovered this gem of a command for nltest to determine which DC will handle a logon request

C:\>nltest /whowill:Domain Account

[16:32:45] Mail message 0 sent successfully (\MAILSLOT\NET\GETDC579)
[16:32:45] Response 0: DC2 D:Domain A:Account (Act found)
The command completed successfully

Even though this command returned “act found” it was returning from DC2.  (I dont exactly understand why the same account would authenticate against 2 different DC’s based on a local desktop login or a SQL login but it apparently can)

After asking the AD guys about DC2 the light bulbs apparently went off for them as that server actually exists behind a different set of firewalls, in a totally different location. While DC2 would return a ping, the console wouldn’t allow logons for some reason. After a quick reboot of DC2, and some magic AD pixie dust (I am not an AD admin, if it wasn’t totally obvious from my newfound friend nltest) the windows Id’s that were having trouble started authenticating against DC3 and our SSPI errors went away.

Interesting tidbit — During troubleshooting, I found that this particular SQL Server was authenticating accounts against at least 5 different DC’s. Some of this might be expected since there are different domains at play but, I haven’t heard a final answer from the AD guys about whether it should work that way.

The solution

Reboot the misbehaving DC, of course there may be other ways to fix this by redirecting requests to a different DC without a reboot but, since it was misbehaving anyway, and the AD experts wanted to reboot so we went with that. A reboot of SQL would have likely solved this problem too but, I hate reboot fixes of issues, they always seem to come back!

SQL Active Directory User ID SID Mismapings

Sometimes login mapping issues exist where you least expect them

This is not the traditional SQL login SID mismap issue that is frequently encountered and discussed here. This mismap was a new one on me so I thought id document it.

When trying to add a new Windows login for SQL Server 2005 or 2008 (probably earlier versions but not tested) you may wind up with this error message

Msg 15025, Level 16, State 2, Line 1

The server principal 'DXXXX\UXXX' already exists.

Contrary to the error message, If we need to proove the account doesnt exist, the following code should suffice

select name from sys.server_principals where name = ‘DXXXX\UXXX’

SQL wont let you create an account because it thinks it already exists, but clearly the account doesnt exist.

How did this happen?

If a login was created previously for a windows account that has since been renamed in the active directory you cannot grant the new userid access to the SQL server because the SID already exists in SQL and you cannot duplicate it.  This occurs when renaming an account in Active directory, because the SID is reused instead of recreated.

Find the pre-existing SID

The SID from Active directory can be obtained many ways, the one I use is PsGetsid which can be obtained here the syntax you’d use for this is

PsGetSid DOMAIN\USER (or DXXXX\UXXX from earlier)

This will return the SID in the SDDL Format of S-x-x-x-x

Unfortunately SQL Stores the binary representation of the SID not the SDDL format.  You have several choices to do the mapping, you can hand figure out the SDDL mappings from sys.server_principals using this page  Or the better way -> Todd Engen had found some need to convert this before and designed a great function to do this conversion from binary to SDDL , im only going to list it here for completeness, the original is found here
CREATE FUNCTION fn_SIDToString
(
@BinSID AS VARBINARY(100)
)

RETURNS VARCHAR(100)
AS BEGIN
 
  IF LEN(@BinSID) % 4 <> 0 RETURN(NULL)
 
  DECLARE @StringSID VARCHAR(100)
  DECLARE @i AS INT
  DECLARE @j AS INT
 
  SELECT @StringSID = 'S-'
     + CONVERT(VARCHAR, CONVERT(INT, CONVERT(VARBINARY, SUBSTRING(@BinSID, 1, 1))))
  SELECT @StringSID = @StringSID + '-'
     + CONVERT(VARCHAR, CONVERT(INT, CONVERT(VARBINARY, SUBSTRING(@BinSID, 3, 6))))
 
  SET @j = 9
  SET @i = LEN(@BinSID)
 
  WHILE @j < @i
  BEGIN
    DECLARE @val BINARY(4)
    SELECT @val = SUBSTRING(@BinSID, @j, 4)
    SELECT @StringSID = @StringSID + '-'
      + CONVERT(VARCHAR, CONVERT(BIGINT, CONVERT(VARBINARY, REVERSE(CONVERT(VARBINARY, @val)))))
    SET @j = @j + 4
  END
  RETURN ( @StringSID )
END

 

After creating this function use it like so

select name from sys.server_principals where dbo.fn_SIDToString(sid)=‘S-X-X-X-X’ where the ‘S-X-X-X-X’ is the SID obtained earlier from PsGetSid

This should return the name of the user that has the offending “duplicate” SID

Once you know the logon ID that has been renamed you can script out the permissions of that ID (hopefully it doesn’t own any objects), drop it, and recreate it with the appropriate name and grant any additional permissions

Go to Top