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.

192 lines
7.3 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.

-- CasualtySightPlus 战场探索系统 - 更新的数据库表结构
-- 数据库: Client
-- 更新日期: 2025-06-18
-- 变更: 合并UAV和Dog设备表移除伤员记录表
USE Client;
-- 删除旧的分离表和视图(如果存在)
DROP VIEW IF EXISTS uavdatabase;
DROP VIEW IF EXISTS dogdatabase;
DROP VIEW IF EXISTS injurydatabase;
DROP TABLE IF EXISTS uav_devices;
DROP TABLE IF EXISTS dog_devices;
DROP TABLE IF EXISTS injury_records;
-- 1. 统一设备表 (无人机 + 地面机器人)
CREATE TABLE IF NOT EXISTS devices (
id VARCHAR(50) PRIMARY KEY,
name VARCHAR(100) NOT NULL DEFAULT '无人设备',
device_type VARCHAR(20) NOT NULL COMMENT '设备类型: uav=无人机, dog=地面机器人',
state INT DEFAULT 0 COMMENT '设备状态: 0=离线, 1=在线, 2=工作中, 3=错误',
ip VARCHAR(15),
port INT,
longitude DOUBLE,
latitude DOUBLE,
signal_strength INT DEFAULT 0 COMMENT '信号强度 0-100',
last_heartbeat TIMESTAMP NULL COMMENT '最后心跳时间',
battery_level INT DEFAULT 100 COMMENT '电池电量 0-100',
firmware_version VARCHAR(50) COMMENT '固件版本',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
-- 索引优化
INDEX idx_device_type (device_type),
INDEX idx_state (state),
INDEX idx_location (longitude, latitude),
INDEX idx_type_state (device_type, state)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='统一设备表(无人机+地面机器人)';
-- 2. 系统配置表
CREATE TABLE IF NOT EXISTS system_config (
config_key VARCHAR(100) PRIMARY KEY,
config_value TEXT,
config_type VARCHAR(20) DEFAULT 'string' COMMENT '配置类型: string, int, float, boolean, json',
description VARCHAR(500),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='系统配置表';
-- 3. 用户会话表
CREATE TABLE IF NOT EXISTS user_sessions (
session_id VARCHAR(100) PRIMARY KEY,
user_name VARCHAR(50),
login_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
last_activity TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
ip_address VARCHAR(45),
user_agent TEXT,
status INT DEFAULT 1 COMMENT '会话状态: 0=已注销, 1=活跃',
INDEX idx_user (user_name),
INDEX idx_status (status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='用户会话表';
-- 4. 设备操作日志表
CREATE TABLE IF NOT EXISTS device_operation_logs (
log_id BIGINT AUTO_INCREMENT PRIMARY KEY,
device_id VARCHAR(50),
device_type VARCHAR(20) COMMENT '设备类型: uav, dog',
operation VARCHAR(50) COMMENT '操作类型: connect, disconnect, control, move, takeoff, land',
operation_result VARCHAR(20) DEFAULT 'success' COMMENT '操作结果: success, failed, timeout',
operator VARCHAR(50) COMMENT '操作员',
operation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
details JSON COMMENT '操作详细信息',
INDEX idx_device (device_id),
INDEX idx_operation_time (operation_time),
INDEX idx_device_type (device_type),
FOREIGN KEY (device_id) REFERENCES devices(id) ON DELETE SET NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='设备操作日志表';
-- 5. 探索任务表 (战场探索系统的核心功能)
CREATE TABLE IF NOT EXISTS exploration_tasks (
task_id VARCHAR(50) PRIMARY KEY,
task_name VARCHAR(200) NOT NULL,
task_type VARCHAR(50) COMMENT '任务类型: patrol=巡逻, reconnaissance=侦察, search=搜索',
assigned_devices JSON COMMENT '分配的设备ID列表',
task_status VARCHAR(20) DEFAULT 'created' COMMENT '任务状态: created, running, paused, completed, failed',
start_time TIMESTAMP NULL,
end_time TIMESTAMP NULL,
target_area JSON COMMENT '目标区域坐标',
task_priority INT DEFAULT 1 COMMENT '任务优先级: 1=低, 2=中, 3=高, 4=紧急',
created_by VARCHAR(50),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_status (task_status),
INDEX idx_priority (task_priority),
INDEX idx_type (task_type)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='探索任务表';
-- 插入默认系统配置
INSERT INTO system_config (config_key, config_value, config_type, description) VALUES
('app.version', '2.0.0', 'string', '应用程序版本'),
('app.theme', 'military', 'string', '默认主题'),
('database.connection_timeout', '30000', 'int', '数据库连接超时时间(毫秒)'),
('ui.auto_refresh_interval', '5000', 'int', '界面自动刷新间隔(毫秒)'),
('ui.device_card_style', 'modern', 'string', '设备卡片样式'),
('map.default_center_lat', '39.9', 'float', '地图默认中心纬度'),
('map.default_center_lon', '116.4', 'float', '地图默认中心经度'),
('map.default_zoom', '12', 'int', '地图默认缩放级别'),
('device.heartbeat_interval', '10000', 'int', '设备心跳间隔(毫秒)'),
('device.connection_timeout', '30000', 'int', '设备连接超时(毫秒)'),
('exploration.max_concurrent_tasks', '5', 'int', '最大并发探索任务数'),
('exploration.default_patrol_speed', '2.0', 'float', '默认巡逻速度(m/s)')
ON DUPLICATE KEY UPDATE
config_value = VALUES(config_value),
updated_at = CURRENT_TIMESTAMP;
-- 插入示例设备数据
INSERT INTO devices (id, name, device_type, state, ip, port, longitude, latitude, signal_strength, battery_level) VALUES
('UAV001', '侦察无人机-01', 'uav', 1, '192.168.1.101', 8001, 116.4074, 39.9042, 85, 95),
('UAV002', '侦察无人机-02', 'uav', 0, '192.168.1.102', 8002, 116.4084, 39.9052, 0, 78),
('DOG001', '地面机器人-01', 'dog', 1, '192.168.1.201', 8101, 116.4064, 39.9032, 92, 88),
('DOG002', '地面机器人-02', 'dog', 2, '192.168.1.202', 8102, 116.4054, 39.9022, 76, 65)
ON DUPLICATE KEY UPDATE
name = VALUES(name),
device_type = VALUES(device_type),
updated_at = CURRENT_TIMESTAMP;
-- 为兼容现有代码,创建视图
CREATE OR REPLACE VIEW uavdatabase AS
SELECT
id,
state,
ip,
port,
longitude as lon,
latitude as lat
FROM devices
WHERE device_type = 'uav';
CREATE OR REPLACE VIEW dogdatabase AS
SELECT
id,
state,
ip,
port,
longitude as lon,
latitude as lat
FROM devices
WHERE device_type = 'dog';
-- 创建统一的设备视图(用于新的界面代码)
CREATE OR REPLACE VIEW device_list AS
SELECT
id,
name,
device_type,
CASE device_type
WHEN 'uav' THEN '无人机'
WHEN 'dog' THEN '地面机器人'
ELSE '未知设备'
END as device_type_name,
CASE state
WHEN 0 THEN '离线'
WHEN 1 THEN '在线'
WHEN 2 THEN '工作中'
WHEN 3 THEN '错误'
ELSE '未知状态'
END as state_name,
state,
ip,
port,
longitude,
latitude,
signal_strength,
battery_level,
last_heartbeat,
created_at,
updated_at
FROM devices
ORDER BY device_type, name;
-- 显示创建的表
SHOW TABLES;
-- 显示表结构概要
SELECT
TABLE_NAME as '表名',
TABLE_COMMENT as '说明',
TABLE_ROWS as '记录数'
FROM information_schema.TABLES
WHERE TABLE_SCHEMA = 'Client'
AND TABLE_TYPE = 'BASE TABLE'
ORDER BY TABLE_NAME;