-- ============================================================ -- Production Database Upgrade Script (Final Version) -- ============================================================ -- 使用 session_replication_role 方法绕过外键约束检查 -- 这是数据迁移的最佳实践,显著提升升级效率 -- ============================================================ -- -- 优势: -- 1. 无需关心插入顺序 -- 2. 大幅提升导入速度 -- 3. 事务安全,失败自动回滚 -- -- 注意:需要 superuser 权限 -- ============================================================ -- 开启"上帝模式":忽略外键约束和触发器 SET session_replication_role = 'replica'; BEGIN; -- ============================================================ -- 0. Ensure roles exist (适配 display_name 字段) -- ============================================================ -- 方式1: 如果 roles 表有 display_name 字段,使用这个 INSERT INTO roles (name, display_name, description, created_at, updated_at) VALUES ('admin', '管理员', '管理员角色,拥有所有权限', NOW(), NOW()), ('user', '普通用户', '普通用户角色,只能访问基本功能', NOW(), NOW()) ON CONFLICT (name) DO UPDATE SET display_name = EXCLUDED.display_name, description = EXCLUDED.description, updated_at = NOW(); -- 方式2: 如果没有 display_name 字段,注释掉上面的,使用下面的 -- INSERT INTO roles (name, description, created_at, updated_at) -- VALUES -- ('admin', '管理员角色,拥有所有权限', NOW(), NOW()), -- ('user', '普通用户角色,只能访问基本功能', NOW(), NOW()) -- ON CONFLICT (name) DO UPDATE SET -- description = EXCLUDED.description, -- updated_at = NOW(); -- Reset sequence for roles SELECT setval('roles_id_seq', (SELECT COALESCE(MAX(id), 0) FROM roles)); -- ============================================================ -- 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 to celestial_bodies'; ELSE RAISE NOTICE 'short_name column already exists'; END IF; END $$; -- ============================================================ -- 2. Import menus and role_menus -- ============================================================ -- 清空现有数据(因为禁用了约束,可以直接 TRUNCATE) TRUNCATE TABLE menus CASCADE; -- 插入菜单数据(无需关心父子顺序!) 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 for menus SELECT setval('menus_id_seq', (SELECT MAX(id) FROM menus)); -- 插入 role_menus(无需担心 roles 是否存在!) INSERT INTO role_menus (role_id, menu_id) VALUES -- Admin role (role_id = 1) has access to all menus (1, 1), (1, 2), (1, 3), (1, 4), (1, 5), (1, 6), (1, 7), (1, 8), (1, 10), (1, 11), (1, 12), (1, 13), (1, 14), (1, 15), -- User role (role_id = 2) has access to user menus only (2, 14), (2, 15); -- ============================================================ -- 3. Import celestial_events -- ============================================================ TRUNCATE TABLE celestial_events; -- ============================================================ -- 4. Import scheduled_jobs -- ============================================================ TRUNCATE TABLE scheduled_jobs CASCADE; 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. Import system_settings -- ============================================================ 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. Ensure existing users have roles assigned -- ============================================================ DO $$ DECLARE user_record RECORD; user_role_id INTEGER := 2; -- user role BEGIN FOR user_record IN SELECT id FROM users LOOP IF NOT EXISTS ( SELECT 1 FROM user_roles WHERE user_id = user_record.id ) THEN INSERT INTO user_roles (user_id, role_id) VALUES (user_record.id, user_role_id); RAISE NOTICE 'Assigned user role to user %', user_record.id; END IF; END LOOP; END $$; -- ============================================================ -- 提交事务 -- ============================================================ COMMIT; -- ============================================================ -- 恢复正常模式(关键步骤!) -- ============================================================ SET session_replication_role = 'origin'; -- ============================================================ -- 数据一致性验证(在恢复约束后执行) -- ============================================================ -- 验证外键一致性 DO $$ DECLARE invalid_count INTEGER; BEGIN -- 检查 role_menus 中是否有无效的 role_id SELECT COUNT(*) INTO invalid_count FROM role_menus rm WHERE NOT EXISTS (SELECT 1 FROM roles r WHERE r.id = rm.role_id); IF invalid_count > 0 THEN RAISE WARNING 'Found % invalid role_id references in role_menus', invalid_count; END IF; -- 检查 role_menus 中是否有无效的 menu_id SELECT COUNT(*) INTO invalid_count FROM role_menus rm WHERE NOT EXISTS (SELECT 1 FROM menus m WHERE m.id = rm.menu_id); IF invalid_count > 0 THEN RAISE WARNING 'Found % invalid menu_id references in role_menus', invalid_count; END IF; -- 检查 menus 中是否有无效的 parent_id SELECT COUNT(*) INTO invalid_count FROM menus m1 WHERE m1.parent_id IS NOT NULL AND NOT EXISTS (SELECT 1 FROM menus m2 WHERE m2.id = m1.parent_id); IF invalid_count > 0 THEN RAISE WARNING 'Found % invalid parent_id references in menus', invalid_count; END IF; RAISE NOTICE 'Data integrity validation completed'; END $$; -- ============================================================ -- Verification queries -- ============================================================ -- Check roles SELECT id, name, description FROM roles ORDER BY id; -- Check if short_name column exists 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"; -- Check record counts SELECT 'roles' as "Table", COUNT(*)::text || ' records' as "Count" FROM roles UNION ALL SELECT 'menus', COUNT(*)::text || ' records' FROM menus UNION ALL SELECT 'role_menus', COUNT(*)::text || ' records' FROM role_menus UNION ALL SELECT 'scheduled_jobs', COUNT(*)::text || ' records' FROM scheduled_jobs UNION ALL SELECT 'system_settings', COUNT(*)::text || ' records' FROM system_settings; -- Check user role assignments SELECT u.id, u.username, COALESCE(array_agg(r.name), ARRAY[]::varchar[]) as roles FROM users u LEFT JOIN user_roles ur ON u.id = ur.user_id LEFT JOIN roles r ON ur.role_id = r.id GROUP BY u.id, u.username ORDER BY u.id;