-- Create database CREATE DATABASE IF NOT EXISTS chat CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; USE chat; -- 1. 用户主表 CREATE TABLE users ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, username VARCHAR(50) DEFAULT NULL COMMENT '昵称/展示名', password_hash VARCHAR(255) DEFAULT NULL COMMENT '哈希密码(可为空)', phone VARCHAR(20) UNIQUE DEFAULT NULL COMMENT '手机号', email VARCHAR(100)UNIQUE DEFAULT NULL COMMENT '邮箱', avatar_url VARCHAR(255) DEFAULT NULL, user_type ENUM('personal','enterprise','admin') NOT NULL DEFAULT 'personal' COMMENT '用户类型', membership_level_id SMALLINT UNSIGNED NOT NULL DEFAULT 1 COMMENT '付费等级', status TINYINT NOT NULL DEFAULT 1 COMMENT '1=正常, 0=封禁', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, last_login_at DATETIME NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='用户主表'; -- 2. 第三方账号绑定表 CREATE TABLE user_auth_accounts ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, user_id BIGINT UNSIGNED NOT NULL, provider ENUM('wechat_mini','wechat_open','google','github','apple','custom') NOT NULL COMMENT '登录方式', provider_user_id VARCHAR(100) NOT NULL COMMENT '第三方平台唯一ID', access_token VARCHAR(255) DEFAULT NULL, refresh_token VARCHAR(255) DEFAULT NULL, expires_at DATETIME DEFAULT NULL, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, UNIQUE KEY uq_provider_user (provider, provider_user_id), CONSTRAINT fk_auth_user FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='第三方登录账号绑定表'; -- 3. 会员等级表 CREATE TABLE membership_levels ( id SMALLINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, name VARCHAR(50) NOT NULL, price_month DECIMAL(10,2) NOT NULL DEFAULT 0.00 COMMENT '月费', daily_msg_limit INT UNSIGNED NOT NULL DEFAULT 20, features JSON DEFAULT NULL COMMENT '权限 JSON', sort_order TINYINT NOT NULL DEFAULT 0, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='会员等级定义'; -- 4. 会话表(支持普通与研究模式) CREATE TABLE conversations ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, user_id BIGINT UNSIGNED NOT NULL, title VARCHAR(100) DEFAULT NULL, model_version VARCHAR(50) DEFAULT NULL COMMENT '使用模型版本', chat_mode ENUM('chat','research') NOT NULL DEFAULT 'chat' COMMENT 'chat=普通,research=深度研究', is_active TINYINT NOT NULL DEFAULT 1, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, CONSTRAINT fk_conv_user FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='会话表'; -- 5. 深度研究扩展表 CREATE TABLE conversation_research_meta ( conversation_id BIGINT UNSIGNED PRIMARY KEY, topic VARCHAR(200) NOT NULL COMMENT '研究主题', goal TEXT DEFAULT NULL COMMENT '研究目标描述', progress_json JSON DEFAULT NULL COMMENT '阶段进度', draft_report_id BIGINT UNSIGNED DEFAULT NULL COMMENT '草稿报告 ID(预留)', cite_style ENUM('APA','IEEE','GB/T-7714') DEFAULT 'APA', tokens_consumed INT UNSIGNED NOT NULL DEFAULT 0, last_summary_at DATETIME DEFAULT NULL, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, CONSTRAINT fk_research_conv FOREIGN KEY (conversation_id) REFERENCES conversations(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='深度研究元数据'; -- 6. 消息表 CREATE TABLE messages ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, conversation_id BIGINT UNSIGNED NOT NULL, sequence_no INT UNSIGNED NOT NULL COMMENT '会话内顺序编号', role ENUM('user','assistant','system','tool') NOT NULL, content LONGTEXT NOT NULL, tokens INT UNSIGNED DEFAULT NULL, latency_ms INT UNSIGNED DEFAULT NULL COMMENT '响应耗时', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT fk_msg_conv FOREIGN KEY (conversation_id) REFERENCES conversations(id) ON DELETE CASCADE, UNIQUE KEY uq_conv_seq (conversation_id, sequence_no) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='消息表'; -- 7. 密码重置令牌表(用于密码重置功能) CREATE TABLE password_reset_tokens ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, user_id BIGINT UNSIGNED NOT NULL, token VARCHAR(255) NOT NULL UNIQUE, expires_at DATETIME NOT NULL, used TINYINT NOT NULL DEFAULT 0, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT fk_reset_user FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='密码重置令牌表'; -- 插入默认会员等级数据 INSERT INTO membership_levels (id, name, price_month, daily_msg_limit, features, sort_order) VALUES (1, '免费版', 0.00, 20, '{"models": ["gpt-3.5"], "features": ["basic_chat"]}', 1), (2, '专业版', 29.99, 100, '{"models": ["gpt-3.5", "gpt-4"], "features": ["basic_chat", "research_mode"]}', 2), (3, '企业版', 99.99, 1000, '{"models": ["gpt-3.5", "gpt-4", "gpt-4-turbo"], "features": ["basic_chat", "research_mode", "priority_support"]}', 3);