-- 重建预测市场表(完全删除后重新创建) -- 警告:会删除所有现有数据! -- 仅在测试环境或数据可以丢失时使用 -- 执行前请备份数据库! USE stock; -- 删除旧表(按依赖关系倒序删除) DROP TABLE IF EXISTS time_slot_bid; DROP TABLE IF EXISTS time_capsule_time_slot; DROP TABLE IF EXISTS time_capsule_topic; DROP TABLE IF EXISTS comment_position_bid; DROP TABLE IF EXISTS comment_investment; DROP TABLE IF EXISTS topic_comment; DROP TABLE IF EXISTS prediction_transaction; DROP TABLE IF EXISTS prediction_position; DROP TABLE IF EXISTS prediction_topic; -- 重新创建表(按依赖关系正序创建) -- 1. 预测话题表 CREATE TABLE prediction_topic ( id INT AUTO_INCREMENT PRIMARY KEY, creator_id INT NOT NULL, -- 基本信息 title VARCHAR(200) NOT NULL COMMENT '话题标题', description TEXT COMMENT '话题描述', category VARCHAR(50) DEFAULT 'stock' COMMENT '分类: stock/index/concept/policy/event/other', -- 市场数据 yes_total_shares INT DEFAULT 0 NOT NULL COMMENT 'YES方总份额', no_total_shares INT DEFAULT 0 NOT NULL COMMENT 'NO方总份额', yes_price FLOAT DEFAULT 500.0 NOT NULL COMMENT 'YES方价格(0-1000)', no_price FLOAT DEFAULT 500.0 NOT NULL COMMENT 'NO方价格(0-1000)', -- 奖池 total_pool FLOAT DEFAULT 0.0 NOT NULL COMMENT '总奖池(2%交易税累积)', -- 领主信息 yes_lord_id INT COMMENT 'YES方领主', no_lord_id INT COMMENT 'NO方领主', -- 状态 status VARCHAR(20) DEFAULT 'active' NOT NULL COMMENT '状态: active/settled/cancelled', result VARCHAR(10) COMMENT '结算结果: yes/no/draw', -- 时间 deadline DATETIME NOT NULL COMMENT '截止时间', settled_at DATETIME COMMENT '结算时间', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, -- 统计 views_count INT DEFAULT 0, comments_count INT DEFAULT 0, participants_count INT DEFAULT 0, FOREIGN KEY (creator_id) REFERENCES user(id), FOREIGN KEY (yes_lord_id) REFERENCES user(id), FOREIGN KEY (no_lord_id) REFERENCES user(id), INDEX idx_creator_id (creator_id), INDEX idx_status (status), INDEX idx_category (category), INDEX idx_created_at (created_at) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='预测话题'; -- 2. 用户持仓表 CREATE TABLE prediction_position ( id INT AUTO_INCREMENT PRIMARY KEY, user_id INT NOT NULL, topic_id INT NOT NULL, direction VARCHAR(3) NOT NULL COMMENT '方向: yes/no', shares INT DEFAULT 0 NOT NULL COMMENT '持有份额', avg_cost FLOAT DEFAULT 0.0 NOT NULL COMMENT '平均成本', total_invested FLOAT DEFAULT 0.0 NOT NULL COMMENT '总投入', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES user(id) ON DELETE CASCADE, FOREIGN KEY (topic_id) REFERENCES prediction_topic(id) ON DELETE CASCADE, UNIQUE KEY unique_position (user_id, topic_id, direction), INDEX idx_user_topic (user_id, topic_id), INDEX idx_topic (topic_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='用户持仓'; -- 3. 交易记录表 CREATE TABLE prediction_transaction ( id INT AUTO_INCREMENT PRIMARY KEY, user_id INT NOT NULL, topic_id INT NOT NULL, direction VARCHAR(3) NOT NULL COMMENT '方向: yes/no', trade_type VARCHAR(10) NOT NULL COMMENT '交易类型: buy/sell', shares INT NOT NULL COMMENT '交易份额', price FLOAT NOT NULL COMMENT '交易价格', amount FLOAT NOT NULL COMMENT '交易金额', tax FLOAT DEFAULT 0.0 NOT NULL COMMENT '交易税', total_cost FLOAT NOT NULL COMMENT '总成本(含税)', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES user(id), FOREIGN KEY (topic_id) REFERENCES prediction_topic(id), INDEX idx_user_id (user_id), INDEX idx_topic_id (topic_id), INDEX idx_created_at (created_at) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='交易记录'; -- 4. 话题评论表 CREATE TABLE topic_comment ( id INT AUTO_INCREMENT PRIMARY KEY, topic_id INT NOT NULL, user_id INT NOT NULL, content TEXT NOT NULL COMMENT '评论内容', direction VARCHAR(3) COMMENT '预测方向: yes/no', is_published BOOLEAN DEFAULT FALSE NOT NULL COMMENT '是否已发布', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, -- 观点IPO相关 total_investment INT DEFAULT 0 NOT NULL COMMENT '总投资额', investor_count INT DEFAULT 0 NOT NULL COMMENT '投资人数', is_verified BOOLEAN DEFAULT FALSE NOT NULL COMMENT '是否已验证', verification_result VARCHAR(20) COMMENT '验证结果: correct/incorrect', position_rank INT COMMENT '评论位置排名', FOREIGN KEY (topic_id) REFERENCES prediction_topic(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES user(id), INDEX idx_topic_id (topic_id), INDEX idx_user_id (user_id), INDEX idx_position_rank (position_rank) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='话题评论'; -- 5. 评论投资记录表(观点IPO) CREATE TABLE comment_investment ( id INT AUTO_INCREMENT PRIMARY KEY, comment_id INT NOT NULL, user_id INT NOT NULL, shares INT NOT NULL COMMENT '投资份额', amount INT NOT NULL COMMENT '投资金额', avg_price FLOAT NOT NULL COMMENT '平均价格', status VARCHAR(20) DEFAULT 'active' NOT NULL COMMENT '状态: active/settled', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (comment_id) REFERENCES topic_comment(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES user(id), INDEX idx_comment_id (comment_id), INDEX idx_user_id (user_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='评论投资记录'; -- 6. 评论位置竞拍记录(首发权拍卖) CREATE TABLE comment_position_bid ( id INT AUTO_INCREMENT PRIMARY KEY, topic_id INT NOT NULL, user_id INT NOT NULL, position INT NOT NULL COMMENT '位置:1/2/3', bid_amount INT NOT NULL COMMENT '竞拍金额', status VARCHAR(20) DEFAULT 'pending' NOT NULL COMMENT '状态: pending/won/outbid', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, expires_at DATETIME NOT NULL COMMENT '过期时间', FOREIGN KEY (topic_id) REFERENCES prediction_topic(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES user(id), INDEX idx_topic_id (topic_id), INDEX idx_user_id (user_id), INDEX idx_position (topic_id, position) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='评论位置竞拍记录'; -- 7. 时间胶囊话题表 CREATE TABLE time_capsule_topic ( id INT AUTO_INCREMENT PRIMARY KEY, user_id INT NOT NULL, title VARCHAR(200) NOT NULL COMMENT '话题标题', description TEXT COMMENT '话题描述', encrypted_content TEXT COMMENT '加密的预测内容', encryption_key VARCHAR(500) COMMENT '加密密钥(后端存储)', start_year INT NOT NULL COMMENT '开始年份', end_year INT NOT NULL COMMENT '结束年份', status VARCHAR(20) DEFAULT 'active' NOT NULL COMMENT '状态: active/settled/cancelled', is_decrypted BOOLEAN DEFAULT FALSE NOT NULL COMMENT '是否已解密', actual_happened_year INT COMMENT '实际发生年份', total_pool INT DEFAULT 0 NOT NULL COMMENT '总奖池', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES user(id), INDEX idx_user_id (user_id), INDEX idx_status (status), INDEX idx_year_range (start_year, end_year) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='时间胶囊话题'; -- 8. 时间胶囊时间段表 CREATE TABLE time_capsule_time_slot ( id INT AUTO_INCREMENT PRIMARY KEY, topic_id INT NOT NULL, year_start INT NOT NULL COMMENT '年份区间开始', year_end INT NOT NULL COMMENT '年份区间结束', current_holder_id INT COMMENT '当前持有者', current_price INT DEFAULT 100 NOT NULL COMMENT '当前价格', total_bids INT DEFAULT 0 NOT NULL COMMENT '总竞拍次数', status VARCHAR(20) DEFAULT 'active' NOT NULL COMMENT '状态: active/settled', FOREIGN KEY (topic_id) REFERENCES time_capsule_topic(id) ON DELETE CASCADE, FOREIGN KEY (current_holder_id) REFERENCES user(id), INDEX idx_topic_id (topic_id), INDEX idx_holder (current_holder_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='时间胶囊时间段'; -- 9. 时间段竞拍记录表 CREATE TABLE time_slot_bid ( id INT AUTO_INCREMENT PRIMARY KEY, slot_id INT NOT NULL, user_id INT NOT NULL, bid_amount INT NOT NULL COMMENT '竞拍金额', status VARCHAR(20) DEFAULT 'outbid' NOT NULL COMMENT '状态: current/outbid/won', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (slot_id) REFERENCES time_capsule_time_slot(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES user(id), INDEX idx_slot_id (slot_id), INDEX idx_user_id (user_id), INDEX idx_created_at (created_at) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='时间段竞拍记录';