mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 06:51:12 -05:00
200 lines
5.3 KiB
PL/PgSQL
200 lines
5.3 KiB
PL/PgSQL
-- =====================================================
|
|
-- CRITICAL SECURITY FIXES - Priority 1 & 2
|
|
-- =====================================================
|
|
|
|
-- =====================================================
|
|
-- 1. PREVENT PRIVILEGE ESCALATION
|
|
-- =====================================================
|
|
|
|
-- Function to prevent unauthorized superuser role assignment
|
|
CREATE OR REPLACE FUNCTION public.prevent_superuser_escalation()
|
|
RETURNS TRIGGER
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
BEGIN
|
|
-- If trying to grant superuser role
|
|
IF NEW.role = 'superuser' THEN
|
|
-- Only existing superusers can grant superuser role
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM public.user_roles
|
|
WHERE user_id = auth.uid()
|
|
AND role = 'superuser'
|
|
) THEN
|
|
RAISE EXCEPTION 'Only superusers can grant the superuser role';
|
|
END IF;
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$;
|
|
|
|
-- Apply trigger to user_roles INSERT
|
|
DROP TRIGGER IF EXISTS enforce_superuser_escalation_prevention ON public.user_roles;
|
|
CREATE TRIGGER enforce_superuser_escalation_prevention
|
|
BEFORE INSERT ON public.user_roles
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.prevent_superuser_escalation();
|
|
|
|
-- Function to prevent unauthorized modification of superuser roles
|
|
CREATE OR REPLACE FUNCTION public.prevent_superuser_role_removal()
|
|
RETURNS TRIGGER
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
BEGIN
|
|
-- If trying to delete a superuser role
|
|
IF OLD.role = 'superuser' THEN
|
|
-- Only existing superusers can remove superuser roles
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM public.user_roles
|
|
WHERE user_id = auth.uid()
|
|
AND role = 'superuser'
|
|
) THEN
|
|
RAISE EXCEPTION 'Only superusers can remove the superuser role';
|
|
END IF;
|
|
END IF;
|
|
|
|
RETURN OLD;
|
|
END;
|
|
$$;
|
|
|
|
-- Apply trigger to user_roles DELETE
|
|
DROP TRIGGER IF EXISTS enforce_superuser_removal_prevention ON public.user_roles;
|
|
CREATE TRIGGER enforce_superuser_removal_prevention
|
|
BEFORE DELETE ON public.user_roles
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.prevent_superuser_role_removal();
|
|
|
|
-- Function to audit all role changes
|
|
CREATE OR REPLACE FUNCTION public.audit_role_changes()
|
|
RETURNS TRIGGER
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
BEGIN
|
|
IF TG_OP = 'INSERT' THEN
|
|
INSERT INTO public.admin_audit_log (
|
|
admin_user_id,
|
|
target_user_id,
|
|
action,
|
|
details
|
|
) VALUES (
|
|
auth.uid(),
|
|
NEW.user_id,
|
|
'role_granted',
|
|
jsonb_build_object(
|
|
'role', NEW.role,
|
|
'timestamp', now()
|
|
)
|
|
);
|
|
ELSIF TG_OP = 'DELETE' THEN
|
|
INSERT INTO public.admin_audit_log (
|
|
admin_user_id,
|
|
target_user_id,
|
|
action,
|
|
details
|
|
) VALUES (
|
|
auth.uid(),
|
|
OLD.user_id,
|
|
'role_revoked',
|
|
jsonb_build_object(
|
|
'role', OLD.role,
|
|
'timestamp', now()
|
|
)
|
|
);
|
|
END IF;
|
|
|
|
RETURN COALESCE(NEW, OLD);
|
|
END;
|
|
$$;
|
|
|
|
-- Apply trigger to user_roles
|
|
DROP TRIGGER IF EXISTS audit_role_changes_trigger ON public.user_roles;
|
|
CREATE TRIGGER audit_role_changes_trigger
|
|
AFTER INSERT OR DELETE ON public.user_roles
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.audit_role_changes();
|
|
|
|
-- =====================================================
|
|
-- 2. RESTRICT PUBLIC PROFILE ACCESS
|
|
-- =====================================================
|
|
|
|
-- Remove overly permissive policy
|
|
DROP POLICY IF EXISTS "Public can view basic profile info only" ON public.profiles;
|
|
|
|
-- New policy: Authenticated users can view profiles
|
|
CREATE POLICY "Authenticated users can view profiles"
|
|
ON public.profiles
|
|
FOR SELECT
|
|
TO authenticated
|
|
USING (
|
|
-- Users can view their own profile completely
|
|
(auth.uid() = user_id)
|
|
OR
|
|
-- Moderators can view all profiles
|
|
is_moderator(auth.uid())
|
|
OR
|
|
-- Others can only view public, non-banned profiles
|
|
(privacy_level = 'public' AND NOT banned)
|
|
);
|
|
|
|
-- =====================================================
|
|
-- 3. SESSION SECURITY ENHANCEMENTS
|
|
-- =====================================================
|
|
|
|
-- Function to hash IP addresses for privacy
|
|
CREATE OR REPLACE FUNCTION public.hash_ip_address(ip_text text)
|
|
RETURNS text
|
|
LANGUAGE plpgsql
|
|
IMMUTABLE
|
|
AS $$
|
|
BEGIN
|
|
-- Use SHA256 hash with salt
|
|
RETURN encode(
|
|
digest(ip_text || 'thrillwiki_ip_salt_2025', 'sha256'),
|
|
'hex'
|
|
);
|
|
END;
|
|
$$;
|
|
|
|
-- Add hashed IP column if not exists
|
|
ALTER TABLE public.user_sessions
|
|
ADD COLUMN IF NOT EXISTS ip_address_hash text;
|
|
|
|
-- Update existing records (hash current IPs)
|
|
UPDATE public.user_sessions
|
|
SET ip_address_hash = public.hash_ip_address(host(ip_address)::text)
|
|
WHERE ip_address IS NOT NULL AND ip_address_hash IS NULL;
|
|
|
|
-- Function to clean up expired sessions
|
|
CREATE OR REPLACE FUNCTION public.cleanup_expired_sessions()
|
|
RETURNS void
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
BEGIN
|
|
DELETE FROM public.user_sessions
|
|
WHERE expires_at < now();
|
|
END;
|
|
$$;
|
|
|
|
-- Allow users to delete their own sessions (for revocation)
|
|
DROP POLICY IF EXISTS "Users can delete their own sessions" ON public.user_sessions;
|
|
CREATE POLICY "Users can delete their own sessions"
|
|
ON public.user_sessions
|
|
FOR DELETE
|
|
TO authenticated
|
|
USING (auth.uid() = user_id);
|
|
|
|
-- Allow users to view their own sessions
|
|
DROP POLICY IF EXISTS "Users can view their own sessions" ON public.user_sessions;
|
|
CREATE POLICY "Users can view their own sessions"
|
|
ON public.user_sessions
|
|
FOR SELECT
|
|
TO authenticated
|
|
USING (auth.uid() = user_id); |