Files
feiqiu-ETL/etl_billiards/docs/table_2025-12-19/助教详情_奈千.md
2026-01-18 22:37:38 +08:00

7.5 KiB
Raw Blame History

助教详情奈千2025年10-12月

思考过程

按模板拆分5部分输出月度排名采用dense_rank均值/中位数在当月该指标>0助教集合上计算。

查询说明

本表包含5个部分基础课业绩、附加课业绩、客户消费业绩、客户充值业绩、头部客户情况。均值/中位数差值对比集合为当月该指标>0的助教。充值/客户流水多助教与多订单命中均按全额复制计入,故汇总可能大于门店总额。 评价基础59.0h附加0.0h客户流水¥107484.78充值归因¥18000.00;头部客户(12月)Top3轩哥、黎先生、陈先生。

SQL

服务时长(助教-客户-月份)

with raw as (
  select
    asl.nickname as assistant,
    asl.tenant_member_id as member_id,
    case when asl.start_use_time >= '2025-10-01 00:00:00+08'::timestamptz and asl.start_use_time < '2025-11-01 00:00:00+08'::timestamptz then '2025-10' when asl.start_use_time >= '2025-11-01 00:00:00+08'::timestamptz and asl.start_use_time < '2025-12-01 00:00:00+08'::timestamptz then '2025-11' when 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 then '2025-12' else null end as month_key,
    asl.order_assistant_type,
    asl.income_seconds
  from billiards_dwd.dwd_assistant_service_log asl
  where asl.site_id=%(site_id)s and coalesce(asl.is_delete,0)=0
    and asl.start_use_time >= %(window_start)s::timestamptz
    and asl.start_use_time <  %(window_end)s::timestamptz
    and asl.tenant_member_id is not null and asl.tenant_member_id<>0
)
select
  assistant,
  member_id,
  month_key,
  sum(case when order_assistant_type=1 then income_seconds else 0 end)/3600.0 as base_hours,
  sum(case when order_assistant_type=2 then income_seconds else 0 end)/3600.0 as extra_hours
from raw
where month_key is not null
group by assistant, member_id, month_key;

客户流水(助教-客户-月份)

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

充值归因(助教-客户-月份)

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,
    ow.member_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,
    m.member_id,
    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,
  member_id,
  month_key,
  sum(pay_amount) as recharge_amount
from raw
where month_key is not null
group by assistant, member_id, month_key;