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

  • Good day!

    Don't know much about security, but I've created my web service function to return a dataset from SQL Server 2000. When I invoked the function it is giving me this error in the page although I can generate a dataset and connect to the db, only when invoking the web service that I'm getting this.

    Need help please.

    Thanks

  • usual reason for this error is the sql instance is set to only accept windows authenticated logins but you are trying to connect with a sql authenticated ID. check the properties on your sql instance.

    If this is your problem will need to change authentication mode to windows and sql authentication, which will require a sql bounce to take effect.

    ...or connect with a windows id, which is more secure

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

  • When you connect, you use your credentials, likely your Windows account. When the web service connects, it's probably using different credentials, probably IIS credentials. Be sure those have access to the SQL server.

  • I'm having the exact same issue when using a linked server on a SQL Server 2005 instance (target is a SQL 2000 instance).

    The exact error is:

    OLE DB provider "SQLNCLI" for linked server "server\instance" returned message "Communication link failure".

    Msg 10054, Level 16, State 1, Line 0

    TCP Provider: An existing connection was forcibly closed by the remote host.

    Msg 18452, Level 14, State 1, Line 0

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

    The user getting this error is able to successfully connect to the target instance on SSMS, while logged on the source sql 2005 instance where the linked server is created.

    The linked server is created by the following command (note that security is configured for windows integrated auth., NOT SQL auth.):

    EXEC sp_addlinkedserver 'server\instance2k', N'SQL Server';

    The user is getting the error above after running:

    select * from [server\instance2k].DBNAME.dbo.TableName;

    I find this issue odd because, as I mentioned, the user is able to connect with no problems to server\instance2k on SSMS, while logged on the sql2005 instance.

    I strongly suspect this is the exact same problem as that posted initially on this thread.

    __________________________________________________________________________________
    SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
    Persisting SQL Server Index-Usage Statistics with MERGE[/url]
    Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]

  • You need to check the linked server credentials to see what's there. You can either have set credentials for everyone, rights for some people and not others, or pass through credentials.

    Check in SSMS how the linked server security is configured.

  • Connections are made using the login's current security context.

    So in the following query, the login running the query is the same account in whose context the connection is attempted:

    SELECT * from [server\instance2k].dbName.dbo.tblName;

    The puzzling thing is that the same user is able to connect to instance server\instance2k through SSMS, while logged on the instance hosting the linked server.

    __________________________________________________________________________________
    SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
    Persisting SQL Server Index-Usage Statistics with MERGE[/url]
    Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]

  • Marios Philippopoulos (3/22/2008)


    Connections are made using the login's current security context.

    So in the following query, the login running the query is the same account in whose context the connection is attempted:

    SELECT * from [server\instance2k].dbName.dbo.tblName;

    The puzzling thing is that the same user is able to connect to instance server\instance2k through SSMS, while logged on the instance hosting the linked server.

    In your case it is pretty clear what the problem is (not so clear for the OP, who had less detail). What you are running into is almost certainly the "Two Hop Rule", which is that under windows domain security, an impersonated security context cannot re-impersonate (that is, it cannot generate the same impersonation on another server).

    This is relevant because when you connect from a client to the SQL Server, it impersonates you to generate the security context. In order to get to the linked server using Trusted connections, the security context of your server session would have to be re-impersonated on the target server, and that is not allowed. So even though you can connect directly from your client to both servers, you cannot connect from you client to the first server and then through that to the linked server, because that would be a two-hop impersonation.

    The way to test to see if this is really the problem is to find a way to get a session on your SQL server without it having to be impersonated and then try to connect to the linked server from there. I know of two ways to do this:

    1) Log on to your server at the console or through Remote Desktop, then run your client to connect to the SQL server on the same box; then connect through it to the Linked Server; it should work now. OR..

    2) Write a stored procedure that tries to connect to the linked server and run it using the SQL Agent making sure the the Run As.. is set. (Actually, I am not sure that this still works under Sql2005..)

    If you ask Microsoft, they will say that the solution to this problem is Kerberos, but I have yet to see anyone successfully use Kerberos to address this problem in a complex multi-domain corporate enterprise network.

    The solution that everyone ends up using is SQL Logins for server-to-server communications. Not ideal, and not a secure as anyone would like, but it does work.

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • It is indeed as you say.

    When running the same SELECT linked-server query while RDP'd directly on the source server (the server instance to which the linked server is added) it works! The error occurs when running the query while connected remotely to the server (through SSMS).

    So it looks like it is indeed a double-hop integrated authentication issue.

    We are running this query from a SQL job so we just need to give the SQL Agent account sufficient privileges on the target instance for it to be able to view the data.

    __________________________________________________________________________________
    SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
    Persisting SQL Server Index-Usage Statistics with MERGE[/url]
    Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]

  • Marios: Glad I could help. I lost many days to this problem the first time that I tripped over it.

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • rbarryyoung (3/24/2008)


    Marios: Glad I could help. I lost many days to this problem the first time that I tripped over it.

    Thank you!

    This problem rears its ugly head in many different ways. It occurs when I attempt to open an SSRS report on my local workstation that connects through Windows auth. to a production instance and surveys user-database permissions. To resolve I need to create a special SQL login with sysadmin permissions on the instance! The alternative would be to map that login to EVERY single user database with db_datareader permissions, something hard to pull off logistically (and messy).

    So at the moment I'm stuck with a less than ideal scenario, and I want to try the Kerberos-auth option...

    __________________________________________________________________________________
    SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
    Persisting SQL Server Index-Usage Statistics with MERGE[/url]
    Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]

  • Jani Lane (3/18/2008)


    Good day!

    Don't know much about security, but I've created my web service function to return a dataset from SQL Server 2000. When I invoked the function it is giving me this error in the page although I can generate a dataset and connect to the db, only when invoking the web service that I'm getting this.

    Need help please.

    Thanks

    BTW, apologies for cutting into this thread with my own problem! 😉

    I think it is the same as what you posted, but, if not, pls let us know.

    thx!

    __________________________________________________________________________________
    SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
    Persisting SQL Server Index-Usage Statistics with MERGE[/url]
    Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]

  • Don't know how our DBA resolved this, but he gave me a new ID/password that I've used in my connectionString. Not a very wise move but for now that's all I can do, to include those credentials in my connection string. cheers

  • rbarryyoung (3/22/2008)


    Marios Philippopoulos (3/22/2008)


    Connections are made using the login's current security context.

    So in the following query, the login running the query is the same account in whose context the connection is attempted:

    SELECT * from [server\instance2k].dbName.dbo.tblName;

    The puzzling thing is that the same user is able to connect to instance server\instance2k through SSMS, while logged on the instance hosting the linked server.

    In your case it is pretty clear what the problem is (not so clear for the OP, who had less detail). What you are running into is almost certainly the "Two Hop Rule", which is that under windows domain security, an impersonated security context cannot re-impersonate (that is, it cannot generate the same impersonation on another server).

    This is relevant because when you connect from a client to the SQL Server, it impersonates you to generate the security context. In order to get to the linked server using Trusted connections, the security context of your server session would have to be re-impersonated on the target server, and that is not allowed. So even though you can connect directly from your client to both servers, you cannot connect from you client to the first server and then through that to the linked server, because that would be a two-hop impersonation.

    The way to test to see if this is really the problem is to find a way to get a session on your SQL server without it having to be impersonated and then try to connect to the linked server from there. I know of two ways to do this:

    1) Log on to your server at the console or through Remote Desktop, then run your client to connect to the SQL server on the same box; then connect through it to the Linked Server; it should work now. OR..

    2) Write a stored procedure that tries to connect to the linked server and run it using the SQL Agent making sure the the Run As.. is set. (Actually, I am not sure that this still works under Sql2005..)

    If you ask Microsoft, they will say that the solution to this problem is Kerberos, but I have yet to see anyone successfully use Kerberos to address this problem in a complex multi-domain corporate enterprise network.

    The solution that everyone ends up using is SQL Logins for server-to-server communications. Not ideal, and not a secure as anyone would like, but it does work.

    The answer isn't just Kerberos, as in Kerberos authentication, but actually Kerberos delegation. Kerberos authentication, by default, is just like NTLM: double-hops aren't permitted. With Kerberos delegation, multiple hops can be set up. Where we typically see this is web browser (client) to web server (first hop) to SQL Server (second hop) all trying to pass the user credentials from the web browser all the way through to the SQL Server. Another instance is SQL Server client to first SQL Server (first hop) to linked SQL Server (second hop), again using the user's credentials the same way. If the security context changes between hops, either by using a "service account" or by using a SQL Server login, then the double hop situation doesn't occur.

    With respect to complex multi-domain environments, the big thing is forest level. In Windows 2000 AD you don't have forest level trusts. So domains from one forest can't talk to domains in other forests and do Kerberos authentication. The forest is the Kerberos realm boundary. Windows will drop back to NTLM, which absolutely does not support more than one hop (by design). In Windows 2003 and above domains, Forest-level trusts are permitted, which means forests can have Kerberos authentication between domains in the separate forests.

    K. Brian Kelley
    @kbriankelley

  • He's avoiding the double-hop issue by switching the security context. Previously you were doing this:

    client -> web server (as Windows user) -> SQL Server (as Windows user)

    now you're doing this:

    client -> web server (as Windows user) -> SQL Server (as SQL Server login)

    K. Brian Kelley
    @kbriankelley

  • Marios Philippopoulos (3/24/2008)


    rbarryyoung (3/24/2008)


    Marios: Glad I could help. I lost many days to this problem the first time that I tripped over it.

    Thank you!

    This problem rears its ugly head in many different ways. It occurs when I attempt to open an SSRS report on my local workstation that connects through Windows auth. to a production instance and surveys user-database permissions. To resolve I need to create a special SQL login with sysadmin permissions on the instance! The alternative would be to map that login to EVERY single user database with db_datareader permissions, something hard to pull off logistically (and messy).

    So at the moment I'm stuck with a less than ideal scenario, and I want to try the Kerberos-auth option...

    This is what you're effectively doing and why you see the double hop issue:

    client (through the web report) -> initial SQL Server (as Windows user) -> linked SQL Server (as Windows user)

    That's the double-hop issue. Here's what would have to be configured to make Kerberos work in this situation (and it'll require a domain admin/forest admin to do):

    - Service Principal Names (SPNs) properly configured for the initial SQL Server instance (and if this is on a cluster, the Network name will have to be configured for Kerberos authentication)

    - Service Principal Names (SPNs) properly configured for the linked SQL Server instance (see above note about cluster config)

    - Constrained delegation (I'm assuming Windows 2003/2008 AD) for the service account for the first SQL Server instance permitting it to connect and impersonate to the second SQL Server instance

    - If in a multiple domain environment, where you're crossing domains in any way, using fully qualified domain names (FQDNs) in all computer name references (instead of just mysqlserver, mysqlserver.thedomain.net or what have you).

    There's a great document which details how to configure and troubleshoot Kerberos delegation related problems here (it's essential reading for CRM 3.0 configurations where all the tiers are on separate servers):

    Troubleshooting Kerberos Delegation

    K. Brian Kelley
    @kbriankelley

Viewing 15 posts - 1 through 15 (of 35 total)

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