- 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?
Exception Handling
One of the reasons .NET Framework procedures are appealing is that the .NET Framework has real structured exception handling. SQL Server 2005 includes improvements in error handling (see BEGIN/END TRY, BEGIN/END CATCH in Chapter 8), but this isn’t true of structured exception handling. With .NET Framework procedures, you can accomplish something that wasn’t available in previous versions of SQL Server. You can choose to consume the exception and not return the error to the caller, as shown in Listing 4-20.
Listing 4-20: Result of consuming an exception in a SQLCLR procedure
public static void EatException() { try { // cause a divide-by-zero exception int i = 42; int j = 0; j = i / j; } catch (Exception e) { SqlContext.Pipe.Send("Ate the exception"); SqlContext.Pipe.Send(e.Message); } } -- Run this T-SQL code to test it -- The transaction commits and the row is inserted -- prints: -- (1 row(s) affected) -- Ate the exception -- Attempt to divide by zero BEGIN TRANSACTION INSERT INTO jobs VALUES(’before exception’, 10, 10) EXECUTE EatException COMMIT
You can even catch an error in .NET Framework code and rethrow it as a user-defined exception. There is a catch (pun intended), however. Any unhandled exceptions that make their way out of your CLR procedure result in the same error at the client, whether the client is SQL Server Management Studio or a user application. If you are called from a .NET Framework try/catch block inside another .NET Framework stored procedure, however, that procedure can catch your exception without causing an underlying T-SQL exception. Listing 4-21 illustrates this.
Listing 4-21: Catching an exception and rethrowing it using SQLCLR
public static void ExceptionThrower() { try { int i = 42; int j = 0; j = i / j; } catch (Exception e) { SqlContext.Pipe.Send("In exception thrower"); SqlContext.Pipe.Send(e.Message); throw (e); } } public static void ExceptionCatcher() { using (SqlConnection conn = new SqlConnection("context connection=true")) using (SqlCommand cmd = new SqlCommand("ExceptionThrower", conn)) { try { cmd.CommandType = CommandType.StoredProcedure; conn.Open(); cmd.ExecuteNonQuery(); SqlContext.Pipe.Send("Shouldn’t get here"); } catch (SqlException e) { SqlContext.Pipe.Send("In exception catcher"); SqlContext.Pipe.Send(e.Number + ": " + e.Message); } } }
The results of using the ExceptionThrower procedure, both stand-alone and from the ExceptionCatcher, are shown in Listing 4-22.
Listing 4-22: Results of catching and rethrowing an exception
-- exception thrower standalone BEGIN TRANSACTION INSERT INTO jobs VALUES(’thrower’, 10, 10) EXECUTE ExceptionThrower COMMIT -- results in the messages window (1 row(s) affected) In exception thrower Attempted to divide by zero. Msg 6522, Level 16, State 1, Procedure ExceptionThrower, Line 0 A .NET Framework error occurred during execution of user defined routine or aggregate ’ExceptionThrower’: System.DivideByZeroException: Attempted to divide by zero. System.DivideByZeroException: at StoredProcedures.ExceptionThrower() -- exception catcher calls exception thrower BEGIN TRANSACTION INSERT INTO jobs VALUES(’catcher’, 10, 10) EXECUTE ExceptionCatcher COMMIT (1 row(s) affected) In exception catcher 6522: A .NET Framework error occurred during execution of user defined routine or aggregate ’ExceptionThrower’: System.DivideByZeroException: Attempted to divide by zero. System.DivideByZeroException: at StoredProcedures.ExceptionThrower(). In exception thrower Attempted to divide by zero.
Note that in each case, the transaction will commit. The only thing that would cause the transaction to roll back would be if the call to the stand-alone ExceptionThrower were called from a T-SQL TRY/CATCH block. In the case of ExceptionCatcher, it catches and discards the exception raised by the ExceptionThrower (the error message comes from ExceptionCatcher’s write of e.Message to the SqlPipe). The only unusual thing is that we don’t see the messages sent by the ExceptionThrower.
A disappointing thing about errors from SQLCLR procedures is that they are always wrapped in a general error with error number 6522. This makes it more difficult to get the actual error from a client. ADO.NET or OLE DB clients can return a stack of errors, but the actual error does not appear in the error stack. Note that SQL Server Management Studio is an ADO.NET application, so when we execute the code in SSMS, we get both errors. The 6522 contains the complete text and error number of the inner (actual) error.
From ODBC and (especially) from T-SQL callers, the picture is not as rosy, however. If you’ve not updated your error handling to use TRY/CATCH, you’re looking just at the value of @@ERROR. That value is always 6522, which makes determining what happened rather difficult. In this case, your only alternative is to expose your own error via the SqlPipe, as we’ll show you soon. An inelegant workaround is always to use SqlPipe’s ExecuteAndSend method inside of a .NET Framework try block that is followed by a dummy (do-nothing) catch block. In this case, provided that you are also using T-SQL’s new TRY/CATCH functionality, the outer (6522) error is stripped off, and the actual error information is available through the ERROR_NUMBER, ERROR_MESSAGE, and other new T-SQL functions we’ll be looking at soon. Be very careful to keep the 6522 wrapper error in mind as you plan for overall error handling strategy.
To return a custom error, the tried-and-true method is best. In fact, it is the only strategy that works regardless of the client stack you’re using and whether or not you’re being called by T-SQL:
- Define your error to the SQL Server error catalog with sp_addmessage.
- Use the T-SQL RAISERROR command in SqlCommand.Text.
- Use SqlPipe’s ExecuteAndSend method to return the error. Wrap the call to in a .NET Framework try/catch block with an empty catch clause.
Listing 4-23 shows this method.
Listing 4-23: Returning a user error from a SQLCLR procedure
public static SqlInt32 getAuthorWithErrors( SqlString au_id, out SqlString au_info) { // -- In SQL Server Management Studio add custom message to be used // -- when an author cannot be found // sp_addmessage 50005, 16, // ’author with ssn: %s, not found in the database’ // go // build a command SqlConnection conn = new SqlConnection("context connection=true"); conn.Open(); SqlCommand cmd = conn.CreateCommand(); // build command text cmd.CommandText = "select address, city, state, zip" + " from authors where au_id = @au_id"; // make a parameter to hold the author id cmd.Parameters.Add("@au_id", SqlDbType.VarChar); // put in the value of the author id cmd.Parameters[0].Value = au_id; SqlDataReader rec = cmd.ExecuteReader(); // make SqlString to hold result // note that if you do not give this // string a value it will be null au_info = new SqlString(); // check to see if lookup was successful if (rec.Read() == false) { rec.Close(); // lookup was not successful, raise an error cmd.CommandText = "Raiserror (50005, 16, 1, ’" + au_id.ToString() +"’) with seterror"; // use the try-catch with empty catch clause try { SqlContext.Pipe.ExecuteAndSend(cmd); } catch { } // this return statement will never be executed return 0; } else { // lookup was successful, set au_info to information string au_info = String.Format("{0} {1} {2} {3}", rec["address"], rec["city"], rec["state"], rec["zip"]); rec.Close(); } // nothing to return, either success returned author info in au_info // or error was raised return 0; }
This procedure will return the correct custom error (and not return error 6522) when invoked from T-SQL, whether T-SQL’s @@ERROR or the new T-SQL TRY/CATCH construct is used to return error information.