mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-22 14:11:12 -05:00
Refactor: Complete photo system migration
This commit is contained in:
@@ -537,6 +537,100 @@ export type Database = {
|
|||||||
},
|
},
|
||||||
]
|
]
|
||||||
}
|
}
|
||||||
|
photo_submission_items: {
|
||||||
|
Row: {
|
||||||
|
caption: string | null
|
||||||
|
cloudflare_image_id: string
|
||||||
|
cloudflare_image_url: string
|
||||||
|
created_at: string
|
||||||
|
date_taken: string | null
|
||||||
|
file_size: number | null
|
||||||
|
filename: string | null
|
||||||
|
id: string
|
||||||
|
mime_type: string | null
|
||||||
|
order_index: number
|
||||||
|
photo_submission_id: string
|
||||||
|
title: string | null
|
||||||
|
}
|
||||||
|
Insert: {
|
||||||
|
caption?: string | null
|
||||||
|
cloudflare_image_id: string
|
||||||
|
cloudflare_image_url: string
|
||||||
|
created_at?: string
|
||||||
|
date_taken?: string | null
|
||||||
|
file_size?: number | null
|
||||||
|
filename?: string | null
|
||||||
|
id?: string
|
||||||
|
mime_type?: string | null
|
||||||
|
order_index?: number
|
||||||
|
photo_submission_id: string
|
||||||
|
title?: string | null
|
||||||
|
}
|
||||||
|
Update: {
|
||||||
|
caption?: string | null
|
||||||
|
cloudflare_image_id?: string
|
||||||
|
cloudflare_image_url?: string
|
||||||
|
created_at?: string
|
||||||
|
date_taken?: string | null
|
||||||
|
file_size?: number | null
|
||||||
|
filename?: string | null
|
||||||
|
id?: string
|
||||||
|
mime_type?: string | null
|
||||||
|
order_index?: number
|
||||||
|
photo_submission_id?: string
|
||||||
|
title?: string | null
|
||||||
|
}
|
||||||
|
Relationships: [
|
||||||
|
{
|
||||||
|
foreignKeyName: "photo_submission_items_photo_submission_id_fkey"
|
||||||
|
columns: ["photo_submission_id"]
|
||||||
|
isOneToOne: false
|
||||||
|
referencedRelation: "photo_submissions"
|
||||||
|
referencedColumns: ["id"]
|
||||||
|
},
|
||||||
|
]
|
||||||
|
}
|
||||||
|
photo_submissions: {
|
||||||
|
Row: {
|
||||||
|
created_at: string
|
||||||
|
entity_id: string
|
||||||
|
entity_type: string
|
||||||
|
id: string
|
||||||
|
parent_id: string | null
|
||||||
|
submission_id: string
|
||||||
|
title: string | null
|
||||||
|
updated_at: string
|
||||||
|
}
|
||||||
|
Insert: {
|
||||||
|
created_at?: string
|
||||||
|
entity_id: string
|
||||||
|
entity_type: string
|
||||||
|
id?: string
|
||||||
|
parent_id?: string | null
|
||||||
|
submission_id: string
|
||||||
|
title?: string | null
|
||||||
|
updated_at?: string
|
||||||
|
}
|
||||||
|
Update: {
|
||||||
|
created_at?: string
|
||||||
|
entity_id?: string
|
||||||
|
entity_type?: string
|
||||||
|
id?: string
|
||||||
|
parent_id?: string | null
|
||||||
|
submission_id?: string
|
||||||
|
title?: string | null
|
||||||
|
updated_at?: string
|
||||||
|
}
|
||||||
|
Relationships: [
|
||||||
|
{
|
||||||
|
foreignKeyName: "photo_submissions_submission_id_fkey"
|
||||||
|
columns: ["submission_id"]
|
||||||
|
isOneToOne: false
|
||||||
|
referencedRelation: "content_submissions"
|
||||||
|
referencedColumns: ["id"]
|
||||||
|
},
|
||||||
|
]
|
||||||
|
}
|
||||||
photos: {
|
photos: {
|
||||||
Row: {
|
Row: {
|
||||||
approved_at: string | null
|
approved_at: string | null
|
||||||
@@ -738,6 +832,44 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
Relationships: []
|
Relationships: []
|
||||||
}
|
}
|
||||||
|
review_photos: {
|
||||||
|
Row: {
|
||||||
|
caption: string | null
|
||||||
|
cloudflare_image_id: string
|
||||||
|
cloudflare_image_url: string
|
||||||
|
created_at: string
|
||||||
|
id: string
|
||||||
|
order_index: number
|
||||||
|
review_id: string
|
||||||
|
}
|
||||||
|
Insert: {
|
||||||
|
caption?: string | null
|
||||||
|
cloudflare_image_id: string
|
||||||
|
cloudflare_image_url: string
|
||||||
|
created_at?: string
|
||||||
|
id?: string
|
||||||
|
order_index?: number
|
||||||
|
review_id: string
|
||||||
|
}
|
||||||
|
Update: {
|
||||||
|
caption?: string | null
|
||||||
|
cloudflare_image_id?: string
|
||||||
|
cloudflare_image_url?: string
|
||||||
|
created_at?: string
|
||||||
|
id?: string
|
||||||
|
order_index?: number
|
||||||
|
review_id?: string
|
||||||
|
}
|
||||||
|
Relationships: [
|
||||||
|
{
|
||||||
|
foreignKeyName: "review_photos_review_id_fkey"
|
||||||
|
columns: ["review_id"]
|
||||||
|
isOneToOne: false
|
||||||
|
referencedRelation: "reviews"
|
||||||
|
referencedColumns: ["id"]
|
||||||
|
},
|
||||||
|
]
|
||||||
|
}
|
||||||
reviews: {
|
reviews: {
|
||||||
Row: {
|
Row: {
|
||||||
content: string | null
|
content: string | null
|
||||||
@@ -1346,6 +1478,10 @@ export type Database = {
|
|||||||
Args: { _user_id: string }
|
Args: { _user_id: string }
|
||||||
Returns: boolean
|
Returns: boolean
|
||||||
}
|
}
|
||||||
|
extract_cf_image_id: {
|
||||||
|
Args: { url: string }
|
||||||
|
Returns: string
|
||||||
|
}
|
||||||
get_filtered_profile: {
|
get_filtered_profile: {
|
||||||
Args: { _profile_user_id: string; _viewer_id?: string }
|
Args: { _profile_user_id: string; _viewer_id?: string }
|
||||||
Returns: Json
|
Returns: Json
|
||||||
|
|||||||
@@ -0,0 +1,317 @@
|
|||||||
|
-- Phase 1: Photo System Refactor (Fixed Migration)
|
||||||
|
-- Create proper relational tables for photo submissions and review photos
|
||||||
|
|
||||||
|
-- 1. Create photo_submissions table for photo submission metadata
|
||||||
|
CREATE TABLE IF NOT EXISTS public.photo_submissions (
|
||||||
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||||
|
submission_id UUID NOT NULL REFERENCES public.content_submissions(id) ON DELETE CASCADE,
|
||||||
|
entity_type TEXT NOT NULL CHECK (entity_type IN ('park', 'ride', 'manufacturer', 'operator', 'designer', 'property_owner')),
|
||||||
|
entity_id UUID NOT NULL,
|
||||||
|
parent_id UUID, -- e.g., parkId for rides
|
||||||
|
title TEXT,
|
||||||
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||||
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
|
||||||
|
);
|
||||||
|
|
||||||
|
-- 2. Create photo_submission_items table for individual photos in a submission
|
||||||
|
CREATE TABLE IF NOT EXISTS public.photo_submission_items (
|
||||||
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||||
|
photo_submission_id UUID NOT NULL REFERENCES public.photo_submissions(id) ON DELETE CASCADE,
|
||||||
|
cloudflare_image_id TEXT NOT NULL,
|
||||||
|
cloudflare_image_url TEXT NOT NULL,
|
||||||
|
caption TEXT,
|
||||||
|
title TEXT,
|
||||||
|
filename TEXT,
|
||||||
|
order_index INTEGER NOT NULL DEFAULT 0,
|
||||||
|
file_size BIGINT,
|
||||||
|
mime_type TEXT,
|
||||||
|
date_taken DATE,
|
||||||
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
|
||||||
|
);
|
||||||
|
|
||||||
|
-- 3. Create review_photos table to replace reviews.photos JSONB
|
||||||
|
CREATE TABLE IF NOT EXISTS public.review_photos (
|
||||||
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||||
|
review_id UUID NOT NULL REFERENCES public.reviews(id) ON DELETE CASCADE,
|
||||||
|
cloudflare_image_id TEXT NOT NULL,
|
||||||
|
cloudflare_image_url TEXT NOT NULL,
|
||||||
|
caption TEXT,
|
||||||
|
order_index INTEGER NOT NULL DEFAULT 0,
|
||||||
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Create indexes for performance
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_photo_submissions_submission_id ON public.photo_submissions(submission_id);
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_photo_submissions_entity ON public.photo_submissions(entity_type, entity_id);
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_photo_submission_items_photo_submission_id ON public.photo_submission_items(photo_submission_id);
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_photo_submission_items_order ON public.photo_submission_items(photo_submission_id, order_index);
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_review_photos_review_id ON public.review_photos(review_id);
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_review_photos_order ON public.review_photos(review_id, order_index);
|
||||||
|
|
||||||
|
-- Enable RLS
|
||||||
|
ALTER TABLE public.photo_submissions ENABLE ROW LEVEL SECURITY;
|
||||||
|
ALTER TABLE public.photo_submission_items ENABLE ROW LEVEL SECURITY;
|
||||||
|
ALTER TABLE public.review_photos ENABLE ROW LEVEL SECURITY;
|
||||||
|
|
||||||
|
-- RLS Policies for photo_submissions
|
||||||
|
CREATE POLICY "Moderators can view all photo submissions"
|
||||||
|
ON public.photo_submissions FOR SELECT
|
||||||
|
USING (is_moderator(auth.uid()));
|
||||||
|
|
||||||
|
CREATE POLICY "Users can view their own photo submissions"
|
||||||
|
ON public.photo_submissions FOR SELECT
|
||||||
|
USING (EXISTS (
|
||||||
|
SELECT 1 FROM public.content_submissions
|
||||||
|
WHERE content_submissions.id = photo_submissions.submission_id
|
||||||
|
AND content_submissions.user_id = auth.uid()
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Users can create photo submissions"
|
||||||
|
ON public.photo_submissions FOR INSERT
|
||||||
|
WITH CHECK (EXISTS (
|
||||||
|
SELECT 1 FROM public.content_submissions
|
||||||
|
WHERE content_submissions.id = photo_submissions.submission_id
|
||||||
|
AND content_submissions.user_id = auth.uid()
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Moderators can update photo submissions"
|
||||||
|
ON public.photo_submissions FOR UPDATE
|
||||||
|
USING (is_moderator(auth.uid()));
|
||||||
|
|
||||||
|
CREATE POLICY "Moderators can delete photo submissions"
|
||||||
|
ON public.photo_submissions FOR DELETE
|
||||||
|
USING (is_moderator(auth.uid()));
|
||||||
|
|
||||||
|
-- RLS Policies for photo_submission_items
|
||||||
|
CREATE POLICY "Moderators can view all photo submission items"
|
||||||
|
ON public.photo_submission_items FOR SELECT
|
||||||
|
USING (is_moderator(auth.uid()));
|
||||||
|
|
||||||
|
CREATE POLICY "Users can view their own photo submission items"
|
||||||
|
ON public.photo_submission_items FOR SELECT
|
||||||
|
USING (EXISTS (
|
||||||
|
SELECT 1 FROM public.photo_submissions ps
|
||||||
|
JOIN public.content_submissions cs ON cs.id = ps.submission_id
|
||||||
|
WHERE ps.id = photo_submission_items.photo_submission_id
|
||||||
|
AND cs.user_id = auth.uid()
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Users can create photo submission items"
|
||||||
|
ON public.photo_submission_items FOR INSERT
|
||||||
|
WITH CHECK (EXISTS (
|
||||||
|
SELECT 1 FROM public.photo_submissions ps
|
||||||
|
JOIN public.content_submissions cs ON cs.id = ps.submission_id
|
||||||
|
WHERE ps.id = photo_submission_items.photo_submission_id
|
||||||
|
AND cs.user_id = auth.uid()
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Moderators can update photo submission items"
|
||||||
|
ON public.photo_submission_items FOR UPDATE
|
||||||
|
USING (is_moderator(auth.uid()));
|
||||||
|
|
||||||
|
CREATE POLICY "Moderators can delete photo submission items"
|
||||||
|
ON public.photo_submission_items FOR DELETE
|
||||||
|
USING (is_moderator(auth.uid()));
|
||||||
|
|
||||||
|
-- RLS Policies for review_photos
|
||||||
|
CREATE POLICY "Public can view approved review photos"
|
||||||
|
ON public.review_photos FOR SELECT
|
||||||
|
USING (EXISTS (
|
||||||
|
SELECT 1 FROM public.reviews
|
||||||
|
WHERE reviews.id = review_photos.review_id
|
||||||
|
AND reviews.moderation_status = 'approved'
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Users can view their own review photos"
|
||||||
|
ON public.review_photos FOR SELECT
|
||||||
|
USING (EXISTS (
|
||||||
|
SELECT 1 FROM public.reviews
|
||||||
|
WHERE reviews.id = review_photos.review_id
|
||||||
|
AND reviews.user_id = auth.uid()
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Users can create review photos"
|
||||||
|
ON public.review_photos FOR INSERT
|
||||||
|
WITH CHECK (EXISTS (
|
||||||
|
SELECT 1 FROM public.reviews
|
||||||
|
WHERE reviews.id = review_photos.review_id
|
||||||
|
AND reviews.user_id = auth.uid()
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Users can update their own review photos"
|
||||||
|
ON public.review_photos FOR UPDATE
|
||||||
|
USING (EXISTS (
|
||||||
|
SELECT 1 FROM public.reviews
|
||||||
|
WHERE reviews.id = review_photos.review_id
|
||||||
|
AND reviews.user_id = auth.uid()
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Users can delete their own review photos"
|
||||||
|
ON public.review_photos FOR DELETE
|
||||||
|
USING (EXISTS (
|
||||||
|
SELECT 1 FROM public.reviews
|
||||||
|
WHERE reviews.id = review_photos.review_id
|
||||||
|
AND reviews.user_id = auth.uid()
|
||||||
|
));
|
||||||
|
|
||||||
|
CREATE POLICY "Moderators can manage all review photos"
|
||||||
|
ON public.review_photos FOR ALL
|
||||||
|
USING (is_moderator(auth.uid()));
|
||||||
|
|
||||||
|
-- Create triggers for updated_at
|
||||||
|
CREATE TRIGGER update_photo_submissions_updated_at
|
||||||
|
BEFORE UPDATE ON public.photo_submissions
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE FUNCTION public.update_updated_at_column();
|
||||||
|
|
||||||
|
-- Helper function to extract Cloudflare image ID from URL
|
||||||
|
CREATE OR REPLACE FUNCTION extract_cf_image_id(url TEXT)
|
||||||
|
RETURNS TEXT
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
IMMUTABLE
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
-- Extract ID from imagedelivery.net URL pattern
|
||||||
|
-- Pattern: https://imagedelivery.net/{account-hash}/{image-id}/{variant}
|
||||||
|
RETURN (regexp_match(url, '/([a-f0-9-]+)/[a-z0-9]+$'))[1];
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Migrate existing photo submission data from content_submissions.content JSONB
|
||||||
|
DO $$
|
||||||
|
DECLARE
|
||||||
|
submission_record RECORD;
|
||||||
|
photo_submission_id UUID;
|
||||||
|
photo_record JSONB;
|
||||||
|
photo_index INTEGER;
|
||||||
|
cf_id TEXT;
|
||||||
|
cf_url TEXT;
|
||||||
|
BEGIN
|
||||||
|
-- Loop through all photo submissions
|
||||||
|
FOR submission_record IN
|
||||||
|
SELECT id, content, user_id, created_at
|
||||||
|
FROM public.content_submissions
|
||||||
|
WHERE submission_type = 'photo'
|
||||||
|
AND content IS NOT NULL
|
||||||
|
LOOP
|
||||||
|
-- Create photo_submission record
|
||||||
|
INSERT INTO public.photo_submissions (
|
||||||
|
submission_id,
|
||||||
|
entity_type,
|
||||||
|
entity_id,
|
||||||
|
parent_id,
|
||||||
|
title,
|
||||||
|
created_at
|
||||||
|
)
|
||||||
|
VALUES (
|
||||||
|
submission_record.id,
|
||||||
|
COALESCE(submission_record.content->>'context', 'park'),
|
||||||
|
(submission_record.content->>'entity_id')::UUID,
|
||||||
|
NULLIF(submission_record.content->>'parent_id', '')::UUID,
|
||||||
|
submission_record.content->>'title',
|
||||||
|
submission_record.created_at
|
||||||
|
)
|
||||||
|
RETURNING id INTO photo_submission_id;
|
||||||
|
|
||||||
|
-- Insert individual photos
|
||||||
|
photo_index := 0;
|
||||||
|
FOR photo_record IN
|
||||||
|
SELECT * FROM jsonb_array_elements(COALESCE(submission_record.content->'photos', '[]'::jsonb))
|
||||||
|
LOOP
|
||||||
|
-- Get cloudflare ID - try direct field first, then extract from URL
|
||||||
|
cf_id := photo_record->>'cloudflare_id';
|
||||||
|
cf_url := photo_record->>'url';
|
||||||
|
|
||||||
|
-- Skip if we don't have a URL
|
||||||
|
IF cf_url IS NULL OR cf_url = '' THEN
|
||||||
|
CONTINUE;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Extract ID from URL if not directly available
|
||||||
|
IF cf_id IS NULL OR cf_id = '' THEN
|
||||||
|
cf_id := extract_cf_image_id(cf_url);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Only insert if we have a valid ID
|
||||||
|
IF cf_id IS NOT NULL AND cf_id != '' THEN
|
||||||
|
INSERT INTO public.photo_submission_items (
|
||||||
|
photo_submission_id,
|
||||||
|
cloudflare_image_id,
|
||||||
|
cloudflare_image_url,
|
||||||
|
caption,
|
||||||
|
title,
|
||||||
|
order_index
|
||||||
|
)
|
||||||
|
VALUES (
|
||||||
|
photo_submission_id,
|
||||||
|
cf_id,
|
||||||
|
cf_url,
|
||||||
|
photo_record->>'caption',
|
||||||
|
photo_record->>'title',
|
||||||
|
COALESCE((photo_record->>'order')::INTEGER, photo_index)
|
||||||
|
);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
photo_index := photo_index + 1;
|
||||||
|
END LOOP;
|
||||||
|
END LOOP;
|
||||||
|
END $$;
|
||||||
|
|
||||||
|
-- Migrate existing review photos from reviews.photos JSONB to review_photos table
|
||||||
|
DO $$
|
||||||
|
DECLARE
|
||||||
|
review_record RECORD;
|
||||||
|
photo_record JSONB;
|
||||||
|
photo_index INTEGER;
|
||||||
|
cf_id TEXT;
|
||||||
|
cf_url TEXT;
|
||||||
|
BEGIN
|
||||||
|
-- Loop through all reviews with photos
|
||||||
|
FOR review_record IN
|
||||||
|
SELECT id, photos
|
||||||
|
FROM public.reviews
|
||||||
|
WHERE photos IS NOT NULL
|
||||||
|
AND jsonb_array_length(photos) > 0
|
||||||
|
LOOP
|
||||||
|
photo_index := 0;
|
||||||
|
|
||||||
|
-- Insert each photo from the JSONB array
|
||||||
|
FOR photo_record IN
|
||||||
|
SELECT * FROM jsonb_array_elements(review_record.photos)
|
||||||
|
LOOP
|
||||||
|
-- Get cloudflare ID - try direct field first, then extract from URL
|
||||||
|
cf_id := photo_record->>'cloudflare_id';
|
||||||
|
cf_url := photo_record->>'url';
|
||||||
|
|
||||||
|
-- Skip if we don't have a URL
|
||||||
|
IF cf_url IS NULL OR cf_url = '' THEN
|
||||||
|
CONTINUE;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Extract ID from URL if not directly available
|
||||||
|
IF cf_id IS NULL OR cf_id = '' THEN
|
||||||
|
cf_id := extract_cf_image_id(cf_url);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Only insert if we have a valid ID
|
||||||
|
IF cf_id IS NOT NULL AND cf_id != '' THEN
|
||||||
|
INSERT INTO public.review_photos (
|
||||||
|
review_id,
|
||||||
|
cloudflare_image_id,
|
||||||
|
cloudflare_image_url,
|
||||||
|
caption,
|
||||||
|
order_index
|
||||||
|
)
|
||||||
|
VALUES (
|
||||||
|
review_record.id,
|
||||||
|
cf_id,
|
||||||
|
cf_url,
|
||||||
|
photo_record->>'caption',
|
||||||
|
photo_index
|
||||||
|
);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
photo_index := photo_index + 1;
|
||||||
|
END LOOP;
|
||||||
|
END LOOP;
|
||||||
|
END $$;
|
||||||
Reference in New Issue
Block a user