# -*- coding: utf-8 -*- """Recompute billiards_dws.dws_order_summary from DWD tables (dwd_*).""" from __future__ import annotations import argparse import os import sys from pathlib import Path PROJECT_ROOT = Path(__file__).resolve().parents[1] if str(PROJECT_ROOT) not in sys.path: sys.path.insert(0, str(PROJECT_ROOT)) from database.connection import DatabaseConnection # noqa: E402 SQL_BUILD_SUMMARY = r""" WITH base AS ( SELECT sh.site_id, sh.order_settle_id, sh.order_trade_no, COALESCE(sh.pay_time, sh.create_time)::date AS order_date, sh.tenant_id, sh.member_id, COALESCE(sh.is_bind_member, FALSE) AS member_flag, (COALESCE(sh.consume_money, 0) = 0 AND COALESCE(sh.pay_amount, 0) > 0) AS recharge_order_flag, COALESCE(sh.member_discount_amount, 0) AS member_discount_amount, COALESCE(sh.adjust_amount, 0) AS manual_discount_amount, COALESCE(sh.pay_amount, 0) AS total_paid_amount, COALESCE(sh.balance_amount, 0) + COALESCE(sh.recharge_card_amount, 0) + COALESCE(sh.gift_card_amount, 0) AS stored_card_deduct, COALESCE(sh.coupon_amount, 0) AS total_coupon_deduction, COALESCE(sh.table_charge_money, 0) AS settle_table_fee_amount, COALESCE(sh.assistant_pd_money, 0) + COALESCE(sh.assistant_cx_money, 0) AS settle_assistant_service_amount, COALESCE(sh.real_goods_money, 0) AS settle_goods_amount FROM billiards_dwd.dwd_settlement_head sh WHERE (%(site_id)s IS NULL OR sh.site_id = %(site_id)s) AND (%(start_date)s IS NULL OR COALESCE(sh.pay_time, sh.create_time)::date >= %(start_date)s) AND (%(end_date)s IS NULL OR COALESCE(sh.pay_time, sh.create_time)::date <= %(end_date)s) ), table_fee AS ( SELECT site_id, order_settle_id, SUM(COALESCE(real_table_charge_money, 0)) AS table_fee_amount FROM billiards_dwd.dwd_table_fee_log WHERE COALESCE(is_delete, 0) = 0 AND (%(site_id)s IS NULL OR site_id = %(site_id)s) AND (%(start_date)s IS NULL OR start_use_time::date >= %(start_date)s) AND (%(end_date)s IS NULL OR start_use_time::date <= %(end_date)s) GROUP BY site_id, order_settle_id ), assistant_fee AS ( SELECT site_id, order_settle_id, SUM(COALESCE(ledger_amount, 0)) AS assistant_service_amount FROM billiards_dwd.dwd_assistant_service_log WHERE COALESCE(is_delete, 0) = 0 AND (%(site_id)s IS NULL OR site_id = %(site_id)s) AND (%(start_date)s IS NULL OR start_use_time::date >= %(start_date)s) AND (%(end_date)s IS NULL OR start_use_time::date <= %(end_date)s) GROUP BY site_id, order_settle_id ), goods_fee AS ( SELECT site_id, order_settle_id, COUNT(*) AS item_count, SUM(COALESCE(ledger_count, 0)) AS total_item_quantity, SUM(COALESCE(real_goods_money, 0)) AS goods_amount FROM billiards_dwd.dwd_store_goods_sale WHERE COALESCE(is_delete, 0) = 0 AND (%(site_id)s IS NULL OR site_id = %(site_id)s) AND (%(start_date)s IS NULL OR create_time::date >= %(start_date)s) AND (%(end_date)s IS NULL OR create_time::date <= %(end_date)s) GROUP BY site_id, order_settle_id ), group_fee AS ( SELECT site_id, order_settle_id, SUM(COALESCE(ledger_amount, 0)) AS group_amount FROM billiards_dwd.dwd_groupbuy_redemption WHERE COALESCE(is_delete, 0) = 0 AND (%(site_id)s IS NULL OR site_id = %(site_id)s) AND (%(start_date)s IS NULL OR create_time::date >= %(start_date)s) AND (%(end_date)s IS NULL OR create_time::date <= %(end_date)s) GROUP BY site_id, order_settle_id ), refunds AS ( SELECT r.site_id, r.relate_id AS order_settle_id, SUM(COALESCE(rx.refund_amount, 0)) AS refund_amount FROM billiards_dwd.dwd_refund r LEFT JOIN billiards_dwd.dwd_refund_ex rx ON r.refund_id = rx.refund_id WHERE (%(site_id)s IS NULL OR r.site_id = %(site_id)s) AND (%(start_date)s IS NULL OR r.pay_time::date >= %(start_date)s) AND (%(end_date)s IS NULL OR r.pay_time::date <= %(end_date)s) GROUP BY r.site_id, r.relate_id ) INSERT INTO billiards_dws.dws_order_summary ( site_id, order_settle_id, order_trade_no, order_date, tenant_id, member_id, member_flag, recharge_order_flag, item_count, total_item_quantity, table_fee_amount, assistant_service_amount, goods_amount, group_amount, total_coupon_deduction, member_discount_amount, manual_discount_amount, order_original_amount, order_final_amount, stored_card_deduct, external_paid_amount, total_paid_amount, book_table_flow, book_assistant_flow, book_goods_flow, book_group_flow, book_order_flow, order_effective_consume_cash, order_effective_recharge_cash, order_effective_flow, refund_amount, net_income, created_at, updated_at ) SELECT b.site_id, b.order_settle_id, b.order_trade_no::text AS order_trade_no, b.order_date, b.tenant_id, b.member_id, b.member_flag, b.recharge_order_flag, COALESCE(gf.item_count, 0) AS item_count, COALESCE(gf.total_item_quantity, 0) AS total_item_quantity, COALESCE(tf.table_fee_amount, b.settle_table_fee_amount) AS table_fee_amount, COALESCE(af.assistant_service_amount, b.settle_assistant_service_amount) AS assistant_service_amount, COALESCE(gf.goods_amount, b.settle_goods_amount) AS goods_amount, COALESCE(gr.group_amount, 0) AS group_amount, b.total_coupon_deduction AS total_coupon_deduction, b.member_discount_amount AS member_discount_amount, b.manual_discount_amount AS manual_discount_amount, -- approximate original amount: final + discounts/coupon (b.total_paid_amount + b.total_coupon_deduction + b.member_discount_amount + b.manual_discount_amount) AS order_original_amount, b.total_paid_amount AS order_final_amount, b.stored_card_deduct AS stored_card_deduct, GREATEST(b.total_paid_amount - b.stored_card_deduct, 0) AS external_paid_amount, b.total_paid_amount AS total_paid_amount, COALESCE(tf.table_fee_amount, b.settle_table_fee_amount) AS book_table_flow, COALESCE(af.assistant_service_amount, b.settle_assistant_service_amount) AS book_assistant_flow, COALESCE(gf.goods_amount, b.settle_goods_amount) AS book_goods_flow, COALESCE(gr.group_amount, 0) AS book_group_flow, COALESCE(tf.table_fee_amount, b.settle_table_fee_amount) + COALESCE(af.assistant_service_amount, b.settle_assistant_service_amount) + COALESCE(gf.goods_amount, b.settle_goods_amount) + COALESCE(gr.group_amount, 0) AS book_order_flow, GREATEST(b.total_paid_amount - b.stored_card_deduct, 0) AS order_effective_consume_cash, 0 AS order_effective_recharge_cash, b.total_paid_amount AS order_effective_flow, COALESCE(rf.refund_amount, 0) AS refund_amount, b.total_paid_amount - COALESCE(rf.refund_amount, 0) AS net_income, now() AS created_at, now() AS updated_at FROM base b LEFT JOIN table_fee tf ON b.site_id = tf.site_id AND b.order_settle_id = tf.order_settle_id LEFT JOIN assistant_fee af ON b.site_id = af.site_id AND b.order_settle_id = af.order_settle_id LEFT JOIN goods_fee gf ON b.site_id = gf.site_id AND b.order_settle_id = gf.order_settle_id LEFT JOIN group_fee gr ON b.site_id = gr.site_id AND b.order_settle_id = gr.order_settle_id LEFT JOIN refunds rf ON b.site_id = rf.site_id AND b.order_settle_id = rf.order_settle_id ON CONFLICT (site_id, order_settle_id) DO UPDATE SET order_trade_no = EXCLUDED.order_trade_no, order_date = EXCLUDED.order_date, tenant_id = EXCLUDED.tenant_id, member_id = EXCLUDED.member_id, member_flag = EXCLUDED.member_flag, recharge_order_flag = EXCLUDED.recharge_order_flag, item_count = EXCLUDED.item_count, total_item_quantity = EXCLUDED.total_item_quantity, table_fee_amount = EXCLUDED.table_fee_amount, assistant_service_amount = EXCLUDED.assistant_service_amount, goods_amount = EXCLUDED.goods_amount, group_amount = EXCLUDED.group_amount, total_coupon_deduction = EXCLUDED.total_coupon_deduction, member_discount_amount = EXCLUDED.member_discount_amount, manual_discount_amount = EXCLUDED.manual_discount_amount, order_original_amount = EXCLUDED.order_original_amount, order_final_amount = EXCLUDED.order_final_amount, stored_card_deduct = EXCLUDED.stored_card_deduct, external_paid_amount = EXCLUDED.external_paid_amount, total_paid_amount = EXCLUDED.total_paid_amount, book_table_flow = EXCLUDED.book_table_flow, book_assistant_flow = EXCLUDED.book_assistant_flow, book_goods_flow = EXCLUDED.book_goods_flow, book_group_flow = EXCLUDED.book_group_flow, book_order_flow = EXCLUDED.book_order_flow, order_effective_consume_cash = EXCLUDED.order_effective_consume_cash, order_effective_recharge_cash = EXCLUDED.order_effective_recharge_cash, order_effective_flow = EXCLUDED.order_effective_flow, refund_amount = EXCLUDED.refund_amount, net_income = EXCLUDED.net_income, updated_at = now(); """ def parse_args() -> argparse.Namespace: parser = argparse.ArgumentParser( description="Build/update dws_order_summary from DWD fact tables." ) parser.add_argument( "--dsn", default=os.environ.get("PG_DSN"), help="PostgreSQL DSN (fallback: PG_DSN env)", ) parser.add_argument( "--site-id", type=int, default=None, help="Filter by site_id (optional, default all sites)", ) parser.add_argument( "--start-date", dest="start_date", default=None, help="Filter facts from this date (YYYY-MM-DD, optional)", ) parser.add_argument( "--end-date", dest="end_date", default=None, help="Filter facts until this date (YYYY-MM-DD, optional)", ) parser.add_argument( "--timeout", type=int, default=int(os.environ.get("PG_CONNECT_TIMEOUT", 10) or 10), help="connect_timeout seconds (capped at 20, default 10)", ) return parser.parse_args() def main() -> int: args = parse_args() if not args.dsn: print("Missing DSN. Set PG_DSN or pass --dsn.", file=sys.stderr) return 2 params = { "site_id": args.site_id, "start_date": args.start_date, "end_date": args.end_date, } timeout_val = max(1, min(args.timeout, 20)) conn = DatabaseConnection(args.dsn, connect_timeout=timeout_val) try: with conn.conn.cursor() as cur: cur.execute(SQL_BUILD_SUMMARY, params) conn.commit() except Exception as exc: # pragma: no cover - operational script conn.rollback() print(f"DWS build failed: {exc}", file=sys.stderr) return 1 finally: conn.close() print("dws_order_summary refreshed.") return 0 if __name__ == "__main__": raise SystemExit(main())