Files
urbanLifeline/docs/数据库表结构速查.md
2025-12-02 13:21:18 +08:00

600 lines
18 KiB
Markdown
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.

# 数据库表结构速查手册
## 快速导航
- [系统基础模块 (sys)](#系统基础模块-sys)
- [文件管理模块 (file)](#文件管理模块-file)
- [消息通知模块 (message)](#消息通知模块-message)
- [日志模块 (log)](#日志模块-log)
- [配置管理模块 (config)](#配置管理模块-config)
- [知识库管理模块 (knowledge)](#知识库管理模块-knowledge)
- [招投标智能体模块 (bidding)](#招投标智能体模块-bidding)
- [智能客服系统模块 (customer_service)](#智能客服系统模块-customerservice)
- [智能体管理模块 (agent)](#智能体管理模块-agent)
---
## 系统基础模块 (sys)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_sys_user` | 用户表 | user_id | email, phone, wechat_id, status |
| `tb_sys_user_info` | 用户信息表 | user_id | avatar, full_name, gender, level |
| `tb_sys_dept` | 部门表 | dept_id | name, parent_id, dept_path |
| `tb_sys_role` | 角色表 | role_id | name, scope, owner_dept_id |
| `tb_sys_permission` | 权限表 | permission_id | name, code, module_id |
| `tb_sys_user_role` | 用户角色关联表 | (user_id, role_id) | - |
| `tb_sys_role_permission` | 角色权限关联表 | (role_id, permission_id) | - |
| `tb_sys_view` | 视图/菜单表 | view_id | name, url, component, type |
| `tb_sys_module` | 模块表 | module_id | name, description |
| `tb_sys_acl` | 对象级权限表 | acl_id | object_type, object_id, principal_type, permission |
| `tb_sys_acl_policy` | ACL策略表 | policy_id | object_type, edit_hierarchy_rule, view_hierarchy_rule |
| `tb_sys_login_log` | 登录日志表 | optsn | user_id, ip_address, login_time, status |
| `tb_sys_user_dept` | 用户部门关联表 | (user_id, dept_id) | is_primary, position |
### 权限模型
```
用户 (tb_sys_user)
├─ 用户角色 (tb_sys_user_role)
│ └─ 角色 (tb_sys_role)
│ ├─ 角色权限 (tb_sys_role_permission)
│ │ └─ 权限 (tb_sys_permission)
│ │ └─ 模块 (tb_sys_module)
│ └─ 视图权限 (tb_sys_view_permission)
│ └─ 视图 (tb_sys_view)
└─ 对象权限 (tb_sys_acl)
└─ ACL策略 (tb_sys_acl_policy)
```
### 常用查询
```sql
-- 查询用户所有权限
SELECT p.code, p.name
FROM sys.tb_sys_user_role ur
JOIN sys.tb_sys_role_permission rp ON ur.role_id = rp.role_id
JOIN sys.tb_sys_permission p ON rp.permission_id = p.permission_id
WHERE ur.user_id = 'USER_ID' AND ur.deleted = false;
-- 查询部门树
WITH RECURSIVE dept_tree AS (
SELECT *, 1 AS level FROM sys.tb_sys_dept WHERE parent_id IS NULL
UNION ALL
SELECT d.*, dt.level + 1
FROM sys.tb_sys_dept d
JOIN dept_tree dt ON d.parent_id = dt.dept_id
)
SELECT * FROM dept_tree ORDER BY level, dept_id;
```
---
## 文件管理模块 (file)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_sys_file` | 文件表 | file_id | name, path, size, type, storage_type, url |
| `tb_file_relation` | 文件关联表 | relation_id | file_id, object_type, object_id, relation_type |
### 文件类型
- `storage_type`: local(本地存储) / oss(对象存储) / ftp / sftp
- `relation_type`: attachment(附件) / avatar(头像) / banner(横幅)
### 常用查询
```sql
-- 查询对象的所有附件
SELECT f.*
FROM file.tb_sys_file f
JOIN file.tb_file_relation fr ON f.file_id = fr.file_id
WHERE fr.object_type = 'bidding_project'
AND fr.object_id = 'PROJECT_ID'
AND fr.deleted = false;
```
---
## 消息通知模块 (message)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_message` | 消息表 | message_id | title, content, type, status |
| `tb_message_range` | 消息发送范围表 | optsn | message_id, target_type, target_id, channel |
| `tb_message_receiver` | 用户消息接收表 | optsn | message_id, user_id, status, read_time |
| `tb_message_channel` | 消息渠道配置表 | channel_id | channel_code, channel_name, status |
| `tb_message_template` | 消息模板表 | template_id | template_code, title_template, content_template |
### 消息发送流程
```
创建消息 (tb_message)
定义发送范围 (tb_message_range)
├─ target_type: user(指定用户) / dept(部门) / role(角色) / all(全员)
├─ channel: app / sms / email / wechat
生成接收记录 (tb_message_receiver)
└─ status: unread → read → handled / deleted
```
### 常用查询
```sql
-- 查询用户未读消息
SELECT m.*, mr.create_time AS receive_time
FROM message.tb_message m
JOIN message.tb_message_receiver mr ON m.message_id = mr.message_id
WHERE mr.user_id = 'USER_ID'
AND mr.status = 'unread'
AND mr.deleted = false
ORDER BY mr.create_time DESC;
```
---
## 日志模块 (log)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_sys_log` | 系统日志表 | log_id | type, level, module, message, data, trace_id |
### 日志级别
- `level`: debug / info / warn / error / fatal
- `type`: system / audit / security / business / api
### 常用查询
```sql
-- 查询错误日志
SELECT * FROM log.tb_sys_log
WHERE level IN ('error', 'fatal')
AND create_time > now() - interval '24 hours'
ORDER BY create_time DESC;
-- 链路追踪
SELECT * FROM log.tb_sys_log
WHERE trace_id = 'TRACE_ID'
ORDER BY create_time;
```
---
## 配置管理模块 (config)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_sys_config` | 系统配置表 | config_id | key, name, value, config_type, render_type |
### 配置类型
- `config_type`: String / Integer / Boolean / Float / Double
- `render_type`: select / input / textarea / checkbox / radio / switch
### 常用查询
```sql
-- 按模块查询配置
SELECT * FROM config.tb_sys_config
WHERE module_id = 'MODULE_ID' AND deleted = false
ORDER BY order_num;
```
---
## 知识库管理模块 (knowledge)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_knowledge_base` | 知识库表 | kb_id | name, kb_type, access_level, version |
| `tb_knowledge_document` | 知识文档表 | doc_id | kb_id, title, doc_type, category, embedding_status |
| `tb_knowledge_chunk` | 文档片段表 | chunk_id | doc_id, kb_id, content, embedding |
| `tb_knowledge_access_log` | 知识访问日志表 | log_id | kb_id, doc_id, user_id, access_type |
### 知识库类型
- `kb_type`: bidding(招投标) / customer_service(客服) / internal(内部协同)
- `access_level`: public(公开) / private(私有) / internal(内部)
- `embedding_status`: pending(待处理) / processing(处理中) / completed(完成) / failed(失败)
### RAG检索流程
```
用户查询
向量化查询文本
在 tb_knowledge_chunk 中进行向量检索 (embedding)
获取相关文档片段
关联 tb_knowledge_document 获取完整文档信息
返回结果 + 记录访问日志
```
### 常用查询
```sql
-- 查询知识库文档
SELECT d.*, kb.name AS kb_name
FROM knowledge.tb_knowledge_document d
JOIN knowledge.tb_knowledge_base kb ON d.kb_id = kb.kb_id
WHERE d.kb_id = 'KB_ID'
AND d.embedding_status = 'completed'
AND d.deleted = false;
-- 向量检索需要pgvector扩展
-- SELECT chunk_id, content,
-- 1 - (embedding <=> '[查询向量]'::vector) AS similarity
-- FROM knowledge.tb_knowledge_chunk
-- WHERE kb_id = 'KB_ID'
-- ORDER BY embedding <=> '[查询向量]'::vector
-- LIMIT 10;
```
---
## 招投标智能体模块 (bidding)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_bidding_project` | 招标项目表 | project_id | project_no, project_name, project_status, deadline |
| `tb_bidding_document` | 招标文件表 | doc_id | project_id, doc_type, parse_status, parse_result |
| `tb_bidding_requirement` | 要素提取表 | req_id | project_id, req_category, is_veto, compliance_status |
| `tb_bid_response` | 投标文件生成表 | response_id | project_id, response_type, generation_status |
| `tb_bidding_scoring_rule` | 评分规则表 | rule_id | project_id, rule_category, max_score, our_score |
| `tb_bidding_process` | 流程节点表 | process_id | project_id, node_type, node_status |
| `tb_bid_template` | 投标模板表 | template_id | template_name, template_type, usage_count |
### 项目生命周期
```
collecting(收集中)
analyzing(分析中) - 智能解读招标文件
preparing(准备投标) - 生成投标文件
submitted(已提交)
opened(已开标)
won(中标) / lost(未中标) / abandoned(放弃)
```
### 要素类别
- `req_category`:
- commercial: 商务要素
- technical: 技术参数
- veto: 否决项 ⚠️
- qualification: 资质要求
- delivery: 交付要求
- payment: 付款条件
- scoring: 评分标准
### 常用查询
```sql
-- 查询项目的所有否决项
SELECT * FROM bidding.tb_bidding_requirement
WHERE project_id = 'PROJECT_ID'
AND is_veto = true
AND deleted = false;
-- 查询项目评分预估
SELECT
rule_category,
SUM(max_score) AS total_max_score,
SUM(our_score) AS total_our_score,
ROUND(SUM(our_score) / SUM(max_score) * 100, 2) AS score_percentage
FROM bidding.tb_bidding_scoring_rule
WHERE project_id = 'PROJECT_ID' AND deleted = false
GROUP BY rule_category;
```
---
## 智能客服系统模块 (customer_service)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_customer` | 客户信息表 | customer_id | customer_name, phone, wechat_openid, customer_level |
| `tb_conversation` | 会话表 | conversation_id | customer_id, conversation_type, agent_id, satisfaction_rating |
| `tb_conversation_message` | 会话消息表 | message_id | conversation_id, sender_type, content, is_ai_generated |
| `tb_ticket` | 工单表 | ticket_id | ticket_no, customer_id, ticket_type, ticket_status, sla_deadline |
| `tb_ticket_log` | 工单处理记录表 | log_id | ticket_id, action_type, action_content |
| `tb_faq` | FAQ表 | faq_id | category, question, answer, hit_count |
| `tb_service_evaluation` | 客服评价表 | evaluation_id | customer_id, evaluation_type, rating |
| `tb_crm_config` | CRM集成配置表 | config_id | crm_system, api_endpoint, sync_enabled |
### 会话流程
```
客户发起咨询
创建会话 (tb_conversation)
├─ conversation_type: ai(AI客服) / human(人工) / transfer(转接)
消息交互 (tb_conversation_message)
├─ sender_type: customer / agent / system
├─ is_ai_generated: true/false
├─ kb_references: [知识库文档ID]
智能工单生成 (tb_ticket)
├─ ticket_source: ai / manual / system
满意度评价 (tb_service_evaluation / tb_conversation)
```
### 工单状态
- `ticket_status`:
- pending: 待处理
- processing: 处理中
- resolved: 已解决
- closed: 已关闭
- cancelled: 已取消
### 常用查询
```sql
-- 查询客户的活跃会话
SELECT * FROM customer_service.tb_conversation
WHERE customer_id = 'CUSTOMER_ID'
AND conversation_status = 'active'
AND deleted = false;
-- 查询逾期工单
SELECT * FROM customer_service.tb_ticket
WHERE is_overdue = true
AND ticket_status IN ('pending', 'processing')
AND deleted = false
ORDER BY sla_deadline;
-- 查询AI回答质量
SELECT
DATE(create_time) AS stat_date,
AVG(confidence_score) AS avg_confidence,
COUNT(*) FILTER (WHERE confidence_score > 0.8) AS high_confidence_count,
COUNT(*) AS total_count
FROM customer_service.tb_conversation_message
WHERE is_ai_generated = true
AND deleted = false
GROUP BY DATE(create_time);
```
---
## 智能体管理模块 (agent)
### 核心表结构
| 表名 | 说明 | 主键 | 核心字段 |
|------|------|------|----------|
| `tb_agent` | 智能体定义表 | agent_id | agent_code, agent_name, agent_type, model_config |
| `tb_agent_session` | 智能体会话表 | session_id | agent_id, user_id, session_status, token_usage |
| `tb_agent_message` | 智能体消息表 | message_id | session_id, role, content, function_call |
| `tb_agent_tool` | 智能体工具表 | tool_id | tool_code, tool_type, function_schema, api_endpoint |
| `tb_api_integration` | API集成表 | integration_id | integration_name, base_url, auth_config |
| `tb_api_call_log` | API调用日志表 | log_id | integration_id, endpoint, response_status, duration_ms |
| `tb_agent_metrics` | 智能体监控指标表 | metric_id | agent_id, metric_date, total_sessions, total_tokens |
| `tb_agent_error_log` | 智能体异常日志表 | log_id | agent_id, error_type, error_message, severity |
| `tb_agent_rating` | 智能体评价表 | rating_id | agent_id, rating, feedback |
### 智能体类型
- `agent_type`:
- bidding: 招投标智能体
- customer_service: 客服智能体
- knowledge_assistant: 知识助手
- custom: 自定义智能体
### 工具类型
- `tool_type`:
- api: API调用
- function: 函数
- plugin: 插件
- integration: 集成
### 会话流程
```
用户请求
创建会话 (tb_agent_session)
消息交互 (tb_agent_message)
├─ role: user / assistant / system / function
├─ function_call: 工具调用
工具执行 (tb_agent_tool)
├─ API调用记录 (tb_api_call_log)
记录监控指标 (tb_agent_metrics)
├─ 错误记录 (tb_agent_error_log)
用户评价 (tb_agent_rating)
```
### 常用查询
```sql
-- 查询智能体使用统计
SELECT * FROM agent.v_agent_usage_stats
WHERE agent_id = 'AGENT_ID';
-- 查询API健康状态
SELECT
integration_name,
health_status,
last_health_check,
EXTRACT(EPOCH FROM (now() - last_health_check))/60 AS minutes_since_check
FROM agent.tb_api_integration
WHERE deleted = false
ORDER BY health_status, last_health_check;
-- 查询智能体错误率
SELECT
a.agent_name,
COUNT(*) FILTER (WHERE e.severity = 'critical') AS critical_errors,
COUNT(*) FILTER (WHERE e.severity = 'error') AS errors,
COUNT(*) AS total_errors
FROM agent.tb_agent a
LEFT JOIN agent.tb_agent_error_log e ON a.agent_id = e.agent_id
WHERE e.create_time > now() - interval '24 hours'
GROUP BY a.agent_id, a.agent_name;
```
---
## 数据字典常用字段说明
### 通用字段
所有表都包含以下标准字段:
| 字段 | 类型 | 说明 |
|------|------|------|
| `optsn` | VARCHAR(50) | 流水号(唯一标识) |
| `xxx_id` | VARCHAR(50) | 主键ID |
| `dept_path` | VARCHAR(255) | 部门全路径(多租户隔离) |
| `creator` | VARCHAR(50) | 创建者ID |
| `updater` | VARCHAR(50) | 更新者ID |
| `create_time` | timestamptz | 创建时间(带时区) |
| `update_time` | timestamptz | 更新时间(触发器自动更新) |
| `delete_time` | timestamptz | 删除时间 |
| `deleted` | BOOLEAN | 软删除标记 |
### 时间戳说明
- 使用 `timestamptz` 类型(带时区的时间戳)
- 自动记录创建时间
- 更新时间由触发器自动维护
- 支持软删除(保留 delete_time
### 部门路径dept_path
格式:`/1/2/3/`
- 用于多租户数据隔离
- 支持 LIKE 递归查询
- 示例查询:`WHERE dept_path LIKE '/1/2/%'`
---
## 视图速查
| 视图名 | Schema | 说明 |
|--------|--------|------|
| `v_user_full_info` | sys | 用户完整信息(含用户信息表) |
| `v_user_role_permission` | sys | 用户角色权限(含模块) |
| `v_user_full_permissions` | sys | 用户完整权限含ACL |
| `v_agent_usage_stats` | agent | 智能体使用统计 |
| `v_agent_realtime_status` | agent | 智能体实时状态 |
| `v_ticket_stats` | customer_service | 工单统计 |
| `v_ticket_efficiency` | customer_service | 工单处理效率 |
| `v_project_stats` | bidding | 招投标项目统计 |
---
## 函数速查
| 函数名 | Schema | 说明 |
|--------|--------|------|
| `update_modified_column()` | public | 自动更新update_time触发器函数 |
| `audit_trigger_func()` | public | 审计日志触发器函数 |
| `archive_old_logs()` | public | 归档旧日志数据 |
| `archive_api_logs()` | agent | 归档API调用日志 |
| `check_table_bloat()` | public | 检查表膨胀情况 |
| `create_update_triggers()` | public | 批量创建更新触发器 |
---
## 索引策略
### 主要索引类型
1. **B-Tree索引**(默认):主键、外键、常规查询字段
2. **GIN索引**JSONB字段、数组字段、全文搜索
3. **部分索引**带WHERE条件的索引`WHERE deleted = false`
4. **表达式索引**:函数索引(如 `lower(email)`
### 关键索引示例
```sql
-- 部分索引(减少索引大小)
CREATE INDEX idx_xxx ON table_name(column) WHERE deleted = false;
-- GIN索引数组查询
CREATE INDEX idx_xxx ON table_name USING gin(array_column);
-- 全文搜索索引
CREATE INDEX idx_xxx ON table_name USING gin(text_column gin_trgm_ops);
-- 表达式索引
CREATE INDEX idx_xxx ON table_name(lower(email));
```
---
## 性能优化建议
### 查询优化
1. **使用索引**WHERE、JOIN、ORDER BY字段都要有索引
2. **避免SELECT ***:只查询需要的字段
3. **使用LIMIT**:分页查询限制返回行数
4. **使用EXPLAIN**:分析查询计划
### 批量操作
```sql
-- 批量插入使用COPY或批量INSERT
COPY table_name FROM '/path/to/file.csv' WITH CSV;
-- 批量更新使用UPDATE...FROM
UPDATE table_name t
SET column = data.value
FROM (VALUES (1, 'a'), (2, 'b')) AS data(id, value)
WHERE t.id = data.id;
```
### 定期维护
```sql
-- 分析表(更新统计信息)
ANALYZE table_name;
-- 清理和分析
VACUUM ANALYZE table_name;
-- 重建索引
REINDEX TABLE table_name;
```
---
**版本**: 1.0
**更新时间**: 2024-12-02