SQL Linked Server Query failed with “Login failed for user …”

SQL Linked Server Query failed with “Login failed for user …”

Rate This
  • Comments 75

SQL Server 2005: “Login failed for user 'NT AUTHORITY\ANONYMOUS LOGON'”.

SQL Server 2000: "Login failed for user "(null)". Reason: Not associated with a trusted SQL Server connection".

 

The errors listed above is very typical when deploy linked server with delegation. They actually are thrown by the linked server and pass by middle server to the client application. In this post, I will discuss how to properly configure SQL instances and Windows environment in most common scenario and try to make configuration steps as explicit as possible.

 

By using delegation in distributed query, such as linked server query, the SQL instance obtains impersonated token of the user logon credential to gain access to resources of another SQL instance, the linked server. In delegation setting, the client connection and linked server object are configured to use integrated authentication in SQL Server’s term as opposed to SQL login. Some time integrated authentication also referred as trusted connection or Windows authentication. Linked server login can also use SQL login, but it is not discussed here.

 

To simplify the discussion, let’s assume two SQL Server instances are installed on machine A and B respectively. Also, let’s assume A is the middle server that has a linked server object configured which points to a SQL instance on machine B. If the client is on machine C different from A, we call it double-hop setting; if the client is collocated with middle server machine A, we call it single-hop setting. In single-hop setting, it is relatively straightforward to configure linked server to work. Believe or not, double-hop setting requires more careful configurations as you will see. This is because in single-hop setting, windows NTLM authentication, which is available in most common setting if all machines are windows, is sufficient for delegation; while in double-hop setting, Kerberos authentication is mandate for flowing user’s credential through machine boundaries from the client to the linked server. It requires windows domain, correct DNS name resolution, proper account setting in both Active Directory and SQL Server.  To make sure Kerberos delegation [1] is correct becomes vital to operate distributed query with delegation. The authentication scheme required by delegation in different setting is illustrated by the following table.

 

Authentication scheme

C to A

A to B

Single hop

NTLM or Kerberos

(C is on the same box as A)

NTLM or Kerberos

Double hops

Kerberos

Kerberos

 

[Create Linked Server Object on Middle Server]

Before getting into details on how to configure other components, since I am talking about delegation in the context of SQL Server distributed query, let’s first give an example on how to configure a linked server object on A and set up its login to use delegation.  To do so, you need the following two steps.

 

(1) Use sp_addlinkedserver to create a linked server object and name it “LinkedServer” which points to the SQL instance on machine B, SQLB.

 

“EXEC sp_addlinkedserver @server=’LinkedServer’,

                                                 @srvproduct=''”,

                                                 @provider='SQLNCLI',

                                                 @datasrc=’SQLB’,--the data source

                                                 @provstr="Integrated Security=SSPI; "

To verify if the command is executed correctly, run query

select * from sys.servers where name='LinkedServer'”;

 

(2) Use sp_addlinkedsrvlogin to configure login to use self-mapping as following

exec sp_addlinkedsrvlogin ‘LinkedServer’, 'true'”

Step (2) makes middle server A try to use impersonated token of user to authenticate to server B. To verify that the linked server is setup for “self-mapping”, run query

 

select uses_self_credential as delegation

from sys.linked_logins as L, sys.servers as S

where S.server_id=L.server_id

            and S.name=N'LinkedServer'

 

The resulting table should show the delegation column is “1”.

 

[Test Linked Server Query in Single-hop Settting]

Before test-drive a link server query in single-hop setting, you need also make sure that the client user can make direct query to the SQL instances on both A and B. This means that the user account, either windows domain account or a machine account, must have permission to access both SQL instances.

 

(3) To verify the user domain account has permission to access both SQL instances, use your favorite client tool, for example,“osql –E –S SQLA” and “osql –E –S SQLB”. If you are failing for whatever reason, please refer to [5][6].

 

(4) To test linked server query, run query at SQLA,

“select * from LinkedServer.master.dbo.sysdatabases”.

 

 

[Configure and Test Double-hop Setting]

To deploy delegation based linked server in double-hop setting, the followings need to be configured correctly.

(3)   Kerberos in Windows mandates Windows domain. Therefore the user account needs to be a domain account and middle server and linked server need to join a domain. All machines involved in the delegation, including client machine, middle server and linked server, must have good TCP/IP connectivity between each other and to the domain controller and Active Directory. To not complicate thing further, we assume that A, B and C are in same Windows domain D and the user account is a domain account in D.

(4)   The user’s domain account must NOT select “Account is sensitive and cannot be delegated” in its Active Directory properties of domain D. Please refer to [1] on how to configure this on Active Directory machine.

(5)   The service account under which the SQL instance is running must be “trusted for delegation”, configured in Active Directory. If the service is running as “NT AUTHORITY\SYSTEM” or “NT AUTHORITY\NETWORK SERVICE”, the computer must be “trusted for delegation”. Please refer to [1] on how to configure this on Active Directory Machine. You need to have domain admin privilege to do/verify so.

