Files
feiqiu-ETL/etl_billiards/docs/table_2025-12-19/助教_客户充值归因排行_2025年10-12月.md
2026-01-18 22:37:38 +08:00

3.2 KiB
Raw Blame History

2025年10-12月 助教客户充值归因排行榜(全额复制口径)

思考过程

按“消费窗口±30分钟”把充值支付命中到订单再全额计入订单内助教并按月排名。

查询说明

注意:多助教/多订单命中按全额复制,充值会重复计入,故助教汇总可能大于门店总额。

SQL

充值归因(助教+月份汇总,全额复制)

with base_orders as (
  select
    tfl.order_settle_id,
    max(tfl.member_id) as member_id,
    min(tfl.start_use_time) as table_start_time,
    max(tfl.ledger_end_time) as table_end_time
  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
),
assistant_time as (
  select
    asl.order_settle_id,
    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
),
order_windows as (
  select
    bo.order_settle_id,
    bo.member_id,
    least(bo.table_start_time, coalesce(at.assistant_start_time, bo.table_start_time)) as win_start,
    greatest(bo.table_end_time, coalesce(at.assistant_end_time, bo.table_end_time)) as win_end
  from base_orders bo
  left join assistant_time at on at.order_settle_id=bo.order_settle_id
  where bo.member_id is not null and bo.member_id<>0
),
assistant_orders as (
  select distinct order_settle_id, nickname as assistant
  from billiards_dwd.dwd_assistant_service_log
  where site_id=%(site_id)s and coalesce(is_delete,0)=0
    and start_use_time >= %(window_start)s::timestamptz
    and start_use_time <  %(window_end)s::timestamptz
),
recharge_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
),
matched as (
  select rp.pay_time, ow.order_settle_id, rp.pay_amount
  from recharge_pay rp
  join order_windows ow
    on ow.member_id=rp.member_id
   and rp.pay_time >= ow.win_start - interval '30 minutes'
   and rp.pay_time <= ow.win_end   + interval '30 minutes'
),
raw as (
  select
    ao.assistant,
    case when m.pay_time >= '2025-10-01 00:00:00+08'::timestamptz and m.pay_time < '2025-11-01 00:00:00+08'::timestamptz then '2025-10' when m.pay_time >= '2025-11-01 00:00:00+08'::timestamptz and m.pay_time < '2025-12-01 00:00:00+08'::timestamptz then '2025-11' when m.pay_time >= '2025-12-01 00:00:00+08'::timestamptz and m.pay_time < '2026-01-01 00:00:00+08'::timestamptz then '2025-12' else null end as month_key,
    m.pay_amount
  from matched m
  join assistant_orders ao on ao.order_settle_id=m.order_settle_id
)
select assistant, month_key, sum(pay_amount) as recharge_amount
from raw
where month_key is not null
group by assistant, month_key;