Stored procedures can include handlers that are called when certain conditions occur within the procedure. The applicability of each handler depends on its position within the procedure definition and the one or more conditions it handles.
Scope and rules for handlers
The following rules apply to the scope of handlers in OceanBase Database:
Handlers declared in a
BEGIN ... ENDblock are only applicable to SQL statements that follow the handler declaration within the block. If a handler itself raises a condition, it cannot handle that condition, and no other handlers can be declared within the block. In the following example, handlersh1andh2are valid for conditions raised by statementsst1andst2, respectively, but not for conditions raised within the bodies ofh1orh2.BEGIN -- outer block DECLARE EXIT HANDLER FOR ...; -- handler h1 DECLARE EXIT HANDLER FOR ...; -- handler h2 st1; st2; END;A handler is only valid within the block in which it is declared and cannot be activated by conditions occurring outside of that block. In the following example, handler
h1is valid within the scope ofst1in the inner block, but not forst2in the outer block:BEGIN -- outer block BEGIN -- inner block DECLARE EXIT HANDLER FOR ...; -- handler h1 st1; END; st2; END;Handlers can be specific or general. Specific handlers are used for error codes,
SQLSTATEvalues, or condition names. General handlers are used for conditions in theSQLWARNING,SQLEXCEPTION, orNOT FOUNDcategories. Condition specificity is related to condition priority.Multiple handlers with different characteristics can be declared in different scopes. For example, an outer block may have a specific error code handler, while an inner block may have a general
SQLWARNINGhandler. Alternatively, a single block may have both specific error code handlers and generalSQLWARNINGhandlers.
The activation of a handler depends not only on its scope and condition value but also on other handlers. When a condition occurs in a stored program, the server searches for applicable handlers within the current scope (the current BEGIN ... END block). If no applicable handler is found, it continues searching in the next outer scope (block). When the server finds one or more applicable handlers in the specified scope, it selects based on condition priority. The condition priorities are as follows:
Error code handlers have higher priority than
SQLSTATEvalue handlers.SQLSTATEvalue handlers have higher priority than generalSQLWARNING,SQLEXCEPTION, orNOT FOUNDhandlers.SQLEXCEPTIONhandlers have higher priority thanSQLWARNINGhandlers.Multiple applicable handlers with the same priority can exist. For example, a statement can generate multiple warnings with different error codes, each having a specific handler. In such cases, the server's choice of which handler to activate is indeterminate and may vary based on the situation.
If multiple applicable handlers exist in different scopes, the handler in the local scope takes precedence over those in the outer scope, even if the outer scope's handler has a higher priority.
If no applicable handler exists when a condition occurs, the following actions are taken based on the condition's category:
For
SQLEXCEPTIONconditions, the stored program terminates at the statement that raised the condition, similar to using anEXIThandler. If the program is called by another stored program, the calling program will use its own selection rules to handle the condition.For
SQLWARNINGconditions, the program continues execution, similar to using aCONTINUEhandler.For
NOT FOUNDconditions, if the condition is raised normally, the action isCONTINUE. If the condition is raised bySIGNALorRESIGNAL, the action isEXIT.
Examples
Examples 1, 2, 3, and 4 show how the handler selection rules apply.
The following example 1 shows a procedure that contains two handlers. One handler is for the specified SQLSTATE value ('42S02') that occurs when an attempt is made to drop a nonexistent table. The other handler is for the general SQLEXCEPTION category.
-- Example 1
CREATE PROCEDURE proc1()
BEGIN
DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02'
SELECT 'SQLSTATE handler was activated' AS msg;
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
SELECT 'SQLEXCEPTION handler was activated' AS msg;
DROP TABLE test.tbl1;
END;
In example 1, both handlers are declared in the same block and have the same scope. However, the SQLSTATE handler takes precedence over the SQLEXCEPTION handler. Therefore, if the table tbl1 does not exist, the DROP TABLE statement raises a condition that activates the SQLSTATE handler. Here is the result:
obclient> CALL proc1();
+--------------------------------+
| msg |
+--------------------------------+
| SQLSTATE handler was activated |
+--------------------------------+
1 row in set
In example 2, the procedure contains the same two handlers as in example 1. However, the DROP TABLE statement and the SQLEXCEPTION handler are in an inner block.
-- Example 2
CREATE PROCEDURE proc2()
BEGIN -- outer block
DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02'
SELECT 'SQLSTATE handler was activated' AS msg;
BEGIN -- inner block
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
SELECT 'SQLEXCEPTION handler was activated' AS msg;
DROP TABLE test.tbl1; -- occurs in the inner block
END;
END;
In example 2, the handler that is closer to the location where the condition occurs is activated first. Therefore, the SQLEXCEPTION handler is activated, even though it is more general than the SQLSTATE handler. Here is the result:
obclient> CALL proc2();
+------------------------------------+
| msg |
+------------------------------------+
| SQLEXCEPTION handler was activated |
+------------------------------------+
1 row in set
In example 3, one handler is declared in a block within the scope of the DROP TABLE statement:
-- Example 3
CREATE PROCEDURE proc3()
BEGIN -- outer block
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
SELECT 'SQLEXCEPTION handler was activated' AS msg;
BEGIN -- inner block
DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02'
SELECT 'SQLSTATE handler was activated' AS msg;
END;
DROP TABLE test.tbl1; -- occurs in the outer block
END;
In example 3, the SQLEXCEPTION handler is activated because the SQLSTATE value is not in the scope of the condition raised by the DROP TABLE statement. Here is the result:
obclient> CALL proc3();
+------------------------------------+
| msg |
+------------------------------------+
| SQLEXCEPTION handler was activated |
+------------------------------------+
1 row in set
In example 4, both handlers are declared in a block within the scope of the DROP TABLE statement:
-- Example 4
CREATE PROCEDURE proc4()
BEGIN -- outer block
BEGIN -- inner block
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
SELECT 'SQLEXCEPTION handler was activated' AS msg;
DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02'
SELECT 'SQLSTATE handler was activated' AS msg;
END;
DROP TABLE test.tbl1; -- occurs in the outer block
END;
In example 4, neither handler is activated because they are not in the scope of the DROP TABLE statement. The condition raised by this statement is not handled and the procedure terminates with an error. Here is the result:
obclient> CALL proc4();
ERROR 1051 (42S02): Unknown table 'test.tbl1'