Error handling with a called stored procedure

  • Stored procedure OUTER_TEST calls stored procedure INNER_TEST.

    If an error in INNER_TEST, how do I capture the error message (to store in a table). When I have a try-catch in OUTER_TEST, I can only access a later error message and not the initial one from INNER_TEST?

  • Try out the following code. You will see that the error generated in the first proc is captured in the second.

    CREATE OR ALTER PROCEDURE dbo.ErrorTest1
    AS
    BEGIN
    SET NOCOUNT ON;

    BEGIN TRY
    SELECT 1 / 0;
    END TRY
    BEGIN CATCH
    DECLARE @ErrorMessage NVARCHAR(4000);
    DECLARE @ErrorSeverity INT;
    DECLARE @ErrorState INT;

    SELECT @ErrorMessage = ERROR_MESSAGE()
    ,@ErrorSeverity = ERROR_SEVERITY()
    ,@ErrorState = ERROR_STATE();

    RAISERROR(@ErrorMessage, @ErrorSeverity, @ErrorState);
    END CATCH;
    END;
    GO

    CREATE OR ALTER PROCEDURE dbo.ErrorTest2
    AS
    BEGIN
    SET NOCOUNT ON;

    BEGIN TRY
    EXEC dbo.ErrorTest1;
    END TRY
    BEGIN CATCH
    DECLARE @ErrorMessage NVARCHAR(4000);
    DECLARE @ErrorSeverity INT;
    DECLARE @ErrorState INT;

    SELECT @ErrorMessage = ERROR_MESSAGE()
    ,@ErrorSeverity = ERROR_SEVERITY()
    ,@ErrorState = ERROR_STATE();

    RAISERROR(@ErrorMessage, @ErrorSeverity, @ErrorState);
    END CATCH;
    END;
    GO

    EXEC dbo.ErrorTest2;

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

  • It might be a better option - if using TRY/CATCH - to THROW the error instead of using RAISERROR.

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • Jeffrey Williams wrote:

    It might be a better option - if using TRY/CATCH - to THROW the error instead of using RAISERROR.

    I'd be interested to hear your reasoning.

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

  • This was removed by the editor as SPAM

  • zoah666 wrote:

    zoah666 wrote:

    Stored procedure OUTER_TEST calls stored procedure INNER_TEST.

    If an error in INNER_TEST, how do I capture the error message (to store in a table). When I have a try-catch in OUTER_TEST, I can only access a later error message and not the initial one from INNER_TEST

    I got this,..

    What, exactly, have you got?

    Did you understand my code? A very simple modification to it would achieve your desired outcome.

    • This reply was modified 2 years, 1 month ago by  Phil Parkin.

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

  • Phil Parkin wrote:

    Jeffrey Williams wrote:

    It might be a better option - if using TRY/CATCH - to THROW the error instead of using RAISERROR.

    I'd be interested to hear your reasoning.

    This is the main one that sticks out to me

    Raiserror >Does not honor SET XACT_ABORT.

    Throw > Transactions will be rolled back if SET XACT_ABORT is ON.

    ----------------------------------------------------

  • Phil Parkin wrote:

    Jeffrey Williams wrote:

    It might be a better option - if using TRY/CATCH - to THROW the error instead of using RAISERROR.

    I'd be interested to hear your reasoning.

    Using THROW will save all that coding for getting the error values. So 1 line instead of  7. Your code would just look like this

    CREATE OR ALTER PROCEDURE dbo.ErrorTest1
    AS
    BEGIN
    SET NOCOUNT ON;

    BEGIN TRY
    SELECT 1 / 0;
    END TRY
    BEGIN CATCH
    THROW;
    END CATCH;
    END;
    GO

    CREATE OR ALTER PROCEDURE dbo.ErrorTest2
    AS
    BEGIN
    SET NOCOUNT ON;

    BEGIN TRY
    EXEC dbo.ErrorTest1;
    END TRY
    BEGIN CATCH
    THROW;
    END CATCH;
    END;
    GO

    EXEC dbo.ErrorTest2;

Viewing 8 posts - 1 through 7 (of 7 total)

You must be logged in to reply to this topic. Login to reply