2.1 KiB
2.1 KiB
2025年10-12月 财务优惠(会员折扣+台费调账)分布
思考过程
用台费订单为基准关联调账表,再按客户+月份汇总,输出“谁享受了优惠”及金额分布。
查询说明
优惠=会员折扣(dwd_table_fee_log.member_discount_amount)+台费调账(dwd_table_fee_adjust.ledger_amount),按订单归集后汇总到客户(member_id),按订单最早开台时间切月;不含团购抵扣等其它优惠。
SQL
优惠分布(客户+月份)
with base_orders as (
select
tfl.order_settle_id,
max(tfl.member_id) as member_id,
min(tfl.start_use_time) as order_start_time,
sum(tfl.member_discount_amount) as member_discount_amount
from billiards_dwd.dwd_table_fee_log tfl
where tfl.site_id = %(site_id)s
and coalesce(tfl.is_delete,0) = 0
and tfl.start_use_time >= %(window_start)s::timestamptz
and tfl.start_use_time < %(window_end)s::timestamptz
group by tfl.order_settle_id
),
adjusts as (
select
tfa.order_settle_id,
sum(tfa.ledger_amount) as adjust_amount
from billiards_dwd.dwd_table_fee_adjust tfa
join base_orders bo on bo.order_settle_id = tfa.order_settle_id
where tfa.site_id = %(site_id)s
and coalesce(tfa.is_delete,0) = 0
group by tfa.order_settle_id
)
, x as (
select
bo.member_id,
case when bo.order_start_time >= '2025-10-01 00:00:00+08'::timestamptz and bo.order_start_time < '2025-11-01 00:00:00+08'::timestamptz then '2025-10' when bo.order_start_time >= '2025-11-01 00:00:00+08'::timestamptz and bo.order_start_time < '2025-12-01 00:00:00+08'::timestamptz then '2025-11' when bo.order_start_time >= '2025-12-01 00:00:00+08'::timestamptz and bo.order_start_time < '2026-01-01 00:00:00+08'::timestamptz then '2025-12' else null end as month_key,
coalesce(bo.member_discount_amount,0) as member_discount_amount,
coalesce(a.adjust_amount,0) as adjust_amount
from base_orders bo
left join adjusts a on a.order_settle_id = bo.order_settle_id
)
select
member_id,
month_key,
sum(member_discount_amount) as member_discount_sum,
sum(adjust_amount) as adjust_sum
from x
where month_key is not null
group by member_id, month_key;