Commit f688d87c authored by dwentzel's avatar dwentzel

Added \Transactions (fun with transactions)

parent c3ad7b45
/*
According to BOL (http://msdn.microsoft.com/en-us/library/ms188929.aspx) named transactions
must adhere to the rules for identifiers, except names will be truncated at 32 characters.
Nothing is mentioned about case-sensitivity.
Transaction identifiers are always matched binary.
*/
--create a case-insensitive db
CREATE DATABASE TranDemo collate latin1_general_ci_ai
GO
USE TranDemo
GO
CREATE TABLE FooBar (ID int NOT NULL);
GO
--Test 1: note the case of the transaction name is different...
BEGIN TRANSACTION MyTrans
INSERT INTO FooBar VALUES (1);
COMMIT TRANSACTION mytrans
--...however, everything works as we would expect.
--this is because transaction name is IGNORED when specified with COMMIT and is solely
--there to aid readability. (http://msdn.microsoft.com/en-us/library/ms190295.aspx)
SELECT @@trancount NumOpenTransactions, ID FROM FooBar
--Test 2: but this is not the case with ROLLBACK...
BEGIN TRANSACTION MyTrans
INSERT INTO FooBar VALUES (2);
ROLLBACK TRANSACTION mytrans
--...which will throw an error and leave the transaction open
SELECT @@trancount NumOpenTxAfterFailedRollback
--rollback the open transaction
ROLLBACK;
--cleanup
USE master
GO
DROP DATABASE TranDemo;
GO
/*
According to BOL (http://msdn.microsoft.com/en-us/library/ms188929.aspx) named transactions
must adhere to the rules for identifiers, except names will be truncated at 32 characters.
Committing a named transaction is actually entirely meaningless. You can commit
any meaningless/non-existent name whatsoever and it works. The rationale is that
COMMIT will merely decrement @@TRANCOUNT regardless of the name, so the name is
simply ignored.
*/
--create a case-insensitive db
CREATE DATABASE TranDemo collate latin1_general_ci_ai
GO
USE TranDemo
GO
CREATE TABLE FooBar (ID int NOT NULL);
GO
--Test 3: you can commit any transaction name
BEGIN TRANSACTION MyTrans
INSERT INTO FooBar VALUES (1);
COMMIT TRANSACTION BlahdyBlah --this doesn't exist
SELECT @@trancount TranCount
SELECT * FROM FooBar
--cleanup
USE master
GO
DROP DATABASE TranDemo;
GO
/*
Sometimes it would be nice if we had the ability to have "autonomous" transactions
like in Oracle (https://docs.oracle.com/cd/B19306_01/appdev.102/b14261/autonotransaction_pragma.htm)
An example in SQL Server...logging.
*/
CREATE DATABASE TranDemo
GO
USE TranDemo
GO
CREATE TABLE FooBar (ID int NOT NULL PRIMARY KEY CLUSTERED);
GO
CREATE TABLE Logger (ID int NOT NULL IDENTITY(1,1) , Msg varchar(200));
GO
--start my batch processing
BEGIN TRY
BEGIN TRAN
INSERT INTO Logger (Msg) VALUES ('Starting my batch processing.');
INSERT INTO Logger (Msg) VALUES ('Inserting 1');
INSERT INTO FooBar VALUES (1);
INSERT INTO Logger (Msg) VALUES ('Inserting 2');
INSERT INTO FooBar VALUES (2);
INSERT INTO Logger (Msg) VALUES ('Inserting 3');
INSERT INTO FooBar VALUES (3);
INSERT INTO Logger (Msg) VALUES ('Inserting 1...again');
INSERT INTO FooBar VALUES (1);
INSERT INTO Logger (Msg) VALUES ('Completed my batch processing.');
COMMIT
END TRY
BEGIN CATCH
ROLLBACK TRAN
INSERT INTO Logger (Msg) VALUES ('Error occurred during my batch processing');
END CATCH
--Let's look at Logger
SELECT * FROM Logger
--cleanup
USE master
GO
DROP DATABASE TranDemo;
GO
/*
One method to simulate an autonomous transaction is with @TableVariables
*/
CREATE DATABASE TranDemo
GO
USE TranDemo
GO
CREATE TABLE FooBar (ID int NOT NULL PRIMARY KEY CLUSTERED);
GO
CREATE TABLE Logger (ID int NOT NULL, Msg varchar(200));
GO
--@TableVariables do NOT participate in transaction management
DECLARE @Logger TABLE (ID int NOT NULL IDENTITY(1,1) , Msg varchar(200));
--start my batch processing
BEGIN TRY
BEGIN TRAN
INSERT INTO @Logger (Msg) VALUES ('Starting my batch processing.');
INSERT INTO @Logger (Msg) VALUES ('Inserting 1');
INSERT INTO FooBar VALUES (1);
INSERT INTO @Logger (Msg) VALUES ('Inserting 2');
INSERT INTO FooBar VALUES (2);
INSERT INTO @Logger (Msg) VALUES ('Inserting 3');
INSERT INTO FooBar VALUES (3);
INSERT INTO @Logger (Msg) VALUES ('Inserting 1...again');
INSERT INTO FooBar VALUES (1);
INSERT INTO @Logger (Msg) VALUES ('Completed my batch processing.');
COMMIT
END TRY
BEGIN CATCH
ROLLBACK TRAN
INSERT INTO @Logger (Msg) VALUES ('Error occurred during my batch processing');
END CATCH
--FINALLY...update dbo.Logger
INSERT INTO Logger SELECT * FROM @Logger
--Let's look at Logger
SELECT * FROM Logger
--cleanup
USE master
GO
DROP DATABASE TranDemo;
GO
/*
Another method to simulate an autonomous transaction is with linked servers
*/
CREATE DATABASE TranDemo
GO
USE TranDemo
GO
CREATE TABLE FooBar (ID int NOT NULL PRIMARY KEY CLUSTERED);
GO
CREATE TABLE Logger (ID int NOT NULL IDENTITY(1,1), Msg varchar(200));
GO
--build a linked server that does not participate in existing transactions
EXEC sp_addlinkedserver
@server = 'AutonomousLoopback',
@srvproduct = N'',
@provider = N'SQLNCLI',
@datasrc = @@servername;
EXEC sp_serveroption
@server = 'AutonomousLoopback',
@optname = N'RPC OUT',
@optvalue = 'TRUE'; --enables RPC
EXEC sp_serveroption
@server = 'AutonomousLoopback',
@optname = N'remote proc transaction promotion',
@optvalue = 'FALSE'; --when FALSE then calling a remote stored proc will not start a distributed tx
GO
--build two Logger stored procs...one does the work, the other is called over the Loopback linked server
CREATE PROC LogMsgBase @Msg varchar(200)
AS
INSERT INTO dbo.Logger (Msg) VALUES (@Msg)
GO
CREATE PROC LogMsg @Msg varchar(200)
AS
EXEC AutonomousLoopback.TranDemo.dbo.LogMsgBase @Msg;
GO
--start my batch processing
BEGIN TRY
BEGIN TRAN
EXEC LogMsg 'Starting my batch processing.';
EXEC LogMsg 'Inserting 1';
INSERT INTO FooBar VALUES (1);
EXEC LogMsg 'Inserting 2';
INSERT INTO FooBar VALUES (2);
EXEC LogMsg 'Inserting 3';
INSERT INTO FooBar VALUES (3);
EXEC LogMsg 'Inserting 1...again';
INSERT INTO FooBar VALUES (1);
EXEC LogMsg 'Completed my batch processing.'
COMMIT
END TRY
BEGIN CATCH
ROLLBACK TRAN
EXEC LogMsg 'Error occurred during my batch processing';
END CATCH
--Let's look at Logger
SELECT * FROM Logger
--cleanup
USE master
GO
DROP DATABASE TranDemo;
GO
EXEC sp_dropserver @server = 'AutonomousLoopback';
/*
In this example SQL Server will help you if you mismatch your BEGIN and COMMIT TRAN statements.
Neither Wrapper nor CalledProcedure are taking into consideration the fact that other procedures
may have altered the open tran count of the workflow.
But this behavior does not work when using implicit transactions
Demo:
1)EXEC Wrapper 1 with implicit_transactions OFF...note that Error 266 is thrown
2)EXEC Wrapper 0 with implicit_transactions OFF...note that Error 266 is thrown
3)EXEC Wrapper 0 with implicit_transactions ON...Error 3902 occurs in Wrapper Procedure
3)EXEC Wrapper 1 with implicit_transactions ON...in this case no error is thrown and we "dangled" a transaction
*/
CREATE DATABASE TranDemo
GO
USE TranDemo
GO
--SET IMPLICIT_TRANSACTIONS ON;
--GO
CREATE PROCEDURE CalledProcedure @int INT AS
BEGIN TRY
BEGIN TRAN
SELECT 1/@int AS DivisionResult
END TRY
BEGIN CATCH
ROLLBACK TRAN
END CATCH
--missing COMMIT TRAN statement here
GO
CREATE PROCEDURE Wrapper @int INT AS
BEGIN TRANSACTION
EXEC CalledProcedure @int
COMMIT
GO
EXEC Wrapper 1
GO
SELECT @@trancount AS '@@TRANCOUNT'
--cleanup
IF @@TRANCOUNT > 0
ROLLBACK TRAN
GO
USE master
GO
DROP DATABASE TranDemo;
GO
SET IMPLICIT_TRANSACTIONS OFF
GO
\ No newline at end of file
/*
Your procedures should always be coded to respect the open transactions that may exist
when the procedure is called and always commit back to that number of open transactions.
In some cases we specifically do not want our procedure to be called in the context of an
open transaction. For example, when batch processing all rows in a table we may only want to
process a few thousand rows at a time to avoid long-duration locking, chances of deadlocking,
and lock escalations.
Demo:
1)Error: "BatchProcessing cannot be called in the context of an open transaction"
2)Even with SET IMPLICIT_TRANSACTIONS ON everything works correctly. (Line 63-64)
3)But does not function correctly without the wrapper (Line 70-71). Note that we have 2
transactions.
http://msdn.microsoft.com/en-us/library/ms187807(v=sql.100).aspx : states that a
SELECT will start a transaction if one does not already exist when a SELECT is encountered.
But this is not true, see Lines 46-48. Instead you must SELECT from an actual table.
032_implicit_tx.sql has one possible fix.
*/
CREATE DATABASE TranDemo
GO
USE TranDemo
GO
--create and populate a test table with 10,000 rows
CREATE TABLE BigTable (ID int NOT NULL, Processed BIT NOT NULL);
;WITH TenRows(n) AS
(
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1
),
OneHundredRows(n) AS (SELECT 1 FROM TenRows CROSS JOIN TenRows b),
OneThousandRows(n) AS (SELECT 1 FROM OneHundredRows CROSS JOIN OneHundredRows b)
INSERT INTO BigTable (ID, Processed)
SELECT ROW_NUMBER() OVER(ORDER BY n) AS ID , 0 AS Processed FROM OneThousandRows ;
GO
--we want to set the Processed flag to 1 for 2000 rows at a time.
--this procedure should be written better to avoid locking problems, but we
--merely want to demo how transaction handling works.
CREATE PROCEDURE BatchProcessing AS
DECLARE @TRANCOUNT INT
SELECT @TRANCOUNT = @@TRANCOUNT
IF @TRANCOUNT <> 0
BEGIN
RAISERROR ('BatchProcessing cannot be called in the context of an open transaction',16,1)
RETURN 1
END
WHILE EXISTS (SELECT 1 FROM BigTable WHERE Processed = 0)
BEGIN
BEGIN TRAN
SELECT @@trancount AS 'TranCount in Loop'
UPDATE TOP (2000) BigTable SET Processed = 1 WHERE Processed = 0
COMMIT TRAN
END;
GO
CREATE PROCEDURE Wrapper AS
BEGIN TRANSACTION
EXEC BatchProcessing
COMMIT
GO
--SET IMPLICIT_TRANSACTIONS ON;
--GO
EXEC Wrapper
GO
--EXEC BatchProcessing
--GO
--cleanup
IF @@TRANCOUNT > 0
ROLLBACK TRAN
GO
USE master
GO
DROP DATABASE TranDemo;
GO
SET IMPLICIT_TRANSACTIONS OFF
GO
\ No newline at end of file
/*
http://msdn.microsoft.com/en-us/library/ms187807(v=sql.100).aspx : states that a
SELECT will start a transaction if one does not already exist when a SELECT is encountered.
But this is not true. This builds on 031_implicit_tx.sql.
See the new code for Lines 33-35.
*/
CREATE DATABASE TranDemo
GO
USE TranDemo
GO
--create and populate a test table with 10,000 rows
CREATE TABLE BigTable (ID int NOT NULL, Processed BIT NOT NULL);
;WITH TenRows(n) AS
(
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1
),
OneHundredRows(n) AS (SELECT 1 FROM TenRows CROSS JOIN TenRows b),
OneThousandRows(n) AS (SELECT 1 FROM OneHundredRows CROSS JOIN OneHundredRows b)
INSERT INTO BigTable (ID, Processed)
SELECT ROW_NUMBER() OVER(ORDER BY n) AS ID , 0 AS Processed FROM OneThousandRows ;
GO
--we want to set the Processed flag to 1 for 2000 rows at a time.
--this procedure should be written better to avoid locking problems, but we
--merely want to demo how transaction handling works.
CREATE PROCEDURE BatchProcessing AS
DECLARE @TRANCOUNT INT
--SELECT @TRANCOUNT = @@trancount
SELECT TOP 1 @TRANCOUNT = @@TRANCOUNT FROM sys.objects
IF @TRANCOUNT <> 0
BEGIN
RAISERROR ('BatchProcessing cannot be called in the context of an open transaction',16,1)
RETURN 1
END
WHILE EXISTS (SELECT 1 FROM BigTable WHERE Processed = 0)
BEGIN
BEGIN TRAN
SELECT @@trancount AS 'TranCount in Loop'
UPDATE TOP (2000) BigTable SET Processed = 1 WHERE Processed = 0
COMMIT TRAN
END;
GO
--CREATE PROCEDURE Wrapper AS
--BEGIN TRANSACTION
-- EXEC BatchProcessing
--COMMIT
--GO
SET IMPLICIT_TRANSACTIONS ON;
GO
--EXEC Wrapper
--GO
EXEC BatchProcessing
GO
--cleanup
IF @@TRANCOUNT > 0
ROLLBACK TRAN
GO
USE master
GO
DROP DATABASE TranDemo;
GO
SET IMPLICIT_TRANSACTIONS OFF
GO
\ No newline at end of file
/*
This further demos how to check if you are running under
implicit transactions (IT) and some of the consequences
of doing so.
*/
CREATE DATABASE TranDemo
GO
USE TranDemo
GO
SELECT 'Let''s set up a test. Clean up my env.' AS Message
SET IMPLICIT_TRANSACTIONS OFF
IF @@TRANCOUNT > 0 ROLLBACK TRAN
SELECT 'IT should be OFF and my @@trancount should be 0' AS Message
SELECT CASE (2 & @@OPTIONS) WHEN 2 THEN 'ON' ELSE 'OFF' END AS [IT Status], @@trancount AS [@@trancount]
SET IMPLICIT_TRANSACTIONS ON
SELECT 'Turn on IT and doublecheck that @@OPTIONS is set correctly' AS Message
SELECT CASE (2 & @@OPTIONS) WHEN 2 THEN 'ON' ELSE 'OFF' END AS [IT Status]
SELECT 'TEST 1: IT ON, what is my trancount? Should be zero, because I did no work yet' AS Message
SELECT 'This runs contrary to: http://msdn.microsoft.com/en-us/library/ms187807(v=sql.100).aspx'
SELECT getdate() AS [a random SELECT]
SELECT @@TRANCOUNT AS [@@trancount before querying a real table]
SELECT 'TEST 2: SELECT must have a FROM clause to start an implicit transaction.'
--The mere act of querying a "real table" causes a transaction to become "active"
select @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
SELECT 'TEST 3: Start an explicit transaction. @@trancount is now 2.'
SELECT 'But note that we do not see DMV rows for EVERY transaction'
BEGIN TRAN
select @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
SELECT 'ROLLBACK and start over. Verify IT status and trancount'
ROLLBACK TRAN
SELECT CASE (2 & @@OPTIONS) WHEN 2 THEN 'ON' ELSE 'OFF' END AS [Status of IT],@@TRANCOUNT [TranCount]
SELECT 'TEST 4: impl_tran on with nested user tran, DMV results are unexpected'
set implicit_transactions ON
select 'Impl_tran ON only' AS [Test 4a], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
BEGIN TRAN
select 'Impl_tran ON with one user tran' AS [Test 4b], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
BEGIN TRAN MyNamedTransaction
select 'Impl_tran ON with two user trans' AS [Test 4c], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
if @@trancount > 0 rollback
SELECT 'TEST 5: What do the DMVs look like without using IT?'
set implicit_transactions OFF
select 'Without a transaction' AS [Test 5a], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
BEGIN TRAN
select 'With one transaction' AS [Test 5b], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
BEGIN TRAN
select 'With two transactions' AS [Test 5c], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
if @@trancount > 0 rollback
SELECT 'TEST 6: What do the DMVs look like when I use named transactions'
set implicit_transactions OFF
select 'Without a transaction' AS [Test 6a], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
BEGIN TRAN MyOuterTransaction
select 'With one transaction' AS [Test 6b], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
BEGIN TRAN MyInnerTransaction
select 'With two transactions' AS [Test 6c], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
if @@trancount > 0 rollback
--so the rule seems to always be to show implicit_transaction when that is ON, else show the outermost user_transaction name (or just user_transaction if there is no name)
--...or is this the rule?
--let's see what happens with "marked transactions"
SELECT 'TEST 7: impl_tran OFF/nested "marked" user tran, expect OuterNamedTran'
set implicit_transactions OFF
begin tran OuterNamedTran WITH MARK 'OuterMark'
begin tran InnerNamedTran WITH MARK 'InnerMark'
select 'Marked Transactions' AS [Test 7], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
if @@trancount > 0 rollback
SELECT 'TEST 8: impl_tran ON with marked transactions'
set implicit_transactions ON
begin tran OuterNamedTran WITH MARK 'OuterMark'
select 'OuterNamedTran and mark' AS [Test 8a], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
begin tran InnerNamedTran WITH MARK 'InnerMark'
select 'InnerNamedTran and mark' AS [Test 8b], @@TRANCOUNT AS [@@trancount],tat.name [dm tran name], tst.is_user_transaction,CASE WHEN tat.transaction_state = 2 THEN 'Active' END AS transaction_state, tat.transaction_status2
from sys.dm_tran_active_transactions tat, sys.dm_tran_session_transactions tst
where tat.transaction_id = tst.transaction_id and tst.session_id = @@spid
if @@trancount > 0 rollback
/*
So the rule is that sys.dm_tran_active_transactions returns the "name" of the OUTER transaction (or implicit_transaction) and never any rows for the inner transactions as
long as transaction_status2 = 258 (which, I guess means non-marked transactions). When a transaction is marked then sys.dm_tran_active_transactions returns the outer most
named and marked transaction, regardless of whether there is an implicit_transaction. We can deduce this because transaction_status2= 266 (which I guess means HasMarkedTransaction
transaction_status2 is not supported and future compatibility is not guaranteed.
*/
--cleanup
IF @@TRANCOUNT > 0
ROLLBACK TRAN
GO
USE master
GO
DROP DATABASE TranDemo;
GO
SET IMPLICIT_TRANSACTIONS OFF
GO
\ No newline at end of file
Transaction Trivia
Did you ever notice that sp_reset_connection is called A LOT?
Did you ever see an "orphaned spid" with an open transaction that caused you massive blocking?
Do you run jdbc or dblib data access technologies?
Have you ever had @@TRANCOUNT show an incorrect value?
Wouldn't it be nice to spin up a autonomous "auditing" transaction in the middle of your main transaction
that will not be rolled back? If you answered yes to any of these then you are ready to delve deeper
into SQL Server transactions. You may be surprised that transaction handling doesn't always work the
way you think it does.
`FunWithTransactions.pptx` : Presentation file.
Transaction Names
-------------------
`010_transaction_names.sql` : demo anomalies with transaction names and their case
`011_transaction_names.sql` : demo that ANY transaction name can be committed, even one that doesn't exist
Autonomous Transactions
------------------------
`020_autonomous_tx.sql` : demo for the need for autonomous transactions in SQL Server.
`021_autonomous_tx.sql` : demo for one way to achieve an autonomous transaction using table variables
`022_autonomous_tx.sql` : demo for a nifty way to get an autonomous transaction using a loopback linked server
Implicit Transactions
-----------
`030_implicit_tx.sql` : when mismatching BEGIN TRAN/COMMIT statements you will get an error message, unless you
use implicit transactions.
`031_implicit_tx.sql` : when batch processing data we may need fine grain control over transactions. This demos
what happens when you are not careful with implicit transactions.
`032_implicit_tx.sql` : shows a simple trick to overcome the issue in `031_implicit_tx.sql`
`033_implicit_tx.sql` : this demos what happens when you mix explicit and implicit transactions. This also covers
how to monitor your open transactions (which doesn't always work as expected either). There is all kinds of
goofiness here.
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment