Files
game_server/database_improvements.sql

99 lines
6.0 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.

/*
数据库优化脚本
解决设备冷却、游戏完成检测等问题
*/
SET NAMES utf8mb4;
SET FOREIGN_KEY_CHECKS = 0;
-- ----------------------------
-- Table structure for machine_cooldown
-- 解决问题1设备10分钟内重复调用
-- ----------------------------
DROP TABLE IF EXISTS `machine_cooldown`;
CREATE TABLE `machine_cooldown` (
`id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT,
`machine_id` varchar(64) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '设备ID',
`cooldown_start_time` datetime(3) NOT NULL COMMENT '冷却开始时间',
`cooldown_end_time` datetime(3) NOT NULL COMMENT '冷却结束时间',
`reason` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '冷却原因',
`link_task_id` bigint(20) UNSIGNED NULL DEFAULT NULL COMMENT '关联的链接任务ID',
`status` enum('ACTIVE','EXPIRED','MANUALLY_REMOVED') CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'ACTIVE' COMMENT '冷却状态',
`created_at` datetime(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
`updated_at` datetime(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3) ON UPDATE CURRENT_TIMESTAMP(3),
PRIMARY KEY (`id`) USING BTREE,
UNIQUE INDEX `uk_machine_active`(`machine_id`, `status`) USING BTREE COMMENT '确保同一设备只有一个活跃冷却记录',
INDEX `idx_machine_end_time`(`machine_id`, `cooldown_end_time`) USING BTREE,
INDEX `idx_cooldown_end_time`(`cooldown_end_time`) USING BTREE,
INDEX `fk_mc_link_task`(`link_task_id`) USING BTREE,
CONSTRAINT `fk_mc_link_task` FOREIGN KEY (`link_task_id`) REFERENCES `link_task` (`id`) ON DELETE SET NULL ON UPDATE RESTRICT
) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_unicode_ci COMMENT = '设备冷却状态表' ROW_FORMAT = DYNAMIC;
-- ----------------------------
-- Table structure for game_completion_log
-- 解决问题2误判游戏完成
-- ----------------------------
DROP TABLE IF EXISTS `game_completion_log`;
CREATE TABLE `game_completion_log` (
`id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT,
`link_task_id` bigint(20) UNSIGNED NOT NULL COMMENT '链接任务ID',
`machine_id` varchar(64) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '设备ID',
`detection_source` enum('TIMER_TASK','EVENT_LISTENER','REGION_SELECT','MANUAL') CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '检测来源',
`device_status` varchar(50) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '设备状态',
`points_detected` int(10) UNSIGNED NULL DEFAULT NULL COMMENT '检测到的点数',
`completion_confidence` enum('HIGH','MEDIUM','LOW') CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'MEDIUM' COMMENT '完成置信度',
`is_confirmed` tinyint(1) NOT NULL DEFAULT 0 COMMENT '是否已确认完成',
`confirmation_time` datetime(3) NULL DEFAULT NULL COMMENT '确认完成时间',
`created_at` datetime(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
PRIMARY KEY (`id`) USING BTREE,
INDEX `idx_link_task`(`link_task_id`) USING BTREE,
INDEX `idx_machine_time`(`machine_id`, `created_at`) USING BTREE,
INDEX `idx_source_confidence`(`detection_source`, `completion_confidence`) USING BTREE,
CONSTRAINT `fk_gcl_link_task` FOREIGN KEY (`link_task_id`) REFERENCES `link_task` (`id`) ON DELETE CASCADE ON UPDATE RESTRICT
) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_unicode_ci COMMENT = '游戏完成检测日志表' ROW_FORMAT = DYNAMIC;
-- ----------------------------
-- 为link_task表添加更多索引优化
-- ----------------------------
ALTER TABLE `link_task`
ADD INDEX `idx_machine_status`(`machine_id`, `status`) USING BTREE COMMENT '按设备和状态查询优化',
ADD INDEX `idx_status_updated`(`status`, `updated_at`) USING BTREE COMMENT '按状态和更新时间查询优化',
ADD INDEX `idx_login_time`(`login_at`) USING BTREE COMMENT '登录时间查询优化';
-- ----------------------------
-- 添加唯一编号生成序列表(备用方案)
-- ----------------------------
DROP TABLE IF EXISTS `code_sequence`;
CREATE TABLE `code_sequence` (
`id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT,
`sequence_value` bigint(20) UNSIGNED NOT NULL DEFAULT 0 COMMENT '序列值',
`last_reset_date` date NOT NULL COMMENT '最后重置日期',
`created_at` datetime(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
`updated_at` datetime(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3) ON UPDATE CURRENT_TIMESTAMP(3),
PRIMARY KEY (`id`) USING BTREE
) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_unicode_ci COMMENT = '编号序列表(用于生成唯一编号)' ROW_FORMAT = DYNAMIC;
-- 初始化序列表
INSERT INTO `code_sequence` (`sequence_value`, `last_reset_date`) VALUES (0, CURDATE());
-- ----------------------------
-- 添加系统监控表
-- ----------------------------
DROP TABLE IF EXISTS `system_monitor`;
CREATE TABLE `system_monitor` (
`id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT,
`monitor_type` enum('DEVICE_STATUS','TASK_STATUS','COOLDOWN_STATUS','ERROR_LOG') CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '监控类型',
`monitor_key` varchar(100) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '监控键',
`monitor_value` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '监控值',
`alert_level` enum('INFO','WARN','ERROR','CRITICAL') CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'INFO' COMMENT '告警级别',
`is_resolved` tinyint(1) NOT NULL DEFAULT 0 COMMENT '是否已解决',
`resolved_at` datetime(3) NULL DEFAULT NULL COMMENT '解决时间',
`created_at` datetime(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
PRIMARY KEY (`id`) USING BTREE,
INDEX `idx_type_key`(`monitor_type`, `monitor_key`) USING BTREE,
INDEX `idx_level_resolved`(`alert_level`, `is_resolved`) USING BTREE,
INDEX `idx_created_at`(`created_at`) USING BTREE
) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_unicode_ci COMMENT = '系统监控表' ROW_FORMAT = DYNAMIC;
SET FOREIGN_KEY_CHECKS = 1;