第十五章、存储过程与函数.sql 5.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273
  1. #第十五章、存储过程与函数
  2. #0、准备工作
  3. CREATE DATABASE DBTEST15;
  4. USE dbtest15;
  5. #复制员工表
  6. CREATE TABLE employees
  7. AS
  8. SELECT *
  9. FROM atguigudb.employees;
  10. #复制部门表
  11. CREATE TABLE departments
  12. AS
  13. SELECT *
  14. FROM atguigudb.departments;
  15. SELECT * FROM employees;
  16. SELECT * FROM departments;
  17. #1、创建存储过程
  18. #类型1:无参数无返回值
  19. #举例1:创建存储过程select_all_data(),查看employees表的所有数据
  20. DELIMITER $
  21. CREATE PROCEDURE select_all_data()
  22. BEGIN
  23. SELECT * FROM employees;
  24. END $
  25. DELIMITER ;
  26. #2、存储过程的调用
  27. CALL select_all_data();
  28. #例2:创建存储过程avg_employee_salary(),返回所有员工的平均工资
  29. DELIMITER //
  30. CREATE PROCEDURE avg_employee_salary()
  31. BEGIN
  32. SELECT AVG(salary)
  33. FROM employees;
  34. END //
  35. DELIMITER ;
  36. #调用
  37. CALL avg_employee_salary();
  38. #举例3:创建存储过程show_max_salary(),用来查看“employees”表的最高薪资值。
  39. DELIMITER $
  40. CREATE PROCEDURE show_max_salary()
  41. BEGIN
  42. SELECT MAX(salary)
  43. FROM employees;
  44. END $
  45. DELIMITER ;
  46. #调用
  47. CALL show_max_salary();
  48. #类型2:带OUT
  49. #举例4:创建存储过程show_min_salary(),查看“employees”表的最低薪资值。并将最低薪资通过OUT参数“ms”输出
  50. DESC employees;
  51. DELIMITER //
  52. CREATE PROCEDURE show_min_salary(OUT ms DOUBLE)
  53. BEGIN
  54. SELECT MIN(salary) INTO ms
  55. FROM employees;
  56. END //
  57. DELIMITER ;
  58. #调用
  59. CALL show_min_salary(@ms);
  60. #查看变量值
  61. SELECT @ms;
  62. #类型3:带IN
  63. #举例5:创建存储过程show_someone_salary(),查看“employees”表的某个员工的薪资,并用IN参数empname输入员工姓名。
  64. DELIMITER //
  65. CREATE PROCEDURE show_someone_salary(IN empname VARCHAR(25))
  66. BEGIN
  67. SELECT salary FROM employees
  68. WHERE last_name = empname;
  69. END //
  70. DELIMITER ;
  71. #调用方式1
  72. CALL show_someone_salary('Abel');
  73. #调用方式2
  74. SET @empname := 'Abel'; #写成SET @empname = 'Abel';也可以
  75. CALL show_someone_salary(@empname);
  76. #类型4:带IN和OUT
  77. #举例6:创建存储过程show_someone_salary2(),查看“employees”表的某个员工的薪资,并用IN参数empname输入员工姓名,用OUT参数empsalary输出员工薪资。
  78. DELIMITER //
  79. CREATE PROCEDURE show_someone_salary2(IN empname VARCHAR(25),OUT empsalary DOUBLE)
  80. BEGIN
  81. SELECT salary INTO empsalary
  82. FROM employees
  83. WHERE last_name = empname;
  84. END //
  85. DELIMITER ;
  86. #调用
  87. SET @empname = 'Abel';
  88. CALL show_someone_salary2(@empname,@empsalary)
  89. SELECT @empsalary;
  90. #类型5:带INOUT
  91. #举例7:创建存储过程show_mgr_name(),查询某个员工领导的姓名,并用INOUT参数“empname”输入员工姓名,输出领导的姓名。
  92. DELIMITER $
  93. CREATE PROCEDURE show_mgr_name(INOUT empname VARCHAR(25))
  94. BEGIN
  95. SELECT last_name INTO empname
  96. FROM employees
  97. WHERE employee_id = (
  98. SELECT manager_id
  99. FROM employees
  100. WHERE last_name = empname
  101. );
  102. END $
  103. DELIMITER ;
  104. #调用
  105. SET @empname := 'Abel';
  106. CALL show_mgr_name(@empname);
  107. SELECT @empname;
  108. #2、存储函数
  109. #举例1:创建存储函数,名称为email_by_name(),参数定义为空,该函数查询Abel的email,并返回,数据类型为字符串型。
  110. DELIMITER //
  111. CREATE FUNCTION email_by_name()
  112. RETURNS VARCHAR(25)
  113. DETERMINISTIC
  114. CONTAINS SQL
  115. READS SQL DATA
  116. BEGIN
  117. RETURN (SELECT email FROM employees WHERE last_name = 'Abel');
  118. END //
  119. DELIMITER ;
  120. #调用
  121. SELECT email_by_name();
  122. #举例2:创建存储函数,名称为email_by_id(),参数传入emp_id,该函数查询emp_id的email,并返回,数据类型为字符串型。
  123. #创建函数前执行此语句,保证函数的创建会成功
  124. SET GLOBAL log_bin_trust_function_creators = 1;
  125. #声明函数
  126. DELIMITER //
  127. CREATE FUNCTION email_by_id(emp_id INT)
  128. RETURNS VARCHAR(25)
  129. BEGIN
  130. RETURN (SELECT email FROM employees WHERE employee_id = emp_id);
  131. END //
  132. DELIMITER ;
  133. #调用方式一
  134. SELECT email_by_id(101);
  135. #调用方式二
  136. SET @emp_id := 102;
  137. SELECT email_by_id(@emp_id);
  138. #举例3:创建存储函数count_by_id(),参数传入dept_id,该函数查询dept_id部门的员工人数,并返回,数据类型为整型。
  139. DELIMITER //
  140. CREATE FUNCTION count_by_id(dept_id INT)
  141. RETURNS INT
  142. BEGIN
  143. RETURN (SELECT COUNT(*) FROM employees WHERE department_id = dept_id);
  144. END //
  145. DELIMITER ;
  146. #调用
  147. SET @dept_id := 50;
  148. SELECT count_by_id(@dept_id);
  149. #3、存储过程、存储函数的查看
  150. #方式1、使用SHOW CREATE语句查看存储过程和函数的创建信息
  151. SHOW CREATE PROCEDURE show_mgr_name;
  152. SHOW CREATE FUNCTION count_by_id;
  153. #方式2、使用SHOW STATUS语句查看存储过程和函数的状态信息
  154. SHOW PROCEDURE STATUS;
  155. SHOW PROCEDURE STATUS LIKE 'show_max_salary';
  156. SHOW FUNCTION STATUS LIKE 'email_by_id';
  157. #方式3、从information_schema.Routines表中查看存储过程和函数的信息
  158. SELECT * FROM information_schema.ROUTINES
  159. WHERE ROUTINE_NAME = 'email_by_id';
  160. SELECT * FROM information_schema.ROUTINES
  161. WHERE ROUTINE_NAME = 'email_by_id' AND ROUTINE_TYPE = 'FUNCTION';
  162. SELECT * FROM information_schema.ROUTINES
  163. WHERE ROUTINE_NAME = 'show_min_salary' AND ROUTINE_TYPE = 'PROCEDURE';
  164. #4、存储过程、函数的修改
  165. ALTER PROCEDURE show_max_salary
  166. SQL SECURITY INVOKER
  167. COMMENT '查询最高工资';
  168. #5、存储过程、函数的删除
  169. DROP FUNCTION IF EXISTS count_by_id;
  170. DROP PROCEDURE IF EXISTS show_min_salary;