Files
niumalll/docs/数据库设计.md

1059 lines
37 KiB
Markdown
Raw Normal View History

# 活牛采购智能数字化系统 - 数据库设计
## 版本历史
| 版本 | 日期 | 作者 | 变更说明 |
|------|------|------|----------|
| v1.0 | 2024-12-20 | 数据库架构师 | 初版数据库设计文档 |
## 1. 数据库概览
### 1.1 设计原则
- **规范化设计**:遵循第三范式,减少数据冗余
- **性能优化**:合理设计索引,优化查询性能
- **扩展性**:支持业务扩展和数据增长
- **一致性**:保证数据完整性和事务一致性
- **安全性**:敏感数据加密存储
### 1.2 数据库架构
```mermaid
graph TB
A[应用层] --> B[数据访问层<br/>Sequelize ORM]
B --> C[主数据库<br/>MySQL Master]
B --> D[从数据库<br/>MySQL Slave]
B --> E[缓存层<br/>Redis]
B --> F[文件存储<br/>MinIO]
C --> G[用户数据]
C --> H[订单数据]
C --> I[运输数据]
C --> J[财务数据]
E --> K[会话缓存]
E --> L[查询缓存]
E --> M[计数器缓存]
```
### 1.3 数据库配置
| 配置项 | 值 | 说明 |
|--------|----|----- |
| 数据库版本 | MySQL 8.0+ | 支持JSON字段、窗口函数等新特性 |
| 字符集 | utf8mb4 | 支持完整的UTF-8字符集包括emoji |
| 排序规则 | utf8mb4_unicode_ci | 支持多语言排序 |
| 存储引擎 | InnoDB | 支持事务、外键约束 |
| 时区 | UTC | 统一使用UTC时间 |
## 2. 数据表设计
### 2.1 用户管理模块
#### 2.1.1 用户基础表 (users)
```sql
CREATE TABLE users (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '用户ID',
phone VARCHAR(20) UNIQUE NOT NULL COMMENT '手机号',
password VARCHAR(255) NOT NULL COMMENT '密码哈希',
name VARCHAR(100) NOT NULL COMMENT '姓名',
role ENUM('client', 'supplier', 'driver', 'trader', 'admin') NOT NULL COMMENT '用户角色',
status ENUM('active', 'inactive', 'banned') DEFAULT 'active' COMMENT '用户状态',
avatar VARCHAR(500) COMMENT '头像URL',
last_login_at TIMESTAMP NULL COMMENT '最后登录时间',
login_count INT DEFAULT 0 COMMENT '登录次数',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
INDEX idx_phone (phone),
INDEX idx_role (role),
INDEX idx_status (status),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户基础表';
```
**字段说明**
- `role`:用户角色,支持采购人、供应商、司机、贸易商、管理员
- `status`:用户状态,支持激活、未激活、禁用
- `password`使用bcrypt加密存储
#### 2.1.2 用户详情表 (user_profiles)
```sql
CREATE TABLE user_profiles (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '详情ID',
user_id BIGINT NOT NULL COMMENT '用户ID',
company_name VARCHAR(200) COMMENT '公司名称',
business_license VARCHAR(500) COMMENT '营业执照URL',
license_number VARCHAR(100) COMMENT '营业执照号',
legal_person VARCHAR(100) COMMENT '法人代表',
contact_address TEXT COMMENT '联系地址',
emergency_contact VARCHAR(100) COMMENT '紧急联系人',
emergency_phone VARCHAR(20) COMMENT '紧急联系电话',
bank_account VARCHAR(50) COMMENT '银行账号',
bank_name VARCHAR(200) COMMENT '开户银行',
tax_number VARCHAR(50) COMMENT '税号',
qualification_docs JSON COMMENT '资质文件JSON',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
UNIQUE KEY uk_user_id (user_id),
INDEX idx_company_name (company_name),
INDEX idx_license_number (license_number)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户详情表';
```
#### 2.1.3 用户认证表 (user_tokens)
```sql
CREATE TABLE user_tokens (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT 'Token ID',
user_id BIGINT NOT NULL COMMENT '用户ID',
token_type ENUM('access', 'refresh', 'reset_password') NOT NULL COMMENT 'Token类型',
token_hash VARCHAR(255) NOT NULL COMMENT 'Token哈希值',
expires_at TIMESTAMP NOT NULL COMMENT '过期时间',
is_revoked BOOLEAN DEFAULT FALSE COMMENT '是否已撤销',
device_info JSON COMMENT '设备信息',
ip_address VARCHAR(45) COMMENT 'IP地址',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
INDEX idx_user_id (user_id),
INDEX idx_token_hash (token_hash),
INDEX idx_expires_at (expires_at),
INDEX idx_token_type (token_type)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户认证Token表';
```
### 2.2 订单管理模块
#### 2.2.1 订单主表 (orders)
```sql
CREATE TABLE orders (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '订单ID',
order_no VARCHAR(50) UNIQUE NOT NULL COMMENT '订单号',
client_id BIGINT NOT NULL COMMENT '采购人ID',
trader_id BIGINT COMMENT '贸易商ID',
supplier_id BIGINT COMMENT '供应商ID',
-- 牛只信息
cattle_type VARCHAR(50) NOT NULL COMMENT '牛只品种',
quantity INT NOT NULL COMMENT '数量(头)',
weight_range VARCHAR(50) COMMENT '重量范围',
estimated_weight DECIMAL(8,2) COMMENT '预估总重量kg',
actual_weight DECIMAL(8,2) COMMENT '实际总重量kg',
-- 价格信息
unit_price DECIMAL(10,2) NOT NULL COMMENT '单价(元/kg或元/头)',
price_type ENUM('per_kg', 'per_head') DEFAULT 'per_kg' COMMENT '计价方式',
total_amount DECIMAL(12,2) NOT NULL COMMENT '订单总金额',
prepaid_amount DECIMAL(12,2) DEFAULT 0 COMMENT '预付金额',
final_amount DECIMAL(12,2) COMMENT '最终结算金额',
-- 交付信息
pickup_address TEXT COMMENT '取货地址',
delivery_address TEXT NOT NULL COMMENT '交货地址',
pickup_time DATETIME COMMENT '取货时间',
delivery_time DATETIME COMMENT '要求交货时间',
actual_delivery_time DATETIME COMMENT '实际交货时间',
-- 状态信息
status ENUM('draft', 'pending', 'confirmed', 'preparing', 'loading', 'transporting', 'arrived', 'inspecting', 'accepted', 'completed', 'cancelled') DEFAULT 'draft' COMMENT '订单状态',
cancel_reason TEXT COMMENT '取消原因',
-- 特殊要求
special_requirements TEXT COMMENT '特殊要求',
quality_standards JSON COMMENT '质量标准JSON',
-- 时间戳
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
confirmed_at TIMESTAMP NULL COMMENT '确认时间',
completed_at TIMESTAMP NULL COMMENT '完成时间',
FOREIGN KEY (client_id) REFERENCES users(id),
FOREIGN KEY (trader_id) REFERENCES users(id),
FOREIGN KEY (supplier_id) REFERENCES users(id),
INDEX idx_order_no (order_no),
INDEX idx_client_id (client_id),
INDEX idx_trader_id (trader_id),
INDEX idx_supplier_id (supplier_id),
INDEX idx_status (status),
INDEX idx_created_at (created_at),
INDEX idx_delivery_time (delivery_time),
INDEX idx_cattle_type (cattle_type)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单主表';
```
#### 2.2.2 订单状态变更记录表 (order_status_logs)
```sql
CREATE TABLE order_status_logs (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '记录ID',
order_id BIGINT NOT NULL COMMENT '订单ID',
from_status VARCHAR(50) COMMENT '原状态',
to_status VARCHAR(50) NOT NULL COMMENT '新状态',
operator_id BIGINT COMMENT '操作人ID',
operator_role VARCHAR(50) COMMENT '操作人角色',
remark TEXT COMMENT '备注说明',
extra_data JSON COMMENT '额外数据',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
FOREIGN KEY (order_id) REFERENCES orders(id) ON DELETE CASCADE,
FOREIGN KEY (operator_id) REFERENCES users(id),
INDEX idx_order_id (order_id),
INDEX idx_operator_id (operator_id),
INDEX idx_created_at (created_at),
INDEX idx_to_status (to_status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单状态变更记录表';
```
#### 2.2.3 订单附件表 (order_attachments)
```sql
CREATE TABLE order_attachments (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '附件ID',
order_id BIGINT NOT NULL COMMENT '订单ID',
file_name VARCHAR(255) NOT NULL COMMENT '文件名',
file_url VARCHAR(500) NOT NULL COMMENT '文件URL',
file_type VARCHAR(50) NOT NULL COMMENT '文件类型',
file_size BIGINT COMMENT '文件大小(字节)',
attachment_type ENUM('contract', 'certificate', 'photo', 'video', 'other') NOT NULL COMMENT '附件类型',
uploader_id BIGINT NOT NULL COMMENT '上传人ID',
description TEXT COMMENT '文件描述',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
FOREIGN KEY (order_id) REFERENCES orders(id) ON DELETE CASCADE,
FOREIGN KEY (uploader_id) REFERENCES users(id),
INDEX idx_order_id (order_id),
INDEX idx_attachment_type (attachment_type),
INDEX idx_uploader_id (uploader_id),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单附件表';
```
### 2.3 运输管理模块
#### 2.3.1 运输任务表 (transport_tasks)
```sql
CREATE TABLE transport_tasks (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '任务ID',
task_no VARCHAR(50) UNIQUE NOT NULL COMMENT '任务编号',
order_id BIGINT NOT NULL COMMENT '订单ID',
driver_id BIGINT NOT NULL COMMENT '司机ID',
-- 车辆信息
vehicle_no VARCHAR(20) NOT NULL COMMENT '车牌号',
vehicle_type VARCHAR(50) COMMENT '车辆类型',
vehicle_capacity DECIMAL(8,2) COMMENT '载重量(吨)',
driver_license VARCHAR(50) COMMENT '驾驶证号',
-- 路线信息
start_location VARCHAR(200) COMMENT '起始地点',
end_location VARCHAR(200) COMMENT '目的地点',
start_latitude DECIMAL(10,6) COMMENT '起始纬度',
start_longitude DECIMAL(10,6) COMMENT '起始经度',
end_latitude DECIMAL(10,6) COMMENT '目的纬度',
end_longitude DECIMAL(10,6) COMMENT '目的经度',
planned_distance DECIMAL(8,2) COMMENT '计划距离(公里)',
actual_distance DECIMAL(8,2) COMMENT '实际距离(公里)',
-- 时间信息
planned_start_time DATETIME COMMENT '计划开始时间',
actual_start_time DATETIME COMMENT '实际开始时间',
planned_end_time DATETIME COMMENT '计划结束时间',
actual_end_time DATETIME COMMENT '实际结束时间',
estimated_arrival_time DATETIME COMMENT '预计到达时间',
-- 状态信息
status ENUM('assigned', 'preparing', 'loading', 'started', 'transporting', 'arrived', 'unloading', 'completed', 'cancelled') DEFAULT 'assigned' COMMENT '任务状态',
-- 运输费用
transport_fee DECIMAL(10,2) COMMENT '运输费用',
fuel_cost DECIMAL(10,2) COMMENT '燃油费用',
toll_cost DECIMAL(10,2) COMMENT '过路费',
other_cost DECIMAL(10,2) COMMENT '其他费用',
-- 备注信息
notes TEXT COMMENT '备注',
cancel_reason TEXT COMMENT '取消原因',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
FOREIGN KEY (order_id) REFERENCES orders(id),
FOREIGN KEY (driver_id) REFERENCES users(id),
INDEX idx_task_no (task_no),
INDEX idx_order_id (order_id),
INDEX idx_driver_id (driver_id),
INDEX idx_vehicle_no (vehicle_no),
INDEX idx_status (status),
INDEX idx_planned_start_time (planned_start_time),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='运输任务表';
```
#### 2.3.2 位置跟踪表 (location_tracks)
```sql
CREATE TABLE location_tracks (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '跟踪ID',
task_id BIGINT NOT NULL COMMENT '任务ID',
latitude DECIMAL(10,6) NOT NULL COMMENT '纬度',
longitude DECIMAL(10,6) NOT NULL COMMENT '经度',
altitude DECIMAL(8,2) COMMENT '海拔(米)',
accuracy DECIMAL(8,2) COMMENT '精度(米)',
speed DECIMAL(5,2) COMMENT '速度km/h',
direction DECIMAL(5,2) COMMENT '方向角(度)',
address VARCHAR(500) COMMENT '地址描述',
-- 状态信息
cattle_status ENUM('normal', 'stressed', 'sick', 'dead') DEFAULT 'normal' COMMENT '牛只状态',
temperature DECIMAL(4,1) COMMENT '温度(摄氏度)',
humidity DECIMAL(5,2) COMMENT '湿度(%',
-- 时间信息
recorded_at TIMESTAMP NOT NULL COMMENT '记录时间',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
FOREIGN KEY (task_id) REFERENCES transport_tasks(id) ON DELETE CASCADE,
INDEX idx_task_id (task_id),
INDEX idx_recorded_at (recorded_at),
INDEX idx_location (latitude, longitude),
INDEX idx_cattle_status (cattle_status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='位置跟踪表'
PARTITION BY RANGE (YEAR(recorded_at)) (
PARTITION p2024 VALUES LESS THAN (2025),
PARTITION p2025 VALUES LESS THAN (2026),
PARTITION p_future VALUES LESS THAN MAXVALUE
);
```
#### 2.3.3 运输事件表 (transport_events)
```sql
CREATE TABLE transport_events (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '事件ID',
task_id BIGINT NOT NULL COMMENT '任务ID',
event_type ENUM('loading_start', 'loading_complete', 'departure', 'rest_stop', 'refuel', 'accident', 'breakdown', 'arrival', 'unloading_start', 'unloading_complete', 'emergency') NOT NULL COMMENT '事件类型',
event_title VARCHAR(200) NOT NULL COMMENT '事件标题',
event_description TEXT COMMENT '事件描述',
-- 位置信息
latitude DECIMAL(10,6) COMMENT '事件发生纬度',
longitude DECIMAL(10,6) COMMENT '事件发生经度',
address VARCHAR(500) COMMENT '事件发生地址',
-- 附件信息
photos JSON COMMENT '照片URLs',
videos JSON COMMENT '视频URLs',
documents JSON COMMENT '文档URLs',
-- 处理信息
severity ENUM('low', 'medium', 'high', 'critical') DEFAULT 'low' COMMENT '严重程度',
is_resolved BOOLEAN DEFAULT FALSE COMMENT '是否已解决',
resolution TEXT COMMENT '解决方案',
resolver_id BIGINT COMMENT '处理人ID',
resolved_at TIMESTAMP NULL COMMENT '解决时间',
reporter_id BIGINT NOT NULL COMMENT '报告人ID',
occurred_at TIMESTAMP NOT NULL COMMENT '发生时间',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
FOREIGN KEY (task_id) REFERENCES transport_tasks(id) ON DELETE CASCADE,
FOREIGN KEY (reporter_id) REFERENCES users(id),
FOREIGN KEY (resolver_id) REFERENCES users(id),
INDEX idx_task_id (task_id),
INDEX idx_event_type (event_type),
INDEX idx_severity (severity),
INDEX idx_is_resolved (is_resolved),
INDEX idx_occurred_at (occurred_at),
INDEX idx_reporter_id (reporter_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='运输事件表';
```
### 2.4 质量管理模块
#### 2.4.1 牛只信息表 (cattle_info)
```sql
CREATE TABLE cattle_info (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '牛只ID',
order_id BIGINT NOT NULL COMMENT '订单ID',
supplier_id BIGINT NOT NULL COMMENT '供应商ID',
-- 基本信息
cattle_no VARCHAR(50) COMMENT '牛只编号',
breed VARCHAR(50) NOT NULL COMMENT '品种',
gender ENUM('male', 'female') NOT NULL COMMENT '性别',
age_months INT COMMENT '月龄',
weight DECIMAL(6,2) COMMENT '重量kg',
height DECIMAL(5,2) COMMENT '体高cm',
body_length DECIMAL(5,2) COMMENT '体长cm',
-- 健康信息
health_status ENUM('healthy', 'sick', 'quarantine', 'dead') DEFAULT 'healthy' COMMENT '健康状态',
vaccination_records JSON COMMENT '疫苗记录',
medical_history JSON COMMENT '病史记录',
quarantine_certificate VARCHAR(500) COMMENT '检疫证明URL',
-- 质量评级
quality_grade ENUM('A', 'B', 'C', 'D') COMMENT '质量等级',
meat_quality_score DECIMAL(3,1) COMMENT '肉质评分',
appearance_score DECIMAL(3,1) COMMENT '外观评分',
health_score DECIMAL(3,1) COMMENT '健康评分',
-- 来源信息
origin_farm VARCHAR(200) COMMENT '来源农场',
origin_address TEXT COMMENT '来源地址',
birth_date DATE COMMENT '出生日期',
parent_info JSON COMMENT '父母信息',
-- 状态信息
status ENUM('registered', 'prepared', 'loaded', 'transported', 'delivered', 'accepted', 'rejected') DEFAULT 'registered' COMMENT '状态',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
FOREIGN KEY (order_id) REFERENCES orders(id) ON DELETE CASCADE,
FOREIGN KEY (supplier_id) REFERENCES users(id),
INDEX idx_order_id (order_id),
INDEX idx_supplier_id (supplier_id),
INDEX idx_cattle_no (cattle_no),
INDEX idx_breed (breed),
INDEX idx_health_status (health_status),
INDEX idx_quality_grade (quality_grade),
INDEX idx_status (status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='牛只信息表';
```
#### 2.4.2 质量检验记录表 (quality_inspections)
```sql
CREATE TABLE quality_inspections (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '检验ID',
order_id BIGINT NOT NULL COMMENT '订单ID',
inspector_id BIGINT NOT NULL COMMENT '检验员ID',
inspection_type ENUM('pre_loading', 'during_transport', 'post_delivery') NOT NULL COMMENT '检验类型',
-- 检验结果
total_count INT NOT NULL COMMENT '总数量',
qualified_count INT NOT NULL COMMENT '合格数量',
unqualified_count INT NOT NULL COMMENT '不合格数量',
dead_count INT DEFAULT 0 COMMENT '死亡数量',
sick_count INT DEFAULT 0 COMMENT '患病数量',
-- 重量信息
total_weight DECIMAL(8,2) COMMENT '总重量',
average_weight DECIMAL(6,2) COMMENT '平均重量',
weight_variance DECIMAL(6,2) COMMENT '重量方差',
-- 质量评估
overall_grade ENUM('A', 'B', 'C', 'D') COMMENT '整体等级',
quality_score DECIMAL(4,2) COMMENT '质量评分',
health_score DECIMAL(4,2) COMMENT '健康评分',
appearance_score DECIMAL(4,2) COMMENT '外观评分',
-- 检验详情
inspection_items JSON COMMENT '检验项目详情',
defect_details JSON COMMENT '缺陷详情',
photos JSON COMMENT '检验照片',
videos JSON COMMENT '检验视频',
-- 结论
is_passed BOOLEAN NOT NULL COMMENT '是否通过检验',
rejection_reason TEXT COMMENT '拒收原因',
recommendations TEXT COMMENT '建议',
inspection_date DATETIME NOT NULL COMMENT '检验时间',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
FOREIGN KEY (order_id) REFERENCES orders(id) ON DELETE CASCADE,
FOREIGN KEY (inspector_id) REFERENCES users(id),
INDEX idx_order_id (order_id),
INDEX idx_inspector_id (inspector_id),
INDEX idx_inspection_type (inspection_type),
INDEX idx_is_passed (is_passed),
INDEX idx_inspection_date (inspection_date),
INDEX idx_overall_grade (overall_grade)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='质量检验记录表';
```
### 2.5 财务管理模块
#### 2.5.1 财务结算表 (financial_settlements)
```sql
CREATE TABLE financial_settlements (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '结算ID',
settlement_no VARCHAR(50) UNIQUE NOT NULL COMMENT '结算单号',
order_id BIGINT NOT NULL COMMENT '订单ID',
-- 结算金额
order_amount DECIMAL(12,2) NOT NULL COMMENT '订单金额',
prepaid_amount DECIMAL(12,2) DEFAULT 0 COMMENT '预付金额',
transport_fee DECIMAL(10,2) DEFAULT 0 COMMENT '运输费用',
insurance_fee DECIMAL(10,2) DEFAULT 0 COMMENT '保险费用',
service_fee DECIMAL(10,2) DEFAULT 0 COMMENT '服务费',
penalty_amount DECIMAL(10,2) DEFAULT 0 COMMENT '违约金',
discount_amount DECIMAL(10,2) DEFAULT 0 COMMENT '优惠金额',
tax_amount DECIMAL(10,2) DEFAULT 0 COMMENT '税费',
final_amount DECIMAL(12,2) NOT NULL COMMENT '最终结算金额',
-- 结算方式
settlement_type ENUM('full_payment', 'partial_payment', 'installment') DEFAULT 'full_payment' COMMENT '结算方式',
payment_terms VARCHAR(200) COMMENT '付款条件',
-- 状态信息
status ENUM('draft', 'pending', 'approved', 'paid', 'cancelled') DEFAULT 'draft' COMMENT '结算状态',
-- 审批信息
approver_id BIGINT COMMENT '审批人ID',
approved_at TIMESTAMP NULL COMMENT '审批时间',
approval_notes TEXT COMMENT '审批备注',
-- 时间信息
settlement_date DATE NOT NULL COMMENT '结算日期',
due_date DATE COMMENT '付款截止日期',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
FOREIGN KEY (order_id) REFERENCES orders(id),
FOREIGN KEY (approver_id) REFERENCES users(id),
INDEX idx_settlement_no (settlement_no),
INDEX idx_order_id (order_id),
INDEX idx_status (status),
INDEX idx_settlement_date (settlement_date),
INDEX idx_due_date (due_date),
INDEX idx_approver_id (approver_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='财务结算表';
```
#### 2.5.2 支付记录表 (payment_records)
```sql
CREATE TABLE payment_records (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '支付ID',
payment_no VARCHAR(50) UNIQUE NOT NULL COMMENT '支付单号',
settlement_id BIGINT NOT NULL COMMENT '结算ID',
order_id BIGINT NOT NULL COMMENT '订单ID',
payer_id BIGINT NOT NULL COMMENT '付款人ID',
payee_id BIGINT NOT NULL COMMENT '收款人ID',
-- 支付金额
payment_amount DECIMAL(12,2) NOT NULL COMMENT '支付金额',
currency VARCHAR(10) DEFAULT 'CNY' COMMENT '货币类型',
-- 支付方式
payment_method ENUM('bank_transfer', 'alipay', 'wechat_pay', 'cash', 'check', 'other') NOT NULL COMMENT '支付方式',
payment_channel VARCHAR(100) COMMENT '支付渠道',
-- 第三方支付信息
third_party_order_no VARCHAR(100) COMMENT '第三方订单号',
third_party_transaction_id VARCHAR(100) COMMENT '第三方交易ID',
-- 银行信息
payer_bank_account VARCHAR(50) COMMENT '付款账户',
payer_bank_name VARCHAR(200) COMMENT '付款银行',
payee_bank_account VARCHAR(50) COMMENT '收款账户',
payee_bank_name VARCHAR(200) COMMENT '收款银行',
-- 状态信息
status ENUM('pending', 'processing', 'success', 'failed', 'cancelled', 'refunded') DEFAULT 'pending' COMMENT '支付状态',
failure_reason TEXT COMMENT '失败原因',
-- 时间信息
payment_time DATETIME COMMENT '支付时间',
confirmed_time DATETIME COMMENT '确认时间',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
-- 备注信息
notes TEXT COMMENT '支付备注',
receipt_url VARCHAR(500) COMMENT '支付凭证URL',
FOREIGN KEY (settlement_id) REFERENCES financial_settlements(id),
FOREIGN KEY (order_id) REFERENCES orders(id),
FOREIGN KEY (payer_id) REFERENCES users(id),
FOREIGN KEY (payee_id) REFERENCES users(id),
INDEX idx_payment_no (payment_no),
INDEX idx_settlement_id (settlement_id),
INDEX idx_order_id (order_id),
INDEX idx_payer_id (payer_id),
INDEX idx_payee_id (payee_id),
INDEX idx_status (status),
INDEX idx_payment_method (payment_method),
INDEX idx_payment_time (payment_time),
INDEX idx_third_party_order_no (third_party_order_no)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='支付记录表';
```
### 2.6 系统管理模块
#### 2.6.1 系统配置表 (system_configs)
```sql
CREATE TABLE system_configs (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '配置ID',
config_key VARCHAR(100) UNIQUE NOT NULL COMMENT '配置键',
config_value TEXT NOT NULL COMMENT '配置值',
config_type ENUM('string', 'number', 'boolean', 'json', 'array') DEFAULT 'string' COMMENT '配置类型',
category VARCHAR(50) NOT NULL COMMENT '配置分类',
description TEXT COMMENT '配置描述',
is_public BOOLEAN DEFAULT FALSE COMMENT '是否公开配置',
is_editable BOOLEAN DEFAULT TRUE COMMENT '是否可编辑',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
INDEX idx_config_key (config_key),
INDEX idx_category (category),
INDEX idx_is_public (is_public)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='系统配置表';
```
#### 2.6.2 操作日志表 (operation_logs)
```sql
CREATE TABLE operation_logs (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '日志ID',
user_id BIGINT COMMENT '操作用户ID',
username VARCHAR(100) COMMENT '用户名',
user_role VARCHAR(50) COMMENT '用户角色',
-- 操作信息
operation_type VARCHAR(50) NOT NULL COMMENT '操作类型',
operation_module VARCHAR(50) NOT NULL COMMENT '操作模块',
operation_description TEXT COMMENT '操作描述',
-- 请求信息
request_method VARCHAR(10) COMMENT '请求方法',
request_url VARCHAR(500) COMMENT '请求URL',
request_params JSON COMMENT '请求参数',
request_body JSON COMMENT '请求体',
-- 响应信息
response_status INT COMMENT '响应状态码',
response_data JSON COMMENT '响应数据',
-- 环境信息
ip_address VARCHAR(45) COMMENT 'IP地址',
user_agent TEXT COMMENT '用户代理',
device_info JSON COMMENT '设备信息',
-- 时间信息
execution_time INT COMMENT '执行时间(毫秒)',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
FOREIGN KEY (user_id) REFERENCES users(id),
INDEX idx_user_id (user_id),
INDEX idx_operation_type (operation_type),
INDEX idx_operation_module (operation_module),
INDEX idx_ip_address (ip_address),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='操作日志表'
PARTITION BY RANGE (YEAR(created_at)) (
PARTITION p2024 VALUES LESS THAN (2025),
PARTITION p2025 VALUES LESS THAN (2026),
PARTITION p_future VALUES LESS THAN MAXVALUE
);
```
#### 2.6.3 消息通知表 (notifications)
```sql
CREATE TABLE notifications (
id BIGINT PRIMARY KEY AUTO_INCREMENT COMMENT '通知ID',
recipient_id BIGINT NOT NULL COMMENT '接收人ID',
sender_id BIGINT COMMENT '发送人ID',
-- 通知内容
title VARCHAR(200) NOT NULL COMMENT '通知标题',
content TEXT NOT NULL COMMENT '通知内容',
notification_type ENUM('system', 'order', 'transport', 'payment', 'quality', 'emergency') NOT NULL COMMENT '通知类型',
priority ENUM('low', 'medium', 'high', 'urgent') DEFAULT 'medium' COMMENT '优先级',
-- 关联信息
related_type VARCHAR(50) COMMENT '关联类型',
related_id BIGINT COMMENT '关联ID',
-- 发送渠道
channels JSON COMMENT '发送渠道app, sms, email, wechat',
-- 状态信息
is_read BOOLEAN DEFAULT FALSE COMMENT '是否已读',
read_at TIMESTAMP NULL COMMENT '阅读时间',
is_sent BOOLEAN DEFAULT FALSE COMMENT '是否已发送',
sent_at TIMESTAMP NULL COMMENT '发送时间',
-- 时间信息
scheduled_at TIMESTAMP COMMENT '计划发送时间',
expires_at TIMESTAMP COMMENT '过期时间',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
FOREIGN KEY (recipient_id) REFERENCES users(id),
FOREIGN KEY (sender_id) REFERENCES users(id),
INDEX idx_recipient_id (recipient_id),
INDEX idx_sender_id (sender_id),
INDEX idx_notification_type (notification_type),
INDEX idx_priority (priority),
INDEX idx_is_read (is_read),
INDEX idx_is_sent (is_sent),
INDEX idx_created_at (created_at),
INDEX idx_scheduled_at (scheduled_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='消息通知表';
```
## 3. 数据库关系图
```mermaid
erDiagram
users ||--o{ user_profiles : "1:1"
users ||--o{ user_tokens : "1:N"
users ||--o{ orders : "client_id"
users ||--o{ orders : "trader_id"
users ||--o{ orders : "supplier_id"
users ||--o{ transport_tasks : "driver_id"
users ||--o{ operation_logs : "user_id"
users ||--o{ notifications : "recipient_id"
orders ||--o{ order_status_logs : "1:N"
orders ||--o{ order_attachments : "1:N"
orders ||--o{ transport_tasks : "1:N"
orders ||--o{ cattle_info : "1:N"
orders ||--o{ quality_inspections : "1:N"
orders ||--o{ financial_settlements : "1:1"
orders ||--o{ payment_records : "1:N"
transport_tasks ||--o{ location_tracks : "1:N"
transport_tasks ||--o{ transport_events : "1:N"
financial_settlements ||--o{ payment_records : "1:N"
users {
bigint id PK
varchar phone UK
varchar password
varchar name
enum role
enum status
varchar avatar
timestamp created_at
timestamp updated_at
}
orders {
bigint id PK
varchar order_no UK
bigint client_id FK
bigint trader_id FK
bigint supplier_id FK
varchar cattle_type
int quantity
decimal unit_price
decimal total_amount
enum status
timestamp created_at
timestamp updated_at
}
transport_tasks {
bigint id PK
varchar task_no UK
bigint order_id FK
bigint driver_id FK
varchar vehicle_no
varchar start_location
varchar end_location
enum status
timestamp created_at
timestamp updated_at
}
location_tracks {
bigint id PK
bigint task_id FK
decimal latitude
decimal longitude
decimal speed
timestamp recorded_at
timestamp created_at
}
```
## 4. 索引优化策略
### 4.1 主要索引设计
#### 4.1.1 单列索引
```sql
-- 用户表索引
CREATE INDEX idx_users_phone ON users(phone);
CREATE INDEX idx_users_role ON users(role);
CREATE INDEX idx_users_status ON users(status);
-- 订单表索引
CREATE INDEX idx_orders_status ON orders(status);
CREATE INDEX idx_orders_created_at ON orders(created_at);
CREATE INDEX idx_orders_cattle_type ON orders(cattle_type);
```
#### 4.1.2 复合索引
```sql
-- 订单查询优化
CREATE INDEX idx_orders_client_status ON orders(client_id, status);
CREATE INDEX idx_orders_supplier_status ON orders(supplier_id, status);
CREATE INDEX idx_orders_status_created ON orders(status, created_at);
-- 位置跟踪查询优化
CREATE INDEX idx_location_task_time ON location_tracks(task_id, recorded_at);
CREATE INDEX idx_location_time_status ON location_tracks(recorded_at, cattle_status);
-- 支付记录查询优化
CREATE INDEX idx_payment_payer_status ON payment_records(payer_id, status);
CREATE INDEX idx_payment_method_time ON payment_records(payment_method, payment_time);
```
#### 4.1.3 覆盖索引
```sql
-- 订单列表查询覆盖索引
CREATE INDEX idx_orders_list_cover ON orders(status, client_id, created_at, order_no, cattle_type, total_amount);
-- 用户基本信息覆盖索引
CREATE INDEX idx_users_basic_cover ON users(id, name, role, status, avatar);
```
### 4.2 分区策略
#### 4.2.1 时间分区
```sql
-- 位置跟踪表按年分区
ALTER TABLE location_tracks PARTITION BY RANGE (YEAR(recorded_at)) (
PARTITION p2024 VALUES LESS THAN (2025),
PARTITION p2025 VALUES LESS THAN (2026),
PARTITION p2026 VALUES LESS THAN (2027),
PARTITION p_future VALUES LESS THAN MAXVALUE
);
-- 操作日志表按月分区
ALTER TABLE operation_logs PARTITION BY RANGE (YEAR(created_at) * 100 + MONTH(created_at)) (
PARTITION p202401 VALUES LESS THAN (202402),
PARTITION p202402 VALUES LESS THAN (202403),
-- ... 其他月份分区
PARTITION p_future VALUES LESS THAN MAXVALUE
);
```
## 5. 数据库安全策略
### 5.1 访问控制
#### 5.1.1 用户权限设计
```sql
-- 应用程序数据库用户
CREATE USER 'niumall_app'@'%' IDENTIFIED BY 'strong_password_123!';
GRANT SELECT, INSERT, UPDATE, DELETE ON niumall.* TO 'niumall_app'@'%';
-- 只读用户(用于报表和分析)
CREATE USER 'niumall_readonly'@'%' IDENTIFIED BY 'readonly_password_123!';
GRANT SELECT ON niumall.* TO 'niumall_readonly'@'%';
-- 备份用户
CREATE USER 'niumall_backup'@'localhost' IDENTIFIED BY 'backup_password_123!';
GRANT SELECT, LOCK TABLES, SHOW VIEW, EVENT, TRIGGER ON niumall.* TO 'niumall_backup'@'localhost';
```
#### 5.1.2 敏感数据加密
```sql
-- 用户密码加密存储(应用层处理)
-- 银行账号加密存储
-- 身份证号加密存储
-- 手机号部分加密显示
```
### 5.2 数据备份策略
#### 5.2.1 备份计划
```bash
#!/bin/bash
# 每日全量备份脚本
DATE=$(date +%Y%m%d_%H%M%S)
BACKUP_DIR="/backup/mysql"
DB_NAME="niumall"
# 全量备份
mysqldump -u niumall_backup -p${BACKUP_PASSWORD} \
--single-transaction \
--routines \
--triggers \
--events \
${DB_NAME} > ${BACKUP_DIR}/niumall_full_${DATE}.sql
# 压缩备份文件
gzip ${BACKUP_DIR}/niumall_full_${DATE}.sql
# 删除7天前的备份文件
find ${BACKUP_DIR} -name "niumall_full_*.sql.gz" -mtime +7 -delete
```
#### 5.2.2 恢复测试
```bash
#!/bin/bash
# 备份恢复测试脚本
TEST_DB="niumall_test"
BACKUP_FILE="niumall_full_20241220_120000.sql.gz"
# 创建测试数据库
mysql -u root -p -e "CREATE DATABASE IF NOT EXISTS ${TEST_DB};"
# 恢复数据
zcat ${BACKUP_FILE} | mysql -u root -p ${TEST_DB}
# 验证数据完整性
mysql -u root -p ${TEST_DB} -e "SELECT COUNT(*) FROM users;"
mysql -u root -p ${TEST_DB} -e "SELECT COUNT(*) FROM orders;"
```
## 6. 性能监控与优化
### 6.1 慢查询监控
#### 6.1.1 慢查询配置
```sql
-- 启用慢查询日志
SET GLOBAL slow_query_log = 'ON';
SET GLOBAL long_query_time = 1;
SET GLOBAL log_queries_not_using_indexes = 'ON';
```
#### 6.1.2 常见慢查询优化
```sql
-- 优化前:全表扫描
SELECT * FROM orders WHERE created_at > '2024-01-01';
-- 优化后:使用索引
SELECT id, order_no, client_id, status, created_at
FROM orders
WHERE created_at > '2024-01-01'
ORDER BY created_at DESC
LIMIT 100;
-- 添加索引
CREATE INDEX idx_orders_created_at ON orders(created_at);
```
### 6.2 数据库监控指标
| 监控指标 | 正常范围 | 告警阈值 | 处理建议 |
|---------|---------|---------|----------|
| 连接数 | < 80% | > 90% | 检查连接池配置 |
| CPU使用率 | < 70% | > 85% | 优化查询,增加资源 |
| 内存使用率 | < 80% | > 90% | 调整缓存配置 |
| 磁盘使用率 | < 80% | > 90% | 清理日志,扩容 |
| 慢查询数量 | < 10/小时 | > 50/小时 | 优化SQL语句 |
| 锁等待时间 | < 1秒 | > 5秒 | 优化事务逻辑 |
## 7. 数据迁移与版本管理
### 7.1 数据库版本控制
#### 7.1.1 迁移脚本示例
```sql
-- V1.0.0__Initial_schema.sql
-- 创建初始表结构
-- V1.0.1__Add_user_profiles.sql
-- 添加用户详情表
-- V1.1.0__Add_transport_module.sql
-- 添加运输管理模块
-- V1.1.1__Add_location_tracking.sql
-- 添加位置跟踪功能
```
#### 7.1.2 数据迁移脚本
```sql
-- 用户数据迁移示例
INSERT INTO users (phone, password, name, role, status, created_at)
SELECT
old_phone,
old_password_hash,
old_username,
CASE old_user_type
WHEN 1 THEN 'client'
WHEN 2 THEN 'supplier'
WHEN 3 THEN 'driver'
ELSE 'admin'
END,
CASE old_status
WHEN 1 THEN 'active'
ELSE 'inactive'
END,
old_create_time
FROM old_user_table
WHERE old_phone IS NOT NULL;
```
### 7.2 数据一致性检查
#### 7.2.1 数据完整性验证
```sql
-- 检查外键约束
SELECT
TABLE_NAME,
CONSTRAINT_NAME,
REFERENCED_TABLE_NAME
FROM information_schema.KEY_COLUMN_USAGE
WHERE REFERENCED_TABLE_SCHEMA = 'niumall'
AND REFERENCED_TABLE_NAME IS NOT NULL;
-- 检查数据一致性
SELECT
o.id,
o.order_no,
o.client_id,
u.name as client_name
FROM orders o
LEFT JOIN users u ON o.client_id = u.id
WHERE u.id IS NULL;
```
#### 7.2.2 数据质量监控
```sql
-- 检查重复数据
SELECT phone, COUNT(*) as count
FROM users
GROUP BY phone
HAVING COUNT(*) > 1;
-- 检查空值数据
SELECT
COUNT(*) as total_orders,
COUNT(client_id) as orders_with_client,
COUNT(supplier_id) as orders_with_supplier
FROM orders;
```
---
**文档维护**:本文档由数据库团队负责维护,数据库结构变更时及时更新。
**最后更新时间**2024年12月20日