cosmo/backend/scripts/upgrade_complete.sql

275 lines
13 KiB
PL/PgSQL
Raw Blame History

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.

-- ============================================================
-- Production Database Upgrade Script (Complete)
-- ============================================================
-- 严格按照要求执行以下升级:
-- 1. celestial_bodies - 增加 short_name 字段
-- 2. menus + role_menus - 完整导入
-- 3. celestial_events - 完整导入(新表)
-- 4. scheduled_jobs - 完整导入(新表)
-- 5. system_settings - 完整导入
-- 6. user_follows - 完整导入(新表)
-- ============================================================
-- 开启"上帝模式":忽略外键约束和触发器
SET session_replication_role = 'replica';
BEGIN;
-- ============================================================
-- 1. Add short_name column to celestial_bodies
-- ============================================================
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_name = 'celestial_bodies'
AND column_name = 'short_name'
) THEN
ALTER TABLE celestial_bodies ADD COLUMN short_name VARCHAR(50);
RAISE NOTICE 'Added short_name column';
END IF;
END $$;
-- ============================================================
-- 2. 创建并导入 menus 和 role_menus 表
-- ============================================================
-- 清空现有数据(如果表存在)
DO $$
BEGIN
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'menus') THEN
TRUNCATE TABLE menus CASCADE;
END IF;
END $$;
-- 创建 menus 表(如果不存在)
CREATE TABLE IF NOT EXISTS menus (
id SERIAL PRIMARY KEY,
parent_id INTEGER REFERENCES menus(id) ON DELETE CASCADE,
name VARCHAR(100) NOT NULL,
title VARCHAR(100) NOT NULL,
icon VARCHAR(50),
path VARCHAR(200),
component VARCHAR(200),
sort_order INTEGER DEFAULT 0,
is_active BOOLEAN DEFAULT true,
description TEXT,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
-- 插入 menus 数据
INSERT INTO menus (id, parent_id, name, title, icon, path, component, sort_order, is_active, description, created_at, updated_at) VALUES
(1, NULL, 'dashboard', '控制台', 'dashboard', '/admin/dashboard', 'admin/Dashboard', 1, true, '系统控制台', '2025-11-28 18:07:11.767382', '2025-11-28 18:07:11.767382'),
(2, NULL, 'data_management', '数据管理', 'database', '', '', 2, true, '数据管理模块', '2025-11-28 18:07:11.767382', '2025-11-28 18:07:11.767382'),
(6, NULL, 'platform_management', '平台管理', 'settings', '', '', 3, true, '管理用户和系统参数', '2025-11-29 19:03:08.776597', '2025-11-29 19:03:08.776597'),
(14, NULL, 'user_profile', '个人资料', 'profile', '/user/profile', 'user/Profile', 1, true, '个人资料管理', '2025-12-18 16:26:11.778475', '2025-12-18 16:26:11.778475'),
(15, NULL, 'user_follow', '我的天体', 'star', '/user/follow', 'user/UserFollow', 2, true, '我关注的天体', '2025-12-18 16:27:48.688747', '2025-12-18 16:27:48.688747'),
(11, 2, 'star_systems', '恒星系统管理', 'StarOutlined', '/admin/star-systems', 'StarSystems', 1, true, '管理太阳系和系外恒星系统', '2025-12-06 02:35:21.137234', '2025-12-06 02:35:21.137234'),
(3, 2, 'celestial_bodies', '天体数据管理', NULL, '/admin/celestial-bodies', 'admin/CelestialBodies', 2, true, '查看和管理天体数据', '2025-11-28 18:07:11.767382', '2025-11-28 18:07:11.767382'),
(4, 2, 'static_data', '静态数据管理', NULL, '/admin/static-data', 'admin/StaticData', 2, true, '查看和管理静态数据(星座、星系等)', '2025-11-28 18:07:11.767382', '2025-11-28 18:07:11.767382'),
(5, 2, 'nasa_data', 'Horizon数据下载', NULL, '/admin/nasa-data', 'admin/NasaData', 3, true, '管理NASA Horizons数据下载', '2025-11-28 18:07:11.767382', '2025-11-28 18:07:11.767382'),
(13, 2, 'celestial_events', '天体事件', 'CalendarOutlined', '/admin/celestial-events', '', 4, true, '', '2025-12-15 03:20:39.798021', '2025-12-15 03:20:39.798021'),
(7, 6, 'user_management', '用户管理', NULL, '/admin/users', 'admin/Users', 1, true, '管理系统用户账号', '2025-11-29 19:03:08.776597', '2025-11-29 19:03:08.776597'),
(8, 6, 'platform_parameters_management', '平台参数管理', NULL, '/admin/settings', 'admin/Settings', 2, true, '管理系统通用配置参数', '2025-11-29 19:03:08.776597', '2025-11-29 19:03:08.776597'),
(12, 6, 'scheduled_jobs', '定时任务设置', 'ClockCircleOutlined', '/admin/scheduled-jobs', 'admin/ScheduledJobs', 5, true, '管理系统定时任务及脚本', '2025-12-10 17:42:38.031518', '2025-12-10 17:42:38.031518'),
(10, 6, 'system_tasks', '系统任务监控', 'schedule', '/admin/tasks', 'admin/Tasks', 30, true, '', '2025-11-30 16:04:59.572869', '2025-11-30 16:04:59.572869');
-- Reset sequence
SELECT setval('menus_id_seq', (SELECT MAX(id) FROM menus));
-- 创建 role_menus 表(如果不存在)
CREATE TABLE IF NOT EXISTS role_menus (
role_id INTEGER NOT NULL,
menu_id INTEGER NOT NULL,
PRIMARY KEY (role_id, menu_id)
);
-- 清空并插入 role_menus 数据
TRUNCATE TABLE role_menus;
-- 动态获取 admin 和 user 角色 ID 并插入
DO $$
DECLARE
admin_role_id INTEGER;
user_role_id INTEGER;
BEGIN
SELECT id INTO admin_role_id FROM roles WHERE name = 'admin' LIMIT 1;
SELECT id INTO user_role_id FROM roles WHERE name = 'user' LIMIT 1;
IF admin_role_id IS NOT NULL THEN
INSERT INTO role_menus (role_id, menu_id) VALUES
(admin_role_id, 1), (admin_role_id, 2), (admin_role_id, 3), (admin_role_id, 4),
(admin_role_id, 5), (admin_role_id, 6), (admin_role_id, 7), (admin_role_id, 8),
(admin_role_id, 10), (admin_role_id, 11), (admin_role_id, 12), (admin_role_id, 13),
(admin_role_id, 14), (admin_role_id, 15);
END IF;
IF user_role_id IS NOT NULL THEN
INSERT INTO role_menus (role_id, menu_id) VALUES
(user_role_id, 14), (user_role_id, 15);
END IF;
END $$;
-- ============================================================
-- 3. 创建并导入 celestial_events 表(新表)
-- ============================================================
-- 创建表
CREATE TABLE IF NOT EXISTS celestial_events (
id SERIAL PRIMARY KEY,
body_id VARCHAR(20) NOT NULL,
body_name VARCHAR(100),
event_type VARCHAR(50) NOT NULL,
event_time TIMESTAMP NOT NULL,
longitude DECIMAL(10, 6),
latitude DECIMAL(10, 6),
description TEXT,
source VARCHAR(50),
related_body_id VARCHAR(20),
related_body_name VARCHAR(100),
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
-- 创建索引
CREATE INDEX IF NOT EXISTS idx_celestial_events_body_id ON celestial_events(body_id);
CREATE INDEX IF NOT EXISTS idx_celestial_events_event_time ON celestial_events(event_time);
CREATE INDEX IF NOT EXISTS idx_celestial_events_event_type ON celestial_events(event_type);
-- 清空数据(如果需要导入具体数据,请在这里添加 INSERT 语句)
TRUNCATE TABLE celestial_events;
-- ============================================================
-- 4. 创建并导入 scheduled_jobs 表(新表)
-- ============================================================
-- 创建表
CREATE TABLE IF NOT EXISTS scheduled_jobs (
id SERIAL PRIMARY KEY,
name VARCHAR(200) NOT NULL,
cron_expression VARCHAR(100) NOT NULL,
python_code TEXT,
is_active BOOLEAN DEFAULT true,
last_run_at TIMESTAMP,
last_run_status VARCHAR(50),
next_run_at TIMESTAMP,
description TEXT,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
job_type VARCHAR(50) DEFAULT 'custom',
predefined_function VARCHAR(200),
function_params JSONB
);
-- 清空并插入数据
TRUNCATE TABLE scheduled_jobs;
INSERT INTO scheduled_jobs (id, name, cron_expression, python_code, is_active, last_run_at, last_run_status, next_run_at, description, created_at, updated_at, job_type, predefined_function, function_params) VALUES
(1, '每日更新天体位置数据', '0 2 * * *', NULL, false, NULL, NULL, NULL, '每天凌晨2点自动从NASA Horizons下载主要天体的位置数据', '2025-12-10 17:43:01.234567', '2025-12-10 17:43:01.234567', 'predefined', 'download_positions_task', '{"body_ids": ["10", "199", "299", "399", "301", "499", "599", "699", "799", "899"], "days_range": "3"}'),
(2, '获取主要天体的食、合、冲等事件', '0 3 1 * *', NULL, true, NULL, NULL, NULL, '每月1日凌晨3点计算未来一年的主要天文事件', '2025-12-10 17:43:01.234567', '2025-12-10 17:43:01.234567', 'predefined', 'calculate_planetary_events', '{"body_ids": ["199", "299", "499", "599", "699", "799", "899"], "days_ahead": "365", "clean_old_events": true, "threshold_degrees": "5", "calculate_close_approaches": true}');
-- Reset sequence
SELECT setval('scheduled_jobs_id_seq', (SELECT MAX(id) FROM scheduled_jobs));
-- ============================================================
-- 5. 导入 system_settings 表
-- ============================================================
-- 创建表(如果不存在)
CREATE TABLE IF NOT EXISTS system_settings (
key VARCHAR(100) PRIMARY KEY,
value TEXT,
value_type VARCHAR(20) DEFAULT 'string',
category VARCHAR(50),
label VARCHAR(200),
description TEXT,
is_public BOOLEAN DEFAULT false,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
-- 插入或更新数据
INSERT INTO system_settings (key, value, value_type, category, label, description, is_public, created_at, updated_at) VALUES
('view_mode', 'solar', 'string', 'ui', '默认视图模式', '系统默认的3D场景视图模式solar或galaxy', true, NOW(), NOW()),
('nasa_api_timeout', '120', 'int', 'api', 'NASA API超时时间', 'NASA Horizons API请求超时时间', false, NOW(), NOW()),
('auto_download_positions', 'False', 'bool', 'system', '自动下载位置数据', '当位置数据不存在时是否自动从NASA Horizons下载', false, NOW(), NOW())
ON CONFLICT (key) DO UPDATE SET
value = EXCLUDED.value,
value_type = EXCLUDED.value_type,
category = EXCLUDED.category,
label = EXCLUDED.label,
description = EXCLUDED.description,
is_public = EXCLUDED.is_public,
updated_at = NOW();
-- ============================================================
-- 6. 创建并导入 user_follows 表(新表)
-- ============================================================
-- 创建表
CREATE TABLE IF NOT EXISTS user_follows (
user_id INTEGER NOT NULL,
body_id INTEGER NOT NULL,
created_at TIMESTAMP DEFAULT NOW(),
PRIMARY KEY (user_id, body_id)
);
-- 创建索引
CREATE INDEX IF NOT EXISTS idx_user_follows_user_id ON user_follows(user_id);
CREATE INDEX IF NOT EXISTS idx_user_follows_body_id ON user_follows(body_id);
-- 清空数据(保留现有用户关注数据,不做导入)
-- 如果需要导入数据,请在这里添加 INSERT 语句
-- ============================================================
-- 提交事务
-- ============================================================
COMMIT;
-- ============================================================
-- 恢复正常模式
-- ============================================================
SET session_replication_role = 'origin';
-- ============================================================
-- 验证结果
-- ============================================================
SELECT 'celestial_bodies.short_name' as "Item",
CASE WHEN EXISTS(
SELECT 1 FROM information_schema.columns
WHERE table_name='celestial_bodies' AND column_name='short_name'
) THEN '✓ EXISTS' ELSE '✗ MISSING' END as "Status"
UNION ALL
SELECT 'menus table',
CASE WHEN EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name='menus')
THEN '✓ EXISTS' ELSE '✗ MISSING' END
UNION ALL
SELECT 'celestial_events table',
CASE WHEN EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name='celestial_events')
THEN '✓ EXISTS' ELSE '✗ MISSING' END
UNION ALL
SELECT 'scheduled_jobs table',
CASE WHEN EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name='scheduled_jobs')
THEN '✓ EXISTS' ELSE '✗ MISSING' END
UNION ALL
SELECT 'user_follows table',
CASE WHEN EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name='user_follows')
THEN '✓ EXISTS' ELSE '✗ MISSING' END;
-- 检查记录数
SELECT 'menus' as "Table", COUNT(*)::text || ' records' as "Count" FROM menus
UNION ALL
SELECT 'role_menus', COUNT(*)::text || ' records' FROM role_menus
UNION ALL
SELECT 'celestial_events', COUNT(*)::text || ' records' FROM celestial_events
UNION ALL
SELECT 'scheduled_jobs', COUNT(*)::text || ' records' FROM scheduled_jobs
UNION ALL
SELECT 'system_settings', COUNT(*)::text || ' records' FROM system_settings
UNION ALL
SELECT 'user_follows', COUNT(*)::text || ' records' FROM user_follows;