-- Phase 4: Create edit history tracking table CREATE TABLE IF NOT EXISTS public.item_edit_history ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), item_id UUID NOT NULL REFERENCES public.submission_items(id) ON DELETE CASCADE, editor_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, changes JSONB NOT NULL, edited_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Add index for efficient querying CREATE INDEX IF NOT EXISTS idx_item_edit_history_item_id ON public.item_edit_history(item_id); CREATE INDEX IF NOT EXISTS idx_item_edit_history_edited_at ON public.item_edit_history(edited_at DESC); -- Enable RLS ALTER TABLE public.item_edit_history ENABLE ROW LEVEL SECURITY; -- Allow moderators and admins to view edit history CREATE POLICY "Moderators can view edit history" ON public.item_edit_history FOR SELECT TO authenticated USING ( public.has_role(auth.uid(), 'moderator') OR public.has_role(auth.uid(), 'admin') OR public.has_role(auth.uid(), 'superuser') ); -- Allow system to insert edit history (via service role) CREATE POLICY "System can insert edit history" ON public.item_edit_history FOR INSERT TO authenticated WITH CHECK ( public.has_role(auth.uid(), 'moderator') OR public.has_role(auth.uid(), 'admin') OR public.has_role(auth.uid(), 'superuser') ); -- Create view to get edit history with user info CREATE OR REPLACE VIEW public.item_edit_history_view AS SELECT ieh.id, ieh.item_id, ieh.editor_id, ieh.changes, ieh.edited_at, p.username as editor_username, p.display_name as editor_display_name, p.avatar_url as editor_avatar_url FROM public.item_edit_history ieh LEFT JOIN public.profiles p ON p.user_id = ieh.editor_id ORDER BY ieh.edited_at DESC; -- Grant access to the view GRANT SELECT ON public.item_edit_history_view TO authenticated;