Technical: Microsoft – SQL Server – Linked Server (LoopBack) – Errors – “Transaction context in use by another session” in InsteadofTrigger

Technical: Microsoft – SQL Server – Linked Server (LoopBack) – Errors – “Transaction context in use by another session” in InsteadofTrigger

Introduction

So basically we have a SQL Server Database Application and our topology involves a few DB SQL Server Instances.  During development, we are trying to constrain each Development\Developer environment to a single (lone) server.

Processing

Processing – Linked Server – Loopback (Create)



use master
go

/*
	select * from sys.servers
*/

declare @serverNameLocal sysname
declare @lsRemote        sysname
declare @tab		 sysname

set @lsRemote = 'LSREMOTE'
set @serverNameLocal = cast(serverproperty('servername') as sysname)
set @tab = char(9)

if exists
	(
	   select *
	   from   sys.servers tblServer
	   where  tblServer.name = @lsRemote
	)
begin

	print @tab + 'Dropping server ' + @lsRemote + ' ....'

	EXEC master.dbo.sp_dropserver @server=@lsRemote, @droplogins='droplogins'

end

print  @tab + 'Adding Self Server as Linked Server ... ' + @lsRemote

EXEC master.dbo.sp_addlinkedserver 
		  @server = @lsRemote
		, @srvproduct=@serverNameLocal
		, @provider=N'SQLOLEDB'
		, @datasrc=@serverNameLocal

EXEC master.dbo.sp_serveroption @server=@lsRemote
           , @optname=N'collation compatible', @optvalue=N'true'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'data access', @optvalue=N'true'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'dist', @optvalue=N'false'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'pub', @optvalue=N'false'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'rpc', @optvalue=N'true'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'rpc out', @optvalue=N'true'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'sub', @optvalue=N'false'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'connect timeout', @optvalue=N'0'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'collation name', @optvalue=null

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'lazy schema validation', @optvalue=N'true'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'query timeout', @optvalue=N'0'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'use remote collation', @optvalue=N'true'

EXEC master.dbo.sp_serveroption @server=@lsRemote
       , @optname=N'remote proc transaction promotion'
       , @optvalue=N'false'

EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = @lsRemote
       , @locallogin = NULL 
       , @useself = N'True'

print  @tab + 'Added Self Server as Linked Server ' + @lsRemote

Processing – Create Database (DBLab)


use [master]
go

if db_id('DBLab') is null
begin

	print 'Creating DB - DBLab .... '

	exec('create database [DBLab]')

	exec('ALTER DATABASE [DBLab] set recovery simple')

	print 'Creating DB - DBLab'

end
go

Processing – Table – dbo.whatisonyourmind (Create)

set noexec off
go

use [DBLab]
go

if object_id('dbo.whatisonyourmind') is not null
begin

	set noexec on
end
go

create table dbo.whatisonyourmind
(
	  [post] nvarchar(600)

	, [addedBy] sysname not null 
		constraint defaultWhatIsOnYourMindAddedBy default SYSTEM_USER

	, [addedOn] datetime not null 
		constraint defaultWhatIsOnYourMindAddedOn default getutcdate()

)

go

set noexec off
go

Processing – Table – dbo.whatisonyourmindArchive (Create)


set noexec off
go
use [DBLab]
go

if object_id('dbo.whatisonyourmindArchive') is not null
begin
	set noexec on
end
go

/*
	drop table dbo.whatisonyourmindArchive
*/
create table dbo.whatisonyourmindArchive
(

	  [id] bigint not null identity(1,1)

	, [post] nvarchar(600)

	, [addedBy] sysname not null 

	, [addedOn] datetime not null 

	, [modificationType] char (1) not null

	, [archivedBy] sysname not null 
		constraint defaultWhatIsOnYourMindArchivedBy default SYSTEM_USER

	, [dateArchived]  datetime not null 
		constraint defaultWhatIsOnYourMindArchivedOn default getutcdate()

)

go

set noexec off
go

Trigger

Here is a trigger the captures changes occurring on dbo.whatisonyourmind and propagates them unto dbo.whatisonyourmindArchive.


set noexec off
go

use [DBLab]
go

if object_id('dbo.TR_InsteadOf_Whatisonyourmind', 'TR') is not null
begin
	drop trigger dbo.TR_InsteadOf_Whatisonyourmind
end
go

if object_id('dbo.TR_InsteadOf_WhatisonyourmindLS', 'TR') is not null
begin
	drop trigger dbo.TR_InsteadOf_WhatisonyourmindLS
