暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

MySQL流程控制语句简介

原创 只是甲 2020-06-05
1939

备注:测试数据库版本为MySQL 8.0

这个blog我们来聊聊MySQL流程控制语句,流程控制语句在存储过程、函数、触发器和事件里面可以被使用到。

Table of Contents

一.CASE语句

CASE语句用于条件判断
CASE语句与CASE函数使用上有差异:
1.CASE函数是在SQL里使用,而CASE语句在存储过程及函数里使用
2.CASE语句不能用esle null子句,用else begin end; 空的程序块代替
3.CASE函数的结尾是END,而CASE语句结尾是END CASE

语法:

-- 语法1: CASE case_value WHEN when_value THEN statement_list [WHEN when_value THEN statement_list] ... [ELSE statement_list] END CASE -- 语法2: CASE WHEN search_condition THEN statement_list [WHEN search_condition THEN statement_list] ... [ELSE statement_list] END CASE
复制

案例:

DELIMITER | CREATE PROCEDURE p(in pi_num int) BEGIN CASE pi_num WHEN 2 THEN SELECT 'TWO'; WHEN 3 THEN SELECT 'THREE'; ELSE BEGIN END; END CASE; END; | DELIMITER ;
复制
mysql> DELIMITER | mysql> mysql> CREATE PROCEDURE p(in pi_num int) -> BEGIN -> -> CASE pi_num -> WHEN 2 THEN SELECT 'TWO'; -> WHEN 3 THEN SELECT 'THREE'; -> ELSE -> BEGIN -> END; -> END CASE; -> END; -> | Query OK, 0 rows affected (0.04 sec) mysql> mysql> DELIMITER ; mysql> mysql> CALL P(2); +-----+ | TWO | +-----+ | TWO | +-----+ 1 row in set (0.03 sec) Query OK, 0 rows affected (0.04 sec) mysql> CALL P(3); +-------+ | THREE | +-------+ | THREE | +-------+ 1 row in set (0.00 sec) Query OK, 0 rows affected (0.01 sec) mysql> CALL P(4); Query OK, 0 rows affected (0.00 sec)
复制

二.IF语句

IF语句用于条件判断
IF语句和IF函数差别比较大,可以参考我之前的blog

语法:

IF search_condition THEN statement_list [ELSEIF search_condition THEN statement_list] ... [ELSE statement_list] END IF
复制

案例:

DELIMITER // CREATE PROCEDURE P2(in pi_a INT,in pi_b INT) BEGIN DECLARE l_result VARCHAR(20); IF pi_a > pi_b THEN SET l_result = '>'; ELSEIF pi_a = pi_b THEN SET l_result = '='; ELSE SET l_result = '<'; END IF; SET l_result = CONCAT(pi_a, ' ', l_result, ' ', pi_b); select l_result as result; END // DELIMITER ;
复制
mysql> DELIMITER // mysql> mysql> CREATE PROCEDURE P2(in pi_a INT,in pi_b INT) -> -> BEGIN -> DECLARE l_result VARCHAR(20); -> -> IF pi_a > pi_b THEN SET l_result = '>'; -> ELSEIF pi_a = pi_b THEN SET l_result = '='; -> ELSE SET l_result = '<'; -> END IF; -> -> SET l_result = CONCAT(pi_a, ' ', l_result, ' ', pi_b); -> -> select l_result as result; -> END // Query OK, 0 rows affected (0.01 sec) mysql> mysql> DELIMITER ; mysql> mysql> call p2(1,2); +--------+ | result | +--------+ | 1 < 2 | +--------+ 1 row in set (0.00 sec) Query OK, 0 rows affected (0.01 sec) mysql> call p2(2,2); +--------+ | result | +--------+ | 2 = 2 | +--------+ 1 row in set (0.00 sec) Query OK, 0 rows affected (0.01 sec) mysql> call p2(3,2); +--------+ | result | +--------+ | 3 > 2 | +--------+ 1 row in set (0.00 sec) Query OK, 0 rows affected (0.01 sec)
复制

三.ITERATE语句

