Tag Archives: Sql Server 2005

TRY…CATCH In Sql Server

This is the second article in the series of articles on Exception Handling in Sql Server. Below is the list of other articles in this series.

Part   I: Exception Handling Basics – MUST Read Article
Part  II: TRY…CATCH (Introduced in Sql Server 2005)
Part III: RAISERROR Vs THROW (Throw: Introduced in Sql Server 2012)
Part IV: Exception Handling Template

TRY…CATCH

TRY…CATCH is the Structured Error handling construct introduced in Sql Server 2005. It is similar to the one which we have in C#, but it doesn’t have the FINALLY block. If any error is raised by the statement in the TRY block then the control is immediately passed to the CATCH block. If none of the statement in the TRY block raises any exception then the CATCH block will not be executed.

SYNTAX:

BEGIN TRY
 -- T-Sql Statements
END TRY
BEGIN CATCH
 -- T-Sql Statements
 /*Control is passed to CATCH block only if
   there are any exceptions in the TRY block*/
END CATCH

Let us understand TRY…CATCH construct with below extensive list of examples.

To demonstrate this let us create a New Database and table as shown below:

--Create a New database for the Demo
CREATE DATABASE SqlHintsErrorHandlingDemo
GO
USE SqlHintsErrorHandlingDemo
GO
CREATE TABLE dbo.Account
(	
 AccountId INT NOT NULL PRIMARY KEY, 
 Name	 NVARCHAR (50) NOT NULL,
 Balance Money NOT NULL CHECK (Balance>=0)	
)
GO

As the Account table has Primary Key on the AccountId column, so it will raise an error if we try to duplicate the AccountId column value. And the Balance column has a CHECK constraint Balance>=0, so it will raise an exception if the value of Balance is <0.

DEMO 1:

Let us execute the below script and observe what will be the behavior of TRY..CATCH construct if none of the Statements in the TRY block raises any exception.

PRINT 'BEFORE TRY'
BEGIN TRY
 PRINT 'First Statement in the TRY block'	
 INSERT INTO dbo.Account(AccountId, Name , Balance) 
 VALUES(1, 'Account1', 10000)
 PRINT 'Last Statement in the TRY block'
END TRY
BEGIN CATCH
	PRINT 'In CATCH Block'
END CATCH
PRINT 'After END CATCH'
GO

RESULT:
TryCatch

From the above result it is clear that, if the statements enclosed within TRY block doesn’t result in any errors then the control is not passed to the CATCH block instead the execution continues with immediate statement after the END CATCH statement.

Let us empty the Account Table before proceeding with the next DEMO.

DELETE FROM dbo.Account
GO

DEMO 2:

Let us execute the below script and observe what will be the behavior of TRY..CATCH construct. Here the Second INSERT statement results in a statement Terminating Primary Key Violation error.

PRINT 'BEFORE TRY'  
BEGIN TRY
 PRINT 'First Statement in the TRY block'
 INSERT INTO dbo.Account(AccountId, Name , Balance)
 VALUES(1, 'Account1',  10000)
 INSERT INTO dbo.Account(AccountId, Name , Balance)
 VALUES(1, 'Duplicate', 10000)
 INSERT INTO dbo.Account(AccountId, Name , Balance)
 VALUES(2, 'Account2',  20000)
 PRINT 'Last Statement in the TRY block'
END TRY
BEGIN CATCH
	PRINT 'In CATCH Block'	
END CATCH
PRINT 'After END CATCH'
SELECT * FROM dbo.Account WITH(NOLOCK)
GO

RESULT:
SqlServerTRYCATCH2

From the above result it is clear that as soon as the error is encountered in the TRY block, sql server terminates the Statement which raised the error, no subsequent statements in the TRY block are executed and the control is passed to the CATCH block.

Let us empty the Account Table before proceeding with the next DEMO.

DELETE FROM dbo.Account
GO

DEMO 3:

Let us execute the below script and observe what will be the behavior of TRY..CATCH construct. Here the Second statement (i.e. UPDATE statement) results in a Batch Abortion CONVERSION/CAST error.

PRINT 'BEFORE TRY'  
BEGIN TRY
 PRINT 'First Statement in the TRY block'
 INSERT INTO dbo.Account(AccountId, Name , Balance)
 VALUES(1, 'Account1',  10000)

 UPDATE dbo.Account
 SET Balance = Balance + CAST('TEN THOUSAND' AS MONEY) 
 WHERE AccountId = 1

 INSERT INTO dbo.Account(AccountId, Name , Balance)
 VALUES(2, 'Account2',  20000)
 PRINT 'Last Statement in the TRY block'
END TRY
BEGIN CATCH
	PRINT 'In CATCH Block'	
