49 lines
1.5 KiB
SQL
49 lines
1.5 KiB
SQL
-- Add unique constraint to celestial_events table to prevent duplicate events
|
|
-- This ensures that the same event (same body, type, and time) cannot be inserted twice
|
|
|
|
-- Step 1: Remove duplicate events (keep the earliest created_at)
|
|
WITH duplicates AS (
|
|
SELECT
|
|
id,
|
|
ROW_NUMBER() OVER (
|
|
PARTITION BY body_id, event_type, DATE_TRUNC('minute', event_time)
|
|
ORDER BY created_at ASC
|
|
) AS rn
|
|
FROM celestial_events
|
|
)
|
|
DELETE FROM celestial_events
|
|
WHERE id IN (
|
|
SELECT id FROM duplicates WHERE rn > 1
|
|
);
|
|
|
|
-- Step 2: Add unique constraint
|
|
-- Note: We truncate to minute precision for event_time to handle slight variations
|
|
-- Create a unique index instead of constraint to allow custom handling
|
|
CREATE UNIQUE INDEX IF NOT EXISTS idx_celestial_events_unique
|
|
ON celestial_events (
|
|
body_id,
|
|
event_type,
|
|
DATE_TRUNC('minute', event_time)
|
|
);
|
|
|
|
-- Note: For the exact timestamp constraint, use this instead:
|
|
-- CREATE UNIQUE INDEX IF NOT EXISTS idx_celestial_events_unique_exact
|
|
-- ON celestial_events (body_id, event_type, event_time);
|
|
|
|
-- Verify the constraint was added
|
|
SELECT
|
|
indexname,
|
|
indexdef
|
|
FROM pg_indexes
|
|
WHERE tablename = 'celestial_events' AND indexname = 'idx_celestial_events_unique';
|
|
|
|
-- Check for remaining duplicates
|
|
SELECT
|
|
body_id,
|
|
event_type,
|
|
DATE_TRUNC('minute', event_time) as event_time_minute,
|
|
COUNT(*) as count
|
|
FROM celestial_events
|
|
GROUP BY body_id, event_type, DATE_TRUNC('minute', event_time)
|
|
HAVING COUNT(*) > 1;
|