- Programming with SqlClient
- Context: The SqlContext Class
- Connections
- Commands: Making Things Happen
- Obtaining Results
- Transactions
- Pipe
- Creating and Sending New Rowsets
- Using the WindowsIdentity
- Calling a Web Service from SQLCLR
- Exception Handling
- SqlTriggerContext
- SqlClient Classes That You Can’t Use on the Server
- Where Are We?
Transactions
Multiple SQL operations within a stored procedure or user-defined function can be executed individually or composed within a single transaction. Composing multistatement procedural code inside a transaction ensures that a set of operations has ACID properties. ACID is an acronym for the following:
- Atomicity—All the operations in a transaction will succeed, or none of them will.
- Consistency—The transaction transforms the database from one consistent state to another.
- Isolation—Each transaction has its own view of the database state.
- Durability—These behaviors are guaranteed even if the database or host operating system fails—for example, because of a power failure.
You can use transactions in two general ways within the SqlClient managed provider: by starting a transaction by using the SqlConnection’s BeginTransaction method or by using declarative transactions using System.Transaction.TransactionScope. The TransactionScope is part of a new library in .NET Framework 2.0: the System.Transactions library. Listing 4-10 shows a simple example of each method.
Listing 4-10: SqlClient can use two different coding styles for transactions
// Example 1: start transaction using the API SqlConnection conn = new SqlConnection("context connection=true"); conn.Open(); SqlTransaction tx = conn.BeginTransaction(); // do some work tx.Commit(); conn.Dispose(); // Example 2: start transaction using Transaction Scope using System.Data.SqlClient; using System.Transactions; using (TransactionScope ts = new TransactionScope()) { SqlConnection conn = new SqlConnection("context connection=true"); // connection auto-enlisted in transaction on Open() conn.Open(); // transactional commands here conn.Close(); ts.Complete(); } // transaction commits when TransactionScope.Dispose called implicitly
If you’ve done any ADO.NET coding before, you’ve probably run into the BeginTransaction method. This method encapsulates issuing a BEGIN TRANSACTION statement in T-SQL. The TransactionScope requires a bit more explanation.
The System.Transactions library is meant to provide a representation of the concept of a transaction in the managed world. It is also a lightweight way to access MSDTC, the distributed transaction coordinator. It can be used as a replacement for the automatic transaction functionality in COM+ exposed by the System.EnterpriseServices library, but it does not require the components that use it to be registered in the COM+ catalog. System.EnterpriseServices cannot be used in .NET Framework procedural code that runs in SQL Server. To use automatic transactions with System.Transactions, simply instantiate a TransactionScope object with a using statement, and any connections that are opened inside the using block will be enlisted in the transaction automatically. The transaction will be committed or rolled back when you exit the using block and the TransactionScope’s Dispose method is called. Notice that the default behavior when Dispose is called is to roll back the transaction. To commit the transaction, you need to call the TransactionScope’s Complete method.
In SQL Server 2005, using the TransactionScope starts a local, not a distributed, transaction. This is the behavior whether TransactionScope is used with client-side code or SQLCLR procedures unless there is already a transaction started when the SQLCLR procedure is invoked. This phenomenon is illustrated below:
-- Calling a SQLCLR procedure that uses TransactionScope EXECUTE MySQLCLRProcThatUsesTransactionScope -- local transaction GO BEGIN TRANSACTION -- other T-SQL statements EXECUTE MySQLCLRProcThatUsesTransactionScope -- distributed transaction COMMIT GO
The transaction actually begins when Open is called on the SqlConnection, not when the TransactionScope instance is created. If more than one SqlConnection is opened inside a TransactionScope, both connections are enlisted in a distributed transaction when the second connection is opened. The transaction on the first connection actually changes from a local transaction to a distributed transaction. Recall that you can have only a single instance of the context connection, so opening a second connection really means opening a connection using SqlClient and a network library. Most often, you’ll be doing this specifically to start a distributed transaction with another database. Because of the network traffic involved and the nature of the two-phase commit protocol used by distributed transactions, a distributed transaction will be much higher overhead than a local transaction.
BeginTransaction and TransactionScope work identically in the simple case. But some database programmers like to make each procedure usable and transactional when used stand-alone or when called when a transaction already exists. To accomplish this, you would put transaction code in each procedure. When one procedure with transaction code calls another procedure with transaction code, this is called composing transactions. SQL Server supports nesting of transactions and named savepoints, but not autonomous (true nested) transactions. So using a T-SQL procedure X as an example,
CREATE PROCEDURE X AS BEGIN TRAN -- work here COMMIT
calling it stand-alone (EXECUTE X) means that the work is in a transaction. Calling it from procedure Y
CREATE PROCEDURE Y AS BEGIN TRANSACTION -- other work here EXECUTE X COMMIT
doesn’t start an autonomous transaction (a second transaction with a different scope); the BEGIN TRANSACTION in X merely increases a T-SQL variable @@TRANCOUNT by one. Two error messages are produced when you roll back in procedure X while it’s being called by procedure Y:
Msg 266, Level 16, State 2, Procedure Y, Line 0 Transaction count after EXECUTE indicates that a COMMIT or ROLLBACK TRANSACTION statement is missing. Previous count = 1, current count = 0. Msg 3902, Level 16, State 1, Procedure X, Line 5 The COMMIT TRANSACTION request has no corresponding BEGIN TRANSACTION.
I’d like to emulate this behavior in SQLCLR—that is, have a procedure that acts like X and that can be used stand-alone or composed. I can do something akin to T-SQL (and get the interesting rollback behavior with a slightly different error number) using the BeginTransaction method on the context SqlConnection. Using a TransactionScope has a different behavior, however. If I have a SQLCLR proc that looks like this (condensed version),
public static void X { using (TransactionScope ts = new TransactionScope()) using ( SqlConnection conn = new SqlConnection("Context connection=true")) { conn.Open(); ts.Complete(); } }
and if SQLCLR X is used stand-alone, all is well, and the TransactionScope code gets a local transaction. If SQLCLR X is called from procedure Y (above), SqlConnection’s Open starts a distributed transaction. Apparently, it has to be this way, at least for now, because of how TransactionScope works. Local transactions don’t expose the events that TransactionScope needs to compose transactions.
If you want a distributed transaction composed with your outer transaction (your SqlConnection is calling to another instance, for example), use TransactionScope; if you don’t want one, use SqlConnection’s BeginTransaction. It won’t act any different from T-SQL (except you do get a different error number) if you roll back inside an "inner" transaction. But you get a nesting local transaction with BeginTransaction.
Listing 4-11 shows an example of using a distributed transaction with TransactionScope.
Listing 4-11: A distributed transaction using TransactionScope
public static void DoDistributed() { string ConnStr = "server=server2;integrated security=sspi;database=pubs"; using (TransactionScope ts = new TransactionScope()) using (SqlConnection conn1 = new SqlConnection("Context connection=true")) using (SqlConnection conn2 = new SqlConnection(ConnStr)) { conn1.Open(); conn2.Open(); // do work on connection 1 // do work on connection 2 // ask to commit the distributed transaction ts.Complete(); } }
TransactionScope Exotica
You can use options of the TransactionScope class to compose multiple transactions in interesting ways. You can start multiple transactions, for example (but not on the context connection), by using a different TransactionScopeOption. Listing 4-12 will begin a local transaction using the context connection and then begin an autonomous transaction using a connection to the same server.
Listing 4-12: Producing the equivalent of an autonomous transaction
public static void DoPseudoAutonomous() { string ConnStr = "server=sameserver;integrated security=sspi;database=samedb"; using (TransactionScope ts1 = new TransactionScope()) using (SqlConnection conn1 = new SqlConnection("context connection=true")) { conn1.Open(); // do work on connection 1, then { using (TransactionScope ts2 = new TransactionScope(TransactionScopeOption.RequiresNew)) using (SqlConnection conn2 = new SqlConnection(ConnStr)) { conn2.Open(); // do work on connection 2 ts2.Complete(); } // ask to commit transaction1 ts1.Complete(); } }
This code works because it uses a second connection to the same server to start a second transaction. This second connection is separate from the first one, not an autonomous transaction on the same connection. The result is the same as you would get from an autonomous transaction; you just need two connections (the context connection and a second connection) to accomplish it.
Attempting to use any TransactionScopeOption other than the default TransactionRequired fails if there already is an existing transaction (as we saw before, when BEGIN TRANSACTION was called in T-SQL before EXECUTE on the SQLCLR procedure) and you attempt to use context connection, as shown in Listing 4-13. You’ll get a message saying "no autonomous transaction".
Listing 4-13: Attempting to use autonomous transactions on a single connection fails
-- Calling a SQLCLR procedure that uses TransactionScope -- with an option other than TransactionRequired EXECUTE DoPseudoAutonomous -- works GO BEGIN TRANSACTION -- other T-SQL statements EXECUTE DoPseudoAutonomous -- fails, "no autonomous transaction" COMMIT GO
This is because SQL Server doesn’t support autonomous transactions on a single connection.
Best Practices
With all these options and different behaviors, what’s the best and easier thing to do to ensure that your local transactions always work correctly in SQLCLR procedures? At this point, because SQL Server 2005 doesn’t support autonomous transactions on the same connection, SqlConnection’s BeginTransaction method is the best choice for local transactions. In addition, you need to use the Transaction.Current static properties in System.Transactions.dll to determine whether a transaction already exists—that is, whether the caller has already started a transaction. Listing 4-14 shows a strategy that works well whether or not you compose transactions.
Listing 4-14: A generalized strategy for nesting transactions
// Works whether caller has transaction or not public static int ComposeTx() { int returnCode = 0; // determine if we have transaction bool noCallerTx = (Transaction.Current == null); SqlTransaction tx = null; SqlConnection conn = new SqlConnection("context connection=true"); conn.Open(); if (noCallerTx) tx = conn.BeginTransaction(); try { // do the procedure’s work here SqlCommand workcmd = new SqlCommand( "INSERT jobs VALUES(’New job’, 10, 10)", conn); if (tx != null) workcmd.Transaction = tx; int rowsAffected = workcmd.ExecuteNonQuery(); if (noCallerTx) tx.Commit(); } catch (Exception ex) { if (noCallerTx) { tx.Rollback(); // raise error - covered later in chapter } else { // signal an error to the caller with return code returnCode = 50010; } } conn.Dispose(); return returnCode; }
For distributed transactions as well as the pseudoautonomous transactions described earlier, you must use TransactionScope or a separate second connection back to the server using SqlClient. If you don’t mind the behavior that nesting transactions with TransactionScope force a distributed transaction and the extra overhead caused by MSDTC, you can use TransactionScope all the time. Finally, if you know your procedure won’t be called with an existing transaction, you can use either BeginTransaction or TransactionScope. Refraining from nesting transactions inside nested procedures may be a good strategy until this gets sorted out.