ITERATE迭代语句
语法:

ITERATE label
复制

ITERATE只能和LOOP,REPEAT,WHILE语句配合使用,作用是再次启动循环。

四.LEAVE语句

LEAVE退出语句
语法:

LEAVE label
复制

LEAVE语句退出循环或程序块,只能和begin … end,LOOP,REPEAT,WHILE语句配合使用

五.LOOP语句

LOOP循环语句
语法:

[begin_label:] LOOP statement_list END LOOP [end_label]
复制

案例:用LOOP循环求1到10之和

DELIMITER // CREATE PROCEDURE p3() BEGIN declare sum int default 0; declare l_num int default 1; -- loop_1为接下来loop循环的标签 loop_1: LOOP SET sum = sum + l_num; SET l_num = l_num + 1; IF l_num <= 10 THEN -- 条件成立,继续循环 ITERATE loop_1; END IF; -- 退出循环 LEAVE loop_1; END LOOP loop_1; select sum; END; // DELIMITER ;
复制
mysql> DELIMITER // mysql> mysql> CREATE PROCEDURE p3() -> BEGIN -> -> declare sum int default 0; -> declare l_num int default 1; -> -> -- loop_1为接下来loop循环的标签 -> loop_1: LOOP -> SET sum = sum + l_num; -> SET l_num = l_num + 1; -> IF l_num <= 10 THEN -> -- 条件成立,继续循环 -> ITERATE loop_1; -> END IF; -> -- 退出循环 -> LEAVE loop_1; -> END LOOP loop_1; -> -> select sum; -> -> END; -> // Query OK, 0 rows affected (0.01 sec) mysql> mysql> DELIMITER ; mysql> mysql> call p3; +------+ | sum | +------+ | 55 | +------+ 1 row in set (0.00 sec) Query OK, 0 rows affected (0.01 sec)
复制

六.REPEAT语句

REPEAT语句一直重复,直到条件不满足
语法:

[begin_label:] REPEAT statement_list UNTIL search_condition END REPEAT [end_label]
复制

案例:

DELIMITER // CREATE PROCEDURE p4() BEGIN declare l_n1 int default 10; declare l_n2 int default 1; -- 重复给l_n2加1,直到l_n2大于l_n1 repeat set l_n2 = l_n2 + 1; until l_n2 > l_n1 end repeat; select l_n2; END; // DELIMITER ;
复制
mysql> DELIMITER // mysql> mysql> CREATE PROCEDURE p4() -> BEGIN -> -> declare l_n1 int default 10; -> declare l_n2 int default 1; -> -> -- 重复给l_n2加1,直到l_n2大于l_n1 -> repeat -> set l_n2 = l_n2 + 1; -> until l_n2 > l_n1 end repeat; -> -> select l_n2; -> -> END; -> // Query OK, 0 rows affected (0.01 sec) mysql> mysql> DELIMITER ; mysql> mysql> mysql> call p4; +------+ | l_n2 | +------+ | 11 | +------+ 1 row in set (0.00 sec) Query OK, 0 rows affected (0.01 sec)
复制

七.WHILE语句

语法:

[begin_label:] WHILE search_condition DO statement_list END WHILE [end_label]
复制

案例:

DELIMITER // CREATE PROCEDURE p5() BEGIN declare l_n1 int default 10; while l_n1 > 0 DO set l_n1 = l_n1 - 1; end while; select l_n1; END; // DELIMITER ;
复制
mysql> DELIMITER // mysql> mysql> CREATE PROCEDURE p5() -> BEGIN -> -> declare l_n1 int default 10; -> -> -> while l_n1 > 0 DO -> set l_n1 = l_n1 - 1; -> end while; -> -> select l_n1; -> -> END; -> // Query OK, 0 rows affected (0.04 sec) mysql> mysql> DELIMITER ; mysql> mysql> call p5; +------+ | l_n1 | +------+ | 0 | +------+ 1 row in set (0.00 sec) Query OK, 0 rows affected (0.01 sec)
复制
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

文章被以下合辑收录

评论