Scope of handlers
Stored programs can include handlers that are called when specific conditions occur within the program. The applicability of each handler depends on its position within the program definition and the one or more conditions it handles.
Scope and rules for handlers
The following rules apply to the scope of handlers in seekdb:
-
Handlers declared within a
BEGIN ... ENDblock apply only to SQL statements that follow the handler declaration in the block. If a handler itself raises a condition, it cannot handle that condition, and no other handlers can be declared in the block. In the following example, handlersh1andh2apply to conditions raised by statementsst1andst2, respectively, but not to 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 valid only within the block in which it is declared and cannot be activated by conditions that occur outside of that block. In the following example, handler
h1is valid within thest1scope of the inner block, but not within thest2scope of 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 might have a specific error code handler, while an inner block might have a general
SQLWARNINGhandler. Alternatively, a block might have both a specific error code handler and a generalSQLWARNINGhandler.
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 handlers are 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. Condition priorities are as follows:
-
Error code handlers take precedence over
SQLSTATEvalue handlers. -
SQLSTATEvalue handlers take precedence over generalSQLWARNING,SQLEXCEPTION, orNOT FOUNDhandlers. -
SQLEXCEPTIONhandlers take precedence overSQLWARNINGhandlers. -
Multiple applicable handlers with the same priority can exist. For example, a statement can generate multiple warnings with different error codes, each with a specific error handler. In such cases, the server's choice of which handler to activate is indeterminate and may vary depending on the situation.
If multiple applicable handlers exist in different scopes, the handler in the local scope takes precedence over handlers in the outer scope, even if the outer scope's handler has a higher priority for the specified condition.
If no applicable handler exists when a condition occurs, the following actions are taken based on the condition's category:
-
For an
SQLEXCEPTIONcondition, 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 apply its own selection rules to handle the condition. -
For an
SQLWARNINGcondition, the program continues execution, similar to using aCONTINUEhandler. -
For a
NOT FOUNDcondition, 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 to apply the handler selection rules.
Example 1 shows a procedure that contains two handlers. One handler is activated when a specified SQLSTATE value ('42S02') occurs during an attempt to drop a table that does not exist. The other handler belongs to 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 triggers a condition that activates the SQLSTATE handler. The following code shows this:
CALL proc1();
+--------------------------------+
| msg |
+--------------------------------+
| SQLSTATE handler was activated |
+--------------------------------+
1 row in set
Example 2 shows a procedure that contains the same two handlers as Example 1. However, the DROP TABLE statement and the SQLEXCEPTION handler are declared in an inner block, which is nested within the block that contains the SQLSTATE handler.
-- 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 within 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. The following code shows this:
CALL proc2();
+------------------------------------+
| msg |
+------------------------------------+
| SQLEXCEPTION handler was activated |
+------------------------------------+
1 row in set
Example 3 shows a procedure that contains one handler declared in a block that is 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 within the outer block
END;
In Example 3, the SQLEXCEPTION handler is activated because the SQLSTATE handler is not within the scope of the condition triggered by the DROP TABLE statement. The following code shows this:
CALL proc3();
+------------------------------------+
| msg |
+------------------------------------+
| SQLEXCEPTION handler was activated |
+------------------------------------+
1 row in set
Example 4 shows a procedure that contains two handlers declared in a block that is 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 within the outer block
END;
In Example 4, neither handler is applicable because they are not within the scope of the DROP TABLE statement. The condition triggered by the statement is not handled and the procedure terminates with an error. The following code shows this:
CALL proc4();
ERROR 1051 (42S02): Unknown table 'test.tbl1'