Error handling in stored procedure AND checking

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • barmatt80@gmail.com

    Error handling in stored procedure AND checking

    I am stumped on the error reporting with sql server. I was told i
    need to return @SQLCode(code showing if successful or not) and
    @ErrMsg(and the message returned). I am clueless on this.

    I wrote this procedure:

    Code:
    ALTER PROCEDURE [dbo].[usp_AcceptLeaveBalance]
    
    @Emp_SSN int,
    @Annual_Forward decimal(10,2),
    @Sick_Forward decimal(10,2),
    @Family_Forward decimal(10,2),
    @Other_Forward decimal(10,2)
    
    AS
    
    UPDATE OT_MAIN
    
    SET
    
    EmpAnnual_Forward = IsNull(@Annual_Forward, EmpAnnual_Forward),
    EmpSick_Forward = IsNull(@Sick_Forward, EmpSick_Forward),
    EmpFamily_Forward = IsNull(@Family_Forward, EmpFamily_Forward),
    EmpOther_Forward = IsNull(@Other_Forward, EmpOther_Forward)
    
    WHERE
    
    Emp_SSN=@Emp_SSN
    I can execute the procedure using this:

    Code:
    exec usp_AcceptLeaveBalance 123456789, 10, 10, null, 10
    Sql comments that it is successful and that 0 rows are changed. I
    know it shouldn't be successful because 123456789 does not refer to
    any SSN.

    So i am just inquring how to do the error handling and secondly I am
    guessing I need to check to see if the ssn exists first.

    Any suggestions or help.

    I greatly appreciate it, and thanks for the help.
  • Plamen Ratchev

    #2
    Re: Error handling in stored procedure AND checking

    SQL Server reports that the stored procedure executed successfully because
    there are no errors. Just because your SQL statement attempts to update
    non-existing SSN, it does not mean you will get an error. You have to handle
    this using application logic, not to expect SQL Server to report an error.

    If you really do want to get an error when invalid SSN update is attempted,
    then you can add something like the code below at the end of your stored
    procedure, just after the UPDATE statement:

    IF @@ROWCOUNT = 0
    RAISERROR ('Invalid SSN.', 16, 1)

    The @@ROWCOUNT function returns the number of rows affected by the last
    statement. Then if 0 rows have been updated it means the SSN is invalid and
    RAISERROR will force an error.

    However, based on the requirements that you need to return @SQLCode and
    @ErrMsg, you are probably looking for something like this:

    1). Add two OUTPUT parameters to the stored procedure for @@SQLCode and
    @ErrMsg:
    @SQLCode CHAR(1) OUTPUT, @ErrMsg VARCHAR(20) OUTPUT

    2) Inside the stored procedure, just after the UPDATE check if rows have
    been updated and set those two parameters:
    IF @@ROWCOUNT = 0
    SELECT @SQLCode = 'E', @ErrMsg = 'Invalid SSN.'

    3) Then when you declare those two parameters and pass to the stored
    procedure with the OUTPUT keyword.

    This is just one example on how you can return the error code and message,
    based on your application architecture different variations can be used. You
    can probably go only with error message as the error code is redundant, but
    not sure about your specs.

    HTH,

    Plamen Ratchev


    Comment

    • barmatt80@gmail.com

      #3
      Re: Error handling in stored procedure AND checking

      On Jan 3, 5:25 pm, "Plamen Ratchev" <Pla...@SQLStud io.comwrote:
      SQL Server reports that the stored procedure executed successfully because
      there are no errors. Just because your SQL statement attempts to update
      non-existing SSN, it does not mean you will get an error. You have to handle
      this using application logic, not to expect SQL Server to report an error.
      >
      If you really do want to get an error when invalid SSN update is attempted,
      then you can add something like the code below at the end of your stored
      procedure, just after the UPDATE statement:
      >
      IF @@ROWCOUNT = 0
      RAISERROR ('Invalid SSN.', 16, 1)
      >
      The @@ROWCOUNT function returns the number of rows affected by the last
      statement. Then if 0 rows have been updated it means the SSN is invalid and
      RAISERROR will force an error.
      >
      However, based on the requirements that you need to return @SQLCode and
      @ErrMsg, you are probably looking for something like this:
      >
      1). Add two OUTPUT parameters to the stored procedure for @@SQLCode and
      @ErrMsg:
      @SQLCode CHAR(1) OUTPUT, @ErrMsg VARCHAR(20) OUTPUT
      >
      2) Inside the stored procedure, just after the UPDATE check if rows have
      been updated and set those two parameters:
      IF @@ROWCOUNT = 0
      SELECT @SQLCode = 'E', @ErrMsg = 'Invalid SSN.'
      >
      3) Then when you declare those two parameters and pass to the stored
      procedure with the OUTPUT keyword.
      >
      This is just one example on how you can return the error code and message,
      based on your application architecture different variations can be used. You
      can probably go only with error message as the error code is redundant, but
      not sure about your specs.
      >
      HTH,
      >
      Plamen Ratchevhttp://www.SQLStudio.c om
      thanks for the help, i understand what and how you are doing it and
      had the output variables in my stored procedure at one time, but the
      if statement was my downfall. I showed the guy that told me to create
      the procedure and said it was coming along but wanted me to setup if
      there was an error(i am guessing any error) that he wants an email
      generated with the error sent to him. I am at a complete standstill
      till i figure that one out.

      Thanks for the help I do appreciate it.

      Comment

      • Plamen Ratchev

        #4
        Re: Error handling in stored procedure AND checking

        In general if I have an option I would prefer to handle e-mail notifications
        at the application layer (that is the .NET application for example), where
        this is much easier and more natural. In that case you just pass the output
        parameters back to the application layer and use the utilities at hand to
        send the e-mail notification.

        Based on your notes seems that you need to send the e-mail notification from
        inside the stored procedure. Here are a couple options:

        1). If on SQL Server 2000 then you can use the built-in extended stored
        procedure xp_sendmail. An example will be something like this:

        EXEC master.dbo.xp_s endmail
        @recipients=N't est@company.com ',
        @message=N'Inva lid SSN.'

        You can read more about all options and configuration for for xp_sendmail
        here:


        2). On SQL Server 2005 you can use sp_send_dbmail. Here is an example:

        EXEC msdb.dbo.sp_sen d_dbmail
        @profile_name = 'Test',
        @recipients = 'test@company.c om',
        @body = 'Invalid SSN.',
        @subject = 'Automated notification'

        More about sp_send_dbmail here:


        3). On SQL Server 2000 (and I have seen posts it works on SQL Server 2005
        too) you can use the third party extended stored procedure xp_smtp_sendmai l.
        It is using directly SMTP (while xp_sendmail uses MAPI), like sp_send_dbmail
        does. More info about it here:
        Dumpster & Co. provides local dumpster rental near you. Give us a call today at 866-946-8519 for a free quote!


        Note that all those methods for sending e-mail are not automatically
        available. Read the information at the above links on security and
        configuration.

        HTH,

        Plamen Ratchev


        Comment

        • barmatt80@gmail.com

          #5
          Re: Error handling in stored procedure AND checking

          On Jan 4, 10:30 pm, "Plamen Ratchev" <Pla...@SQLStud io.comwrote:
          In general if I have an option I would prefer to handle e-mail notifications
          at the application layer (that is the .NET application for example), where
          this is much easier and more natural. In that case you just pass the output
          parameters back to the application layer and use the utilities at hand to
          send the e-mail notification.
          >
          Based on your notes seems that you need to send the e-mail notification from
          inside the stored procedure. Here are a couple options:
          >
          1). If on SQL Server 2000 then you can use the built-in extended stored
          procedure xp_sendmail. An example will be something like this:
          >
          EXEC master.dbo.xp_s endmail
                 @recipients=N't ...@company.com ',
                 @message=N'Inva lid SSN.'
          >
          You can read more about all options and configuration for for xp_sendmail
          here:http://technet.microsoft.com/en-us/l.../ms189505.aspx
          >
          2). On SQL Server 2005 you can use sp_send_dbmail. Here is an example:
          >
          EXEC msdb.dbo.sp_sen d_dbmail
                 @profile_name = 'Test',
                 @recipients = 't...@company.c om',
                 @body = 'Invalid SSN.',
                 @subject = 'Automated notification'
          >
          More about sp_send_dbmail here:http://msdn2.microsoft.com/en-us/library/ms190307.aspx
          >
          3). On SQL Server 2000 (and I have seen posts it works on SQL Server 2005
          too) you can use the third party extended stored procedure xp_smtp_sendmai l.
          It is using directly SMTP (while xp_sendmail uses MAPI), like sp_send_dbmail
          does. More info about it here:http://sqldev.net/xp/xpsmtp.htm
          >
          Note that all those methods for sending e-mail are not automatically
          available. Read the information at the above links on security and
          configuration.
          >
          HTH,
          >
          Plamen Ratchevhttp://www.SQLStudio.c om
          Thanks for the help, I greatly appreciate it. I will look into the
          link provided.

          Comment

          Working...