end
go

CREATE TRIGGER dbo.TR_InsteadOf_Whatisonyourmind
ON dbo.WhatIsOnYourMind
INSTEAD OF INSERT, UPDATE, DELETE
AS
begin

        --post changes unto dbo.whatisonyourmindArchive
	insert into dbo.whatisonyourmindArchive
	(
		  [post]

		, [addedBy]

		, [addedOn]

		, [modificationType]

	)
	select 
		  isNull(tblInsert.[post], tblDeleted.[post])

		, isNull(tblInsert.[addedBy], tblDeleted.[addedBy])

		, isNull(tblInsert.[addedOn], tblDeleted.[addedOn])

		, 
			case

				when ( 

				           (tblInsert.[post] is not null)
				        and (tblDeleted.[post] is null)

				      ) then  'I'

				when ( 

				               (tblInsert.[post] is null)
					   and (tblDeleted.[post] is not null)

				     ) then  'D'

				else 'U'

			end

	from   inserted tblInsert

		  full join deleted tblDeleted

		    on tblInsert.[post] = tblDeleted.[post]

        /* process insert/updates as 1 */
	MERGE INTO dbo.whatisonyourmind AS Target
	USING (
			select *
			from   inserted tblInsert
          )
			AS Source ([post], [addedBy], [addedOn] )
				ON Target.[addedBy] = Source.[addedBy]

	WHEN MATCHED THEN

		UPDATE 
		SET 
				  [post] = Source.[post]
				, [addedOn] = SOurce.[addedOn]

	WHEN NOT MATCHED BY TARGET THEN
		INSERT (post)
		VALUES (post)

	;

        /* remove records that are being deleted */
	delete tblTarget

	from   dbo.whatisonyourmind tblTarget

	where  tblTarget.[post] = 
			(

			   select  tblDeleted.[post]

			   from    deleted tblDeleted
											                           left outer join inserted tblInsert
													              on tblDeleted.[post] = tblInsert.[post]
										        			              and tblDeleted.[addedBy] = tblInsert.[addedBy]

			    where tblInsert.[post] is null

			)

end
go

Data Changes

Let us instigate data changes



use [DBLab]
go

/*

	truncate table [dbo].[whatisonyourmindArchive];
	truncate table [dbo].[whatisonyourmind];

*/

insert into [dbo].[whatisonyourmind]
([post])
values ('Dev1819')

insert into [dbo].[whatisonyourmind]
([post])
values ('DEV1819.2')

update [dbo].[whatisonyourmind]
set    [post] = 'DEV1819.3'
where  [addedBy] = SYSTEM_USER

delete
from   [dbo].[whatisonyourmind]
where  [post] = 'DEV1819.3'

select *
from   [dbo].[whatisonyourmind]

select *
from   [dbo].[whatisonyourmindArchive]

everything is good!

Trigger – Link Server

A few months later we get a request that we should decouple our OLTP (dbo.whatisonyourmind) and OLAP System (dbo.whatisonyourmindArchive).

And, we created the Linked Server mentioned earlier and change the trigger code a bit.

Here is our new trigger:



set noexec off
go

use [DBLab]
go

if object_id('dbo.TR_InsteadOf_Whatisonyourmind', 'TR') is not null
begin
	drop trigger dbo.TR_InsteadOf_Whatisonyourmind
end
go

if object_id('dbo.TR_InsteadOf_WhatisonyourmindLS', 'TR') is not null
begin
	drop trigger dbo.TR_InsteadOf_WhatisonyourmindLS
end
go

