Problem Statement:
We had an issue with Linked Server in one of our environment while executing a functionality. The error message is shown as below.
OLE DB provider “SQLNCLI11” for linked server “” returned message “The transaction manager has disabled its support for remote/network transactions.”.
Msg 7391, Level 16, State 2, Procedure “VIEWNAME” Line 8 [Batch Start Line 1]
The operation could not be performed because OLE DB provider “SQLNCLI11” for linked server “” was unable to begin a distributed transaction.
Analysis:
While analyzing, we identified the reason for the error is actually an INSERT operation on a view.To be more clear, lets discuss the scenario with an example as below.
Lets assume we have two servers ServerA and ServerB connected through linked server “LKSERVER”.
1. Create a table Called – dbo.TestLinkedServerTargetonPrimary in ServerA
Create Table dbo.TestLinkedServerTargetonPrimary(Col1 int)
2. Create a view called vw_LinkedServerTest in ServerB
create view vw_LinkedServerTest
as
Select Col1 From [ServerA].DatabaseA.dbo.TestLinkedServerTargetonPrimary
3. Create an INSTEAD OF Trigger for INSERT operation on the view created above
create TRIGGER [dbo].TR_LinkedServerTest on [dbo].vw_LinkedServerTest
INSTEAD OF INSERT
AS
BEGIN
INSERT INTO [ServerA].DatabaseA.dbo.TestLinkedServerTargetonPrimary
(
Col1
)
SELECT
Col1
from inserted
END
4. Try inserting data into Linked Server table through view.
Insert into vw_LinkedServerTest Select 1
The insert operation is failing with the below error message.
OLE DB provider “SQLNCLI11” for linked server “LKSERVER” returned message “The transaction manager has disabled its support for remote/network transactions.”.
Msg 7391, Level 16, State 2, Procedure TR_LinkedServerTest, Line 7 [Batch Start Line 21]
The operation could not be performed because OLE DB provider “SQLNCLI11” for linked server “LKSERVER” was unable to begin a distributed transaction.
The error is due to the transaction created by the INSTEAD OF Trigger on the view. Though, we dont have any explicit transaction defined, the instead of trigger is creating an implicit transaction. As the transaction scope is across linked server, it tries to open a distributed transaction in the trigger and it fails due to non access to network DTC access.
Lets quickly confirm the cause of the issue by modifying the trigger code to get the transaction count.
From the above, we can clearly see the transaction count is increasing as the trigger is getting executed.
Solution:
There are two options to solve the issue.
1. Provide enough security or enable the configuration at Network DTC access
a. Open “Component Services” in both servers and change the security settings as below.
b. Once the settings are changed, try to execute the INSERT query.
One drawback of this solution is a high dependency on MSDTC. Unless there are no alternatives, I would not suggest to use this method .
2. Try to Avoid the Trigger
Yes, As already discussed,INSTEAD OF trigger on the view is causing the issue. If we can drop the trigger on the view, it will not create a distributed transaction and the query will be executed successfully.
Hope this post helps you for similar situations, please share your feedback/comments….
One thought on “Error Message: The operation could not be performed because OLE DB provider “SQLNCLI11” for linked server “” was unable to begin a distributed transaction.”