567 lines
27 KiB
SQL
567 lines
27 KiB
SQL
-- =====================================================================
|
||
-- 配件查询 App 数据库结构(MySQL 8.0)
|
||
-- 依据:/doc/requirements.md、/doc/functional_spec.md、/doc/architecture.md
|
||
-- 注意:不在此文件中创建数据库与用户,请在外部以环境配置完成
|
||
-- 字符集统一为 utf8mb4,排序规则 utf8mb4_0900_ai_ci
|
||
-- =====================================================================
|
||
|
||
SET NAMES utf8mb4;
|
||
SET time_zone = '+00:00';
|
||
SET sql_mode = 'STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_ENGINE_SUBSTITUTION';
|
||
SET FOREIGN_KEY_CHECKS = 0;
|
||
|
||
-- =====================================================================
|
||
-- 基础:租户与用户
|
||
-- =====================================================================
|
||
|
||
CREATE TABLE IF NOT EXISTS shops (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '店铺/租户ID',
|
||
name VARCHAR(100) NOT NULL COMMENT '店铺名称',
|
||
status TINYINT UNSIGNED NOT NULL DEFAULT 1 COMMENT '状态:1启用 0停用',
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
KEY idx_shops_status (status)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='店铺/租户';
|
||
|
||
CREATE TABLE IF NOT EXISTS users (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '用户ID',
|
||
shop_id BIGINT UNSIGNED NOT NULL COMMENT '所属店铺',
|
||
phone VARCHAR(32) NULL COMMENT '手机号',
|
||
name VARCHAR(64) NOT NULL COMMENT '姓名',
|
||
role VARCHAR(32) NOT NULL DEFAULT 'staff' COMMENT '角色:owner/staff/finance/...',
|
||
password_hash VARCHAR(255) NULL COMMENT '密码哈希(若采用短信登录可为空)',
|
||
status TINYINT UNSIGNED NOT NULL DEFAULT 1 COMMENT '状态:1启用 0停用',
|
||
is_owner TINYINT(1) NOT NULL DEFAULT 0 COMMENT '是否店主',
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_users_shop_phone (shop_id, phone),
|
||
KEY idx_users_shop (shop_id),
|
||
CONSTRAINT fk_users_shop FOREIGN KEY (shop_id) REFERENCES shops(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='用户';
|
||
|
||
-- 第三方身份映射(微信)
|
||
CREATE TABLE IF NOT EXISTS user_identities (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
provider ENUM('wechat_mp','wechat_app') NOT NULL COMMENT '身份提供方:小程序/APP',
|
||
openid VARCHAR(64) NOT NULL,
|
||
unionid VARCHAR(64) NULL,
|
||
nickname VARCHAR(64) NULL,
|
||
avatar_url VARCHAR(512) NULL,
|
||
last_login_at DATETIME NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_identity_provider_openid (provider, openid),
|
||
UNIQUE KEY ux_identity_unionid (unionid),
|
||
KEY idx_identity_user (user_id),
|
||
KEY idx_identity_shop (shop_id),
|
||
CONSTRAINT fk_identity_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_identity_user FOREIGN KEY (user_id) REFERENCES users(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='第三方身份映射(微信)';
|
||
|
||
-- 微信会话(小程序/APP 临时会话)
|
||
CREATE TABLE IF NOT EXISTS wechat_sessions (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
provider ENUM('wechat_mp','wechat_app') NOT NULL,
|
||
openid VARCHAR(64) NOT NULL,
|
||
session_key VARCHAR(128) NOT NULL,
|
||
expires_at DATETIME NOT NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_wechat_session (provider, openid),
|
||
KEY idx_wechat_session_expires (expires_at)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='微信会话(临时)';
|
||
|
||
CREATE TABLE IF NOT EXISTS system_parameters (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL COMMENT '创建/最后修改人',
|
||
`key` VARCHAR(64) NOT NULL COMMENT '参数键',
|
||
`value` JSON NOT NULL COMMENT '参数值(JSON)',
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_sysparams_shop_key (shop_id, `key`),
|
||
KEY idx_sysparams_shop (shop_id),
|
||
CONSTRAINT fk_sysparams_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_sysparams_user FOREIGN KEY (user_id) REFERENCES users(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='系统参数(租户级)';
|
||
|
||
-- =====================================================================
|
||
-- 货品域(含价格/库存/图片/别名)
|
||
-- =====================================================================
|
||
|
||
CREATE TABLE IF NOT EXISTS product_categories (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
name VARCHAR(64) NOT NULL,
|
||
parent_id BIGINT UNSIGNED NULL,
|
||
sort_order INT NOT NULL DEFAULT 0,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_categories_shop_name (shop_id, name),
|
||
KEY idx_categories_shop (shop_id),
|
||
KEY idx_categories_parent (parent_id),
|
||
CONSTRAINT fk_categories_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_categories_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT fk_categories_parent FOREIGN KEY (parent_id) REFERENCES product_categories(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='商品类别';
|
||
|
||
CREATE TABLE IF NOT EXISTS product_units (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
name VARCHAR(16) NOT NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_units_shop_name (shop_id, name),
|
||
KEY idx_units_shop (shop_id),
|
||
CONSTRAINT fk_units_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_units_user FOREIGN KEY (user_id) REFERENCES users(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='商品单位';
|
||
|
||
CREATE TABLE IF NOT EXISTS global_skus (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
name VARCHAR(120) NOT NULL COMMENT 'SKU名称',
|
||
brand VARCHAR(64) NULL,
|
||
model VARCHAR(64) NULL,
|
||
spec VARCHAR(128) NULL,
|
||
barcode VARCHAR(32) NULL,
|
||
unit_id BIGINT UNSIGNED NULL,
|
||
tags JSON NULL,
|
||
status ENUM('published','offline') NOT NULL DEFAULT 'published',
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_global_skus_barcode (barcode),
|
||
KEY idx_global_skus_brand_model (brand, model),
|
||
CONSTRAINT fk_globalsku_unit FOREIGN KEY (unit_id) REFERENCES product_units(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='全局SKU(众包)';
|
||
|
||
CREATE TABLE IF NOT EXISTS products (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
name VARCHAR(120) NOT NULL,
|
||
category_id BIGINT UNSIGNED NULL,
|
||
unit_id BIGINT UNSIGNED NOT NULL,
|
||
brand VARCHAR(64) NULL,
|
||
model VARCHAR(64) NULL,
|
||
spec VARCHAR(128) NULL,
|
||
origin VARCHAR(64) NULL,
|
||
barcode VARCHAR(32) NULL,
|
||
alias VARCHAR(120) NULL,
|
||
description TEXT NULL,
|
||
global_sku_id BIGINT UNSIGNED NULL,
|
||
safe_min DECIMAL(18,3) NULL,
|
||
safe_max DECIMAL(18,3) NULL,
|
||
search_text TEXT NULL COMMENT '供全文检索的聚合字段(名称/品牌/型号/规格/别名)',
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_products_shop_barcode (shop_id, barcode),
|
||
KEY idx_products_shop (shop_id),
|
||
KEY idx_products_category (category_id),
|
||
KEY idx_products_unit (unit_id),
|
||
FULLTEXT KEY ft_products_search (name, brand, model, spec, search_text),
|
||
CONSTRAINT fk_products_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_products_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT fk_products_category FOREIGN KEY (category_id) REFERENCES product_categories(id),
|
||
CONSTRAINT fk_products_unit FOREIGN KEY (unit_id) REFERENCES product_units(id),
|
||
CONSTRAINT fk_products_globalsku FOREIGN KEY (global_sku_id) REFERENCES global_skus(id),
|
||
CONSTRAINT ck_products_safe_range CHECK (safe_min IS NULL OR safe_max IS NULL OR safe_min <= safe_max)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='商品';
|
||
|
||
CREATE TABLE IF NOT EXISTS product_aliases (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
product_id BIGINT UNSIGNED NOT NULL,
|
||
alias VARCHAR(120) NOT NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_product_alias (product_id, alias),
|
||
KEY idx_product_alias_product (product_id),
|
||
CONSTRAINT fk_alias_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_alias_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT fk_alias_product FOREIGN KEY (product_id) REFERENCES products(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='商品别名';
|
||
|
||
CREATE TABLE IF NOT EXISTS product_prices (
|
||
product_id BIGINT UNSIGNED NOT NULL,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
purchase_price DECIMAL(18,2) NOT NULL DEFAULT 0,
|
||
retail_price DECIMAL(18,2) NOT NULL DEFAULT 0,
|
||
distribution_price DECIMAL(18,2) NOT NULL DEFAULT 0,
|
||
wholesale_price DECIMAL(18,2) NOT NULL DEFAULT 0,
|
||
big_client_price DECIMAL(18,2) NOT NULL DEFAULT 0,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (product_id),
|
||
KEY idx_prices_shop (shop_id),
|
||
CONSTRAINT fk_prices_product FOREIGN KEY (product_id) REFERENCES products(id) ON DELETE CASCADE,
|
||
CONSTRAINT fk_prices_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_prices_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT ck_prices_non_negative CHECK (
|
||
purchase_price >= 0 AND retail_price >= 0 AND distribution_price >= 0 AND wholesale_price >= 0 AND big_client_price >= 0
|
||
)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='商品价格(含四列销售价)';
|
||
|
||
CREATE TABLE IF NOT EXISTS inventories (
|
||
product_id BIGINT UNSIGNED NOT NULL,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
quantity DECIMAL(18,3) NOT NULL DEFAULT 0,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (product_id),
|
||
KEY idx_inventories_shop (shop_id),
|
||
CONSTRAINT fk_inv_product FOREIGN KEY (product_id) REFERENCES products(id) ON DELETE CASCADE,
|
||
CONSTRAINT fk_inv_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_inv_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT ck_inv_qty_non_negative CHECK (quantity >= 0)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='库存';
|
||
|
||
CREATE TABLE IF NOT EXISTS product_images (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
product_id BIGINT UNSIGNED NOT NULL,
|
||
url VARCHAR(512) NOT NULL,
|
||
hash VARCHAR(64) NULL COMMENT '内容哈希(去重)',
|
||
sort_order INT NOT NULL DEFAULT 0,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_product_image_hash (product_id, hash),
|
||
KEY idx_product_images_product (product_id),
|
||
CONSTRAINT fk_pimg_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_pimg_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT fk_pimg_product FOREIGN KEY (product_id) REFERENCES products(id) ON DELETE CASCADE
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='商品图片';
|
||
|
||
-- =====================================================================
|
||
-- 往来单位与账户
|
||
-- =====================================================================
|
||
|
||
CREATE TABLE IF NOT EXISTS customers (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
name VARCHAR(120) NOT NULL,
|
||
phone VARCHAR(32) NULL,
|
||
level VARCHAR(32) NULL COMMENT '客户等级标签',
|
||
price_level ENUM('retail','distribution','wholesale','big_client') NOT NULL DEFAULT 'retail' COMMENT '默认售价列',
|
||
status TINYINT UNSIGNED NOT NULL DEFAULT 1,
|
||
remark VARCHAR(255) NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
KEY idx_customers_shop (shop_id),
|
||
KEY idx_customers_phone (phone),
|
||
CONSTRAINT fk_customers_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_customers_user FOREIGN KEY (user_id) REFERENCES users(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='客户';
|
||
|
||
CREATE TABLE IF NOT EXISTS suppliers (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
name VARCHAR(120) NOT NULL,
|
||
phone VARCHAR(32) NULL,
|
||
status TINYINT UNSIGNED NOT NULL DEFAULT 1,
|
||
remark VARCHAR(255) NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
KEY idx_suppliers_shop (shop_id),
|
||
KEY idx_suppliers_phone (phone),
|
||
CONSTRAINT fk_suppliers_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_suppliers_user FOREIGN KEY (user_id) REFERENCES users(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='供应商';
|
||
|
||
CREATE TABLE IF NOT EXISTS accounts (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
name VARCHAR(64) NOT NULL,
|
||
`type` ENUM('cash','bank','alipay','wechat','other') NOT NULL DEFAULT 'cash',
|
||
balance DECIMAL(18,2) NOT NULL DEFAULT 0,
|
||
status TINYINT UNSIGNED NOT NULL DEFAULT 1,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_accounts_shop_name (shop_id, name),
|
||
KEY idx_accounts_shop (shop_id),
|
||
CONSTRAINT fk_accounts_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_accounts_user FOREIGN KEY (user_id) REFERENCES users(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='结算账户';
|
||
|
||
-- =====================================================================
|
||
-- 单据域(销售/进货/其他收支/流水)
|
||
-- =====================================================================
|
||
|
||
CREATE TABLE IF NOT EXISTS sales_orders (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL COMMENT '创建人',
|
||
customer_id BIGINT UNSIGNED NULL,
|
||
order_no VARCHAR(32) NOT NULL,
|
||
order_time DATETIME NOT NULL,
|
||
status ENUM('draft','approved','returned','void') NOT NULL DEFAULT 'draft',
|
||
amount DECIMAL(18,2) NOT NULL DEFAULT 0 COMMENT '应收合计',
|
||
paid_amount DECIMAL(18,2) NOT NULL DEFAULT 0 COMMENT '已收合计',
|
||
remark VARCHAR(255) NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_sales_order_no (shop_id, order_no),
|
||
KEY idx_sales_shop_time (shop_id, order_time),
|
||
KEY idx_sales_customer (customer_id),
|
||
CONSTRAINT fk_sales_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_sales_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT fk_sales_customer FOREIGN KEY (customer_id) REFERENCES customers(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='销售单';
|
||
|
||
CREATE TABLE IF NOT EXISTS sales_order_items (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
order_id BIGINT UNSIGNED NOT NULL,
|
||
product_id BIGINT UNSIGNED NOT NULL,
|
||
quantity DECIMAL(18,3) NOT NULL,
|
||
unit_price DECIMAL(18,2) NOT NULL,
|
||
discount_rate DECIMAL(5,2) NOT NULL DEFAULT 0 COMMENT '折扣百分比0-100',
|
||
amount DECIMAL(18,2) NOT NULL,
|
||
PRIMARY KEY (id),
|
||
KEY idx_soi_order (order_id),
|
||
KEY idx_soi_product (product_id),
|
||
CONSTRAINT fk_soi_order FOREIGN KEY (order_id) REFERENCES sales_orders(id) ON DELETE CASCADE,
|
||
CONSTRAINT fk_soi_product FOREIGN KEY (product_id) REFERENCES products(id),
|
||
CONSTRAINT ck_soi_qty CHECK (quantity > 0),
|
||
CONSTRAINT ck_soi_price CHECK (unit_price >= 0),
|
||
CONSTRAINT ck_soi_discount CHECK (discount_rate >= 0 AND discount_rate <= 100)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='销售单明细';
|
||
|
||
CREATE TABLE IF NOT EXISTS purchase_orders (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
supplier_id BIGINT UNSIGNED NULL,
|
||
order_no VARCHAR(32) NOT NULL,
|
||
order_time DATETIME NOT NULL,
|
||
status ENUM('draft','approved','void') NOT NULL DEFAULT 'draft',
|
||
amount DECIMAL(18,2) NOT NULL DEFAULT 0 COMMENT '应付合计',
|
||
paid_amount DECIMAL(18,2) NOT NULL DEFAULT 0 COMMENT '已付合计',
|
||
remark VARCHAR(255) NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_purchase_order_no (shop_id, order_no),
|
||
KEY idx_purchase_shop_time (shop_id, order_time),
|
||
KEY idx_purchase_supplier (supplier_id),
|
||
CONSTRAINT fk_purchase_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_purchase_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT fk_purchase_supplier FOREIGN KEY (supplier_id) REFERENCES suppliers(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='进货单';
|
||
|
||
CREATE TABLE IF NOT EXISTS purchase_order_items (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
order_id BIGINT UNSIGNED NOT NULL,
|
||
product_id BIGINT UNSIGNED NOT NULL,
|
||
quantity DECIMAL(18,3) NOT NULL,
|
||
unit_price DECIMAL(18,2) NOT NULL,
|
||
amount DECIMAL(18,2) NOT NULL,
|
||
PRIMARY KEY (id),
|
||
KEY idx_poi_order (order_id),
|
||
KEY idx_poi_product (product_id),
|
||
CONSTRAINT fk_poi_order FOREIGN KEY (order_id) REFERENCES purchase_orders(id) ON DELETE CASCADE,
|
||
CONSTRAINT fk_poi_product FOREIGN KEY (product_id) REFERENCES products(id),
|
||
CONSTRAINT ck_poi_qty CHECK (quantity > 0),
|
||
CONSTRAINT ck_poi_price CHECK (unit_price >= 0)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='进货单明细';
|
||
|
||
CREATE TABLE IF NOT EXISTS payments (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
biz_type ENUM('sale','purchase','other') NOT NULL,
|
||
biz_id BIGINT UNSIGNED NULL COMMENT '业务表ID:sales_orders/purchase_orders/other_transactions',
|
||
account_id BIGINT UNSIGNED NOT NULL,
|
||
direction ENUM('in','out') NOT NULL COMMENT '收款/付款',
|
||
amount DECIMAL(18,2) NOT NULL,
|
||
pay_time DATETIME NOT NULL,
|
||
remark VARCHAR(255) NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (id),
|
||
KEY idx_payments_shop_time (shop_id, pay_time),
|
||
KEY idx_payments_biz (biz_type, biz_id),
|
||
CONSTRAINT fk_payments_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_payments_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT fk_payments_account FOREIGN KEY (account_id) REFERENCES accounts(id),
|
||
CONSTRAINT ck_payments_amount CHECK (amount > 0)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='收付款记录';
|
||
|
||
CREATE TABLE IF NOT EXISTS other_transactions (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
`type` ENUM('income','expense') NOT NULL,
|
||
category VARCHAR(64) NOT NULL,
|
||
counterparty_type VARCHAR(32) NULL COMMENT 'customer/supplier/other',
|
||
counterparty_id BIGINT UNSIGNED NULL,
|
||
account_id BIGINT UNSIGNED NOT NULL,
|
||
amount DECIMAL(18,2) NOT NULL,
|
||
tx_time DATETIME NOT NULL,
|
||
remark VARCHAR(255) NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
KEY idx_ot_shop_time (shop_id, tx_time),
|
||
KEY idx_ot_account (account_id),
|
||
CONSTRAINT fk_ot_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_ot_user FOREIGN KEY (user_id) REFERENCES users(id),
|
||
CONSTRAINT fk_ot_account FOREIGN KEY (account_id) REFERENCES accounts(id),
|
||
CONSTRAINT ck_ot_amount CHECK (amount > 0)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='其他收入/支出';
|
||
|
||
-- =====================================================================
|
||
-- 配件查询与审核、附件
|
||
-- =====================================================================
|
||
|
||
CREATE TABLE IF NOT EXISTS part_submissions (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NOT NULL,
|
||
user_id BIGINT UNSIGNED NOT NULL,
|
||
model_unique VARCHAR(128) NOT NULL COMMENT '型号(唯一)',
|
||
brand VARCHAR(64) NULL,
|
||
spec VARCHAR(128) NULL,
|
||
size VARCHAR(64) NULL,
|
||
aperture VARCHAR(64) NULL,
|
||
compatible TEXT NULL COMMENT '适配信息',
|
||
status ENUM('draft','pending','rejected','published') NOT NULL DEFAULT 'pending',
|
||
reason VARCHAR(255) NULL COMMENT '驳回原因',
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
deleted_at DATETIME NULL,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_part_model_unique (model_unique),
|
||
KEY idx_part_submissions_shop (shop_id),
|
||
CONSTRAINT fk_part_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_part_user FOREIGN KEY (user_id) REFERENCES users(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='配件数据提交(审核)';
|
||
|
||
CREATE TABLE IF NOT EXISTS attachments (
|
||
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||
shop_id BIGINT UNSIGNED NULL COMMENT '全局资源可空,本地资源属于租户',
|
||
user_id BIGINT UNSIGNED NULL,
|
||
owner_type VARCHAR(32) NOT NULL COMMENT '资源归属类型:product/part_submission/global_sku/...',
|
||
owner_id BIGINT UNSIGNED NOT NULL,
|
||
url VARCHAR(512) NOT NULL,
|
||
hash VARCHAR(64) NULL,
|
||
meta JSON NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (id),
|
||
UNIQUE KEY ux_attachments_hash (hash),
|
||
KEY idx_attachments_owner (owner_type, owner_id),
|
||
CONSTRAINT fk_att_shop FOREIGN KEY (shop_id) REFERENCES shops(id),
|
||
CONSTRAINT fk_att_user FOREIGN KEY (user_id) REFERENCES users(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='通用附件(图片等)';
|
||
|
||
-- =====================================================================
|
||
-- 触发器:维护 products.search_text 聚合字段
|
||
-- =====================================================================
|
||
|
||
DROP TRIGGER IF EXISTS trg_products_ai;
|
||
DELIMITER $$
|
||
CREATE TRIGGER trg_products_ai AFTER INSERT ON products
|
||
FOR EACH ROW
|
||
BEGIN
|
||
UPDATE products
|
||
SET search_text = CONCAT_WS(' ', NEW.name, NEW.brand, NEW.model, NEW.spec)
|
||
WHERE id = NEW.id;
|
||
END $$
|
||
DELIMITER ;
|
||
|
||
DROP TRIGGER IF EXISTS trg_products_au;
|
||
DELIMITER $$
|
||
CREATE TRIGGER trg_products_au BEFORE UPDATE ON products
|
||
FOR EACH ROW
|
||
BEGIN
|
||
SET NEW.search_text = CONCAT_WS(' ', NEW.name, NEW.brand, NEW.model, NEW.spec);
|
||
END $$
|
||
DELIMITER ;
|
||
|
||
-- 当别名变化时重建 search_text(名称/品牌/型号/规格 + 所有别名)
|
||
DROP TRIGGER IF EXISTS trg_palias_ai;
|
||
DELIMITER $$
|
||
CREATE TRIGGER trg_palias_ai AFTER INSERT ON product_aliases
|
||
FOR EACH ROW
|
||
BEGIN
|
||
UPDATE products p
|
||
JOIN (
|
||
SELECT pa.product_id, GROUP_CONCAT(pa.alias SEPARATOR ' ') AS aliases
|
||
FROM product_aliases pa
|
||
WHERE pa.product_id = NEW.product_id AND pa.deleted_at IS NULL
|
||
GROUP BY pa.product_id
|
||
) a ON a.product_id = p.id
|
||
SET p.search_text = CONCAT_WS(' ', p.name, p.brand, p.model, p.spec, a.aliases)
|
||
WHERE p.id = NEW.product_id;
|
||
END $$
|
||
DELIMITER ;
|
||
|
||
DROP TRIGGER IF EXISTS trg_palias_au;
|
||
DELIMITER $$
|
||
CREATE TRIGGER trg_palias_au AFTER UPDATE ON product_aliases
|
||
FOR EACH ROW
|
||
BEGIN
|
||
UPDATE products p
|
||
JOIN (
|
||
SELECT pa.product_id, GROUP_CONCAT(pa.alias SEPARATOR ' ') AS aliases
|
||
FROM product_aliases pa
|
||
WHERE pa.product_id = NEW.product_id AND pa.deleted_at IS NULL
|
||
GROUP BY pa.product_id
|
||
) a ON a.product_id = p.id
|
||
SET p.search_text = CONCAT_WS(' ', p.name, p.brand, p.model, p.spec, a.aliases)
|
||
WHERE p.id = NEW.product_id;
|
||
END $$
|
||
DELIMITER ;
|
||
|
||
DROP TRIGGER IF EXISTS trg_palias_ad;
|
||
DELIMITER $$
|
||
CREATE TRIGGER trg_palias_ad AFTER DELETE ON product_aliases
|
||
FOR EACH ROW
|
||
BEGIN
|
||
UPDATE products p
|
||
LEFT JOIN (
|
||
SELECT pa.product_id, GROUP_CONCAT(pa.alias SEPARATOR ' ') AS aliases
|
||
FROM product_aliases pa
|
||
WHERE pa.product_id = OLD.product_id AND pa.deleted_at IS NULL
|
||
GROUP BY pa.product_id
|
||
) a ON a.product_id = p.id
|
||
SET p.search_text = CONCAT_WS(' ', p.name, p.brand, p.model, p.spec, COALESCE(a.aliases, ''))
|
||
WHERE p.id = OLD.product_id;
|
||
END $$
|
||
DELIMITER ;
|
||
|
||
SET FOREIGN_KEY_CHECKS = 1;
|
||
|
||
|