cosmo/backend/DATABASE_SCHEMA_MISSING.md

4.0 KiB
Raw Blame History

缺失的表定义

DATABASE_SCHEMA.md 文档中缺少以下表的定义,但代码中已经实现:

1. celestial_events - 天体事件表

CREATE TABLE celestial_events (
    id SERIAL PRIMARY KEY,
    body_id VARCHAR(50) NOT NULL REFERENCES celestial_bodies(id) ON DELETE CASCADE,
    title VARCHAR(200) NOT NULL,
    event_type VARCHAR(50) NOT NULL,
    event_time TIMESTAMP NOT NULL,
    description TEXT,
    details JSONB,
    source VARCHAR(50) DEFAULT 'nasa_sbdb',
    created_at TIMESTAMP DEFAULT NOW(),

    CONSTRAINT chk_event_type CHECK (event_type IN (
        'approach', 'opposition', 'conjunction', 'eclipse',
        'perihelion', 'aphelion', 'closest_approach'
    ))
);

-- 索引
CREATE INDEX idx_celestial_events_body_id ON celestial_events(body_id);
CREATE INDEX idx_celestial_events_event_time ON celestial_events(event_time);
CREATE INDEX idx_celestial_events_event_type ON celestial_events(event_type);

-- 注释
COMMENT ON TABLE celestial_events IS '天体事件表(接近、冲、合、食等天文事件)';
COMMENT ON COLUMN celestial_events.event_type IS '事件类型approach(接近), opposition(冲), conjunction(合), eclipse(食), perihelion(近日点), aphelion(远日点), closest_approach(最接近)';
COMMENT ON COLUMN celestial_events.details IS 'JSON格式事件详细信息';
COMMENT ON COLUMN celestial_events.source IS '数据来源nasa_sbdb, calculated, skyfield_calculation';

2. user_follows - 用户关注天体表

CREATE TABLE user_follows (
    user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
    body_id VARCHAR(50) NOT NULL REFERENCES celestial_bodies(id) ON DELETE CASCADE,
    created_at TIMESTAMP DEFAULT NOW(),

    PRIMARY KEY (user_id, body_id)
);

-- 索引
CREATE INDEX idx_user_follows_user_id ON user_follows(user_id);
CREATE INDEX idx_user_follows_body_id ON user_follows(body_id);

-- 注释
COMMENT ON TABLE user_follows IS '用户关注天体关联表';
COMMENT ON COLUMN user_follows.user_id IS '用户ID外键关联users表';
COMMENT ON COLUMN user_follows.body_id IS '天体ID外键关联celestial_bodies表';

3. positions 表的 source 约束需要更新

文档中:

CONSTRAINT chk_source CHECK (source IN (
    'nasa_horizons', 'calculated', 'user_defined', 'imported'
))

实际代码中应该是:

CONSTRAINT chk_source CHECK (source IN (
    'nasa_horizons', 'nasa_horizons_cron', 'calculated', 'user_defined', 'imported'
))

4. scheduled_jobs 表结构需要更新

文档中使用了 ENUM 类型,但实际代码使用 VARCHAR

CREATE TABLE 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
);

5. system_settings 表主键

文档中有 id 字段,但实际代码中 key 是主键:

CREATE TABLE system_settings (
    key VARCHAR(100) PRIMARY KEY,  -- 主键,不是 id
    value TEXT NOT NULL,
    value_type VARCHAR(20) NOT NULL DEFAULT 'string',
    category VARCHAR(50) NOT NULL DEFAULT 'general',
    label VARCHAR(200) NOT NULL,
    description TEXT,
    is_public BOOLEAN DEFAULT FALSE,
    created_at TIMESTAMP DEFAULT NOW(),
    updated_at TIMESTAMP DEFAULT NOW(),

    CONSTRAINT chk_value_type CHECK (value_type IN (
        'string', 'int', 'float', 'bool', 'json'
    ))
);

6. role_menus 表主键

文档中有 id 字段,但实际代码使用复合主键:

CREATE TABLE role_menus (
    role_id INTEGER NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
    menu_id INTEGER NOT NULL REFERENCES menus(id) ON DELETE CASCADE,

    PRIMARY KEY (role_id, menu_id)  -- 复合主键,没有 id 字段
);