mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-23 15:51:13 -05:00
Add moderation queue tables
This commit is contained in:
@@ -0,0 +1,156 @@
|
||||
-- Create user roles enum
|
||||
CREATE TYPE public.app_role AS ENUM ('admin', 'moderator', 'user');
|
||||
|
||||
-- Create user_roles table
|
||||
CREATE TABLE public.user_roles (
|
||||
id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
|
||||
role public.app_role NOT NULL,
|
||||
granted_by UUID REFERENCES auth.users(id),
|
||||
granted_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
||||
UNIQUE(user_id, role)
|
||||
);
|
||||
|
||||
-- Enable RLS on user_roles
|
||||
ALTER TABLE public.user_roles ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Create reports table
|
||||
CREATE TABLE public.reports (
|
||||
id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
reporter_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
|
||||
reported_entity_type TEXT NOT NULL CHECK (reported_entity_type IN ('review', 'profile', 'content_submission')),
|
||||
reported_entity_id UUID NOT NULL,
|
||||
report_type TEXT NOT NULL CHECK (report_type IN ('spam', 'inappropriate', 'harassment', 'fake_info', 'offensive')),
|
||||
reason TEXT,
|
||||
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'reviewed', 'dismissed')),
|
||||
reviewed_by UUID REFERENCES auth.users(id),
|
||||
reviewed_at TIMESTAMP WITH TIME ZONE,
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
-- Enable RLS on reports
|
||||
ALTER TABLE public.reports ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Add report_count to reviews table for auto-flagging
|
||||
ALTER TABLE public.reviews ADD COLUMN report_count INTEGER NOT NULL DEFAULT 0;
|
||||
|
||||
-- Create security definer function to check user roles
|
||||
CREATE OR REPLACE FUNCTION public.has_role(_user_id UUID, _role public.app_role)
|
||||
RETURNS BOOLEAN
|
||||
LANGUAGE SQL
|
||||
STABLE
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
SELECT EXISTS (
|
||||
SELECT 1
|
||||
FROM public.user_roles
|
||||
WHERE user_id = _user_id
|
||||
AND role = _role
|
||||
)
|
||||
$$;
|
||||
|
||||
-- Create function to check if user is moderator or admin
|
||||
CREATE OR REPLACE FUNCTION public.is_moderator(_user_id UUID)
|
||||
RETURNS BOOLEAN
|
||||
LANGUAGE SQL
|
||||
STABLE
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
SELECT EXISTS (
|
||||
SELECT 1
|
||||
FROM public.user_roles
|
||||
WHERE user_id = _user_id
|
||||
AND role IN ('moderator', 'admin')
|
||||
)
|
||||
$$;
|
||||
|
||||
-- RLS Policies for user_roles
|
||||
CREATE POLICY "Admins can manage all user roles"
|
||||
ON public.user_roles
|
||||
FOR ALL
|
||||
USING (public.has_role(auth.uid(), 'admin'));
|
||||
|
||||
CREATE POLICY "Users can view their own roles"
|
||||
ON public.user_roles
|
||||
FOR SELECT
|
||||
USING (auth.uid() = user_id);
|
||||
|
||||
-- RLS Policies for reports
|
||||
CREATE POLICY "Users can create reports"
|
||||
ON public.reports
|
||||
FOR INSERT
|
||||
WITH CHECK (auth.uid() = reporter_id);
|
||||
|
||||
CREATE POLICY "Users can view their own reports"
|
||||
ON public.reports
|
||||
FOR SELECT
|
||||
USING (auth.uid() = reporter_id);
|
||||
|
||||
CREATE POLICY "Moderators can view all reports"
|
||||
ON public.reports
|
||||
FOR SELECT
|
||||
USING (public.is_moderator(auth.uid()));
|
||||
|
||||
CREATE POLICY "Moderators can update reports"
|
||||
ON public.reports
|
||||
FOR UPDATE
|
||||
USING (public.is_moderator(auth.uid()));
|
||||
|
||||
-- Update RLS policies for reviews to allow moderator access
|
||||
CREATE POLICY "Moderators can view all reviews"
|
||||
ON public.reviews
|
||||
FOR SELECT
|
||||
USING (public.is_moderator(auth.uid()));
|
||||
|
||||
CREATE POLICY "Moderators can update review status"
|
||||
ON public.reviews
|
||||
FOR UPDATE
|
||||
USING (public.is_moderator(auth.uid()));
|
||||
|
||||
-- Update RLS policies for content_submissions to allow moderator access
|
||||
CREATE POLICY "Moderators can view all content submissions"
|
||||
ON public.content_submissions
|
||||
FOR SELECT
|
||||
USING (public.is_moderator(auth.uid()));
|
||||
|
||||
CREATE POLICY "Moderators can update content submissions"
|
||||
ON public.content_submissions
|
||||
FOR UPDATE
|
||||
USING (public.is_moderator(auth.uid()));
|
||||
|
||||
-- Create trigger to update report_count on reviews when reports are created
|
||||
CREATE OR REPLACE FUNCTION public.update_report_count()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
BEGIN
|
||||
IF NEW.reported_entity_type = 'review' THEN
|
||||
UPDATE public.reviews
|
||||
SET report_count = report_count + 1,
|
||||
moderation_status = CASE
|
||||
WHEN report_count + 1 >= 3 THEN 'flagged'
|
||||
ELSE moderation_status
|
||||
END
|
||||
WHERE id = NEW.reported_entity_id;
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE TRIGGER increment_report_count
|
||||
AFTER INSERT ON public.reports
|
||||
FOR EACH ROW
|
||||
WHEN (NEW.reported_entity_type = 'review')
|
||||
EXECUTE FUNCTION public.update_report_count();
|
||||
|
||||
-- Create trigger for updating updated_at on reports
|
||||
CREATE TRIGGER update_reports_updated_at
|
||||
BEFORE UPDATE ON public.reports
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION public.update_updated_at_column();
|
||||
Reference in New Issue
Block a user