41 lines
1.9 KiB
PL/PgSQL
41 lines
1.9 KiB
PL/PgSQL
-- Phase 5 Database Schema Changes (Updated)
|
|
-- Run this script to add tables for Celestial Events and User Follows
|
|
-- Note: Channel messages are now stored in Redis, so no table is created for them.
|
|
|
|
BEGIN;
|
|
|
|
-- 1. Celestial Events Table
|
|
CREATE TABLE IF NOT EXISTS "public"."celestial_events" (
|
|
"id" SERIAL PRIMARY KEY,
|
|
"body_id" VARCHAR(50) NOT NULL REFERENCES "public"."celestial_bodies"("id") ON DELETE CASCADE,
|
|
"title" VARCHAR(200) NOT NULL,
|
|
"event_type" VARCHAR(50) NOT NULL, -- 'approach' (close approach), 'opposition' (冲日), etc.
|
|
"event_time" TIMESTAMP NOT NULL,
|
|
"description" TEXT,
|
|
"details" JSONB, -- Store distance (nominal_dist_au), v_rel, etc.
|
|
"source" VARCHAR(50) DEFAULT 'nasa_sbdb',
|
|
"created_at" TIMESTAMP DEFAULT NOW()
|
|
);
|
|
|
|
CREATE INDEX "idx_celestial_events_body_id" ON "public"."celestial_events" ("body_id");
|
|
CREATE INDEX "idx_celestial_events_time" ON "public"."celestial_events" ("event_time");
|
|
COMMENT ON TABLE "public"."celestial_events" IS '天体动态事件表 (如飞掠、冲日)';
|
|
|
|
-- 2. User Follows Table (Relationships)
|
|
CREATE TABLE IF NOT EXISTS "public"."user_follows" (
|
|
"user_id" INTEGER NOT NULL REFERENCES "public"."users"("id") ON DELETE CASCADE,
|
|
"body_id" VARCHAR(50) NOT NULL REFERENCES "public"."celestial_bodies"("id") ON DELETE CASCADE,
|
|
"created_at" TIMESTAMP DEFAULT NOW(),
|
|
PRIMARY KEY ("user_id", "body_id")
|
|
);
|
|
|
|
CREATE INDEX "idx_user_follows_user" ON "public"."user_follows" ("user_id");
|
|
COMMENT ON TABLE "public"."user_follows" IS '用户关注天体关联表';
|
|
|
|
-- 3. Ensure 'icon' is in resources check constraint (Idempotent check)
|
|
-- Dropping and recreating constraint is the safest way to ensure 'icon' is present if it wasn't
|
|
ALTER TABLE "public"."resources" DROP CONSTRAINT IF EXISTS "chk_resource_type";
|
|
ALTER TABLE "public"."resources" ADD CONSTRAINT "chk_resource_type"
|
|
CHECK (resource_type IN ('texture', 'model', 'icon', 'thumbnail', 'data'));
|
|
|
|
COMMIT; |