CREATE TRIGGER dbo.TR_InsteadOf_WhatisonyourmindLS
ON dbo.WhatIsOnYourMind
INSTEAD OF INSERT, UPDATE, DELETE
AS
begin

        /* insert into dbo.whatisonyourmind */
	insert into [LSREMOTE].[DBLab].dbo.whatisonyourmindArchive
	(
		  [post]

		, [addedBy]

		, [addedOn]

		, [modificationType]

	)
	select 
		  isNull(tblInsert.[post], tblDeleted.[post])

		, isNull(tblInsert.[addedBy], tblDeleted.[addedBy])

		, isNull(tblInsert.[addedOn], tblDeleted.[addedOn])

		, 
			case

				when ( 

				           (tblInsert.[post] is not null)
				        and (tblDeleted.[post] is null)

				      ) then  'I'

				when ( 

				               (tblInsert.[post] is null)
					   and (tblDeleted.[post] is not null)

				     ) then  'D'

				else 'U'

			end

	from   inserted tblInsert

		  full join deleted tblDeleted

		    on tblInsert.[post] = tblDeleted.[post]

	MERGE INTO dbo.whatisonyourmind AS Target
	USING (
			select *
			from   inserted tblInsert
          )
			AS Source ([post], [addedBy], [addedOn] )
				ON Target.[addedBy] = Source.[addedBy]

	WHEN MATCHED THEN

		UPDATE 
		SET 
				  [post] = Source.[post]
				, [addedOn] = SOurce.[addedOn]

	WHEN NOT MATCHED BY TARGET THEN
		INSERT (post)
		VALUES (post)

	;

	delete tblTarget

	from   dbo.whatisonyourmind tblTarget

	where  tblTarget.[post] = 
			(

			   select  tblDeleted.[post]

			   from    deleted tblDeleted
											                           left outer join inserted tblInsert
													              on tblDeleted.[post] = tblInsert.[post]
										        			              and tblDeleted.[addedBy] = tblInsert.[addedBy]

			    where tblInsert.[post] is null

			)

end
go

The basic changes between this new trigger and our earlier one is:

  • Changed “insert into dbo.whatisonyourmind” to “insert into [LSREMOTE].[DBLab].dbo.whatisonyourmindArchive”

Data Changes (Failed)

Let us instigate data changes



use [DBLab]
go

/*

	truncate table [dbo].[whatisonyourmindArchive];
	truncate table [dbo].[whatisonyourmind];

*/

insert into [dbo].[whatisonyourmind]
([post])
values ('DEV6834')

Upon, a quick test, nothing is good, as we get the error pasted below:


Msg 3910, Level 16, State 2, Line 1
Transaction context in use by another session.

Code Repository

To facilitate quick and broad participation and review,  I have shared this code in github. And, it is available in https://github.com/DanielAdeniji/MSSQLServerLinkedServerLBTrigger

 

Lab Environment

This problem has been tested out in the following environments:

  • Microsoft SQL Server 2012 – SP1 {11.0.2100}
  • Microsoft SQL Server 2008/R2 – SP2 {10.50.4000}
  • Microsoft SQL Server 2000 – SP4 {8.0.2039}

 

Summary

This seems to be a problem and I have been able to reproduce on a couple of MS SQL Server Instances; both of them running MS SQL Server 2012.

