MySQL 从 5.0 开始支持存储过程,到现在最新版本5.5 已经好几个年头了。 虽然MYSQL的异常处理不是很完善,但是处理大多数的应用还是足够了。异常处理的语句有如下几种:1. DECLARE ... CONDITION.
2. DECLARE ... HANDLER.
3. RESIGNAL.
4. SIGNAL.第一种,名为条件声明。DECLARE condition_name CONDITION FOR condition_value这里condition_name 为标准的变量命名, condition_value 为SQLSTATE 值 或者 MySQL 自身的ERROR CODE.单独的condition 语句不能直接运行。 只能作为第二种的一部分。第二种, 名为条件处理。第一种声明好了,接下来自然要做相应的处理。DECLARE handler_action HANDLER
FOR condition_value [, condition_value] ...
statement
handler_action:
CONTINUE
| EXIT
| UNDO
condition_value:
mysql_error_code
| SQLSTATE [VALUE] sqlstate_value
| condition_name
| SQLWARNING
| NOT FOUND
| SQLEXCEPTIONhandler_action 代表处理的动作,目前有效的有两种, 继续和直接退出。condition_value 有好几种,其中包括前面条件声明里的SQLSTATE, MYSQL EEROR CODE, condition_name 以及范围混淆的其他两种SQLWARNING,SQLEXCEPTION. NOT FOUND表示任何不存在的WARNING或者ERROR。第三种, 代表伪装系统的错误信息以及代码,刷新当前警告缓冲区域。RESIGNAL [condition_value]
[SET signal_information_item
[, signal_information_item] ...]
condition_value:
SQLSTATE [VALUE] sqlstate_value
| condition_name
signal_information_item:
condition_information_item_name = simple_value_specification
condition_information_item_name:
CLASS_ORIGIN
| SUBCLASS_ORIGIN
| MESSAGE_TEXT
| MYSQL_ERRNO
| CONSTRAINT_CATALOG
| CONSTRAINT_SCHEMA
| CONSTRAINT_NAME
| CATALOG_NAME
| SCHEMA_NAME
| TABLE_NAME
| COLUMN_NAME
| CURSOR_NAME
特别注意的是可以伪装的具体东西很多,包括错误代码(MYSQL自身的东东),错误内容,错误的数据库名,表名,列名等等。第四种,SIGNAL和RESIGNAL差别不大,我们记住signal 不能单独运行,resignal可以单独运行。SIGNAL condition_value
[SET signal_information_item
[, signal_information_item] ...]
condition_value:
SQLSTATE [VALUE] sqlstate_value
| condition_name
signal_information_item:
condition_information_item_name = simple_value_specification
condition_information_item_name:
CLASS_ORIGIN
| SUBCLASS_ORIGIN
| MESSAGE_TEXT
| MYSQL_ERRNO
| CONSTRAINT_CATALOG
| CONSTRAINT_SCHEMA
| CONSTRAINT_NAME
| CATALOG_NAME
| SCHEMA_NAME
| TABLE_NAME
| COLUMN_NAME
| CURSOR_NAME
我们现在给几个例子。
不用RESIGNAL/SIGNAL。- DELIMITER $$
- USE `t_girl`$$
- DROP PROCEDURE IF EXISTS `sp_signal1`$$
- CREATE DEFINER=`root`@`localhost` PROCEDURE `sp_signal1`(
- IN f_id INT
- )
- BEGIN
- DECLARE con1 TINYINT DEFAULT 0;
- DECLARE con1 CONDITION FOR SQLSTATE '23000';
- DECLARE CONTINUE HANDLER FOR con1
- BEGIN
- SELECT 'Error Code : 22\r\nDuplicated!';
- END;
- INSERT INTO user_info VALUES (f_id);
- END$$
- DELIMITER ;
CALL sp_signal1(12);query result
result
Error Code : 22
Duplicated!用RESIGNAL/SIGNAL 重刷当前错误诊断区域。- DELIMITER $$
- USE `t_girl`$$
- DROP PROCEDURE IF EXISTS `sp_signal1`$$
- CREATE DEFINER=`root`@`localhost` PROCEDURE `sp_signal1`(
- IN f_id INT
- )
- BEGIN
- DECLARE con1 TINYINT DEFAULT 0;
- DECLARE con1 CONDITION FOR SQLSTATE '23000';
- DECLARE CONTINUE HANDLER FOR con1
- BEGIN
- resignal SET schema_name = 'action',
- table_name = 'action_tb',
- message_text = 'Duplicated!',
- mysql_errno = 22;
- /*
- signal con1 SET schema_name = 'action',
- table_name = 'action_tb',
- message_text = 'Duplicated!',
- mysql_errno = 22;
- */
- END;
- INSERT INTO user_info VALUES (f_id);
- END$$
- DELIMITER ;
CALL sp_signal1(12);Query : call sp_signal1(12)
Error Code : 22
Duplicated!
Execution Time : 00:00:00:000
Transfer Time : 00:00:00:000
Total Time : 00:00:00:000
阅读(3269) | 评论(0) | 转发(0) |