mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 06:51:12 -05:00
100 lines
3.6 KiB
PL/PgSQL
100 lines
3.6 KiB
PL/PgSQL
-- Create contact submissions table
|
|
CREATE TABLE IF NOT EXISTS public.contact_submissions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
|
|
|
-- Sender Information
|
|
user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
|
|
name TEXT NOT NULL,
|
|
email TEXT NOT NULL,
|
|
|
|
-- Message Details
|
|
subject TEXT NOT NULL,
|
|
message TEXT NOT NULL,
|
|
category TEXT NOT NULL CHECK (category IN ('general', 'moderation', 'technical', 'account', 'partnership', 'report', 'other')),
|
|
|
|
-- Admin Management
|
|
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'in_progress', 'resolved', 'closed')),
|
|
assigned_to UUID REFERENCES auth.users(id) ON DELETE SET NULL,
|
|
admin_notes TEXT,
|
|
resolved_at TIMESTAMPTZ,
|
|
resolved_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
|
|
|
|
-- Metadata
|
|
user_agent TEXT,
|
|
ip_address_hash TEXT
|
|
);
|
|
|
|
-- Create indexes
|
|
CREATE INDEX IF NOT EXISTS idx_contact_submissions_status ON public.contact_submissions(status) WHERE status IN ('pending', 'in_progress');
|
|
CREATE INDEX IF NOT EXISTS idx_contact_submissions_created_at ON public.contact_submissions(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_contact_submissions_user_id ON public.contact_submissions(user_id) WHERE user_id IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_contact_submissions_assigned_to ON public.contact_submissions(assigned_to) WHERE assigned_to IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_contact_submissions_email ON public.contact_submissions(email);
|
|
|
|
-- Enable RLS
|
|
ALTER TABLE public.contact_submissions ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Anyone can submit contact form (including non-authenticated users)
|
|
CREATE POLICY "Anyone can submit contact form"
|
|
ON public.contact_submissions
|
|
FOR INSERT
|
|
WITH CHECK (true);
|
|
|
|
-- Users can view their own submissions (by user_id or email)
|
|
CREATE POLICY "Users can view own contact submissions"
|
|
ON public.contact_submissions
|
|
FOR SELECT
|
|
USING (
|
|
user_id = auth.uid()
|
|
OR (auth.uid() IS NOT NULL AND email = (SELECT email FROM auth.users WHERE id = auth.uid()))
|
|
);
|
|
|
|
-- Moderators/Admins can view all submissions
|
|
CREATE POLICY "Moderators can view all contact submissions"
|
|
ON public.contact_submissions
|
|
FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
-- Moderators/Admins can update submissions (for management)
|
|
CREATE POLICY "Moderators can update contact submissions"
|
|
ON public.contact_submissions
|
|
FOR UPDATE
|
|
USING (is_moderator(auth.uid()) AND ((NOT has_mfa_enabled(auth.uid())) OR has_aal2()))
|
|
WITH CHECK (is_moderator(auth.uid()) AND ((NOT has_mfa_enabled(auth.uid())) OR has_aal2()));
|
|
|
|
-- Create trigger to update updated_at
|
|
CREATE OR REPLACE FUNCTION public.update_contact_submissions_updated_at()
|
|
RETURNS TRIGGER
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
BEGIN
|
|
NEW.updated_at = NOW();
|
|
RETURN NEW;
|
|
END;
|
|
$$;
|
|
|
|
CREATE TRIGGER update_contact_submissions_updated_at
|
|
BEFORE UPDATE ON public.contact_submissions
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.update_contact_submissions_updated_at();
|
|
|
|
-- Create contact rate limiting table
|
|
CREATE TABLE IF NOT EXISTS public.contact_rate_limits (
|
|
email TEXT PRIMARY KEY,
|
|
submission_count INTEGER NOT NULL DEFAULT 1,
|
|
window_start TIMESTAMPTZ NOT NULL DEFAULT now(),
|
|
last_submission_at TIMESTAMPTZ NOT NULL DEFAULT now()
|
|
);
|
|
|
|
-- Enable RLS on rate limits (only system can access)
|
|
ALTER TABLE public.contact_rate_limits ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- No public access to rate limits table
|
|
CREATE POLICY "No public access to rate limits"
|
|
ON public.contact_rate_limits
|
|
FOR ALL
|
|
USING (false); |