sojorn/go-backend/internal/database/migrations/000014_structural_moderation.up.sql

61 lines
2.5 KiB
PL/PgSQL

-- Structural Blocking & Abuse Tracking
-- Create abuse_logs table
CREATE TABLE IF NOT EXISTS public.abuse_logs (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
actor_id UUID REFERENCES public.profiles(id) ON DELETE SET NULL,
blocked_id UUID NOT NULL REFERENCES public.profiles(id) ON DELETE CASCADE,
blocked_handle TEXT NOT NULL,
actor_ip TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Create reports table
CREATE TABLE IF NOT EXISTS public.reports (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
reporter_id UUID NOT NULL REFERENCES public.profiles(id) ON DELETE CASCADE,
target_user_id UUID NOT NULL REFERENCES public.profiles(id) ON DELETE CASCADE,
post_id UUID REFERENCES public.posts(id) ON DELETE SET NULL,
comment_id UUID REFERENCES public.comments(id) ON DELETE SET NULL,
violation_type TEXT NOT NULL, -- e.g., 'hate', 'greed', 'delusion'
description TEXT,
status TEXT NOT NULL DEFAULT 'pending', -- pending, reviewed, resolved
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Create pending_moderation table for AI flags
CREATE TABLE IF NOT EXISTS public.pending_moderation (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
post_id UUID REFERENCES public.posts(id) ON DELETE CASCADE,
comment_id UUID REFERENCES public.comments(id) ON DELETE CASCADE,
flag_reason TEXT NOT NULL,
scores JSONB, -- store AI scores for 'hate', 'greed', 'delusion'
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Blocking Function
CREATE OR REPLACE FUNCTION public.has_block_between(user_a UUID, user_b UUID)
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1 FROM public.blocks
WHERE (blocker_id = user_a AND blocked_id = user_b)
OR (blocker_id = user_b AND blocked_id = user_a)
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Note: RLS implementation typically requires the database to be aware of the "current_user_id".
-- Since this is an external Go API, we will enforce structural invisibility in the Repositories/Queries
-- for now if RLS isn't fully configured with the Auth provider's claims.
-- However, we'll set up the policies anyway for parity.
-- Enable RLS
ALTER TABLE public.posts ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.comments ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.profiles ENABLE ROW LEVEL SECURITY;
-- Post Policy: Hide posts from/to blocked users
-- This assuming jwt.claims.sub can be passed to session configs
-- For now, we will focus on SQL Query enforcement in Repo layer which is more reliable for custom Go Backends