|
|
-- ============================================
|
|
|
-- 无人机指挥中心数据库初始化脚本
|
|
|
-- 包含用户认证、威胁区域管理、路径规划等核心功能
|
|
|
-- ============================================
|
|
|
|
|
|
-- 创建数据库
|
|
|
CREATE DATABASE IF NOT EXISTS command_center CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
|
|
|
USE command_center;
|
|
|
|
|
|
-- 设置字符集
|
|
|
SET NAMES utf8mb4;
|
|
|
SET CHARACTER SET utf8mb4;
|
|
|
SET character_set_connection=utf8mb4;
|
|
|
|
|
|
-- ============================================
|
|
|
-- 1. 用户认证系统
|
|
|
-- ============================================
|
|
|
|
|
|
-- 创建用户表
|
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
|
id INT PRIMARY KEY AUTO_INCREMENT,
|
|
|
username VARCHAR(50) NOT NULL UNIQUE,
|
|
|
password VARCHAR(255) NOT NULL,
|
|
|
role ENUM('admin', 'operator') NOT NULL DEFAULT 'operator',
|
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
|
|
|
) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
|
|
|
|
|
|
-- ============================================
|
|
|
-- 2. 威胁区域管理系统
|
|
|
-- ============================================
|
|
|
|
|
|
-- 删除现有威胁区表(如果存在)以确保结构正确
|
|
|
DROP TABLE IF EXISTS threat_zones;
|
|
|
|
|
|
-- 创建威胁区表
|
|
|
CREATE TABLE threat_zones (
|
|
|
id INT PRIMARY KEY AUTO_INCREMENT,
|
|
|
type ENUM('radar', 'missile', 'aircraft', 'ground', 'weather') NOT NULL,
|
|
|
level ENUM('low', 'medium', 'high', 'critical') NOT NULL,
|
|
|
description TEXT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci,
|
|
|
geometry_type ENUM('circle', 'polygon', 'rectangle') NOT NULL,
|
|
|
geometry_data JSON NOT NULL COMMENT '存储几何形状数据',
|
|
|
time_start TIMESTAMP NULL COMMENT '威胁区开始时间',
|
|
|
time_end TIMESTAMP NULL COMMENT '威胁区结束时间',
|
|
|
status ENUM('active', 'inactive') NOT NULL DEFAULT 'active',
|
|
|
created_by INT DEFAULT NULL,
|
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
INDEX idx_type (type),
|
|
|
INDEX idx_level (level),
|
|
|
INDEX idx_status (status),
|
|
|
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE SET NULL
|
|
|
) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
|
|
|
|
|
|
-- ============================================
|
|
|
-- 3. 路径规划系统
|
|
|
-- ============================================
|
|
|
|
|
|
-- 删除现有路径规划表(如果存在)以确保结构正确
|
|
|
DROP TABLE IF EXISTS path_plans;
|
|
|
|
|
|
-- 创建路径规划表(基于最新API结构)
|
|
|
CREATE TABLE path_plans (
|
|
|
id INT PRIMARY KEY AUTO_INCREMENT,
|
|
|
name VARCHAR(255) DEFAULT NULL COMMENT '路径规划名称',
|
|
|
start_latitude DECIMAL(10, 7) NOT NULL COMMENT '起点纬度',
|
|
|
start_longitude DECIMAL(10, 7) NOT NULL COMMENT '起点经度',
|
|
|
end_latitude DECIMAL(10, 7) NOT NULL COMMENT '终点纬度',
|
|
|
end_longitude DECIMAL(10, 7) NOT NULL COMMENT '终点经度',
|
|
|
path_points JSON NOT NULL COMMENT '路径点数据,包含lng, lat, altitude',
|
|
|
algorithm VARCHAR(20) NOT NULL DEFAULT 'astar' COMMENT '使用的规划算法',
|
|
|
distance DECIMAL(10, 2) DEFAULT NULL COMMENT '路径总距离(米)',
|
|
|
estimated_time INT DEFAULT NULL COMMENT '预计时间(分钟)',
|
|
|
flight_altitude INT DEFAULT 100 COMMENT '飞行高度(米)',
|
|
|
flight_speed DECIMAL(5, 2) DEFAULT 10.00 COMMENT '飞行速度(米/秒)',
|
|
|
threat_zones_avoided JSON DEFAULT NULL COMMENT '避开的威胁区ID列表',
|
|
|
threat_zones_passed JSON DEFAULT NULL COMMENT '穿过的威胁区ID列表',
|
|
|
target_order JSON DEFAULT NULL COMMENT '目标点访问顺序',
|
|
|
status ENUM('planned', 'executing', 'completed', 'failed', 'cancelled') NOT NULL DEFAULT 'planned',
|
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
executed_at TIMESTAMP NULL COMMENT '开始执行时间',
|
|
|
completed_at TIMESTAMP NULL COMMENT '完成时间',
|
|
|
INDEX idx_status (status),
|
|
|
INDEX idx_algorithm (algorithm),
|
|
|
INDEX idx_created_at (created_at)
|
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='路径规划表';
|
|
|
|
|
|
-- ============================================
|
|
|
-- 4. 操作日志系统
|
|
|
-- ============================================
|
|
|
|
|
|
-- 创建操作日志表
|
|
|
CREATE TABLE IF NOT EXISTS operation_logs (
|
|
|
id INT PRIMARY KEY AUTO_INCREMENT,
|
|
|
user_id INT NOT NULL,
|
|
|
action VARCHAR(50) NOT NULL,
|
|
|
target_type VARCHAR(50) NOT NULL,
|
|
|
target_id INT NOT NULL,
|
|
|
details JSON,
|
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
|
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
|
|
|
INDEX idx_user_id (user_id),
|
|
|
INDEX idx_action (action),
|
|
|
INDEX idx_target_type (target_type),
|
|
|
INDEX idx_created_at (created_at)
|
|
|
) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
|
|
|
|
|
|
-- ============================================
|
|
|
-- 5. 插入初始数据
|
|
|
-- ============================================
|
|
|
|
|
|
-- 插入默认管理员用户
|
|
|
INSERT INTO users (username, password, role)
|
|
|
VALUES ('admin', '$2a$10$X7UrH5QxX5QxX5QxX5QxX.5QxX5QxX5QxX5QxX5QxX5QxX5QxX5Qx', 'admin')
|
|
|
ON DUPLICATE KEY UPDATE username = username;
|
|
|
|
|
|
-- 插入示例威胁区数据
|
|
|
INSERT INTO threat_zones (type, level, description, geometry_type, geometry_data, time_start, time_end, status, created_by)
|
|
|
VALUES
|
|
|
('radar', 'high', 'Radar Station', 'circle',
|
|
|
JSON_OBJECT('center', JSON_OBJECT('lng', 112.982279, 'lat', 28.19409), 'radius', 2000),
|
|
|
'2024-01-01 00:00:00', '2024-12-31 23:59:59', 'active', 1),
|
|
|
('missile', 'critical', 'Missile Site', 'circle',
|
|
|
JSON_OBJECT('center', JSON_OBJECT('lng', 112.992279, 'lat', 28.18409), 'radius', 3000),
|
|
|
'2024-01-01 00:00:00', '2024-12-31 23:59:59', 'active', 1),
|
|
|
('aircraft', 'medium', 'Air Patrol Zone', 'polygon',
|
|
|
JSON_OBJECT('coordinates', JSON_ARRAY(
|
|
|
JSON_OBJECT('lng', 112.970000, 'lat', 28.200000),
|
|
|
JSON_OBJECT('lng', 112.990000, 'lat', 28.200000),
|
|
|
JSON_OBJECT('lng', 112.990000, 'lat', 28.180000),
|
|
|
JSON_OBJECT('lng', 112.970000, 'lat', 28.180000)
|
|
|
)),
|
|
|
'2024-01-01 06:00:00', '2024-01-01 18:00:00', 'active', 1),
|
|
|
('weather', 'low', 'Weather Zone', 'rectangle',
|
|
|
JSON_OBJECT('southwest', JSON_OBJECT('lng', 112.960000, 'lat', 28.170000), 'northeast', JSON_OBJECT('lng', 112.980000, 'lat', 28.190000)),
|
|
|
'2024-01-01 00:00:00', '2024-12-31 23:59:59', 'active', 1),
|
|
|
('ground', 'medium', 'Military Base', 'polygon',
|
|
|
JSON_OBJECT('coordinates', JSON_ARRAY(
|
|
|
JSON_OBJECT('lng', 112.975000, 'lat', 28.195000),
|
|
|
JSON_OBJECT('lng', 112.980000, 'lat', 28.195000),
|
|
|
JSON_OBJECT('lng', 112.980000, 'lat', 28.190000),
|
|
|
JSON_OBJECT('lng', 112.975000, 'lat', 28.190000)
|
|
|
)),
|
|
|
'2024-01-01 00:00:00', '2024-12-31 23:59:59', 'active', 1);
|
|
|
|
|
|
-- 插入示例路径规划数据
|
|
|
INSERT INTO path_plans (
|
|
|
name, start_latitude, start_longitude, end_latitude, end_longitude,
|
|
|
path_points, algorithm, distance, estimated_time, flight_altitude, flight_speed,
|
|
|
threat_zones_avoided, status
|
|
|
) VALUES
|
|
|
(
|
|
|
'长沙市区巡逻路径', 28.194090, 112.982279, 28.200000, 112.990000,
|
|
|
JSON_ARRAY(
|
|
|
JSON_OBJECT('lng', 112.982279, 'lat', 28.194090, 'altitude', 100),
|
|
|
JSON_OBJECT('lng', 112.985000, 'lat', 28.197000, 'altitude', 100),
|
|
|
JSON_OBJECT('lng', 112.990000, 'lat', 28.200000, 'altitude', 100)
|
|
|
),
|
|
|
'astar', 1200.50, 8, 100, 10.0,
|
|
|
JSON_ARRAY(1, 2), 'completed'
|
|
|
),
|
|
|
(
|
|
|
'湘江沿岸监控路径', 28.196000, 112.985000, 28.205000, 112.995000,
|
|
|
JSON_ARRAY(
|
|
|
JSON_OBJECT('lng', 112.985000, 'lat', 28.196000, 'altitude', 120),
|
|
|
JSON_OBJECT('lng', 112.988000, 'lat', 28.199000, 'altitude', 120),
|
|
|
JSON_OBJECT('lng', 112.992000, 'lat', 28.202000, 'altitude', 120),
|
|
|
JSON_OBJECT('lng', 112.995000, 'lat', 28.205000, 'altitude', 120)
|
|
|
),
|
|
|
'astar', 1800.75, 12, 120, 10.0,
|
|
|
JSON_ARRAY(1, 3), 'executing'
|
|
|
),
|
|
|
(
|
|
|
'橘子洲头勘察路径', 28.180000, 112.970000, 28.185000, 112.975000,
|
|
|
JSON_ARRAY(
|
|
|
JSON_OBJECT('lng', 112.970000, 'lat', 28.180000, 'altitude', 50),
|
|
|
JSON_OBJECT('lng', 112.972000, 'lat', 28.182000, 'altitude', 60),
|
|
|
JSON_OBJECT('lng', 112.975000, 'lat', 28.185000, 'altitude', 50)
|
|
|
),
|
|
|
'straight', 800.25, 5, 50, 8.0,
|
|
|
JSON_ARRAY(), 'planned'
|
|
|
);
|
|
|
|
|
|
-- ============================================
|
|
|
-- 6. 数据验证和显示
|
|
|
-- ============================================
|
|
|
|
|
|
-- 验证数据插入
|
|
|
SELECT '=== 数据库初始化完成 ===' as status;
|
|
|
SELECT 'Users count:' as info, COUNT(*) as count FROM users;
|
|
|
SELECT 'Threat zones count:' as info, COUNT(*) as count FROM threat_zones;
|
|
|
SELECT 'Path plans count:' as info, COUNT(*) as count FROM path_plans;
|
|
|
SELECT 'Operation logs count:' as info, COUNT(*) as count FROM operation_logs;
|
|
|
|
|
|
-- 显示威胁区域统计
|
|
|
SELECT
|
|
|
level as '威胁级别',
|
|
|
COUNT(*) as '数量',
|
|
|
GROUP_CONCAT(type SEPARATOR ', ') as '类型'
|
|
|
FROM threat_zones
|
|
|
WHERE status = 'active'
|
|
|
GROUP BY level
|
|
|
ORDER BY FIELD(level, 'low', 'medium', 'high', 'critical');
|
|
|
|
|
|
-- 显示路径规划统计
|
|
|
SELECT
|
|
|
algorithm as '算法',
|
|
|
status as '状态',
|
|
|
COUNT(*) as '数量',
|
|
|
ROUND(AVG(distance), 2) as '平均距离(米)'
|
|
|
FROM path_plans
|
|
|
GROUP BY algorithm, status
|
|
|
ORDER BY algorithm, status;
|
|
|
|
|
|
-- ============================================
|
|
|
-- 初始化完成
|
|
|
-- ============================================ |