iconsulting/infrastructure/docker/services/postgres/init.sql

1451 lines
59 KiB
PL/PgSQL
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.

-- ===========================================
-- iConsulting 数据库初始化脚本
-- 香港移民在线咨询系统
-- ===========================================
-- 启用必要的扩展
CREATE EXTENSION IF NOT EXISTS vector; -- pgvector: 向量存储和相似度搜索
CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- UUID生成函数
-- ===========================================
-- 用户表 (users)
-- 存储系统用户信息,支持匿名用户和注册用户
-- ===========================================
CREATE TABLE users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 用户类型: ANONYMOUS(匿名访客), REGISTERED(已注册用户)
type VARCHAR(20) NOT NULL DEFAULT 'ANONYMOUS'
CHECK (type IN ('ANONYMOUS', 'REGISTERED')),
-- 浏览器指纹,用于识别匿名用户
fingerprint VARCHAR(255),
-- 手机号码(注册用户必填)
phone VARCHAR(20),
-- 用户昵称
nickname VARCHAR(100),
-- 头像URL
avatar VARCHAR(500),
-- 用户来源渠道: WEB, H5, WECHAT_MP, ALIPAY_MP, LINE, WHATSAPP
source_channel VARCHAR(50) DEFAULT 'WEB',
-- 用户来源标识如推广码、活动ID等
source_ref VARCHAR(100),
-- 用户标签JSON数组如["高净值", "技术人才"]
tags JSONB DEFAULT '[]',
-- 用户偏好设置
preferences JSONB DEFAULT '{}',
-- 备注信息(管理员可编辑)
notes TEXT,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 最后活跃时间
last_active_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE users IS '用户表 - 存储系统所有用户信息';
COMMENT ON COLUMN users.type IS '用户类型: ANONYMOUS=匿名访客, REGISTERED=已注册用户';
COMMENT ON COLUMN users.fingerprint IS '浏览器指纹,用于识别和关联匿名用户';
COMMENT ON COLUMN users.source_channel IS '用户来源渠道,用于统计分析';
COMMENT ON COLUMN users.tags IS '用户标签JSON数组格式用于用户分群';
CREATE INDEX idx_users_fingerprint ON users(fingerprint);
CREATE INDEX idx_users_phone ON users(phone);
CREATE INDEX idx_users_type ON users(type);
CREATE INDEX idx_users_source_channel ON users(source_channel);
CREATE INDEX idx_users_created_at ON users(created_at);
-- ===========================================
-- 对话表 (conversations)
-- 存储用户与AI助手的对话会话
-- ===========================================
CREATE TABLE conversations (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 所属用户ID
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
-- 对话状态: ACTIVE(进行中), ENDED(已结束), ARCHIVED(已归档)
status VARCHAR(20) NOT NULL DEFAULT 'ACTIVE'
CHECK (status IN ('ACTIVE', 'ENDED', 'ARCHIVED')),
-- 对话标题(自动生成或用户设置)
title VARCHAR(255),
-- 对话摘要AI生成
summary TEXT,
-- 主要咨询的移民类别: QMAS, GEP, IANG, TTPS, CIES, TECHTAS
category VARCHAR(50),
-- 消息数量(通过触发器自动更新)
message_count INT DEFAULT 0,
-- 用户消息数量
user_message_count INT DEFAULT 0,
-- AI消息数量
assistant_message_count INT DEFAULT 0,
-- Token消耗统计
total_input_tokens INT DEFAULT 0,
total_output_tokens INT DEFAULT 0,
-- 对话评分用户反馈1-5分
rating SMALLINT CHECK (rating >= 1 AND rating <= 5),
-- 用户反馈内容
feedback TEXT,
-- 是否转化为付费(用于统计转化率)
has_converted BOOLEAN DEFAULT FALSE,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 结束时间
ended_at TIMESTAMP WITH TIME ZONE
);
COMMENT ON TABLE conversations IS '对话表 - 存储用户与AI助手的对话会话';
COMMENT ON COLUMN conversations.category IS '主要咨询的移民类别,用于分析用户兴趣分布';
COMMENT ON COLUMN conversations.has_converted IS '是否产生付费转化,用于计算转化率';
COMMENT ON COLUMN conversations.rating IS '用户对对话的评分1-5分';
CREATE INDEX idx_conversations_user_id ON conversations(user_id);
CREATE INDEX idx_conversations_status ON conversations(status);
CREATE INDEX idx_conversations_category ON conversations(category);
CREATE INDEX idx_conversations_created_at ON conversations(created_at DESC);
CREATE INDEX idx_conversations_has_converted ON conversations(has_converted) WHERE has_converted = TRUE;
-- ===========================================
-- 消息表 (messages)
-- 存储对话中的每条消息
-- ===========================================
CREATE TABLE messages (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 所属对话ID
conversation_id UUID REFERENCES conversations(id) ON DELETE CASCADE,
-- 消息角色: user(用户), assistant(AI助手), system(系统)
role VARCHAR(20) NOT NULL CHECK (role IN ('user', 'assistant', 'system')),
-- 消息类型
type VARCHAR(30) NOT NULL DEFAULT 'TEXT'
CHECK (type IN ('TEXT', 'TOOL_CALL', 'TOOL_RESULT', 'PAYMENT_REQUEST', 'ASSESSMENT_START', 'ASSESSMENT_RESULT')),
-- 消息内容
content TEXT NOT NULL,
-- 元数据工具调用信息、Token使用等
metadata JSONB,
-- Token使用量
input_tokens INT,
output_tokens INT,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE messages IS '消息表 - 存储对话中的每条消息';
COMMENT ON COLUMN messages.role IS '消息角色: user=用户发送, assistant=AI回复, system=系统消息';
COMMENT ON COLUMN messages.type IS '消息类型,用于区分普通文本、工具调用、支付请求等';
COMMENT ON COLUMN messages.metadata IS '元数据,存储工具调用参数、结果等扩展信息';
CREATE INDEX idx_messages_conversation_id ON messages(conversation_id);
CREATE INDEX idx_messages_role ON messages(role);
CREATE INDEX idx_messages_created_at ON messages(created_at);
-- ===========================================
-- 订单表 (orders)
-- 存储用户购买的服务订单
-- ===========================================
CREATE TABLE orders (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 订单号用于展示格式ORD + 年月日 + 序号)
order_no VARCHAR(50) UNIQUE,
-- 所属用户ID
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
-- 关联的对话ID订单从哪个对话产生
conversation_id UUID REFERENCES conversations(id) ON DELETE SET NULL,
-- 服务类型: ASSESSMENT(评估), CONSULTATION(咨询), DOCUMENT_REVIEW(文档审核)
service_type VARCHAR(50) NOT NULL
CHECK (service_type IN ('ASSESSMENT', 'CONSULTATION', 'DOCUMENT_REVIEW')),
-- 服务对应的移民类别
service_category VARCHAR(50),
-- 订单金额
amount DECIMAL(10, 2) NOT NULL,
-- 货币类型
currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
-- 订单状态
status VARCHAR(20) NOT NULL DEFAULT 'CREATED'
CHECK (status IN ('CREATED', 'PENDING_PAYMENT', 'PAID', 'PROCESSING', 'COMPLETED', 'CANCELLED', 'REFUNDED')),
-- 支付方式: ALIPAY, WECHAT, CREDIT_CARD
payment_method VARCHAR(20),
-- 关联的支付ID
payment_id UUID,
-- 优惠券ID
coupon_id UUID,
-- 优惠金额
discount_amount DECIMAL(10, 2) DEFAULT 0,
-- 实付金额
paid_amount DECIMAL(10, 2),
-- 支付时间
paid_at TIMESTAMP WITH TIME ZONE,
-- 完成时间
completed_at TIMESTAMP WITH TIME ZONE,
-- 取消时间
cancelled_at TIMESTAMP WITH TIME ZONE,
-- 取消原因
cancel_reason TEXT,
-- 退款时间
refunded_at TIMESTAMP WITH TIME ZONE,
-- 退款原因
refund_reason TEXT,
-- 订单备注
notes TEXT,
-- 扩展元数据(评估结果等)
metadata JSONB,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE orders IS '订单表 - 存储用户购买的服务订单';
COMMENT ON COLUMN orders.order_no IS '订单号用于对外展示格式ORD + 年月日 + 序号';
COMMENT ON COLUMN orders.service_type IS '服务类型: ASSESSMENT=移民评估, CONSULTATION=付费咨询, DOCUMENT_REVIEW=文档审核';
COMMENT ON COLUMN orders.metadata IS '扩展数据,如评估结果详情等';
CREATE INDEX idx_orders_order_no ON orders(order_no);
CREATE INDEX idx_orders_user_id ON orders(user_id);
CREATE INDEX idx_orders_status ON orders(status);
CREATE INDEX idx_orders_service_type ON orders(service_type);
CREATE INDEX idx_orders_created_at ON orders(created_at DESC);
CREATE INDEX idx_orders_paid_at ON orders(paid_at) WHERE paid_at IS NOT NULL;
-- ===========================================
-- 支付表 (payments)
-- 存储支付交易记录
-- ===========================================
CREATE TABLE payments (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 关联的订单ID
order_id UUID REFERENCES orders(id) ON DELETE CASCADE,
-- 支付方式
method VARCHAR(20) NOT NULL CHECK (method IN ('ALIPAY', 'WECHAT', 'CREDIT_CARD')),
-- 支付金额
amount DECIMAL(10, 2) NOT NULL,
-- 货币类型
currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
-- 支付状态
status VARCHAR(20) NOT NULL DEFAULT 'PENDING'
CHECK (status IN ('PENDING', 'PROCESSING', 'COMPLETED', 'FAILED', 'REFUNDED', 'CANCELLED')),
-- 第三方交易号(支付宝/微信/Stripe的交易ID
transaction_id VARCHAR(255),
-- 支付二维码URL支付宝/微信)
qr_code_url TEXT,
-- 支付页面URLStripe
payment_url TEXT,
-- 支付过期时间
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
-- 实际支付时间
paid_at TIMESTAMP WITH TIME ZONE,
-- 失败原因
failed_reason TEXT,
-- 第三方回调原始数据(用于对账和排查问题)
callback_payload JSONB,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE payments IS '支付表 - 存储支付交易记录';
COMMENT ON COLUMN payments.transaction_id IS '第三方支付平台的交易号,用于对账';
COMMENT ON COLUMN payments.callback_payload IS '支付回调的原始数据,用于问题排查和对账';
CREATE INDEX idx_payments_order_id ON payments(order_id);
CREATE INDEX idx_payments_status ON payments(status);
CREATE INDEX idx_payments_method ON payments(method);
CREATE INDEX idx_payments_transaction_id ON payments(transaction_id);
CREATE INDEX idx_payments_created_at ON payments(created_at);
-- ===========================================
-- 分类账/财务流水表 (ledger_entries)
-- 记录所有资金流动,支持财务对账和报表
-- ===========================================
CREATE TABLE ledger_entries (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 流水号(唯一标识)
entry_no VARCHAR(50) UNIQUE NOT NULL,
-- 流水类型
entry_type VARCHAR(30) NOT NULL
CHECK (entry_type IN ('INCOME', 'REFUND', 'COMMISSION', 'WITHDRAWAL', 'ADJUSTMENT')),
-- 关联订单ID
order_id UUID REFERENCES orders(id) ON DELETE SET NULL,
-- 关联支付ID
payment_id UUID REFERENCES payments(id) ON DELETE SET NULL,
-- 关联用户ID
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
-- 金额(正数为收入,负数为支出)
amount DECIMAL(12, 2) NOT NULL,
-- 货币类型
currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
-- 账户余额(流水后的账户余额快照)
balance_after DECIMAL(12, 2),
-- 交易渠道: ALIPAY, WECHAT, STRIPE, BANK, MANUAL
channel VARCHAR(30),
-- 第三方交易号
transaction_id VARCHAR(255),
-- 业务类型: ASSESSMENT, CONSULTATION, DOCUMENT_REVIEW
business_type VARCHAR(50),
-- 业务类别: QMAS, GEP, IANG, TTPS, CIES, TECHTAS
business_category VARCHAR(50),
-- 摘要/描述
description TEXT,
-- 备注
notes TEXT,
-- 状态: PENDING(待确认), CONFIRMED(已确认), CANCELLED(已取消)
status VARCHAR(20) NOT NULL DEFAULT 'CONFIRMED'
CHECK (status IN ('PENDING', 'CONFIRMED', 'CANCELLED')),
-- 确认时间
confirmed_at TIMESTAMP WITH TIME ZONE,
-- 确认人管理员ID
confirmed_by UUID,
-- 会计期间格式YYYY-MM
accounting_period VARCHAR(7),
-- 创建时间(流水发生时间)
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE ledger_entries IS '分类账/财务流水表 - 记录所有资金流动,支持财务对账和报表生成';
COMMENT ON COLUMN ledger_entries.entry_no IS '流水号格式LE + 年月日 + 序号';
COMMENT ON COLUMN ledger_entries.entry_type IS '流水类型: INCOME=收入, REFUND=退款, COMMISSION=佣金, WITHDRAWAL=提现, ADJUSTMENT=调整';
COMMENT ON COLUMN ledger_entries.balance_after IS '该笔流水后的账户余额快照,用于对账';
COMMENT ON COLUMN ledger_entries.accounting_period IS '会计期间格式YYYY-MM用于月度报表';
CREATE INDEX idx_ledger_entries_entry_no ON ledger_entries(entry_no);
CREATE INDEX idx_ledger_entries_entry_type ON ledger_entries(entry_type);
CREATE INDEX idx_ledger_entries_order_id ON ledger_entries(order_id);
CREATE INDEX idx_ledger_entries_user_id ON ledger_entries(user_id);
CREATE INDEX idx_ledger_entries_status ON ledger_entries(status);
CREATE INDEX idx_ledger_entries_accounting_period ON ledger_entries(accounting_period);
CREATE INDEX idx_ledger_entries_created_at ON ledger_entries(created_at DESC);
CREATE INDEX idx_ledger_entries_business_type ON ledger_entries(business_type);
-- ===========================================
-- 日统计表 (daily_statistics)
-- 预聚合的每日统计数据,用于快速报表查询
-- ===========================================
CREATE TABLE daily_statistics (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 统计日期
stat_date DATE NOT NULL,
-- 统计维度: OVERALL(总体), CHANNEL(渠道), CATEGORY(移民类别)
dimension VARCHAR(30) NOT NULL DEFAULT 'OVERALL',
-- 维度值(如渠道名称、类别代码)
dimension_value VARCHAR(50),
-- ===== 用户统计 =====
-- 新增用户数
new_users INT DEFAULT 0,
-- 新增注册用户数
new_registered_users INT DEFAULT 0,
-- 活跃用户数
active_users INT DEFAULT 0,
-- ===== 对话统计 =====
-- 新增对话数
new_conversations INT DEFAULT 0,
-- 总消息数
total_messages INT DEFAULT 0,
-- 用户消息数
user_messages INT DEFAULT 0,
-- AI消息数
assistant_messages INT DEFAULT 0,
-- 平均对话轮次
avg_conversation_turns DECIMAL(10, 2) DEFAULT 0,
-- ===== 订单统计 =====
-- 新增订单数
new_orders INT DEFAULT 0,
-- 支付成功订单数
paid_orders INT DEFAULT 0,
-- 订单总金额
total_order_amount DECIMAL(12, 2) DEFAULT 0,
-- 实收金额
total_paid_amount DECIMAL(12, 2) DEFAULT 0,
-- 退款订单数
refunded_orders INT DEFAULT 0,
-- 退款金额
refund_amount DECIMAL(12, 2) DEFAULT 0,
-- ===== 转化统计 =====
-- 咨询转化数(对话转订单)
conversion_count INT DEFAULT 0,
-- 转化率
conversion_rate DECIMAL(5, 4) DEFAULT 0,
-- ===== Token消耗统计 =====
-- 输入Token总数
total_input_tokens BIGINT DEFAULT 0,
-- 输出Token总数
total_output_tokens BIGINT DEFAULT 0,
-- 预估API成本美元
estimated_api_cost DECIMAL(10, 4) DEFAULT 0,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 唯一约束:同一天同一维度同一维度值只有一条记录
UNIQUE(stat_date, dimension, dimension_value)
);
COMMENT ON TABLE daily_statistics IS '日统计表 - 预聚合的每日统计数据,支持多维度分析';
COMMENT ON COLUMN daily_statistics.dimension IS '统计维度: OVERALL=总体统计, CHANNEL=按渠道, CATEGORY=按移民类别';
COMMENT ON COLUMN daily_statistics.conversion_rate IS '转化率 = 支付订单数 / 新对话数';
COMMENT ON COLUMN daily_statistics.estimated_api_cost IS '预估Claude API成本基于Token消耗计算';
CREATE INDEX idx_daily_statistics_stat_date ON daily_statistics(stat_date DESC);
CREATE INDEX idx_daily_statistics_dimension ON daily_statistics(dimension, dimension_value);
-- ===========================================
-- 月度财务报表 (monthly_financial_reports)
-- 月度汇总的财务数据
-- ===========================================
CREATE TABLE monthly_financial_reports (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 报表月份格式YYYY-MM
report_month VARCHAR(7) NOT NULL UNIQUE,
-- ===== 收入统计 =====
-- 总收入
total_revenue DECIMAL(12, 2) DEFAULT 0,
-- 评估服务收入
assessment_revenue DECIMAL(12, 2) DEFAULT 0,
-- 咨询服务收入
consultation_revenue DECIMAL(12, 2) DEFAULT 0,
-- 其他收入
other_revenue DECIMAL(12, 2) DEFAULT 0,
-- ===== 退款统计 =====
-- 总退款
total_refunds DECIMAL(12, 2) DEFAULT 0,
-- 净收入(总收入 - 退款)
net_revenue DECIMAL(12, 2) DEFAULT 0,
-- ===== 成本统计 =====
-- API成本Claude
api_cost DECIMAL(10, 2) DEFAULT 0,
-- 支付手续费
payment_fees DECIMAL(10, 2) DEFAULT 0,
-- 其他成本
other_costs DECIMAL(10, 2) DEFAULT 0,
-- 总成本
total_costs DECIMAL(10, 2) DEFAULT 0,
-- ===== 利润统计 =====
-- 毛利润
gross_profit DECIMAL(12, 2) DEFAULT 0,
-- 毛利率
gross_margin DECIMAL(5, 4) DEFAULT 0,
-- ===== 订单统计 =====
-- 总订单数
total_orders INT DEFAULT 0,
-- 成功订单数
successful_orders INT DEFAULT 0,
-- 平均订单金额
avg_order_amount DECIMAL(10, 2) DEFAULT 0,
-- ===== 按类别收入明细JSONB =====
revenue_by_category JSONB DEFAULT '{}',
-- ===== 按渠道收入明细JSONB =====
revenue_by_channel JSONB DEFAULT '{}',
-- 报表状态: DRAFT(草稿), CONFIRMED(已确认), LOCKED(已锁定)
status VARCHAR(20) NOT NULL DEFAULT 'DRAFT'
CHECK (status IN ('DRAFT', 'CONFIRMED', 'LOCKED')),
-- 确认人
confirmed_by UUID,
-- 确认时间
confirmed_at TIMESTAMP WITH TIME ZONE,
-- 备注
notes TEXT,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE monthly_financial_reports IS '月度财务报表 - 月度汇总的财务数据,支持确认和锁定';
COMMENT ON COLUMN monthly_financial_reports.report_month IS '报表月份格式YYYY-MM';
COMMENT ON COLUMN monthly_financial_reports.revenue_by_category IS '按移民类别的收入明细JSON格式';
COMMENT ON COLUMN monthly_financial_reports.status IS 'DRAFT=草稿可修改, CONFIRMED=已确认, LOCKED=已锁定不可修改';
CREATE INDEX idx_monthly_financial_reports_month ON monthly_financial_reports(report_month DESC);
CREATE INDEX idx_monthly_financial_reports_status ON monthly_financial_reports(status);
-- ===========================================
-- 审计日志表 (audit_logs)
-- 记录所有重要操作,用于安全审计和问题追踪
-- ===========================================
CREATE TABLE audit_logs (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 操作者ID用户或管理员
actor_id UUID,
-- 操作者类型: USER, ADMIN, SYSTEM
actor_type VARCHAR(20) NOT NULL CHECK (actor_type IN ('USER', 'ADMIN', 'SYSTEM')),
-- 操作者名称/标识
actor_name VARCHAR(100),
-- 操作类型
action VARCHAR(50) NOT NULL,
-- 操作对象类型(表名)
entity_type VARCHAR(50) NOT NULL,
-- 操作对象ID
entity_id UUID,
-- 操作前的数据快照
old_values JSONB,
-- 操作后的数据快照
new_values JSONB,
-- 变更的字段列表
changed_fields TEXT[],
-- 操作描述
description TEXT,
-- 客户端IP地址
ip_address INET,
-- 用户代理(浏览器信息)
user_agent TEXT,
-- 请求ID用于追踪
request_id VARCHAR(100),
-- 操作结果: SUCCESS, FAILED
result VARCHAR(20) DEFAULT 'SUCCESS' CHECK (result IN ('SUCCESS', 'FAILED')),
-- 错误信息(如果失败)
error_message TEXT,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE audit_logs IS '审计日志表 - 记录所有重要操作,用于安全审计';
COMMENT ON COLUMN audit_logs.action IS '操作类型,如: CREATE, UPDATE, DELETE, LOGIN, LOGOUT, PAYMENT等';
COMMENT ON COLUMN audit_logs.old_values IS '操作前的数据快照,用于审计和回滚';
COMMENT ON COLUMN audit_logs.new_values IS '操作后的数据快照';
CREATE INDEX idx_audit_logs_actor_id ON audit_logs(actor_id);
CREATE INDEX idx_audit_logs_actor_type ON audit_logs(actor_type);
CREATE INDEX idx_audit_logs_action ON audit_logs(action);
CREATE INDEX idx_audit_logs_entity_type ON audit_logs(entity_type);
CREATE INDEX idx_audit_logs_entity_id ON audit_logs(entity_id);
CREATE INDEX idx_audit_logs_created_at ON audit_logs(created_at DESC);
-- 按时间范围查询优化
CREATE INDEX idx_audit_logs_created_at_brin ON audit_logs USING BRIN(created_at);
-- ===========================================
-- 发件箱表 (outbox)
-- 事务发件箱模式确保消息可靠发送到Kafka
-- ===========================================
CREATE TABLE outbox (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 聚合根类型Order, Payment, User
aggregate_type VARCHAR(100) NOT NULL,
-- 聚合根ID
aggregate_id UUID NOT NULL,
-- 事件类型OrderCreated, PaymentCompleted
event_type VARCHAR(100) NOT NULL,
-- 事件负载JSON格式的事件数据
payload JSONB NOT NULL,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 处理时间消息发送到Kafka的时间
processed_at TIMESTAMP WITH TIME ZONE,
-- 处理次数(用于重试机制)
retry_count INT DEFAULT 0,
-- 最后错误信息
last_error TEXT
);
COMMENT ON TABLE outbox IS '发件箱表 - 事务发件箱模式,确保事件消息可靠发送';
COMMENT ON COLUMN outbox.aggregate_type IS '聚合根类型,对应领域模型';
COMMENT ON COLUMN outbox.event_type IS '领域事件类型';
CREATE INDEX idx_outbox_unprocessed ON outbox(created_at) WHERE processed_at IS NULL;
CREATE INDEX idx_outbox_aggregate ON outbox(aggregate_type, aggregate_id);
-- ===========================================
-- 知识文档表 (documents)
-- 存储移民知识库文档用于RAG检索
-- ===========================================
CREATE TABLE documents (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 文档标题
title VARCHAR(255) NOT NULL,
-- 文档内容(原始文本)
content TEXT NOT NULL,
-- 移民类别: QMAS, GEP, IANG, TTPS, CIES, TECHTAS, GENERAL
category VARCHAR(50),
-- 标签数组
tags TEXT[],
-- 来源名称
source VARCHAR(255),
-- 来源URL
source_url VARCHAR(500),
-- 文档元数据
metadata JSONB,
-- 文档版本
version INT DEFAULT 1,
-- 是否启用
is_active BOOLEAN DEFAULT TRUE,
-- 最后验证时间(确认信息仍然有效)
last_verified_at TIMESTAMP WITH TIME ZONE,
-- 验证人
verified_by UUID,
-- 创建人
created_by UUID,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE documents IS '知识文档表 - 存储移民知识库文档用于RAG检索增强';
COMMENT ON COLUMN documents.category IS '移民类别GENERAL表示通用知识';
COMMENT ON COLUMN documents.last_verified_at IS '最后验证时间,确保信息的时效性';
CREATE INDEX idx_documents_category ON documents(category);
CREATE INDEX idx_documents_is_active ON documents(is_active);
CREATE INDEX idx_documents_tags ON documents USING GIN(tags);
CREATE INDEX idx_documents_created_at ON documents(created_at);
-- ===========================================
-- 文档向量嵌入表 (document_embeddings)
-- 存储文档分块的向量嵌入,用于相似度搜索
-- ===========================================
CREATE TABLE document_embeddings (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 所属文档ID
document_id UUID REFERENCES documents(id) ON DELETE CASCADE,
-- 分块序号
chunk_index INT NOT NULL,
-- 分块内容
content TEXT NOT NULL,
-- 向量嵌入1536维对应text-embedding-3-small
embedding vector(1536),
-- 分块元数据
metadata JSONB,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE document_embeddings IS '文档向量嵌入表 - 存储文档分块的向量,用于语义搜索';
COMMENT ON COLUMN document_embeddings.embedding IS '1536维向量使用text-embedding-3-small模型生成';
CREATE INDEX idx_document_embeddings_document_id ON document_embeddings(document_id);
-- IVFFlat索引用于快速向量相似度搜索
CREATE INDEX idx_document_embeddings_embedding ON document_embeddings
USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100);
-- ===========================================
-- 系统配置表 (system_configs)
-- 存储系统配置项,支持动态调整
-- ===========================================
CREATE TABLE system_configs (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 配置键(唯一)
key VARCHAR(100) UNIQUE NOT NULL,
-- 配置值JSON格式
value JSONB NOT NULL,
-- 配置分组: SYSTEM, PROMPT, PAYMENT, NOTIFICATION, FEATURE
config_group VARCHAR(50) DEFAULT 'SYSTEM',
-- 配置描述
description TEXT,
-- 是否敏感信息(敏感信息不在日志中显示完整值)
is_sensitive BOOLEAN DEFAULT FALSE,
-- 更新人
updated_by UUID,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE system_configs IS '系统配置表 - 存储可动态调整的系统配置';
COMMENT ON COLUMN system_configs.config_group IS '配置分组,便于管理和查询';
COMMENT ON COLUMN system_configs.is_sensitive IS '敏感配置在日志中脱敏显示';
CREATE INDEX idx_system_configs_group ON system_configs(config_group);
-- ===========================================
-- 管理员用户表 (admin_users)
-- 存储后台管理员信息
-- ===========================================
CREATE TABLE admin_users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 用户名(唯一)
username VARCHAR(100) UNIQUE NOT NULL,
-- 邮箱
email VARCHAR(255),
-- 密码哈希bcrypt
password_hash VARCHAR(255) NOT NULL,
-- 角色: SUPER_ADMIN, ADMIN, OPERATOR, VIEWER
role VARCHAR(50) NOT NULL CHECK (role IN ('SUPER_ADMIN', 'ADMIN', 'OPERATOR', 'VIEWER')),
-- 姓名
display_name VARCHAR(100),
-- 手机号
phone VARCHAR(20),
-- 是否启用
is_active BOOLEAN DEFAULT TRUE,
-- 最后登录时间
last_login_at TIMESTAMP WITH TIME ZONE,
-- 最后登录IP
last_login_ip INET,
-- 登录失败次数(用于账户锁定)
failed_login_attempts INT DEFAULT 0,
-- 账户锁定时间
locked_until TIMESTAMP WITH TIME ZONE,
-- 备注
notes TEXT,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE admin_users IS '管理员用户表 - 存储后台管理员信息';
COMMENT ON COLUMN admin_users.role IS 'SUPER_ADMIN=超级管理员, ADMIN=管理员, OPERATOR=操作员, VIEWER=只读用户';
COMMENT ON COLUMN admin_users.failed_login_attempts IS '连续登录失败次数,超过阈值锁定账户';
CREATE INDEX idx_admin_users_username ON admin_users(username);
CREATE INDEX idx_admin_users_email ON admin_users(email);
CREATE INDEX idx_admin_users_role ON admin_users(role);
CREATE INDEX idx_admin_users_is_active ON admin_users(is_active);
-- ===========================================
-- 经验库表 (experiences)
-- 存储从对话中提取的经验,用于系统自我进化
-- ===========================================
CREATE TABLE experiences (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 经验类型
type VARCHAR(50) NOT NULL
CHECK (type IN ('FAQ_PATTERN', 'USER_CONCERN', 'EFFECTIVE_RESPONSE', 'CONVERSION_PATTERN', 'CONFUSION_POINT')),
-- 模式描述
pattern TEXT NOT NULL,
-- 洞察/经验总结
insight TEXT NOT NULL,
-- 出现频率
frequency INT DEFAULT 1,
-- 置信度0-1
confidence DECIMAL(3, 2) DEFAULT 0.5 CHECK (confidence >= 0 AND confidence <= 1),
-- 相关移民类别
category VARCHAR(50),
-- 来源对话ID列表
source_conversation_ids UUID[],
-- 示例问题
sample_questions TEXT[],
-- 示例回答
sample_responses TEXT[],
-- 元数据
metadata JSONB,
-- 是否已应用
is_applied BOOLEAN DEFAULT FALSE,
-- 应用时间
applied_at TIMESTAMP WITH TIME ZONE,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE experiences IS '经验库表 - 存储从对话中提取的经验,支持系统自我进化';
COMMENT ON COLUMN experiences.type IS '经验类型: FAQ_PATTERN=常见问题模式, USER_CONCERN=用户关注点, EFFECTIVE_RESPONSE=有效回答, CONVERSION_PATTERN=转化模式, CONFUSION_POINT=困惑点';
COMMENT ON COLUMN experiences.confidence IS '置信度,值越高表示该经验越可靠';
CREATE INDEX idx_experiences_type ON experiences(type);
CREATE INDEX idx_experiences_category ON experiences(category);
CREATE INDEX idx_experiences_confidence ON experiences(confidence DESC);
CREATE INDEX idx_experiences_is_applied ON experiences(is_applied);
-- ===========================================
-- 进化日志表 (evolution_logs)
-- 记录系统配置和行为的变更历史
-- ===========================================
CREATE TABLE evolution_logs (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 触发人管理员ID
triggered_by UUID REFERENCES admin_users(id),
-- 变更类型
type VARCHAR(50) NOT NULL
CHECK (type IN ('PROMPT_UPDATE', 'KNOWLEDGE_UPDATE', 'RULE_UPDATE', 'BEHAVIOR_UPDATE')),
-- 变更状态
status VARCHAR(20) NOT NULL DEFAULT 'PROPOSED'
CHECK (status IN ('PROPOSED', 'APPROVED', 'APPLIED', 'ROLLED_BACK', 'REJECTED')),
-- 变更内容
changes JSONB NOT NULL,
-- 变更原因/说明
reason TEXT,
-- 关联的经验ID列表
related_experience_ids UUID[],
-- 审批人
approved_by UUID REFERENCES admin_users(id),
-- 审批时间
approved_at TIMESTAMP WITH TIME ZONE,
-- 应用时间
applied_at TIMESTAMP WITH TIME ZONE,
-- 回滚时间
rollback_at TIMESTAMP WITH TIME ZONE,
-- 回滚原因
rollback_reason TEXT,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE evolution_logs IS '进化日志表 - 记录系统配置和行为的变更历史';
COMMENT ON COLUMN evolution_logs.type IS '变更类型: PROMPT_UPDATE=提示词更新, KNOWLEDGE_UPDATE=知识库更新, RULE_UPDATE=规则更新, BEHAVIOR_UPDATE=行为更新';
COMMENT ON COLUMN evolution_logs.status IS '变更状态流转: PROPOSED -> APPROVED -> APPLIED, 可回滚为ROLLED_BACK';
CREATE INDEX idx_evolution_logs_status ON evolution_logs(status);
CREATE INDEX idx_evolution_logs_type ON evolution_logs(type);
CREATE INDEX idx_evolution_logs_triggered_by ON evolution_logs(triggered_by);
CREATE INDEX idx_evolution_logs_created_at ON evolution_logs(created_at DESC);
-- ===========================================
-- 验证码表 (verification_codes)
-- 存储手机验证码
-- ===========================================
CREATE TABLE verification_codes (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 手机号
phone VARCHAR(20) NOT NULL,
-- 验证码
code VARCHAR(10) NOT NULL,
-- 过期时间
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
-- 是否已使用
is_used BOOLEAN DEFAULT FALSE,
-- 使用时间
used_at TIMESTAMP WITH TIME ZONE,
-- IP地址用于防刷
ip_address INET,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE verification_codes IS '验证码表 - 存储手机验证码,支持防刷和过期机制';
CREATE INDEX idx_verification_codes_phone ON verification_codes(phone);
CREATE INDEX idx_verification_codes_expires_at ON verification_codes(expires_at);
CREATE INDEX idx_verification_codes_ip ON verification_codes(ip_address);
-- ===========================================
-- 服务定价表 (service_pricing)
-- 存储各类服务的定价信息
-- ===========================================
CREATE TABLE service_pricing (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 服务类型
service_type VARCHAR(50) NOT NULL
CHECK (service_type IN ('ASSESSMENT', 'CONSULTATION', 'DOCUMENT_REVIEW')),
-- 移民类别
category VARCHAR(50),
-- 价格
price DECIMAL(10, 2) NOT NULL,
-- 原价(用于显示折扣)
original_price DECIMAL(10, 2),
-- 货币
currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
-- 服务描述
description TEXT,
-- 服务详情JSON格式
details JSONB,
-- 是否启用
is_active BOOLEAN DEFAULT TRUE,
-- 生效开始时间
effective_from TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 生效结束时间
effective_until TIMESTAMP WITH TIME ZONE,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 唯一约束
UNIQUE(service_type, category)
);
COMMENT ON TABLE service_pricing IS '服务定价表 - 存储各类服务的定价信息';
COMMENT ON COLUMN service_pricing.original_price IS '原价,用于显示折扣效果';
COMMENT ON COLUMN service_pricing.effective_from IS '价格生效开始时间,支持定时调价';
CREATE INDEX idx_service_pricing_service_type ON service_pricing(service_type);
CREATE INDEX idx_service_pricing_is_active ON service_pricing(is_active);
-- ===========================================
-- 优惠券表 (coupons)
-- 存储优惠券信息
-- ===========================================
CREATE TABLE coupons (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 优惠券码
code VARCHAR(50) UNIQUE NOT NULL,
-- 优惠券名称
name VARCHAR(100) NOT NULL,
-- 优惠类型: FIXED(固定金额), PERCENTAGE(百分比)
discount_type VARCHAR(20) NOT NULL CHECK (discount_type IN ('FIXED', 'PERCENTAGE')),
-- 优惠值(固定金额或百分比)
discount_value DECIMAL(10, 2) NOT NULL,
-- 最低消费金额
min_amount DECIMAL(10, 2) DEFAULT 0,
-- 最高优惠金额(百分比优惠时的上限)
max_discount DECIMAL(10, 2),
-- 适用服务类型(为空表示全部适用)
applicable_services TEXT[],
-- 适用移民类别(为空表示全部适用)
applicable_categories TEXT[],
-- 总发行量
total_quantity INT,
-- 已使用数量
used_quantity INT DEFAULT 0,
-- 每人限用次数
per_user_limit INT DEFAULT 1,
-- 生效时间
valid_from TIMESTAMP WITH TIME ZONE NOT NULL,
-- 失效时间
valid_until TIMESTAMP WITH TIME ZONE NOT NULL,
-- 是否启用
is_active BOOLEAN DEFAULT TRUE,
-- 备注
notes TEXT,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE coupons IS '优惠券表 - 存储优惠券信息,支持固定金额和百分比折扣';
CREATE INDEX idx_coupons_code ON coupons(code);
CREATE INDEX idx_coupons_is_active ON coupons(is_active);
CREATE INDEX idx_coupons_valid_until ON coupons(valid_until);
-- ===========================================
-- 用户优惠券表 (user_coupons)
-- 存储用户领取/使用的优惠券
-- ===========================================
CREATE TABLE user_coupons (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 用户ID
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
-- 优惠券ID
coupon_id UUID REFERENCES coupons(id) ON DELETE CASCADE,
-- 状态: AVAILABLE(可用), USED(已使用), EXPIRED(已过期)
status VARCHAR(20) NOT NULL DEFAULT 'AVAILABLE'
CHECK (status IN ('AVAILABLE', 'USED', 'EXPIRED')),
-- 使用的订单ID
used_order_id UUID REFERENCES orders(id) ON DELETE SET NULL,
-- 使用时间
used_at TIMESTAMP WITH TIME ZONE,
-- 领取时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE user_coupons IS '用户优惠券表 - 记录用户领取和使用优惠券的情况';
CREATE INDEX idx_user_coupons_user_id ON user_coupons(user_id);
CREATE INDEX idx_user_coupons_coupon_id ON user_coupons(coupon_id);
CREATE INDEX idx_user_coupons_status ON user_coupons(status);
-- ===========================================
-- 插入默认数据
-- ===========================================
-- 默认管理员用户 (密码: admin123)
INSERT INTO admin_users (username, email, password_hash, role, display_name)
VALUES ('admin', 'admin@iconsulting.com', '$2b$10$rqKu.wB1E8z9vQzKK0FZMuXz.B7xPc5S7BUTr6G9TkVdEX5C0Q.Wy', 'SUPER_ADMIN', '系统管理员');
-- 默认系统配置
INSERT INTO system_configs (key, value, config_group, description) VALUES
('system_prompt_identity', '"专业、友善、耐心的香港移民顾问"', 'PROMPT', '系统身份定位'),
('system_prompt_style', '"专业但不生硬,用简洁明了的语言解答"', 'PROMPT', '对话风格'),
('system_prompt_rules', '["只回答移民相关问题", "复杂评估建议付费服务", "不做法律承诺"]', 'PROMPT', '系统行为规则'),
('max_free_messages_per_day', '50', 'SYSTEM', '每日免费消息数限制'),
('max_conversation_context_messages', '20', 'SYSTEM', '对话上下文最大消息数'),
('assessment_price_default', '99', 'PAYMENT', '默认评估价格(元)'),
('payment_timeout_minutes', '30', 'PAYMENT', '支付超时时间(分钟)'),
('sms_rate_limit_per_hour', '5', 'SYSTEM', '每小时短信发送限制'),
('enable_anonymous_chat', 'true', 'FEATURE', '是否允许匿名用户聊天'),
('require_phone_for_payment', 'true', 'FEATURE', '支付时是否要求手机验证');
-- 默认服务定价
INSERT INTO service_pricing (service_type, category, price, original_price, currency, description) VALUES
('ASSESSMENT', 'QMAS', 99.00, 199.00, 'CNY', '优才计划移民资格评估'),
('ASSESSMENT', 'GEP', 99.00, 199.00, 'CNY', '专才计划移民资格评估'),
('ASSESSMENT', 'IANG', 79.00, 149.00, 'CNY', '留学IANG移民资格评估'),
('ASSESSMENT', 'TTPS', 99.00, 199.00, 'CNY', '高才通移民资格评估'),
('ASSESSMENT', 'CIES', 199.00, 399.00, 'CNY', '投资移民资格评估'),
('ASSESSMENT', 'TECHTAS', 99.00, 199.00, 'CNY', '科技人才移民资格评估');
-- ===========================================
-- 创建函数和触发器
-- ===========================================
-- 更新 updated_at 时间戳的通用函数
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ language 'plpgsql';
-- 为所有需要的表添加更新时间触发器
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_conversations_updated_at BEFORE UPDATE ON conversations FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_orders_updated_at BEFORE UPDATE ON orders FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_payments_updated_at BEFORE UPDATE ON payments FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_documents_updated_at BEFORE UPDATE ON documents FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_system_configs_updated_at BEFORE UPDATE ON system_configs FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_admin_users_updated_at BEFORE UPDATE ON admin_users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_experiences_updated_at BEFORE UPDATE ON experiences FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_service_pricing_updated_at BEFORE UPDATE ON service_pricing FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_coupons_updated_at BEFORE UPDATE ON coupons FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_ledger_entries_updated_at BEFORE UPDATE ON ledger_entries FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_daily_statistics_updated_at BEFORE UPDATE ON daily_statistics FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_monthly_financial_reports_updated_at BEFORE UPDATE ON monthly_financial_reports FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- 更新对话消息计数的函数
CREATE OR REPLACE FUNCTION update_conversation_message_count()
RETURNS TRIGGER AS $$
BEGIN
UPDATE conversations
SET
message_count = message_count + 1,
user_message_count = user_message_count + CASE WHEN NEW.role = 'user' THEN 1 ELSE 0 END,
assistant_message_count = assistant_message_count + CASE WHEN NEW.role = 'assistant' THEN 1 ELSE 0 END,
total_input_tokens = total_input_tokens + COALESCE(NEW.input_tokens, 0),
total_output_tokens = total_output_tokens + COALESCE(NEW.output_tokens, 0)
WHERE id = NEW.conversation_id;
RETURN NEW;
END;
$$ language 'plpgsql';
CREATE TRIGGER increment_conversation_message_count
AFTER INSERT ON messages
FOR EACH ROW
EXECUTE FUNCTION update_conversation_message_count();
-- 生成订单号的函数
CREATE OR REPLACE FUNCTION generate_order_no()
RETURNS TRIGGER AS $$
DECLARE
seq_val INT;
BEGIN
-- 获取当天的序号
SELECT COALESCE(MAX(CAST(SUBSTRING(order_no FROM 12) AS INT)), 0) + 1 INTO seq_val
FROM orders
WHERE order_no LIKE 'ORD' || TO_CHAR(NOW(), 'YYYYMMDD') || '%';
NEW.order_no := 'ORD' || TO_CHAR(NOW(), 'YYYYMMDD') || LPAD(seq_val::TEXT, 6, '0');
RETURN NEW;
END;
$$ language 'plpgsql';
CREATE TRIGGER generate_order_no_trigger
BEFORE INSERT ON orders
FOR EACH ROW
WHEN (NEW.order_no IS NULL)
EXECUTE FUNCTION generate_order_no();
-- 生成分类账流水号的函数
CREATE OR REPLACE FUNCTION generate_ledger_entry_no()
RETURNS TRIGGER AS $$
DECLARE
seq_val INT;
BEGIN
SELECT COALESCE(MAX(CAST(SUBSTRING(entry_no FROM 11) AS INT)), 0) + 1 INTO seq_val
FROM ledger_entries
WHERE entry_no LIKE 'LE' || TO_CHAR(NOW(), 'YYYYMMDD') || '%';
NEW.entry_no := 'LE' || TO_CHAR(NOW(), 'YYYYMMDD') || LPAD(seq_val::TEXT, 6, '0');
NEW.accounting_period := TO_CHAR(NOW(), 'YYYY-MM');
RETURN NEW;
END;
$$ language 'plpgsql';
CREATE TRIGGER generate_ledger_entry_no_trigger
BEFORE INSERT ON ledger_entries
FOR EACH ROW
WHEN (NEW.entry_no IS NULL)
EXECUTE FUNCTION generate_ledger_entry_no();
-- 支付成功后自动创建分类账条目的函数
CREATE OR REPLACE FUNCTION create_ledger_entry_on_payment()
RETURNS TRIGGER AS $$
BEGIN
-- 仅当支付状态变为COMPLETED时创建收入流水
IF NEW.status = 'COMPLETED' AND (OLD.status IS NULL OR OLD.status != 'COMPLETED') THEN
INSERT INTO ledger_entries (
entry_type,
order_id,
payment_id,
user_id,
amount,
currency,
channel,
transaction_id,
description,
status
)
SELECT
'INCOME',
NEW.order_id,
NEW.id,
o.user_id,
NEW.amount,
NEW.currency,
NEW.method,
NEW.transaction_id,
'订单支付: ' || o.order_no || ' - ' || o.service_type || COALESCE(' (' || o.service_category || ')', ''),
'CONFIRMED'
FROM orders o
WHERE o.id = NEW.order_id;
END IF;
-- 退款时创建退款流水
IF NEW.status = 'REFUNDED' AND OLD.status != 'REFUNDED' THEN
INSERT INTO ledger_entries (
entry_type,
order_id,
payment_id,
user_id,
amount,
currency,
channel,
transaction_id,
description,
status
)
SELECT
'REFUND',
NEW.order_id,
NEW.id,
o.user_id,
-NEW.amount, -- 退款为负数
NEW.currency,
NEW.method,
NEW.transaction_id,
'订单退款: ' || o.order_no,
'CONFIRMED'
FROM orders o
WHERE o.id = NEW.order_id;
END IF;
RETURN NEW;
END;
$$ language 'plpgsql';
CREATE TRIGGER create_ledger_entry_on_payment_trigger
AFTER UPDATE ON payments
FOR EACH ROW
EXECUTE FUNCTION create_ledger_entry_on_payment();
-- ===========================================
-- 创建统计视图
-- ===========================================
-- 今日实时统计视图
CREATE OR REPLACE VIEW v_today_statistics AS
SELECT
COUNT(DISTINCT CASE WHEN u.created_at >= CURRENT_DATE THEN u.id END) AS new_users_today,
COUNT(DISTINCT CASE WHEN u.created_at >= CURRENT_DATE AND u.type = 'REGISTERED' THEN u.id END) AS new_registered_today,
COUNT(DISTINCT CASE WHEN c.created_at >= CURRENT_DATE THEN c.id END) AS new_conversations_today,
COUNT(CASE WHEN m.created_at >= CURRENT_DATE THEN 1 END) AS messages_today,
COUNT(DISTINCT CASE WHEN o.created_at >= CURRENT_DATE THEN o.id END) AS new_orders_today,
COUNT(DISTINCT CASE WHEN o.paid_at >= CURRENT_DATE THEN o.id END) AS paid_orders_today,
COALESCE(SUM(CASE WHEN o.paid_at >= CURRENT_DATE THEN o.paid_amount END), 0) AS revenue_today
FROM users u
FULL OUTER JOIN conversations c ON TRUE
FULL OUTER JOIN messages m ON TRUE
FULL OUTER JOIN orders o ON TRUE;
COMMENT ON VIEW v_today_statistics IS '今日实时统计视图 - 展示当天的关键指标';
-- 移民类别统计视图
CREATE OR REPLACE VIEW v_category_statistics AS
SELECT
c.category,
COUNT(DISTINCT c.id) AS total_conversations,
COUNT(DISTINCT c.user_id) AS unique_users,
COUNT(DISTINCT CASE WHEN c.has_converted THEN c.id END) AS converted_conversations,
ROUND(COUNT(DISTINCT CASE WHEN c.has_converted THEN c.id END)::NUMERIC /
NULLIF(COUNT(DISTINCT c.id), 0) * 100, 2) AS conversion_rate,
COALESCE(SUM(o.paid_amount), 0) AS total_revenue
FROM conversations c
LEFT JOIN orders o ON c.id = o.conversation_id AND o.status = 'PAID'
WHERE c.category IS NOT NULL
GROUP BY c.category
ORDER BY total_conversations DESC;
COMMENT ON VIEW v_category_statistics IS '移民类别统计视图 - 按类别汇总对话和转化数据';
-- 渠道统计视图
CREATE OR REPLACE VIEW v_channel_statistics AS
SELECT
u.source_channel,
COUNT(DISTINCT u.id) AS total_users,
COUNT(DISTINCT CASE WHEN u.type = 'REGISTERED' THEN u.id END) AS registered_users,
COUNT(DISTINCT c.id) AS total_conversations,
COALESCE(SUM(o.paid_amount), 0) AS total_revenue,
COUNT(DISTINCT CASE WHEN o.status = 'PAID' THEN o.id END) AS paid_orders
FROM users u
LEFT JOIN conversations c ON u.id = c.user_id
LEFT JOIN orders o ON u.id = o.user_id AND o.status = 'PAID'
GROUP BY u.source_channel
ORDER BY total_users DESC;
COMMENT ON VIEW v_channel_statistics IS '渠道统计视图 - 按来源渠道汇总用户和收入数据';
-- ===========================================
-- 知识文章表 (knowledge_articles)
-- 存储移民相关的知识内容支持RAG检索
-- ===========================================
CREATE TABLE knowledge_articles (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 文章标题
title VARCHAR(500) NOT NULL,
-- 文章内容纯文本或Markdown
content TEXT NOT NULL,
-- 内容摘要(用于预览)
summary TEXT,
-- 移民类别: QMAS, GEP, IANG, TTPS, CIES, TechTAS, GENERAL
category VARCHAR(50) NOT NULL,
-- 内容标签JSON数组
tags TEXT[] DEFAULT '{}',
-- 来源: MANUAL(手动), CRAWL(爬取), EXTRACT(对话提取), IMPORT(批量导入)
source VARCHAR(20) NOT NULL DEFAULT 'MANUAL'
CHECK (source IN ('MANUAL', 'CRAWL', 'EXTRACT', 'IMPORT')),
-- 来源URL
source_url VARCHAR(1000),
-- 内容向量(用于语义搜索)
embedding VECTOR(1536),
-- 是否已发布
is_published BOOLEAN DEFAULT FALSE,
-- 引用次数(被对话引用)
citation_count INT DEFAULT 0,
-- 点赞数
helpful_count INT DEFAULT 0,
-- 点踩数
unhelpful_count INT DEFAULT 0,
-- 质量评分 0-100
quality_score INT DEFAULT 50 CHECK (quality_score >= 0 AND quality_score <= 100),
-- 创建者ID
created_by UUID,
-- 更新者ID
updated_by UUID,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE knowledge_articles IS '知识文章表 - 存储移民相关知识支持RAG语义检索';
COMMENT ON COLUMN knowledge_articles.category IS '移民类别,用于分类筛选';
COMMENT ON COLUMN knowledge_articles.source IS '内容来源MANUAL手动添加,CRAWL网页爬取,EXTRACT对话提取,IMPORT批量导入';
COMMENT ON COLUMN knowledge_articles.embedding IS '文章向量1536维用于pgvector语义搜索';
COMMENT ON COLUMN knowledge_articles.quality_score IS '质量评分,根据引用和反馈自动计算';
CREATE INDEX idx_knowledge_articles_category ON knowledge_articles(category);
CREATE INDEX idx_knowledge_articles_published ON knowledge_articles(is_published);
CREATE INDEX idx_knowledge_articles_quality ON knowledge_articles(quality_score DESC);
CREATE INDEX idx_knowledge_articles_embedding ON knowledge_articles USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100);
-- ===========================================
-- 知识块表 (knowledge_chunks)
-- 将文章拆分为更小的检索单元提高RAG精确度
-- ===========================================
CREATE TABLE knowledge_chunks (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 所属文章ID
article_id UUID NOT NULL REFERENCES knowledge_articles(id) ON DELETE CASCADE,
-- 块内容
content TEXT NOT NULL,
-- 块序号(在文章中的位置)
chunk_index INT NOT NULL,
-- 块类型: TITLE(标题), PARAGRAPH(段落), LIST(列表), TABLE(表格), CODE(代码), FAQ(问答)
chunk_type VARCHAR(20) NOT NULL DEFAULT 'PARAGRAPH'
CHECK (chunk_type IN ('TITLE', 'PARAGRAPH', 'LIST', 'TABLE', 'CODE', 'FAQ')),
-- 内容向量
embedding VECTOR(1536),
-- 元数据(如章节标题、前后块链接等)
metadata JSONB DEFAULT '{}',
-- Token数量估算
token_count INT DEFAULT 0,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE knowledge_chunks IS '知识块表 - 文章分块用于精确RAG检索';
COMMENT ON COLUMN knowledge_chunks.chunk_type IS '块类型,用于理解内容结构';
COMMENT ON COLUMN knowledge_chunks.metadata IS '元数据,包含章节标题、前后块链接等';
CREATE INDEX idx_knowledge_chunks_article ON knowledge_chunks(article_id);
CREATE INDEX idx_knowledge_chunks_embedding ON knowledge_chunks USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100);
-- ===========================================
-- 用户记忆表 (user_memories)
-- 存储用户的长期记忆,用于个性化对话
-- ===========================================
CREATE TABLE user_memories (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 用户ID
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
-- 记忆类型
memory_type VARCHAR(30) NOT NULL
CHECK (memory_type IN (
'PERSONAL_INFO', -- 个人信息
'WORK_EXPERIENCE', -- 工作经历
'EDUCATION', -- 教育背景
'LANGUAGE', -- 语言能力
'IMMIGRATION_INTENT', -- 移民意向
'PREFERRED_CATEGORY', -- 倾向类别
'ASSESSMENT_RESULT', -- 评估结果
'QUESTION_ASKED', -- 问过的问题
'CONCERN', -- 关注点
'PREFERENCE', -- 偏好设置
'CUSTOM' -- 自定义
)),
-- 记忆内容
content TEXT NOT NULL,
-- 重要性 0-100
importance INT DEFAULT 50 CHECK (importance >= 0 AND importance <= 100),
-- 来源对话ID
source_conversation_id UUID,
-- 相关移民类别
related_category VARCHAR(50),
-- 内容向量
embedding VECTOR(1536),
-- 访问次数
access_count INT DEFAULT 0,
-- 最后访问时间
last_accessed_at TIMESTAMP WITH TIME ZONE,
-- 是否已过期
is_expired BOOLEAN DEFAULT FALSE,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE user_memories IS '用户记忆表 - 存储用户长期记忆,支持个性化对话';
COMMENT ON COLUMN user_memories.memory_type IS '记忆类型,用于分类管理用户信息';
COMMENT ON COLUMN user_memories.importance IS '重要性评分,影响检索优先级';
COMMENT ON COLUMN user_memories.is_expired IS '是否过期,用户情况变化时标记';
CREATE INDEX idx_user_memories_user ON user_memories(user_id);
CREATE INDEX idx_user_memories_type ON user_memories(memory_type);
CREATE INDEX idx_user_memories_importance ON user_memories(user_id, importance DESC);
CREATE INDEX idx_user_memories_embedding ON user_memories USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100);
-- ===========================================
-- 系统经验表 (system_experiences)
-- 存储系统从对话中学习到的经验,用于自我进化
-- ===========================================
CREATE TABLE system_experiences (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 经验类型
experience_type VARCHAR(30) NOT NULL
CHECK (experience_type IN (
'COMMON_QUESTION', -- 常见问题
'ANSWER_TEMPLATE', -- 回答模板
'CLARIFICATION', -- 澄清方式
'USER_PATTERN', -- 用户行为模式
'CONVERSION_TRIGGER', -- 转化触发点
'KNOWLEDGE_GAP', -- 知识缺口
'KNOWLEDGE_UPDATE', -- 知识更新
'CONVERSATION_SKILL', -- 对话技巧
'OBJECTION_HANDLING', -- 异议处理
'CUSTOM' -- 自定义
)),
-- 经验内容
content TEXT NOT NULL,
-- 置信度 0-100
confidence INT DEFAULT 50 CHECK (confidence >= 0 AND confidence <= 100),
-- 应用场景描述
scenario TEXT NOT NULL,
-- 相关移民类别
related_category VARCHAR(50),
-- 来源对话ID列表
source_conversation_ids UUID[] DEFAULT '{}',
-- 验证状态: PENDING(待验证), APPROVED(已通过), REJECTED(已拒绝), DEPRECATED(已弃用)
verification_status VARCHAR(20) NOT NULL DEFAULT 'PENDING'
CHECK (verification_status IN ('PENDING', 'APPROVED', 'REJECTED', 'DEPRECATED')),
-- 验证者ID
verified_by UUID,
-- 验证时间
verified_at TIMESTAMP WITH TIME ZONE,
-- 使用次数
usage_count INT DEFAULT 0,
-- 正面反馈次数
positive_count INT DEFAULT 0,
-- 负面反馈次数
negative_count INT DEFAULT 0,
-- 内容向量
embedding VECTOR(1536),
-- 是否激活使用
is_active BOOLEAN DEFAULT FALSE,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE system_experiences IS '系统经验表 - 从对话中学习的经验,支持系统自我进化';
COMMENT ON COLUMN system_experiences.experience_type IS '经验类型,用于分类应用';
COMMENT ON COLUMN system_experiences.confidence IS '置信度,根据来源数量和反馈计算';
COMMENT ON COLUMN system_experiences.verification_status IS '验证状态,需管理员审核后才能激活';
COMMENT ON COLUMN system_experiences.is_active IS '是否激活,只有通过审核才能在对话中使用';
CREATE INDEX idx_system_experiences_type ON system_experiences(experience_type);
CREATE INDEX idx_system_experiences_status ON system_experiences(verification_status);
CREATE INDEX idx_system_experiences_active ON system_experiences(is_active);
CREATE INDEX idx_system_experiences_confidence ON system_experiences(confidence DESC);
CREATE INDEX idx_system_experiences_embedding ON system_experiences USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100);
-- ===========================================
-- 管理员表 (admins)
-- 管理后台用户,支持多角色权限
-- ===========================================
CREATE TABLE admins (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
-- 用户名(登录用)
username VARCHAR(50) NOT NULL UNIQUE,
-- 密码哈希
password_hash VARCHAR(255) NOT NULL,
-- 姓名
name VARCHAR(100) NOT NULL,
-- 邮箱
email VARCHAR(255),
-- 手机号
phone VARCHAR(20),
-- 角色: SUPER_ADMIN(超级管理员), ADMIN(管理员), OPERATOR(运营), VIEWER(只读)
role VARCHAR(20) NOT NULL DEFAULT 'OPERATOR'
CHECK (role IN ('SUPER_ADMIN', 'ADMIN', 'OPERATOR', 'VIEWER')),
-- 权限列表(细粒度权限控制)
permissions JSONB DEFAULT '[]',
-- 头像URL
avatar VARCHAR(500),
-- 最后登录时间
last_login_at TIMESTAMP WITH TIME ZONE,
-- 最后登录IP
last_login_ip VARCHAR(50),
-- 是否启用
is_active BOOLEAN DEFAULT TRUE,
-- 创建时间
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- 更新时间
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
COMMENT ON TABLE admins IS '管理员表 - 管理后台用户,支持多角色权限';
COMMENT ON COLUMN admins.role IS '角色SUPER_ADMIN超管,ADMIN管理员,OPERATOR运营,VIEWER只读';
COMMENT ON COLUMN admins.permissions IS '细粒度权限列表JSON数组格式';
CREATE INDEX idx_admins_username ON admins(username);
CREATE INDEX idx_admins_role ON admins(role);
CREATE INDEX idx_admins_active ON admins(is_active);
-- 插入默认超级管理员(密码: admin123实际生产环境需要修改
INSERT INTO admins (username, password_hash, name, role, permissions) VALUES
('admin', '$2b$10$rQNDjKwYXOw8FNrFcD3e0.T8KCqVJLqDQT9gQR2KPnDqPvqK8VpKi', '系统管理员', 'SUPER_ADMIN', '["*"]');
-- ===========================================
-- 结束
-- ===========================================