(6)   The user domain account must have permission to access both SQL instances from C. To verify, use your favorite client tool, for example,“osql –E –S SQLA” and “osql –E –S SQLB”. If you are failing for whatever reason, please refer to [5][6].

(7)   If the SQL connections are to use TCP/IP connectivity, configure and verify that SQL connections from C to A and A to B are using Kerberos authentication. Please refer to [2] on how to configure Kerberos for SQL. In a nutshell, both services on machine A and B need to have a SPN created in Active Directory for SQL service. If the service running account is not “NT AUTHORITY\SYSTEM”, you need to configure the SPN on the Active Directory Machine with domain admin privileges. To verify that every hop is using Kerberos and TCP connectivity, run query

 

“select net_transport, auth_scheme from sys.dm_exec_connections where session_id=@@spid”

 

when (a) connect to A from C (b) connect to B from A. To make Kerberos work for both hops is crucial and some time it might not be very straightforward on what goes wrong. If fail to get Kerberos to work, please (a) verify If the SPNs are configured and well-formed according to [4]; use “setspn –L acccoutname” to verify the SPN (b) verify if DNS reverse lookups of both machine A and B return well-formed FQDNs. Use “ping –a machinename” on machine A, B and C to verify DNS works as expected, i.e. returning FQDN; (c) make sure that there is no cached Kerberos ticket on machine A and C. Use “klist purge” to purge all tickets. There might be delay before Windows local security authority (LSA) requests a new ticket from Active Directory. Sometime, you need to log out and log back in again before a new Kerberos ticket can take effect. For more Kerberos troubleshooting techniques, please refer to [3].

(8)   If the SQL connections are to use Named Pipe connectivity, SQL level Kerberos is not required as opposed to TCP connectivity. This is because Windows named pipe protocol can use Kerberos to authenticate logon user under the cover. You need to verify that both machine SPNs “HOST/machinename” and “HOST/ machineFQDN” is well-formed use “setspn –L machinename”.

 

(9)   Since double-hop can have combination of Named pipe connectivity on one hop and TCP on the other, the following table is valid configuration for delegation. Run query

 

“select net_transport, auth_scheme from sys.dm_exec_connections where session_id=@@spid”

 

when (a) connect to A from C (b) connect to B from A.

 

{net transport, auth_scheme}

C to A

A to B

1

NP, NTLM*

NP, NTLM*

2

TCP, Kerberos

NP, NTLM*

3

NP, NTLM*

TCP, Kerberos

4

TCP, Kerberos

TCP, Kerberos

* Note that even SQL shows NP is using NTLM at SQL level, Windows named pipe protocol can still use Kerberos under the cover ( the SMB/CIFS windows file system, upon which the named pipe is implemented, can use Kerberos) that allows Kerberos delegation.

 

After verifying the above 9 steps, finally we come to the point to run a double-hop linked query. If you still encounter issues after follow these steps, please send me the error message, your configuration, the output of the queries listed for every step and information required by [6].

 

In discussion above, we assume the A,B and C are in the same domain. If they are in different domains, apart from verifying 9 steps listed above, you also need to make the domains involved trust each other. 

 

Note that setspn.exe, klist.exe referred in this post can be downloaded as part of Windows resource kit. Kerberos delegation is only supported on windows 2000 and onward.

 

[Reference]

[1] Troubleshooting Kerberos Delegation. http://www.microsoft.com/technet/prodtechnol/windowsserver2003/technologies/security/tkerbdel.mspx

[2] Using Kerberos with SQL Server. http://blogs.msdn.com/sql_protocols/archive/2005/10/12/479871.aspx

[3] Troubleshooting Kerberos Errors. http://www.microsoft.com/technet/prodtechnol/windowsserver2003/technologies/security/tkerberr.mspx

[4] http://support.microsoft.com/kb/889615/en-us

[5] http://support.microsoft.com/?id=840219

[6] http://blogs.msdn.com/sql_protocols/archive/2006/04/21/581035.aspx

 

 

Nan Tu

Software Design Engineer, SQL Server Protocols

Disclaimer: This posting is provided "AS IS" with no warranties, and confers no rights

 

