14 KiB
14 KiB
Cosmo 数据库表结构设计
数据库信息
- 数据库类型: PostgreSQL 15+
- 数据库名称: cosmo_db
- 字符集: UTF8
表结构
1. celestial_bodies - 天体基本信息表
存储所有天体的基本信息和元数据。
CREATE TABLE celestial_bodies (
id VARCHAR(50) PRIMARY KEY, -- JPL Horizons ID 或自定义ID
name VARCHAR(200) NOT NULL, -- 英文名称
name_zh VARCHAR(200), -- 中文名称
type VARCHAR(50) NOT NULL, -- 天体类型: star, planet, moon, probe, comet, asteroid, etc.
description TEXT, -- 描述
metadata JSONB, -- 扩展元数据(launch_date, status, mass, radius等)
is_active bool, -- 天体有效状态
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
CONSTRAINT chk_type CHECK (type IN ('star', 'planet', 'moon', 'probe', 'comet', 'asteroid', 'dwarf_planet', 'satellite'))
);
-- 索引
CREATE INDEX idx_celestial_bodies_type ON celestial_bodies(type);
CREATE INDEX idx_celestial_bodies_name ON celestial_bodies(name);
-- 注释
COMMENT ON TABLE celestial_bodies IS '天体基本信息表';
COMMENT ON COLUMN celestial_bodies.id IS 'JPL Horizons ID(如-31代表Voyager 1)或自定义ID';
COMMENT ON COLUMN celestial_bodies.type IS '天体类型:star(恒星), planet(行星), moon(卫星), probe(探测器), comet(彗星), asteroid(小行星)';
COMMENT ON COLUMN celestial_bodies.metadata IS 'JSON格式的扩展元数据,例如:{"launch_date": "1977-09-05", "status": "active", "mass": 722, "radius": 2575}';
metadata JSONB字段示例:
{
"launch_date": "1977-09-05",
"status": "active",
"mass": 722, // kg
"radius": 2575, // km
"orbit_period": 365.25, // days
"rotation_period": 24, // hours
"discovery_date": "1930-02-18",
"discoverer": "Clyde Tombaugh"
}
2. positions - 位置历史表(时间序列)
存储天体的位置历史数据,支持历史查询和轨迹回放。
CREATE TABLE positions (
id BIGSERIAL PRIMARY KEY,
body_id VARCHAR(50) NOT NULL REFERENCES celestial_bodies(id) ON DELETE CASCADE,
time TIMESTAMP NOT NULL, -- 位置时间点
x DOUBLE PRECISION NOT NULL, -- X坐标(AU,日心坐标系)
y DOUBLE PRECISION NOT NULL, -- Y坐标(AU)
z DOUBLE PRECISION NOT NULL, -- Z坐标(AU)
vx DOUBLE PRECISION, -- X方向速度(可选)
vy DOUBLE PRECISION, -- Y方向速度(可选)
vz DOUBLE PRECISION, -- Z方向速度(可选)
source VARCHAR(50) DEFAULT 'nasa_horizons', -- 数据来源
created_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_source CHECK (source IN ('nasa_horizons', 'calculated', 'user_defined', 'imported'))
);
-- 索引(非常重要,用于高效查询)
CREATE INDEX idx_positions_body_time ON positions(body_id, time DESC);
CREATE INDEX idx_positions_time ON positions(time);
CREATE INDEX idx_positions_body_id ON positions(body_id);
-- 注释
COMMENT ON TABLE positions IS '天体位置历史表(时间序列数据)';
COMMENT ON COLUMN positions.body_id IS '关联celestial_bodies表的天体ID';
COMMENT ON COLUMN positions.time IS '该位置的观测/计算时间(UTC)';
COMMENT ON COLUMN positions.x IS 'X坐标,单位AU(天文单位),日心坐标系';
COMMENT ON COLUMN positions.source IS '数据来源:nasa_horizons(NASA API), calculated(计算), user_defined(用户定义), imported(导入)';
使用场景:
- 查询某天体在某时间点的位置
- 查询某天体在时间范围内的轨迹
- 支持时间旅行功能(回放历史位置)
3. resources - 资源文件管理表
统一管理纹理、3D模型、图标等静态资源。
CREATE TABLE resources (
id SERIAL PRIMARY KEY,
body_id VARCHAR(50) REFERENCES celestial_bodies(id) ON DELETE CASCADE,
resource_type VARCHAR(50) NOT NULL, -- 资源类型
file_path VARCHAR(500) NOT NULL, -- 相对于upload目录的路径
file_size INTEGER, -- 文件大小(bytes)
mime_type VARCHAR(100), -- MIME类型
metadata JSONB, -- 扩展信息(分辨率、格式等)
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_resource_type CHECK (resource_type IN ('texture', 'model', 'icon', 'thumbnail', 'data'))
);
-- 索引
CREATE INDEX idx_resources_body_id ON resources(body_id);
CREATE INDEX idx_resources_type ON resources(resource_type);
-- 注释
COMMENT ON TABLE resources IS '资源文件管理表(纹理、模型、图标等)';
COMMENT ON COLUMN resources.resource_type IS '资源类型:texture(纹理), model(3D模型), icon(图标), thumbnail(缩略图), data(数据文件)';
COMMENT ON COLUMN resources.file_path IS '相对路径,例如:textures/planets/earth_2k.jpg';
COMMENT ON COLUMN resources.metadata IS 'JSON格式元数据,例如:{"width": 2048, "height": 1024, "format": "jpg"}';
metadata JSONB字段示例:
{
"width": 2048,
"height": 1024,
"format": "jpg",
"color_space": "sRGB",
"model_format": "glb",
"polygon_count": 15000
}
4. static_data - 静态数据表
存储星座、星系、恒星等不需要动态计算的静态天文数据。
CREATE TABLE static_data (
id SERIAL PRIMARY KEY,
category VARCHAR(50) NOT NULL, -- 数据分类
name VARCHAR(200) NOT NULL, -- 名称
name_zh VARCHAR(200), -- 中文名称
data JSONB NOT NULL, -- 完整数据(JSON格式)
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_category CHECK (category IN ('constellation', 'galaxy', 'star', 'nebula', 'cluster')),
CONSTRAINT uq_category_name UNIQUE (category, name)
);
-- 索引
CREATE INDEX idx_static_data_category ON static_data(category);
CREATE INDEX idx_static_data_name ON static_data(name);
CREATE INDEX idx_static_data_data ON static_data USING GIN(data); -- JSONB索引
-- 注释
COMMENT ON TABLE static_data IS '静态天文数据表(星座、星系、恒星等)';
COMMENT ON COLUMN static_data.category IS '数据分类:constellation(星座), galaxy(星系), star(恒星), nebula(星云), cluster(星团)';
COMMENT ON COLUMN static_data.data IS 'JSON格式的完整数据,结构根据category不同而不同';
data JSONB字段示例:
星座数据:
{
"stars": [
{"name": "Betelgeuse", "ra": 88.79, "dec": 7.41},
{"name": "Rigel", "ra": 78.63, "dec": -8.20}
],
"lines": [[0, 1], [1, 2]],
"mythology": "猎户座的神话故事..."
}
星系数据:
{
"type": "spiral",
"distance_mly": 2.537,
"ra": 10.68,
"dec": 41.27,
"magnitude": 3.44,
"diameter_kly": 220,
"color": "#88aaff"
}
5. nasa_cache - NASA API缓存表
持久化NASA Horizons API的响应结果,减少API调用。
CREATE TABLE nasa_cache (
cache_key VARCHAR(500) PRIMARY KEY, -- 缓存键(body_id:start:end:step)
body_id VARCHAR(50),
start_time TIMESTAMP, -- 查询起始时间
end_time TIMESTAMP, -- 查询结束时间
step VARCHAR(10), -- 时间步长(如'1d')
data JSONB NOT NULL, -- 完整的API响应数据
expires_at TIMESTAMP NOT NULL, -- 过期时间
created_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_time_range CHECK (end_time >= start_time)
);
-- 索引
CREATE INDEX idx_nasa_cache_body_id ON nasa_cache(body_id);
CREATE INDEX idx_nasa_cache_expires ON nasa_cache(expires_at);
CREATE INDEX idx_nasa_cache_time_range ON nasa_cache(body_id, start_time, end_time);
-- 自动清理过期缓存(可选,需要pg_cron扩展)
-- SELECT cron.schedule('clean_expired_cache', '0 0 * * *', 'DELETE FROM nasa_cache WHERE expires_at < NOW()');
-- 注释
COMMENT ON TABLE nasa_cache IS 'NASA Horizons API响应缓存表';
COMMENT ON COLUMN nasa_cache.cache_key IS '缓存键格式:{body_id}:{start}:{end}:{step},例如:-31:2025-11-27:2025-11-28:1d';
COMMENT ON COLUMN nasa_cache.data IS 'NASA API的完整JSON响应';
COMMENT ON COLUMN nasa_cache.expires_at IS '缓存过期时间,过期后自动失效';
初始化脚本
创建数据库
-- 连接到PostgreSQL
psql -U postgres
-- 创建数据库
CREATE DATABASE cosmo_db
WITH
ENCODING = 'UTF8'
LC_COLLATE = 'en_US.UTF-8'
LC_CTYPE = 'en_US.UTF-8'
TEMPLATE = template0;
-- 连接到新数据库
\c cosmo_db
-- 创建必要的扩展(可选)
CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- UUID生成
CREATE EXTENSION IF NOT EXISTS "pg_trgm"; -- 模糊搜索
完整建表脚本
-- 按依赖顺序创建表
-- 1. 天体基本信息表
CREATE TABLE celestial_bodies (
id VARCHAR(50) PRIMARY KEY,
name VARCHAR(200) NOT NULL,
name_zh VARCHAR(200),
type VARCHAR(50) NOT NULL,
description TEXT,
metadata JSONB,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_type CHECK (type IN ('star', 'planet', 'moon', 'probe', 'comet', 'asteroid', 'dwarf_planet', 'satellite'))
);
CREATE INDEX idx_celestial_bodies_type ON celestial_bodies(type);
CREATE INDEX idx_celestial_bodies_name ON celestial_bodies(name);
-- 2. 位置历史表
CREATE TABLE positions (
id BIGSERIAL PRIMARY KEY,
body_id VARCHAR(50) NOT NULL REFERENCES celestial_bodies(id) ON DELETE CASCADE,
time TIMESTAMP NOT NULL,
x DOUBLE PRECISION NOT NULL,
y DOUBLE PRECISION NOT NULL,
z DOUBLE PRECISION NOT NULL,
vx DOUBLE PRECISION,
vy DOUBLE PRECISION,
vz DOUBLE PRECISION,
source VARCHAR(50) DEFAULT 'nasa_horizons',
created_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_source CHECK (source IN ('nasa_horizons', 'calculated', 'user_defined', 'imported'))
);
CREATE INDEX idx_positions_body_time ON positions(body_id, time DESC);
CREATE INDEX idx_positions_time ON positions(time);
CREATE INDEX idx_positions_body_id ON positions(body_id);
-- 3. 资源管理表
CREATE TABLE resources (
id SERIAL PRIMARY KEY,
body_id VARCHAR(50) REFERENCES celestial_bodies(id) ON DELETE CASCADE,
resource_type VARCHAR(50) NOT NULL,
file_path VARCHAR(500) NOT NULL,
file_size INTEGER,
mime_type VARCHAR(100),
metadata JSONB,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_resource_type CHECK (resource_type IN ('texture', 'model', 'icon', 'thumbnail', 'data'))
);
CREATE INDEX idx_resources_body_id ON resources(body_id);
CREATE INDEX idx_resources_type ON resources(resource_type);
-- 4. 静态数据表
CREATE TABLE static_data (
id SERIAL PRIMARY KEY,
category VARCHAR(50) NOT NULL,
name VARCHAR(200) NOT NULL,
name_zh VARCHAR(200),
data JSONB NOT NULL,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_category CHECK (category IN ('constellation', 'galaxy', 'star', 'nebula', 'cluster')),
CONSTRAINT uq_category_name UNIQUE (category, name)
);
CREATE INDEX idx_static_data_category ON static_data(category);
CREATE INDEX idx_static_data_name ON static_data(name);
CREATE INDEX idx_static_data_data ON static_data USING GIN(data);
-- 5. NASA缓存表
CREATE TABLE nasa_cache (
cache_key VARCHAR(500) PRIMARY KEY,
body_id VARCHAR(50),
start_time TIMESTAMP,
end_time TIMESTAMP,
step VARCHAR(10),
data JSONB NOT NULL,
expires_at TIMESTAMP NOT NULL,
created_at TIMESTAMP DEFAULT NOW(),
CONSTRAINT chk_time_range CHECK (end_time >= start_time)
);
CREATE INDEX idx_nasa_cache_body_id ON nasa_cache(body_id);
CREATE INDEX idx_nasa_cache_expires ON nasa_cache(expires_at);
CREATE INDEX idx_nasa_cache_time_range ON nasa_cache(body_id, start_time, end_time);
数据关系图
celestial_bodies (天体)
├── positions (1:N) - 天体位置历史
├── resources (1:N) - 天体资源文件
└── nasa_cache (1:N) - NASA API缓存
static_data (静态数据) - 独立表,不关联celestial_bodies
查询示例
查询某天体的最新位置
SELECT b.name, b.name_zh, p.x, p.y, p.z, p.time
FROM celestial_bodies b
LEFT JOIN LATERAL (
SELECT * FROM positions
WHERE body_id = b.id
ORDER BY time DESC
LIMIT 1
) p ON true
WHERE b.id = '-31';
查询某天体在时间范围内的轨迹
SELECT time, x, y, z
FROM positions
WHERE body_id = '-31'
AND time BETWEEN '2025-01-01' AND '2025-12-31'
ORDER BY time;
查询所有带纹理的行星
SELECT b.name, r.file_path
FROM celestial_bodies b
INNER JOIN resources r ON b.id = r.body_id
WHERE b.type = 'planet' AND r.resource_type = 'texture';
查询所有活跃的探测器
SELECT id, name, name_zh, metadata->>'status' as status
FROM celestial_bodies
WHERE type = 'probe'
AND metadata->>'status' = 'active';
维护建议
- 定期清理过期缓存:
DELETE FROM nasa_cache WHERE expires_at < NOW();
- 分析表性能:
ANALYZE celestial_bodies;
ANALYZE positions;
ANALYZE nasa_cache;
- 重建索引(如果性能下降):
REINDEX TABLE positions;
- 备份数据库:
pg_dump -U postgres cosmo_db > backup_$(date +%Y%m%d).sql
扩展建议
未来可能需要的表
- users - 用户表(如果需要用户系统)
- user_favorites - 用户收藏(收藏的天体)
- observation_logs - 观测日志(用户记录)
- simulation_configs - 模拟配置(用户自定义场景)
性能优化扩展
- TimescaleDB - 时间序列优化
CREATE EXTENSION IF NOT EXISTS timescaledb;
SELECT create_hypertable('positions', 'time');
- PostGIS - 空间数据扩展
CREATE EXTENSION IF NOT EXISTS postgis;
ALTER TABLE positions ADD COLUMN geom geometry(POINTZ, 4326);