Files
feiqiu-ETL/etl_billiards/schema_v2.sql
2025-11-20 01:27:33 +08:00

664 lines
23 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
-- -*- coding: utf-8 -*-
-- Feiqiu-ETL schema (JSON-first alignment)
-- Updated: 2025-11-19 (Refactored for Manual Import & AI-Friendly DWS)
CREATE SCHEMA IF NOT EXISTS billiards;
CREATE SCHEMA IF NOT EXISTS billiards_ods;
CREATE SCHEMA IF NOT EXISTS billiards_dws;
CREATE SCHEMA IF NOT EXISTS etl_admin;
COMMENT ON SCHEMA billiards IS '门店业务数据 Schema存放维度/事实层(与 JSON 字段对应)';
COMMENT ON SCHEMA billiards_ods IS '原始数据层 (ODS),存放原始 JSON支持 API 抓取和手工导入';
COMMENT ON SCHEMA billiards_dws IS '数据汇总层 (DWS),存放面向 AI 分析的宽表视图';
COMMENT ON SCHEMA etl_admin IS 'ETL 调度、游标与运行记录 Schema';
-- =========================
-- 1. Billiards ODS tables
-- =========================
-- 1.1 Order & Settlement ODS
-- Corresponds to /order/list or manual export
CREATE TABLE IF NOT EXISTS billiards_ods.ods_order_settle (
store_id bigint NOT NULL,
order_settle_id bigint NOT NULL,
order_trade_no bigint,
page_no integer, -- Nullable for manual import
page_size integer, -- Nullable for manual import
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, order_settle_id)
);
COMMENT ON TABLE billiards_ods.ods_order_settle IS '订单/结算 ODS/order/list、ticket 接口原始 JSON';
-- 1.2 Ticket Detail ODS (NEW)
-- Corresponds to "小票详情.json" - Contains full nested details
CREATE TABLE IF NOT EXISTS billiards_ods.ods_ticket_detail (
store_id bigint NOT NULL,
order_settle_id bigint NOT NULL,
source_file varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, order_settle_id)
);
COMMENT ON TABLE billiards_ods.ods_ticket_detail IS '小票详情 ODS包含台费、商品、助教明细的完整 JSON';
-- 1.3 Table Usage ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_table_use_detail (
store_id bigint NOT NULL,
ledger_id bigint NOT NULL,
order_trade_no bigint,
order_settle_id bigint,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, ledger_id)
);
-- 1.4 Assistant Ledger ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_assistant_ledger (
store_id bigint NOT NULL,
ledger_id bigint NOT NULL,
order_trade_no bigint,
order_settle_id bigint,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, ledger_id)
);
-- 1.5 Assistant Abolish ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_assistant_abolish (
store_id bigint NOT NULL,
abolish_id bigint NOT NULL,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, abolish_id)
);
-- 1.6 Goods Ledger ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_goods_ledger (
store_id bigint NOT NULL,
order_goods_id bigint NOT NULL,
order_trade_no bigint,
order_settle_id bigint,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, order_goods_id)
);
-- 1.7 Payment ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_payment (
store_id bigint NOT NULL,
pay_id bigint NOT NULL,
relate_type varchar(50),
relate_id bigint,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, pay_id)
);
-- 1.8 Refund ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_refund (
store_id bigint NOT NULL,
refund_id bigint NOT NULL,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, refund_id)
);
-- 1.9 Coupon Verify ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_coupon_verify (
store_id bigint NOT NULL,
coupon_id bigint NOT NULL,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, coupon_id)
);
-- 1.10 Member ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_member (
store_id bigint NOT NULL,
member_id bigint NOT NULL,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, member_id)
);
-- 1.11 Member Card ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_member_card (
store_id bigint NOT NULL,
card_id bigint NOT NULL,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, card_id)
);
-- 1.12 Package Coupon ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_package_coupon (
store_id bigint NOT NULL,
package_id bigint NOT NULL,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, package_id)
);
-- 1.13 Inventory Stock ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_inventory_stock (
store_id bigint NOT NULL,
site_goods_id bigint NOT NULL,
snapshot_key varchar(100) NOT NULL DEFAULT 'default',
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, site_goods_id, snapshot_key)
);
-- 1.14 Inventory Change ODS
CREATE TABLE IF NOT EXISTS billiards_ods.ods_inventory_change (
store_id bigint NOT NULL,
change_id bigint NOT NULL,
page_no integer,
source_file varchar(255),
source_endpoint varchar(255),
fetched_at timestamptz NOT NULL DEFAULT now(),
payload jsonb NOT NULL,
PRIMARY KEY (store_id, change_id)
);
-- =========================
-- 2. Billiards Dimension Tables
-- =========================
CREATE TABLE IF NOT EXISTS billiards.dim_store (
store_id bigint PRIMARY KEY,
store_name varchar(200),
tenant_id bigint,
region_code varchar(30),
address varchar(500),
contact_name varchar(100),
contact_phone varchar(30),
created_time timestamptz,
updated_time timestamptz,
remark text,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb
);
CREATE TABLE IF NOT EXISTS billiards.dim_assistant (
store_id bigint NOT NULL,
assistant_id bigint NOT NULL,
assistant_no varchar(64),
nickname varchar(100),
real_name varchar(100),
gender varchar(20),
mobile varchar(30),
level varchar(50),
team_id bigint,
team_name varchar(100),
assistant_status varchar(30),
work_status varchar(30),
entry_time timestamptz,
resign_time timestamptz,
start_time timestamptz,
end_time timestamptz,
create_time timestamptz,
update_time timestamptz,
system_role_id bigint,
online_status varchar(30),
allow_cx integer,
charge_way varchar(30),
pd_unit_price numeric(14,2),
cx_unit_price numeric(14,2),
is_guaranteed integer,
is_team_leader integer,
serial_number varchar(64),
show_sort integer,
is_delete integer,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, assistant_id)
);
CREATE TABLE IF NOT EXISTS billiards.dim_member (
store_id bigint NOT NULL,
member_id bigint NOT NULL,
member_name varchar(100),
phone varchar(30),
balance numeric(18,4),
status varchar(30),
register_time timestamptz,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, member_id)
);
CREATE TABLE IF NOT EXISTS billiards.dim_package_coupon (
store_id bigint NOT NULL,
package_id bigint NOT NULL,
package_code varchar(100),
package_name varchar(200),
table_area_id bigint,
table_area_name varchar(100),
selling_price numeric(14,2),
duration_seconds integer,
start_time timestamptz,
end_time timestamptz,
type varchar(50),
is_enabled integer,
is_delete integer,
usable_count integer,
creator_name varchar(100),
date_type varchar(50),
group_type varchar(50),
coupon_money numeric(14,2),
area_tag_type varchar(50),
system_group_type varchar(50),
card_type_ids text,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, package_id)
);
CREATE TABLE IF NOT EXISTS billiards.dim_product (
store_id bigint NOT NULL,
product_id bigint NOT NULL,
site_product_id bigint,
product_name varchar(200) NOT NULL,
category_id bigint,
category_name varchar(100),
second_category_id bigint,
unit varchar(20),
cost_price numeric(14,4),
sale_price numeric(14,4),
allow_discount boolean,
status varchar(30),
supplier_id bigint,
barcode varchar(128),
is_combo boolean,
created_time timestamptz,
updated_time timestamptz,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, product_id)
);
CREATE TABLE IF NOT EXISTS billiards.dim_product_price_scd (
product_scd_id bigserial PRIMARY KEY,
store_id bigint NOT NULL,
product_id bigint NOT NULL,
product_name varchar(200),
category_id bigint,
category_name varchar(100),
second_category_id bigint,
cost_price numeric(14,4),
sale_price numeric(14,4),
allow_discount boolean,
status varchar(30),
valid_from timestamptz NOT NULL DEFAULT now(),
valid_to timestamptz,
is_current boolean NOT NULL DEFAULT true,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
CONSTRAINT fk_dpps_product FOREIGN KEY (store_id, product_id)
REFERENCES billiards.dim_product(store_id, product_id) ON DELETE CASCADE,
CONSTRAINT ck_dpps_range CHECK (
valid_from < COALESCE(valid_to, '9999-12-31 00:00:00+00'::timestamptz)
)
);
-- Create partial unique index for current records only
CREATE UNIQUE INDEX uq_dpps_current ON billiards.dim_product_price_scd (store_id, product_id) WHERE is_current;
CREATE VIEW billiards.dim_product_price_current AS
SELECT product_scd_id,
store_id,
product_id,
product_name,
category_id,
category_name,
second_category_id,
cost_price,
sale_price,
allow_discount,
status,
valid_from,
valid_to,
raw_data
FROM billiards.dim_product_price_scd
WHERE is_current;
CREATE TABLE IF NOT EXISTS billiards.dim_table (
store_id bigint NOT NULL,
table_id bigint NOT NULL,
site_id bigint,
area_id bigint,
area_name varchar(100),
table_name varchar(100) NOT NULL,
table_price numeric(14,4),
table_status varchar(30),
table_status_name varchar(50),
light_status integer,
is_rest_area integer,
show_status integer,
virtual_table integer,
charge_free integer,
only_allow_groupon integer,
is_online_reservation integer,
created_time timestamptz,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, table_id)
);
-- =========================
-- 3. Billiards Fact Tables
-- =========================
-- 3.1 Order Fact (Header)
CREATE TABLE IF NOT EXISTS billiards.fact_order (
store_id bigint NOT NULL,
order_settle_id bigint NOT NULL, -- Settle ID is the main key for payment
order_trade_no bigint, -- Can be one of many if merged, but usually 1-1 main
order_no varchar(100),
member_id bigint,
pay_time timestamptz,
total_amount numeric(14,4), -- Original price
pay_amount numeric(14,4), -- Actual paid
discount_amount numeric(14,4),
coupon_amount numeric(14,4),
status varchar(50),
cashier_name varchar(100),
remark text,
raw_data jsonb,
created_at timestamptz DEFAULT now(),
PRIMARY KEY (store_id, order_settle_id)
);
-- 3.2 Order Items (Goods)
CREATE TABLE IF NOT EXISTS billiards.fact_order_goods (
store_id bigint NOT NULL,
order_goods_id bigint NOT NULL, -- orderGoodsLedgerId
order_settle_id bigint NOT NULL,
order_trade_no bigint,
goods_id bigint,
goods_name varchar(200),
quantity numeric(10,2),
unit_price numeric(14,4),
total_amount numeric(14,4), -- quantity * price
pay_amount numeric(14,4), -- After discount
created_at timestamptz DEFAULT now(),
PRIMARY KEY (store_id, order_goods_id)
);
-- 3.3 Table Usage Fact
CREATE TABLE IF NOT EXISTS billiards.fact_table_usage (
store_id bigint NOT NULL,
order_ledger_id bigint NOT NULL, -- orderTableLedgerId
order_settle_id bigint NOT NULL,
table_id bigint,
table_name varchar(100),
start_time timestamptz,
end_time timestamptz,
duration_minutes integer,
total_amount numeric(14,4),
pay_amount numeric(14,4),
created_at timestamptz DEFAULT now(),
PRIMARY KEY (store_id, order_ledger_id)
);
-- 3.4 Assistant Service Fact
CREATE TABLE IF NOT EXISTS billiards.fact_assistant_service (
store_id bigint NOT NULL,
ledger_id bigint NOT NULL, -- orderAssistantLedgerId
order_settle_id bigint NOT NULL,
assistant_id bigint,
assistant_name varchar(100),
service_type varchar(50), -- e.g., "Play with"
start_time timestamptz,
end_time timestamptz,
duration_minutes integer,
total_amount numeric(14,4),
pay_amount numeric(14,4),
created_at timestamptz DEFAULT now(),
PRIMARY KEY (store_id, ledger_id)
);
-- 3.5 Payment Fact
CREATE TABLE IF NOT EXISTS billiards.fact_payment (
store_id bigint NOT NULL,
pay_id bigint NOT NULL,
site_id bigint,
tenant_id bigint,
order_settle_id bigint,
order_trade_no bigint,
relate_type varchar(50),
relate_id bigint,
create_time timestamptz,
pay_time timestamptz,
pay_amount numeric(14,4),
fee_amount numeric(14,4),
discount_amount numeric(14,4),
payment_method varchar(50), -- e.g., 'WeChat', 'Cash', 'Balance'
online_pay_channel varchar(50),
pay_terminal varchar(30),
pay_status varchar(30),
raw_data jsonb,
updated_at timestamptz DEFAULT now(),
PRIMARY KEY (store_id, pay_id)
);
-- 3.6 Legacy/Other Facts (Preserved)
CREATE TABLE IF NOT EXISTS billiards.fact_assistant_abolish (
store_id bigint NOT NULL,
abolish_id bigint NOT NULL,
table_id bigint,
table_name varchar(100),
table_area_id bigint,
table_area varchar(100),
assistant_no varchar(64),
assistant_name varchar(100),
charge_minutes integer,
abolish_amount numeric(14,4),
create_time timestamptz,
trash_reason text,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, abolish_id)
);
CREATE TABLE IF NOT EXISTS billiards.fact_assistant_ledger (
store_id bigint NOT NULL,
ledger_id bigint NOT NULL,
assistant_no varchar(64),
assistant_name varchar(100),
nickname varchar(100),
level_name varchar(50),
table_name varchar(100),
ledger_unit_price numeric(14,4),
ledger_count numeric(14,4),
ledger_amount numeric(14,4),
projected_income numeric(14,4),
service_money numeric(14,4),
member_discount_amount numeric(14,4),
manual_discount_amount numeric(14,4),
coupon_deduct_money numeric(14,4),
order_trade_no bigint,
order_settle_id bigint,
operator_id bigint,
operator_name varchar(100),
assistant_team_id bigint,
assistant_level varchar(50),
site_table_id bigint,
order_assistant_id bigint,
site_assistant_id bigint,
user_id bigint,
ledger_start_time timestamptz,
ledger_end_time timestamptz,
start_use_time timestamptz,
last_use_time timestamptz,
income_seconds integer,
real_use_seconds integer,
is_trash integer,
trash_reason text,
is_confirm integer,
ledger_status varchar(30),
create_time timestamptz,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, ledger_id)
);
CREATE TABLE IF NOT EXISTS billiards.fact_inventory_change (
store_id bigint NOT NULL,
change_id bigint NOT NULL,
site_goods_id bigint,
stock_type varchar(50),
goods_name varchar(200),
change_time timestamptz,
start_qty numeric(18,4),
end_qty numeric(18,4),
change_qty numeric(18,4),
unit varchar(20),
price numeric(14,4),
operator_name varchar(100),
remark text,
goods_category_id bigint,
goods_second_category_id bigint,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, change_id)
);
CREATE TABLE IF NOT EXISTS billiards.fact_refund (
store_id bigint NOT NULL,
refund_id bigint NOT NULL,
site_id bigint,
tenant_id bigint,
pay_amount numeric(14,4),
pay_status varchar(30),
pay_time timestamptz,
create_time timestamptz,
relate_type varchar(50),
relate_id bigint,
payment_method varchar(50),
refund_amount numeric(14,4),
refund_reason text,
raw_data jsonb NOT NULL DEFAULT '{}'::jsonb,
updated_at timestamptz NOT NULL DEFAULT now(),
PRIMARY KEY (store_id, refund_id)
);
-- =========================
-- 4. DWS Layer (Data Warehouse Summary)
-- Views for Analysis & AI
-- =========================
-- 4.1 Sales Detail View (The "AI-Friendly" Wide Table)
-- Unifies Goods, Table Fees, and Assistant Services into a single stream of "Sales Items"
CREATE OR REPLACE VIEW billiards_dws.dws_sales_detail AS
SELECT
'GOODS' as item_type,
g.store_id,
g.order_settle_id,
o.pay_time,
g.goods_name as item_name,
g.quantity,
g.pay_amount as amount,
o.cashier_name
FROM billiards.fact_order_goods g
JOIN billiards.fact_order o ON g.store_id = o.store_id AND g.order_settle_id = o.order_settle_id
UNION ALL
SELECT
'TABLE' as item_type,
t.store_id,
t.order_settle_id,
o.pay_time,
t.table_name || ' (' || t.duration_minutes || ' mins)' as item_name,
1 as quantity,
t.pay_amount as amount,
o.cashier_name
FROM billiards.fact_table_usage t
JOIN billiards.fact_order o ON t.store_id = o.store_id AND t.order_settle_id = o.order_settle_id
UNION ALL
SELECT
'ASSISTANT' as item_type,
a.store_id,
a.order_settle_id,
o.pay_time,
a.assistant_name || ' (' || a.duration_minutes || ' mins)' as item_name,
1 as quantity,
a.pay_amount as amount,
o.cashier_name
FROM billiards.fact_assistant_service a
JOIN billiards.fact_order o ON a.store_id = o.store_id AND a.order_settle_id = o.order_settle_id;
-- 4.2 Daily Revenue View
CREATE OR REPLACE VIEW billiards_dws.dws_daily_revenue AS
SELECT
store_id,
DATE(pay_time) as report_date,
COUNT(DISTINCT order_settle_id) as total_orders,
SUM(amount) as total_revenue,
SUM(amount) FILTER (WHERE item_type = 'GOODS') as goods_revenue,
SUM(amount) FILTER (WHERE item_type = 'TABLE') as table_revenue,
SUM(amount) FILTER (WHERE item_type = 'ASSISTANT') as assistant_revenue
FROM billiards_dws.dws_sales_detail
GROUP BY store_id, DATE(pay_time);
-- 4.3 Order Detail Wide View (For detailed inspection)
CREATE OR REPLACE VIEW billiards_dws.dws_order_detail AS
SELECT
o.store_id,
o.order_settle_id,
o.order_no,
o.pay_time,
o.total_amount,
o.pay_amount,
o.cashier_name,
-- Payment pivot (approximate, assumes simple mapping)
COALESCE(SUM(p.pay_amount) FILTER (WHERE p.payment_method = '1'), 0) AS pay_cash,
COALESCE(SUM(p.pay_amount) FILTER (WHERE p.payment_method = '2'), 0) AS pay_balance,
COALESCE(SUM(p.pay_amount) FILTER (WHERE p.payment_method = '4'), 0) AS pay_wechat,
-- Content summary
(SELECT string_agg(goods_name || 'x' || quantity, '; ') FROM billiards.fact_order_goods WHERE order_settle_id = o.order_settle_id) AS goods_summary,
(SELECT string_agg(assistant_name, '; ') FROM billiards.fact_assistant_service WHERE order_settle_id = o.order_settle_id) AS assistant_summary
FROM billiards.fact_order o
LEFT JOIN billiards.fact_payment p ON o.order_settle_id = p.order_settle_id
GROUP BY o.store_id, o.order_settle_id, o.order_no, o.pay_time, o.total_amount, o.pay_amount, o.cashier_name;