mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 06:51:12 -05:00
150 lines
5.6 KiB
SQL
150 lines
5.6 KiB
SQL
-- Fix: User Personal Information Could Be Stolen by Anyone
|
|
-- Create a secure view that enforces field-level privacy using get_filtered_profile function
|
|
|
|
-- Step 1: Create a secure view that uses get_filtered_profile for field-level privacy
|
|
CREATE OR REPLACE VIEW public.filtered_profiles
|
|
WITH (security_invoker = true)
|
|
AS
|
|
SELECT
|
|
p.id,
|
|
p.user_id,
|
|
p.username,
|
|
p.display_name,
|
|
p.privacy_level,
|
|
p.created_at,
|
|
p.updated_at,
|
|
-- Conditionally include sensitive fields based on privacy settings
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'bio'
|
|
) THEN p.bio ELSE NULL END as bio,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'avatar_url'
|
|
) THEN p.avatar_url ELSE NULL END as avatar_url,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'avatar_image_id'
|
|
) THEN p.avatar_image_id ELSE NULL END as avatar_image_id,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'preferred_pronouns'
|
|
) THEN p.preferred_pronouns ELSE NULL END as preferred_pronouns,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'preferred_pronouns'
|
|
) THEN p.show_pronouns ELSE false END as show_pronouns,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'personal_location'
|
|
) THEN p.personal_location ELSE NULL END as personal_location,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'location_id'
|
|
) THEN p.location_id ELSE NULL END as location_id,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'home_park_id'
|
|
) THEN p.home_park_id ELSE NULL END as home_park_id,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'date_of_birth'
|
|
) THEN p.date_of_birth ELSE NULL END as date_of_birth,
|
|
|
|
-- Always include safe metadata fields
|
|
p.timezone,
|
|
p.preferred_language,
|
|
p.theme_preference,
|
|
|
|
-- Include activity stats based on privacy settings
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'ride_count'
|
|
) THEN p.ride_count ELSE 0 END as ride_count,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'ride_count'
|
|
) THEN p.coaster_count ELSE 0 END as coaster_count,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'ride_count'
|
|
) THEN p.park_count ELSE 0 END as park_count,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'ride_count'
|
|
) THEN p.review_count ELSE 0 END as review_count,
|
|
|
|
CASE WHEN can_view_profile_field(
|
|
COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid),
|
|
p.user_id,
|
|
'ride_count'
|
|
) THEN p.reputation_score ELSE 0 END as reputation_score,
|
|
|
|
-- Never expose banned status except to moderators and the user themselves
|
|
CASE WHEN (auth.uid() = p.user_id OR is_moderator(COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid)))
|
|
THEN p.banned ELSE false END as banned
|
|
FROM public.profiles p
|
|
WHERE
|
|
-- Only show non-banned profiles to non-moderators
|
|
(NOT p.banned OR auth.uid() = p.user_id OR is_moderator(COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid)))
|
|
AND
|
|
-- Only show public or own profiles
|
|
(p.privacy_level = 'public' OR auth.uid() = p.user_id OR is_moderator(COALESCE(auth.uid(), '00000000-0000-0000-0000-000000000000'::uuid)));
|
|
|
|
-- Add comment explaining the view
|
|
COMMENT ON VIEW public.filtered_profiles IS
|
|
'Secure view that enforces field-level privacy for profile data. Uses can_view_profile_field function to filter sensitive fields based on user privacy settings. This view should be used for all profile queries where the viewer may not have full access rights.';
|
|
|
|
-- Grant access to the view
|
|
GRANT SELECT ON public.filtered_profiles TO authenticated;
|
|
GRANT SELECT ON public.filtered_profiles TO anon;
|
|
GRANT SELECT ON public.filtered_profiles TO service_role;
|
|
|
|
-- Step 2: Tighten the base profiles table RLS policies
|
|
-- Drop the overly permissive "Authenticated users can view public profiles" policy
|
|
DROP POLICY IF EXISTS "Authenticated users can view public profiles" ON public.profiles;
|
|
|
|
-- Create a more restrictive policy: users can only view their own full profile via direct table access
|
|
-- Other users should use the filtered_profiles view
|
|
CREATE POLICY "Users view own profile or use filtered view"
|
|
ON public.profiles
|
|
FOR SELECT
|
|
TO authenticated
|
|
USING (
|
|
-- Users can see their own complete profile
|
|
auth.uid() = user_id
|
|
-- Moderators can see all profiles for moderation purposes
|
|
OR is_moderator(auth.uid())
|
|
);
|
|
|
|
-- Keep the existing policies for users viewing their own profiles
|
|
-- The "Users can view their own complete profile" policy may be redundant now, but we'll keep it for clarity
|
|
|
|
-- Step 3: Add helpful documentation
|
|
COMMENT ON TABLE public.profiles IS
|
|
'User profiles table. Direct SELECT access is restricted - use the filtered_profiles view for privacy-respecting queries when viewing other users'' profiles. Only profile owners and moderators have direct table access.';
|