-- Create account deletion status enum CREATE TYPE account_deletion_status AS ENUM ('pending', 'confirmed', 'cancelled', 'completed'); -- Create account deletion requests table CREATE TABLE account_deletion_requests ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, requested_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), scheduled_deletion_at TIMESTAMP WITH TIME ZONE NOT NULL, confirmation_code TEXT NOT NULL, confirmation_code_sent_at TIMESTAMP WITH TIME ZONE, status account_deletion_status NOT NULL DEFAULT 'pending', cancelled_at TIMESTAMP WITH TIME ZONE, completed_at TIMESTAMP WITH TIME ZONE, cancellation_reason TEXT, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() ); -- Add unique constraint for active deletions CREATE UNIQUE INDEX unique_active_deletion_per_user ON account_deletion_requests(user_id) WHERE status = 'pending'; -- Add index for scheduled deletions CREATE INDEX idx_account_deletions_scheduled ON account_deletion_requests(scheduled_deletion_at) WHERE status = 'pending'; -- Enable RLS ALTER TABLE account_deletion_requests ENABLE ROW LEVEL SECURITY; -- RLS Policies CREATE POLICY "Users can view their own deletion requests" ON account_deletion_requests FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Users can insert their own deletion requests" ON account_deletion_requests FOR INSERT WITH CHECK (auth.uid() = user_id); CREATE POLICY "Users can update their own deletion requests" ON account_deletion_requests FOR UPDATE USING (auth.uid() = user_id); CREATE POLICY "Admins can view all deletion requests" ON account_deletion_requests FOR SELECT USING (is_moderator(auth.uid())); -- Add deactivation columns to profiles ALTER TABLE profiles ADD COLUMN deactivated BOOLEAN NOT NULL DEFAULT false, ADD COLUMN deactivated_at TIMESTAMP WITH TIME ZONE, ADD COLUMN deactivation_reason TEXT; -- Index for deactivated profiles CREATE INDEX idx_profiles_deactivated ON profiles(deactivated) WHERE deactivated = true; -- Update profile RLS to hide deactivated profiles CREATE POLICY "Hide deactivated profiles from public" ON profiles FOR SELECT USING ( NOT deactivated OR auth.uid() = user_id OR is_moderator(auth.uid()) ); -- Helper function to generate confirmation code CREATE OR REPLACE FUNCTION generate_deletion_confirmation_code() RETURNS TEXT LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE code TEXT; BEGIN code := LPAD(FLOOR(RANDOM() * 1000000)::TEXT, 6, '0'); RETURN code; END; $$; -- Helper function to anonymize user data CREATE OR REPLACE FUNCTION anonymize_user_submissions(target_user_id UUID) RETURNS VOID LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ BEGIN -- Nullify user_id in content_submissions to preserve submissions UPDATE content_submissions SET user_id = NULL WHERE user_id = target_user_id; -- Nullify submitted_by in photos to preserve photos UPDATE photos SET submitted_by = NULL, photographer_credit = '[Deleted User]' WHERE submitted_by = target_user_id; END; $$; -- Add trigger for updated_at on account_deletion_requests CREATE TRIGGER update_account_deletion_requests_updated_at BEFORE UPDATE ON account_deletion_requests FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();