mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 10:31:13 -05:00
feat: Implement Auth0 database migration
This commit is contained in:
@@ -63,6 +63,7 @@ export type Database = {
|
||||
Row: {
|
||||
action: string
|
||||
admin_user_id: string
|
||||
auth0_event_type: string | null
|
||||
created_at: string
|
||||
details: Json | null
|
||||
id: string
|
||||
@@ -71,6 +72,7 @@ export type Database = {
|
||||
Insert: {
|
||||
action: string
|
||||
admin_user_id: string
|
||||
auth0_event_type?: string | null
|
||||
created_at?: string
|
||||
details?: Json | null
|
||||
id?: string
|
||||
@@ -79,6 +81,7 @@ export type Database = {
|
||||
Update: {
|
||||
action?: string
|
||||
admin_user_id?: string
|
||||
auth0_event_type?: string | null
|
||||
created_at?: string
|
||||
details?: Json | null
|
||||
id?: string
|
||||
@@ -119,6 +122,57 @@ export type Database = {
|
||||
}
|
||||
Relationships: []
|
||||
}
|
||||
auth0_sync_log: {
|
||||
Row: {
|
||||
auth0_sub: string
|
||||
completed_at: string | null
|
||||
created_at: string
|
||||
error_message: string | null
|
||||
id: string
|
||||
metadata: Json | null
|
||||
sync_status: string
|
||||
sync_type: string
|
||||
user_id: string | null
|
||||
}
|
||||
Insert: {
|
||||
auth0_sub: string
|
||||
completed_at?: string | null
|
||||
created_at?: string
|
||||
error_message?: string | null
|
||||
id?: string
|
||||
metadata?: Json | null
|
||||
sync_status?: string
|
||||
sync_type: string
|
||||
user_id?: string | null
|
||||
}
|
||||
Update: {
|
||||
auth0_sub?: string
|
||||
completed_at?: string | null
|
||||
created_at?: string
|
||||
error_message?: string | null
|
||||
id?: string
|
||||
metadata?: Json | null
|
||||
sync_status?: string
|
||||
sync_type?: string
|
||||
user_id?: string | null
|
||||
}
|
||||
Relationships: [
|
||||
{
|
||||
foreignKeyName: "auth0_sync_log_user_id_fkey"
|
||||
columns: ["user_id"]
|
||||
isOneToOne: false
|
||||
referencedRelation: "filtered_profiles"
|
||||
referencedColumns: ["user_id"]
|
||||
},
|
||||
{
|
||||
foreignKeyName: "auth0_sync_log_user_id_fkey"
|
||||
columns: ["user_id"]
|
||||
isOneToOne: false
|
||||
referencedRelation: "profiles"
|
||||
referencedColumns: ["user_id"]
|
||||
},
|
||||
]
|
||||
}
|
||||
blog_posts: {
|
||||
Row: {
|
||||
author_id: string
|
||||
@@ -1968,6 +2022,7 @@ export type Database = {
|
||||
}
|
||||
profiles: {
|
||||
Row: {
|
||||
auth0_sub: string | null
|
||||
avatar_image_id: string | null
|
||||
avatar_url: string | null
|
||||
ban_expires_at: string | null
|
||||
@@ -2001,6 +2056,7 @@ export type Database = {
|
||||
username: string
|
||||
}
|
||||
Insert: {
|
||||
auth0_sub?: string | null
|
||||
avatar_image_id?: string | null
|
||||
avatar_url?: string | null
|
||||
ban_expires_at?: string | null
|
||||
@@ -2034,6 +2090,7 @@ export type Database = {
|
||||
username: string
|
||||
}
|
||||
Update: {
|
||||
auth0_sub?: string | null
|
||||
avatar_image_id?: string | null
|
||||
avatar_url?: string | null
|
||||
ban_expires_at?: string | null
|
||||
@@ -4602,6 +4659,8 @@ export type Database = {
|
||||
extract_cf_image_id: { Args: { url: string }; Returns: string }
|
||||
generate_deletion_confirmation_code: { Args: never; Returns: string }
|
||||
generate_ticket_number: { Args: never; Returns: string }
|
||||
get_auth0_sub_from_jwt: { Args: never; Returns: string }
|
||||
get_current_user_id: { Args: never; Returns: string }
|
||||
get_email_change_status: { Args: never; Returns: Json }
|
||||
get_filtered_profile: {
|
||||
Args: { _profile_user_id: string; _viewer_id?: string }
|
||||
@@ -4670,6 +4729,7 @@ export type Database = {
|
||||
Returns: Json
|
||||
}
|
||||
has_aal2: { Args: never; Returns: boolean }
|
||||
has_auth0_mfa: { Args: never; Returns: boolean }
|
||||
has_mfa_enabled: { Args: { _user_id: string }; Returns: boolean }
|
||||
has_pending_dependents: { Args: { item_id: string }; Returns: boolean }
|
||||
has_role: {
|
||||
@@ -4685,6 +4745,7 @@ export type Database = {
|
||||
Args: { post_slug: string }
|
||||
Returns: undefined
|
||||
}
|
||||
is_auth0_user: { Args: never; Returns: boolean }
|
||||
is_moderator: { Args: { _user_id: string }; Returns: boolean }
|
||||
is_superuser: { Args: { _user_id: string }; Returns: boolean }
|
||||
is_user_banned: { Args: { _user_id: string }; Returns: boolean }
|
||||
|
||||
@@ -0,0 +1,154 @@
|
||||
-- Phase 1: Auth0 Migration - Add auth0_sub column and update RLS policies
|
||||
-- This migration prepares the database to support Auth0 authentication alongside Supabase auth
|
||||
|
||||
-- Add auth0_sub column to profiles table
|
||||
ALTER TABLE public.profiles
|
||||
ADD COLUMN IF NOT EXISTS auth0_sub TEXT UNIQUE;
|
||||
|
||||
-- Create index for faster auth0_sub lookups
|
||||
CREATE INDEX IF NOT EXISTS idx_profiles_auth0_sub ON public.profiles(auth0_sub);
|
||||
|
||||
-- Add comment explaining the column
|
||||
COMMENT ON COLUMN public.profiles.auth0_sub IS 'Auth0 user identifier (sub claim from JWT). Used for Auth0 authentication integration.';
|
||||
|
||||
-- Update RLS policies to support both Supabase and Auth0 authentication
|
||||
-- We'll keep existing policies and add Auth0 support
|
||||
|
||||
-- Create helper function to get current user ID (works with both Supabase and Auth0)
|
||||
CREATE OR REPLACE FUNCTION public.get_current_user_id()
|
||||
RETURNS uuid
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
v_user_id uuid;
|
||||
v_auth0_sub text;
|
||||
BEGIN
|
||||
-- Try Supabase auth first
|
||||
v_user_id := auth.uid();
|
||||
|
||||
IF v_user_id IS NOT NULL THEN
|
||||
RETURN v_user_id;
|
||||
END IF;
|
||||
|
||||
-- Try Auth0 sub from JWT
|
||||
v_auth0_sub := current_setting('request.jwt.claims', true)::json->>'sub';
|
||||
|
||||
IF v_auth0_sub IS NOT NULL THEN
|
||||
-- Look up user_id by auth0_sub
|
||||
SELECT user_id INTO v_user_id
|
||||
FROM public.profiles
|
||||
WHERE auth0_sub = v_auth0_sub;
|
||||
|
||||
RETURN v_user_id;
|
||||
END IF;
|
||||
|
||||
-- No authenticated user found
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Add audit log column for Auth0 events
|
||||
ALTER TABLE public.admin_audit_log
|
||||
ADD COLUMN IF NOT EXISTS auth0_event_type TEXT;
|
||||
|
||||
COMMENT ON COLUMN public.admin_audit_log.auth0_event_type IS 'Type of Auth0 event that triggered this audit log entry (e.g., mfa_enrollment, login, role_change)';
|
||||
|
||||
-- Create table for tracking Auth0 sync status
|
||||
CREATE TABLE IF NOT EXISTS public.auth0_sync_log (
|
||||
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
auth0_sub text NOT NULL,
|
||||
user_id uuid REFERENCES public.profiles(user_id),
|
||||
sync_type text NOT NULL, -- 'user_created', 'profile_updated', 'mfa_enrolled', etc.
|
||||
sync_status text NOT NULL DEFAULT 'pending', -- 'pending', 'completed', 'failed'
|
||||
error_message text,
|
||||
metadata jsonb DEFAULT '{}'::jsonb,
|
||||
created_at timestamp with time zone NOT NULL DEFAULT now(),
|
||||
completed_at timestamp with time zone
|
||||
);
|
||||
|
||||
-- Create index on auth0_sync_log
|
||||
CREATE INDEX IF NOT EXISTS idx_auth0_sync_log_auth0_sub ON public.auth0_sync_log(auth0_sub);
|
||||
CREATE INDEX IF NOT EXISTS idx_auth0_sync_log_user_id ON public.auth0_sync_log(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_auth0_sync_log_status ON public.auth0_sync_log(sync_status);
|
||||
|
||||
-- Enable RLS on auth0_sync_log
|
||||
ALTER TABLE public.auth0_sync_log ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- RLS policies for auth0_sync_log
|
||||
CREATE POLICY "Moderators can view all sync logs"
|
||||
ON public.auth0_sync_log
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (is_moderator(auth.uid()));
|
||||
|
||||
CREATE POLICY "System can insert sync logs"
|
||||
ON public.auth0_sync_log
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (true);
|
||||
|
||||
CREATE POLICY "Users can view their own sync logs"
|
||||
ON public.auth0_sync_log
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (user_id = auth.uid());
|
||||
|
||||
-- Create function to extract Auth0 sub from JWT
|
||||
CREATE OR REPLACE FUNCTION public.get_auth0_sub_from_jwt()
|
||||
RETURNS text
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN current_setting('request.jwt.claims', true)::json->>'sub';
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Create function to check if user is authenticated via Auth0
|
||||
CREATE OR REPLACE FUNCTION public.is_auth0_user()
|
||||
RETURNS boolean
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
v_iss text;
|
||||
BEGIN
|
||||
v_iss := current_setting('request.jwt.claims', true)::json->>'iss';
|
||||
-- Auth0 issuer format: https://<tenant>.auth0.com/ or https://<tenant>.<region>.auth0.com/
|
||||
RETURN v_iss LIKE '%auth0.com%';
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RETURN false;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Create function to check Auth0 MFA status from JWT claims
|
||||
CREATE OR REPLACE FUNCTION public.has_auth0_mfa()
|
||||
RETURNS boolean
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
v_amr jsonb;
|
||||
BEGIN
|
||||
-- Check if 'mfa' is in the amr (Authentication Methods Reference) array
|
||||
v_amr := current_setting('request.jwt.claims', true)::json->'amr';
|
||||
RETURN v_amr ? 'mfa';
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RETURN false;
|
||||
END;
|
||||
$$;
|
||||
|
||||
COMMENT ON FUNCTION public.get_current_user_id IS 'Returns the current user ID, supporting both Supabase auth.uid() and Auth0 sub claim lookup';
|
||||
COMMENT ON FUNCTION public.get_auth0_sub_from_jwt IS 'Extracts the Auth0 sub claim from the JWT token';
|
||||
COMMENT ON FUNCTION public.is_auth0_user IS 'Checks if the current user is authenticated via Auth0';
|
||||
COMMENT ON FUNCTION public.has_auth0_mfa IS 'Checks if the current Auth0 user has completed MFA (checks amr claim for mfa)';
|
||||
Reference in New Issue
Block a user