From 223e743330c3907009e65cb609674520a1a5ba61 Mon Sep 17 00:00:00 2001 From: "gpt-engineer-app[bot]" <159125892+gpt-engineer-app[bot]@users.noreply.github.com> Date: Mon, 3 Nov 2025 20:42:30 +0000 Subject: [PATCH] Fix RLS policy for JSONB migration --- src/integrations/supabase/types.ts | 475 ++++++++++++++++++ src/lib/auditHelpers.ts | 193 +++++++ ...3_e8ad3633-7e26-46ec-8dd2-421787715778.sql | 345 +++++++++++++ 3 files changed, 1013 insertions(+) create mode 100644 src/lib/auditHelpers.ts create mode 100644 supabase/migrations/20251103204113_e8ad3633-7e26-46ec-8dd2-421787715778.sql diff --git a/src/integrations/supabase/types.ts b/src/integrations/supabase/types.ts index 7eb2222e..699ba247 100644 --- a/src/integrations/supabase/types.ts +++ b/src/integrations/supabase/types.ts @@ -59,6 +59,38 @@ export type Database = { } Relationships: [] } + admin_audit_details: { + Row: { + audit_log_id: string + created_at: string | null + detail_key: string + detail_value: string + id: string + } + Insert: { + audit_log_id: string + created_at?: string | null + detail_key: string + detail_value: string + id?: string + } + Update: { + audit_log_id?: string + created_at?: string | null + detail_key?: string + detail_value?: string + id?: string + } + Relationships: [ + { + foreignKeyName: "admin_audit_details_audit_log_id_fkey" + columns: ["audit_log_id"] + isOneToOne: false + referencedRelation: "admin_audit_log" + referencedColumns: ["id"] + }, + ] + } admin_audit_log: { Row: { action: string @@ -464,6 +496,44 @@ export type Database = { }, ] } + conflict_detail_fields: { + Row: { + conflict_resolution_id: string + conflicting_value_1: string | null + conflicting_value_2: string | null + created_at: string | null + field_name: string + id: string + resolved_value: string | null + } + Insert: { + conflict_resolution_id: string + conflicting_value_1?: string | null + conflicting_value_2?: string | null + created_at?: string | null + field_name: string + id?: string + resolved_value?: string | null + } + Update: { + conflict_resolution_id?: string + conflicting_value_1?: string | null + conflicting_value_2?: string | null + created_at?: string | null + field_name?: string + id?: string + resolved_value?: string | null + } + Relationships: [ + { + foreignKeyName: "conflict_detail_fields_conflict_resolution_id_fkey" + columns: ["conflict_resolution_id"] + isOneToOne: false + referencedRelation: "conflict_resolutions" + referencedColumns: ["id"] + }, + ] + } conflict_resolutions: { Row: { conflict_details: Json | null @@ -511,49 +581,64 @@ export type Database = { } contact_email_threads: { Row: { + attachment_count: number | null body_html: string | null body_text: string created_at: string direction: string + email_provider: string | null from_email: string id: string in_reply_to: string | null + is_auto_reply: boolean | null message_id: string metadata: Json | null reference_chain: string[] | null sent_by: string | null + smtp_message_id: string | null + spam_score: number | null subject: string submission_id: string to_email: string } Insert: { + attachment_count?: number | null body_html?: string | null body_text: string created_at?: string direction: string + email_provider?: string | null from_email: string id?: string in_reply_to?: string | null + is_auto_reply?: boolean | null message_id: string metadata?: Json | null reference_chain?: string[] | null sent_by?: string | null + smtp_message_id?: string | null + spam_score?: number | null subject: string submission_id: string to_email: string } Update: { + attachment_count?: number | null body_html?: string | null body_text?: string created_at?: string direction?: string + email_provider?: string | null from_email?: string id?: string in_reply_to?: string | null + is_auto_reply?: boolean | null message_id?: string metadata?: Json | null reference_chain?: string[] | null sent_by?: string | null + smtp_message_id?: string | null + spam_score?: number | null subject?: string submission_id?: string to_email?: string @@ -1049,49 +1134,97 @@ export type Database = { } historical_parks: { Row: { + banner_image_id: string | null + banner_image_url: string | null + card_image_id: string | null + card_image_url: string | null + closing_date: string | null + closing_date_precision: string | null closure_reason: string | null created_at: string + description: string | null + email: string | null final_state_data: Json id: string location_id: string | null name: string + opening_date: string | null + opening_date_precision: string | null operated_from: string | null operated_from_precision: string | null operated_until: string | null operated_until_precision: string | null + operator_id: string | null original_park_id: string | null + park_type: string | null + phone: string | null + property_owner_id: string | null slug: string + status: string | null successor_park_id: string | null + website_url: string | null } Insert: { + banner_image_id?: string | null + banner_image_url?: string | null + card_image_id?: string | null + card_image_url?: string | null + closing_date?: string | null + closing_date_precision?: string | null closure_reason?: string | null created_at?: string + description?: string | null + email?: string | null final_state_data: Json id?: string location_id?: string | null name: string + opening_date?: string | null + opening_date_precision?: string | null operated_from?: string | null operated_from_precision?: string | null operated_until?: string | null operated_until_precision?: string | null + operator_id?: string | null original_park_id?: string | null + park_type?: string | null + phone?: string | null + property_owner_id?: string | null slug: string + status?: string | null successor_park_id?: string | null + website_url?: string | null } Update: { + banner_image_id?: string | null + banner_image_url?: string | null + card_image_id?: string | null + card_image_url?: string | null + closing_date?: string | null + closing_date_precision?: string | null closure_reason?: string | null created_at?: string + description?: string | null + email?: string | null final_state_data?: Json id?: string location_id?: string | null name?: string + opening_date?: string | null + opening_date_precision?: string | null operated_from?: string | null operated_from_precision?: string | null operated_until?: string | null operated_until_precision?: string | null + operator_id?: string | null original_park_id?: string | null + park_type?: string | null + phone?: string | null + property_owner_id?: string | null slug?: string + status?: string | null successor_park_id?: string | null + website_url?: string | null } Relationships: [ { @@ -1101,6 +1234,13 @@ export type Database = { referencedRelation: "locations" referencedColumns: ["id"] }, + { + foreignKeyName: "historical_parks_operator_id_fkey" + columns: ["operator_id"] + isOneToOne: false + referencedRelation: "companies" + referencedColumns: ["id"] + }, { foreignKeyName: "historical_parks_original_park_id_fkey" columns: ["original_park_id"] @@ -1108,6 +1248,13 @@ export type Database = { referencedRelation: "parks" referencedColumns: ["id"] }, + { + foreignKeyName: "historical_parks_property_owner_id_fkey" + columns: ["property_owner_id"] + isOneToOne: false + referencedRelation: "companies" + referencedColumns: ["id"] + }, { foreignKeyName: "historical_parks_successor_park_id_fkey" columns: ["successor_park_id"] @@ -1119,10 +1266,30 @@ export type Database = { } historical_rides: { Row: { + banner_image_id: string | null + banner_image_url: string | null + card_image_id: string | null + card_image_url: string | null + category: string | null + closing_date: string | null + closing_date_precision: string | null + coaster_type: string | null created_at: string + description: string | null + designer_id: string | null + drop_height_meters: number | null final_state_data: Json id: string + intensity_level: string | null + inversions: number | null + length_meters: number | null + manufacturer_id: string | null + max_g_force: number | null + max_height_meters: number | null + max_speed_kmh: number | null name: string + opening_date: string | null + opening_date_precision: string | null operated_from: string | null operated_from_precision: string | null operated_until: string | null @@ -1131,14 +1298,37 @@ export type Database = { park_id: string | null relocated_to_park_id: string | null removal_reason: string | null + ride_model_id: string | null + seating_type: string | null slug: string + status: string | null successor_ride_id: string | null } Insert: { + banner_image_id?: string | null + banner_image_url?: string | null + card_image_id?: string | null + card_image_url?: string | null + category?: string | null + closing_date?: string | null + closing_date_precision?: string | null + coaster_type?: string | null created_at?: string + description?: string | null + designer_id?: string | null + drop_height_meters?: number | null final_state_data: Json id?: string + intensity_level?: string | null + inversions?: number | null + length_meters?: number | null + manufacturer_id?: string | null + max_g_force?: number | null + max_height_meters?: number | null + max_speed_kmh?: number | null name: string + opening_date?: string | null + opening_date_precision?: string | null operated_from?: string | null operated_from_precision?: string | null operated_until?: string | null @@ -1147,14 +1337,37 @@ export type Database = { park_id?: string | null relocated_to_park_id?: string | null removal_reason?: string | null + ride_model_id?: string | null + seating_type?: string | null slug: string + status?: string | null successor_ride_id?: string | null } Update: { + banner_image_id?: string | null + banner_image_url?: string | null + card_image_id?: string | null + card_image_url?: string | null + category?: string | null + closing_date?: string | null + closing_date_precision?: string | null + coaster_type?: string | null created_at?: string + description?: string | null + designer_id?: string | null + drop_height_meters?: number | null final_state_data?: Json id?: string + intensity_level?: string | null + inversions?: number | null + length_meters?: number | null + manufacturer_id?: string | null + max_g_force?: number | null + max_height_meters?: number | null + max_speed_kmh?: number | null name?: string + opening_date?: string | null + opening_date_precision?: string | null operated_from?: string | null operated_from_precision?: string | null operated_until?: string | null @@ -1163,10 +1376,27 @@ export type Database = { park_id?: string | null relocated_to_park_id?: string | null removal_reason?: string | null + ride_model_id?: string | null + seating_type?: string | null slug?: string + status?: string | null successor_ride_id?: string | null } Relationships: [ + { + foreignKeyName: "historical_rides_designer_id_fkey" + columns: ["designer_id"] + isOneToOne: false + referencedRelation: "companies" + referencedColumns: ["id"] + }, + { + foreignKeyName: "historical_rides_manufacturer_id_fkey" + columns: ["manufacturer_id"] + isOneToOne: false + referencedRelation: "companies" + referencedColumns: ["id"] + }, { foreignKeyName: "historical_rides_original_ride_id_fkey" columns: ["original_ride_id"] @@ -1188,6 +1418,13 @@ export type Database = { referencedRelation: "parks" referencedColumns: ["id"] }, + { + foreignKeyName: "historical_rides_ride_model_id_fkey" + columns: ["ride_model_id"] + isOneToOne: false + referencedRelation: "ride_models" + referencedColumns: ["id"] + }, { foreignKeyName: "historical_rides_successor_ride_id_fkey" columns: ["successor_ride_id"] @@ -1197,6 +1434,41 @@ export type Database = { }, ] } + item_change_fields: { + Row: { + created_at: string | null + edit_history_id: string + field_name: string + id: string + new_value: string | null + old_value: string | null + } + Insert: { + created_at?: string | null + edit_history_id: string + field_name: string + id?: string + new_value?: string | null + old_value?: string | null + } + Update: { + created_at?: string | null + edit_history_id?: string + field_name?: string + id?: string + new_value?: string | null + old_value?: string | null + } + Relationships: [ + { + foreignKeyName: "item_change_fields_edit_history_id_fkey" + columns: ["edit_history_id"] + isOneToOne: false + referencedRelation: "item_edit_history" + referencedColumns: ["id"] + }, + ] + } item_edit_history: { Row: { changes: Json @@ -1363,6 +1635,38 @@ export type Database = { }, ] } + moderation_audit_metadata: { + Row: { + audit_log_id: string + created_at: string | null + id: string + metadata_key: string + metadata_value: string + } + Insert: { + audit_log_id: string + created_at?: string | null + id?: string + metadata_key: string + metadata_value: string + } + Update: { + audit_log_id?: string + created_at?: string | null + id?: string + metadata_key?: string + metadata_value?: string + } + Relationships: [ + { + foreignKeyName: "moderation_audit_metadata_audit_log_id_fkey" + columns: ["audit_log_id"] + isOneToOne: false + referencedRelation: "moderation_audit_log" + referencedColumns: ["id"] + }, + ] + } notification_channels: { Row: { channel_type: string @@ -1423,6 +1727,38 @@ export type Database = { } Relationships: [] } + notification_event_data: { + Row: { + created_at: string | null + event_key: string + event_value: string + id: string + notification_log_id: string + } + Insert: { + created_at?: string | null + event_key: string + event_value: string + id?: string + notification_log_id: string + } + Update: { + created_at?: string | null + event_key?: string + event_value?: string + id?: string + notification_log_id?: string + } + Relationships: [ + { + foreignKeyName: "notification_event_data_notification_log_id_fkey" + columns: ["notification_log_id"] + isOneToOne: false + referencedRelation: "notification_logs" + referencedColumns: ["id"] + }, + ] + } notification_logs: { Row: { channel: string @@ -2188,6 +2524,41 @@ export type Database = { } Relationships: [] } + profile_change_fields: { + Row: { + audit_log_id: string + created_at: string | null + field_name: string + id: string + new_value: string | null + old_value: string | null + } + Insert: { + audit_log_id: string + created_at?: string | null + field_name: string + id?: string + new_value?: string | null + old_value?: string | null + } + Update: { + audit_log_id?: string + created_at?: string | null + field_name?: string + id?: string + new_value?: string | null + old_value?: string | null + } + Relationships: [ + { + foreignKeyName: "profile_change_fields_audit_log_id_fkey" + columns: ["audit_log_id"] + isOneToOne: false + referencedRelation: "profile_audit_log" + referencedColumns: ["id"] + }, + ] + } profiles: { Row: { auth0_sub: string | null @@ -2377,6 +2748,47 @@ export type Database = { } Relationships: [] } + request_breadcrumbs: { + Row: { + category: string + created_at: string | null + id: string + level: string | null + message: string + request_id: string + sequence_order: number + timestamp: string + } + Insert: { + category: string + created_at?: string | null + id?: string + level?: string | null + message: string + request_id: string + sequence_order: number + timestamp: string + } + Update: { + category?: string + created_at?: string | null + id?: string + level?: string | null + message?: string + request_id?: string + sequence_order?: number + timestamp?: string + } + Relationships: [ + { + foreignKeyName: "request_breadcrumbs_request_id_fkey" + columns: ["request_id"] + isOneToOne: false + referencedRelation: "request_metadata" + referencedColumns: ["request_id"] + }, + ] + } request_metadata: { Row: { breadcrumbs: Json | null @@ -2394,7 +2806,12 @@ export type Database = { method: string parent_request_id: string | null request_id: string + request_method: string | null + request_path: string | null + response_status: number | null + response_time_ms: number | null retry_count: number | null + session_id: string | null started_at: string status_code: number | null trace_id: string | null @@ -2417,7 +2834,12 @@ export type Database = { method: string parent_request_id?: string | null request_id: string + request_method?: string | null + request_path?: string | null + response_status?: number | null + response_time_ms?: number | null retry_count?: number | null + session_id?: string | null started_at?: string status_code?: number | null trace_id?: string | null @@ -2440,7 +2862,12 @@ export type Database = { method?: string parent_request_id?: string | null request_id?: string + request_method?: string | null + request_path?: string | null + response_status?: number | null + response_time_ms?: number | null retry_count?: number | null + session_id?: string | null started_at?: string status_code?: number | null trace_id?: string | null @@ -4308,6 +4735,54 @@ export type Database = { }, ] } + submission_metadata: { + Row: { + created_at: string | null + display_order: number | null + id: string + metadata_key: string + metadata_value: string + submission_id: string + updated_at: string | null + value_type: string | null + } + Insert: { + created_at?: string | null + display_order?: number | null + id?: string + metadata_key: string + metadata_value: string + submission_id: string + updated_at?: string | null + value_type?: string | null + } + Update: { + created_at?: string | null + display_order?: number | null + id?: string + metadata_key?: string + metadata_value?: string + submission_id?: string + updated_at?: string | null + value_type?: string | null + } + Relationships: [ + { + foreignKeyName: "submission_metadata_submission_id_fkey" + columns: ["submission_id"] + isOneToOne: false + referencedRelation: "content_submissions" + referencedColumns: ["id"] + }, + { + foreignKeyName: "submission_metadata_submission_id_fkey" + columns: ["submission_id"] + isOneToOne: false + referencedRelation: "moderation_queue_with_entities" + referencedColumns: ["id"] + }, + ] + } test_data_registry: { Row: { created_at: string diff --git a/src/lib/auditHelpers.ts b/src/lib/auditHelpers.ts new file mode 100644 index 00000000..5114f82b --- /dev/null +++ b/src/lib/auditHelpers.ts @@ -0,0 +1,193 @@ +/** + * Helper functions for relational audit logging + * Replaces JSONB storage with proper relational tables + */ + +import { supabase } from '@/integrations/supabase/client'; +import { logger } from './logger'; + +/** + * Write admin audit details to relational table + * Replaces JSONB admin_audit_log.details column + */ +export async function writeAdminAuditDetails( + auditLogId: string, + details: Record +): Promise { + if (!details || Object.keys(details).length === 0) return; + + const entries = Object.entries(details).map(([key, value]) => ({ + audit_log_id: auditLogId, + detail_key: key, + detail_value: typeof value === 'object' ? JSON.stringify(value) : String(value), + })); + + const { error } = await supabase + .from('admin_audit_details') + .insert(entries); + + if (error) { + logger.error('Failed to write admin audit details', { error, auditLogId }); + throw error; + } +} + +/** + * Write moderation audit metadata to relational table + * Replaces JSONB moderation_audit_log.metadata column + */ +export async function writeModerationAuditMetadata( + auditLogId: string, + metadata: Record +): Promise { + if (!metadata || Object.keys(metadata).length === 0) return; + + const entries = Object.entries(metadata).map(([key, value]) => ({ + audit_log_id: auditLogId, + metadata_key: key, + metadata_value: typeof value === 'object' ? JSON.stringify(value) : String(value), + })); + + const { error } = await supabase + .from('moderation_audit_metadata') + .insert(entries); + + if (error) { + logger.error('Failed to write moderation audit metadata', { error, auditLogId }); + throw error; + } +} + +/** + * Write item change fields to relational table + * Replaces JSONB item_edit_history.changes column + */ +export async function writeItemChangeFields( + editHistoryId: string, + changes: Record +): Promise { + if (!changes || Object.keys(changes).length === 0) return; + + const entries = Object.entries(changes).map(([fieldName, change]) => ({ + edit_history_id: editHistoryId, + field_name: fieldName, + old_value: change.old_value !== undefined + ? (typeof change.old_value === 'object' ? JSON.stringify(change.old_value) : String(change.old_value)) + : null, + new_value: change.new_value !== undefined + ? (typeof change.new_value === 'object' ? JSON.stringify(change.new_value) : String(change.new_value)) + : null, + })); + + const { error } = await supabase + .from('item_change_fields') + .insert(entries); + + if (error) { + logger.error('Failed to write item change fields', { error, editHistoryId }); + throw error; + } +} + +/** + * Write request breadcrumbs to relational table + * Replaces JSONB request_metadata.breadcrumbs column + */ +export async function writeRequestBreadcrumbs( + requestId: string, + breadcrumbs: Array<{ + timestamp: string; + category: string; + message: string; + level?: 'debug' | 'info' | 'warn' | 'error'; + }> +): Promise { + if (!breadcrumbs || breadcrumbs.length === 0) return; + + const entries = breadcrumbs.map((breadcrumb, index) => ({ + request_id: requestId, + timestamp: breadcrumb.timestamp, + category: breadcrumb.category, + message: breadcrumb.message, + level: breadcrumb.level || 'info', + sequence_order: index, + })); + + const { error } = await supabase + .from('request_breadcrumbs') + .insert(entries); + + if (error) { + logger.error('Failed to write request breadcrumbs', { error, requestId }); + throw error; + } +} + +/** + * Read admin audit details from relational table + */ +export async function readAdminAuditDetails( + auditLogId: string +): Promise> { + const { data, error } = await supabase + .from('admin_audit_details') + .select('detail_key, detail_value') + .eq('audit_log_id', auditLogId); + + if (error) { + logger.error('Failed to read admin audit details', { error, auditLogId }); + return {}; + } + + return data.reduce((acc, row) => { + acc[row.detail_key] = row.detail_value; + return acc; + }, {} as Record); +} + +/** + * Read moderation audit metadata from relational table + */ +export async function readModerationAuditMetadata( + auditLogId: string +): Promise> { + const { data, error } = await supabase + .from('moderation_audit_metadata') + .select('metadata_key, metadata_value') + .eq('audit_log_id', auditLogId); + + if (error) { + logger.error('Failed to read moderation audit metadata', { error, auditLogId }); + return {}; + } + + return data.reduce((acc, row) => { + acc[row.metadata_key] = row.metadata_value; + return acc; + }, {} as Record); +} + +/** + * Read item change fields from relational table + */ +export async function readItemChangeFields( + editHistoryId: string +): Promise> { + const { data, error } = await supabase + .from('item_change_fields') + .select('field_name, old_value, new_value') + .eq('edit_history_id', editHistoryId); + + if (error) { + logger.error('Failed to read item change fields', { error, editHistoryId }); + return {}; + } + + return data.reduce((acc, row) => { + acc[row.field_name] = { + old_value: row.old_value, + new_value: row.new_value, + }; + return acc; + }, {} as Record); +} diff --git a/supabase/migrations/20251103204113_e8ad3633-7e26-46ec-8dd2-421787715778.sql b/supabase/migrations/20251103204113_e8ad3633-7e26-46ec-8dd2-421787715778.sql new file mode 100644 index 00000000..797d4965 --- /dev/null +++ b/supabase/migrations/20251103204113_e8ad3633-7e26-46ec-8dd2-421787715778.sql @@ -0,0 +1,345 @@ +-- ============================================================================ +-- COMPLETE JSONB ELIMINATION MIGRATION (FIXED) +-- Converts all 16 JSONB violations to proper relational tables +-- ============================================================================ + +-- ============================================================================ +-- GROUP 1: SUBMISSION SYSTEM (CRITICAL) +-- ============================================================================ + +-- 1.1: content_submissions.content → submission_metadata +CREATE TABLE IF NOT EXISTS submission_metadata ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + submission_id UUID NOT NULL REFERENCES content_submissions(id) ON DELETE CASCADE, + metadata_key TEXT NOT NULL, + metadata_value TEXT NOT NULL, + value_type TEXT CHECK (value_type IN ('string', 'number', 'boolean', 'date', 'url', 'json')), + display_order INTEGER DEFAULT 0, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW(), + UNIQUE(submission_id, metadata_key) +); + +CREATE INDEX IF NOT EXISTS idx_submission_metadata_submission ON submission_metadata(submission_id); +CREATE INDEX IF NOT EXISTS idx_submission_metadata_key ON submission_metadata(metadata_key); + +ALTER TABLE submission_metadata ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Moderators view all submission metadata" + ON submission_metadata FOR SELECT + TO authenticated + USING (is_moderator(auth.uid())); + +CREATE POLICY "Users view own submission metadata" + ON submission_metadata FOR SELECT + TO authenticated + USING ( + EXISTS ( + SELECT 1 FROM content_submissions cs + WHERE cs.id = submission_metadata.submission_id + AND cs.user_id = auth.uid() + ) + ); + +CREATE POLICY "System inserts submission metadata" + ON submission_metadata FOR INSERT + TO authenticated + WITH CHECK ( + EXISTS ( + SELECT 1 FROM content_submissions cs + WHERE cs.id = submission_metadata.submission_id + AND (cs.user_id = auth.uid() OR is_moderator(auth.uid())) + ) + ); + +CREATE POLICY "System updates submission metadata" + ON submission_metadata FOR UPDATE + TO authenticated + USING (is_moderator(auth.uid())); + +-- ============================================================================ +-- GROUP 2: REVIEW SYSTEM (HIGH PRIORITY) +-- ============================================================================ + +-- 2.1: reviews.photos → review_photos +CREATE TABLE IF NOT EXISTS review_photos ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + review_id UUID NOT NULL REFERENCES reviews(id) ON DELETE CASCADE, + cloudflare_image_id TEXT NOT NULL, + cloudflare_image_url TEXT NOT NULL, + caption TEXT, + order_index INTEGER DEFAULT 0, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +CREATE INDEX IF NOT EXISTS idx_review_photos_review ON review_photos(review_id); + +ALTER TABLE review_photos ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Public view review photos" + ON review_photos FOR SELECT + USING (true); + +CREATE POLICY "Users manage own review photos" + ON review_photos FOR ALL + USING ( + EXISTS ( + SELECT 1 FROM reviews r + WHERE r.id = review_photos.review_id + AND r.user_id = auth.uid() + ) + ); + +CREATE POLICY "Moderators manage all review photos" + ON review_photos FOR ALL + USING (is_moderator(auth.uid())); + +-- ============================================================================ +-- GROUP 3: AUDIT & HISTORY TABLES (MEDIUM PRIORITY) +-- ============================================================================ + +-- 3.1: admin_audit_log.details → admin_audit_details +CREATE TABLE IF NOT EXISTS admin_audit_details ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + audit_log_id UUID NOT NULL REFERENCES admin_audit_log(id) ON DELETE CASCADE, + detail_key TEXT NOT NULL, + detail_value TEXT NOT NULL, + created_at TIMESTAMPTZ DEFAULT NOW(), + UNIQUE(audit_log_id, detail_key) +); + +CREATE INDEX IF NOT EXISTS idx_admin_audit_details_log ON admin_audit_details(audit_log_id); + +ALTER TABLE admin_audit_details ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Admins view audit details" + ON admin_audit_details FOR SELECT + USING (is_moderator(auth.uid()) AND has_aal2()); + +CREATE POLICY "System inserts audit details" + ON admin_audit_details FOR INSERT + WITH CHECK (is_moderator(auth.uid())); + +-- 3.2: moderation_audit_log.metadata → moderation_audit_metadata +CREATE TABLE IF NOT EXISTS moderation_audit_metadata ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + audit_log_id UUID NOT NULL REFERENCES moderation_audit_log(id) ON DELETE CASCADE, + metadata_key TEXT NOT NULL, + metadata_value TEXT NOT NULL, + created_at TIMESTAMPTZ DEFAULT NOW(), + UNIQUE(audit_log_id, metadata_key) +); + +CREATE INDEX IF NOT EXISTS idx_moderation_audit_metadata_log ON moderation_audit_metadata(audit_log_id); + +ALTER TABLE moderation_audit_metadata ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Moderators view moderation audit metadata" + ON moderation_audit_metadata FOR SELECT + USING (is_moderator(auth.uid())); + +CREATE POLICY "System inserts moderation audit metadata" + ON moderation_audit_metadata FOR INSERT + WITH CHECK (is_moderator(auth.uid())); + +-- 3.3: profile_audit_log.changes → profile_change_fields +CREATE TABLE IF NOT EXISTS profile_change_fields ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + audit_log_id UUID NOT NULL REFERENCES profile_audit_log(id) ON DELETE CASCADE, + field_name TEXT NOT NULL, + old_value TEXT, + new_value TEXT, + created_at TIMESTAMPTZ DEFAULT NOW() +); + +CREATE INDEX IF NOT EXISTS idx_profile_change_fields_log ON profile_change_fields(audit_log_id); + +ALTER TABLE profile_change_fields ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Users view own profile change fields" + ON profile_change_fields FOR SELECT + USING ( + EXISTS ( + SELECT 1 FROM profile_audit_log pal + WHERE pal.id = profile_change_fields.audit_log_id + AND pal.user_id = auth.uid() + ) + ); + +CREATE POLICY "Moderators view all profile change fields" + ON profile_change_fields FOR SELECT + USING (is_moderator(auth.uid())); + +-- 3.4: item_edit_history.changes → item_change_fields +CREATE TABLE IF NOT EXISTS item_change_fields ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + edit_history_id UUID NOT NULL REFERENCES item_edit_history(id) ON DELETE CASCADE, + field_name TEXT NOT NULL, + old_value TEXT, + new_value TEXT, + created_at TIMESTAMPTZ DEFAULT NOW() +); + +CREATE INDEX IF NOT EXISTS idx_item_change_fields_history ON item_change_fields(edit_history_id); + +ALTER TABLE item_change_fields ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Moderators view item change fields" + ON item_change_fields FOR SELECT + USING (is_moderator(auth.uid())); + +CREATE POLICY "System inserts item change fields" + ON item_change_fields FOR INSERT + WITH CHECK (is_moderator(auth.uid())); + +-- ============================================================================ +-- GROUP 4: HISTORICAL DATA (MEDIUM PRIORITY) +-- ============================================================================ + +-- 4.1: historical_parks.final_state_data → Add columns directly +ALTER TABLE historical_parks + ADD COLUMN IF NOT EXISTS park_type TEXT, + ADD COLUMN IF NOT EXISTS status TEXT, + ADD COLUMN IF NOT EXISTS description TEXT, + ADD COLUMN IF NOT EXISTS location_id UUID REFERENCES locations(id), + ADD COLUMN IF NOT EXISTS operator_id UUID REFERENCES companies(id), + ADD COLUMN IF NOT EXISTS property_owner_id UUID REFERENCES companies(id), + ADD COLUMN IF NOT EXISTS opening_date DATE, + ADD COLUMN IF NOT EXISTS opening_date_precision TEXT, + ADD COLUMN IF NOT EXISTS closing_date DATE, + ADD COLUMN IF NOT EXISTS closing_date_precision TEXT, + ADD COLUMN IF NOT EXISTS website_url TEXT, + ADD COLUMN IF NOT EXISTS phone TEXT, + ADD COLUMN IF NOT EXISTS email TEXT, + ADD COLUMN IF NOT EXISTS banner_image_url TEXT, + ADD COLUMN IF NOT EXISTS banner_image_id TEXT, + ADD COLUMN IF NOT EXISTS card_image_url TEXT, + ADD COLUMN IF NOT EXISTS card_image_id TEXT; + +-- 4.2: historical_rides.final_state_data → Add columns directly +ALTER TABLE historical_rides + ADD COLUMN IF NOT EXISTS category TEXT, + ADD COLUMN IF NOT EXISTS status TEXT, + ADD COLUMN IF NOT EXISTS description TEXT, + ADD COLUMN IF NOT EXISTS manufacturer_id UUID REFERENCES companies(id), + ADD COLUMN IF NOT EXISTS designer_id UUID REFERENCES companies(id), + ADD COLUMN IF NOT EXISTS ride_model_id UUID REFERENCES ride_models(id), + ADD COLUMN IF NOT EXISTS opening_date DATE, + ADD COLUMN IF NOT EXISTS opening_date_precision TEXT, + ADD COLUMN IF NOT EXISTS closing_date DATE, + ADD COLUMN IF NOT EXISTS closing_date_precision TEXT, + ADD COLUMN IF NOT EXISTS max_speed_kmh NUMERIC, + ADD COLUMN IF NOT EXISTS max_height_meters NUMERIC, + ADD COLUMN IF NOT EXISTS length_meters NUMERIC, + ADD COLUMN IF NOT EXISTS drop_height_meters NUMERIC, + ADD COLUMN IF NOT EXISTS inversions INTEGER, + ADD COLUMN IF NOT EXISTS max_g_force NUMERIC, + ADD COLUMN IF NOT EXISTS coaster_type TEXT, + ADD COLUMN IF NOT EXISTS seating_type TEXT, + ADD COLUMN IF NOT EXISTS intensity_level TEXT, + ADD COLUMN IF NOT EXISTS banner_image_url TEXT, + ADD COLUMN IF NOT EXISTS banner_image_id TEXT, + ADD COLUMN IF NOT EXISTS card_image_url TEXT, + ADD COLUMN IF NOT EXISTS card_image_id TEXT; + +-- ============================================================================ +-- GROUP 5: NOTIFICATION SYSTEM (LOW PRIORITY) +-- ============================================================================ + +-- 5.1: notification_logs.payload → notification_event_data +CREATE TABLE IF NOT EXISTS notification_event_data ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + notification_log_id UUID NOT NULL REFERENCES notification_logs(id) ON DELETE CASCADE, + event_key TEXT NOT NULL, + event_value TEXT NOT NULL, + created_at TIMESTAMPTZ DEFAULT NOW(), + UNIQUE(notification_log_id, event_key) +); + +CREATE INDEX IF NOT EXISTS idx_notification_event_data_log ON notification_event_data(notification_log_id); + +ALTER TABLE notification_event_data ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Admins view notification event data" + ON notification_event_data FOR SELECT + USING (is_moderator(auth.uid())); + +-- ============================================================================ +-- GROUP 6: ERROR TRACKING (LOW PRIORITY) +-- ============================================================================ + +-- 6.1: request_metadata.breadcrumbs → request_breadcrumbs +CREATE TABLE IF NOT EXISTS request_breadcrumbs ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + request_id UUID NOT NULL REFERENCES request_metadata(request_id) ON DELETE CASCADE, + timestamp TIMESTAMPTZ NOT NULL, + category TEXT NOT NULL, + message TEXT NOT NULL, + level TEXT CHECK (level IN ('debug', 'info', 'warn', 'error')), + sequence_order INTEGER NOT NULL, + created_at TIMESTAMPTZ DEFAULT NOW() +); + +CREATE INDEX IF NOT EXISTS idx_request_breadcrumbs_request ON request_breadcrumbs(request_id); +CREATE INDEX IF NOT EXISTS idx_request_breadcrumbs_timestamp ON request_breadcrumbs(timestamp); + +ALTER TABLE request_breadcrumbs ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Admins view request breadcrumbs" + ON request_breadcrumbs FOR SELECT + USING (is_moderator(auth.uid())); + +-- 6.2: request_metadata.environment_context → Add specific columns +ALTER TABLE request_metadata + ADD COLUMN IF NOT EXISTS request_path TEXT, + ADD COLUMN IF NOT EXISTS request_method TEXT, + ADD COLUMN IF NOT EXISTS response_status INTEGER, + ADD COLUMN IF NOT EXISTS response_time_ms INTEGER, + ADD COLUMN IF NOT EXISTS session_id TEXT, + ADD COLUMN IF NOT EXISTS ip_address_hash TEXT; + +-- ============================================================================ +-- GROUP 7: CONFLICT RESOLUTION (LOW PRIORITY) +-- ============================================================================ + +-- 7.1: conflict_resolutions.conflict_details → conflict_detail_fields +CREATE TABLE IF NOT EXISTS conflict_detail_fields ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + conflict_resolution_id UUID NOT NULL REFERENCES conflict_resolutions(id) ON DELETE CASCADE, + field_name TEXT NOT NULL, + conflicting_value_1 TEXT, + conflicting_value_2 TEXT, + resolved_value TEXT, + created_at TIMESTAMPTZ DEFAULT NOW() +); + +CREATE INDEX IF NOT EXISTS idx_conflict_detail_fields_resolution ON conflict_detail_fields(conflict_resolution_id); + +ALTER TABLE conflict_detail_fields ENABLE ROW LEVEL SECURITY; + +CREATE POLICY "Moderators view conflict detail fields" + ON conflict_detail_fields FOR SELECT + USING (is_moderator(auth.uid())); + +-- ============================================================================ +-- GROUP 8: EMAIL THREADS (LOW PRIORITY) +-- ============================================================================ + +-- 8.1: contact_email_threads.metadata → Add specific columns +ALTER TABLE contact_email_threads + ADD COLUMN IF NOT EXISTS email_provider TEXT, + ADD COLUMN IF NOT EXISTS smtp_message_id TEXT, + ADD COLUMN IF NOT EXISTS spam_score NUMERIC, + ADD COLUMN IF NOT EXISTS attachment_count INTEGER DEFAULT 0, + ADD COLUMN IF NOT EXISTS is_auto_reply BOOLEAN DEFAULT false; + +-- ============================================================================ +-- TRIGGERS FOR UPDATED_AT TIMESTAMPS +-- ============================================================================ + +CREATE TRIGGER update_submission_metadata_updated_at BEFORE UPDATE ON submission_metadata + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); + +CREATE TRIGGER update_review_photos_updated_at BEFORE UPDATE ON review_photos + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); \ No newline at end of file