Files
thrilltrack-explorer/supabase/migrations/20251014175811_23db320a-3fea-4b66-9a98-9e708bf4eb2e.sql
2025-10-14 18:00:59 +00:00

124 lines
4.1 KiB
PL/PgSQL

-- =====================================================
-- PRIORITY 1: Fix Function Security (Search Path)
-- =====================================================
-- Fix increment_blog_view_count missing search_path
DROP FUNCTION IF EXISTS public.increment_blog_view_count(text);
CREATE OR REPLACE FUNCTION public.increment_blog_view_count(post_slug text)
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
BEGIN
UPDATE blog_posts
SET view_count = view_count + 1
WHERE slug = post_slug;
END;
$$;
-- =====================================================
-- PRIORITY 2: Backend Username Validation
-- =====================================================
-- Add CHECK constraint for username format
ALTER TABLE public.profiles
DROP CONSTRAINT IF EXISTS username_format_check;
ALTER TABLE public.profiles
ADD CONSTRAINT username_format_check
CHECK (
username ~ '^[a-z0-9]([a-z0-9_-]*[a-z0-9])?$'
AND length(username) >= 3
AND length(username) <= 30
AND username !~ '[-_]{2,}'
);
-- Create function to check forbidden usernames
CREATE OR REPLACE FUNCTION public.check_forbidden_username()
RETURNS TRIGGER
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
forbidden_list TEXT[] := ARRAY[
'admin', 'administrator', 'moderator', 'mod', 'owner', 'root', 'system', 'support',
'staff', 'team', 'official', 'verified', 'bot', 'api', 'service',
'thrillwiki', 'lovable', 'supabase', 'cloudflare',
'www', 'mail', 'email', 'ftp', 'blog', 'forum', 'shop', 'store', 'app', 'mobile',
'help', 'support', 'contact', 'about', 'terms', 'privacy', 'security', 'legal',
'login', 'signup', 'register', 'signin', 'signout', 'logout', 'auth', 'oauth',
'profile', 'profiles', 'user', 'users', 'account', 'accounts', 'settings',
'dashboard', 'console', 'panel', 'manage', 'management',
'null', 'undefined', 'true', 'false', 'delete', 'remove', 'test', 'demo',
'localhost', 'example', 'temp', 'temporary', 'guest', 'anonymous', 'anon',
'fuck', 'shit', 'damn', 'hell', 'ass', 'bitch', 'bastard', 'crap',
'nazi', 'hitler', 'stalin', 'terrorist', 'kill', 'death', 'murder',
'ceo', 'president', 'manager', 'director', 'executive', 'founder'
];
BEGIN
-- Usernames are already lowercased via Zod transform, but ensure it
NEW.username := lower(NEW.username);
IF NEW.username = ANY(forbidden_list) THEN
RAISE EXCEPTION 'Username "%" is not allowed', NEW.username
USING ERRCODE = '23514'; -- check_violation
END IF;
RETURN NEW;
END;
$$;
-- Create trigger for forbidden username check
DROP TRIGGER IF EXISTS enforce_username_rules ON public.profiles;
CREATE TRIGGER enforce_username_rules
BEFORE INSERT OR UPDATE OF username ON public.profiles
FOR EACH ROW
EXECUTE FUNCTION public.check_forbidden_username();
-- Add index for case-insensitive username lookups (if not exists)
CREATE INDEX IF NOT EXISTS profiles_username_lower_idx
ON public.profiles (lower(username));
-- =====================================================
-- PRIORITY 2.5: Add Display Name Content Filtering
-- =====================================================
-- Create function to check display name content
CREATE OR REPLACE FUNCTION public.check_display_name_content()
RETURNS TRIGGER
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
offensive_terms TEXT[] := ARRAY[
'nazi', 'hitler', 'terrorist', 'kill', 'murder', 'fuck', 'shit'
];
term TEXT;
BEGIN
-- Skip if display_name is null
IF NEW.display_name IS NULL THEN
RETURN NEW;
END IF;
-- Check for offensive terms in display name
FOREACH term IN ARRAY offensive_terms
LOOP
IF lower(NEW.display_name) LIKE '%' || term || '%' THEN
RAISE EXCEPTION 'Display name contains inappropriate content'
USING ERRCODE = '23514'; -- check_violation
END IF;
END LOOP;
RETURN NEW;
END;
$$;
-- Create trigger for display name check
DROP TRIGGER IF EXISTS enforce_display_name_rules ON public.profiles;
CREATE TRIGGER enforce_display_name_rules
BEFORE INSERT OR UPDATE OF display_name ON public.profiles
FOR EACH ROW
EXECUTE FUNCTION public.check_display_name_content();