END CATCH
PRINT 'After END CATCH'
SELECT * FROM dbo.Account WITH(NOLOCK)
GO

RESULT:
SqlServerTRYCATCH3

From the above result it is clear that as soon as the error is encountered in the TRY block, sql server terminates the Statement which raised the error, no subsequent statements in the TRY block are executed and the control is passed to the CATCH block.

Let us empty the Account Table before proceeding with the next DEMO.

DELETE FROM dbo.Account
GO

DEMO 4:

In this DEMO we will see how we can use the Transactions with TRY..CATCH constructs.

PRINT 'BEFORE TRY' 
BEGIN TRY
	BEGIN TRAN
	 PRINT 'First Statement in the TRY block'
	 INSERT INTO dbo.Account(AccountId, Name , Balance) VALUES(1, 'Account1',  10000)
	 UPDATE dbo.Account SET Balance = Balance + CAST('TEN THOUSAND' AS MONEY) WHERE AccountId = 1
	 INSERT INTO dbo.Account(AccountId, Name , Balance) VALUES(2, 'Account2',  20000)
	 PRINT 'Last Statement in the TRY block'
	COMMIT TRAN
END TRY
BEGIN CATCH
    PRINT 'In CATCH Block' 
	IF(@@TRANCOUNT > 0)
		ROLLBACK TRAN
END CATCH
PRINT 'After END CATCH'
SELECT * FROM dbo.Account WITH(NOLOCK)
GO

RESULT:
SqlServerTRYCATCH4

Here @@TRANCOUNT in the CATCH block identifies whether we have any active transactions, if yes we are rolling back the transaction. Because of this we don’t see any records in the Account Table.

DEMO 5:

In this demo we will see the set of ERROR FUNCTIONS which we can use in the CATCH block to get the details of the Error which resulted in transfering the control from the TRY block to the CATCH block

BEGIN TRY
 SELECT 5/0
END TRY
BEGIN CATCH
 PRINT '*************Error Detail****************'
 PRINT 'Error Number  :' + CAST(ERROR_NUMBER() AS VARCHAR)
 PRINT 'Error Severity:' + CAST(ERROR_SEVERITY() AS VARCHAR)
 PRINT 'Error State   :' + CAST(ERROR_STATE() AS VARCHAR)
 PRINT 'Error Line    :' + CAST(ERROR_LINE() AS VARCHAR)
 PRINT 'Error Message :' + ERROR_MESSAGE()
END CATCH

RESULT:
SqlServerTRYCATCH5

ERROR FUNCTIONS in Sql Server

Below is the list of ERROR FUNCTIONS which we can use in the CATCH block to get the details of the Error which resulted in transferring the control from the TRY block to the CATCH block.

  • ERROR_NUMBER() : Returns the Error Number.
  • ERROR_SEVERITY() : Returns the Severity of the Error.
  • ERROR_STATE() : Returns the State of the Error.
  • ERROR_PROCEDURE(): Returns the name of the SP/UDF in which the error occurred.
  • ERROR_LINE() : Returns the line number of the Sql statement which raised the error.
  • ERROR_MESSAGE() : Returns the error message.

These function can used only in the scope of the CATCH block. They will not return the value outside the CATCH block, below example demonstrates this:

SELECT 5/0
SELECT ERROR_NUMBER() ‘Error Number’, ERROR_MESSAGE() ‘Error Message’

RESULT:
ErrorFunctions

DEMO 6:

TRY…CATCH construct catches all the errors except the Connection Termination errors. This implies any error in the TRY block with severity level between 11-19 causes Sql Server to transfer the control to the CATCH block. One exception is the Scope Abortion error (i.e. Deferred Name resolution) which is not a connection termination error but can’t be Trapped by the TRY…CATCH construct. The below example demonstrates this:

PRINT 'BEFORE TRY'
BEGIN TRY
  PRINT 'First Statement in the TRY block'
  SELECT * FROM NONExistentTable
  PRINT 'Last Statement in the TRY block'
END TRY
BEGIN CATCH
  PRINT 'In the CATCH block'	
END CATCH
PRINT 'After END CATCH'
GO

RESULT:
DeferredNameResolution

Will cover few more examples of TRY…CATCH construct while discussing on the RAISERROR and THROW Statement.

Differences Between RAISERROR and THROW in Sql Server

Both RAISERROR and THROW statements are used to raise an error in Sql Server. The journey of RAISERROR started from Sql Server 7.0, where as the journey of THROW statement has just began with Sql Server 2012. obviously, Microsoft suggesting us to start using THROW statement instead of RAISERROR. THROW statement seems to be simple and easy to use than RAISERROR.

This is the third article in the series of articles on Exception Handling in Sql Server. Below is the complete list of articles in this series.

