分类: Mysql/postgreSQL
2008-05-05 11:07:51
CREATE TABLE t (s1 int,primary key (s1));
mysql> use t_girl
Database changed
mysql> CREATE TABLE t (s1 int,primary key (s1));
Query OK, 0 rows affected (0.00 sec)
mysql>
mysql>
mysql> DELIMITER ||
mysql> CREATE PROCEDURE handlerdemo ()
-> BEGIN
-> DECLARE EXIT HANDLER FOR SQLSTATE '23000' BEGIN END; -- 遇到重复键值就退出
-> SET @x = 1;
-> INSERT INTO t VALUES (1);
-> SET @x = 2;
-> INSERT INTO t VALUES (1);
-> SET @x = 3;
-> END||
Query OK, 0 rows affected (0.00 sec)
mysql> DELIMITER ;
mysql> call handlerdemo();
Query OK, 0 rows affected (0.00 sec)
mysql> select @x;
+------+
| @x |
+------+
| 2 |
+------+
1 row in set (0.00 sec)
mysql> call handlerdemo();
Query OK, 0 rows affected (0.00 sec)
mysql> select @x;
+------+
| @x |
+------+
| 1 |
+------+
1 row in set (0.00 sec)
mysql>
现在来看一下遇到错误继续的情况
mysql> truncate table t;
Query OK, 0 rows affected (0.01 sec)
mysql> DELIMITER $$
mysql> DROP PROCEDURE IF EXISTS `t_girl`.`handlerdemo`$$
Query OK, 0 rows affected (0.00 sec)
mysql> CREATE DEFINER=`root`@`localhost` PROCEDURE `handlerdemo`()
-> BEGIN
-> DECLARE CONTINUE HANDLER FOR SQLSTATE '23000' BEGIN END;
-> SET @x = 1;
-> INSERT INTO t VALUES (1);
-> SET @x = 2;
-> INSERT INTO t VALUES (1);
-> SET @x = 3;
-> END$$
Query OK, 0 rows affected (0.01 sec)
mysql> DELIMITER ;
mysql> call handlerdemo();
Query OK, 0 rows affected (0.00 sec)
mysql> select @x;
+------+
| @x |
+------+
| 3 |
+------+
1 row in set (0.00 sec)
mysql> call handlerdemo();
Query OK, 0 rows affected (0.00 sec)
mysql> select @x;
+------+
| @x |
+------+
| 3 |
+------+
1 row in set (0.00 sec)
mysql>
可以看到,始终执行到最后。
当然,上面的SQLSTATE '23000'可以替换为1062
我们来看一下警告。
mysql> alter table t add s2 int not null;
Query OK, 0 rows affected (0.01 sec)
Records: 0 Duplicates: 0 Warnings: 0
此列没有默认值,插入的时候会出现警告或者1364错误提示。
mysql> DELIMITER $$
mysql> DROP PROCEDURE IF EXISTS `t_girl`.`handlerdemo`$$
Query OK, 0 rows affected, 1 warning (0.00 sec)
mysql> CREATE DEFINER=`root`@`localhost` PROCEDURE `handlerdemo`()
-> BEGIN
-> DECLARE CONTINUE HANDLER FOR 1062 BEGIN END;
-> DECLARE CONTINUE HANDLER FOR SQLWARNING
-> BEGIN
-> update t set s2 = 2;
-> END;
-> DECLARE CONTINUE HANDLER FOR 1364
-> BEGIN
-> INSERT INTO t(s1,s2) VALUES (1,3);
-> END;
-> SET @x = 1;
-> INSERT INTO t(s1) VALUES (1);
-> SET @x = 2;
-> INSERT INTO t(s1) VALUES (1);
-> SET @x = 3;
-> END$$
Query OK, 0 rows affected (0.00 sec)
mysql> DELIMITER ;
mysql> call handlerdemo();
Query OK, 0 rows affected (0.00 sec)
mysql> select * from t;
+----+----+
| s1 | s2 |
+----+----+
| 1 | 3 |
+----+----+
1 row in set (0.00 sec)
遇到错误的时候插入的新记录。
mysql> select @x;
+------+
| @x |
+------+
| 3 |
+------+
1 row in set (0.00 sec)
4、如果有新的体会,我会再发出来共享。