Files
012-kaopeilian/backend/migrations/admin_platform_schema.sql
111 998211c483 feat: 初始化考培练系统项目
- 从服务器拉取完整代码
- 按框架规范整理项目结构
- 配置 Drone CI 测试环境部署
- 包含后端(FastAPI)、前端(Vue3)、管理端

技术栈: Vue3 + TypeScript + FastAPI + MySQL
2026-01-24 19:33:28 +08:00

299 lines
18 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
-- ============================================
-- 考培练系统 SaaS 超级管理后台数据库架构
-- 数据库名kaopeilian_admin
-- 创建日期2026-01-18
-- ============================================
-- 创建数据库
CREATE DATABASE IF NOT EXISTS kaopeilian_admin
CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci;
USE kaopeilian_admin;
-- ============================================
-- 1. 平台管理员表 (admin_users)
-- ============================================
CREATE TABLE IF NOT EXISTS `admin_users` (
`id` INT AUTO_INCREMENT PRIMARY KEY,
`username` VARCHAR(50) NOT NULL UNIQUE COMMENT '用户名',
`email` VARCHAR(100) UNIQUE COMMENT '邮箱',
`phone` VARCHAR(20) UNIQUE COMMENT '手机号',
`password_hash` VARCHAR(200) NOT NULL COMMENT '密码哈希',
`full_name` VARCHAR(100) COMMENT '姓名',
`avatar_url` VARCHAR(500) COMMENT '头像URL',
`role` VARCHAR(20) DEFAULT 'admin' COMMENT '角色: superadmin, admin, viewer',
`is_active` BOOLEAN DEFAULT TRUE COMMENT '是否激活',
`last_login_at` DATETIME COMMENT '最后登录时间',
`last_login_ip` VARCHAR(50) COMMENT '最后登录IP',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
`updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_role (role),
INDEX idx_is_active (is_active)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='平台管理员表';
-- ============================================
-- 2. 租户表 (tenants)
-- ============================================
CREATE TABLE IF NOT EXISTS `tenants` (
`id` INT AUTO_INCREMENT PRIMARY KEY,
`code` VARCHAR(20) NOT NULL UNIQUE COMMENT '租户编码hua, yy, hl',
`name` VARCHAR(100) NOT NULL COMMENT '租户名称',
`display_name` VARCHAR(200) COMMENT '显示名称(如:华尔倍丽-考培练系统)',
`domain` VARCHAR(200) NOT NULL COMMENT '域名hua.ireborn.com.cn',
`logo_url` VARCHAR(500) COMMENT 'Logo URL',
`favicon_url` VARCHAR(500) COMMENT 'Favicon URL',
`contact_name` VARCHAR(50) COMMENT '联系人',
`contact_phone` VARCHAR(20) COMMENT '联系电话',
`contact_email` VARCHAR(100) COMMENT '联系邮箱',
`industry` VARCHAR(50) DEFAULT 'medical_beauty' COMMENT '行业medical_beauty, pet, education',
`status` VARCHAR(20) DEFAULT 'active' COMMENT '状态active, inactive, suspended',
`expire_at` DATE COMMENT '服务到期日期',
`remarks` TEXT COMMENT '备注',
`created_by` INT COMMENT '创建人ID',
`updated_by` INT COMMENT '更新人ID',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
`updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (created_by) REFERENCES admin_users(id) ON DELETE SET NULL,
FOREIGN KEY (updated_by) REFERENCES admin_users(id) ON DELETE SET NULL,
INDEX idx_code (code),
INDEX idx_status (status),
INDEX idx_domain (domain)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='租户表';
-- ============================================
-- 3. 租户配置表 (tenant_configs)
-- Key-Value 形式存储各类配置
-- ============================================
CREATE TABLE IF NOT EXISTS `tenant_configs` (
`id` INT AUTO_INCREMENT PRIMARY KEY,
`tenant_id` INT NOT NULL COMMENT '租户ID',
`config_group` VARCHAR(50) NOT NULL COMMENT '配置分组database, redis, dify, coze, ai, yanji, security',
`config_key` VARCHAR(100) NOT NULL COMMENT '配置键',
`config_value` TEXT COMMENT '配置值',
`value_type` VARCHAR(20) DEFAULT 'string' COMMENT '值类型string, int, bool, json, secret',
`is_encrypted` BOOLEAN DEFAULT FALSE COMMENT '是否加密存储',
`description` VARCHAR(500) COMMENT '配置说明',
`is_required` BOOLEAN DEFAULT FALSE COMMENT '是否必填',
`default_value` TEXT COMMENT '默认值',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
`updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE,
UNIQUE KEY uk_tenant_group_key (tenant_id, config_group, config_key),
INDEX idx_tenant_id (tenant_id),
INDEX idx_config_group (config_group)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='租户配置表';
-- ============================================
-- 4. AI 提示词模板表 (ai_prompts)
-- ============================================
CREATE TABLE IF NOT EXISTS `ai_prompts` (
`id` INT AUTO_INCREMENT PRIMARY KEY,
`code` VARCHAR(50) NOT NULL COMMENT '提示词编码knowledge_analysis, exam_generator',
`name` VARCHAR(100) NOT NULL COMMENT '提示词名称',
`description` TEXT COMMENT '提示词说明',
`module` VARCHAR(50) NOT NULL COMMENT '所属模块course, exam, practice, ability',
`system_prompt` TEXT NOT NULL COMMENT '系统提示词',
`user_prompt_template` TEXT COMMENT '用户提示词模板',
`variables` JSON COMMENT '变量列表(如:["course_name", "content"]',
`output_schema` JSON COMMENT '输出 JSON Schema',
`model_recommendation` VARCHAR(100) COMMENT '推荐模型',
`max_tokens` INT DEFAULT 4096 COMMENT '最大 token 数',
`temperature` DECIMAL(3,2) DEFAULT 0.70 COMMENT '温度参数',
`is_system` BOOLEAN DEFAULT TRUE COMMENT '是否系统内置(内置不可删除)',
`is_active` BOOLEAN DEFAULT TRUE COMMENT '是否启用',
`version` INT DEFAULT 1 COMMENT '当前版本号',
`created_by` INT COMMENT '创建人ID',
`updated_by` INT COMMENT '更新人ID',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
`updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (created_by) REFERENCES admin_users(id) ON DELETE SET NULL,
FOREIGN KEY (updated_by) REFERENCES admin_users(id) ON DELETE SET NULL,
UNIQUE KEY uk_code (code),
INDEX idx_module (module),
INDEX idx_is_active (is_active)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='AI提示词模板表';
-- ============================================
-- 5. AI 提示词版本历史表 (ai_prompt_versions)
-- ============================================
CREATE TABLE IF NOT EXISTS `ai_prompt_versions` (
`id` INT AUTO_INCREMENT PRIMARY KEY,
`prompt_id` INT NOT NULL COMMENT '提示词ID',
`version` INT NOT NULL COMMENT '版本号',
`system_prompt` TEXT NOT NULL COMMENT '系统提示词',
`user_prompt_template` TEXT COMMENT '用户提示词模板',
`variables` JSON COMMENT '变量列表',
`output_schema` JSON COMMENT '输出 JSON Schema',
`change_summary` VARCHAR(500) COMMENT '变更说明',
`created_by` INT COMMENT '创建人ID',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (prompt_id) REFERENCES ai_prompts(id) ON DELETE CASCADE,
FOREIGN KEY (created_by) REFERENCES admin_users(id) ON DELETE SET NULL,
UNIQUE KEY uk_prompt_version (prompt_id, version),
INDEX idx_prompt_id (prompt_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='AI提示词版本历史表';
-- ============================================
-- 6. 租户自定义提示词表 (tenant_prompts)
-- 租户可覆盖系统默认提示词
-- ============================================
CREATE TABLE IF NOT EXISTS `tenant_prompts` (
`id` INT AUTO_INCREMENT PRIMARY KEY,
`tenant_id` INT NOT NULL COMMENT '租户ID',
`prompt_id` INT NOT NULL COMMENT '基础提示词ID',
`system_prompt` TEXT COMMENT '自定义系统提示词(为空则使用默认)',
`user_prompt_template` TEXT COMMENT '自定义用户提示词模板',
`is_active` BOOLEAN DEFAULT TRUE COMMENT '是否启用自定义',
`created_by` INT COMMENT '创建人ID',
`updated_by` INT COMMENT '更新人ID',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
`updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE,
FOREIGN KEY (prompt_id) REFERENCES ai_prompts(id) ON DELETE CASCADE,
FOREIGN KEY (created_by) REFERENCES admin_users(id) ON DELETE SET NULL,
FOREIGN KEY (updated_by) REFERENCES admin_users(id) ON DELETE SET NULL,
UNIQUE KEY uk_tenant_prompt (tenant_id, prompt_id),
INDEX idx_tenant_id (tenant_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='租户自定义提示词表';
-- ============================================
-- 7. 功能开关表 (feature_switches)
-- ============================================
CREATE TABLE IF NOT EXISTS `feature_switches` (
`id` INT AUTO_INCREMENT PRIMARY KEY,
`tenant_id` INT COMMENT '租户IDNULL表示全局默认',
`feature_code` VARCHAR(50) NOT NULL COMMENT '功能编码',
`feature_name` VARCHAR(100) NOT NULL COMMENT '功能名称',
`feature_group` VARCHAR(50) COMMENT '功能分组exam, practice, broadcast, yanji',
`is_enabled` BOOLEAN DEFAULT TRUE COMMENT '是否启用',
`config` JSON COMMENT '功能配置参数',
`description` VARCHAR(500) COMMENT '功能说明',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
`updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE,
UNIQUE KEY uk_tenant_feature (tenant_id, feature_code),
INDEX idx_tenant_id (tenant_id),
INDEX idx_feature_code (feature_code)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='功能开关表';
-- ============================================
-- 8. 操作审计日志表 (operation_logs)
-- ============================================
CREATE TABLE IF NOT EXISTS `operation_logs` (
`id` BIGINT AUTO_INCREMENT PRIMARY KEY,
`admin_user_id` INT COMMENT '操作人ID',
`admin_username` VARCHAR(50) COMMENT '操作人用户名',
`tenant_id` INT COMMENT '涉及租户ID',
`tenant_code` VARCHAR(20) COMMENT '涉及租户编码',
`operation_type` VARCHAR(50) NOT NULL COMMENT '操作类型create, update, delete, enable, disable',
`resource_type` VARCHAR(50) NOT NULL COMMENT '资源类型tenant, config, prompt, feature',
`resource_id` INT COMMENT '资源ID',
`resource_name` VARCHAR(200) COMMENT '资源名称',
`old_value` JSON COMMENT '变更前值',
`new_value` JSON COMMENT '变更后值',
`ip_address` VARCHAR(50) COMMENT '操作IP',
`user_agent` VARCHAR(500) COMMENT '浏览器信息',
`remarks` TEXT COMMENT '备注',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
INDEX idx_admin_user_id (admin_user_id),
INDEX idx_tenant_id (tenant_id),
INDEX idx_operation_type (operation_type),
INDEX idx_resource_type (resource_type),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='操作审计日志表';
-- ============================================
-- 9. 配置模板表 (config_templates)
-- 定义各配置项的元数据
-- ============================================
CREATE TABLE IF NOT EXISTS `config_templates` (
`id` INT AUTO_INCREMENT PRIMARY KEY,
`config_group` VARCHAR(50) NOT NULL COMMENT '配置分组',
`config_key` VARCHAR(100) NOT NULL COMMENT '配置键',
`display_name` VARCHAR(100) NOT NULL COMMENT '显示名称',
`description` TEXT COMMENT '配置说明',
`value_type` VARCHAR(20) DEFAULT 'string' COMMENT '值类型',
`default_value` TEXT COMMENT '默认值',
`is_required` BOOLEAN DEFAULT FALSE COMMENT '是否必填',
`is_secret` BOOLEAN DEFAULT FALSE COMMENT '是否敏感信息',
`validation_rule` VARCHAR(500) COMMENT '验证规则(正则)',
`options` JSON COMMENT '可选值列表(下拉选择)',
`sort_order` INT DEFAULT 0 COMMENT '排序',
`created_at` DATETIME DEFAULT CURRENT_TIMESTAMP,
`updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
UNIQUE KEY uk_group_key (config_group, config_key),
INDEX idx_config_group (config_group)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='配置模板表';
-- ============================================
-- 初始化数据
-- ============================================
-- 1. 插入超级管理员
INSERT INTO admin_users (username, email, password_hash, full_name, role) VALUES
('superadmin', 'admin@ireborn.com.cn', '$2b$12$LQv3c1yqBWVHxkd0LHAkCOYz6TtxMQJqhN8/X4.ynB8dC.m5QZ9Hy', '超级管理员', 'superadmin');
-- 密码: Superadmin123!
-- 2. 插入配置模板
INSERT INTO config_templates (config_group, config_key, display_name, description, value_type, default_value, is_required, is_secret, sort_order) VALUES
-- 数据库配置
('database', 'MYSQL_HOST', 'MySQL主机', 'MySQL数据库主机地址', 'string', 'prod-mysql', TRUE, FALSE, 1),
('database', 'MYSQL_PORT', 'MySQL端口', 'MySQL数据库端口', 'int', '3306', TRUE, FALSE, 2),
('database', 'MYSQL_USER', 'MySQL用户', 'MySQL数据库用户名', 'string', 'root', TRUE, FALSE, 3),
('database', 'MYSQL_PASSWORD', 'MySQL密码', 'MySQL数据库密码', 'string', NULL, TRUE, TRUE, 4),
('database', 'MYSQL_DATABASE', '数据库名', '租户数据库名称', 'string', NULL, TRUE, FALSE, 5),
-- Redis配置
('redis', 'REDIS_HOST', 'Redis主机', 'Redis缓存主机地址', 'string', 'localhost', TRUE, FALSE, 1),
('redis', 'REDIS_PORT', 'Redis端口', 'Redis端口', 'int', '6379', TRUE, FALSE, 2),
('redis', 'REDIS_DB', 'Redis DB', 'Redis数据库编号', 'int', '0', FALSE, FALSE, 3),
-- 安全配置
('security', 'SECRET_KEY', 'JWT密钥', 'JWT Token签名密钥', 'string', NULL, TRUE, TRUE, 1),
('security', 'CORS_ORIGINS', 'CORS域名', '允许跨域的域名列表', 'json', '[]', FALSE, FALSE, 2),
-- Dify配置
('dify', 'DIFY_API_KEY', '知识点分析 Key', 'Dify 01-知识点分析工作流 API Key', 'string', NULL, FALSE, TRUE, 1),
('dify', 'DIFY_EXAM_GENERATOR_API_KEY', '试题生成器 Key', 'Dify 02-试题生成器工作流 API Key', 'string', NULL, FALSE, TRUE, 2),
('dify', 'DIFY_PRACTICE_API_KEY', '陪练知识准备 Key', 'Dify 03-陪练知识准备工作流 API Key', 'string', NULL, FALSE, TRUE, 3),
('dify', 'DIFY_COURSE_CHAT_API_KEY', '课程对话 Key', 'Dify 04-与课程对话工作流 API Key', 'string', NULL, FALSE, TRUE, 4),
('dify', 'DIFY_YANJI_ANALYSIS_API_KEY', '智能工牌分析 Key', 'Dify 05-智能工牌能力分析工作流 API Key', 'string', NULL, FALSE, TRUE, 5),
-- Coze配置
('coze', 'COZE_PRACTICE_BOT_ID', '陪练Bot ID', 'Coze 陪练机器人ID', 'string', '7560643598174683145', FALSE, FALSE, 1),
('coze', 'COZE_BROADCAST_WORKFLOW_ID', '播课工作流ID', 'Coze 播课工作流ID', 'string', NULL, FALSE, FALSE, 2),
('coze', 'COZE_BROADCAST_SPACE_ID', '播课空间ID', 'Coze 播课工作流空间ID', 'string', '7474971491470688296', FALSE, FALSE, 3),
('coze', 'COZE_OAUTH_CLIENT_ID', 'OAuth Client ID', 'Coze OAuth 客户端ID', 'string', NULL, FALSE, FALSE, 4),
('coze', 'COZE_OAUTH_PUBLIC_KEY_ID', 'OAuth Public Key ID', 'Coze OAuth 公钥ID', 'string', NULL, FALSE, FALSE, 5),
-- AI服务配置
('ai', 'AI_PRIMARY_API_KEY', '首选AI服务Key', '首选AI服务商(4sapi.com) API Key', 'string', NULL, FALSE, TRUE, 1),
('ai', 'AI_PRIMARY_BASE_URL', '首选AI服务地址', '首选AI服务商API地址', 'string', 'https://4sapi.com/v1', FALSE, FALSE, 2),
('ai', 'AI_FALLBACK_API_KEY', '备选AI服务Key', '备选AI服务商(OpenRouter) API Key', 'string', NULL, FALSE, TRUE, 3),
('ai', 'AI_FALLBACK_BASE_URL', '备选AI服务地址', '备选AI服务商API地址', 'string', 'https://openrouter.ai/api/v1', FALSE, FALSE, 4),
('ai', 'AI_DEFAULT_MODEL', '默认模型', '默认使用的AI模型', 'string', 'gemini-3-flash-preview', FALSE, FALSE, 5),
('ai', 'AI_TIMEOUT', 'AI请求超时', 'AI服务请求超时时间(秒)', 'int', '120', FALSE, FALSE, 6),
-- 言迹工牌配置
('yanji', 'YANJI_CLIENT_ID', '客户端ID', '言迹开放平台Client ID', 'string', NULL, FALSE, FALSE, 1),
('yanji', 'YANJI_CLIENT_SECRET', '客户端密钥', '言迹开放平台Client Secret', 'string', NULL, FALSE, TRUE, 2),
('yanji', 'YANJI_TENANT_ID', '租户ID', '言迹租户ID', 'string', NULL, FALSE, FALSE, 3),
('yanji', 'YANJI_ESTATE_ID', '门店ID', '言迹门店ID', 'string', NULL, FALSE, FALSE, 4),
-- 文件存储配置
('storage', 'UPLOAD_DIR', '上传目录', '文件上传目录', 'string', 'uploads', FALSE, FALSE, 1),
('storage', 'MAX_UPLOAD_SIZE', '最大上传大小', '最大文件上传大小(字节)', 'int', '15728640', FALSE, FALSE, 2);
-- 3. 插入功能开关模板(全局默认)
INSERT INTO feature_switches (tenant_id, feature_code, feature_name, feature_group, is_enabled, description) VALUES
(NULL, 'exam_module', '考试模块', 'exam', TRUE, '考试功能总开关'),
(NULL, 'exam_ai_generate', 'AI试题生成', 'exam', TRUE, '使用AI自动生成试题'),
(NULL, 'exam_three_rounds', '三轮考试', 'exam', TRUE, '启用三轮考试机制'),
(NULL, 'practice_module', '陪练模块', 'practice', TRUE, '陪练功能总开关'),
(NULL, 'practice_voice', '语音陪练', 'practice', TRUE, '支持语音对话陪练'),
(NULL, 'broadcast_module', '播课模块', 'broadcast', TRUE, '播课功能总开关'),
(NULL, 'broadcast_auto_generate', '自动生成播课', 'broadcast', TRUE, '自动生成课程播课内容'),
(NULL, 'course_chat', '课程对话', 'course', TRUE, '与课程知识点对话功能'),
(NULL, 'knowledge_ai_analyze', 'AI知识点分析', 'course', TRUE, '使用AI分析提取知识点'),
(NULL, 'yanji_module', '智能工牌模块', 'yanji', FALSE, '言迹智能工牌对接功能'),
(NULL, 'yanji_ability_analysis', '能力分析', 'yanji', FALSE, '基于工牌数据的能力分析');
-- ============================================
-- 完成
-- ============================================