Capture and log error of TSQL code in SQL Server 2012

Capture and log error of TSQL code in SQL Server 2012

SQL Server provides a robust way to capture error with TRY….CATCH but I wanted to have centralized information about error to maintain history and for debugging purpose so that I have created one stored procedure to log error information in one table. I used to call that stored procedure which capture error in my every stored procedure.

I have created “[dbo].[usp_LogErrorHistory] ” stored procedure which logs all errors in “[dbo].[ErrorHistory]” table. I used to call “[dbo].[usp_LogErrorHistory] ” SP in every stored procedure I create and hence I have, now, one central location (“[dbo].[ErrorHistory]” table) where I can go and look for total number of error withing given time period and for given objects.

Let us create “[dbo].[ErrorHistory]” table and “[dbo].[usp_LogErrorHistory] ” stored procedure with following TSQL:

[sourcecode language=”sql”]
CREATE TABLE [dbo].[ErrorHistory](
[ErrorLogID] [int] IDENTITY(1,1) NOT FOR REPLICATION NOT NULL,
[ErrorTime] [datetime] NOT NULL DEFAULT GETDATE(),
[UserName] [sysname] NOT NULL,
[ErrorNumber] [int] NOT NULL,
[ErrorSeverity] [int] NULL,
[ErrorState] [int] NULL,
[ErrorProcedure] [nvarchar](126) NULL,
[ErrorLine] [int] NULL,
[ErrorMessage] [nvarchar](4000) NOT NULL,
[ContextInfo] [varbinary](max) NULL,
CONSTRAINT [PK_ErrorLog_ErrorLogID] PRIMARY KEY CLUSTERED
(
[ErrorLogID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)
)
GO

CREATE PROCEDURE [dbo].[usp_LogErrorHistory]
— contains the ErrorLogID of the row inserted
@ErrorLogID [int] = 0 OUTPUT
AS
BEGIN
SET NOCOUNT ON;
— Output parameter value of 0 indicates that error
— information was not logged
SET @ErrorLogID = 0;

BEGIN TRY
— Return if there is no error information to log

IF ERROR_NUMBER() IS NULL
RETURN;

— Return if inside an uncommittable transaction.
— Data insertion/modification is not allowed when
— a transaction is in an uncommittable state.
IF XACT_STATE() = -1
BEGIN
PRINT ‘Cannot log error since the current transaction is in an uncommittable state. ‘
+ ‘Rollback the transaction before executing usp_LogErrorHistory in order to successfully log error information.’;
RETURN;
END

INSERT [dbo].[ErrorHistory]
(
[UserName],
[ErrorNumber],
[ErrorSeverity],
[ErrorState],
[ErrorProcedure],
[ErrorLine],
[ErrorMessage],
[ContextInfo]
)
VALUES
(
CONVERT(sysname, CURRENT_USER),
ERROR_NUMBER(),
ERROR_SEVERITY(),
ERROR_STATE(),
ERROR_PROCEDURE(),
ERROR_LINE(),
ERROR_MESSAGE(),
CONTEXT_INFO()
);

— Pass back the ErrorLogID of the row inserted
SET @ErrorLogID = @@IDENTITY;
END TRY
BEGIN CATCH
PRINT ‘An error occurred in stored procedure usp_LogErrorHistory: ‘;
RETURN -1;
END CATCH
END;
GO
[/sourcecode]

Once we are done with above given SP and table, we will create one more user stored procedure which we will execute and it will generate an error which will be logged in our error history table.

[sourcecode language=”sql”]
CREATE PROC TestErrorLog1
AS
BEGIN
–Specifies whether SQL Server automatically rolls back the current transaction
–when a Transact-SQL statement raises a run-time error.
–this is the reason I keep having XACT_ABORT in all my SP when transaction is used
SET XACT_ABORT ON;

–used to keep following statement in all my SP for performance point of view
SET NOCOUNT ON

BEGIN TRY
–I am not performing any DML statement here though I have kept transaction here
–to demonstrate the usage
BEGIN TRANSACTION
SELECT 1/0
COMMIT TRANSACTION
END TRY
BEGIN CATCH
IF @@TRANCOUNT>0
ROLLBACK

–to log the error
EXEC [dbo].[usp_LogErrorHistory] ;

–to show the error to the end user
THROW
END CATCH
END
GO
[/sourcecode]

Now this is a time to check functionality of our error SP by executing following TSQL script:

[sourcecode language=”sql”]
–execut TestErrorLog1 SP to confirm whether error is being logged or not
EXECUTE TestErrorLog1
GO
[/sourcecode]

Okay so I hope your first error after creating this environment has logged. Let us confirm it by executing SELECT query in Error History table.

[sourcecode language=”sql”]
–Looking at [dbo].[ErrorHistory] table to see captured error:
SELECT * FROM [dbo].[ErrorHistory]
[/sourcecode]

Here is the output of my SELECT statement on ErrorHistory table.

1Error

Please note that This code should work in older version of SQL Server eg: SQL Server 2008 or 2008 R2 as well. You have to use RAISERROR instead of THROW statement.

If you like this article, do like “Extreme-Advice” page in Facebook.

Reference: Ritesh Shah

http://Extreme-Advice.com

http://www.sqlhub.com

Note: Microsoft Books online is a default reference of all articles.

Error handling with “THROW” command in SQL Server 2012

Error handling with “THROW” command in SQL Server 2012

error

Error handling is one of the essential skill developer should have. It was very difficult to handle error efficiently till SQL Server 2000. After SQL Server 2000, we have get TRY…CATCH in SQL Server along with RAISERROR in SQL Server 2005. RAISERROR is even improved in form of “THROW” in SQL Server 2012.

Let us see how “THROW” command works for error handling efficiently in SQL Server 2012 because without know the error/bug in application, you can’t solve it. It is not possible/feasible, sometime, in big production environment to replicate same issue in development database, at the sametime, we can’t execute some command/query on live environment if it is affecting client’s data so efficient error handling is required so that you can log proper error along with its message, error number and other important things.

Let us create sample temporary table in AdventureWorks2012 database, if you don’t have Adventureworks2012 database with you, you can use your own database as I will be having temp table for this demonstration.

[sourcecode language=”sql”]
IF OBJECT_ID(‘tempdb..#TestingTHROWCommand’) IS NOT NULL
DROP TABLE #TestingTHROWCommand

CREATE TABLE #TestingTHROWCommand
(
ID INT IDENTITY(1,1)
,Name VARCHAR(50)
,OvertimeAmount INT
)

INSERT INTO #TestingTHROWCommand
SELECT ‘Ritesh Shah’,15 UNION ALL
SELECT ‘Teerth Shah’,0 UNION ALL
SELECT ‘Rajan Jain’,9
GO[/sourcecode]

Now let us try to execute one UPDATE statement where we will have one division operator which divide on “OvertimeAmount” field. We have value “0” with row number 2 so obviously we will be facing an error.

[sourcecode language=”sql”]
BEGIN TRY
BEGIN TRANSACTION
UPDATE #TestingTHROWCommand
SET OvertimeAmount=95/OvertimeAmount
COMMIT TRANSACTION
END TRY
BEGIN CATCH
SELECT ERROR_NUMBER(),ERROR_MESSAGE(),ERROR_LINE()
ROLLBACK TRANSACTION
END CATCH
GO[/sourcecode]

As soon as we will execute above code, we will be greeted with an error because on row # 2, we have 0 which will try to divide 95 and 0 can’t be used to divide anything. Here is the error message we will get:

[sourcecode language=”sql”]
(0 row(s) affected)
8134 Divide by zero error encountered. 3
[/sourcecode]

Look at the error number, message and error line number given above. Now, we will try to handle error with different way as follow:

[sourcecode language=”sql”]
BEGIN TRY
BEGIN TRANSACTION
UPDATE #TestingTHROWCommand
SET OvertimeAmount=95/OvertimeAmount
COMMIT TRANSACTION
END TRY
BEGIN CATCH
DECLARE @ErrorMsg NVARCHAR(MAX) = ERROR_MESSAGE()
ROLLBACK TRANSACTION
RAISERROR(@ErrorMsg,16,1)
END CATCH
GO[/sourcecode]

We have same UPDATE statement so obviously we will be getting error message again but this time, it will come by “RAISERROR” command. Here is the output of RAISERROR.

[sourcecode language=”sql”]
(0 row(s) affected)
Msg 50000, Level 16, State 1, Line 10
Divide by zero error encountered.[/sourcecode]

Look at the error number and error line. It seems wrong because of “RAISERROR”. Let us now try to handle the error with “THROW” command.

[sourcecode language=”sql”]
BEGIN TRY
BEGIN TRANSACTION
UPDATE #TestingTHROWCommand
SET OvertimeAmount=95/OvertimeAmount
COMMIT TRANSACTION
END TRY
BEGIN CATCH
ROLLBACK TRANSACTION;
THROW
END CATCH
GO[/sourcecode]

we will again receive proper error message, number and line with “THROW” command. Have a look:

[sourcecode language=”sql”]
(0 row(s) affected)
Msg 8134, Level 16, State 1, Line 3
Divide by zero error encountered.[/sourcecode]

I have recently seen many of the developer who are using SQL Server 2012, still uses “RAISERROR” as against “THROW”. I would highly recommend start using “THROW” command.

If you like this article, do like “Extreme-Advice” page in Facebook.

Reference: Ritesh Shah

http://Extreme-Advice.com

http://www.sqlhub.com

Note: Microsoft Books online is a default reference of all articles.