From 3b7fa01f5886c0447f93ce0ad158610d9c28d14b Mon Sep 17 00:00:00 2001 From: PointSource <47544779+point-source@users.noreply.github.com> Date: Wed, 29 Nov 2023 18:27:20 -0800 Subject: [PATCH] Migrate to TLE-based installation (#2) --- .vscode/settings.json | 15 ++ README.md | 22 +- .../20231130021555_reset_database.sql | 45 ++++ .../20231130022127_install_dbdev.sql | 46 ++++ .../20231130022337_install_rbac.sql | 6 + supabase_rbac--0.0.1.sql | 248 ++++++++++++++++++ supabase_rbac.control | 6 + 7 files changed, 380 insertions(+), 8 deletions(-) create mode 100644 .vscode/settings.json create mode 100644 supabase/migrations/20231130021555_reset_database.sql create mode 100644 supabase/migrations/20231130022127_install_dbdev.sql create mode 100644 supabase/migrations/20231130022337_install_rbac.sql create mode 100644 supabase_rbac--0.0.1.sql create mode 100644 supabase_rbac.control diff --git a/.vscode/settings.json b/.vscode/settings.json new file mode 100644 index 0000000..6c36662 --- /dev/null +++ b/.vscode/settings.json @@ -0,0 +1,15 @@ +{ + "Prettier-SQL.SQLFlavourOverride": "postgresql", + "sqltools.connections": [ + { + "previewLimit": 50, + "server": "localhost", + "port": 54322, + "driver": "PostgreSQL", + "name": "Supabase Local", + "database": "postgres", + "username": "postgres", + "password": "postgres" + } + ] +} \ No newline at end of file diff --git a/README.md b/README.md index f69f968..ebe1704 100644 --- a/README.md +++ b/README.md @@ -1,6 +1,6 @@ # Supabase Multi-Tenant Role-based Access Control -This is a template (set of db migrations) which attempts to provide a group and role system for supabase projects. It is based off the supabase community [custom claims work done here](https://github.com/supabase-community/supabase-custom-claims). +This is a [PostgreSQL TLE](https://github.com/aws/pg_tle) (extension) which attempts to provide a group and role system for supabase projects. You can add it to your database by using the [database.dev](https://database.dev/) tool. It is based off the supabase community [custom claims work done here](https://github.com/supabase-community/supabase-custom-claims). ## Disclaimer @@ -63,7 +63,7 @@ As a security note, `raw_app_meta_data` is stored within the JWTs when a session #### Pre-check - Requires PostgreSQL 15.x (due to use of "security_invoker" on the user_role view) -- This creates the following tables / views. Make sure they do not collide with existing tables: +- This creates the following tables / views. Make sure they do not collide with existing tables. (alternatively, specify an alternate schema during creation of the extension): - groups - group_users - user_roles (view) @@ -78,15 +78,21 @@ As a security note, `raw_app_meta_data` is stored within the JWTs when a session - set_group_owner - add_group_user_by_email -#### Installation via the SQL console +#### Installation via dbdev -1. Copy the contents of one or more of the [migration files](supabase/migrations/) in this repository -1. Paste the contents into the SQL console on your supabase dashboard and run it -1. Optionally, run a diff from your supabase cli to create a migration file capturing these changes +1. Make sure you have [dbdev package manager](https://supabase.github.io/dbdev/install-in-db-client/#use) installed +2. Run `select dbdev.install();` in your SQL console to install the rbac plugin +3. Create the extension by running one of the following: -#### Installation via local migration file +```sql +create extension "pointsource-supabase_rbac"; +``` + +or, if you want to specify a schema or version: -If you use the supabase cli and have a local dev environment, you can copy the migration files from this repo into your `supabase/migrations/*` folder and rename them to reflect a more recent timestamp. Note that in order for supabase to apply the migrations, they must conform to the `_name.sql` format. +```sql +create extension "pointsource-supabase_rbac" schema "my_schema_name" version "0.0.1"; +``` ### Security / RLS diff --git a/supabase/migrations/20231130021555_reset_database.sql b/supabase/migrations/20231130021555_reset_database.sql new file mode 100644 index 0000000..05b754a --- /dev/null +++ b/supabase/migrations/20231130021555_reset_database.sql @@ -0,0 +1,45 @@ +drop trigger if exists "on_change_update_user_metadata" on "public"."group_users"; + +drop trigger if exists "on_insert_set_group_owner" on "public"."groups"; + +drop trigger if exists "on_delete_user" on "public"."user_roles"; + +alter table "public"."group_users" drop constraint "group_users_group_id_fkey"; + +alter table "public"."group_users" drop constraint "group_users_user_id_fkey"; + +drop function if exists "public"."add_group_user_by_email"(user_email text, gid uuid, group_role text); + +drop function if exists "public"."delete_group_users"(); + +drop function if exists "public"."has_group_role"(group_id uuid, group_role text); + +drop function if exists "public"."is_group_member"(group_id uuid); + +drop function if exists "public"."jwt_has_group_role"(group_id uuid, group_role text); + +drop function if exists "public"."jwt_is_expired"(); + +drop function if exists "public"."jwt_is_group_member"(group_id uuid); + +drop function if exists "public"."set_group_owner"(); + +drop function if exists "public"."update_user_roles"(); + +drop view if exists "public"."user_roles"; + +alter table "public"."group_users" drop constraint "group_users_pkey"; + +alter table "public"."groups" drop constraint "group_pkey"; + +drop index if exists "public"."group_pkey"; + +drop index if exists "public"."group_users_group_id_idx"; + +drop index if exists "public"."group_users_pkey"; + +drop table "public"."group_users"; + +drop table "public"."groups"; + + diff --git a/supabase/migrations/20231130022127_install_dbdev.sql b/supabase/migrations/20231130022127_install_dbdev.sql new file mode 100644 index 0000000..aef8ec2 --- /dev/null +++ b/supabase/migrations/20231130022127_install_dbdev.sql @@ -0,0 +1,46 @@ +create extension if not exists http +with + schema extensions; + +create extension if not exists pg_tle; + +select + pgtle.uninstall_extension_if_exists ('supabase-dbdev'); + +drop extension if exists "supabase-dbdev"; + +select + pgtle.install_extension ( + 'supabase-dbdev', + resp.contents ->> 'version', + 'PostgreSQL package manager', + resp.contents ->> 'sql' + ) +from + http ( + ( + 'GET', + 'https://api.database.dev/rest/v1/' || 'package_versions?select=sql,version' || '&package_name=eq.supabase-dbdev' || '&order=version.desc' || '&limit=1', + array[ + ( + 'apiKey', + 'eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJpc3MiOiJzdXBhYmFzZSIsInJlZiI6InhtdXB0cHBsZnZpaWZyYndtbXR2Iiwicm9sZSI6ImFub24iLCJpYXQiOjE2ODAxMDczNzIsImV4cCI6MTk5NTY4MzM3Mn0.z2CN0mvO2No8wSi46Gw59DFGCTJrzM0AQKsu_5k134s' + )::http_header + ], + null, + null + ) + ) x, + lateral ( + select + ((row_to_json(x) -> 'content') #>> '{}')::json -> 0 + ) resp (contents); + +create extension "supabase-dbdev"; + +select + dbdev.install ('supabase-dbdev'); + +drop extension if exists "supabase-dbdev"; + +create extension "supabase-dbdev"; \ No newline at end of file diff --git a/supabase/migrations/20231130022337_install_rbac.sql b/supabase/migrations/20231130022337_install_rbac.sql new file mode 100644 index 0000000..e912048 --- /dev/null +++ b/supabase/migrations/20231130022337_install_rbac.sql @@ -0,0 +1,6 @@ +select + dbdev.install ('pointsource-supabase_rbac'); + +create extension if not exists "pointsource-supabase_rbac" +with + schema "public" version '0.0.1'; \ No newline at end of file diff --git a/supabase_rbac--0.0.1.sql b/supabase_rbac--0.0.1.sql new file mode 100644 index 0000000..726aa29 --- /dev/null +++ b/supabase_rbac--0.0.1.sql @@ -0,0 +1,248 @@ +create table + "groups" ( + "id" uuid not null default gen_random_uuid (), + "name" text not null default ''::text, + "created_at" timestamp with time zone not null default now() + ); + +create table + "group_users" ( + "id" uuid not null default gen_random_uuid (), + "group_id" uuid not null, + "user_id" uuid not null, + "role" text not null default ''::text, + "created_at" timestamp with time zone default now() + ); + +CREATE UNIQUE INDEX group_pkey ON "groups" USING btree (id); + +CREATE UNIQUE INDEX group_users_group_id_idx ON group_users USING btree (group_id, user_id, role); + +CREATE UNIQUE INDEX group_users_pkey ON group_users USING btree (id); + +alter table "groups" +add constraint "group_pkey" PRIMARY KEY using index "group_pkey"; + +alter table "group_users" +add constraint "group_users_pkey" PRIMARY KEY using index "group_users_pkey"; + +alter table "group_users" +add constraint "group_users_group_id_fkey" FOREIGN KEY (group_id) REFERENCES "groups" (id) not valid; + +alter table "group_users" validate constraint "group_users_group_id_fkey"; + +alter table "group_users" +add constraint "group_users_user_id_fkey" FOREIGN KEY (user_id) REFERENCES auth.users (id) not valid; + +alter table "group_users" validate constraint "group_users_user_id_fkey"; + +create or replace view + "user_roles" +WITH + (security_invoker) as +SELECT + gu.id, + g.name AS group_name, + gu.role, + u.email, + gu.group_id, + gu.user_id +FROM + ( + ( + group_users gu + JOIN auth.users u ON ((u.id = gu.user_id)) + ) + JOIN "groups" g ON ((g.id = gu.group_id)) + ); + +CREATE +OR REPLACE FUNCTION delete_group_users () RETURNS trigger LANGUAGE plpgsql AS $function$ BEGIN + DELETE from group_users WHERE id = OLD.id; + RETURN NULL; +END; +$function$; + +CREATE +OR REPLACE FUNCTION has_group_role (group_id uuid, group_role text) RETURNS boolean LANGUAGE plpgsql SECURITY DEFINER AS $function$ +DECLARE retval bool; +BEGIN + IF session_user = 'authenticator' THEN + if jwt_is_expired() then + raise exception 'invalid_jwt' USING HINT = 'JWT is expired or missing'; + end if; + select coalesce( + raw_app_meta_data->'groups'->group_id::text ? group_role, + false + ) + from auth.users into retval + where id = auth.uid(); + return retval; + ELSE -- not a user session, probably being called from a trigger or something + return true; + END IF; +END; +$function$; + +CREATE +OR REPLACE FUNCTION is_group_member (group_id uuid) RETURNS boolean LANGUAGE plpgsql SECURITY DEFINER AS $function$ +DECLARE retval bool; +BEGIN + IF session_user = 'authenticator' THEN + if jwt_is_expired() then + raise exception 'invalid_jwt' USING HINT = 'JWT is expired or missing'; + end if; + select coalesce( + raw_app_meta_data->'groups' ? group_id::text, + false + ) + from auth.users into retval + where id = auth.uid(); + return retval; + ELSE + return true; + END IF; +END; +$function$; + +CREATE +OR REPLACE FUNCTION jwt_has_group_role (group_id uuid, group_role text) RETURNS boolean LANGUAGE plpgsql AS $function$ +DECLARE retval bool; +BEGIN + IF session_user = 'authenticator' THEN + if jwt_is_expired() then + raise exception 'invalid_jwt' USING HINT = 'JWT is expired or missing'; + end if; + select coalesce( + auth.jwt()->'app_metadata'->'groups'->group_id::text ? group_role, + false + ) into retval; + return retval; + ELSE -- not a user session, probably being called from a trigger or something + return true; + END IF; +END; +$function$; + +CREATE +OR REPLACE FUNCTION jwt_is_expired () RETURNS boolean LANGUAGE plpgsql AS $function$ BEGIN + return extract(epoch from now()) > coalesce(auth.jwt()->>'exp', '0')::numeric; +END; +$function$; + +CREATE +OR REPLACE FUNCTION jwt_is_group_member (group_id uuid) RETURNS boolean LANGUAGE plpgsql AS $function$ +DECLARE retval bool; +BEGIN + IF session_user = 'authenticator' THEN + if jwt_is_expired() then + raise exception 'invalid_jwt' USING HINT = 'JWT is expired or missing'; + end if; + select coalesce( + auth.jwt()->'app_metadata'->'groups' ? group_id::text, + false + ) into retval; + return retval; + ELSE -- not a user session, probably being called from a trigger or something + return true; + END IF; +END; +$function$; + +CREATE +OR REPLACE FUNCTION update_user_roles () RETURNS TRIGGER LANGUAGE plpgsql SECURITY DEFINER AS $function$ +DECLARE + _group_id UUID = COALESCE(new.group_id, old.group_id); + _group_id_old UUID = COALESCE(old.group_id, new.group_id); + _user_id UUID = COALESCE(new.user_id, old.user_id); + _user_id_old UUID = COALESCE(old.user_id, new.user_id); +BEGIN + -- Check if user_id or group_id is changed + IF _group_id IS DISTINCT FROM _group_id_old OR _user_id IS DISTINCT FROM _user_id_old THEN + RAISE EXCEPTION 'Changing user_id or group_id is not allowed'; + END IF; + + -- Update raw_app_meta_data in auth.users + UPDATE auth.users + SET raw_app_meta_data = JSONB_SET( + raw_app_meta_data, + '{groups}', + JSONB_STRIP_NULLS( + JSONB_SET( + COALESCE(raw_app_meta_data->'groups', '{}'::JSONB), + ARRAY[_group_id::TEXT], + COALESCE( + (SELECT JSONB_AGG("role") + FROM group_users gu + WHERE gu.group_id = _group_id + AND gu.user_id = _user_id + ), + 'null'::JSONB + ) + ) + ) + ) + WHERE id = _user_id; + + -- Return null (the trigger function requires a return value) + RETURN NULL; +END; +$function$; + +CREATE +OR REPLACE FUNCTION set_group_owner () RETURNS trigger LANGUAGE plpgsql SECURITY DEFINER AS $function$ + begin + IF auth.uid() IS not NULL THEN + insert into group_users(group_id, user_id, role) values(new.id, auth.uid(), 'owner'); + end if; + return new; + end; +$function$; + +CREATE +OR REPLACE FUNCTION add_group_user_by_email (user_email text, gid uuid, group_role text) RETURNS text LANGUAGE plpgsql SECURITY DEFINER AS $function$ + declare + uid uuid = auth.uid(); + recipient_id uuid; + new_record_id uuid; + BEGIN + if uid is null then + raise exception 'not_authorized' using hint = 'You are are not authorized to perform this action'; + end if; + + if not exists(select id from group_users gu where gu.user_id = uid AND gu.group_id = gid AND gu.role = 'owner') then + raise exception 'not_authorized' using hint = 'You are are not authorized to perform this action'; + end if; + + select u.id from auth.users u into recipient_id where u.email = user_email; + + if recipient_id is null then + raise exception 'failed_to_add_user' using hint = 'User could not be added to group'; + end if; + + INSERT INTO group_users (group_id, user_id, role) VALUES (gid, recipient_id, group_role) returning id into new_record_id; + + return new_record_id; + exception + when unique_violation then + raise exception 'failed_to_add_user' using hint = 'User could not be added to group'; + END; +$function$; + +CREATE TRIGGER on_change_update_user_metadata +AFTER INSERT +OR DELETE +OR +UPDATE ON group_users FOR EACH ROW +EXECUTE FUNCTION update_user_roles (); + +CREATE TRIGGER on_delete_user INSTEAD OF DELETE ON user_roles FOR EACH ROW +EXECUTE FUNCTION delete_group_users (); + +CREATE TRIGGER on_insert_set_group_owner +AFTER INSERT ON groups FOR EACH ROW +EXECUTE FUNCTION set_group_owner (); + +alter table "group_users" enable row level security; + +alter table "groups" enable row level security; \ No newline at end of file diff --git a/supabase_rbac.control b/supabase_rbac.control new file mode 100644 index 0000000..3b44399 --- /dev/null +++ b/supabase_rbac.control @@ -0,0 +1,6 @@ +# supabase_rbac extension +comment = 'Provides tables and functions to use Role-Based Access Control in your Supabase project' +default_version = '0.0.1' +superuser = false +relocatable = false +superuser = true \ No newline at end of file