Database Journal
MS SQL Oracle DB2 Access MySQL PostgreSQL Sybase PHP SQL Etc SQL Scripts & Samples Links Database Forum

» Database Journal Home
» Database Articles
» Database Tutorials
MS SQL
Oracle
DB2
MS Access
MySQL
» RESOURCES
Database Tools
SQL Scripts & Samples
Links
» Database Forum
» Sitemap
Free Newsletters:
DatabaseDaily  
News Via RSS Feed


follow us on Twitter
Database Journal |DBA Support |SQLCourse |SQLCourse2
 

Featured Database Articles

MySQL

Posted Oct 11, 2005

MySQL Stored Procedures: Part 3

By Ian Gilfillan



Introduction


In part 3 of the ongoing series about MySQL's stored procedures, we look at handlers and cursors in particular - both logical constructs that allow added functionality. Handlers allow you to run statements if a certain condition is met, while cursors, although only nominally supported in MySQL 5, allow looping through a resultset, processing it row by row. If you have not yet done so, look at part 1 and part 2 of the series first, especially if stored procedures are new to you.


Handlers and error handling


With stored procedures allowing the DBMS to grapple with concepts that beforehand were only dealt with in the murkier programming world, there is a clear need for a more elegant way of handling errors and exceptions. Enter the handler. There are two types of handler supported by MySQL - EXIT handlers that immediately exit the current BEGIN/END block, and CONTINUE handlers that allow processing to continue after the handler actions have been performed (the UNDO handler that may be familiar to users of other DBMS' is not yet supported). Below is an example. Remember that we are still using the | character as a delimiter, as outlined in part 1 of the series.



mysql>
CREATE procedure sp3()
 BEGIN
  DECLARE 'unknown column' CONDITION FOR SQLSTATE '42S22';
  DECLARE EXIT HANDLER FOR 'unknown column'
   SELECT 'error error whoop whoop';
  SELECT aha;
  SELECT 'continuing';
 END;|
Query OK, 0 rows affected (0.00 sec)
mysql> CALL sp3()\G
*************************** 1. row ***************************
error error whoop whoop: error error whoop whoop
1 row in set (0.00 sec)
Query OK, 0 rows affected (0.00 sec)

So, what happened here? We declared a condition, called 'unknown column'. It is a condition that occurs when SQLSTATE 42S22 is reached, which is when there is an unknown column. You can find a full list of error codes and messages on the MySQL site. Next, we declare an exit handler for the 'unknown column' condition, declared above. The handler simply displays the message error error whoop whoop. The actual body of the procedure consists of two statements, SELECT aha, which is designed to trigger SQLSTATE 42S22, and SELECT 'continuing', which is never actually executed as, being an exit handler, the procedure is immediately exited when the condition is met. So, when we call sp3(), the SELECT statement triggers the condition, and the message is displayed. Let's change this to use a CONTINUE handler, and see the difference.

mysql>
CREATE procedure sp4()
 BEGIN
  DECLARE 'unknown column' CONDITION FOR SQLSTATE '42S22';
  DECLARE CONTINUE HANDLER FOR 'unknown column'
   SELECT 'error error whoop whoop';
  SELECT aha;
  SELECT 'continuing';
 END;
 
mysql> CALL sp4()\G
*************************** 1. row ***************************
error error whoop whoop: error error whoop whoop
1 row in set (0.00 sec)
*************************** 1. row ***************************
continuing: continuing
1 row in set (0.06 sec)

As expected, the procedure continues executing after the error, and this time the SELECT 'continuing' statement is run.

Here is another procedure. What do you think it will do? If we want to display the error error and still handling messages as part of the handler, after reaching the aha statement, and then continue with the continuing statement, will this achieve that?

CREATE procedure sp5()
 BEGIN
  DECLARE 'unknown column' CONDITION FOR SQLSTATE '42S22';
  DECLARE CONTINUE HANDLER FOR 'unknown column'
   SELECT 'error error whoop whoop';
   SELECT 'still handling the error';
  SELECT aha;
  SELECT 'continuing';
 END;
 
mysql> CALL sp5()\G
*************************** 1. row ***************************
still handling the error: still handling the error
1 row in set (0.00 sec)
*************************** 1. row ***************************
error error whoop whoop: error error whoop whoop
1 row in set (0.00 sec)
*************************** 1. row ***************************
continuing: continuing
1 row in set (0.00 sec)
Query OK, 0 rows affected (0.00 sec)

The answer is clearly no. I hope that you were eagle-eyed enough to spot the misleading indentation. The SELECT 'still handling the error'; is actually part of the main procedure body, and not part of the error handler. Since we have no BEGIN or END statements as part of the handler, it consists of the one statement only. Here is what will achieve what we actually intended.

mysql>
CREATE procedure sp6()
 BEGIN
  DECLARE 'unknown column' CONDITION FOR SQLSTATE '42S22';
  DECLARE CONTINUE HANDLER FOR 'unknown column'
   BEGIN
    SELECT 'error error whoop whoop';
    SELECT 'still handling the error';
   END;
  SELECT aha;
  SELECT 'continuing';
 END;|
Query OK, 0 rows affected (0.00 sec)
mysql> CALL sp6()\G
*************************** 1. row ***************************
error error whoop whoop: error error whoop whoop
1 row in set (0.00 sec)
*************************** 1. row ***************************
still handling the error: still handling the error
1 row in set (0.00 sec)
*************************** 1. row ***************************
continuing: continuing
1 row in set (0.00 sec)

Just to round off our examples, here is an example of a procedure where the error handler is not called, and none of the handler statements are executed.

mysql>
CREATE procedure sp7()
 BEGIN
  DECLARE 'unknown column' CONDITION FOR SQLSTATE '42S22';
  DECLARE CONTINUE HANDLER FOR 'unknown column'
   BEGIN
    SELECT 'error error whoop whoop';
    SELECT 'still handling the error';
   END;
  SELECT 'continuing';
 END;|
Query OK, 0 rows affected (0.00 sec)
mysql> CALL sp7()\G
*************************** 1. row ***************************
continuing: continuing
1 row in set (0.00 sec)
Query OK, 0 rows affected (0.00 sec)

Variations and uses

For the examples above, we declared a condition to detect an SQLSTATE error. There are other ways. Firstly, handlers can be declared for specific error codes directly - you don't always need to go via an intermediate condition, although doing so is more useful in that the condition name can (and should) be descriptive, so there is no need to refer to a list of error codes at a later stage. The error code can also either be the SQLSTATE error number, as above, or the MySQL error code, as well as one of the more generic SQLWARNING, for all errors with an SQLSTATE beginning with 01, NOT FOUND for all errors with an SQLSTATE beginning with 02, or SQLEXCEPTION for all others. Below is a procedure that acts in a similar manner to our earlier examples. This time we use the MySQL Error code 1054, which is almost equivalent to SQLSTATE 42S22, and we also skip the condition:

mysql> 
CREATE procedure sp8()
 BEGIN
  DECLARE EXIT HANDLER FOR 1054
   BEGIN
    SELECT 'error error whoop whoop';
    SELECT 'still handling the error';
   END;
  SELECT aha;
 END;|
 
mysql> CALL sp8()\G
*************************** 1. row ***************************
error error whoop whoop: error error whoop whoop
1 row in set (0.00 sec)
*************************** 1. row ***************************
still handling the error: still handling the error
1 row in set (0.00 sec)
Query OK, 0 rows affected (0.00 sec)

That's enough examples for now - hopefully you are starting to consider some practical uses for this. The handlers could ROLLBACK statements, or log to an error table. Moreover, the statements could be as complex as required, incorporating all the loops and conditions we looked at in the previous article.



MySQL Archives

Comment and Contribute

 


(Maximum characters: 1200). You have characters left.

 

 




Latest Forum Threads
MySQL Forum
Topic By Replies Updated
MySQL in high availability and transction secure banking application klamor 1 August 28th, 10:24 AM
MySQL rollback UAL225 1 August 28th, 10:15 AM
Browsing a DB file that uses MySql finleytech 1 July 26th, 10:51 AM
php cookie won't pass variable to next page ITdevGirl 0 June 22nd, 12:13 PM


















Thanks for your registration, follow us on our social networks to keep up-to-date