You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
Software_Architecture/src/Client/database/enemy_database_schema.sql

239 lines
7.7 KiB

This file contains ambiguous Unicode characters!

This file contains ambiguous Unicode characters that may be confused with others in your current locale. If your use case is intentional and legitimate, you can safely ignore this warning. Use the Escape button to highlight these characters.

-- 敌情数据库表结构和初始化脚本
-- Enemy Database Schema and Initialization Script
--
-- 用途为BattlefieldExplorationSystem创建敌情相关的数据库表
-- Purpose: Create enemy-related database tables for BattlefieldExplorationSystem
--
-- 作者Claude AI
-- 日期2025-07-08
-- 版本1.0
-- 使用Client数据库
USE Client;
-- 创建敌情记录表
-- Create enemy records table
CREATE TABLE IF NOT EXISTS enemy_records (
-- 基本信息字段
id VARCHAR(50) PRIMARY KEY COMMENT '敌人唯一标识符',
longitude DOUBLE NOT NULL COMMENT '经度坐标',
latitude DOUBLE NOT NULL COMMENT '纬度坐标',
threat_level VARCHAR(20) NOT NULL COMMENT '威胁等级:高/中/低',
discovery_time DATETIME NOT NULL COMMENT '发现时间',
enemy_type VARCHAR(50) COMMENT '敌人类型:装甲车/步兵/坦克/侦察兵等',
status VARCHAR(20) DEFAULT '活跃' COMMENT '状态:活跃/失联/已消除',
description TEXT COMMENT '描述信息',
update_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间',
-- 创建索引以提高查询性能
INDEX idx_threat_level (threat_level),
INDEX idx_status (status),
INDEX idx_discovery_time (discovery_time),
INDEX idx_location (longitude, latitude),
INDEX idx_enemy_type (enemy_type)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='敌情记录表';
-- 创建敌情统计视图
-- Create enemy statistics view
CREATE OR REPLACE VIEW enemy_statistics_view AS
SELECT
threat_level,
COUNT(*) as count,
COUNT(CASE WHEN status = '活跃' THEN 1 END) as active_count,
COUNT(CASE WHEN status = '失联' THEN 1 END) as missing_count,
COUNT(CASE WHEN status = '已消除' THEN 1 END) as eliminated_count,
MIN(discovery_time) as earliest_discovery,
MAX(discovery_time) as latest_discovery
FROM enemy_records
GROUP BY threat_level;
-- 创建威胁等级约束
-- Create threat level constraint
ALTER TABLE enemy_records
ADD CONSTRAINT chk_threat_level
CHECK (threat_level IN ('', '', ''));
-- 创建状态约束
-- Create status constraint
ALTER TABLE enemy_records
ADD CONSTRAINT chk_status
CHECK (status IN ('活跃', '失联', '已消除'));
-- 插入测试数据
-- Insert test data
INSERT INTO enemy_records (
id, longitude, latitude, threat_level, discovery_time,
enemy_type, status, description
) VALUES
('ENEMY001', 116.4074, 39.9042, '', '2025-07-08 08:30:00',
'装甲车', '活跃', '在北京市朝阳区发现的重型装甲车,配备主炮'),
('ENEMY002', 116.3912, 39.9139, '', '2025-07-08 09:15:00',
'步兵', '活跃', '武装步兵小队约5-8人携带轻武器'),
('ENEMY003', 116.4231, 39.8876, '', '2025-07-08 07:45:00',
'侦察兵', '失联', '单独行动的侦察兵最后位置在CBD区域'),
('ENEMY004', 116.3845, 39.9254, '', '2025-07-08 10:20:00',
'坦克', '活跃', '主战坦克,型号不明,具有强大火力'),
('ENEMY005', 116.4156, 39.9087, '', '2025-07-08 11:00:00',
'装甲运兵车', '活跃', '运输型装甲车,可能载有多名士兵'),
('ENEMY006', 116.3978, 39.8945, '', '2025-07-08 06:30:00',
'侦察无人机', '已消除', '小型侦察无人机,已被击落'),
('ENEMY007', 116.4298, 39.9178, '', '2025-07-08 12:15:00',
'自行火炮', '活跃', '远程火炮系统,射程覆盖大片区域'),
('ENEMY008', 116.3756, 39.9034, '', '2025-07-08 13:45:00',
'武装皮卡', '失联', '改装的武装皮卡车,机动性强')
ON DUPLICATE KEY UPDATE
longitude = VALUES(longitude),
latitude = VALUES(latitude),
threat_level = VALUES(threat_level),
discovery_time = VALUES(discovery_time),
enemy_type = VALUES(enemy_type),
status = VALUES(status),
description = VALUES(description),
update_time = CURRENT_TIMESTAMP;
-- 创建敌情操作日志表
-- Create enemy operations log table
CREATE TABLE IF NOT EXISTS enemy_operation_logs (
id INT AUTO_INCREMENT PRIMARY KEY,
enemy_id VARCHAR(50) NOT NULL COMMENT '敌人ID',
operation_type VARCHAR(50) NOT NULL COMMENT '操作类型:发现/更新/消除',
operator VARCHAR(50) NOT NULL COMMENT '操作员',
operation_time DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '操作时间',
old_status VARCHAR(20) COMMENT '操作前状态',
new_status VARCHAR(20) COMMENT '操作后状态',
remarks TEXT COMMENT '备注信息',
INDEX idx_enemy_id (enemy_id),
INDEX idx_operation_time (operation_time),
INDEX idx_operation_type (operation_type),
FOREIGN KEY (enemy_id) REFERENCES enemy_records(id)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='敌情操作日志表';
-- 创建触发器:自动记录状态变更
-- Create trigger: automatically log status changes
DELIMITER //
CREATE TRIGGER enemy_status_change_log
AFTER UPDATE ON enemy_records
FOR EACH ROW
BEGIN
IF OLD.status != NEW.status THEN
INSERT INTO enemy_operation_logs (
enemy_id, operation_type, operator, old_status, new_status, remarks
) VALUES (
NEW.id,
'状态变更',
'SYSTEM',
OLD.status,
NEW.status,
CONCAT('状态从 "', OLD.status, '" 变更为 "', NEW.status, '"')
);
END IF;
END//
DELIMITER ;
-- 创建存储过程:获取指定区域内的敌情
-- Create stored procedure: get enemies in specified area
DELIMITER //
CREATE PROCEDURE GetEnemiesInArea(
IN min_lon DOUBLE,
IN max_lon DOUBLE,
IN min_lat DOUBLE,
IN max_lat DOUBLE,
IN threat_filter VARCHAR(20)
)
BEGIN
SELECT * FROM enemy_records
WHERE longitude BETWEEN min_lon AND max_lon
AND latitude BETWEEN min_lat AND max_lat
AND (threat_filter IS NULL OR threat_level = threat_filter)
AND status = '活跃'
ORDER BY threat_level DESC, discovery_time DESC;
END//
DELIMITER ;
-- 创建存储过程:获取威胁统计信息
-- Create stored procedure: get threat statistics
DELIMITER //
CREATE PROCEDURE GetThreatStatistics()
BEGIN
SELECT
'总计' as category,
COUNT(*) as total_count,
COUNT(CASE WHEN status = '活跃' THEN 1 END) as active_count,
COUNT(CASE WHEN threat_level = '' THEN 1 END) as high_threat_count,
COUNT(CASE WHEN threat_level = '' THEN 1 END) as medium_threat_count,
COUNT(CASE WHEN threat_level = '' THEN 1 END) as low_threat_count
FROM enemy_records
UNION ALL
SELECT
threat_level as category,
COUNT(*) as total_count,
COUNT(CASE WHEN status = '活跃' THEN 1 END) as active_count,
0 as high_threat_count,
0 as medium_threat_count,
0 as low_threat_count
FROM enemy_records
GROUP BY threat_level
ORDER BY
CASE category
WHEN '总计' THEN 0
WHEN '' THEN 1
WHEN '' THEN 2
WHEN '' THEN 3
END;
END//
DELIMITER ;
-- 验证表结构
-- Verify table structure
SELECT
TABLE_NAME,
TABLE_COMMENT,
TABLE_ROWS
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_SCHEMA = 'Client'
AND TABLE_NAME LIKE '%enemy%';
-- 显示测试数据统计
-- Show test data statistics
SELECT
'敌情记录总数' as metric,
COUNT(*) as value
FROM enemy_records
UNION ALL
SELECT
CONCAT(threat_level, '威胁') as metric,
COUNT(*) as value
FROM enemy_records
GROUP BY threat_level
UNION ALL
SELECT
CONCAT(status, '状态') as metric,
COUNT(*) as value
FROM enemy_records
GROUP BY status;
-- 输出成功信息
SELECT 'Enemy database schema created successfully!' as message,
NOW() as created_time;