# Moderation Flow Integration **How versioning integrates with the content moderation system** ## Overview The versioning system is tightly integrated with the moderation queue. When moderators approve submissions, versions are automatically created with proper attribution to the original submitter (not the moderator who approved). ## Submission-to-Version Flow ### Complete Flow Diagram ```mermaid sequenceDiagram participant User participant UI as React UI participant CS as content_submissions participant Edge as Edge Function participant Session as PostgreSQL Session participant Entity as Entity Table participant Trigger as Version Trigger participant Versions as Version Table User->>UI: Submit Park Edit UI->>CS: INSERT content_submission Note over CS: status = 'pending'
user_id = submitter User->>UI: Moderator Reviews Note over UI: Moderator clicks "Approve" UI->>Edge: POST /process-selective-approval Note over Edge: Edge function starts Edge->>Session: SET app.current_user_id = submitter_id Edge->>Session: SET app.submission_id = submission_id Note over Session: Session variables set Edge->>Entity: UPDATE parks SET name = ... Note over Entity: Entity updated Entity->>Trigger: AFTER UPDATE trigger fires Trigger->>Session: Read app.current_user_id Trigger->>Session: Read app.submission_id Trigger->>Versions: Mark previous is_current = false Trigger->>Versions: INSERT park_versions Note over Versions: version_number = N+1
created_by = submitter
submission_id = linked Trigger-->>Entity: RETURN Entity-->>Edge: Success Edge->>CS: UPDATE content_submissions
SET status = 'approved' Edge-->>UI: Return success UI->>User: Toast: "Approved! Version 4 created" ``` ## Key Components ### 1. Content Submissions User creates submission with their proposed changes: ```sql INSERT INTO content_submissions ( user_id, -- Original submitter submission_type, -- 'park_edit', 'ride_create', etc. content, -- Not used in relational system status -- 'pending' ) VALUES ( auth.uid(), 'park_edit', '{}'::jsonb, 'pending' ); ``` ### 2. Entity Submission Tables Detailed submission data stored in entity-specific tables: ```sql INSERT INTO park_submissions ( submission_id, -- FK to content_submissions name, slug, description, park_type, -- ... all park fields ) VALUES (...); ``` ### 3. Edge Function (process-selective-approval) Moderator approves submission, edge function orchestrates: ```typescript // supabase/functions/process-selective-approval/index.ts export async function processSelectiveApproval( submissionId: string, selectedItems: string[] ) { // Get submission details const { data: submission } = await supabase .from('content_submissions') .select('*, park_submissions(*)') .eq('id', submissionId) .single(); // Set session variables for version attribution await supabase.rpc('set_session_variable', { key: 'app.current_user_id', value: submission.user_id, // Original submitter, NOT moderator }); await supabase.rpc('set_session_variable', { key: 'app.submission_id', value: submissionId, }); // Update entity (triggers version creation) const { error } = await supabase .from('parks') .update({ name: submission.park_submissions.name, description: submission.park_submissions.description, // ... approved fields }) .eq('id', submission.park_submissions.park_id); // Version is now created automatically via trigger // with created_by = submission.user_id // and submission_id = submissionId // Update submission status await supabase .from('content_submissions') .update({ status: 'approved', reviewed_at: new Date().toISOString(), reviewer_id: moderatorId, }) .eq('id', submissionId); return { success: true }; } ``` ### 4. Session Variables PostgreSQL session variables pass attribution through triggers: ```sql -- Edge function sets these before entity update SET LOCAL app.current_user_id = 'user-uuid-here'; SET LOCAL app.submission_id = 'submission-uuid-here'; -- Trigger function reads them CREATE FUNCTION create_relational_version() AS $$ DECLARE v_created_by UUID; v_submission_id UUID; BEGIN -- Get from session variables v_created_by := NULLIF(current_setting('app.current_user_id', TRUE), '')::UUID; v_submission_id := NULLIF(current_setting('app.submission_id', TRUE), '')::UUID; -- Fallback to auth.uid() if not set IF v_created_by IS NULL THEN v_created_by := auth.uid(); END IF; -- Insert version with attribution INSERT INTO park_versions (..., created_by, submission_id, ...) VALUES (..., v_created_by, v_submission_id, ...); RETURN NEW; END; $$ LANGUAGE plpgsql; ``` ### 5. Automatic Trigger Execution When entity UPDATE occurs, trigger fires automatically: ```sql CREATE TRIGGER create_park_version_on_change AFTER INSERT OR UPDATE ON parks FOR EACH ROW EXECUTE FUNCTION public.create_relational_version(); ``` ## Version Attribution ### Critical: Submitter vs. Moderator **IMPORTANT:** Versions are attributed to the **original submitter**, not the moderator who approved. ```typescript // ❌ WRONG - This would attribute to moderator created_by: auth.uid() // Moderator's ID // ✅ CORRECT - Attribute to original submitter created_by: submission.user_id // Submitter's ID ``` ### Why This Matters - **Credit** - Users get credit for their contributions - **Audit Trail** - Know who made the change (not just who approved it) - **Reputation** - Contribution counts toward user reputation - **Transparency** - Public can see who contributed what ### Moderator Tracking Moderators are tracked separately in `content_submissions`: ```sql SELECT cs.user_id as original_submitter, cs.reviewer_id as moderator_who_approved, pv.created_by as version_attributed_to FROM content_submissions cs JOIN park_versions pv ON pv.submission_id = cs.id WHERE cs.id = 'submission-uuid'; -- Result: -- original_submitter: user-123 (matches version_attributed_to) -- moderator_who_approved: moderator-456 -- version_attributed_to: user-123 ``` ## Change Types Versions are created with appropriate `change_type`: ### 'created' First version when entity is created: ```sql -- INSERT into parks triggers version INSERT INTO parks (name, slug, ...) VALUES ('New Park', 'new-park', ...); -- Trigger creates: -- version_number: 1 -- change_type: 'created' -- is_current: true ``` ### 'updated' Subsequent updates: ```sql -- UPDATE parks triggers version UPDATE parks SET description = 'Updated description' WHERE id = 'park-uuid'; -- Trigger creates: -- version_number: N+1 -- change_type: 'updated' -- is_current: true -- (Previous version marked is_current = false) ``` ### 'restored' Rollback to previous version: ```sql -- Moderator rolls back erroneous approval SELECT rollback_to_version( 'park', 'park-uuid', 'target-version-uuid', auth.uid(), 'Incorrect data approved by mistake' ); -- Creates new version: -- version_number: N+1 -- change_type: 'restored' -- is_current: true ``` ## Moderation Queue Integration ### Toast Notifications After approval, show version number: ```typescript // In moderation queue component const handleApprove = async (submissionId: string) => { const result = await processSelectiveApproval(submissionId); if (result.success) { // Fetch latest version number const { data: version } = await supabase .from('park_versions') .select('version_number') .eq('submission_id', submissionId) .single(); toast({ title: 'Submission Approved', description: `Version ${version.version_number} created successfully`, }); } }; ``` ### Link to Version History ```typescript ``` ### Real-Time Updates Moderation queue updates when versions are created: ```typescript // Subscribe to content_submissions changes const subscription = supabase .channel('moderation-queue') .on( 'postgres_changes', { event: 'UPDATE', schema: 'public', table: 'content_submissions', filter: 'status=eq.approved', }, (payload) => { // Refresh queue fetchQueue(); // Show notification toast({ title: 'Submission Approved', description: `${payload.new.submission_type} processed`, }); } ) .subscribe(); ``` ## Selective Approval When moderators approve only specific fields: ```typescript // User submits changes to multiple fields const submission = { name: 'Updated Name', // Moderator approves description: 'New Desc', // Moderator approves website_url: 'bad-url.com', // Moderator rejects }; // Edge function updates only approved fields await supabase .from('parks') .update({ name: submission.name, // ✅ Approved description: submission.description, // ✅ Approved // website_url NOT updated ❌ Rejected }) .eq('id', parkId); // Version created with only approved changes ``` ## Rollback After Erroneous Approval If moderator approves wrong data: ```typescript // 1. Moderator realizes mistake // 2. Opens version history // 3. Selects correct previous version // 4. Clicks "Rollback" const rollback = await rollbackToVersion( targetVersionId, 'Incorrect manufacturer approved, reverting to previous' ); // New version created: // - change_type: 'restored' // - Data matches target version // - New version_number (not replacing existing version) ``` ## Audit Trail Complete audit trail from submission to approval to version: ```sql -- Full audit query SELECT cs.id as submission_id, cs.submitted_at, cs.status, submitter.username as submitted_by, cs.reviewed_at, moderator.username as reviewed_by, pv.version_id, pv.version_number, pv.change_type, pv.created_at as version_created_at FROM content_submissions cs LEFT JOIN profiles submitter ON submitter.user_id = cs.user_id LEFT JOIN profiles moderator ON moderator.user_id = cs.reviewer_id LEFT JOIN park_versions pv ON pv.submission_id = cs.id WHERE cs.id = 'submission-uuid'; ``` ## Best Practices ### DO ✅ Always set `app.current_user_id` to original submitter ✅ Link versions to submissions via `submission_id` ✅ Show version numbers in approval toasts ✅ Provide rollback for erroneous approvals ✅ Track moderator in `content_submissions.reviewer_id` ### DON'T ❌ Attribute versions to moderator ❌ Skip setting session variables ❌ Update entities without proper attribution ❌ Delete versions (use rollback instead) ❌ Approve without reviewing version impact ## Testing Moderation Flow ### Test Script ```typescript // 1. Create submission as user const { data: submission } = await supabase .from('content_submissions') .insert({ user_id: userId, submission_type: 'park_edit', status: 'pending', }) .select() .single(); // 2. Create park submission await supabase .from('park_submissions') .insert({ submission_id: submission.id, name: 'Test Park', slug: 'test-park', park_type: 'theme_park', }); // 3. Approve as moderator const result = await processSelectiveApproval(submission.id); // 4. Verify version created const { data: version } = await supabase .from('park_versions') .select('*') .eq('submission_id', submission.id) .single(); expect(version.created_by).toBe(userId); // NOT moderatorId expect(version.submission_id).toBe(submission.id); expect(version.version_number).toBe(1); expect(version.change_type).toBe('created'); ``` ## Error Handling ### Session Variable Not Set ```typescript // Edge function MUST set session variables try { await supabase.rpc('set_session_variable', { key: 'app.current_user_id', value: submission.user_id, }); } catch (error) { console.error('Failed to set session variable:', error); // Version will fallback to auth.uid() (moderator) // This is WRONG but prevents complete failure } ``` ### Version Creation Fails ```typescript // Entity update succeeds but version creation fails // Transaction rollback would be ideal but triggers don't support it // Workaround: Check version was created const { data: version } = await supabase .from('park_versions') .select('version_id') .eq('park_id', parkId) .eq('is_current', true) .single(); if (!version) { console.error('Version creation failed'); // Log to admin audit log await supabase.rpc('log_admin_action', { _admin_user_id: moderatorId, _action: 'version_creation_failure', _details: { park_id: parkId, submission_id: submissionId }, }); } ``` ## Troubleshooting See [TROUBLESHOOTING.md](./TROUBLESHOOTING.md#moderation-issues) for common moderation-related issues.