Files
vf_react/rebuild_all_tables.sql
2025-11-23 22:06:07 +08:00

262 lines
11 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.

-- 完整重建预测市场所有表
-- 会删除旧表并重新创建
-- ⚠️ 警告:会删除所有现有数据!
-- 执行前请确认是测试环境或数据可以丢失
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;
DROP TABLE IF EXISTS user_credit_account;
-- ==================== 重新创建所有表 ====================
-- 按依赖关系正序创建
-- 1. 用户积分账户表
CREATE TABLE user_credit_account (
id INT AUTO_INCREMENT PRIMARY KEY,
user_id INT NOT NULL UNIQUE COMMENT '用户ID',
-- 积分余额
balance FLOAT DEFAULT 10000.0 NOT NULL COMMENT '积分余额初始10000',
frozen_balance FLOAT DEFAULT 0.0 NOT NULL COMMENT '冻结积分',
total_earned FLOAT DEFAULT 0.0 NOT NULL COMMENT '累计获得',
total_spent 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,
last_daily_bonus_at DATETIME COMMENT '最后一次领取每日奖励时间',
FOREIGN KEY (user_id) REFERENCES user(id) ON DELETE CASCADE,
INDEX idx_user_id (user_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='用户积分账户';
-- 2. 预测话题表
CREATE TABLE prediction_topic (
id INT AUTO_INCREMENT PRIMARY KEY,
creator_id INT NOT NULL COMMENT '创建者ID',
-- 基本信息
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 COMMENT '浏览次数',
comments_count INT DEFAULT 0 COMMENT '评论数',
participants_count INT DEFAULT 0 COMMENT '参与人数',
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='预测话题';
-- 3. 用户持仓表
CREATE TABLE prediction_position (
id INT AUTO_INCREMENT PRIMARY KEY,
user_id INT NOT NULL COMMENT '用户ID',
topic_id INT NOT NULL COMMENT '话题ID',
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='用户持仓';
-- 4. 交易记录表
CREATE TABLE prediction_transaction (
id INT AUTO_INCREMENT PRIMARY KEY,
user_id INT NOT NULL COMMENT '用户ID',
topic_id INT NOT NULL COMMENT '话题ID',
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 '交易税2%',
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='交易记录';
-- 5. 话题评论表
CREATE TABLE topic_comment (
id INT AUTO_INCREMENT PRIMARY KEY,
topic_id INT NOT NULL COMMENT '话题ID',
user_id INT NOT NULL COMMENT '用户ID',
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 '评论位置排名1/2/3',
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='话题评论';
-- 6. 评论投资记录表观点IPO
CREATE TABLE comment_investment (
id INT AUTO_INCREMENT PRIMARY KEY,
comment_id INT NOT NULL COMMENT '评论ID',
user_id INT NOT NULL COMMENT '投资者ID',
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='评论投资记录观点IPO';
-- 7. 评论位置竞拍记录表(首发权拍卖)
CREATE TABLE comment_position_bid (
id INT AUTO_INCREMENT PRIMARY KEY,
topic_id INT NOT NULL COMMENT '话题ID',
user_id INT NOT NULL COMMENT '竞拍者ID',
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='评论位置竞拍记录(首发权拍卖)';
-- 8. 时间胶囊话题表
CREATE TABLE time_capsule_topic (
id INT AUTO_INCREMENT PRIMARY KEY,
user_id INT NOT NULL COMMENT '创建者ID',
title VARCHAR(200) NOT NULL COMMENT '话题标题',
description TEXT COMMENT '话题描述',
encrypted_content TEXT COMMENT '加密的预测内容前端AES加密',
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='时间胶囊话题(长期预测)';
-- 9. 时间胶囊时间段表
CREATE TABLE time_capsule_time_slot (
id INT AUTO_INCREMENT PRIMARY KEY,
topic_id INT NOT NULL COMMENT '话题ID',
year_start INT NOT NULL COMMENT '年份区间开始',
year_end INT NOT NULL COMMENT '年份区间结束',
current_holder_id INT COMMENT '当前持有者ID',
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='时间胶囊时间段';
-- 10. 时间段竞拍记录表
CREATE TABLE time_slot_bid (
id INT AUTO_INCREMENT PRIMARY KEY,
slot_id INT NOT NULL COMMENT '时间段ID',
user_id INT NOT NULL COMMENT '竞拍者ID',
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='时间段竞拍记录';
-- ==================== 执行完成提示 ====================
SELECT '✅ 所有表创建成功!' AS status;
SELECT '📊 共创建了 10 个表' AS info;
SELECT '💰 用户注册时将自动获得 10000 初始积分' AS credit_info;
SELECT '🎮 预测市场系统已就绪' AS market_status;