系统变量分为全局系统变量(需要添加 global 关键字)以及会话系统变量(需要添加 session 关键字),有时也把全局系统变量简称为全局变量,有时也把会话系统变量称为local变量。如果不写,默认会话级别。静态变量(在 MySQL 服务实例运行期间它们的值不能使用 set 动态修改)属于特殊的全局系统变量。
CREATE PROCEDURE set_value() BEGIN DECLARE emp_name VARCHAR(25); DECLARE sal DOUBLE(10,2); SELECT last_name, salary INTO emp_name,sal FROM employees WHERE employee_id = 102; SELECT emp_name, sal; END // DELIMITER ;
举例2:声明两个变量,求和并打印 (分别使用会话用户变量、局部变量的方式实现)
1 2 3 4 5
#方式1:使用用户变量 SET @m=1; SET @n=1; SET @sum=@m+@n; SELECT @sum;
1 2 3 4 5 6 7 8 9 10 11 12 13
#方式2:使用局部变量 DELIMITER //
CREATE PROCEDURE add_value() BEGIN #局部变量 DECLARE m INT DEFAULT 1; DECLARE n INT DEFAULT 3; DECLARE SUM INT; SET SUM = m+n; SELECT SUM; END // DELIMITER ;
DELIMITER // CREATE PROCEDURE UpdateDataNoCondition() BEGIN SET @x = 1; UPDATE employees SET email = NULL WHERE last_name = 'Abel'; SET @x = 2; UPDATE employees SET email = 'aabbel' WHERE last_name = 'Abel'; SET @x = 3; END // DELIMITER ;
调用存储过程:
1 2 3 4 5 6 7 8 9
mysql> CALL UpdateDataNoCondition(); ERROR 1048 (23000): Column 'email' cannot be null mysql> SELECT @x; +------+ | @x | +------+ | 1 | +------+ 1 row in set (0.00 sec)
DELIMITER // CREATE PROCEDURE UpdateDataNoCondition() BEGIN #定义处理程序 DECLARE CONTINUE HANDLER FOR 1048 SET @proc_value = -1; SET @x = 1; UPDATE employees SET email = NULL WHERE last_name = 'Abel'; SET @x = 2; UPDATE employees SET email = 'aabbel' WHERE last_name = 'Abel'; SET @x = 3; END // DELIMITER ;
#准备工作 CREATE TABLE departments AS SELECT * FROM atguigudb.`departments`; ALTER TABLE departments ADD CONSTRAINT uk_dept_name UNIQUE(department_id);
DELIMITER // CREATE PROCEDURE InsertDataWithCondition() BEGIN DECLARE duplicate_entry CONDITION FOR SQLSTATE '23000' ; # 定义条件 DECLARE EXIT HANDLER FOR duplicate_entry SET @proc_value = -1; # 定义处理流程
SET @x = 1; INSERT INTO departments(department_name) VALUES('测试'); SET @x = 2; INSERT INTO departments(department_name) VALUES('测试'); SET @x = 3; END // DELIMITER ;
SELECT salary INTO emp_salary FROM employees WHERE employee_id = emp_id; SELECT commission_pct INTO bonus FROM employees WHERE employee_id = emp_id;
IF emp_salary < 9000 THEN UPDATE employees SET salary = 9000 WHERE employee_id = emp_id;
ELSEIF emp_salary < 10000 AND bonus IS NULL THEN UPDATE employees SET commission_pct = 0.01 WHERE employee_id =emp_id;
ELSE UPDATE employees SET salary = salary + 100 WHERE employee_id = emp_id; END IF;
END // DELIMITER ;
2) 分支结构之 CASE
CASE 语句的语法结构1:
1 2 3 4 5 6 7
#情况一:类似于switch CASE 表达式 WHEN 值1 THEN 结果1或语句1(如果是语句,需要加分号) WHEN 值2 THEN 结果2或语句2(如果是语句,需要加分号) ... ELSE 结果n或语句n(如果是语句,需要加分号) END [case](如果是放在begin end中需要加上case,如果放在select后面不需要)
CASE 语句的语法结构2:
1 2 3 4 5 6 7
#情况二:类似于多重if CASE WHEN 条件1 THEN 结果1或语句1(如果是语句,需要加分号) WHEN 条件2 THEN 结果2或语句2(如果是语句,需要加分号) ... ELSE 结果n或语句n(如果是语句,需要加分号) END [case](如果是放在begin end中需要加上case,如果放在select后面不需要)
举例1:使用CASE流程控制语句的第1种格式,判断val值等于1、等于2,或者两者都不等。
1 2 3 4 5
CASE val WHEN 1 THEN SELECT 'val is 1'; WHEN 2 THEN SELECT 'val is 2'; ELSE SELECT 'val is not 1 or 2'; END CASE;
举例2: 使用CASE流程控制语句的第2种格式,判断val是否为空、小于0、大于0或者等于0。
1 2 3 4 5 6
CASE WHEN val IS NULL THEN SELECT 'val is null'; WHEN val < 0 THEN SELECT 'val is less than 0'; WHEN val > 0 THEN SELECT 'val is greater than 0'; ELSE SELECT 'val is 0'; END CASE;
SELECT salary INTO emp_sal FROM employees WHERE employee_id = emp_id; SELECT commission_pct INTO bonus FROM employees WHERE employee_id = emp_id;
CASE WHEN emp_sal<9000 THEN UPDATE employees SET salary=9000 WHERE employee_id = emp_id; WHEN emp_sal<10000 AND bonus IS NULL THEN UPDATE employees SET commission_pct=0.01 WHERE employee_id = emp_id; ELSE UPDATE employees SET salary=salary+100 WHERE employee_id = emp_id; END CASE; END // DELIMITER ;
SELECT salary INTO emp_sal FROM employees WHERE employee_id = emp_id; SELECT ROUND(DATEDIFF(CURDATE(),hire_date)/365) INTO hire_year FROM employees WHERE employee_id = emp_id;
CASE hire_year WHEN 0 THEN UPDATE employees SET salary=salary+50 WHERE employee_id = emp_id; WHEN 1 THEN UPDATE employees SET salary=salary+100 WHERE employee_id = emp_id; WHEN 2 THEN UPDATE employees SET salary=salary+200 WHERE employee_id = emp_id; WHEN 3 THEN UPDATE employees SET salary=salary+300 WHERE employee_id = emp_id; WHEN 4 THEN UPDATE employees SET salary=salary+400 WHERE employee_id = emp_id; ELSE UPDATE employees SET salary=salary+500 WHERE employee_id = emp_id; END CASE; END // DELIMITER ;
DELIMITER // CREATE PROCEDURE update_salary_loop(OUT num INT) BEGIN DECLARE avg_salary DOUBLE; DECLARE loop_count INT DEFAULT 0;
SELECT AVG(salary) INTO avg_salary FROM employees;
label_loop:LOOP IF avg_salary >= 12000 THEN LEAVE label_loop; END IF;
UPDATE employees SET salary = salary * 1.1; SET loop_count = loop_count + 1; SELECT AVG(salary) INTO avg_salary FROM employees; END LOOP label_loop; SET num = loop_count; END // DELIMITER ;
DELIMITER // CREATE PROCEDURE update_salary_repeat(OUT num INT) BEGIN DECLARE avg_sal DOUBLE ; DECLARE repeat_count INT DEFAULT 0;
SELECT AVG(salary) INTO avg_sal FROM employees;
REPEAT UPDATE employees SET salary = salary * 1.15; SET repeat_count = repeat_count + 1; SELECT AVG(salary) INTO avg_sal FROM employees; UNTIL avg_sal >= 13000 END REPEAT; SET num = repeat_count; END // DELIMITER ;
DELIMITER // CREATE PROCEDURE leave_begin(IN num INT) begin_label: BEGIN IF num<=0 THEN LEAVE begin_label; ELSEIF num=1 THEN SELECT AVG(salary) FROM employees; ELSEIF num=2 THEN SELECT MIN(salary) FROM employees; ELSE SELECT MAX(salary) FROM employees; END IF; SELECT COUNT(*) FROM employees; END // DELIMITER ;
DELIMITER // CREATE PROCEDURE test_iterate() BEGIN DECLARE num INT DEFAULT 0; my_loop:LOOP SET num = num + 1; IF num < 10 THEN ITERATE my_loop; ELSEIF num > 15 THEN LEAVE my_loop; END IF; SELECT 'MySQL'; END LOOP my_loop; END // DELIMITER ;
4. 游标
1) 什么是游标(或光标)
虽然我们也可以通过筛选条件 WHERE 和 HAVING,或者是限定返回记录的关键字 LIMIT 返回一条记录, 但是,却无法在结果集中像指针一样,向前定位一条记录、向后定位一条记录,或者是随意定位到某一条记录 ,并对记录的数据进行处理。
DELIMITER // CREATE PROCEDURE get_count_by_limit_total_salary(IN limit_total_salary DOUBLE, OUT total_count INT) BEGIN DECLARE sum_salary DOUBLE DEFAULT 0; # 记录累加的总工资 DECLARE cursor_salary DOUBLE DEFAULT 0; # 记录某一个工资值 DECLARE emp_count INT DEFAULT 0; # 记录循环个数 # 定义游标 DECLARE emp_cursor CURSOR FOR SELECT salary FROM employees ORDER BY salary DESC; # 打开游标 OPEN emp_cursor;
REPEAT # 使用游标(从游标中获取数据) FETCH emp_cursor INTO cursor_salary; SET sum_salary = sum_salary + cursor_salary; SET emp_count = emp_count + 1; UNTIL sum_salary >= limit_total_salary END REPEAT; set total_count = emp_count; # 关闭游标 CLOSE emp_cursor; END // DELIMITER;
4) 小结
游标是 MySQL 的一个重要的功能,为 逐条读取 结果集中的数据,提供了完美的解决方案。跟在应用层面实现相同的功能相比,游标可以在存储程序中使用,效率高,程序也更加简洁。