Exceptions and Exception Handling
This topic describes exceptions and exception handling in SingleStore Helios Procedural SQL (PSQL) user-defined scalar-valued functions (UDFs) and stored procedures (SPs).
Exception Types
UDFs and SPs raise exceptions when errors occur during execution.
Two kinds of exceptions can be raised:
-
An internal exception, which is a predefined exception generated by SingleStore Helios
-
A user-defined exception, which is defined by the user in a UDF or SP
The following sections describe each kind of exception and how to handle exceptions in your UDF or SP.
Exception Handling Syntax
If you want to catch an exception, you can use a Statement Block containing an exception handling section beginning with the EXCEPTION
keyword.EXCEPTION
:
statement_block:
[ DECLARE variable_list ] [ ...n ]
BEGIN
statement_list
[ EXCEPTION
when_clause_list ]
END;
when_clause_list:
when_clause [ ...n ]
when_clause:
WHEN exception_type THEN statement_list
exception_
An exception_
is the name of a built-in server error type.
The keyword OTHERS
can also be used as an exception_
.OTHERS
will match all exceptions.
statement_
A list of one or more statements terminated by semicolons.
Internal Exceptions
Internal exceptions are defined by SingleStore Helios, and they are raised when a function or procedure errors under a wide variety of conditions.
Here are some possible internal exceptions:
Exception Name |
Description |
Scenario When Exception is Thrown |
---|---|---|
|
The Scalar function did not return any value. |
This exception is thrown when a |
|
Column name does not exist. |
A column that does not exist in a table is referenced in a query. |
|
Table already exists. |
While creating a table, a table with the same name already exists. |
|
Table does not exist. |
A table that does not exist is referenced in a query. |
|
Table does not exist. |
A table that does not exist is referenced in a query. |
|
Duplicate key error. |
A duplicate value is entered for a column with a key constraint. |
|
Column count does not match value count. |
The number of columns in a table and the number of values specified in the query are not the same. |
|
Issue with parsing dynamic SQL. |
There is an error in the SQL statement. |
|
Cannot find file, usually in |
Either the file does not exist or the file path is incorrect. |
Consider the following example, where table t
contains two entries and id
is defined as a PRIMARY KEY
:
CREATE TABLE t(id INT PRIMARY KEY, str VARCHAR(255));CREATE TABLE t_errors(dt DATETIME, id INT, str VARCHAR(255));INSERT t VALUES (0, "foo"), (1, "bar");
The following procedure attempts to insert a row with a duplicate primary key, which raises the ER_
exception.t_
table instead:
DELIMITER //CREATE OR REPLACE PROCEDURE insert_handle_exception(id INT, str VARCHAR(255)) ASBEGINSTART TRANSACTION;INSERT INTO t VALUES (1, str);COMMIT;EXCEPTIONWHEN ER_DUP_ENTRY THENROLLBACK;START TRANSACTION;INSERT INTO t_errors VALUES (current_timestamp(), id, str);COMMIT;END //DELIMITER ;
When insert_
is called, the error-handling behavior successful inserts the contents of the row, and the current time, into the t_
table instead:
CALL insert_handle_exception(1, "baz");
Query OK, 0 rows affected (0.26 sec)
SELECT * FROM t_errors;
+---------------------+------+------+
| dt | id | str |
+---------------------+------+------+
| 2017-09-26 22:33:22 | 1 | baz |
+---------------------+------+------+
SELECT * FROM t;
+----+------+
| id | str |
+----+------+
| 0 | foo |
| 1 | bar |
+----+------+
The use of START TRANSACTION
, COMMIT
, and ROLLBACK
above is not really necessary in this simple example, but it does illustrate how you can use transaction control statements in conjunction with exception handling.
User-Generated Exceptions
Users can generate their own exceptions through the RAISE USER_
statement.USER_
is a function that takes a string argument.USER_
argument.ER_
exception.
The RAISE
keyword by itself can only be used inside of an EXCEPTION
block, and it re-raises the currently caught exception.
When in an EXCEPTION
block, the EXCEPTION_
function can be used to get the message that was passed into USER_
for the currently caught exception.EXCEPTION_
DELIMITER //CREATE OR REPLACE PROCEDURE attemptWithRetry() ASDECLARE i INT;BEGINWHILE true LOOPBEGINSTART TRANSACTION;CALL attempt();EXCEPTIONWHEN ER_USER_RAISE THENROLLBACK;IF exception_message() = "retry" THENi = sleep(1);CONTINUE;ELSIF exception_message() = "abort" THENRAISE;END IF;WHEN OTHERS THENROLLBACK;RAISE user_exception("other exception");-- i = sleep(1);END;COMMIT;EXIT;END LOOP;END //DELIMITER ;DELIMITER //CREATE OR REPLACE PROCEDURE attempt() ASDECLARE i INT; j INT NOT NULL = 0;BEGINi = now() % 10;IF i >= 7 THENRAISE user_exception("abort");ELSIF i <= 3 THENj = NULL; -- force an exception by assigning NULL to a NOT NULL typeEND IF;RAISE user_exception("retry");END //DELIMITER ;
This example illustrates the use of OTHERS
to catch exceptions not explicitly named in a WHEN
clause.i <= 3
(about 30% of the time) in attempt()
, the assignment j = NULL
is tried, and it will always fail because j
is declared as NOT NULL
.WHEN OTHERS
.
Now, when we call attemptWithRetry()
, you can see that either the abort
user exception or the other exception
user exception was raised.
CALL attemptWithRetry();
ERROR 2242 (HY000): Unhandled exception
Type: ER_USER_RAISE
Message: abort
Callstack:
#0 Line 7 in `trades`.`attemptWithRetry`
CALL attemptWithRetry();
ERROR 2242 (HY000): Unhandled exception
Type: ER_USER_RAISE
Message: other exception
Callstack:
#0 Line 7 in `trades`.`attemptWithRetry`
Last modified: June 12, 2023