B2B-30: add config, enable mfa for activating super_admin
This commit is contained in:
@@ -1,3 +1,11 @@
|
||||
packages:
|
||||
- packages/**
|
||||
- tooling/*
|
||||
- tooling/*
|
||||
|
||||
onlyBuiltDependencies:
|
||||
- '@sentry/cli'
|
||||
- '@tailwindcss/oxide'
|
||||
- protobufjs
|
||||
- sharp
|
||||
- supabase
|
||||
- unrs-resolver
|
||||
|
||||
@@ -80,8 +80,8 @@ enabled = true
|
||||
# Port to use for the email testing server web interface.
|
||||
port = 54324
|
||||
# Uncomment to expose additional ports for testing user applications that send emails.
|
||||
# smtp_port = 54325
|
||||
# pop3_port = 54326
|
||||
smtp_port = 54325
|
||||
pop3_port = 54326
|
||||
# admin_email = "admin@email.com"
|
||||
# sender_name = "Admin"
|
||||
|
||||
@@ -107,7 +107,7 @@ enabled = true
|
||||
# in emails.
|
||||
site_url = "http://127.0.0.1:3000"
|
||||
# A list of *exact* URLs that auth providers are permitted to redirect to post authentication.
|
||||
additional_redirect_urls = ["https://127.0.0.1:3000"]
|
||||
additional_redirect_urls = ["https://127.0.0.1:3000","http://localhost:3000/auth/callback", "http://localhost:3000/update-password"]
|
||||
# How long tokens are valid for, in seconds. Defaults to 3600 (1 hour), maximum 604,800 (1 week).
|
||||
jwt_expiry = 3600
|
||||
# If disabled, the refresh token will never expire.
|
||||
@@ -129,7 +129,7 @@ password_requirements = ""
|
||||
|
||||
[auth.rate_limit]
|
||||
# Number of emails that can be sent per hour. Requires auth.email.smtp to be enabled.
|
||||
email_sent = 2
|
||||
email_sent = 1000
|
||||
# Number of SMS messages that can be sent per hour. Requires auth.sms to be enabled.
|
||||
sms_sent = 30
|
||||
# Number of anonymous sign-ins that can be made per hour per IP address. Requires enable_anonymous_sign_ins = true.
|
||||
@@ -175,9 +175,26 @@ otp_expiry = 3600
|
||||
# sender_name = "Admin"
|
||||
|
||||
# Uncomment to customize email template
|
||||
# [auth.email.template.invite]
|
||||
# subject = "You have been invited"
|
||||
# content_path = "./supabase/templates/invite.html"
|
||||
[auth.email.template.invite]
|
||||
subject = "You have been invited"
|
||||
content_path = "./supabase/templates/invite-user.html"
|
||||
|
||||
|
||||
[auth.email.template.confirmation]
|
||||
subject = "Confirm your email"
|
||||
content_path = "./supabase/templates/confirm-email.html"
|
||||
|
||||
[auth.email.template.recovery]
|
||||
subject = "Reset your password"
|
||||
content_path = "./supabase/templates/reset-password.html"
|
||||
|
||||
[auth.email.template.email_change]
|
||||
subject = "Confirm your email change"
|
||||
content_path = "./supabase/templates/change-email-address.html"
|
||||
|
||||
[auth.email.template.magic_link]
|
||||
subject = "Sign in to MedReport"
|
||||
content_path = "./supabase/templates/magic-link.html"
|
||||
|
||||
[auth.sms]
|
||||
# Allow/disallow new user signups via SMS to your project.
|
||||
@@ -220,13 +237,13 @@ max_enrolled_factors = 10
|
||||
|
||||
# Control MFA via App Authenticator (TOTP)
|
||||
[auth.mfa.totp]
|
||||
enroll_enabled = false
|
||||
verify_enabled = false
|
||||
enroll_enabled = true
|
||||
verify_enabled = true
|
||||
|
||||
# Configure MFA via Phone Messaging
|
||||
[auth.mfa.phone]
|
||||
enroll_enabled = false
|
||||
verify_enabled = false
|
||||
enroll_enabled = true
|
||||
verify_enabled = true
|
||||
otp_length = 6
|
||||
template = "Your code is {{ .Code }}"
|
||||
max_frequency = "5s"
|
||||
|
||||
349
supabase/migrations/20250612193715_nonces.sql
Normal file
349
supabase/migrations/20250612193715_nonces.sql
Normal file
@@ -0,0 +1,349 @@
|
||||
/*
|
||||
* -------------------------------------------------------
|
||||
* Section: Nonces
|
||||
* We create the schema for the nonces. Nonces are used to create one-time tokens for authentication purposes.
|
||||
* -------------------------------------------------------
|
||||
*/
|
||||
|
||||
create extension if not exists pg_cron;
|
||||
|
||||
-- Create a table to store one-time tokens (nonces)
|
||||
CREATE TABLE IF NOT EXISTS public.nonces (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
client_token TEXT NOT NULL, -- token sent to client (hashed)
|
||||
nonce TEXT NOT NULL, -- token stored in DB (hashed)
|
||||
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE NULL, -- Optional to support anonymous tokens
|
||||
purpose TEXT NOT NULL, -- e.g., 'password-reset', 'email-verification', etc.
|
||||
|
||||
-- Status fields
|
||||
expires_at TIMESTAMPTZ NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||||
used_at TIMESTAMPTZ,
|
||||
revoked BOOLEAN NOT NULL DEFAULT FALSE, -- For administrative revocation
|
||||
revoked_reason TEXT, -- Reason for revocation if applicable
|
||||
|
||||
-- Audit fields
|
||||
verification_attempts INTEGER NOT NULL DEFAULT 0, -- Track attempted uses
|
||||
last_verification_at TIMESTAMPTZ, -- Timestamp of last verification attempt
|
||||
last_verification_ip INET, -- For tracking verification source
|
||||
last_verification_user_agent TEXT, -- For tracking client information
|
||||
|
||||
-- Extensibility fields
|
||||
metadata JSONB DEFAULT '{}'::JSONB, -- optional metadata
|
||||
scopes TEXT[] DEFAULT '{}' -- OAuth-style authorized scopes
|
||||
);
|
||||
|
||||
-- Create indexes for efficient lookups
|
||||
CREATE INDEX IF NOT EXISTS idx_nonces_status ON public.nonces (client_token, user_id, purpose, expires_at)
|
||||
WHERE used_at IS NULL AND revoked = FALSE;
|
||||
|
||||
-- Enable Row Level Security (RLS)
|
||||
ALTER TABLE public.nonces ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- RLS policies
|
||||
-- Users can view their own nonces for verification
|
||||
CREATE POLICY "Users can read their own nonces"
|
||||
ON public.nonces
|
||||
FOR SELECT
|
||||
USING (
|
||||
user_id = (select auth.uid())
|
||||
);
|
||||
|
||||
-- Create a function to create a nonce
|
||||
-- Create a function to create a nonce
|
||||
create or replace function public.create_nonce (
|
||||
p_user_id UUID default null,
|
||||
p_purpose TEXT default null,
|
||||
p_expires_in_seconds INTEGER default 3600, -- 1 hour by default
|
||||
p_metadata JSONB default null,
|
||||
p_scopes text[] default null,
|
||||
p_revoke_previous BOOLEAN default true -- New parameter to control automatic revocation
|
||||
) RETURNS JSONB LANGUAGE plpgsql SECURITY DEFINER
|
||||
set
|
||||
search_path to '' as $$
|
||||
DECLARE
|
||||
v_client_token TEXT;
|
||||
v_nonce TEXT;
|
||||
v_expires_at TIMESTAMPTZ;
|
||||
v_id UUID;
|
||||
v_plaintext_token TEXT;
|
||||
v_revoked_count INTEGER;
|
||||
BEGIN
|
||||
-- Revoke previous tokens for the same user and purpose if requested
|
||||
-- This only applies if a user ID is provided (not for anonymous tokens)
|
||||
IF p_revoke_previous = TRUE AND p_user_id IS NOT NULL THEN
|
||||
WITH revoked AS (
|
||||
UPDATE public.nonces
|
||||
SET
|
||||
revoked = TRUE,
|
||||
revoked_reason = 'Superseded by new token with same purpose'
|
||||
WHERE
|
||||
user_id = p_user_id
|
||||
AND purpose = p_purpose
|
||||
AND used_at IS NULL
|
||||
AND revoked = FALSE
|
||||
AND expires_at > NOW()
|
||||
RETURNING 1
|
||||
)
|
||||
SELECT COUNT(*) INTO v_revoked_count FROM revoked;
|
||||
END IF;
|
||||
|
||||
-- Generate a 6-digit token
|
||||
v_plaintext_token := (100000 + floor(random() * 900000))::text;
|
||||
v_client_token := extensions.crypt(v_plaintext_token, extensions.gen_salt('bf'));
|
||||
|
||||
-- Still generate a secure nonce for internal use
|
||||
v_nonce := encode(extensions.gen_random_bytes(24), 'base64');
|
||||
v_nonce := extensions.crypt(v_nonce, extensions.gen_salt('bf'));
|
||||
|
||||
-- Calculate expiration time
|
||||
v_expires_at := NOW() + (p_expires_in_seconds * interval '1 second');
|
||||
|
||||
-- Insert the new nonce
|
||||
INSERT INTO public.nonces (
|
||||
client_token,
|
||||
nonce,
|
||||
user_id,
|
||||
expires_at,
|
||||
metadata,
|
||||
purpose,
|
||||
scopes
|
||||
)
|
||||
VALUES (
|
||||
v_client_token,
|
||||
v_nonce,
|
||||
p_user_id,
|
||||
v_expires_at,
|
||||
COALESCE(p_metadata, '{}'::JSONB),
|
||||
p_purpose,
|
||||
COALESCE(p_scopes, '{}'::TEXT[])
|
||||
)
|
||||
RETURNING id INTO v_id;
|
||||
|
||||
-- Return the token information
|
||||
-- Note: returning the plaintext token, not the hash
|
||||
RETURN jsonb_build_object(
|
||||
'id', v_id,
|
||||
'token', v_plaintext_token,
|
||||
'expires_at', v_expires_at,
|
||||
'revoked_previous_count', COALESCE(v_revoked_count, 0)
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
grant execute on function public.create_nonce to service_role;
|
||||
|
||||
-- Create a function to verify a nonce
|
||||
create or replace function public.verify_nonce (
|
||||
p_token TEXT,
|
||||
p_purpose TEXT,
|
||||
p_user_id UUID default null,
|
||||
p_required_scopes text[] default null,
|
||||
p_max_verification_attempts INTEGER default 5,
|
||||
p_ip INET default null,
|
||||
p_user_agent TEXT default null
|
||||
) RETURNS JSONB LANGUAGE plpgsql SECURITY DEFINER
|
||||
set
|
||||
SEARCH_PATH to '' as $$
|
||||
DECLARE
|
||||
v_nonce RECORD;
|
||||
v_matching_count INTEGER;
|
||||
BEGIN
|
||||
-- Count how many matching tokens exist before verification attempt
|
||||
SELECT COUNT(*)
|
||||
INTO v_matching_count
|
||||
FROM public.nonces
|
||||
WHERE purpose = p_purpose;
|
||||
|
||||
-- Update verification attempt counter and tracking info for all matching tokens
|
||||
UPDATE public.nonces
|
||||
SET verification_attempts = verification_attempts + 1,
|
||||
last_verification_at = NOW(),
|
||||
last_verification_ip = COALESCE(p_ip, last_verification_ip),
|
||||
last_verification_user_agent = COALESCE(p_user_agent, last_verification_user_agent)
|
||||
WHERE client_token = extensions.crypt(p_token, client_token)
|
||||
AND purpose = p_purpose;
|
||||
|
||||
-- Find the nonce by token and purpose
|
||||
-- Modified to handle user-specific tokens better
|
||||
SELECT *
|
||||
INTO v_nonce
|
||||
FROM public.nonces
|
||||
WHERE client_token = extensions.crypt(p_token, client_token)
|
||||
AND purpose = p_purpose
|
||||
-- Only apply user_id filter if the token was created for a specific user
|
||||
AND (
|
||||
-- Case 1: Anonymous token (user_id is NULL in DB)
|
||||
(user_id IS NULL)
|
||||
OR
|
||||
-- Case 2: User-specific token (check if user_id matches)
|
||||
(user_id = p_user_id)
|
||||
)
|
||||
AND used_at IS NULL
|
||||
AND NOT revoked
|
||||
AND expires_at > NOW();
|
||||
|
||||
-- Check if nonce exists
|
||||
IF v_nonce.id IS NULL THEN
|
||||
RETURN jsonb_build_object(
|
||||
'valid', false,
|
||||
'message', 'Invalid or expired token'
|
||||
);
|
||||
END IF;
|
||||
|
||||
-- Check if max verification attempts exceeded
|
||||
IF p_max_verification_attempts > 0 AND v_nonce.verification_attempts > p_max_verification_attempts THEN
|
||||
-- Automatically revoke the token
|
||||
UPDATE public.nonces
|
||||
SET revoked = TRUE,
|
||||
revoked_reason = 'Maximum verification attempts exceeded'
|
||||
WHERE id = v_nonce.id;
|
||||
|
||||
RETURN jsonb_build_object(
|
||||
'valid', false,
|
||||
'message', 'Token revoked due to too many verification attempts',
|
||||
'max_attempts_exceeded', true
|
||||
);
|
||||
END IF;
|
||||
|
||||
-- Check scopes if required
|
||||
IF p_required_scopes IS NOT NULL AND array_length(p_required_scopes, 1) > 0 THEN
|
||||
-- Fix scope validation to properly check if token scopes contain all required scopes
|
||||
-- Using array containment check: array1 @> array2 (array1 contains array2)
|
||||
IF NOT (v_nonce.scopes @> p_required_scopes) THEN
|
||||
RETURN jsonb_build_object(
|
||||
'valid', false,
|
||||
'message', 'Token does not have required permissions',
|
||||
'token_scopes', v_nonce.scopes,
|
||||
'required_scopes', p_required_scopes
|
||||
);
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Mark nonce as used
|
||||
UPDATE public.nonces
|
||||
SET used_at = NOW()
|
||||
WHERE id = v_nonce.id;
|
||||
|
||||
-- Return success with metadata
|
||||
RETURN jsonb_build_object(
|
||||
'valid', true,
|
||||
'user_id', v_nonce.user_id,
|
||||
'metadata', v_nonce.metadata,
|
||||
'scopes', v_nonce.scopes,
|
||||
'purpose', v_nonce.purpose
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
grant
|
||||
execute on function public.verify_nonce to authenticated,
|
||||
service_role;
|
||||
|
||||
-- Create a function to revoke a nonce
|
||||
CREATE OR REPLACE FUNCTION public.revoke_nonce(
|
||||
p_id UUID,
|
||||
p_reason TEXT DEFAULT NULL
|
||||
)
|
||||
RETURNS BOOLEAN
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path TO ''
|
||||
AS $$
|
||||
DECLARE
|
||||
v_affected_rows INTEGER;
|
||||
BEGIN
|
||||
UPDATE public.nonces
|
||||
SET
|
||||
revoked = TRUE,
|
||||
revoked_reason = p_reason
|
||||
WHERE
|
||||
id = p_id
|
||||
AND used_at IS NULL
|
||||
AND NOT revoked
|
||||
RETURNING 1 INTO v_affected_rows;
|
||||
|
||||
RETURN v_affected_rows > 0;
|
||||
END;
|
||||
$$;
|
||||
|
||||
grant execute on function public.revoke_nonce to service_role;
|
||||
|
||||
-- Create a function to clean up expired nonces
|
||||
CREATE OR REPLACE FUNCTION kit.cleanup_expired_nonces(
|
||||
p_older_than_days INTEGER DEFAULT 1,
|
||||
p_include_used BOOLEAN DEFAULT TRUE,
|
||||
p_include_revoked BOOLEAN DEFAULT TRUE
|
||||
)
|
||||
RETURNS INTEGER
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path TO ''
|
||||
AS $$
|
||||
DECLARE
|
||||
v_count INTEGER;
|
||||
BEGIN
|
||||
-- Count and delete expired or used nonces based on parameters
|
||||
WITH deleted AS (
|
||||
DELETE FROM public.nonces
|
||||
WHERE
|
||||
(
|
||||
-- Expired and unused tokens
|
||||
(expires_at < NOW() AND used_at IS NULL)
|
||||
|
||||
-- Used tokens older than specified days (if enabled)
|
||||
OR (p_include_used = TRUE AND used_at < NOW() - (p_older_than_days * interval '1 day'))
|
||||
|
||||
-- Revoked tokens older than specified days (if enabled)
|
||||
OR (p_include_revoked = TRUE AND revoked = TRUE AND created_at < NOW() - (p_older_than_days * interval '1 day'))
|
||||
)
|
||||
RETURNING 1
|
||||
)
|
||||
SELECT COUNT(*) INTO v_count FROM deleted;
|
||||
|
||||
RETURN v_count;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Create a function to get token status (for administrative use)
|
||||
CREATE OR REPLACE FUNCTION public.get_nonce_status(
|
||||
p_id UUID
|
||||
)
|
||||
RETURNS JSONB
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path TO ''
|
||||
AS $$
|
||||
DECLARE
|
||||
v_nonce public.nonces;
|
||||
BEGIN
|
||||
SELECT * INTO v_nonce FROM public.nonces WHERE id = p_id;
|
||||
|
||||
IF v_nonce.id IS NULL THEN
|
||||
RETURN jsonb_build_object('exists', false);
|
||||
END IF;
|
||||
|
||||
RETURN jsonb_build_object(
|
||||
'exists', true,
|
||||
'purpose', v_nonce.purpose,
|
||||
'user_id', v_nonce.user_id,
|
||||
'created_at', v_nonce.created_at,
|
||||
'expires_at', v_nonce.expires_at,
|
||||
'used_at', v_nonce.used_at,
|
||||
'revoked', v_nonce.revoked,
|
||||
'revoked_reason', v_nonce.revoked_reason,
|
||||
'verification_attempts', v_nonce.verification_attempts,
|
||||
'last_verification_at', v_nonce.last_verification_at,
|
||||
'last_verification_ip', v_nonce.last_verification_ip,
|
||||
'is_valid', (v_nonce.used_at IS NULL AND NOT v_nonce.revoked AND v_nonce.expires_at > NOW())
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comments for documentation
|
||||
COMMENT ON TABLE public.nonces IS 'Table for storing one-time tokens with enhanced security and audit features';
|
||||
COMMENT ON FUNCTION public.create_nonce IS 'Creates a new one-time token for a specific purpose with enhanced options';
|
||||
COMMENT ON FUNCTION public.verify_nonce IS 'Verifies a one-time token, checks scopes, and marks it as used';
|
||||
COMMENT ON FUNCTION public.revoke_nonce IS 'Administratively revokes a token to prevent its use';
|
||||
COMMENT ON FUNCTION kit.cleanup_expired_nonces IS 'Cleans up expired, used, or revoked tokens based on parameters';
|
||||
COMMENT ON FUNCTION public.get_nonce_status IS 'Retrieves the status of a token for administrative purposes';
|
||||
145
supabase/migrations/20250612193815_mfa.sql
Normal file
145
supabase/migrations/20250612193815_mfa.sql
Normal file
@@ -0,0 +1,145 @@
|
||||
/*
|
||||
* -------------------------------------------------------
|
||||
* Section: MFA
|
||||
* We create the policies and functions to enforce MFA
|
||||
* -------------------------------------------------------
|
||||
*/
|
||||
|
||||
/*
|
||||
* public.is_aal2
|
||||
* Check if the user has aal2 access
|
||||
*/
|
||||
create
|
||||
or replace function public.is_aal2() returns boolean
|
||||
set
|
||||
search_path = '' as
|
||||
$$
|
||||
declare
|
||||
is_aal2 boolean;
|
||||
begin
|
||||
select auth.jwt() ->> 'aal' = 'aal2' into is_aal2;
|
||||
|
||||
return coalesce(is_aal2, false);
|
||||
end
|
||||
$$ language plpgsql;
|
||||
|
||||
-- Grant access to the function to authenticated users
|
||||
grant execute on function public.is_aal2() to authenticated;
|
||||
|
||||
/*
|
||||
* public.is_super_admin
|
||||
* Check if the user is a super admin.
|
||||
* A Super Admin is a user that has the role 'super-admin' and has MFA enabled.
|
||||
*/
|
||||
create
|
||||
or replace function public.is_super_admin() returns boolean
|
||||
set
|
||||
search_path = '' as
|
||||
$$
|
||||
declare
|
||||
is_super_admin boolean;
|
||||
begin
|
||||
if not public.is_aal2() then
|
||||
return false;
|
||||
end if;
|
||||
|
||||
select (auth.jwt() ->> 'app_metadata')::jsonb ->> 'role' = 'super-admin' into is_super_admin;
|
||||
|
||||
return coalesce(is_super_admin, false);
|
||||
end
|
||||
$$ language plpgsql;
|
||||
|
||||
-- Grant access to the function to authenticated users
|
||||
grant execute on function public.is_super_admin() to authenticated;
|
||||
|
||||
/*
|
||||
* public.is_mfa_compliant
|
||||
* Check if the user meets MFA requirements if they have MFA enabled.
|
||||
* If the user has MFA enabled, then the user must have aal2 enabled. Otherwise, the user must have aal1 enabled (default behavior).
|
||||
*/
|
||||
create or replace function public.is_mfa_compliant() returns boolean
|
||||
set search_path = '' as
|
||||
$$
|
||||
begin
|
||||
return array[(select auth.jwt()->>'aal')] <@ (
|
||||
select
|
||||
case
|
||||
when count(id) > 0 then array['aal2']
|
||||
else array['aal1', 'aal2']
|
||||
end as aal
|
||||
from auth.mfa_factors
|
||||
where ((select auth.uid()) = auth.mfa_factors.user_id) and auth.mfa_factors.status = 'verified'
|
||||
);
|
||||
end
|
||||
$$ language plpgsql security definer;
|
||||
|
||||
-- Grant access to the function to authenticated users
|
||||
grant execute on function public.is_mfa_compliant() to authenticated;
|
||||
|
||||
-- MFA Restrictions:
|
||||
-- the following policies are applied to the tables as a
|
||||
-- restrictive policy to ensure that if MFA is enabled, then the policy will be applied.
|
||||
-- For users that have not enabled MFA, the policy will not be applied and will keep the default behavior.
|
||||
|
||||
-- Restrict access to accounts if MFA is enabled
|
||||
create policy restrict_mfa_accounts
|
||||
on public.accounts
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
|
||||
-- Restrict access to accounts memberships if MFA is enabled
|
||||
create policy restrict_mfa_accounts_memberships
|
||||
on public.accounts_memberships
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
|
||||
-- Restrict access to subscriptions if MFA is enabled
|
||||
create policy restrict_mfa_subscriptions
|
||||
on public.subscriptions
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
|
||||
-- Restrict access to subscription items if MFA is enabled
|
||||
create policy restrict_mfa_subscription_items
|
||||
on public.subscription_items
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
|
||||
-- Restrict access to role permissions if MFA is enabled
|
||||
create policy restrict_mfa_role_permissions
|
||||
on public.role_permissions
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
|
||||
-- Restrict access to invitations if MFA is enabled
|
||||
create policy restrict_mfa_invitations
|
||||
on public.invitations
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
|
||||
-- Restrict access to orders if MFA is enabled
|
||||
create policy restrict_mfa_orders
|
||||
on public.orders
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
|
||||
-- Restrict access to orders items if MFA is enabled
|
||||
create policy restrict_mfa_order_items
|
||||
on public.order_items
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
|
||||
-- Restrict access to orders if MFA is enabled
|
||||
create policy restrict_mfa_notifications
|
||||
on public.notifications
|
||||
as restrictive
|
||||
to authenticated
|
||||
using (public.is_mfa_compliant());
|
||||
73
supabase/migrations/20250612193836_super_admin.sql
Normal file
73
supabase/migrations/20250612193836_super_admin.sql
Normal file
@@ -0,0 +1,73 @@
|
||||
/*
|
||||
* -------------------------------------------------------
|
||||
* Section: Super Admin
|
||||
* We create the policies and functions to enforce super admin access
|
||||
* -------------------------------------------------------
|
||||
*/
|
||||
|
||||
-- the following policies are applied to the tables as a permissive policy to ensure that
|
||||
-- super admins can access all tables (view only).
|
||||
|
||||
-- Allow Super Admins to access the accounts table
|
||||
create policy super_admins_access_accounts
|
||||
on public.accounts
|
||||
as permissive
|
||||
for select
|
||||
to authenticated
|
||||
using (public.is_super_admin());
|
||||
|
||||
-- Allow Super Admins to access the accounts memberships table
|
||||
create policy super_admins_access_accounts_memberships
|
||||
on public.accounts_memberships
|
||||
as permissive
|
||||
for select
|
||||
to authenticated
|
||||
using (public.is_super_admin());
|
||||
|
||||
-- Allow Super Admins to access the subscriptions table
|
||||
create policy super_admins_access_subscriptions
|
||||
on public.subscriptions
|
||||
as permissive
|
||||
for select
|
||||
to authenticated
|
||||
using (public.is_super_admin());
|
||||
|
||||
-- Allow Super Admins to access the subscription items table
|
||||
create policy super_admins_access_subscription_items
|
||||
on public.subscription_items
|
||||
as permissive
|
||||
for select
|
||||
to authenticated
|
||||
using (public.is_super_admin());
|
||||
|
||||
-- Allow Super Admins to access the invitations items table
|
||||
create policy super_admins_access_invitations
|
||||
on public.invitations
|
||||
as permissive
|
||||
for select
|
||||
to authenticated
|
||||
using (public.is_super_admin());
|
||||
|
||||
-- Allow Super Admins to access the orders table
|
||||
create policy super_admins_access_orders
|
||||
on public.orders
|
||||
as permissive
|
||||
for select
|
||||
to authenticated
|
||||
using (public.is_super_admin());
|
||||
|
||||
-- Allow Super Admins to access the order items table
|
||||
create policy super_admins_access_order_items
|
||||
on public.order_items
|
||||
as permissive
|
||||
for select
|
||||
to authenticated
|
||||
using (public.is_super_admin());
|
||||
|
||||
-- Allow Super Admins to access the role permissions table
|
||||
create policy super_admins_access_role_permissions
|
||||
on public.role_permissions
|
||||
as permissive
|
||||
for select
|
||||
to authenticated
|
||||
using (public.is_super_admin());
|
||||
126
supabase/migrations/20250612193929_account_functions.sql
Normal file
126
supabase/migrations/20250612193929_account_functions.sql
Normal file
@@ -0,0 +1,126 @@
|
||||
/*
|
||||
* -------------------------------------------------------
|
||||
* Section: Account Functions
|
||||
* We create the schema for the functions. Functions are the custom functions for the application.
|
||||
* -------------------------------------------------------
|
||||
*/
|
||||
|
||||
|
||||
--
|
||||
-- VIEW "user_account_workspace":
|
||||
-- we create a view to load the general app data for the authenticated
|
||||
-- user which includes the user accounts and memberships
|
||||
create or replace view
|
||||
public.user_account_workspace
|
||||
with
|
||||
(security_invoker = true) as
|
||||
select
|
||||
accounts.id as id,
|
||||
accounts.name as name,
|
||||
accounts.picture_url as picture_url,
|
||||
(
|
||||
select
|
||||
status
|
||||
from
|
||||
public.subscriptions
|
||||
where
|
||||
account_id = accounts.id
|
||||
limit
|
||||
1
|
||||
) as subscription_status
|
||||
from
|
||||
public.accounts
|
||||
where
|
||||
primary_owner_user_id = (select auth.uid ())
|
||||
and accounts.is_personal_account = true
|
||||
limit
|
||||
1;
|
||||
|
||||
grant
|
||||
select
|
||||
on public.user_account_workspace to authenticated,
|
||||
service_role;
|
||||
|
||||
--
|
||||
-- VIEW "user_accounts":
|
||||
-- we create a view to load the user's accounts and memberships
|
||||
-- useful to display the user's accounts in the app
|
||||
create or replace view
|
||||
public.user_accounts (id, name, picture_url, slug, role)
|
||||
with
|
||||
(security_invoker = true) as
|
||||
select
|
||||
account.id,
|
||||
account.name,
|
||||
account.picture_url,
|
||||
account.slug,
|
||||
membership.account_role
|
||||
from
|
||||
public.accounts account
|
||||
join public.accounts_memberships membership on account.id = membership.account_id
|
||||
where
|
||||
membership.user_id = (select auth.uid ())
|
||||
and account.is_personal_account = false
|
||||
and account.id in (
|
||||
select
|
||||
account_id
|
||||
from
|
||||
public.accounts_memberships
|
||||
where
|
||||
user_id = (select auth.uid ())
|
||||
);
|
||||
|
||||
grant
|
||||
select
|
||||
on public.user_accounts to authenticated,
|
||||
service_role;
|
||||
|
||||
--
|
||||
-- Function "public.team_account_workspace"
|
||||
-- Load all the data for a team account workspace
|
||||
create or replace function public.team_account_workspace(account_slug text)
|
||||
returns table (
|
||||
id uuid,
|
||||
name varchar(255),
|
||||
picture_url varchar(1000),
|
||||
slug text,
|
||||
role varchar(50),
|
||||
role_hierarchy_level int,
|
||||
primary_owner_user_id uuid,
|
||||
subscription_status public.subscription_status,
|
||||
permissions public.app_permissions[]
|
||||
)
|
||||
set search_path to ''
|
||||
as $$
|
||||
begin
|
||||
return QUERY
|
||||
select
|
||||
accounts.id,
|
||||
accounts.name,
|
||||
accounts.picture_url,
|
||||
accounts.slug,
|
||||
accounts_memberships.account_role,
|
||||
roles.hierarchy_level,
|
||||
accounts.primary_owner_user_id,
|
||||
subscriptions.status,
|
||||
array_agg(role_permissions.permission)
|
||||
from
|
||||
public.accounts
|
||||
join public.accounts_memberships on accounts.id = accounts_memberships.account_id
|
||||
left join public.subscriptions on accounts.id = subscriptions.account_id
|
||||
join public.roles on accounts_memberships.account_role = roles.name
|
||||
left join public.role_permissions on accounts_memberships.account_role = role_permissions.role
|
||||
where
|
||||
accounts.slug = account_slug
|
||||
and public.accounts_memberships.user_id = (select auth.uid())
|
||||
group by
|
||||
accounts.id,
|
||||
accounts_memberships.account_role,
|
||||
subscriptions.status,
|
||||
roles.hierarchy_level;
|
||||
end;
|
||||
$$ language plpgsql;
|
||||
|
||||
grant
|
||||
execute on function public.team_account_workspace (text) to authenticated,
|
||||
service_role;
|
||||
8
supabase/templates/change-email-address.html
Normal file
8
supabase/templates/change-email-address.html
Normal file
File diff suppressed because one or more lines are too long
8
supabase/templates/confirm-email.html
Normal file
8
supabase/templates/confirm-email.html
Normal file
File diff suppressed because one or more lines are too long
8
supabase/templates/invite-user.html
Normal file
8
supabase/templates/invite-user.html
Normal file
File diff suppressed because one or more lines are too long
8
supabase/templates/magic-link.html
Normal file
8
supabase/templates/magic-link.html
Normal file
File diff suppressed because one or more lines are too long
8
supabase/templates/reset-password.html
Normal file
8
supabase/templates/reset-password.html
Normal file
File diff suppressed because one or more lines are too long
Reference in New Issue
Block a user