Leave a Comment
  • Please add 5 and 6 and type the answer here:
  • Post
  • Ming,

     First, a general observation, resulting from more testing on my part:

    2005 server StdEd sp1 (A) can't seem to double hop to any named instance (either 2000 or 2005).  2005 server Ent Ed SP1 (B) can double hop (pass credentials) to any of my 40+ servers (default or named instance).

    To answer your questions:

    1.  Same script created linked servers on both 'middle servers' A & B.  Both have 4 linkedserver accounts authorized for 'impersonation'...one of those is the 'serviceaccount'.  All linkedservers are set this way.

    2.  Client was queryanalyzer or SSMS on my workstation, so yes double-hop was required.

    3.  Yes, from my workstation using q/a or SSMS, i can log directly to any of the servers...

    4.  I don't know how to check that i'm using kerboros from my workstation out.

    5.  Both A, B are: WinSrv2003 SP1 Std Ed.

    6.  A is 2005 SP1 Std Edition

    7.  B is 2005 SP1 Ent Edition

    8.  A & B are on different boxes.

  • Ming,

     Another point: I logged on to my workstation as the SQLService account.  (The same SQLservice account is used to run SQl server and the agent account.)  I opened an SSMS session query to Server A.  

    1. Select * [C\I1].master.dbo.sysdatabases  FAILED (msg 18452)

    2. Executed a storedProc which has (different) distributed query to [C\I1].  SUCCEEDED!

    3. Re-ran query 1...SUCCEEDED!

    4. Waited 10 minutes. Re-ran query 1...FAILED.

    Can you help me understand what is happening here?

  • Hi Steve,

    This sounds like linked server connection pooling is making the hop succeed.  To prove if this is the case, try running:

    DBCC FREESYSTEMCACHE ('ALL')

    After step 2.  If this causes step 3 to fail, then you are just reusing the authenticated connection you created in step 2.  Pooling auto shuts down the connection in around 8 mins so this is why it fails later.

  • This double-hop kerberos issue with linked servers in SQL2005 is an actual MS bug and is resolved with SP2:  http://support.microsoft.com/default.aspx?scid=kb;en-us;921896

    or hotfix 925843 (http://support.microsoft.com/kb/925843/)  

    Cheers

    Wendy

  • Matt, Thanks for your comment.  That did help me understand the connection pooling issue.

    Ming, (or Matt)

    Could there be a difference in SQL server versions linked server functionality?  My 3 SQL 2005 Enterprise versions are all able to double hop to named instances.  The Standard Edition server is only able to double hop to default instances.

    Thanks for any input!

  • Wendy,

     I didn't see your comment until after i posted my last note.  To be more specific: my 2005 Enterprise versions can all double hop to 2000 named instances.  My one 2005 Std edition can only double hop to 2000 default instances.  The fixes you refer to relate to 2005 to 2005 double hopping.

    Thanks.

  • I am experiencing the same problem. Only the edition I have is Developers Edition. I applied service pack 2 and am still getting the error when I try to run a distributed query from my pc to a SQL server 2005 (developer's ed) that has a linked server to a SQL server 2000 (standard edition).

    Does anyone know if it's because of sql editions that this problem occurs.

    Thanks

    Lyn

  • I AM CREATE USER ACCOUNT BUT GOT THE MESSAGE "CANNOT FIND LOGON CODE <USER NAME> ON THE DATABASE WHIL CONNECTING FROM THE USER PC.PLS WHAT DO I DO TO SOLVE THIS PROBLEM

  • I have an "Authentication scheme" double hop.

    When I make my connection from the client to server "A" and then by linked server to server "B", it doesn´t work, when I run the query "“select net_transport, auth_scheme from sys.dm_exec_connections where session_id=@@spid” I have: NAME PIPES/NTLM.

    In the other hand when I make the connection from the client to server "B" and then by linked server to server "A", it works, and my net transport is TCP/KERBEROS.

    How can I change the net transport of my server "A" to TCP/KERBEROS?????

    Thanks....

  • Thank you for this useful post.

    Is there any special cases for 64bit Sql Servers?

    I have configured the system using this article. All the servers now looks good, and only x64 machine does not use kerberos while connecting to other servers.

    Any ideas?

    Thanks in advance

  • more specific answer for "Login fail NT Authority\Network Service"

  • I finally figured it out.  Here is the simple answer:

    On server B, the server where you add the linked server, go into SQL Server configuration manager and disable Named Pipes under SQL Server 2005 Network Configuration > Protocols for MSSQLSERVER.

    You should only have Shared Memory and TCP enabled under this setting.  

    After I made this change, I was able to execute a linked query from server C to A.  

    Jason

  • Also, running

    "select net_transport, auth_scheme from sys.dm_exec_connections where session_id=@@spid"

    from Server B should yield Shared Memory and NTLM.

    running it from Server B should yield TCP and NTLM.

    I hope this helps.

    Jason

  • Correction:

    running

    "select net_transport, auth_scheme from sys.dm_exec_connections where session_id=@@spid"

    from Server B should yield Shared Memory and NTLM.

    running it from Server C should yield TCP and NTLM.

    I hope this helps.

    Jason

  • Double hopes are working fine in my environment using Domain Authentication. They connect as KERBEROS. The issue is that after 8 hours it seems that the Token expires and the connection falls back to NTML. At that point double hop does not longer work. I need to close the connection and reopen.

    The issue I am facing is that it is not possible for us to reset a database connection from a .NET application, and seems that some of those connections are lasting over 8 hours.

    Any advice?

Page 2 of 5 (75 items) 12345