baoxiang/init_mysql.sql
2025-12-16 18:06:50 +08:00

200 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.

-- ============================================
-- 宝箱游戏系统 MySQL 初始化脚本
-- 生成时间: 2025-12-13
-- 字符集: utf8mb4
-- ============================================
-- 创建数据库(如果不存在)
CREATE DATABASE IF NOT EXISTS treasure_box_game
CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci;
USE treasure_box_game;
-- ============================================
-- 1. 用户表 (users)
-- ============================================
CREATE TABLE IF NOT EXISTS users (
id INT AUTO_INCREMENT PRIMARY KEY,
username VARCHAR(50) NOT NULL UNIQUE COMMENT '用户名',
email VARCHAR(100) NOT NULL UNIQUE COMMENT '邮箱',
hashed_password VARCHAR(255) NOT NULL COMMENT '哈希密码',
role ENUM('USER', 'STREAMER', 'ADMIN') NOT NULL DEFAULT 'USER' COMMENT '用户角色',
nickname VARCHAR(64) DEFAULT NULL COMMENT '用户昵称',
avatar_url VARCHAR(255) DEFAULT NULL COMMENT '头像URL',
phone VARCHAR(20) DEFAULT NULL COMMENT '手机号',
status ENUM('ACTIVE', 'DISABLED', 'BANNED') NOT NULL DEFAULT 'ACTIVE' COMMENT '用户状态',
balance BIGINT NOT NULL DEFAULT 0 COMMENT '余额(单位:分)',
version INT NOT NULL DEFAULT 0 COMMENT '乐观锁版本号',
last_login_at DATETIME DEFAULT NULL COMMENT '最后登录时间',
login_count INT NOT NULL DEFAULT 0 COMMENT '登录次数',
is_active TINYINT(1) NOT NULL DEFAULT 1 COMMENT '是否激活',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
INDEX idx_username (username),
INDEX idx_email (email)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户表';
-- ============================================
-- 2. 交易记录表 (transactions)
-- ============================================
CREATE TABLE IF NOT EXISTS transactions (
id INT AUTO_INCREMENT PRIMARY KEY,
user_id INT NOT NULL COMMENT '用户ID',
type VARCHAR(30) NOT NULL COMMENT '交易类型',
amount BIGINT NOT NULL COMMENT '金额(单位:分)',
balance_after BIGINT NOT NULL COMMENT '交易后余额',
related_id INT DEFAULT NULL COMMENT '关联ID',
description TEXT DEFAULT NULL COMMENT '描述',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
INDEX idx_user_id (user_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='交易记录表';
-- ============================================
-- 3. 宝箱表 (chests)
-- ============================================
CREATE TABLE IF NOT EXISTS chests (
id INT AUTO_INCREMENT PRIMARY KEY,
streamer_id INT NOT NULL COMMENT '主播ID',
title VARCHAR(200) NOT NULL COMMENT '宝箱标题',
option_a VARCHAR(100) NOT NULL COMMENT '选项A',
option_b VARCHAR(100) NOT NULL COMMENT '选项B',
status ENUM('BETTING', 'LOCKED', 'SETTLING', 'FINISHED', 'REFUNDED') NOT NULL DEFAULT 'BETTING' COMMENT '宝箱状态',
pool_a BIGINT NOT NULL DEFAULT 0 COMMENT 'A边奖池(单位:分)',
pool_b BIGINT NOT NULL DEFAULT 0 COMMENT 'B边奖池(单位:分)',
total_bets INT NOT NULL DEFAULT 0 COMMENT '总下注次数',
countdown_seconds INT DEFAULT NULL COMMENT '倒计时(秒)',
locked_at DATETIME DEFAULT NULL COMMENT '封盘时间',
settled_at DATETIME DEFAULT NULL COMMENT '结算时间',
result VARCHAR(10) DEFAULT NULL COMMENT '结算结果',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
INDEX idx_streamer_id (streamer_id),
INDEX idx_status (status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='宝箱表';
-- ============================================
-- 4. 下注记录表 (bets)
-- ============================================
CREATE TABLE IF NOT EXISTS bets (
id INT AUTO_INCREMENT PRIMARY KEY,
user_id INT NOT NULL COMMENT '用户ID',
chest_id INT NOT NULL COMMENT '宝箱ID',
`option` CHAR(1) NOT NULL COMMENT '下注选项(A或B)',
amount BIGINT NOT NULL COMMENT '下注金额(单位:分)',
payout BIGINT DEFAULT NULL COMMENT '获奖金额(单位:分)',
status VARCHAR(20) NOT NULL DEFAULT 'PENDING' COMMENT '状态',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
INDEX idx_user_id (user_id),
INDEX idx_chest_id (chest_id),
CONSTRAINT fk_bets_chest FOREIGN KEY (chest_id) REFERENCES chests(id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='下注记录表';
-- ============================================
-- 5. 系统配置表 (system_configs)
-- ============================================
CREATE TABLE IF NOT EXISTS system_configs (
id INT AUTO_INCREMENT PRIMARY KEY,
config_key VARCHAR(64) NOT NULL UNIQUE COMMENT '配置键',
config_value TEXT DEFAULT NULL COMMENT '配置值',
config_type ENUM('STRING', 'NUMBER', 'BOOLEAN', 'JSON') NOT NULL DEFAULT 'STRING' COMMENT '配置类型',
category ENUM('GAME_ECONOMY', 'GAME_LOGIC', 'SYSTEM_OPERATIONS', 'UI_DISPLAY') NOT NULL COMMENT '配置分类',
description VARCHAR(255) DEFAULT NULL COMMENT '配置描述',
is_editable TINYINT(1) NOT NULL DEFAULT 1 COMMENT '是否可编辑',
is_public TINYINT(1) NOT NULL DEFAULT 0 COMMENT '是否对前端公开',
display_order INT NOT NULL DEFAULT 0 COMMENT '显示顺序',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
INDEX idx_config_key (config_key),
INDEX idx_category (category)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='系统配置表';
-- ============================================
-- 6. 主播资料表 (streamer_profiles)
-- ============================================
CREATE TABLE IF NOT EXISTS streamer_profiles (
id INT AUTO_INCREMENT PRIMARY KEY,
user_id INT NOT NULL UNIQUE COMMENT '用户ID',
display_name VARCHAR(64) DEFAULT NULL COMMENT '主播展示名称',
avatar_url VARCHAR(255) DEFAULT NULL COMMENT '主播头像',
bio TEXT DEFAULT NULL COMMENT '主播简介',
commission_rate DECIMAL(5,2) NOT NULL DEFAULT 5.00 COMMENT '主播抽成比例(%)',
max_active_chests INT NOT NULL DEFAULT 10 COMMENT '最大活跃宝箱数',
total_chests INT NOT NULL DEFAULT 0 COMMENT '历史宝箱总数',
total_winnings DECIMAL(15,2) NOT NULL DEFAULT 0.00 COMMENT '历史获奖总额',
status ENUM('ACTIVE', 'SUSPENDED', 'BANNED') NOT NULL DEFAULT 'ACTIVE' COMMENT '主播状态',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
INDEX idx_user_id (user_id),
INDEX idx_status (status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='主播资料表';
-- ============================================
-- 7. 用户操作日志表 (user_operation_logs)
-- ============================================
CREATE TABLE IF NOT EXISTS user_operation_logs (
id INT AUTO_INCREMENT PRIMARY KEY,
user_id INT NOT NULL COMMENT '操作用户ID',
operator_id INT DEFAULT NULL COMMENT '操作人ID(管理员)',
operation_type VARCHAR(64) NOT NULL COMMENT '操作类型',
operation_details TEXT DEFAULT NULL COMMENT '操作详情(JSON格式)',
ip_address VARCHAR(45) DEFAULT NULL COMMENT 'IP地址',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
INDEX idx_user_id (user_id),
INDEX idx_operator_id (operator_id),
INDEX idx_operation_type (operation_type),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户操作日志表';
-- ============================================
-- 8. 公告表 (announcements)
-- ============================================
CREATE TABLE IF NOT EXISTS announcements (
id INT AUTO_INCREMENT PRIMARY KEY,
title VARCHAR(255) NOT NULL COMMENT '公告标题',
content TEXT NOT NULL COMMENT '公告内容',
type ENUM('INFO', 'WARNING', 'PRIZE') NOT NULL DEFAULT 'INFO' COMMENT '公告类型',
is_pinned TINYINT(1) NOT NULL DEFAULT 0 COMMENT '是否置顶',
priority INT NOT NULL DEFAULT 0 COMMENT '优先级(数字越大优先级越高)',
starts_at DATETIME DEFAULT NULL COMMENT '生效时间',
expires_at DATETIME DEFAULT NULL COMMENT '过期时间',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
INDEX idx_type (type),
INDEX idx_is_pinned (is_pinned),
INDEX idx_starts_at (starts_at),
INDEX idx_expires_at (expires_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='公告表';
-- ============================================
-- 初始化默认数据
-- ============================================
-- 插入默认管理员账户 (密码: admin123请及时修改)
-- 密码使用 bcrypt 加密,此处为示例哈希值
INSERT INTO users (username, email, hashed_password, role, nickname, status, is_active)
VALUES ('admin', 'admin@example.com', '$2b$12$LQv3c1yqBWVHxkd0LHAkCOYz6TtxMQJqhN8/X4.qXaFn8c0LsMLQe', 'ADMIN', '系统管理员', 'ACTIVE', 1)
ON DUPLICATE KEY UPDATE username = username;
-- 插入默认系统配置
INSERT INTO system_configs (config_key, config_value, config_type, category, description, is_editable, is_public, display_order) VALUES
-- 游戏经济配置
('min_bet_amount', '100', 'NUMBER', 'GAME_ECONOMY', '最小下注金额(分)', 1, 1, 1),
('max_bet_amount', '100000', 'NUMBER', 'GAME_ECONOMY', '最大下注金额(分)', 1, 1, 2),
('platform_fee_rate', '5', 'NUMBER', 'GAME_ECONOMY', '平台抽成比例(%)', 1, 0, 3),
('default_commission_rate', '5', 'NUMBER', 'GAME_ECONOMY', '默认主播抽成比例(%)', 1, 0, 4),
-- 游戏逻辑配置
('default_countdown_seconds', '60', 'NUMBER', 'GAME_LOGIC', '默认倒计时秒数', 1, 1, 10),
('max_active_chests_per_streamer', '10', 'NUMBER', 'GAME_LOGIC', '每个主播最大活跃宝箱数', 1, 0, 11),
-- 系统运营配置
('maintenance_mode', 'false', 'BOOLEAN', 'SYSTEM_OPERATIONS', '维护模式', 1, 1, 20),
('registration_enabled', 'true', 'BOOLEAN', 'SYSTEM_OPERATIONS', '是否开放注册', 1, 1, 21),
-- UI显示配置
('site_name', '宝箱游戏', 'STRING', 'UI_DISPLAY', '网站名称', 1, 1, 30),
('site_logo_url', '', 'STRING', 'UI_DISPLAY', '网站Logo URL', 1, 1, 31)
ON DUPLICATE KEY UPDATE config_key = config_key;
-- ============================================
-- 完成
-- ============================================
SELECT '数据库初始化完成!' AS message;