编写MySQL关于总积分、总金额的触发器
需求:我有一张心愿表,还有一张捐款表,捐款表每次支付或修改,相应的心愿表总金额也会随之修改。
心愿表:
CREATE TABLE `qs_wish` ( `id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT, `title` varchar(255) CHARACTER '心愿标题', `total_amount` decimal(10, 2) DEFAULT 0.00 COMMENT '捐赠总金额', PRIMARY KEY (`id`) USING BTREE ) ENGINE = InnoDB AUTO_INCREMENT = 5 CHARACTER SET = utf8mb4 COLLATE = utf8mb4_general_ci ROW_FORMAT = Dynamic;
捐款表:
CREATE TABLE `qs_wish_donate` ( `id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT, `wish_id` bigint(20) NOT NULL DEFAULT 0 COMMENT '心愿id', `amount` decimal(10, 2) NOT NULL DEFAULT 0.00 COMMENT '捐款', `status` tinyint(4) NOT NULL DEFAULT 0 COMMENT '支付状态', PRIMARY KEY (`id`) USING BTREE ) ENGINE = InnoDB AUTO_INCREMENT = 2 CHARACTER SET = utf8mb4 COLLATE = utf8mb4_general_ci ROW_FORMAT = Dynamic;
触发器代码
新增:新增时只要状态(status)为1,心愿表总金额也随之增加。
CREATE TRIGGER `tri_wish_donate_insert_after` AFTER INSERT ON `qs_wish_donate` FOR EACH ROW begin if new.status = 1 then UPDATE qs_wish SET total_amount=total_amount+new.amount WHERE id=new.wish_id; END if; end
修改:修改可大致分为三种情况
1、将状态由0改成1,即由待支付状态改成支付状态。
2、将状态由1改成0或其他值,即由支付状态改成待支付或退回状态。
3、状态未修改,且状态为1,但是修改了心愿id或者金额,异或两者都被修改。
三种情况代码如下:
CREATE TRIGGER `tri_wish_donate_update_after` AFTER UPDATE ON `qs_wish_donate` FOR EACH ROW begin if new.status =1 and old.status != 1 then UPDATE qs_wish SET total_amount=total_amount+new.amount WHERE id=new.wish_id; elseif old.status = 1 and new.status != 1 then UPDATE qs_wish SET total_amount=total_amount-old.amount WHERE id=old.wish_id; elseif old.status=1 and new.status=1 and (old.wish_id != new.wish_id or old.amount != new.amount) then UPDATE qs_wish SET total_amount=total_amount-old.amount WHERE id=old.wish_id; UPDATE qs_wish SET total_amount=total_amount+new.amount WHERE id=new.wish_id; END if; end
删除:删除只关注已支付的捐款,即status=1的情况
CREATE TRIGGER `tri_wish_donate_delete_after` AFTER DELETE ON `qs_wish_donate` FOR EACH ROW begin if old.status = 1 then UPDATE qs_wish SET total_amount=total_amount-old.amount WHERE id=old.wish_id; END if; end