|
| 1 | +# 第一个存储过程 |
| 2 | +# 根据用户 id 查询用户其他信息 |
| 3 | +# 方法看着很奇葩,但是展示了多个输出参数 |
| 4 | +DROP PROCEDURE IF EXISTS `select_user_by_id`; |
| 5 | +DELIMITER ;; |
| 6 | +CREATE PROCEDURE `select_user_by_id`( |
| 7 | +IN userId BIGINT, |
| 8 | +OUT userName VARCHAR(50), |
| 9 | +OUT userPassword VARCHAR(50), |
| 10 | +OUT userEmail VARCHAR(50), |
| 11 | +OUT userInfo TEXT, |
| 12 | +OUT headImg BLOB, |
| 13 | +OUT createTime DATETIME) |
| 14 | +BEGIN |
| 15 | +# 根据用户 id 查询其他数据 |
| 16 | +select user_name,user_password,user_email,user_info,head_img,create_time |
| 17 | +INTO userName,userPassword,userEmail,userInfo,headImg,createTime |
| 18 | +from sys_user |
| 19 | +WHERE id = userId; |
| 20 | +END |
| 21 | +;; |
| 22 | +DELIMITER ; |
| 23 | + |
| 24 | +# 第二个存储过程 |
| 25 | +# 简单的根据用户名和分页参数进行查询,返回总数和分页数据 |
| 26 | +DROP PROCEDURE IF EXISTS `select_user_page`; |
| 27 | +DELIMITER ;; |
| 28 | +CREATE PROCEDURE `select_user_page`( |
| 29 | +IN userName VARCHAR(50), |
| 30 | +IN _offset BIGINT, |
| 31 | +IN _limit BIGINT, |
| 32 | +OUT total BIGINT) |
| 33 | +BEGIN |
| 34 | +# 查询数据总数 |
| 35 | +select count(*) INTO total |
| 36 | +from sys_user |
| 37 | +where user_name like concat('%', userName, '%'); |
| 38 | +# 分页查询数据 |
| 39 | +select * |
| 40 | +from sys_user |
| 41 | +where user_name like concat('%', userName, '%') |
| 42 | +limit _offset, _limit; |
| 43 | +END |
| 44 | +;; |
| 45 | +DELIMITER ; |
| 46 | + |
| 47 | +# 第三个存储过程 |
| 48 | +# 保存用户信息和角色关联信息 |
| 49 | +DROP PROCEDURE IF EXISTS `insert_user_and_roles`; |
| 50 | +DELIMITER ;; |
| 51 | +CREATE PROCEDURE `insert_user_and_roles`( |
| 52 | +OUT userId BIGINT, |
| 53 | +IN userName VARCHAR(50), |
| 54 | +IN userPassword VARCHAR(50), |
| 55 | +IN userEmail VARCHAR(50), |
| 56 | +IN userInfo TEXT, |
| 57 | +IN headImg BLOB, |
| 58 | +OUT createTime DATETIME, |
| 59 | +IN roleIds VARCHAR(200) |
| 60 | +) |
| 61 | + |
| 62 | +BEGIN |
| 63 | +# 设置当前时间 |
| 64 | +SET createTime = NOW(); |
| 65 | +# 插入数据 |
| 66 | +INSERT INTO sys_user(user_name, user_password, user_email, user_info, head_img, create_time) |
| 67 | +VALUES (userName, userPassword, userEmail, userInfo, headImg, createTime); |
| 68 | +# 获取自增主键 |
| 69 | +SELECT LAST_INSERT_ID() INTO userId; |
| 70 | +# 保存用户和角色关系数据 |
| 71 | +SET roleIds = CONCAT(',',roleIds,','); |
| 72 | +INSERT INTO sys_user_role(user_id, role_id) |
| 73 | +select userId, id from sys_role |
| 74 | +where INSTR(roleIds, CONCAT(',',id,',')) > 0; |
| 75 | +END |
| 76 | +;; |
| 77 | +DELIMITER ; |
| 78 | + |
| 79 | +# 第四个存储过程 |
| 80 | +# 删除用户信息和角色关联信息 |
| 81 | +DROP PROCEDURE IF EXISTS `delete_user_by_id`; |
| 82 | +DELIMITER ;; |
| 83 | +CREATE PROCEDURE `delete_user_by_id`(IN userId BIGINT) |
| 84 | +BEGIN |
| 85 | +DELETE FROM sys_user_role where user_id = userId; |
| 86 | +DELETE FROM sys_user where id = userId; |
| 87 | +END |
| 88 | +;; |
| 89 | +DELIMITER ; |
0 commit comments