89 lines
3.4 KiB
SQL
89 lines
3.4 KiB
SQL
-- ============================================================
|
|
-- Create orbits table for storing precomputed orbital paths
|
|
-- ============================================================
|
|
-- Purpose: Store complete orbital trajectories for planets and dwarf planets
|
|
-- This eliminates the need to query NASA Horizons API for orbit visualization
|
|
--
|
|
-- Usage:
|
|
-- psql -U your_user -d cosmo < create_orbits_table.sql
|
|
-- OR execute in your SQL client/tool
|
|
--
|
|
-- Version: 1.0
|
|
-- Created: 2025-11-29
|
|
-- ============================================================
|
|
|
|
-- Create orbits table
|
|
CREATE TABLE IF NOT EXISTS orbits (
|
|
id SERIAL PRIMARY KEY,
|
|
body_id TEXT NOT NULL,
|
|
points JSONB NOT NULL, -- Array of orbital points: [{"x": 1.0, "y": 0.0, "z": 0.0}, ...]
|
|
num_points INTEGER NOT NULL, -- Number of points in the orbit
|
|
period_days FLOAT, -- Orbital period in days
|
|
color VARCHAR(20), -- Orbit line color (hex format: #RRGGBB)
|
|
created_at TIMESTAMP DEFAULT NOW(),
|
|
updated_at TIMESTAMP DEFAULT NOW(),
|
|
CONSTRAINT orbits_body_id_unique UNIQUE(body_id),
|
|
CONSTRAINT orbits_body_id_fkey FOREIGN KEY (body_id) REFERENCES celestial_bodies(id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Create index on body_id for fast lookups
|
|
CREATE INDEX IF NOT EXISTS idx_orbits_body_id ON orbits(body_id);
|
|
|
|
-- Create index on updated_at for tracking data freshness
|
|
CREATE INDEX IF NOT EXISTS idx_orbits_updated_at ON orbits(updated_at);
|
|
|
|
-- Add comments to table
|
|
COMMENT ON TABLE orbits IS 'Precomputed orbital paths for celestial bodies';
|
|
COMMENT ON COLUMN orbits.body_id IS 'Foreign key to celestial_bodies.id';
|
|
COMMENT ON COLUMN orbits.points IS 'Array of 3D points (x,y,z in AU) defining the orbital path';
|
|
COMMENT ON COLUMN orbits.num_points IS 'Total number of points in the orbit';
|
|
COMMENT ON COLUMN orbits.period_days IS 'Orbital period in Earth days';
|
|
COMMENT ON COLUMN orbits.color IS 'Hex color code for rendering the orbit line';
|
|
|
|
-- ============================================================
|
|
-- Sample data for testing (optional - can be removed)
|
|
-- ============================================================
|
|
-- Uncomment below to insert sample orbit for Earth
|
|
/*
|
|
INSERT INTO orbits (body_id, points, num_points, period_days, color)
|
|
VALUES (
|
|
'399', -- Earth
|
|
'[
|
|
{"x": 1.0, "y": 0.0, "z": 0.0},
|
|
{"x": 0.707, "y": 0.707, "z": 0.0},
|
|
{"x": 0.0, "y": 1.0, "z": 0.0},
|
|
{"x": -0.707, "y": 0.707, "z": 0.0},
|
|
{"x": -1.0, "y": 0.0, "z": 0.0},
|
|
{"x": -0.707, "y": -0.707, "z": 0.0},
|
|
{"x": 0.0, "y": -1.0, "z": 0.0},
|
|
{"x": 0.707, "y": -0.707, "z": 0.0}
|
|
]'::jsonb,
|
|
8,
|
|
365.25,
|
|
'#4A90E2'
|
|
)
|
|
ON CONFLICT (body_id) DO UPDATE
|
|
SET
|
|
points = EXCLUDED.points,
|
|
num_points = EXCLUDED.num_points,
|
|
period_days = EXCLUDED.period_days,
|
|
color = EXCLUDED.color,
|
|
updated_at = NOW();
|
|
*/
|
|
|
|
-- ============================================================
|
|
-- Verification queries (execute separately if needed)
|
|
-- ============================================================
|
|
-- Check if table was created successfully
|
|
-- SELECT schemaname, tablename, tableowner FROM pg_tables WHERE tablename = 'orbits';
|
|
|
|
-- Check indexes
|
|
-- SELECT indexname, indexdef FROM pg_indexes WHERE tablename = 'orbits';
|
|
|
|
-- Show table structure
|
|
-- SELECT column_name, data_type, is_nullable, column_default
|
|
-- FROM information_schema.columns
|
|
-- WHERE table_name = 'orbits'
|
|
-- ORDER BY ordinal_position;
|
|
|