mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-23 14:51:13 -05:00
Fix park submission locations
Implement Phase 1 of the JSONB violation fix by creating the `park_submission_locations` table. This includes migrating existing data from `park_submissions.temp_location_data` and updating relevant code to read and write to the new relational table. The `temp_location_data` column will be dropped after data migration.
This commit is contained in:
@@ -0,0 +1,122 @@
|
||||
-- Phase 1: Fix park_submissions.temp_location_data JSONB violation
|
||||
-- Create relational table for temporary location data
|
||||
|
||||
-- Create park_submission_locations table
|
||||
CREATE TABLE IF NOT EXISTS public.park_submission_locations (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
park_submission_id UUID NOT NULL REFERENCES public.park_submissions(id) ON DELETE CASCADE,
|
||||
name TEXT NOT NULL,
|
||||
street_address TEXT,
|
||||
city TEXT,
|
||||
state_province TEXT,
|
||||
country TEXT NOT NULL,
|
||||
postal_code TEXT,
|
||||
latitude NUMERIC(10, 7),
|
||||
longitude NUMERIC(10, 7),
|
||||
timezone TEXT,
|
||||
display_name TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
-- Create indexes for performance
|
||||
CREATE INDEX IF NOT EXISTS idx_park_submission_locations_submission
|
||||
ON public.park_submission_locations(park_submission_id);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_park_submission_locations_country
|
||||
ON public.park_submission_locations(country);
|
||||
|
||||
-- Enable RLS
|
||||
ALTER TABLE public.park_submission_locations ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- RLS Policies (mirror park_submissions policies)
|
||||
CREATE POLICY "Moderators can view all park submission locations"
|
||||
ON public.park_submission_locations
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (
|
||||
is_moderator(auth.uid())
|
||||
AND ((NOT has_mfa_enabled(auth.uid())) OR has_aal2())
|
||||
);
|
||||
|
||||
CREATE POLICY "Users can view their own park submission locations"
|
||||
ON public.park_submission_locations
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1 FROM content_submissions cs
|
||||
INNER JOIN park_submissions ps ON ps.submission_id = cs.id
|
||||
WHERE ps.id = park_submission_locations.park_submission_id
|
||||
AND cs.user_id = auth.uid()
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY "Users can insert park submission locations"
|
||||
ON public.park_submission_locations
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (
|
||||
EXISTS (
|
||||
SELECT 1 FROM content_submissions cs
|
||||
INNER JOIN park_submissions ps ON ps.submission_id = cs.id
|
||||
WHERE ps.id = park_submission_locations.park_submission_id
|
||||
AND cs.user_id = auth.uid()
|
||||
)
|
||||
AND NOT is_user_banned(auth.uid())
|
||||
);
|
||||
|
||||
CREATE POLICY "Moderators can update park submission locations"
|
||||
ON public.park_submission_locations
|
||||
FOR UPDATE
|
||||
TO authenticated
|
||||
USING (
|
||||
is_moderator(auth.uid())
|
||||
AND ((NOT has_mfa_enabled(auth.uid())) OR has_aal2())
|
||||
);
|
||||
|
||||
CREATE POLICY "Moderators can delete park submission locations"
|
||||
ON public.park_submission_locations
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (
|
||||
is_moderator(auth.uid())
|
||||
AND ((NOT has_mfa_enabled(auth.uid())) OR has_aal2())
|
||||
);
|
||||
|
||||
-- Migrate existing temp_location_data to new table
|
||||
INSERT INTO public.park_submission_locations (
|
||||
park_submission_id,
|
||||
name,
|
||||
street_address,
|
||||
city,
|
||||
state_province,
|
||||
country,
|
||||
postal_code,
|
||||
latitude,
|
||||
longitude,
|
||||
timezone,
|
||||
display_name
|
||||
)
|
||||
SELECT
|
||||
id,
|
||||
temp_location_data->>'name',
|
||||
temp_location_data->>'street_address',
|
||||
temp_location_data->>'city',
|
||||
temp_location_data->>'state_province',
|
||||
temp_location_data->>'country',
|
||||
temp_location_data->>'postal_code',
|
||||
(temp_location_data->>'latitude')::numeric,
|
||||
(temp_location_data->>'longitude')::numeric,
|
||||
temp_location_data->>'timezone',
|
||||
temp_location_data->>'display_name'
|
||||
FROM public.park_submissions
|
||||
WHERE temp_location_data IS NOT NULL
|
||||
AND temp_location_data->>'name' IS NOT NULL;
|
||||
|
||||
-- Drop the JSONB column
|
||||
ALTER TABLE public.park_submissions DROP COLUMN IF EXISTS temp_location_data;
|
||||
|
||||
-- Add comment
|
||||
COMMENT ON TABLE public.park_submission_locations IS
|
||||
'Relational storage for park submission location data. Replaces temp_location_data JSONB column for proper queryability and data integrity.';
|
||||
Reference in New Issue
Block a user