diff --git a/src/components/dashboard/UsageCard.vue b/src/components/dashboard/UsageCard.vue index 8556992df9..e5eb07caaa 100644 --- a/src/components/dashboard/UsageCard.vue +++ b/src/components/dashboard/UsageCard.vue @@ -10,7 +10,6 @@ import { generateDemoStorageData, getDemoDayCount, } from '~/services/demoChartData' -import { useDashboardAppsStore } from '~/stores/dashboardApps' import ChartCard from './ChartCard.vue' import LineChartStats from './LineChartStats.vue' @@ -33,7 +32,7 @@ const props = defineProps({ }, data: { type: Array, - default: () => Array.from({ length: getDaysInCurrentMonth() }).fill(undefined) as number[], + default: undefined, }, dataByApp: { type: Object, @@ -54,6 +53,25 @@ const props = defineProps({ }, }) +const dataArray = computed(() => { + if (!props.data || props.data.length === 0) { + return Array.from({ length: getDaysInCurrentMonth() }).fill(undefined) as (number | undefined)[] + } + return props.data as (number | undefined)[] +}) + +// Check if we have real data +const hasRealData = computed(() => { + const arr = dataArray.value ?? [] + // Has data if there's at least one defined, non-zero value + const hasDefinedData = arr.some(val => val !== undefined && val !== null && val > 0) + // Or has data by app with at least one defined value + const hasAppData = props.dataByApp && Object.values(props.dataByApp).some((appValues: any) => + appValues.some((val: any) => val !== undefined && val !== null && val > 0), + ) + return hasDefinedData || hasAppData +}) + // Get the appropriate data generator based on chart type function getDataGenerator(title: string) { const titleLower = title.toLowerCase() @@ -72,7 +90,7 @@ function getDataGenerator(title: string) { // Generate consistent demo data where total is derived from per-app breakdown // Use existing data length or default based on billing period mode const consistentDemoData = computed(() => { - const dataLength = (props.data as number[]).length + const dataLength = dataArray.value?.length ?? 0 const days = getDemoDayCount(props.useBillingPeriod, dataLength) const generator = getDataGenerator(props.title) return generateConsistentDemoData(days, generator) @@ -82,34 +100,24 @@ const consistentDemoData = computed(() => { const demoData = computed(() => consistentDemoData.value.total) const demoDataByApp = computed(() => consistentDemoData.value.byApp) -// Demo mode: show demo data only when forceDemo is true OR user has no apps -// If user has apps, ALWAYS show real data (even if empty) -const dashboardAppsStore = useDashboardAppsStore() -const isDemoMode = computed(() => { - if (props.forceDemo) - return true - // If user has apps, never show demo data - if (dashboardAppsStore.apps.length > 0) - return false - // No apps and store is loaded = show demo - return dashboardAppsStore.isLoaded -}) -const effectiveData = computed(() => isDemoMode.value ? demoData.value : props.data as number[]) +// Use real data or demo data +const isDemoMode = computed(() => props.forceDemo || (!hasRealData.value && !props.isLoading)) +const effectiveData = computed(() => isDemoMode.value ? demoData.value : dataArray.value) const effectiveDataByApp = computed(() => isDemoMode.value ? demoDataByApp.value : props.dataByApp) const effectiveAppNames = computed(() => isDemoMode.value ? DEMO_APP_NAMES : props.appNames) const total = computed(() => { - const dataArray = effectiveData.value - const hasData = dataArray.some(val => val !== undefined) - const sumValues = (values: number[]) => values.reduce((acc, val) => (typeof val === 'number' ? acc + val : acc), 0) + const arr = effectiveData.value + const hasData = arr.some(val => val !== undefined) + const sumValues = (values: (number | undefined)[]): number => values.reduce((acc, val) => (typeof val === 'number' ? acc + val : acc), 0) if (hasData) { - return sumValues(dataArray) + return sumValues(arr) } if (effectiveDataByApp.value && Object.keys(effectiveDataByApp.value).length > 0) { - return Object.values(effectiveDataByApp.value).reduce((totalSum, appValues: any) => { - return totalSum + sumValues(appValues) + return Object.values(effectiveDataByApp.value).reduce((totalSum: number, appValues: any) => { + return totalSum + sumValues(appValues as (number | undefined)[]) }, 0) } @@ -118,10 +126,10 @@ const total = computed(() => { const lastDayEvolution = computed(() => { if (isDemoMode.value) { - return calculateDemoEvolution(effectiveData.value) + return calculateDemoEvolution(effectiveData.value.filter((v): v is number => typeof v === 'number')) } - const arr = props.data as number[] + const arr = dataArray.value ?? [] const arrWithoutUndefined = arr.filter((val: any) => val !== undefined) if (arrWithoutUndefined.length < 2) { @@ -138,14 +146,9 @@ const lastDayEvolution = computed(() => { return ((lastValue - previousValue) / previousValue) * 100 }) -// Check if there's actual chart data (values in the array), not just a total -// This handles cases like Storage where total can be > 0 but no activity in current period const hasChartData = computed(() => { - if (isDemoMode.value) - return true - const dataArray = effectiveData.value - // Check if any value in the array is defined and > 0 - return dataArray.some(val => typeof val === 'number' && val > 0) + const arr = effectiveData.value + return arr.some(val => val !== undefined && val !== null && val > 0) }) diff --git a/supabase/functions/_backend/utils/postgres_schema.ts b/supabase/functions/_backend/utils/postgres_schema.ts index 0f400d8afe..21580de831 100644 --- a/supabase/functions/_backend/utils/postgres_schema.ts +++ b/supabase/functions/_backend/utils/postgres_schema.ts @@ -137,3 +137,53 @@ export const org_users = pgTable('org_users', { channel_id: bigint('channel_id', { mode: 'number' }), user_right: userMinRightPgEnum('user_right'), }) +export const org_saml_connections = pgTable('org_saml_connections', { + id: uuid('id').primaryKey().notNull(), + org_id: uuid('org_id').notNull(), + sso_provider_id: uuid('sso_provider_id').notNull().unique(), + provider_name: text('provider_name').notNull(), + metadata_url: text('metadata_url'), + metadata_xml: text('metadata_xml'), + entity_id: text('entity_id').notNull(), + current_certificate: text('current_certificate'), + certificate_expires_at: timestamp('certificate_expires_at', { withTimezone: true }), + certificate_last_checked: timestamp('certificate_last_checked', { withTimezone: true }).defaultNow(), + enabled: boolean('enabled').notNull().default(false), + verified: boolean('verified').notNull().default(false), + auto_join_enabled: boolean('auto_join_enabled').notNull().default(false), + attribute_mapping: text('attribute_mapping').default('{}'), + created_at: timestamp('created_at', { withTimezone: true }).notNull().defaultNow(), + updated_at: timestamp('updated_at', { withTimezone: true }).notNull().defaultNow(), + created_by: uuid('created_by'), +}) + +export const saml_domain_mappings = pgTable('saml_domain_mappings', { + id: uuid('id').primaryKey().notNull(), + domain: text('domain').notNull(), + org_id: uuid('org_id').notNull(), + sso_connection_id: uuid('sso_connection_id').notNull(), + priority: integer('priority').notNull().default(0), + verified: boolean('verified').notNull().default(true), + verification_code: text('verification_code'), + verified_at: timestamp('verified_at', { withTimezone: true }), + created_at: timestamp('created_at', { withTimezone: true }).notNull().defaultNow(), +}) + +export const sso_audit_logs = pgTable('sso_audit_logs', { + id: uuid('id').primaryKey().notNull(), + timestamp: timestamp('timestamp', { withTimezone: true }).notNull().defaultNow(), + user_id: uuid('user_id'), + email: text('email'), + event_type: text('event_type').notNull(), + org_id: uuid('org_id'), + sso_provider_id: uuid('sso_provider_id'), + sso_connection_id: uuid('sso_connection_id'), + ip_address: text('ip_address'), + user_agent: text('user_agent'), + country: text('country'), + saml_assertion_id: text('saml_assertion_id'), + saml_session_index: text('saml_session_index'), + error_code: text('error_code'), + error_message: text('error_message'), + metadata: text('metadata').default('{}'), +}) diff --git a/supabase/migrations/20260107210800_sso_saml_complete.sql b/supabase/migrations/20260107210800_sso_saml_complete.sql new file mode 100644 index 0000000000..a20b8e714b --- /dev/null +++ b/supabase/migrations/20260107210800_sso_saml_complete.sql @@ -0,0 +1,1106 @@ +-- ============================================================================ +-- CONSOLIDATED SSO SAML Migration +-- Replaces 12 incremental migrations (20251224022658 through 20260106000000) +-- ============================================================================ +-- This migration consolidates all SSO/SAML functionality including: +-- - SAML SSO configuration tables +-- - Domain-to-provider mappings +-- - Auto-enrollment logic with auto_join_enabled flag +-- - Comprehensive audit logging +-- - SSO provider lookup functions with all fixes applied +-- - Auto-join triggers with all domain/metadata checks +-- - Single SSO per organization enforcement +-- - RLS policies for security +-- ============================================================================ + +-- ============================================================================ +-- TABLE: org_saml_connections +-- Stores SAML SSO configuration per organization (ONE per org) +-- ============================================================================ +CREATE TABLE IF NOT EXISTS public.org_saml_connections ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + org_id uuid NOT NULL REFERENCES public.orgs(id) ON DELETE CASCADE, + +-- Supabase SSO Provider Info (from CLI output) +sso_provider_id uuid NOT NULL UNIQUE, +provider_name text NOT NULL, -- "Okta", "Azure AD", "Google Workspace", etc. + +-- SAML Configuration +metadata_url text, -- IdP metadata URL (preferred for auto-refresh) +metadata_xml text, -- Stored XML if URL not available +entity_id text NOT NULL, -- IdP's SAML EntityID + +-- Certificate Management (for rotation detection) +current_certificate text, +certificate_expires_at timestamptz, +certificate_last_checked timestamptz DEFAULT now(), + +-- Status Flags +enabled boolean NOT NULL DEFAULT false, +verified boolean NOT NULL DEFAULT false, +auto_join_enabled boolean NOT NULL DEFAULT false, -- Controls automatic enrollment + +-- Optional Attribute Mapping +-- Maps SAML attributes to user properties +-- Example: {"email": {"name": "mail"}, "first_name": {"name": "givenName"}} +attribute_mapping jsonb DEFAULT '{}'::jsonb, + +-- Audit Fields +created_at timestamptz NOT NULL DEFAULT now(), +updated_at timestamptz NOT NULL DEFAULT now(), +created_by uuid REFERENCES auth.users (id), + +-- Constraints +CONSTRAINT org_saml_connections_org_unique UNIQUE(org_id), + CONSTRAINT org_saml_connections_entity_id_unique UNIQUE(entity_id), + CONSTRAINT org_saml_connections_metadata_check CHECK ( + metadata_url IS NOT NULL OR metadata_xml IS NOT NULL + ) +); + +COMMENT ON +TABLE public.org_saml_connections IS 'Tracks SAML SSO configurations per organization (one per org)'; + +COMMENT ON COLUMN public.org_saml_connections.sso_provider_id IS 'UUID returned by Supabase CLI when adding SSO provider'; + +COMMENT ON COLUMN public.org_saml_connections.metadata_url IS 'IdP metadata URL for automatic refresh'; + +COMMENT ON COLUMN public.org_saml_connections.verified IS 'Whether SSO connection has been successfully tested'; + +COMMENT ON COLUMN public.org_saml_connections.auto_join_enabled IS 'Whether SSO-authenticated users are automatically enrolled in the organization'; + +COMMENT ON CONSTRAINT org_saml_connections_org_unique ON public.org_saml_connections IS 'Ensures each organization can only have one SSO configuration'; + +COMMENT ON CONSTRAINT org_saml_connections_entity_id_unique ON public.org_saml_connections IS 'Ensures each IdP entity ID can only be used by one organization'; + +-- ============================================================================ +-- TABLE: saml_domain_mappings +-- Maps email domains to SSO providers (supports multi-provider setups) +-- ============================================================================ +CREATE TABLE IF NOT EXISTS public.saml_domain_mappings ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + +-- Domain Configuration +domain text NOT NULL, +org_id uuid NOT NULL REFERENCES public.orgs (id) ON DELETE CASCADE, +sso_connection_id uuid NOT NULL REFERENCES public.org_saml_connections (id) ON DELETE CASCADE, + +-- Priority for multiple providers (higher = shown first) +priority int NOT NULL DEFAULT 0, + +-- Verification Status (future: DNS TXT validation if needed) +verified boolean NOT NULL DEFAULT true, -- Auto-verified via SSO by default +verification_code text, +verified_at timestamptz, + +-- Audit +created_at timestamptz NOT NULL DEFAULT now(), + +-- Constraints +CONSTRAINT saml_domain_mappings_domain_connection_unique UNIQUE(domain, sso_connection_id) +); + +COMMENT ON +TABLE public.saml_domain_mappings IS 'Maps email domains to SSO providers for auto-join'; + +COMMENT ON COLUMN public.saml_domain_mappings.priority IS 'Display order when multiple providers exist (higher first)'; + +-- ============================================================================ +-- TABLE: sso_audit_logs +-- Comprehensive audit trail for SSO authentication events +-- ============================================================================ +CREATE TABLE IF NOT EXISTS public.sso_audit_logs ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + timestamp timestamptz NOT NULL DEFAULT now(), + +-- User Identity +user_id uuid REFERENCES auth.users (id) ON DELETE SET NULL, +email text, + +-- Event Type +event_type text NOT NULL, +-- Possible values: 'login_success', 'login_failed', 'logout', 'session_expired', +-- 'config_created', 'config_updated', 'config_deleted', +-- 'provider_added', 'provider_removed', 'auto_join_success' + +-- Context +org_id uuid REFERENCES public.orgs (id) ON DELETE SET NULL, +sso_provider_id uuid, +sso_connection_id uuid REFERENCES public.org_saml_connections (id) ON DELETE SET NULL, + +-- Technical Details +ip_address inet, user_agent text, country text, + +-- SAML-Specific Fields +saml_assertion_id text, -- SAML assertion ID for tracing +saml_session_index text, -- Session identifier from IdP + +-- Error Details (for failed events) +error_code text, error_message text, + +-- Additional Metadata +metadata jsonb DEFAULT '{}'::jsonb ); + +COMMENT ON +TABLE public.sso_audit_logs IS 'Audit trail for all SSO authentication and configuration events'; + +COMMENT ON COLUMN public.sso_audit_logs.event_type IS 'Type of SSO event (login, logout, config change, etc.)'; + +-- ============================================================================ +-- INDEXES for Performance +-- ============================================================================ + +-- org_saml_connections indexes +CREATE INDEX IF NOT EXISTS idx_saml_connections_org_enabled ON public.org_saml_connections (org_id) +WHERE + enabled = true; + +CREATE INDEX IF NOT EXISTS idx_saml_connections_provider ON public.org_saml_connections (sso_provider_id); + +CREATE INDEX IF NOT EXISTS idx_saml_connections_cert_expiry ON public.org_saml_connections (certificate_expires_at) +WHERE + certificate_expires_at IS NOT NULL + AND enabled = true; + +-- saml_domain_mappings indexes +CREATE INDEX IF NOT EXISTS idx_saml_domains_domain_verified ON public.saml_domain_mappings (domain) +WHERE + verified = true; + +CREATE INDEX IF NOT EXISTS idx_saml_domains_connection ON public.saml_domain_mappings (sso_connection_id); + +CREATE INDEX IF NOT EXISTS idx_saml_domains_org ON public.saml_domain_mappings (org_id); + +-- sso_audit_logs indexes +CREATE INDEX IF NOT EXISTS idx_sso_audit_user_time ON public.sso_audit_logs (user_id, timestamp DESC) +WHERE + user_id IS NOT NULL; + +CREATE INDEX IF NOT EXISTS idx_sso_audit_org_time ON public.sso_audit_logs (org_id, timestamp DESC) +WHERE + org_id IS NOT NULL; + +CREATE INDEX IF NOT EXISTS idx_sso_audit_event_time ON public.sso_audit_logs (event_type, timestamp DESC); + +CREATE INDEX IF NOT EXISTS idx_sso_audit_provider ON public.sso_audit_logs ( + sso_provider_id, + timestamp DESC +) +WHERE + sso_provider_id IS NOT NULL; + +-- Failed login monitoring +CREATE INDEX IF NOT EXISTS idx_sso_audit_failures ON public.sso_audit_logs (ip_address, timestamp DESC) +WHERE + event_type = 'login_failed'; + +-- ============================================================================ +-- HELPER FUNCTIONS +-- ============================================================================ + +-- Helper function to check if domain requires SSO +CREATE OR REPLACE FUNCTION public.check_sso_required_for_domain(p_email text) +RETURNS boolean +LANGUAGE plpgsql +STABLE +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_domain text; + v_has_sso boolean; +BEGIN + v_domain := lower(split_part(p_email, '@', 2)); + + IF v_domain IS NULL OR LENGTH(v_domain) = 0 THEN + RETURN false; + END IF; + + SELECT EXISTS ( + SELECT 1 + FROM public.saml_domain_mappings sdm + JOIN public.org_saml_connections osc ON osc.id = sdm.sso_connection_id + WHERE sdm.domain = v_domain + AND sdm.verified = true + AND osc.enabled = true + ) INTO v_has_sso; + + RETURN v_has_sso; +END; +$$; + +COMMENT ON FUNCTION public.check_sso_required_for_domain IS 'Checks if an email domain has SSO configured and enabled'; + +-- Helper function to check if org has SSO configured +CREATE OR REPLACE FUNCTION public.check_org_sso_configured(p_org_id uuid) +RETURNS boolean +LANGUAGE plpgsql +STABLE +SECURITY DEFINER +SET search_path = public +AS $$ +BEGIN + RETURN EXISTS ( + SELECT 1 + FROM public.org_saml_connections + WHERE org_id = p_org_id + AND enabled = true + ); +END; +$$; + +COMMENT ON FUNCTION public.check_org_sso_configured IS 'Checks if an organization has SSO enabled'; + +-- Helper function to get SSO provider ID for a user +CREATE OR REPLACE FUNCTION public.get_sso_provider_id_for_user(p_user_id uuid) +RETURNS uuid +LANGUAGE plpgsql +STABLE +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_provider_id uuid; +BEGIN + SELECT (raw_app_meta_data->>'sso_provider_id')::uuid + INTO v_provider_id + FROM auth.users + WHERE id = p_user_id; + + IF v_provider_id IS NULL THEN + SELECT (raw_user_meta_data->>'sso_provider_id')::uuid + INTO v_provider_id + FROM auth.users + WHERE id = p_user_id; + END IF; + + RETURN v_provider_id; +END; +$$; + +COMMENT ON FUNCTION public.get_sso_provider_id_for_user IS 'Retrieves SSO provider ID from user metadata'; + +-- Helper function to check if org already has SSO configured +CREATE OR REPLACE FUNCTION public.org_has_sso_configured(p_org_id uuid) +RETURNS boolean +LANGUAGE plpgsql +STABLE +AS $$ +BEGIN + RETURN EXISTS ( + SELECT 1 + FROM public.org_saml_connections + WHERE org_id = p_org_id + ); +END; +$$; + +COMMENT ON FUNCTION public.org_has_sso_configured (uuid) IS 'Check if an organization already has SSO configured'; + +-- ============================================================================ +-- FUNCTIONS: SSO Provider Lookup (FINAL VERSION WITH ALL FIXES) +-- ============================================================================ + +-- Function to lookup SSO provider by email domain +CREATE OR REPLACE FUNCTION public.lookup_sso_provider_by_domain( + p_email text +) +RETURNS TABLE ( + provider_id uuid, + entity_id text, + org_id uuid, + org_name text, + provider_name text, + metadata_url text, + enabled boolean +) +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_domain text; +BEGIN + -- Extract domain from email + v_domain := lower(split_part(p_email, '@', 2)); + + IF v_domain IS NULL OR LENGTH(v_domain) = 0 THEN + RETURN; + END IF; + + -- Return all matching SSO providers ordered by priority + RETURN QUERY + SELECT + osc.sso_provider_id as provider_id, + osc.entity_id, + osc.org_id, + o.name as org_name, + osc.provider_name, + osc.metadata_url, + osc.enabled + FROM public.saml_domain_mappings sdm + JOIN public.org_saml_connections osc ON osc.id = sdm.sso_connection_id + JOIN public.orgs o ON o.id = osc.org_id + WHERE sdm.domain = v_domain + AND sdm.verified = true + AND osc.enabled = true + ORDER BY sdm.priority DESC, osc.created_at DESC; +END; +$$; + +COMMENT ON FUNCTION public.lookup_sso_provider_by_domain IS 'Finds SSO providers configured for an email domain'; + +-- Alternative lookup function that returns the sso_provider_id directly +CREATE OR REPLACE FUNCTION public.lookup_sso_provider_for_email(p_email text) +RETURNS uuid +LANGUAGE plpgsql +STABLE +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_domain text; + v_provider_id uuid; +BEGIN + v_domain := lower(split_part(p_email, '@', 2)); + + IF v_domain IS NULL OR LENGTH(v_domain) = 0 THEN + RETURN NULL; + END IF; + + SELECT osc.sso_provider_id + INTO v_provider_id + FROM public.saml_domain_mappings sdm + JOIN public.org_saml_connections osc ON osc.id = sdm.sso_connection_id + WHERE sdm.domain = v_domain + AND sdm.verified = true + AND osc.enabled = true + ORDER BY sdm.priority DESC, osc.created_at DESC + LIMIT 1; + + RETURN v_provider_id; +END; +$$; + +COMMENT ON FUNCTION public.lookup_sso_provider_for_email IS 'Returns the SSO provider ID for an email address if one exists'; + +-- ============================================================================ +-- FUNCTIONS: Auto-Enrollment (FINAL VERSION WITH auto_join_enabled CHECK) +-- ============================================================================ + +-- Function to auto-enroll SSO-authenticated user to their organization +-- Internal version for triggers (no auth check) +CREATE OR REPLACE FUNCTION internal_auto_enroll_sso_user( + p_user_id uuid, + p_email text, + p_sso_provider_id uuid +) +RETURNS TABLE ( + enrolled_org_id uuid, + org_name text +) +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_org record; + v_already_member boolean; +BEGIN + -- No auth.uid() check - this is an internal function for triggers + + -- Find organizations with this SSO provider that have auto-join enabled + FOR v_org IN + SELECT DISTINCT + osc.org_id, + o.name as org_name + FROM public.org_saml_connections osc + JOIN public.orgs o ON o.id = osc.org_id + WHERE osc.sso_provider_id = p_sso_provider_id + AND osc.enabled = true + AND osc.auto_join_enabled = true -- Only enroll if auto-join is enabled + LOOP + -- Check if already a member + SELECT EXISTS ( + SELECT 1 FROM public.org_users + WHERE user_id = p_user_id AND org_id = v_org.org_id + ) INTO v_already_member; + + IF NOT v_already_member THEN + -- Add user to organization with read permission + INSERT INTO public.org_users (user_id, org_id, user_right, created_at) + VALUES (p_user_id, v_org.org_id, 'read', now()); + + -- Log the auto-enrollment + INSERT INTO public.sso_audit_logs ( + user_id, + email, + event_type, + org_id, + sso_provider_id, + metadata + ) VALUES ( + p_user_id, + p_email, + 'auto_join_success', + v_org.org_id, + p_sso_provider_id, + jsonb_build_object( + 'enrollment_method', 'sso_auto_join', + 'timestamp', now() + ) + ); + + -- Return enrolled org + enrolled_org_id := v_org.org_id; + org_name := v_org.org_name; + RETURN NEXT; + END IF; + END LOOP; +END; +$$; + +COMMENT ON FUNCTION internal_auto_enroll_sso_user IS 'Internal function for triggers: Automatically enrolls SSO user to their organization ONLY if both SSO enabled AND auto_join_enabled = true'; + +-- Public version for user calls (with auth check) +CREATE OR REPLACE FUNCTION public.auto_enroll_sso_user( + p_user_id uuid, + p_email text, + p_sso_provider_id uuid +) +RETURNS TABLE ( + enrolled_org_id uuid, + org_name text +) +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_auth_email text; +BEGIN + -- Authorization: reject calls where p_user_id does not match the authenticated user + IF p_user_id != auth.uid() THEN + RAISE EXCEPTION 'Unauthorized: cannot enroll other users (user_id mismatch)'; + END IF; + + -- Email validation: ensure p_email matches the email in auth.users for p_user_id + SELECT email INTO v_auth_email FROM auth.users WHERE id = p_user_id; + IF v_auth_email IS NULL OR lower(v_auth_email) != lower(p_email) THEN + RAISE EXCEPTION 'Unauthorized: email mismatch for user'; + END IF; + + -- Call internal version to perform enrollment + RETURN QUERY SELECT * FROM internal_auto_enroll_sso_user(p_user_id, p_email, p_sso_provider_id); +END; +$$; + +COMMENT ON FUNCTION public.auto_enroll_sso_user IS 'Public function: Automatically enrolls SSO user to their organization ONLY if both SSO enabled AND auto_join_enabled = true'; + +-- Function to auto-join users by email using saml_domain_mappings +CREATE OR REPLACE FUNCTION public.auto_join_user_to_orgs_by_email( + p_user_id uuid, + p_email text, + p_sso_provider_id uuid DEFAULT NULL +) +RETURNS void +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_domain text; + v_org record; + v_auth_email text; +BEGIN + -- Authorization: allow if user_id matches OR caller has service_role privileges + IF p_user_id != auth.uid() AND auth.jwt() ->> 'role' != 'service_role' THEN + RAISE EXCEPTION 'Unauthorized: cannot join other users to orgs (user_id mismatch)'; + END IF; + + -- Email validation: ensure p_email matches the email in auth.users for p_user_id + SELECT email INTO v_auth_email FROM auth.users WHERE id = p_user_id; + IF v_auth_email IS NULL OR lower(v_auth_email) != lower(p_email) THEN + RAISE EXCEPTION 'Unauthorized: email mismatch for user'; + END IF; + + v_domain := lower(split_part(p_email, '@', 2)); + + IF v_domain IS NULL OR LENGTH(v_domain) = 0 THEN + RETURN; + END IF; + + -- Priority 1: SSO provider-based enrollment (strongest binding) + IF p_sso_provider_id IS NOT NULL THEN + PERFORM internal_auto_enroll_sso_user(p_user_id, p_email, p_sso_provider_id); + RETURN; -- SSO enrollment takes precedence + END IF; + + -- Priority 2: SAML domain mappings based enrollment + -- Check saml_domain_mappings table for matching domains + FOR v_org IN + SELECT DISTINCT o.id, o.name + FROM public.orgs o + INNER JOIN public.saml_domain_mappings sdm ON sdm.org_id = o.id + INNER JOIN public.org_saml_connections osc ON osc.id = sdm.sso_connection_id + WHERE sdm.domain = v_domain + AND sdm.verified = true + AND osc.auto_join_enabled = true + AND NOT EXISTS ( + SELECT 1 FROM public.org_users ou + WHERE ou.user_id = p_user_id AND ou.org_id = o.id + ) + LOOP + -- Add user to org with read permission + -- Use conditional INSERT to avoid conflicts + INSERT INTO public.org_users (user_id, org_id, user_right, created_at) + SELECT p_user_id, v_org.id, 'read', now() + WHERE NOT EXISTS ( + SELECT 1 FROM public.org_users ou + WHERE ou.user_id = p_user_id AND ou.org_id = v_org.id + ); + + -- Log domain-based auto-join + INSERT INTO public.sso_audit_logs ( + user_id, + email, + event_type, + org_id, + metadata + ) VALUES ( + p_user_id, + p_email, + 'auto_join_success', + v_org.id, + jsonb_build_object( + 'enrollment_method', 'saml_domain_mapping', + 'domain', v_domain + ) + ); + END LOOP; +END; +$$; + +COMMENT ON FUNCTION public.auto_join_user_to_orgs_by_email IS 'Auto-enrolls users via SSO provider or SAML domain mappings. Does not use allowed_email_domains column.'; + +-- ============================================================================ +-- TRIGGER FUNCTIONS: Auto-Join Logic (FINAL VERSION WITH ALL FIXES) +-- ============================================================================ + +-- Trigger function for user creation (called on INSERT to auth.users) +CREATE OR REPLACE FUNCTION public.trigger_auto_join_on_user_create() +RETURNS TRIGGER +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_email text; + v_sso_provider_id uuid; +BEGIN + v_email := COALESCE(NEW.raw_user_meta_data->>'email', NEW.email); + + IF v_email IS NULL THEN + RETURN NEW; + END IF; + + -- Extract SSO provider ID from metadata + v_sso_provider_id := public.get_sso_provider_id_for_user(NEW.id); + + -- If no SSO provider, try looking it up by domain + IF v_sso_provider_id IS NULL THEN + v_sso_provider_id := public.lookup_sso_provider_for_email(v_email); + END IF; + + -- Perform auto-join with the provider ID (if found) + PERFORM public.auto_join_user_to_orgs_by_email(NEW.id, v_email, v_sso_provider_id); + + RETURN NEW; +END; +$$; + +COMMENT ON FUNCTION public.trigger_auto_join_on_user_create IS 'Auto-enrolls new users on account creation'; + +-- Trigger function for user update (called on UPDATE to auth.users) +CREATE OR REPLACE FUNCTION public.trigger_auto_join_on_user_update() +RETURNS TRIGGER +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_email text; + v_sso_provider_id uuid; + v_already_enrolled boolean; +BEGIN + -- Only process if email confirmation changed or SSO metadata added + IF OLD.email_confirmed_at IS NOT DISTINCT FROM NEW.email_confirmed_at + AND OLD.raw_app_meta_data IS NOT DISTINCT FROM NEW.raw_app_meta_data + AND OLD.raw_user_meta_data IS NOT DISTINCT FROM NEW.raw_user_meta_data THEN + RETURN NEW; + END IF; + + v_email := COALESCE(NEW.raw_user_meta_data->>'email', NEW.email); + + IF v_email IS NULL THEN + RETURN NEW; + END IF; + + -- Get SSO provider ID from user metadata + v_sso_provider_id := public.get_sso_provider_id_for_user(NEW.id); + + -- Only proceed with SSO auto-join if provider ID exists + IF v_sso_provider_id IS NOT NULL THEN + -- Check if user is already enrolled in an org with this SSO provider + SELECT EXISTS ( + SELECT 1 + FROM public.org_users ou + JOIN public.org_saml_connections osc ON osc.org_id = ou.org_id + WHERE ou.user_id = NEW.id + AND osc.sso_provider_id = v_sso_provider_id + ) INTO v_already_enrolled; + + -- Only auto-enroll if not already in an org with this SSO provider + IF NOT v_already_enrolled THEN + PERFORM public.auto_join_user_to_orgs_by_email(NEW.id, v_email, v_sso_provider_id); + END IF; + END IF; + + RETURN NEW; +END; +$$; + +COMMENT ON FUNCTION public.trigger_auto_join_on_user_update IS 'Auto-enrolls existing users when they log in with SSO'; + +-- ============================================================================ +-- TRIGGER FUNCTION: Enforce SSO for Domains (FINAL VERSION WITH METADATA BYPASS) +-- ============================================================================ + +-- Function to enforce SSO for configured domains (with metadata bypass) +CREATE OR REPLACE FUNCTION public.enforce_sso_for_domains() +RETURNS TRIGGER +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_email text; + v_domain text; + v_sso_required boolean; + v_metadata_provider_id uuid; + v_metadata_allows boolean := false; +BEGIN + IF TG_OP != 'INSERT' THEN + RETURN NEW; + END IF; + + v_email := COALESCE( + NEW.raw_user_meta_data->>'email', + NEW.email + ); + + IF v_email IS NULL THEN + RETURN NEW; + END IF; + + v_domain := lower(split_part(v_email, '@', 2)); + + -- Try to read the SSO provider ID that a trusted SSO flow would set on the + -- user row. If present and it matches the verified domain entry, allow the + -- insert to proceed before blocking emails. + BEGIN + v_metadata_provider_id := NULLIF(NEW.raw_user_meta_data->>'sso_provider_id', '')::uuid; + EXCEPTION WHEN invalid_text_representation THEN + v_metadata_provider_id := NULL; + END; + + IF v_metadata_provider_id IS NULL THEN + BEGIN + v_metadata_provider_id := NULLIF(NEW.raw_app_meta_data->>'sso_provider_id', '')::uuid; + EXCEPTION WHEN invalid_text_representation THEN + v_metadata_provider_id := NULL; + END; + END IF; + + IF v_metadata_provider_id IS NOT NULL THEN + SELECT EXISTS ( + SELECT 1 + FROM public.saml_domain_mappings sdm + JOIN public.org_saml_connections osc ON osc.id = sdm.sso_connection_id + WHERE sdm.domain = v_domain + AND sdm.verified = true + AND osc.enabled = true + AND osc.sso_provider_id = v_metadata_provider_id + ) INTO v_metadata_allows; + + IF v_metadata_allows THEN + RETURN NEW; + END IF; + END IF; + + -- NOTE: Cannot check auth.identities here - identity records are created AFTER user insert + -- in AFTER INSERT triggers, so NEW.id does not yet exist in auth.identities table. + -- We rely exclusively on the metadata-based validation above (sso_provider_id in raw_user_meta_data). + + -- Check if domain requires SSO + v_sso_required := public.check_sso_required_for_domain(v_email); + + IF v_sso_required THEN + RAISE EXCEPTION 'SSO authentication required for this email domain. Please use "Sign in with SSO" instead.' + USING ERRCODE = 'CAPCR', + HINT = 'Your organization requires SSO authentication'; + END IF; + + RETURN NEW; +END; +$$; + +COMMENT ON FUNCTION public.enforce_sso_for_domains IS 'Trigger function to enforce SSO for configured email domains'; + +-- ============================================================================ +-- TRIGGER FUNCTION: Validation and Audit +-- ============================================================================ + +-- Validation trigger for SSO configuration +CREATE OR REPLACE FUNCTION public.validate_sso_configuration() +RETURNS TRIGGER +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public, pg_temp +AS $$ +BEGIN + -- Validate metadata exists + IF NEW.metadata_url IS NULL AND NEW.metadata_xml IS NULL THEN + RAISE EXCEPTION 'Either metadata_url or metadata_xml must be provided'; + END IF; + + -- Validate entity_id format + IF NEW.entity_id IS NULL OR LENGTH(NEW.entity_id) = 0 THEN + RAISE EXCEPTION 'entity_id is required'; + END IF; + + -- Update timestamp + NEW.updated_at := now(); + + -- Log configuration change + IF TG_OP = 'INSERT' THEN + INSERT INTO public.sso_audit_logs ( + event_type, + org_id, + sso_provider_id, + metadata + ) VALUES ( + 'config_created', + NEW.org_id, + NEW.sso_provider_id, + jsonb_build_object( + 'provider_name', NEW.provider_name, + 'entity_id', NEW.entity_id, + 'created_by', NEW.created_by + ) + ); + ELSIF TG_OP = 'UPDATE' THEN + INSERT INTO public.sso_audit_logs ( + event_type, + org_id, + sso_provider_id, + metadata + ) VALUES ( + 'config_updated', + NEW.org_id, + NEW.sso_provider_id, + jsonb_build_object( + 'provider_name', NEW.provider_name, + 'changes', jsonb_build_object( + 'enabled', jsonb_build_object('old', OLD.enabled, 'new', NEW.enabled), + 'verified', jsonb_build_object('old', OLD.verified, 'new', NEW.verified) + ) + ) + ); + END IF; + + RETURN NEW; +END; +$$; + +COMMENT ON FUNCTION public.validate_sso_configuration IS 'Validates SSO configuration and logs changes'; + +-- ============================================================================ +-- TRIGGERS: Create All Triggers +-- ============================================================================ + +-- Drop existing triggers to ensure clean state +DROP TRIGGER IF EXISTS auto_join_user_to_orgs_on_create ON auth.users; + +DROP TRIGGER IF EXISTS auto_join_user_to_orgs_on_update ON auth.users; + +DROP TRIGGER IF EXISTS sso_user_auto_enroll_on_create ON auth.users; + +DROP TRIGGER IF EXISTS check_sso_domain_on_signup_trigger ON auth.users; + +DROP TRIGGER IF EXISTS trigger_validate_sso_configuration ON public.org_saml_connections; + +-- Create auto-join trigger for user creation +CREATE TRIGGER auto_join_user_to_orgs_on_create + AFTER INSERT ON auth.users + FOR EACH ROW + EXECUTE FUNCTION public.trigger_auto_join_on_user_create(); + +-- Create auto-join trigger for user updates +CREATE TRIGGER auto_join_user_to_orgs_on_update + AFTER UPDATE ON auth.users + FOR EACH ROW + EXECUTE FUNCTION public.trigger_auto_join_on_user_update(); + +-- Create SSO domain enforcement trigger +CREATE TRIGGER check_sso_domain_on_signup_trigger + BEFORE INSERT ON auth.users + FOR EACH ROW + EXECUTE FUNCTION public.enforce_sso_for_domains(); + +-- Create SSO configuration validation trigger +CREATE TRIGGER trigger_validate_sso_configuration + BEFORE INSERT OR UPDATE ON public.org_saml_connections + FOR EACH ROW + EXECUTE FUNCTION public.validate_sso_configuration(); + +COMMENT ON TRIGGER trigger_validate_sso_configuration ON public.org_saml_connections IS 'Validates SSO config and logs changes'; + +-- ============================================================================ +-- ROW LEVEL SECURITY (RLS) POLICIES +-- ============================================================================ + +-- Enable RLS on all tables +ALTER TABLE public.org_saml_connections ENABLE ROW LEVEL SECURITY; + +ALTER TABLE public.saml_domain_mappings ENABLE ROW LEVEL SECURITY; + +ALTER TABLE public.sso_audit_logs ENABLE ROW LEVEL SECURITY; + +-- Drop all existing policies first (idempotent) +DROP POLICY IF EXISTS "Super admins can manage SSO connections" ON public.org_saml_connections; + +DROP POLICY IF EXISTS "Org members can read SSO status" ON public.org_saml_connections; + +DROP POLICY IF EXISTS "Anyone can read verified domain mappings" ON public.saml_domain_mappings; + +DROP POLICY IF EXISTS "Super admins can manage domain mappings" ON public.saml_domain_mappings; + +DROP POLICY IF EXISTS "Users can view own SSO audit logs" ON public.sso_audit_logs; + +DROP POLICY IF EXISTS "Org admins can view org SSO audit logs" ON public.sso_audit_logs; + +DROP POLICY IF EXISTS "System can insert audit logs" ON public.sso_audit_logs; + +-- ============================================================================ +-- RLS POLICIES: org_saml_connections +-- ============================================================================ + +-- Super admins can manage SSO connections +CREATE POLICY "Super admins can manage SSO connections" + ON public.org_saml_connections + FOR ALL + TO authenticated + USING ( + public.check_min_rights( + 'super_admin'::public.user_min_right, + public.get_identity_org_allowed('{all,write}'::public.key_mode[], org_id), + org_id, + NULL::character varying, + NULL::bigint + ) + ) + WITH CHECK ( + public.check_min_rights( + 'super_admin'::public.user_min_right, + public.get_identity_org_allowed('{all,write}'::public.key_mode[], org_id), + org_id, + NULL::character varying, + NULL::bigint + ) + ); + +-- Org members can read their org's SSO status (for UI display) +CREATE POLICY "Org members can read SSO status" + ON public.org_saml_connections + FOR SELECT + TO authenticated + USING ( + public.check_min_rights( + 'read'::public.user_min_right, + public.get_identity_org_allowed('{read,write,all}'::public.key_mode[], org_id), + org_id, + NULL::character varying, + NULL::bigint + ) + ); + +-- ============================================================================ +-- RLS POLICIES: saml_domain_mappings +-- ============================================================================ + +-- Anyone (including anon) can read verified domain mappings for SSO detection +CREATE POLICY "Anyone can read verified domain mappings" ON public.saml_domain_mappings FOR +SELECT TO authenticated, anon USING (verified = true); + +-- Super admins can manage domain mappings +CREATE POLICY "Super admins can manage domain mappings" + ON public.saml_domain_mappings + FOR ALL + TO authenticated + USING ( + EXISTS ( + SELECT 1 FROM public.org_saml_connections osc + WHERE osc.id = sso_connection_id + AND public.check_min_rights( + 'super_admin'::public.user_min_right, + public.get_identity_org_allowed('{all,write}'::public.key_mode[], osc.org_id), + osc.org_id, + NULL::character varying, + NULL::bigint + ) + ) + ) + WITH CHECK ( + EXISTS ( + SELECT 1 FROM public.org_saml_connections osc + WHERE osc.id = sso_connection_id + AND public.check_min_rights( + 'super_admin'::public.user_min_right, + public.get_identity_org_allowed('{all,write}'::public.key_mode[], osc.org_id), + osc.org_id, + NULL::character varying, + NULL::bigint + ) + ) + ); + +-- ============================================================================ +-- RLS POLICIES: sso_audit_logs +-- ============================================================================ + +-- Users can view their own audit logs +CREATE POLICY "Users can view own SSO audit logs" ON public.sso_audit_logs FOR +SELECT TO authenticated USING (user_id = auth.uid ()); + +-- Org admins can view org audit logs +CREATE POLICY "Org admins can view org SSO audit logs" + ON public.sso_audit_logs + FOR SELECT + TO authenticated + USING ( + org_id IS NOT NULL + AND public.check_min_rights( + 'admin'::public.user_min_right, + public.get_identity_org_allowed('{read,write,all}'::public.key_mode[], org_id), + org_id, + NULL::character varying, + NULL::bigint + ) + ); + +-- NOTE: No INSERT policy needed - SECURITY DEFINER functions bypass RLS +-- Removing overly permissive policy that allowed any authenticated user to insert audit logs + +-- ============================================================================ +-- GRANTS: Ensure proper permissions +-- ============================================================================ + +-- Grant usage on public schema +GRANT USAGE ON SCHEMA public TO authenticated, anon; + +-- Grant access to tables +GRANT SELECT ON public.org_saml_connections TO authenticated, anon; + +GRANT SELECT ON public.saml_domain_mappings TO authenticated, anon; + +GRANT SELECT ON public.sso_audit_logs TO authenticated; + +-- Grant INSERT on sso_audit_logs to postgres for SECURITY DEFINER trigger functions +GRANT INSERT ON public.sso_audit_logs TO postgres; + +-- Grant function execution to authenticated users and anon for SSO detection +GRANT EXECUTE ON FUNCTION public.check_sso_required_for_domain TO authenticated, anon; + +GRANT +EXECUTE ON FUNCTION public.check_org_sso_configured TO authenticated, +anon; + +GRANT +EXECUTE ON FUNCTION public.get_sso_provider_id_for_user TO authenticated; + +GRANT +EXECUTE ON FUNCTION public.org_has_sso_configured (uuid) TO authenticated; + +GRANT +EXECUTE ON FUNCTION public.lookup_sso_provider_by_domain TO authenticated, +anon; + +GRANT +EXECUTE ON FUNCTION public.lookup_sso_provider_for_email TO authenticated, +anon; + +GRANT +EXECUTE ON FUNCTION public.auto_enroll_sso_user TO authenticated; + +GRANT +EXECUTE ON FUNCTION public.auto_join_user_to_orgs_by_email TO authenticated; + +-- NOTE: Trigger functions should NOT be granted to authenticated - they are only called by DB triggers +-- Only postgres and supabase_auth_admin (trigger context) should have EXECUTE permissions + +-- Grant special permissions to auth admin for trigger functions +GRANT +EXECUTE ON FUNCTION public.get_sso_provider_id_for_user TO postgres, +supabase_auth_admin; + +GRANT +EXECUTE ON FUNCTION public.trigger_auto_join_on_user_create TO postgres, +supabase_auth_admin; + +GRANT +EXECUTE ON FUNCTION public.trigger_auto_join_on_user_update TO postgres, +supabase_auth_admin; + +-- ============================================================================ +-- FUNCTION: Cleanup old SSO audit logs (PII compliance) +-- ============================================================================ + +-- Function to cleanup old SSO audit logs for GDPR/CCPA compliance +-- Removes logs older than 90 days and anonymizes PII for deleted users +CREATE OR REPLACE FUNCTION public.cleanup_old_sso_audit_logs() +RETURNS void +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_deleted_count integer; + v_anonymized_count integer; +BEGIN + -- Delete audit logs older than 90 days (data retention policy) + DELETE FROM public.sso_audit_logs + WHERE timestamp < NOW() - INTERVAL '90 days'; + + GET DIAGNOSTICS v_deleted_count = ROW_COUNT; + + -- Anonymize email addresses for deleted users (user_id IS NULL but email still exists) + -- This handles the case where user was deleted but their email remains in audit logs + UPDATE public.sso_audit_logs + SET email = 'deleted-user-' || id::text || '@anonymized.local' + WHERE user_id IS NULL + AND email IS NOT NULL + AND email NOT LIKE 'deleted-user-%@anonymized.local'; + + GET DIAGNOSTICS v_anonymized_count = ROW_COUNT; + + RAISE NOTICE 'SSO audit log cleanup: deleted % old records, anonymized % emails for deleted users', + v_deleted_count, v_anonymized_count; +END; +$$; + +COMMENT ON FUNCTION public.cleanup_old_sso_audit_logs IS 'Cleans up SSO audit logs older than 90 days and anonymizes PII for deleted users. Run daily via cron for GDPR/CCPA compliance.'; + +-- Grant execute to service_role for cron job +GRANT +EXECUTE ON FUNCTION public.cleanup_old_sso_audit_logs TO service_role; \ No newline at end of file diff --git a/supabase/migrations/20260108052411_add_sso_audit_cleanup_cron.sql b/supabase/migrations/20260108052411_add_sso_audit_cleanup_cron.sql new file mode 100644 index 0000000000..688e249870 --- /dev/null +++ b/supabase/migrations/20260108052411_add_sso_audit_cleanup_cron.sql @@ -0,0 +1,6 @@ +-- Add SSO audit log cleanup to process_all_cron_tasks function for PII compliance +-- Runs daily at 3:00 AM UTC to delete logs older than 90 days and anonymize deleted users' emails +-- Per Capgo convention: do NOT add rows to cron_tasks table, only update process_all_cron_tasks() + +COMMENT ON +TABLE public.sso_audit_logs IS 'Audit trail for all SSO authentication and configuration events. Auto-cleanup: logs older than 90 days are deleted daily at 3 AM UTC. PII (email) is anonymized for deleted users.'; \ No newline at end of file diff --git a/supabase/migrations/20260108204828_add_sso_audit_cleanup_to_cron_processor.sql b/supabase/migrations/20260108204828_add_sso_audit_cleanup_to_cron_processor.sql new file mode 100644 index 0000000000..995aceb2f6 --- /dev/null +++ b/supabase/migrations/20260108204828_add_sso_audit_cleanup_to_cron_processor.sql @@ -0,0 +1,146 @@ +-- Update process_all_cron_tasks() to include SSO audit log cleanup +-- Runs daily at 3:00 AM UTC (hour == 3, minute < 5) to delete logs older than 90 days +-- Per Capgo convention: do NOT use cron_tasks table, embed logic in process_all_cron_tasks() + +CREATE OR REPLACE FUNCTION public.process_all_cron_tasks() RETURNS void +LANGUAGE plpgsql +SET search_path TO '' +AS $$ +DECLARE + current_hour int; + current_minute int; + current_second int; + current_dow int; + current_day int; + task RECORD; + queue_names text[]; + should_run boolean; + lock_acquired boolean; +BEGIN + -- Try to acquire an advisory lock (non-blocking) + -- Lock ID 1 is reserved for process_all_cron_tasks + -- pg_try_advisory_lock returns true if lock acquired, false if already held + lock_acquired := pg_try_advisory_lock(1); + + IF NOT lock_acquired THEN + -- Another instance is already running, skip this execution + RAISE NOTICE 'process_all_cron_tasks: skipped, another instance is already running'; + RETURN; + END IF; + + -- Wrap everything in a block so we can ensure the lock is released + BEGIN + -- Get current time components in UTC + current_hour := EXTRACT(HOUR FROM NOW()); + current_minute := EXTRACT(MINUTE FROM NOW()); + current_second := EXTRACT(SECOND FROM NOW()); + current_dow := EXTRACT(DOW FROM NOW()); + current_day := EXTRACT(DAY FROM NOW()); + + -- ========================================================================= + -- SSO Audit Log Cleanup (Daily at 3:00 AM UTC) + -- ========================================================================= + IF current_hour = 3 AND current_minute < 5 AND current_second < 10 THEN + BEGIN + PERFORM public.cleanup_old_sso_audit_logs(); + RAISE NOTICE 'SSO audit log cleanup completed successfully'; + EXCEPTION WHEN OTHERS THEN + RAISE WARNING 'SSO audit log cleanup failed: %', SQLERRM; + END; + END IF; + + -- ========================================================================= + -- Loop through all enabled cron_tasks + -- ========================================================================= + FOR task IN SELECT * FROM public.cron_tasks WHERE enabled = true LOOP + should_run := false; + + -- Check if task should run based on its schedule + IF task.second_interval IS NOT NULL THEN + -- Run every N seconds + -- Since pg_cron interval is not clock-aligned, we run on every invocation + -- for second_interval tasks (the cron job itself runs every 10 seconds) + should_run := true; + ELSIF task.minute_interval IS NOT NULL THEN + -- Run every N minutes + -- Use current_second < 10 to catch first run of each minute (works with any cron offset) + should_run := (current_minute % task.minute_interval = 0) + AND (current_second < 10); + ELSIF task.hour_interval IS NOT NULL THEN + -- Run every N hours at specific minute + -- Use current_second < 10 to catch first run + should_run := (current_hour % task.hour_interval = 0) + AND (current_minute = COALESCE(task.run_at_minute, 0)) + AND (current_second < 10); + ELSIF task.run_at_hour IS NOT NULL THEN + -- Run at specific time + -- Use current_second < 10 to catch first run + should_run := (current_hour = task.run_at_hour) + AND (current_minute = COALESCE(task.run_at_minute, 0)) + AND (current_second < 10); + + -- Check day of week constraint + IF should_run AND task.run_on_dow IS NOT NULL THEN + should_run := (current_dow = task.run_on_dow); + END IF; + + -- Check day of month constraint + IF should_run AND task.run_on_day IS NOT NULL THEN + should_run := (current_day = task.run_on_day); + END IF; + END IF; + + -- Execute the task if it should run + IF should_run THEN + BEGIN + CASE task.task_type + WHEN 'function' THEN + -- Whitelist allowed functions for security + IF task.target IN ( + 'public.cleanup_old_sso_audit_logs', + 'public.cleanup_queue_messages', + 'public.cleanup_old_audit_logs', + 'public.process_stats_queue', + 'public.send_stats_email' + ) THEN + EXECUTE 'SELECT ' || task.target; + ELSE + RAISE WARNING 'Unknown or unauthorized function: %', task.target; + END IF; + + WHEN 'queue' THEN + PERFORM pgmq.send( + task.target, + COALESCE(task.payload, jsonb_build_object('function_name', task.target)) + ); + + WHEN 'function_queue' THEN + -- Parse JSON array of queue names + SELECT array_agg(value::text) INTO queue_names + FROM jsonb_array_elements_text(task.target::jsonb); + + IF task.batch_size IS NOT NULL THEN + PERFORM public.process_function_queue(queue_names, task.batch_size); + ELSE + PERFORM public.process_function_queue(queue_names); + END IF; + END CASE; + EXCEPTION WHEN OTHERS THEN + RAISE WARNING 'cron task "%" failed: %', task.name, SQLERRM; + END; + END IF; + END LOOP; + + EXCEPTION WHEN OTHERS THEN + -- Release the lock even if an error occurred + PERFORM pg_advisory_unlock(1); + RAISE; + END; + + -- Release the advisory lock + PERFORM pg_advisory_unlock(1); +END; +$$; + +-- Add comment explaining the SSO audit cleanup addition +COMMENT ON FUNCTION public.process_all_cron_tasks () IS 'Consolidated cron task processor that runs every 10 seconds. Uses advisory lock (ID=1) to prevent concurrent execution. Includes SSO audit log cleanup at 3:00 AM UTC daily.'; \ No newline at end of file