Files
thrilltrack-explorer/supabase/migrations/20251002033636_549a9c8b-5621-4c5e-921a-b4d9f37d7e60.sql
gpt-engineer-app[bot] 8ec0d59e75 Refactor user lists
2025-10-02 03:38:55 +00:00

109 lines
3.2 KiB
PL/PgSQL

-- Phase 4: User Lists Refactor - Create relational list items table
-- Create user_top_list_items table with proper relational structure
CREATE TABLE IF NOT EXISTS public.user_top_list_items (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
list_id uuid NOT NULL REFERENCES public.user_top_lists(id) ON DELETE CASCADE,
entity_type text NOT NULL CHECK (entity_type IN ('park', 'ride', 'company')),
entity_id uuid NOT NULL,
position integer NOT NULL,
notes text,
created_at timestamp with time zone NOT NULL DEFAULT now(),
updated_at timestamp with time zone NOT NULL DEFAULT now(),
CONSTRAINT unique_list_position UNIQUE(list_id, position),
CONSTRAINT unique_list_entity UNIQUE(list_id, entity_type, entity_id)
);
-- Enable Row Level Security
ALTER TABLE public.user_top_list_items ENABLE ROW LEVEL SECURITY;
-- RLS Policy: Users can manage items in their own lists
CREATE POLICY "Users can manage their own list items"
ON public.user_top_list_items
FOR ALL
USING (
EXISTS (
SELECT 1 FROM public.user_top_lists
WHERE id = user_top_list_items.list_id
AND user_id = auth.uid()
)
);
-- RLS Policy: Public list items can be viewed by anyone
CREATE POLICY "Public list items can be viewed"
ON public.user_top_list_items
FOR SELECT
USING (
EXISTS (
SELECT 1 FROM public.user_top_lists
WHERE id = user_top_list_items.list_id
AND is_public = true
)
);
-- Create data migration function to move JSON data to relational structure
CREATE OR REPLACE FUNCTION public.migrate_user_list_items()
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
list_record RECORD;
item_record JSONB;
item_position INTEGER;
BEGIN
-- Iterate through all lists with items
FOR list_record IN
SELECT id, items
FROM public.user_top_lists
WHERE items IS NOT NULL AND jsonb_array_length(items) > 0
LOOP
item_position := 1;
-- Iterate through each item in the JSON array
FOR item_record IN
SELECT value FROM jsonb_array_elements(list_record.items)
LOOP
-- Insert into relational table, skip if already exists
INSERT INTO public.user_top_list_items (
list_id,
entity_type,
entity_id,
position,
notes
) VALUES (
list_record.id,
item_record->>'entity_type',
(item_record->>'entity_id')::uuid,
item_position,
item_record->>'notes'
)
ON CONFLICT (list_id, entity_type, entity_id) DO NOTHING;
item_position := item_position + 1;
END LOOP;
END LOOP;
RAISE NOTICE 'Migration completed successfully';
END;
$$;
-- Add performance indexes
CREATE INDEX IF NOT EXISTS idx_user_list_items_list_position
ON public.user_top_list_items (list_id, position);
CREATE INDEX IF NOT EXISTS idx_user_list_items_entity
ON public.user_top_list_items (entity_type, entity_id);
CREATE INDEX IF NOT EXISTS idx_user_list_items_list_type
ON public.user_top_list_items (list_id, entity_type);
-- Add trigger for updated_at
CREATE TRIGGER update_user_top_list_items_updated_at
BEFORE UPDATE ON public.user_top_list_items
FOR EACH ROW
EXECUTE FUNCTION public.update_updated_at_column();
-- Run migration to move existing data
SELECT public.migrate_user_list_items();