bindbox-game/.trae/documents/发货统计SQL设计与字段映射.md
邹方成 6ee627139c
Some checks failed
Build docker and publish / linux (1.24.5) (push) Failing after 40s
feat: 新增支付测试小程序与微信支付集成
feat(pay): 添加支付API基础结构
feat(miniapp): 创建支付测试小程序页面与配置
feat(wechatpay): 配置微信支付参数与证书
fix(guild): 修复成员列表查询条件
docs: 更新代码规范文档与需求文档
style: 统一前后端枚举显示与注释格式
refactor(admin): 重构用户奖励发放接口参数处理
test(title): 添加称号效果参数验证测试
2025-11-17 00:42:08 +08:00

109 lines
5.0 KiB
Markdown
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

## 模型目标
- 为运营提供“发货统计”独立表,脱离业务在线查询复杂度,支持导出与审计。
- 字段覆盖:产品、价格、发货数量、用户收件信息、物流、订单聚合、盈亏、来源、垫付人、时间。
## 表结构DDL
```sql
CREATE TABLE IF NOT EXISTS ops_shipping_stats (
id BIGINT PRIMARY KEY AUTO_INCREMENT,
shipped_at DATETIME NOT NULL COMMENT '发货时间',
product_id BIGINT NULL,
product_name VARCHAR(255) NOT NULL,
product_price_cents BIGINT NOT NULL COMMENT '单位:分',
shipped_qty BIGINT NOT NULL,
user_id BIGINT NOT NULL,
user_name VARCHAR(100) NOT NULL,
user_address_text VARCHAR(512) NOT NULL,
express_code VARCHAR(64) NULL,
express_no VARCHAR(128) NULL,
order_id BIGINT NULL,
order_no VARCHAR(64) NULL,
order_qty BIGINT NULL,
order_amount_cents BIGINT NULL COMMENT '单位:分',
profit_loss_cents BIGINT NULL COMMENT '单位:分',
order_source_type INT NULL,
order_source_text VARCHAR(32) NULL,
payer VARCHAR(128) NULL COMMENT '垫付人后续录入或从remark规范解析',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
KEY idx_shipped_at(shipped_at),
KEY idx_product(product_id),
KEY idx_order(order_id),
KEY idx_express(express_no)
) COMMENT='运营发货统计';
```
## 明细数据入库INSERT…SELECT
```sql
/* 参数:@start_date, @end_date */
INSERT INTO ops_shipping_stats (
shipped_at, product_id, product_name, product_price_cents, shipped_qty,
user_id, user_name, user_address_text, express_code, express_no,
order_id, order_no, order_qty, order_amount_cents, profit_loss_cents,
order_source_type, order_source_text, payer
)
SELECT
sr.shipped_at,
COALESCE(sr.product_id, oi.product_id) AS product_id,
COALESCE(oi.title, p.name) AS product_name,
COALESCE(sr.price, oi.price, p.price) AS product_price_cents,
sr.quantity AS shipped_qty,
ua.user_id AS user_id,
ua.name AS user_name,
CONCAT(ua.province, ua.city, ua.district, ua.address) AS user_address_text,
sr.express_code,
sr.express_no,
o.id AS order_id,
o.order_no AS order_no,
os.total_qty AS order_qty,
o.actual_amount AS order_amount_cents,
/* 盈亏:行价格×发货数量 订单实付金额(可根据口径调整) */
COALESCE(sr.price, oi.price, p.price) * sr.quantity - o.actual_amount AS profit_loss_cents,
o.source_type AS order_source_type,
CASE o.source_type WHEN 1 THEN '商城直购' WHEN 2 THEN '抽奖票据' WHEN 3 THEN '其他' ELSE CONCAT('未知-', o.source_type) END AS order_source_text,
/* 垫付人:暂为空,后续从 remark 或新增字段填充 */
NULL AS payer
FROM shipping_records sr
LEFT JOIN order_items oi ON oi.id = sr.order_item_id
LEFT JOIN products p ON p.id = COALESCE(sr.product_id, oi.product_id)
LEFT JOIN orders o ON o.id = sr.order_id
LEFT JOIN (
SELECT order_id, SUM(quantity) AS total_qty
FROM order_items
GROUP BY order_id
) os ON os.order_id = o.id
LEFT JOIN user_addresses ua ON ua.id = COALESCE(sr.address_id, o.user_address_id)
WHERE sr.status IN (2,3) /* 已发货/已签收 */
AND sr.shipped_at BETWEEN @start_date AND @end_date;
```
## 查询(导出)
```sql
/* 查询明细(元) */
SELECT
product_name,
ROUND(product_price_cents/100, 2) AS product_price_yuan,
shipped_qty,
user_name,
user_address_text,
express_code,
express_no,
order_no,
order_qty,
ROUND(order_amount_cents/100, 2) AS order_amount_yuan,
ROUND(profit_loss_cents/100, 2) AS profit_loss_yuan,
order_source_text,
payer,
shipped_at
FROM ops_shipping_stats
WHERE shipped_at BETWEEN @start_date AND @end_date
ORDER BY shipped_at DESC;
```
## 口径与可调整项
- 盈亏口径:当前为“行价格×发货数量 订单实付金额”;如需改为“订单行应付总额(`oi.total_amount` 订单实付金额”,可替换。
- 下单数量:当前为订单维度总件数(聚合);如需改为行数量,改用 `oi.quantity`
- 垫付人:建议在 `shipping_records` 增加 `payer` 字段或在 `remark` 规范写入 `payer:xxx`,入库时解析填充。
## 后续实现建议
- 管理后台增加导出按钮,直接查询 `ops_shipping_stats` 并输出 CSV/Excel。
- 每日定时任务或发货事件触发增量写入,保证统计表实时/准实时更新。