Part   I: Exception Handling Basics – MUST Read Article
Part  II: TRY…CATCH (Introduced in Sql Server 2005)
Part III: RAISERROR Vs THROW (Throw: Introduced in Sql Server 2012)
Part IV: Exception Handling Template

Raiserror Vs Throw

Below table lists-out 10 major difference between RAISERROR and THROW with examples:

RAISERROR THROW
Version of the Sql Server in which it is introduced?
Introduced in SQL SERVER 7.0. And as per BOL, Microsoft is suggesting to start using THROW statement instead of RAISERROR in New Applications.

RAISERROR can’t be used in the Sql Server 2014’s Natively compiled Stored Procedures.

Introduced in SQL SERVER 2012. THROW statement seems to be simple and easy to use than RAISERROR.

THROW statement can be used in the Sql Server 2014’s Natively Compiled Stored Procedure.

SYNTAX
RAISERROR 
 ( { error_number | message 
        | @local_variable }
    { ,severity ,state }
    [ ,argument [ ,...n ] ] )
    [ WITH option [ ,...n ] ]
THROW 
 [ { error_number 
     | @local_variable },
   { message | @local_variable },
   { state | @local_variable } ] 
[ ; ]
Can re-throw the original exception that invoked the CATCH block?
NO. It always generates new exception and results in the loss of the original exception details. Below example demonstrates this:

BEGIN TRY
  DECLARE @result INT
--Generate divide-by-zero error
  SET @result = 55/0
END TRY
BEGIN CATCH
--Get the details of the error
--that invoked the CATCH block
 DECLARE 
   @ErMessage NVARCHAR(2048),
   @ErSeverity INT,
   @ErState INT

 SELECT
   @ErMessage = ERROR_MESSAGE(),
   @ErSeverity = ERROR_SEVERITY(),
   @ErState = ERROR_STATE()

 RAISERROR (@ErMessage,
             @ErSeverity,
             @ErState )
END CATCH

RESULT:
Msg 50000, Level 16, State 1, Line 19
Divide by zero error encountered.

NOTE:The actual line number of the code which generated Divided By Zero error here is 4, but the exception message returned by RAISERROR is showiung it as 19. Also the error number corresponding to divide by zero error is 8134 in the SYS.Messages table, but the one returned by RAISERROR is 50000.

YES. To Re-THROW the original exception caught in the TRY Block, we can just specify the THROW statement without any parameters in the CATCH block. Below example demonstrates this:

BEGIN TRY
  DECLARE @result INT
--Generate divide-by-zero error
  SET @result = 55/0
END TRY
BEGIN CATCH
    THROW
END CATCH

RESULT:
Msg 8134, Level 16, State 1, Line 4
Divide by zero error encountered.

With above example it is clear that THROW statement is very simple for RE-THROWING the exception. And also it returns correct error number and line number.

Causes the statement batch to be ended?
Example 1: In the below Batch of statements the PRINT statement after RAISERROR statement will be executed.

BEGIN
 PRINT 'BEFORE RAISERROR'
 RAISERROR('RAISERROR TEST',16,1)
 PRINT 'AFTER RAISERROR'
END

RESULT:

BEFORE RAISERROR
Msg 50000, Level 16, State 1, Line 3
RAISERROR TEST

AFTER RAISERROR

Example 2: In the below example all the statement’s after RAISERROR statement are executed.

BEGIN TRY
 DECLARE @RESULT INT = 55/0	
END TRY
BEGIN CATCH
 PRINT 'BEFORE RAISERROR';

--Get the details of the error
--that invoked the CATCH block
 DECLARE 
  @ErMessage NVARCHAR(2048),
  @ErSeverity INT,
  @ErState INT

 SELECT
  @ErMessage = ERROR_MESSAGE(),
  @ErSeverity = ERROR_SEVERITY(),
  @ErState = ERROR_STATE()

 RAISERROR (@ErMessage,
             @ErSeverity,
             @ErState )

 PRINT 'AFTER RAISERROR'
END CATCH
 PRINT 'AFTER CATCH'

RESULT:
BEFORE RAISERROR
Msg 50000, Level 16, State 1, Line 19
Divide by zero error encountered.

AFTER RAISERROR
AFTER CATCH

Example 1: In the below Batch of statements the PRINT statement after THROW statement will not executed.

BEGIN
	PRINT 'BEFORE THROW';
	THROW 50000,'THROW TEST',1
	PRINT 'AFTER THROW'
END

RESULT:

BEFORE THROW
Msg 50000, Level 16, State 1, Line 3
THROW TEST

Example 2: In the below example no PRINT statement’s after THROW statement are executed.

BEGIN TRY
  DECLARE @RESULT INT = 55/0	
END TRY
BEGIN CATCH
  PRINT 'BEFORE THROW';
  THROW;
  PRINT 'AFTER THROW'
