119 lines
4.8 KiB
SQL
119 lines
4.8 KiB
SQL
-- 一体化游戏运营平台数据库初始化脚本(MySQL 8.4兼容版)
|
||
-- 创建日期: 2024-05-20
|
||
|
||
-- 创建数据库(如果不存在)
|
||
CREATE DATABASE IF NOT EXISTS mhxy_web DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
|
||
|
||
-- 切换到mhxy_web数据库
|
||
USE mhxy_web;
|
||
|
||
-- 创建用户表
|
||
CREATE TABLE IF NOT EXISTS users (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
username VARCHAR(50) UNIQUE NOT NULL,
|
||
password VARCHAR(100) NOT NULL,
|
||
email VARCHAR(100) UNIQUE NULL,
|
||
phone VARCHAR(20) UNIQUE NULL,
|
||
role ENUM('admin', 'player') DEFAULT 'admin' NOT NULL,
|
||
status ENUM('ACTIVE', 'INACTIVE') DEFAULT 'ACTIVE' NOT NULL,
|
||
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||
|
||
-- 创建配置表
|
||
CREATE TABLE IF NOT EXISTS config (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
`key` VARCHAR(50) UNIQUE NOT NULL,
|
||
value TEXT NULL,
|
||
description VARCHAR(100) NULL,
|
||
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||
|
||
-- 创建管理员用户(密码:admin123,已通过bcrypt加密)
|
||
INSERT INTO users (username, password, role, status) VALUES (
|
||
'admin',
|
||
'$2a$12$A3KXVvye0Q1WMx3AjqRgb.ea3PTUpJHLyOBrm9Q8PAVMYVxNCvZrO',
|
||
'admin',
|
||
'ACTIVE'
|
||
) ON DUPLICATE KEY UPDATE id = id;
|
||
|
||
-- 插入初始配置
|
||
INSERT INTO config (`key`, `value`, description) VALUES
|
||
('game_api_url', 'http://127.0.0.1:8080/tool/http', '游戏服务端API地址'),
|
||
('max_login_attempts', '5', '最大登录尝试次数'),
|
||
('login_lock_time', '300', '登录锁定时间(秒)')
|
||
ON DUPLICATE KEY UPDATE id = id;
|
||
|
||
-- 插入系统配置
|
||
INSERT INTO config (`key`, `value`, description) VALUES
|
||
('website_name', '梦幻西游WEB版', '网站名称'),
|
||
('admin_domain', 'http://localhost:5173', '运营后台域名'),
|
||
('player_domain', 'http://localhost:5173', '玩家中心域名'),
|
||
('server_host', 'localhost', '后端服务器主机地址'),
|
||
('server_port', '3000', '后端服务器端口'),
|
||
('game_api_url', 'http://127.0.0.1:8080/tool/http', '游戏服务API地址'),
|
||
('game_psk', 'THIS_IS_A_32_BYTE_FIXED_PSK!!!!!', '游戏服务端的PSK'),
|
||
('jwt_secret', 'your_jwt_secret_key_here_change_in_production', 'JWT密钥'),
|
||
('jwt_expires_in', '24h', 'JWT过期时间'),
|
||
('jwt_refresh_secret', 'your_jwt_refresh_secret_key_here_change_in_production', 'JWT刷新令牌密钥'),
|
||
('jwt_refresh_expires_in', '7d', 'JWT刷新令牌过期时间'),
|
||
('service_status', 'running', '服务运行状态'),
|
||
('maintenance_mode', 'false', '维护模式开关')
|
||
ON DUPLICATE KEY UPDATE id = id;
|
||
|
||
-- 创建索引(MySQL 8.4不支持IF NOT EXISTS语法,使用IGNORE错误处理)
|
||
SET @sql = (SELECT IF(
|
||
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
|
||
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'users' AND INDEX_NAME = 'idx_users_username') > 0,
|
||
'SELECT "Index idx_users_username already exists" AS message;',
|
||
'CREATE INDEX idx_users_username ON users(username);'
|
||
));
|
||
PREPARE stmt FROM @sql;
|
||
EXECUTE stmt;
|
||
DEALLOCATE PREPARE stmt;
|
||
|
||
SET @sql = (SELECT IF(
|
||
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
|
||
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'users' AND INDEX_NAME = 'idx_users_email') > 0,
|
||
'SELECT "Index idx_users_email already exists" AS message;',
|
||
'CREATE INDEX idx_users_email ON users(email);'
|
||
));
|
||
PREPARE stmt FROM @sql;
|
||
EXECUTE stmt;
|
||
DEALLOCATE PREPARE stmt;
|
||
|
||
SET @sql = (SELECT IF(
|
||
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
|
||
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'users' AND INDEX_NAME = 'idx_users_phone') > 0,
|
||
'SELECT "Index idx_users_phone already exists" AS message;',
|
||
'CREATE INDEX idx_users_phone ON users(phone);'
|
||
));
|
||
PREPARE stmt FROM @sql;
|
||
EXECUTE stmt;
|
||
DEALLOCATE PREPARE stmt;
|
||
|
||
SET @sql = (SELECT IF(
|
||
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
|
||
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'users' AND INDEX_NAME = 'idx_users_status') > 0,
|
||
'SELECT "Index idx_users_status already exists" AS message;',
|
||
'CREATE INDEX idx_users_status ON users(status);'
|
||
));
|
||
PREPARE stmt FROM @sql;
|
||
EXECUTE stmt;
|
||
DEALLOCATE PREPARE stmt;
|
||
|
||
SET @sql = (SELECT IF(
|
||
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
|
||
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'config' AND INDEX_NAME = 'idx_config_key') > 0,
|
||
'SELECT "Index idx_config_key already exists" AS message;',
|
||
'CREATE INDEX idx_config_key ON config(`key`);'
|
||
));
|
||
PREPARE stmt FROM @sql;
|
||
EXECUTE stmt;
|
||
DEALLOCATE PREPARE stmt;
|
||
|
||
-- 输出初始化完成信息
|
||
SELECT '数据库初始化完成!' AS message;
|
||
SELECT '管理员用户名: admin, 密码: admin123' AS admin_info;
|