From 443824093f87dcb27531d0b7b03fd8d8e1381931 Mon Sep 17 00:00:00 2001 From: dzq Date: Mon, 8 Dec 2025 09:32:36 +0800 Subject: [PATCH] =?UTF-8?q?docs:=20=E6=B7=BB=E5=8A=A0=E7=94=A8=E6=88=B7?= =?UTF-8?q?=E4=BD=99=E9=A2=9D=E8=AE=A1=E7=AE=97SQL=E8=84=9A=E6=9C=AC?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit 添加用于计算用户余额使用情况的SQL脚本,包含临时表创建、数据计算和更新逻辑 --- doc/sql/user_balance_action.sql | 95 +++++++++++++++++++++++++++++++++ 1 file changed, 95 insertions(+) create mode 100644 doc/sql/user_balance_action.sql diff --git a/doc/sql/user_balance_action.sql b/doc/sql/user_balance_action.sql new file mode 100644 index 0000000..40fa595 --- /dev/null +++ b/doc/sql/user_balance_action.sql @@ -0,0 +1,95 @@ +-- 首先,我们需要找到所有符合条件的订单(已支付且使用余额支付) +-- 然后关联到shop_order_goods,计算每个用户的总余额使用情况 +-- 最后更新user_balance表的use_balance字段 + +-- 先创建一个临时表来存储每个用户的use_balance计算结果 +CREATE TEMPORARY TABLE IF NOT EXISTS temp_user_balance_calc ( + ab98_user_id BIGINT NOT NULL, + total_use_balance BIGINT NOT NULL DEFAULT 0, + PRIMARY KEY (ab98_user_id) +); + +-- 清空临时表 +TRUNCATE TABLE temp_user_balance_calc; + +-- 计算每个用户的use_balance +-- 规则:status为1的total_amount总和 - status为2的total_amount总和 +-- 注意:total_amount是元,需要转换为分(乘以100) +INSERT INTO temp_user_balance_calc (ab98_user_id, total_use_balance) +SELECT + COALESCE( + -- 优先使用ab98_user_id直接关联 + so.ab98_user_id, + -- 通过openid关联ab98_user表 + au.ab98_user_id, + -- 通过openid关联wx_user表,再关联ab98_user表 + wu.ab98_user_id, + -- 通过userid关联ab98_user表 + au_by_userid.ab98_user_id, + -- 通过userid关联qy_user表,再关联ab98_user表 + qu.ab98_user_id + ) AS final_ab98_user_id, + -- 计算总使用余额(单位:分) + SUM( + CASE sog.status + WHEN 1 THEN CAST(sog.total_amount * 100 AS UNSIGNED) -- 正常购买,增加使用余额 + -- WHEN 2 THEN -CAST(sog.total_amount * 100 AS UNSIGNED) -- 退货,减少使用余额 + ELSE 0 + END + ) AS total_use_balance +FROM shop_order so +-- 关联订单商品 +INNER JOIN shop_order_goods sog ON so.order_id = sog.order_id +-- 通过openid关联ab98_user表 +LEFT JOIN ab98_user au ON so.openid = au.openid COLLATE utf8mb4_unicode_ci +-- 通过openid关联wx_user表,再获取ab98_user_id +LEFT JOIN wx_user wu ON so.openid = wu.openid COLLATE utf8mb4_unicode_ci +-- 通过userid关联ab98_user表(使用userid字段) +LEFT JOIN ab98_user au_by_userid ON so.userid = au_by_userid.userid COLLATE utf8mb4_unicode_ci +-- 通过userid关联qy_user表 +LEFT JOIN qy_user qu ON so.userid = qu.userid COLLATE utf8mb4_unicode_ci +WHERE so.pay_status = 2 -- 已支付 + AND so.payment_method = 'balance' -- 余额支付方式 + -- 限定特定的corpid,请将'wpZ1ZrEgAA2QTxIRcB4cMtY7hQbTcPAw'替换为实际的corpid + AND so.corpid = 'wpZ1ZrEgAA2QTxIRcB4cMtY7hQbTcPAw' COLLATE utf8mb4_unicode_ci + -- 确保商品状态是1或2 + AND sog.status IN (1, 2) + -- 确保能关联到ab98_user + AND ( + so.ab98_user_id IS NOT NULL + OR au.ab98_user_id IS NOT NULL + OR wu.ab98_user_id IS NOT NULL + OR au_by_userid.ab98_user_id IS NOT NULL + OR qu.ab98_user_id IS NOT NULL + ) +GROUP BY final_ab98_user_id +HAVING final_ab98_user_id IS NOT NULL; + +-- 更新user_balance表的use_balance字段 +UPDATE user_balance ub +INNER JOIN temp_user_balance_calc calc ON ub.ab98_user_id = calc.ab98_user_id +SET ub.use_balance = calc.total_use_balance +-- 限定特定的corpid,请将'wpZ1ZrEgAA2QTxIRcB4cMtY7hQbTcPAw'替换为实际的corpid +WHERE ub.corpid = 'wpZ1ZrEgAA2QTxIRcB4cMtY7hQbTcPAw' COLLATE utf8mb4_unicode_ci; + +-- 修改user_balance的balance值为balance_limit - use_balance +UPDATE user_balance ub +SET ub.balance = ub.balance_limit - ub.use_balance +WHERE ub.corpid = 'wpZ1ZrEgAA2QTxIRcB4cMtY7hQbTcPAw' COLLATE utf8mb4_unicode_ci; + +-- 删除临时表 +DROP TEMPORARY TABLE IF EXISTS temp_user_balance_calc; + +-- 显示更新结果 +SELECT + ub.user_balance_id, + ub.ab98_user_id, + ub.balance, + ub.use_balance, + ub.balance_limit, + CONCAT(FORMAT(ub.use_balance / 100, 2), '元') AS use_balance_yuan, + CONCAT(FORMAT(ub.balance / 100, 2), '元') AS balance_yuan, + CONCAT(FORMAT(ub.balance_limit / 100, 2), '元') AS balance_limit_yuan +FROM user_balance ub +WHERE ub.corpid = 'wpZ1ZrEgAA2QTxIRcB4cMtY7hQbTcPAw' COLLATE utf8mb4_unicode_ci +ORDER BY ub.ab98_user_id; \ No newline at end of file