END CATCH
  PRINT 'AFTER CATCH'

RESULT:
BEFORE THROW
Msg 8134, Level 16, State 1, Line 2
Divide by zero error encountered.

CAN SET SEVERITY LEVEL?
YES. The severity parameter specifies the severity of the exception. NO. There is no severity parameter. The exception severity is always set to 16. (unless re-throwing in a CATCH block)
Requires preceding statement to end with semicolon (;) statement terminator?
NO. YES. The statement before the THROW statement must be followed by the semicolon (;) statement terminator.
CAN RAISE SYSTEM ERROR MESSAGE?
The SYS.MESSAGES Table will have both system-defined and user-defined messages. Message IDs less than 50000 are system messages.
YES. With RAISERROR we can raise the System Exception.
Example:
RAISERROR (40655,16,1)RESULT:
Msg 40655, Level 16, State 1, Line 1
Database ‘master’ cannot be restored.
NO. With THROW we can’t raise the System Exception. But when it used in CATCH BLOCK it can Re-THROW the system exception.Example: Trying to raise system exception (i.e. exception with ErrorNumber less than 50000).

THROW 40655, ‘Database master cannot be restored.’, 1

RESULT:
Msg 35100, Level 16, State 10, Line 1
Error number 40655 in the THROW statement is outside the valid range. Specify an error number in the valid range of 50000 to 2147483647

CAN RAISE user-defined message with message_id greater than 50000 which is not defined in SYS.MESSAGES table?
NO. If a msg_id is passed to RAISERROR, the ID must be defined in sys.messages.Example:

RAISERROR (60000, 16, 1)

RESULT:
Msg 18054, Level 16, State 1, Line 1
Error 60000, severity 16, state 1 was raised, but no message with that error number was found in sys.messages. If error is larger than 50000, make sure the user-defined message is added using sp_addmessage.

Now add the Message to SYS.MESSAGES Table by using the below statement:

EXEC sys.sp_addmessage 60000, 16, ‘Test User Defined Message’

Now try to Raise the Error:
RAISERROR (60000, 16, 1)

RESULT:
Msg 60000, Level 16, State 1, Line 1
Test User Defined Message

YES. The error_number parameter does not have to be defined in sys.messages.Example:
THROW 60000, ‘Test User Defined Message’, 1RESULT:
Msg 60000, Level 16, State 1, Line 1
Test User Defined Message
Allows substitution parameters in the message parameter?
By using the below statement add a sample test message with parameteres to the SYS.Messages Table:
EXEC sp_addmessage 70000,16,‘Message with Parameter 1: %d and Parameter 2:%s’
YES.The msg_str parameter can contain printf formatting styles.Example 1:

RAISERROR (70000, 16, 1, 505,‘Basavaraj’ )

RESULT:
Msg 70000, Level 16, State 1, Line 1
Message with Parameter 1: 505 and Parameter 2:Basavaraj

NO.The message parameter does not accept printf style formatting.Example 1:

THROW 70000, ‘Message with Parameter 1: %d and Parameter 2:%s’, 1, 505,’Basavaraj’

RESULT:
Msg 102, Level 15, State 1, Line 1
Incorrect syntax near ‘,’.

Alternative Way of doing this is:

DECLARE @ErrorMsg NVARCHAR(2048) = FORMATMESSAGE(70000, 505, ‘Basavaraj’ );
THROW 70000, @ErrorMsg, 1

Example 2: Message manipulation is not allowed in the THROW statement

Below statement will fail

THROW 58000,‘String1’ + ‘ String2’,1

RESULT:
Msg 102, Level 15, State 1, Line 1
Incorrect syntax near ‘+’.

We can solve such problems, we can prepare the message prior to the THROW statement and then pass it to throw statement as a variable. Below example illustrates this.

DECLARE @message NVARCHAR(2048)
SET @message = ‘String1’ + ‘ String2’;
THROW 58000, @message, 1

RESULT:
Msg 58000, Level 16, State 1, Line 3
String1 String2

RAISERROR WITH NOWAIT statement can also be used to flushes all the buffered PRINT/SELECT Statement Messages within a batch.

[ALSO READ] You may like to read below other popular articles on differences

1. Varchar vs NVarchar
2. Varchar vs Varchar(MAX)
3. Char vs Varchar
4. Text vs Varchar(Max)
5. Union vs Union All
6. DateTime vs DateTime2
7. SET QUOTED_IDENTIFIER ON vs SET QUOTED_IDENTIFIER OFF
8. Stored Procedure vs User Defined Function
9. Primary Key vs Unique Key
10. RAISERROR vs THROW
11. Temporary Table vs Table Variable
12. Len() vs Datalength()
13. Sequence vs Identity
14. DATEDIFF vs DATEDIFF_BIG