diff --git a/SQL.sql b/SQL.sql index a303508..b1f369e 100644 --- a/SQL.sql +++ b/SQL.sql @@ -15,6 +15,7 @@ FROM( -- 针对并单号情况,统计总行数加逗号个数得到总订单数量 COUNT(platform_order_no) + SUM(LENGTH(platform_order_no) - LENGTH(REPLACE(platform_order_no, ',', ''))) AS '订单数量' + FROM dwd_trade_hkaudit_ecommerce_sale_mt WHERE order_date >= '2022-01-01 00:00:00' @@ -31,7 +32,7 @@ LEFT JOIN( FROM( SELECT -- 将拆分后的单个订单号作为分组和查询的键 - single_order_id AS platform_order_no, + single_order_id AS single_order_no, MIN(store_code) AS store_code, MIN(order_date) AS order_date FROM( @@ -85,14 +86,14 @@ SELECT count(CASE WHEN pay_amt > 0 THEN receipt_no ELSE NULL END) as '订单数量', round(abs(sum(CASE WHEN pay_amt < 0 THEN pay_amt ELSE 0 END)), 2) as '退款金额', count(CASE WHEN pay_amt < 0 THEN receipt_no ELSE NULL END) as '退款订单数' -FROM +FROM dwd_trade_hkaudit_shop_receipt_pay_mt -WHERE +WHERE pay_date >= '2022-01-01 00:00:00' AND pay_date < '2025-07-01 00:00:00' -GROUP BY +GROUP BY store_code, YEAR(pay_date) -ORDER BY +ORDER BY store_code ASC, 年份 ASC; -- 线上店铺月度销售金额 @@ -131,7 +132,7 @@ order BY SELECT goods_barcode, year(order_date) as '年份', - sum(good_qty) as '产品数量', + sum(goods_qty) as '产品数量', order_settle_amt as '销售金额' FROM dwd_trade_hkaudit_ecommerce_sale_mt @@ -145,33 +146,41 @@ order BY -- 线下每年各产品数量、产品销售金额 -- (订单号重复,根据订单号groupby后失去产品信息,小票支付表仅有订单号可关联,如何计算?) -SELECT - YEAR(b.pay_time) as '年份', - a.goods_name as '商品名称', - a.goods_barcode as '商品条码', - SUM(a.good_qty) as '产品数量', - ROUND(SUM(b.pay_amt), 2) as '销售金额' +-- 根据商品标价比例计算实际金额 +SELECT + YEAR(b.pay_time) AS '年份', + a.goods_barcode AS '商品条码', + SUM(a.qty) AS '产品数量', + ROUND(SUM(b.total_real_amt * (a.goods_amt) / b.price_tag), 2) AS '销售金额' FROM ( SELECT platform_order_no, - goods_name, goods_barcode, - good_qty + goods_amt + price, + qty FROM dwd_trade_hkaudit_shop_receipt_mt ) a +INNER JOIN( + SELECT + platform_order_no, + SUM(goods_amt) as price_tag + FROM dwd_trade_hkaudit_shop_receipt_mt + GROUP BY platform_order_no +) b + ON a.platform_order_no = b.platform_order_no INNER JOIN ( SELECT platform_order_no, - MAX(pay_date) as pay_time, - SUM(pay_amt) as pay_amt + SUM(pay_amt) as total_real_amt FROM dwd_trade_hkaudit_shop_receipt_pay_mt - WHERE pay_date >= '2022-01-01 00:00:00' - AND pay_date < '2025-07-01 00:00:00' - AND pay_amt > 0 GROUP BY platform_order_no -) b ON a.platform_order_no = b.platform_order_no -GROUP BY YEAR(b.pay_time), a.goods_name, a.goods_barcode -ORDER BY 年份, 销售金额 DESC; +) c ON + a.platform_order_no = c.platform_order_no +GROUP BY + YEAR(b.pay_time), a.goods_barcode +ORDER BY + 年份, 销售金额 DESC; -- 线上每年前五店铺金额分布 @@ -235,33 +244,48 @@ order BY -- 线上每年单笔订单金额分布 -- (并单如何考虑单笔金额?) +-- 单个订单号使用订单均摊金额,并单号均分金额 SELECT - YEAR(order_date) AS '年份', + YEAR(a.order_date) AS '年份', a.money_area AS '单笔订单金额', - count(a.platform_order_no) as '订单数量', - ROUND(sum(a.order_settle_amt),2) AS '销售金额' + count(a.split_item) as '订单数量', + ROUND(sum(a.split_amount),2) AS '销售金额' FROM( SELECT - order_settle_amt, - platform_order_no, + single.split_amount, + single.split_item, + single.order_date, CASE - WHEN order_settle_amt >0 AND order_settle_amt <10 THEN '0-10' - WHEN order_settle_amt >=10 AND order_settle_amt <50 THEN '10-50' - WHEN order_settle_amt >=50 AND order_settle_amt <100 THEN '50-100' - WHEN order_settle_amt >=100 AND order_settle_amt <500 THEN '100-500' - WHEN order_settle_amt >=500 AND order_settle_amt <1000 THEN '500-1000' - WHEN order_settle_amt >=1000 AND order_settle_amt <5000 THEN '1000-5000' - WHEN order_settle_amt >=5000 AND order_settle_amt <10000 THEN '5000-10000' - WHEN order_settle_amt >=10000 THEN '10000及以上' + WHEN single.split_amount >0 AND single.split_amount <10 THEN '0-10' + WHEN single.split_amount >=10 AND single.split_amount <50 THEN '10-50' + WHEN single.split_amount >=50 AND single.split_amount <100 THEN '50-100' + WHEN single.split_amount >=100 AND single.split_amount <500 THEN '100-500' + WHEN single.split_amount >=500 AND single.split_amount <1000 THEN '500-1000' + WHEN single.split_amount >=1000 AND single.split_amount <5000 THEN '1000-5000' + WHEN single.split_amount >=5000 AND single.split_amount <10000 THEN '5000-10000' + WHEN single.split_amount >=10000 THEN '10000及以上' END AS money_area - FROM - dwd_trade_hkaudit_ecommerce_sale_mt - WHERE - order_date >='2022-01-01 00:00:00' - AND order_date <'2025-07-01 00:00:00' - ) a + FROM( + SELECT + order_date, + split_item, + goods_amt / length(split_array) as split_amount -- 金额均分 + FROM ( + SELECT + order_date, + goods_amt, + splitByChar(',', platform_order_no) as split_array + FROM + dwd_trade_hkaudit_ecommerce_sale_mt + WHERE + order_date >='2022-01-01 00:00:00' + AND order_date <'2025-07-01 00:00:00' + ) single + ARRAY JOIN split_array AS split_item + ) +) a GROUP BY - a.money_area + YEAR(a.order_date),a.money_area ORDER BY 年份, CASE a.money_area @@ -517,14 +541,36 @@ ORDER BY store_code, 年份, -- 线上每年订单下单和发货间隔的销售金额、订单数量分布 -- (并单如何考虑下单时间?) +-- 视为同一时间下单 SELECT - - CASE + CASE timestampdiff(day,deliver_date,order_date) + WHEN 0 THEN '当天' + WHEN 1 THEN '1天' + WHEN 2 THEN '2天' + WHEN 3 THEN '3天' + WHEN 4 THEN '4天' + ELSE '5天及以上' + END AS '发货间隔', + SUM(order_settle_amt) AS '销售金额', + COUNT(platform_order_no) + + SUM(LENGTH(platform_order_no) - LENGTH(REPLACE(platform_order_no, ',', ''))) AS '订单数量' FROM dwd_trade_hkaudit_ecommerce_sale_mt sales -WHERE +WHERE order_date >= '2022-01-01 00:00:00' AND order_date < '2025-07-31 00:00:00' +GROUP BY + 发货间隔 +ORDER BY + CASE 发货间隔 + WHEN '当天' THEN 1 + WHEN '1天' THEN 2 + WHEN '2天' THEN 3 + WHEN '3天' THEN 4 + WHEN '4天' THEN 5 + WHEN '5天及以上' THEN 6 + END; + -- 线上每年各物流承运商销售金额、订单数量 SELECT @@ -543,7 +589,40 @@ GROUP BY order BY 年份, carrier; -- 线上每年退款大于原销售的差异金额、订单数量 - +SELECT + store_code AS '店铺编码', + YEAR(order_date) AS '年份', + ROUND(SUM(excess_refund), 2) AS '差异金额', + COUNT(*) AS '订单数量' +FROM ( + SELECT + s.store_code, + s.order_date, + s.order_settle_amt AS sale_amt, + COALESCE(r.return_amt, 0) + COALESCE(c.change_amt, 0) AS refund_amt, + CASE + WHEN (COALESCE(r.return_amt, 0) + COALESCE(c.change_amt, 0)) > ABS(s.order_settle_amt) + THEN (COALESCE(r.return_amt, 0) + COALESCE(c.change_amt, 0)) - ABS(s.order_settle_amt) + ELSE 0 + END AS excess_refund + FROM dwd_trade_hkaudit_ecommerce_sale_mt s + LEFT JOIN ( + SELECT platform_order_no, SUM(return_goods_amt) AS return_amt + FROM dwd_trade_hkaudit_ecommerce_sale_return_mt + GROUP BY platform_order_no + ) r ON s.platform_order_no = r.platform_order_no + LEFT JOIN ( + SELECT platform_order_no, SUM(special_barcode_amt) AS change_amt + FROM dwd_trade_hkaudit_ecommerce_sale_change_mt + GROUP BY platform_order_no + ) c ON s.platform_order_no = c.platform_order_no + WHERE (r.return_amt IS NOT NULL OR c.change_amt IS NOT NULL) + AND s.order_date >= '2022-01-01 00:00:00' + AND s.order_date < '2025-07-01 00:00:00' +) excess_data +WHERE excess_refund > 0 +GROUP BY store_code, YEAR(order_date) +ORDER BY 年份, 超额退款总金额 DESC; -- 线下每年退款大于原销售的差异金额、订单数量 @@ -558,7 +637,7 @@ FROM ( SUM(CASE WHEN pay_amt < 0 THEN ABS(pay_amt) ELSE 0 END) AS total_refund, MAX(pay_date) AS pay_time FROM dwd_trade_hkaudit_shop_receipt_pay_mt - GROUP BY order_id + GROUP BY receipt_no HAVING total_refund > total_sale ) GROUP BY YEAR(pay_time); \ No newline at end of file