Files
feiqiu-ETL/etl_billiards/docs/table_2025-12-19/助教_客户流水排行_2025年10-12月.md
2026-01-27 22:45:50 +08:00

2.8 KiB
Raw Permalink Blame History

2025年10-12月 助教客户流水排行榜(全额复制口径)

思考过程

先把订单应付金额汇总为 order_amount再把该订单全额计入订单内每位助教并按月排名。

查询说明

注意:多助教按全额复制计入,导致助教汇总>门店总额,这是刻意口径。

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.ledger_amount) as table_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
),
assistant_amount as (
  select
    asl.order_settle_id,
    sum(asl.ledger_amount) as assistant_amount
  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,
    bo.order_start_time,
    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_amount a on a.order_settle_id=bo.order_settle_id
  left join goods_amount g on g.order_settle_id=bo.order_settle_id
)

, 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
),
raw as (
  select
    ao.assistant,
    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
  join assistant_orders ao on ao.order_settle_id=o.order_settle_id
)
select assistant, month_key, sum(order_amount) as revenue_amount
from raw
where month_key is not null
group by assistant, month_key;