7.0 KiB
7.0 KiB
2025年10-12月 客户消费能力Top100(分表)
思考过程
以台费订单为基准汇总三类明细,满足应付金额口径,并输出Top100客户的消费/充值/助教偏好。按你的要求,先生成评价为空的版本,再在脚本末尾回填评价。
查询说明
与总表同口径;分表仅计算12月喜爱助教Top5,并展示10-12月各月消费/充值。
SQL
Top100(按消费总额)
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,
max(tfl.ledger_end_time) as order_end_time,
sum(tfl.ledger_amount) as table_amount,
sum(tfl.real_table_use_seconds) as table_use_seconds
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 >= '2025-10-01 00:00:00+08'::timestamptz
and tfl.start_use_time < '2026-01-01 00:00:00+08'::timestamptz
group by tfl.order_settle_id
),
assistant_info as (
select
asl.order_settle_id,
sum(asl.ledger_amount) as assistant_amount,
min(asl.start_use_time) as assistant_start_time,
max(asl.last_use_time) as assistant_end_time
from billiards_dwd.dwd_assistant_service_log asl
join base_orders bo on bo.order_settle_id = asl.order_settle_id
where asl.site_id = %(site_id)s
and coalesce(asl.is_delete,0) = 0
group by asl.order_settle_id
),
goods_amount as (
select
g.order_settle_id,
sum(g.ledger_amount) as goods_amount
from billiards_dwd.dwd_store_goods_sale g
join base_orders bo on bo.order_settle_id = g.order_settle_id
where g.site_id = %(site_id)s
and coalesce(g.is_delete,0) = 0
group by g.order_settle_id
),
orders as (
select
bo.order_settle_id,
bo.member_id,
least(bo.order_start_time, coalesce(a.assistant_start_time, bo.order_start_time)) as order_start_time,
greatest(bo.order_end_time, coalesce(a.assistant_end_time, bo.order_end_time)) as order_end_time,
bo.table_use_seconds,
coalesce(bo.table_amount,0) + coalesce(a.assistant_amount,0) + coalesce(g.goods_amount,0) as order_amount
from base_orders bo
left join assistant_info a on a.order_settle_id = bo.order_settle_id
left join goods_amount g on g.order_settle_id = bo.order_settle_id
)
select
o.member_id,
sum(o.order_amount) as consume_total,
count(*) as order_cnt
from orders o
where o.member_id is not null and o.member_id <> 0
group by o.member_id
order by consume_total desc
limit 100;
按月消费汇总
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,
max(tfl.ledger_end_time) as order_end_time,
sum(tfl.ledger_amount) as table_amount,
sum(tfl.real_table_use_seconds) as table_use_seconds
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 >= '2025-10-01 00:00:00+08'::timestamptz
and tfl.start_use_time < '2026-01-01 00:00:00+08'::timestamptz
group by tfl.order_settle_id
),
assistant_info as (
select
asl.order_settle_id,
sum(asl.ledger_amount) as assistant_amount,
min(asl.start_use_time) as assistant_start_time,
max(asl.last_use_time) as assistant_end_time
from billiards_dwd.dwd_assistant_service_log asl
join base_orders bo on bo.order_settle_id = asl.order_settle_id
where asl.site_id = %(site_id)s
and coalesce(asl.is_delete,0) = 0
group by asl.order_settle_id
),
goods_amount as (
select
g.order_settle_id,
sum(g.ledger_amount) as goods_amount
from billiards_dwd.dwd_store_goods_sale g
join base_orders bo on bo.order_settle_id = g.order_settle_id
where g.site_id = %(site_id)s
and coalesce(g.is_delete,0) = 0
group by g.order_settle_id
),
orders as (
select
bo.order_settle_id,
bo.member_id,
least(bo.order_start_time, coalesce(a.assistant_start_time, bo.order_start_time)) as order_start_time,
greatest(bo.order_end_time, coalesce(a.assistant_end_time, bo.order_end_time)) as order_end_time,
bo.table_use_seconds,
coalesce(bo.table_amount,0) + coalesce(a.assistant_amount,0) + coalesce(g.goods_amount,0) as order_amount
from base_orders bo
left join assistant_info a on a.order_settle_id = bo.order_settle_id
left join goods_amount g on g.order_settle_id = bo.order_settle_id
)
, x as (
select
o.member_id,
case when o.order_start_time >= '2025-10-01 00:00:00+08'::timestamptz and o.order_start_time < '2025-11-01 00:00:00+08'::timestamptz then '2025-10' when o.order_start_time >= '2025-11-01 00:00:00+08'::timestamptz and o.order_start_time < '2025-12-01 00:00:00+08'::timestamptz then '2025-11' when o.order_start_time >= '2025-12-01 00:00:00+08'::timestamptz and o.order_start_time < '2026-01-01 00:00:00+08'::timestamptz then '2025-12' else null end as month_key,
o.order_amount
from orders o
where o.member_id is not null and o.member_id <> 0
)
select
member_id,
month_key,
sum(order_amount) as consume_sum
from x
where month_key is not null
group by member_id, month_key;
按月充值汇总
with pay as (
select
p.pay_time,
r.member_id,
p.pay_amount
from billiards_dwd.dwd_payment p
join billiards_dwd.dwd_recharge_order r on r.recharge_order_id = p.relate_id
where p.site_id = %(site_id)s
and p.relate_type = 5
and p.pay_status = 2
and p.pay_amount > 0
and p.pay_time >= %(window_start)s::timestamptz
and p.pay_time < %(window_end)s::timestamptz
)
, x as (
select
member_id,
case when pay_time >= '2025-10-01 00:00:00+08'::timestamptz and pay_time < '2025-11-01 00:00:00+08'::timestamptz then '2025-10' when pay_time >= '2025-11-01 00:00:00+08'::timestamptz and pay_time < '2025-12-01 00:00:00+08'::timestamptz then '2025-11' when pay_time >= '2025-12-01 00:00:00+08'::timestamptz and pay_time < '2026-01-01 00:00:00+08'::timestamptz then '2025-12' else null end as month_key,
pay_amount
from pay
)
select
member_id,
month_key,
sum(pay_amount) as recharge_sum
from x
where month_key is not null
group by member_id, month_key;
喜爱助教Top5(仅12月)
with x as (
select
asl.tenant_member_id as member_id,
asl.nickname as assistant_nickname,
sum(case when asl.order_assistant_type=1 then asl.income_seconds else asl.income_seconds*1.5 end) / 3600.0 as weighted_hours
from billiards_dwd.dwd_assistant_service_log asl
where asl.site_id = %(site_id)s
and coalesce(asl.is_delete,0)=0
and asl.tenant_member_id is not null and asl.tenant_member_id <> 0
and asl.start_use_time >= '2025-12-01 00:00:00+08'::timestamptz
and asl.start_use_time < '2026-01-01 00:00:00+08'::timestamptz
group by asl.tenant_member_id, asl.nickname
),
ranked as (
select *, row_number() over(partition by member_id order by weighted_hours desc) as rn
from x
)
select
member_id,
string_agg(assistant_nickname || '(' || to_char(round(weighted_hours::numeric, 1), 'FM999999990.0') || 'h)', '、' order by weighted_hours desc) as fav5
from ranked
where rn <= 5
group by member_id;