FirebirdSQL logo

WHEN …​ DO

Catches an exception for error handling

Syntax
WHEN {<error> [, <error> ...] | ANY}
DO <compound_statement>

<error> ::=
  { EXCEPTION exception_name
  | SQLCODE number
  | GDSCODE errcode
  | SQLSTATE sqlstate_code }
Table 1. WHEN …​ DO Statement Parameters
Argument Description

exception_name

Exception name

number

SQLCODE error code

errcode

Symbolic GDSCODE error name

sqlstate_code

String literal with the SQLSTATE error code

compound_statement

A single statement, or a block of statements

The WHEN …​ DO statement handles Firebird errors and user-defined exceptions.The statement catches all errors and user-defined exceptions listed after the keyword WHEN keyword.If WHEN is followed by the keyword ANY, the statement catches any error or user-defined exception, even if they have already been handled in a WHEN block located higher up.

The WHEN …​ DO statements must be located at the end of a block of statements, before the block’s END statement, and after any other statement.

The keyword DO is followed by a single statement, or statements wrapped in a BEGIN …​ END block, that handles the exception.The SQLCODE, GDSCODE, and SQLSTATE context variables are available in the context of this statement or block.Use the RDB$ERROR function to obtain the SQLCODE, GDSCODE, SQLSTATE, custom exception name and exception message.The EXCEPTION statement, without parameters, can also be used in this context to re-throw the error or exception.

Targeting GDSCODE

The argument for the WHEN GDSCODE clause is the symbolic name associated with the internally-defined exception, such as grant_obj_notfound for GDS error 335544551.

In a statement or block of statements of the DO clause, a GDSCODE context variable, containing the numeric code, becomes available.That numeric code is required if you want to compare a GDSCODE exception with a targeted error.To compare it with a specific error, you need to use a numeric values, for example 335544551 for grant_obj_notfound.

Similar context variables are available for SQLCODE and SQLSTATE.

The WHEN …​ DO statement or block is only executed when one of the events targeted by its conditions occurs at run-time.If the WHEN …​ DO statement is executed, even if it does nothing, execution will continue as if no error occurred: the error or user-defined exception neither terminates nor rolls back the operations of the trigger or stored procedure.

However, if the WHEN …​ DO statement or block does nothing to handle or resolve the error, the DML statement (SELECT, INSERT, UPDATE, DELETE, MERGE) that caused the error will be rolled back and none of the statements below it in the same block of statements are executed.

Important
  1. If the error is not caused by one of the DML statements (SELECT, INSERT, UPDATE, DELETE, MERGE), the entire block of statements will be rolled back, not only the one that caused an error.Any operations in the WHEN …​ DO statement will be rolled back as well.The same limitation applies to the EXECUTE PROCEDURE statement.Read an interesting discussion of the phenomenon in Firebird Tracker ticket firebird#4803.

  2. In selectable stored procedures, output rows that were already passed to the client in previous iterations of a FOR SELECT …​ DO …​ SUSPEND loop remain available to the client if an exception is thrown subsequently in the process of retrieving rows.

Scope of a WHEN …​ DO Statement

A WHEN …​ DO statement catches errors and exceptions in the current block of statements.It also catches exceptions from nested blocks, if those exceptions have not been handled in those blocks.

All changes made before the statement that caused the error are visible to a WHEN …​ DO statement.However, if you try to log them in an autonomous transaction, those changes are unavailable, because the transaction where the changes took place is not committed at the point when the autonomous transaction is started.Example 4, below, demonstrates this behaviour.

Tip

When handling exceptions, it is sometimes desirable to handle the exception by writing a log message to mark the fault and having execution continue past the faulty record.Logs can be written to regular tables, but there is a problem with that: the log records will “disappear” if an unhandled error causes the module to stop executing, and a rollback is performed.Use of external tables can be useful here, as data written to them is transaction-independent.The date inserted into a linked external file will still be there, regardless of whether the overall process succeeds or not.

docnext count = 1

Examples using WHEN…​DO

  1. Replacing the standard error with a custom one:

    CREATE EXCEPTION COUNTRY_EXIST '';
    SET TERM ^;
    CREATE PROCEDURE ADD_COUNTRY (
      ACountryName COUNTRYNAME,
      ACurrency VARCHAR(10) )
    AS
    BEGIN
      INSERT INTO country (country, currency)
        VALUES (:ACountryName, :ACurrency);
    
      WHEN SQLCODE -803 DO
        EXCEPTION COUNTRY_EXIST 'Country already exists!';
    END^
    SET TERM ^;
  2. Logging an error and re-throwing it in the WHEN block:

    CREATE PROCEDURE ADD_COUNTRY (
      ACountryName COUNTRYNAME,
      ACurrency VARCHAR(10) )
    AS
    BEGIN
      INSERT INTO country (country,
                           currency)
      VALUES (:ACountryName,
              :ACurrency);
      WHEN ANY DO
      BEGIN
        -- write an error in log
        IN AUTONOMOUS TRANSACTION DO
          INSERT INTO ERROR_LOG (PSQL_MODULE,
                                 GDS_CODE,
                                 SQL_CODE,
                                 SQL_STATE,
                                 MESSAGE)
          VALUES ('ADD_COUNTRY',
                  GDSCODE,
                  SQLCODE,
                  SQLSTATE,
                  RDB$ERROR(MESSAGE));
        -- Re-throw exception
        EXCEPTION;
      END
    END
  3. Handling several errors in one WHEN block

    ...
    WHEN GDSCODE GRANT_OBJ_NOTFOUND,
    	 GDSCODE GRANT_FLD_NOTFOUND,
    	 GDSCODE GRANT_NOPRIV,
    	 GDSCODE GRANT_NOPRIV_ON_BASE
    DO
    BEGIN
      EXECUTE PROCEDURE LOG_GRANT_ERROR(GDSCODE,
        RDB$ERROR(MESSAGE);
      EXIT;
    END
    ...
  4. Catching errors using the SQLSTATE code

    EXECUTE BLOCK
    AS
      DECLARE VARIABLE I INT;
    BEGIN
      BEGIN
        I = 1/0;
        WHEN SQLSTATE '22003' DO
          EXCEPTION E_CUSTOM_EXCEPTION
            'Numeric value out of range.';
        WHEN SQLSTATE '22012' DO
          EXCEPTION E_CUSTOM_EXCEPTION
            'Division by zero.';
        WHEN SQLSTATE '23000' DO
          EXCEPTION E_CUSTOM_EXCEPTION
           'Integrity constraint violation.';
      END
    END