And, thus I opened a Connect Item – “Transaction context in use by another session (when LoopBack LinkedServer is used in trigger” {https://connect.microsoft.com/SQLServer/feedback/details/814524/transaction-context-in-use-by-another-session-when-loopback-linkedserver-is-used-in-trigger} to track.

Addendum

2014-04-09 – Connect Feedback – Alexey Stepanov

Alexey commented on the Connect Item and pointed out two Technet Articles that discusses the ‘handicap’:

References

References – Linked Server – Loopback

SQL Server – v2000 – BCP – Error – FUNCTION SEQUENCE ERROR

Introduction

Trying to get data out of SQL Server and hoping to use the quickest path.  One traditional tool is bcp.

Code – Transact SQL

Code – Transact SQL – dbProduct

Create database dbProduct and create a lone table dbo.product.

set noexec off
go

use [master]
go

if db_id('dbproduct') is null
begin

	print 'Creating DB dbproduct ...' 	

	exec('create database [dbproduct]')
	exec('alter database [dbproduct] set recovery simple');

	print 'Created DB dbproduct' 	

end
go

use [dbproduct]
go

/*
	drop table [dbo].[product]
*/
if object_id('dbo.product') is not null
begin

	set noexec on

end
go

/*
	drop table dbo.product;
*/

create table dbo.product
(

 	  [id] bigint not null identity(1,1)
	, [productName] varchar(600) not null
	, [size] varchar(80) null
	, [price] money not null

	, constraint PK_product primary key
		([id])

	, constraint Unique_ProductName unique
		([productName])

	, [addedBy] sysname not null
		constraint defaultproductAddedBy default SYSTEM_USER

	, [addedOn] datetime not null
		constraint defaultproductAddedOn default getdate()

)

set noexec off
go

Code – Transact SQL – dbSales

Create database dbSales and create a lone table dbo.order and dbo.orderDetail.


set noexec off
go

use [master]
go

if db_id('dbSales') is null
begin

	print 'Creating DB dbSales ...' 	

	exec('create database [dbSales]')
	exec('alter database [dbSales] set recovery simple');

	print 'Created DB dbSales' 	

end
go

use [dbSales]
go

if object_id('dbo.[order]') is not null
begin

	set noexec on

end
go

/*

	drop table dbo.[orderDetail];
	drop table dbo.[order];

*/

/*

	exec sp_help 'dbo.Order'

	exec sp_help 'dbo.OrderDetail'
*/

create table dbo.[order]
(
 	  [id] bigint not null identity(1,1) 

	, constraint PK_Order primary key
		([id])

	, [addedBy] sysname not null
		constraint defaultOrderAddedBy default SYSTEM_USER

	, [addedOn] datetime not null
		constraint defaultOrderAddedOn default getdate()

)
go

set noexec off
go

if object_id('dbo.[orderDetail]') is not null
begin

	set noexec on

end
go

create table dbo.[orderDetail]
(
 	   [OrderID] bigint
 	,  [sequenceID] int not null

	,  [productID] int not null

	,  [NumberofItems] int not null

		  constraint defaultOrderDetailNumbreofItems default 1

	,  [addedBy] sysname not null

		  constraint defaultOrderDetailAddedBy default SYSTEM_USER

	, [addedOn] datetime not null

		  constraint defaultOrderDetailAddedOn default getdate()

	, constraint PK_OrderDetail primary key
		(
			  [OrderID]
			, [SequenceID]
               )

	, constraint FK_OrderDetail foreign key
		(
			  [OrderID]
                )
	        references dbo.[Order]
	        (
			  [id]
                )

)
go

set noexec off
go

Code – Transact SQL – dbSales – dbo.ufn_computedCost

Create Scaler function dbo.ufn_computedCost.


use [dbSales]
go

if object_id('dbo.ufn_computedCost') is not null
begin

	set noexec on

end
go

/*

	drop function dbo.ufn_computedCost

*/

create function dbo.ufn_computedCost
(
	  @productID   int
	, @NumberofItems  int
)
returns money
as
begin

	declare @cost money

	select @cost = 
			@NumberofItems * tblProduct.[price]
	from   [dbProduct].dbo.product tblProduct
	where  tblProduct.[id] = @productID

	return (@cost)

end
go

set noexec off
go

Code – Transact SQL – dbSales – dbo.OrderDetail.cost

On the dbo.OrderDetail table, create a new column (cost) and bind it to the user function dbo.ufn_computedCost.


use [dbSales]
go

/*
	alter table dbo.orderDetail
	  drop column [cost]
*/

if not exists
	(

	    select name
	    from   syscolumns tblColumn
	    where  tblColumn.id = object_id('dbo.orderDetail')
	    and    tblColumn.name = 'cost'

	)
begin

	print 'Adding new column dbo.orderDetail - cost ... '

		alter table [dbo].[orderDetail]
		   add [cost]
			as dbo.ufn_computedCost(
                                                    [productID]
                                                  , [NumberofItems]
                                               )

	print 'Added new column dbo.orderDetail - cost'

end
go

Populate Tables

Let us populate the tables

Populate tables – [dbProduct].dbo.Product


set nocount on;
go

delete from [dbproduct].dbo.product;
go

set identity_insert [dbproduct].dbo.product on
go

	insert into [dbproduct].dbo.product
	([id], [productName], [size], [price])
	values(1, 'Frosted Flakes Cereal', '15 oz',2.98)

	insert into [dbproduct].dbo.product
	([id],[productName], [size], [price])
	values(2, 'Kellogg''s Corn Flakes Cereal', '24 oz', 4.67)

	insert into [dbproduct].dbo.product
	([id],[productName],[size], [price])
	values(3, 'Milk - Vitamin D','1 Gallon', 3.65)

	insert into [dbproduct].dbo.product
	([id],[productName],[size], [price])
	values(31, 'Chobani Non-Fat Greek Yogurt','15/6 oz', 15.99)

	insert into [dbproduct].dbo.product
	([id],[productName],[size], [price])
	values(41, 'Donsuemor Madeleines French Cakes','28 oz', 8.13)

	insert into [dbproduct].dbo.product
	([id],[productName],[size], [price])
	values(51, 'Turon','15 pieces', 11.85)

        insert into [dbProduct].[dbo].product
	([id],[productName],[size], [price])
	values(52, 'empanada','7 pieces', 7.00)

go

set identity_insert [dbproduct].dbo.product off
go

Populate tables – [dbSales].dbo.Order and [dbSales].dbo.OrderDetail


set nocount on;
go

delete from [dbSales].dbo.[orderDetail];
delete from [dbSales].dbo.[order];
go

set identity_insert [dbSales].dbo.[order] on

	insert into [dbSales].dbo.[order]
	([id])
	values (1)

	insert into [dbSales].dbo.[orderDetail]
	(
		[orderID], [sequenceID], [productID]
	)
	values
	(
		1, 1, 1
	)

	insert into [dbSales].dbo.[orderDetail]
	(
		[orderID], [sequenceID], [productID]
	)
	values
	(
		1, 2, 3
	)

        --------------------------------------------------------
	insert into [dbSales].dbo.[order]
	([id])
	values (2)

	insert into [dbSales].dbo.[orderDetail]
	(
		[orderID], [sequenceID], [productID]
	)
	values
	(
		2, 1, 1
	)

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

	insert into [dbSales].dbo.[order]
	([id])
	values (3)

	insert into [dbSales].dbo.[orderDetail]
	(
		[orderID], [sequenceID], [productID], [NumberofItems]
	)
	values
	(
		3, 1, 51,1
	)

	insert into [dbSales].dbo.[orderDetail]
	(
		[orderID], [sequenceID], [productID],[NumberofItems]
	)
	values
	(
		3, 2, 52,2
	)

go

set identity_insert [dbSales].dbo.[order] off
go

Bcp Data

Bcp Data – OrderDetail

Fetch data out of the dbo.OrderDetail table.

Script:

"C:\Program Files (x86)\Microsoft SQL Server\80\Tools\Binn\bcp"  "select * from [dbSales].dbo.[orderDetail]" queryout orderDetail.csv -c -S DBLAB\MSSQL2000  -T

Output:

bcp-good

Bcp Data – Failed

Let us imagine that a few weeks later or we are are in the process of moving to a new system and we try to bcp again, but upon issuing an identical BCP Command, we are now getting an error.

Bcp Data – OrderDetail

Fetch data out of the dbo.OrderDetail table.

Script:


"C:\Program Files (x86)\Microsoft SQL Server\80\Tools\Binn\bcp"  "select * from [dbSales].dbo.[orderDetail]" queryout orderDetail.csv -c -S DBLAB\MSSQL2000  -T

 

Error:

Error – Textual

SQLState = S1010, NativeError = 0
Error = [Microsoft][ODBC SQL Server Driver]Function sequence error

Error – Image

bcp-failed

Error Diagnosis

An error that reads “Function sequence error” seems intimidating. But, no problem.

We issued a select statement against the target table for our bcp:

select * from dbsales.dbo.orderDetail

And, got back an helpful error message:

Server: Msg 208, Level 16, State 1, Procedure ufn_computedCost, Line 24
Invalid object name 'dbProduct.dbo.product'.

Fix

Our fix was to move the dbProduct database to our new system.

In Microsoft SQL Server it is sometimes difficult to find cross database dependencies;  partly because Transact SQL does not allow us to specify those relationships and constraints.

Using the code pasted below, we tried relating the dbo.OrderDetail.productID column in the dbSales database to the id column in the dbProduct.dbo.product table.

     use [dbSales]
     go

     alter table dbo.OrderDetail
	   add constraint FK_OrderDetail_Product foreign key
       (
   	   [productID]
       )
       references [dbProduct].dbo.[product]
       (
    	  [id]
       )

But, you will get an error stating “cross-database foreign key references are not supported.



Server: Msg 1763, Level 16, State 1, Line 2
Cross-database foreign key references are not supported. 
Foreign key 'dbProduct.dbo.product'.
Server: Msg 1750, Level 16, State 1, Line 2
Could not create constraint. See previous errors.

Please keep in mind that if you try to reference an entirely missing database object, you will get a different error.

In the example below, we tried referencing a missing object (dbProduct.dbo.productMissing):


     use [dbSales]
     go

     alter table dbo.OrderDetail
	   add constraint FK_OrderDetail_Product foreign key
       (
   	   [productID]
       )
       references [dbProduct].dbo.[productMissing]
       (
    	  [id]
       )

And, get an error stating “references invalid table ….”


Server: Msg 1767, Level 16, State 1, Line 1
Foreign key 'FK_OrderDetail_Product' references invalid table 'dbProduct.dbo.product1'.
Server: Msg 1750, Level 16, State 1, Line 1
Could not create constraint. See previous errors.

More research might reveal different root causes:

  • Someone might have renamed the dbProduct.dbo.product table
  • In our case, the dbProduct database had not yet been moved to our new system

Conclusion

Yes,  error messages are sometimes unpleasant.  And, quick Google searches might find problems that a bit worse and laiden with unrelated riddles.

But, steady and progressive remediation steps wins the day!

References