├── Performance.md ├── README.md ├── groups.sql ├── images ├── img.png ├── img1.png ├── img_1.png ├── img_2.png ├── img_3.png ├── img_4.png ├── imgg1.png ├── staff.png └── students.png ├── properties.sql ├── roles.sql ├── test.sql ├── tle-custom-properties ├── README.md ├── custom_properties--0.0.3.sql └── custom_properties.control └── tle-custom-roles ├── README.md ├── custom_roles--0.0.3.sql └── custom_roles.control /Performance.md: -------------------------------------------------------------------------------- 1 | # Performance Results 2 | 3 | Run on a Supabase free instance. 4 | 100k and 1M row table protected with various RLS. 5 | All times in Msec. SQL simulates an authenticated user in SQL. REST API is supabase-js call. 6 | 7 | See the test.sql for some info on table and tests. 8 | Note the test.sql is just various tables,policies and jwt claims code for doing a variety of tests. 9 | It is not a complete packaged test suit. 10 | See https://github.com/GaryAustin1/RLS-Performance for better performance analysis with improved RLS methods used here. 11 | 12 | ### 100k rows 13 | custom-properties table RLS of versus JWT with get_my_claim in auth.app_metadata. 14 | 15 | |RLS| SQL | REST API | 16 | |--|-----|----------| 17 | |(select user_roles.user_has_property('Teacher'))| 13 | 30 | 18 | |(select get_my_claim('role')::text) = '"Teacher"'| 17 | 29| 19 | 20 | ### 1M rows 21 | custom-properties table RLS of versus JWT with get_my_claim in auth.app_metadata. 22 | 23 | |RLS|SQL|REST API| 24 | |--|--|--| 25 | |(select user_roles.user_has_property('Teacher'))|133|315| 26 | |(select get_my_claim('role')::text) = '"Teacher"'|166|290| 27 | 28 | ### 1M rows with 900k for role Student, 100K for Teacher and 1000 for Dean 29 | Only has a user with 1 role and change the role for each test. 30 | I would not recommend this method using jwt if over 10 roles per user. 31 | NO INDEXING on for_role column. 32 | 33 | Uses RLS policies: 34 | for_role = any (array(select user_roles.get_user_properties())) 35 | for_role = (select get_my_claim('role')->>0) 36 | 37 | | RLS | SQL-table | SQL-jwt | REST API-table | REST API-jwt | 38 | |-------------------------------|-----------|---------|----------------|--------------| 39 | | Dean (1k) | 127 | 112 | 135 | 145 | 40 | | Teacher (100K) | 169 | 131 | 427 | 425 | 41 | | Student (900K) API limit 100k | 231 |208|302|292| 42 | | Student (900k) API limit 1M |231|208|2840|2704| 43 | 44 | ### 100k rows without RLS tuning 45 | This is why jwt method became popular. 46 | 47 | | RLS | SQL | REST API | 48 | |------------------------------------------|------|----------| 49 | | user_roles.user_has_property('Teacher') | 1874 | 3005 | 50 | | get_my_claim('role')::text = '"Teacher"' | 195 | 1158 | 51 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # custom-properties 2 | Custom roles/teams/groups/claims using tables and a setof functions for RLS in Supabase environment. 3 | 4 | Roles and Properties code seem in good shape. Groups is still a work in progress. 5 | 6 | The goals: 7 | Show a table based approach to roles/claims management, then group management with individual group admins. 8 | Have RLS functions use the roles/claims. 9 | Compare the RLS performance of using a roles table versus using a JWT custom-claims approach. See [Performance](https://github.com/GaryAustin1/custom-properties/blob/main/Performance.md) 10 | 11 | The concept is to have a simple property name table and user properties table for each type of property desired. 12 | All management of user properties is done thru standard table management of the user properties table. 13 | RLS by default allows postgres, service_role and an authenticated user with an admin property in the table to manage the user properties. 14 | If the schema is added to the API schemas in the dashboard then a user can read their own properties but only the admin roles can modify. 15 | 16 | Many have turned to using the app_metadata column in auth.users and the user JWT for roles and claims management. 17 | This repository https://github.com/supabase-community/supabase-custom-claims is popular for this. 18 | This was mainly driven by the slow performance of RLS with table joins versus a function checking the JWT. 19 | Recent testing has shown that RLS performance of generic functions and table joins can be greatly improved. 20 | This repository also looks at that. 21 | 22 | A roles/claims table also has the advantage of easier admin using direct table manipulation and views. 23 | It also allows changes in claims and roles to immediately take effect versus waiting for the JWT to refresh 24 | 25 | The initial approach here uses a meaningful schema name for the type of property being used. 26 | This is in part because the goal is to make this a TLE in dbdev. 27 | One could certainly rename the functions and tables as desired instead of using a schema name. 28 | 29 | If it is desired to automatically populate properties this can be done with a typical auth.users 30 | trigger function on user creation by just inserting desired user/property pairs into the user properties table. 31 | 32 | The code also has an optional trigger function that will update Supabase app_metadata on any change to the user's properties in the user property table. 33 | This json object will be named after the schema name in the current version. 34 | 35 | properties.sql is the main code to set up a property in schema. Right now this is hard coded to user_roles schema. 36 | roles.sql is a version with hard coded function and table names using 'role'. Can be installed in public schema. 37 | test.sql is sample code used to test performance of this method versus the typical custom-claims method which uses claims in the JWT as the RLS test. 38 | There are two TLE directories for a custom-properties and custom-roles version of this repository. These are available from https://database.dev/. 39 | 40 | The RLS functions are called like (note the examples here are from custom-properties installed in the user_roles schema): 41 | 42 | `USING ( (select user_roles.user_has_property('Teacher') )` 43 | `USING ( (select user_roles.user_property_in('{"Teacher","Staff"}') )` {} is string format for array in Postgres 44 | `USING ( (select user_roles.user_properties_match('{"Teacher","Staff"}') )` must match all roles in array 45 | `USING ( role_column = any (array(select user_roles.get_user_properties())) )` if user has over 1000 properties performance should be studied 46 | `USING ( (select user_roles.user_has_property('PropertyAdmin') )` default property for admin of the properties 47 | 48 | It is CRITICAL TO CALL THEM IN THE FORMAT SHOWN to get fast performance. The wrapping with parenthesis and select: `(select function())`. 49 | 50 | Example of roles: 51 | 52 | ![img1.png](images%2Fimg1.png) 53 | 54 | ![img_1.png](images/img_1.png) 55 | 56 | ![img_2.png](images/img_2.png) 57 | 58 | Foreign key property types link enforces choices: 59 | ![img_3.png](images/img_3.png) 60 | 61 | And the real winner with just using tables for roles, groups, etc. is being able to just use table/view operations as part of joins. 62 | ```sql 63 | create view 64 | public.student_view with (security_invoker = true) as 65 | select 66 | u.user_id, 67 | u.property, 68 | p.name, 69 | p.email 70 | from 71 | user_roles.user_properties u 72 | join user_profiles as p on p.user_id = u.user_id 73 | where 74 | u.property = 'Student'::text; 75 | ``` 76 | Yields: 77 | ![students.png](images%2Fstudents.png) 78 | 79 | And: 80 | ```sql 81 | create view 82 | public.college_staff_view with (security_invoker = true) as 83 | select 84 | u.user_id, 85 | u.property, 86 | p.name, 87 | p.email 88 | from 89 | user_roles.user_properties u 90 | join user_profiles as p on p.user_id = u.user_id 91 | where 92 | u.property =any ('{"Dean","Teacher"}'); 93 | ``` 94 | Gives: 95 | ![staff.png](images%2Fstaff.png) 96 | 97 | 98 | ### Custom-properties for managing groups in the works. 99 | Same general idea but have the property_names table use an id for primary and fk so that group names can change. 100 | Add a group_admin column in the user_properties table for individual group admin in addition to an over all group admin role. 101 | Don't support app_metadata reflection as large jwt's can cause session and performance issues as well cookie size problems. 102 | 103 | ![imgg1.png](images/imgg1.png) 104 | -------------------------------------------------------------------------------- /groups.sql: -------------------------------------------------------------------------------- 1 | -- Right now the schema is hard coded to user_groups.... 2 | -- NOT MUCH OF THIS IS TESTED YET!!!!!!!!!!!!!!! 3 | -- This is very similar to properties but uses id's to allow changing names and individual group admin flag. 4 | 5 | DROP SCHEMA IF EXISTS user_groups cascade; 6 | CREATE SCHEMA user_groups; 7 | GRANT USAGE ON SCHEMA user_groups TO postgres, authenticated, service_role; 8 | 9 | CREATE TABLE user_groups.group_names ( 10 | group_id serial primary key, 11 | group_name text unique 12 | ); 13 | ALTER TABLE user_groups.group_names ENABLE ROW LEVEL SECURITY; 14 | 15 | -- Adding admin role. Postgres,service_role and an authenticated user with this role in the roles table can manage the table. 16 | INSERT INTO user_groups.group_names (group_name) VALUES 17 | ('GroupAdmin'); 18 | 19 | CREATE TABLE user_groups.user_groups ( 20 | user_id UUID not null, 21 | group_id int4, 22 | group_admin boolean, 23 | constraint fk_groupname foreign key (group_id) references user_groups.group_names(group_id) on update cascade on delete cascade, 24 | constraint fk_user foreign key (user_id) references auth.users(id) on delete cascade, -- If you have a profile table you can link to that instead 25 | primary key (user_id,group_id) 26 | ); 27 | ALTER TABLE user_groups.user_groups ENABLE ROW LEVEL SECURITY; 28 | GRANT ALL ON user_groups.user_groups TO postgres,service_role,authenticated; -- note RLS also protects this table 29 | 30 | -- These are example functions for use in RLS. 31 | -- They depend on the auth.uid() of the user so are secure. 32 | -- They must be called like (select user_groups.user_has_group_id(group_id)) with the outer parentheses and select or the performance will be greatly impacted. 33 | -- See https://github.com/GaryAustin1/RLS-Performance for more info on performance of functions in RLS. 34 | 35 | -- Match a group id for current user 36 | CREATE FUNCTION user_groups.user_has_group_id(_group_id int4) RETURNS boolean 37 | LANGUAGE SQL SECURITY DEFINER SET search_path = user_groups,public 38 | AS $$ 39 | select exists (select 1 from user_groups where user_id = auth.uid() and _group_id = group_id); 40 | $$; 41 | 42 | -- get group id for group name 43 | CREATE FUNCTION user_groups.get_id_from_group_name(_group_name text) RETURNS int4 44 | LANGUAGE SQL SECURITY DEFINER SET search_path = user_groups,public 45 | AS $$ 46 | select group_id from group_names where _group_name= group_name; 47 | $$; 48 | 49 | -- is this user admin for this group 50 | CREATE FUNCTION user_groups.user_is_this_group_admin(_group_id int4) RETURNS boolean 51 | LANGUAGE SQL SECURITY DEFINER SET search_path = user_groups,public 52 | AS $$ 53 | select exists (select 1 from user_groups where user_id = auth.uid() and group_admin = true); 54 | $$; 55 | 56 | -- get all group ids the current user has 57 | -- called as (col = any (array(select user_groups.get_user_group_ids())) in RLS 58 | CREATE FUNCTION user_groups.get_user_group_ids() RETURNS int4[] 59 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = user_groups,public 60 | AS $$ 61 | begin 62 | return array (select group_id from user_groups where user_id = auth.uid()); 63 | end; 64 | $$; 65 | 66 | 67 | -- Typical policies to protect user_groups table and allow admin of it. 68 | -- postgres and service role have access by default. 69 | -- If you want to block service role you would need to remove grants for that role from the table. 70 | CREATE policy "User can read own rows" 71 | ON user_groups.user_groups 72 | FOR select 73 | TO authenticated 74 | USING (auth.uid()=user_id); 75 | CREATE policy "All Groups Admin can do all operations" 76 | ON user_groups.user_groups 77 | FOR all 78 | TO authenticated 79 | USING ((select user_groups.user_has_group_id(user_groups.get_id_from_group_name('GroupAdmin')))); 80 | CREATE policy "Group Admin can do all operations on Group" 81 | ON user_groups.user_groups 82 | FOR all 83 | TO authenticated 84 | USING ((select user_groups.user_is_this_group_admin(group_id))) 85 | -------------------------------------------------------------------------------- /images/img.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/img.png -------------------------------------------------------------------------------- /images/img1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/img1.png -------------------------------------------------------------------------------- /images/img_1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/img_1.png -------------------------------------------------------------------------------- /images/img_2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/img_2.png -------------------------------------------------------------------------------- /images/img_3.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/img_3.png -------------------------------------------------------------------------------- /images/img_4.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/img_4.png -------------------------------------------------------------------------------- /images/imgg1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/imgg1.png -------------------------------------------------------------------------------- /images/staff.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/staff.png -------------------------------------------------------------------------------- /images/students.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/GaryAustin1/custom-properties/41f8434fab75171b0fe4080c0d150d85bcc16b18/images/students.png -------------------------------------------------------------------------------- /properties.sql: -------------------------------------------------------------------------------- 1 | -- Right now the schema is hard coded to user_roles.... 2 | -- Note the schema name should reflect the type of property this is. For example user_roles, user_groups, user_teams, user_claims 3 | -- The schema name is also used as the default value in the OPTIONAL jwt app_metadata update trigger for the property name. 4 | 5 | DROP SCHEMA IF EXISTS user_roles cascade; 6 | CREATE SCHEMA user_roles; 7 | GRANT USAGE ON SCHEMA user_roles TO postgres, authenticated, service_role; 8 | 9 | -- This table is just used to enforce a set of names for properties. It is a more flexible approach than Postgres enums. 10 | CREATE TABLE user_roles.property_names ( 11 | property_name text primary key 12 | ); 13 | ALTER TABLE user_roles.property_names ENABLE ROW LEVEL SECURITY; 14 | 15 | -- Adding admin role. Postgres,service_role and an authenticated user with this property in the properties table can manage the table. 16 | INSERT INTO user_roles.property_names (property_name) VALUES 17 | ('PropertyAdmin'); 18 | 19 | CREATE TABLE user_roles.user_properties ( 20 | user_id UUID not null, 21 | property text , 22 | constraint fk_propertyname foreign key (property) references user_roles.property_names(property_name) on update cascade on delete cascade, 23 | constraint fk_user foreign key (user_id) references auth.users(id) on delete cascade, -- If you have a profile table you can link to that instead 24 | primary key (user_id,property) 25 | ); 26 | ALTER TABLE user_roles.user_properties ENABLE ROW LEVEL SECURITY; 27 | GRANT ALL ON user_roles.user_properties TO postgres,service_role,authenticated; -- note RLS also protects this table 28 | 29 | -- These are example functions for use in RLS. 30 | -- They depend on the auth.uid() of the user so are secure. 31 | -- They must be called like (select user_roles.user_has_property('Role')) with the outer parentheses and select or the performance will be greatly impacted. 32 | -- See https://github.com/GaryAustin1/RLS-Performance for more info on performance of functions in RLS. 33 | 34 | -- Match a property for the current user 35 | CREATE FUNCTION user_roles.user_has_property(_property text) RETURNS boolean 36 | LANGUAGE SQL SECURITY DEFINER SET search_path = user_roles,public 37 | AS $$ 38 | select exists (select 1 from user_properties where user_id = auth.uid() and property = _property); 39 | $$; 40 | 41 | -- Match any properties in array for the current user 42 | CREATE FUNCTION user_roles.user_property_in(_properties text[]) RETURNS boolean 43 | LANGUAGE SQL SECURITY DEFINER STABLE SET search_path = user_roles,public 44 | AS $$ 45 | select exists (select 1 from user_properties where user_id = auth.uid() and property = any (_properties)); 46 | $$; 47 | 48 | -- Match all properties in array for the current user 49 | CREATE FUNCTION user_roles.user_properties_match(_properties text[]) RETURNS boolean 50 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = user_roles,public 51 | AS $$ 52 | declare matches int; 53 | begin 54 | select count(*) into matches from user_properties where auth.uid() = user_id and property = any (_properties); 55 | return matches = array_length(_properties,1); 56 | end; 57 | $$; 58 | 59 | -- get all properties the current user has 60 | -- called as (col = any (array(select user_roles.get_user_properties())) in RLS 61 | 62 | CREATE FUNCTION user_roles.get_user_properties() RETURNS text[] 63 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = user_roles,public 64 | AS $$ 65 | begin 66 | return array (select property from user_properties where user_id = auth.uid()); 67 | end; 68 | $$; 69 | -- If for some reason you want the JWT and associated user object to also reflect the property(s) for the user then you can use a trigger function. 70 | -- The JWT will reflect the current properties after it is refreshed from the client. 71 | -- WARNING by default this codes sets the property type to the schema name 72 | -- The trigger is initially DISABLED IN THE CODE so as to not pollute the jwt. 73 | CREATE FUNCTION user_roles.update_to_app_metadata() returns trigger 74 | LANGUAGE plpgsql SECURITY DEFINER SET search_path = public 75 | as $$ 76 | declare 77 | _properties text[]; 78 | _id UUID; 79 | begin 80 | if (TG_OP = 'DELETE') then _id = old.user_id; 81 | else _id = new.user_id; 82 | end if; 83 | select array_agg(property) into _properties from user_roles.user_properties where user_id = _id; 84 | update auth.users set raw_app_meta_data = raw_app_meta_data || json_build_object('user_roles', _properties)::jsonb where id = _id; 85 | return new; 86 | end; 87 | $$; 88 | CREATE TRIGGER on_property_change 89 | after insert or update or delete on user_roles.user_properties 90 | for each row execute function user_roles.update_to_app_metadata(); 91 | ALTER TABLE user_roles.user_properties DISABLE TRIGGER on_property_change; -- Enable the trigger in the Dashboard or remove this if desired 92 | 93 | -- Typical policies to protect user_properites table and allow admin of it. 94 | -- postgres and service role have access by default. 95 | -- If you want to block service role you would need to remove grants for that role from the table. 96 | CREATE policy "User can read own rows" 97 | ON user_roles.user_properties 98 | FOR select 99 | TO authenticated 100 | USING (auth.uid()=user_id); 101 | CREATE policy "PropertyAdmin can do all operations" 102 | ON user_roles.user_properties 103 | FOR all 104 | TO authenticated 105 | USING ((select user_roles.user_has_property('PropertyAdmin'))); 106 | 107 | -------------------------------------------------------------------------------- /roles.sql: -------------------------------------------------------------------------------- 1 | -- This is a hardcoded version of custom_properties just for roles. 2 | 3 | -- This table is just used to enforce a set of names for properties. It is a more flexible approach than Postgres enums. 4 | CREATE TABLE custom_role_names ( 5 | role_name text primary key 6 | ); 7 | ALTER TABLE custom_role_names ENABLE ROW LEVEL SECURITY; 8 | 9 | -- Adding admin role. Postgres,service_role and an authenticated user with this property in the properties table can manage the table. 10 | INSERT INTO custom_role_names (role_name) VALUES 11 | ('RoleAdmin'); 12 | 13 | CREATE TABLE custom_user_roles ( 14 | user_id UUID not null, 15 | role text , 16 | constraint fk_rolename foreign key (role) references custom_role_names(role_name) on update cascade on delete cascade, 17 | constraint fk_user foreign key (user_id) references auth.users(id) on delete cascade, -- If you have a profile table you can link to that instead 18 | primary key (user_id,role) 19 | ); 20 | ALTER TABLE custom_user_roles ENABLE ROW LEVEL SECURITY; 21 | --GRANT ALL ON custom_user_properties TO postgres,service_role,authenticated; -- note RLS also protects this table 22 | 23 | -- These are example functions for use in RLS. 24 | -- They depend on the auth.uid() of the user so are secure. 25 | -- They must be called like (select user_has_role('Role')) with the outer parentheses and select or the performance will be greatly impacted. 26 | -- See https://github.com/GaryAustin1/RLS-Performance for more info on performance of functions in RLS. 27 | 28 | -- Match a role for the current user 29 | CREATE FUNCTION user_has_role(_role text) RETURNS boolean 30 | LANGUAGE SQL SECURITY DEFINER SET search_path = public 31 | AS $$ 32 | select exists (select 1 from custom_user_roles where user_id = auth.uid() and role = _role); 33 | $$; 34 | 35 | -- Match any roles in array for the current user 36 | CREATE FUNCTION user_role_in(_roles text[]) RETURNS boolean 37 | LANGUAGE SQL SECURITY DEFINER STABLE SET search_path = public 38 | AS $$ 39 | select exists (select 1 from custom_user_roles where user_id = auth.uid() and role = any (_roles)); 40 | $$; 41 | 42 | -- Match all roles in array for the current user 43 | CREATE FUNCTION user_roles_match(_roles text[]) RETURNS boolean 44 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = public 45 | AS $$ 46 | declare matches int; 47 | begin 48 | select count(*) into matches from custom_user_roles where auth.uid() = user_id and role = any (_roles); 49 | return matches = array_length(_roles,1); 50 | end; 51 | $$; 52 | 53 | -- get all roles the current user has 54 | -- called as (col = any (array(select get_user_roles())) in RLS 55 | 56 | CREATE FUNCTION get_user_roles() RETURNS text[] 57 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = public 58 | AS $$ 59 | begin 60 | return array (select role from custom_user_roles where user_id = auth.uid()); 61 | end; 62 | $$; 63 | -- If for some reason you want the JWT and associated user object to also reflect the roles(s) for the user then you can use a trigger function. 64 | -- The JWT will reflect the current roles after it is refreshed from the client. 65 | -- WARNING by default this codes sets the role type to the schema name 66 | -- The trigger is initially DISABLED IN THE CODE so as to not pollute the jwt. 67 | CREATE FUNCTION custom_roles_update_to_app_metadata() returns trigger 68 | LANGUAGE plpgsql SECURITY DEFINER SET search_path = public 69 | as $$ 70 | declare 71 | _roles text[]; 72 | _id UUID; 73 | begin 74 | if (TG_OP = 'DELETE') then _id = old.user_id; 75 | else _id = new.user_id; 76 | end if; 77 | select array_agg(role) into _roles from custom_user_roles where user_id = _id; 78 | update auth.users set raw_app_meta_data = raw_app_meta_data || json_build_object('user_roles', _roles)::jsonb where id = _id; 79 | return new; 80 | end; 81 | $$; 82 | CREATE TRIGGER on_custom_role_change 83 | after insert or update or delete on custom_user_roles 84 | for each row execute function custom_roles_update_to_app_metadata(); 85 | ALTER TABLE custom_user_roles DISABLE TRIGGER on_custom_role_change; -- Enable the trigger in the Dashboard or remove this if desired 86 | 87 | -- Typical policies to protect user_roles table and allow admin of it. 88 | -- postgres and service role have access by default. 89 | -- If you want to block service role you would need to remove grants for that role from the table. 90 | CREATE policy "User can read own rows" 91 | ON custom_user_roles 92 | FOR select 93 | TO authenticated 94 | USING (auth.uid()=user_id); 95 | CREATE policy "RoleAdmin can do all operations" 96 | ON custom_user_roles 97 | FOR all 98 | TO authenticated 99 | USING ((select user_has_role('RoleAdmin'))); 100 | 101 | -------------------------------------------------------------------------------- /test.sql: -------------------------------------------------------------------------------- 1 | -- This file is for testing table based roles versus jwt based roles peformance. 2 | -- Right now most setup is being done by hand for user id, properties, etc. 3 | -- This is not meant to be run as one large test, but are the pieces used to be able to test 4 | 5 | DROP TABLE IF EXISTS test_posts cascade; 6 | CREATE TABLE test_posts ( 7 | id serial primary key, 8 | creator_id uuid not null, 9 | title text not null, 10 | body text not null, 11 | for_role text not null, 12 | publish_date date not null default now() 13 | ); 14 | --change this for 1M or 100K 15 | ALTER TABLE test_posts ENABLE ROW LEVEL SECURITY; 16 | INSERT INTO test_posts (creator_id,title,body,for_role) 17 | select uuid_generate_v4(),'title-'||x,'body-'||x,'Student' 18 | from generate_series(1, 90000) x; 19 | INSERT INTO test_posts (creator_id,title,body,for_role) 20 | select uuid_generate_v4(),'title-'||x,'body-'||x,'Teacher' 21 | from generate_series(90001, 100000) x; 22 | INSERT INTO test_posts (creator_id,title,body,for_role) 23 | select uuid_generate_v4(),'title-'||x,'body-'||x,'Dean' 24 | from generate_series(100001, 101000) x; 25 | 26 | -- change policies here for testing 27 | 28 | DROP POLICY IF EXISTS "Teacher role can read these posts" on test_posts; 29 | CREATE POLICY "Teacher role can read these posts" 30 | on test_posts 31 | for select 32 | using ( 33 | get_my_claim('role')::text = '"Teacher"' 34 | --(select get_my_claim('role')::text) = '"Teacher"' --jwt method 35 | --(select user_roles.user_has_property('Teacher')) 36 | -- (select user_roles.user_property_in('{"Teacher","Staff"}')) 37 | --for_role = any (array(select user_roles.get_user_properties())) 38 | --for_role = (select get_my_claim('role')->>0) -- jwt method 39 | ); 40 | -- ADD roles for test 41 | INSERT INTO user_roles.property_names(property_name) VALUES ('Teacher'),('Student'),('Administrator'),('Coach'),('Dean'); 42 | --Using existing UUIDs in my test instance 43 | INSERT INTO user_roles.user_properties (user_id,property) VALUES 44 | ('d7124d4a-22e7-49d7-87a4-55ad09cd5783'::UUID,'Teacher'), 45 | ('c8fc722a-22fb-4483-aab7-6c2be88bc03c'::UUID,'Student'), 46 | ('2eaa730d-bbb0-478c-bde6-d51890e8bd28'::UUID,'Student'), 47 | ('679e25e3-5402-4c9f-87b3-793af97540ae'::UUID,'Student'), 48 | ('722498ac-0a23-4f94-b3c6-bed52f1d7f3d'::UUID,'Dean'); 49 | 50 | DROP TABLE IF EXISTS user_profiles; 51 | CREATE TABLE user_profiles ( 52 | user_id UUID, 53 | name text, 54 | email text, 55 | age int2 56 | ); 57 | INSERT INTO user_profiles (user_id,name,email,age) VALUES 58 | ('d7124d4a-22e7-49d7-87a4-55ad09cd5783'::UUID,'Dave Jennings','djenning@fabercollege.org',40), 59 | ('c8fc722a-22fb-4483-aab7-6c2be88bc03c'::UUID,'John "Bluto" Blutarsky','jbb@deltahouse.org',32), 60 | ('2eaa730d-bbb0-478c-bde6-d51890e8bd28'::UUID,'Eric "Otter" Stratton','eos@deltahouse.org',23), 61 | ('679e25e3-5402-4c9f-87b3-793af97540ae'::UUID,'Kent "Flounder" Dorfman','kfd@deltahouse.org',24), 62 | ('722498ac-0a23-4f94-b3c6-bed52f1d7f3d'::UUID,'Vernon Wormer','vwormer@fabercollege.org',50); 63 | -- demo view 64 | create view 65 | public.student_view with (security_invoker = true) as 66 | select 67 | u.user_id, 68 | u.property, 69 | p.name, 70 | p.email 71 | from 72 | user_roles.user_properties u 73 | join user_profiles as p on p.user_id = u.user_id 74 | where 75 | u.property = 'Student'::text; 76 | 77 | create view 78 | public.college_staff_view with (security_invoker = true) as 79 | select 80 | u.user_id, 81 | u.property, 82 | p.name, 83 | p.email 84 | from 85 | user_roles.user_properties u 86 | join user_profiles as p on p.user_id = u.user_id 87 | where 88 | u.property =any ('{"Dean","Teacher"}'); 89 | -- generate a custom_claims function for checking role. 90 | CREATE OR REPLACE FUNCTION get_my_claim(claim TEXT) RETURNS "jsonb" 91 | LANGUAGE "sql" STABLE 92 | AS $$ 93 | select 94 | coalesce(nullif(current_setting('request.jwt.claims', true), '')::jsonb -> 'app_metadata' -> claim, null) 95 | $$; 96 | --- Change out roles to test with Dean, Teacher, Student 97 | update auth.users set raw_app_meta_data = 98 | raw_app_meta_data || 99 | json_build_object('role', 'Teacher')::jsonb where id = 'c8fc722a-22fb-4483-aab7-6c2be88bc03c'::UUID; 100 | 101 | update auth.users set raw_app_meta_data = 102 | raw_app_meta_data || 103 | json_build_object('role', 'Teacher')::jsonb where id = 'd7124d4a-22e7-49d7-87a4-55ad09cd5783'::UUID; 104 | 105 | set session role authenticated; 106 | set request.jwt.claims to '{"role":"authenticated", "sub":"c8fc722a-22fb-4483-aab7-6c2be88bc03c", "app_metadata":{"role":"Student"}}'; 107 | --explain analyze SELECT * FROM test_posts; 108 | select get_my_claim('role')->>'role'; 109 | set session role postgres; 110 | -------------------------------------------------------------------------------- /tle-custom-properties/README.md: -------------------------------------------------------------------------------- 1 | ### TLE for custom-properties 2 | 3 | Please see https://github.com/GaryAustin1/custom-properties for more info. 4 | 5 | You can use the TLE install method to install custom-properties. 6 | You need to run the SQL here to install the TLE installer: [dbdev](https://supabase.github.io/dbdev/install-in-db-client/) 7 | Once you have the installer loaded: 8 | 9 | Create a custom schema to load a copy of custom-properties into. 10 | Note this schema name should be meaningful like `roles`, `user_roles`, `custom_teams`, etc. 11 | The schema name will be used to call functions from RLS and as the name for the property in the app_metadata jwt if you decide to use that. 12 | 13 | In the SQL editor: 14 | ```sql 15 | create extension user_roles; 16 | ``` 17 | 18 | The TLE will assign basic grants to service_role, authenticated and postgres roles. 19 | 20 | Next install the TLE using the SQL editor: 21 | ```sql 22 | select dbdev.install('garyaustin-custom_properties'); 23 | create extension "garyaustin-custom_properties" 24 | schema user_roles 25 | version '0.0.1'; 26 | ``` 27 | 28 | Two tables will be created in the schema. 29 | property_names -- Has a property admin "role" added. Add your property names in the table UI or with SQL inserts. 30 | user_properties -- You insert user UUID, property_name pairs into this table for one or more properties per user. 31 | 32 | Five functions will be created in the schema. 33 | user_has_property('Teacher') - returns boolean 34 | user_property_in('{"Teacher","Staff"}') - returns boolean - {} is string format for array in Postgres 35 | user_properties_match('{"Teacher","Staff"}') - returns boolean - must match all roles in array 36 | get_user_properties() - returns array - if user has over 1000 properties performance should be studied 37 | update_to_app_metadata() - trigger function - updates app_metadata with an array of properties for user 38 | 39 | Check the main readme for more info on how to add policies to your tables. 40 | You MUST use the example methods for calling the functions to have performant results. 41 | 42 | If you want your user JWTs updated with your property data, please enable the trigger function found in the custom schema you created. 43 | This can be done in the UI or with SQL. 44 | 45 | All management of your properties is done with standard table selects/inserts/updates/deletes and views. 46 | The user_properties table can only be updated by postgres, service_role and an authenticated user with the PropertyAdmin property. 47 | Authenticated users can only read their own properties. 48 | If you desire to access or manage the properties from the API you need to use the Dashboard and goto API settings. 49 | Add your new schema to make it available thru the API. 50 | 51 | 52 | 53 | 54 | 55 | -------------------------------------------------------------------------------- /tle-custom-properties/custom_properties--0.0.3.sql: -------------------------------------------------------------------------------- 1 | -- Note the schema name should reflect the type of property this is. For example user_roles, user_groups, user_teams, user_claims. 2 | -- The schema name is also used as the default value in the OPTIONAL jwt app_metadata update trigger for the property name. 3 | -- This trigger is disabled by default. 4 | -- You may want to change user_id fk to your profile table user_id if you have by dropping and adding the fk_user constraint. 5 | 6 | GRANT USAGE ON SCHEMA @extschema@ TO postgres, authenticated, service_role; 7 | 8 | -- This table is just used to enforce a set of names for properties. It is a more flexible approach than Postgres enums. 9 | CREATE TABLE @extschema@.property_names ( 10 | property_name text primary key 11 | ); 12 | ALTER TABLE @extschema@.property_names ENABLE ROW LEVEL SECURITY; 13 | 14 | -- Adding admin role. Postgres,service_role and an authenticated user with this property in the properties table can manage the table. 15 | INSERT INTO @extschema@.property_names (property_name) VALUES 16 | ('PropertyAdmin'); 17 | 18 | CREATE TABLE @extschema@.user_properties ( 19 | user_id UUID not null, 20 | property text , 21 | constraint fk_propertyname foreign key (property) references @extschema@.property_names(property_name) on update cascade on delete cascade, 22 | constraint fk_user foreign key (user_id) references auth.users(id) on delete cascade, -- If you have a profile table you can link to that instead 23 | primary key (user_id,property) 24 | ); 25 | ALTER TABLE @extschema@.user_properties ENABLE ROW LEVEL SECURITY; 26 | GRANT ALL ON @extschema@.user_properties TO postgres,service_role,authenticated; -- note RLS also protects this table 27 | 28 | -- These are example functions for use in RLS. 29 | -- They depend on the auth.uid() of the user so are secure. 30 | -- They must be called like (select user_roles.user_has_property('PropertyName')) with the outer parentheses and select or the performance will be greatly impacted. 31 | -- See https://github.com/GaryAustin1/RLS-Performance for more info on performance of functions in RLS. 32 | 33 | -- Match a property for the current user 34 | CREATE FUNCTION @extschema@.user_has_property(_property text) RETURNS boolean 35 | LANGUAGE SQL SECURITY DEFINER SET search_path = @extschema@,public 36 | AS $$ 37 | select exists (select 1 from user_properties where user_id = auth.uid() and property = _property); 38 | $$; 39 | 40 | -- Match any properties in array for the current user 41 | CREATE FUNCTION @extschema@.user_property_in(_properties text[]) RETURNS boolean 42 | LANGUAGE SQL SECURITY DEFINER STABLE SET search_path = @extschema@,public 43 | AS $$ 44 | select exists (select 1 from user_properties where user_id = auth.uid() and property = any (_properties)); 45 | $$; 46 | 47 | -- Match all properties in array for the current user 48 | CREATE FUNCTION @extschema@.user_properties_match(_properties text[]) RETURNS boolean 49 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = @extschema@,public 50 | AS $$ 51 | declare matches int; 52 | begin 53 | select count(*) into matches from user_properties where auth.uid() = user_id and property = any (_properties); 54 | return matches = array_length(_properties,1); 55 | end; 56 | $$; 57 | 58 | -- get all properties the current user has 59 | -- called as (col = any (array(select user_roles.get_user_properties())) in RLS 60 | 61 | CREATE FUNCTION @extschema@.get_user_properties() RETURNS text[] 62 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = @extschema@,public 63 | AS $$ 64 | begin 65 | return array (select property from user_properties where user_id = auth.uid()); 66 | end; 67 | $$; 68 | -- If for some reason you want the JWT and associated user object to also reflect the property(s) for the user then you can use a trigger function. 69 | -- The JWT will reflect the current properties after it is refreshed from the client. 70 | -- WARNING by default this codes sets the property type to the schema name 71 | -- The trigger is initially DISABLED IN THE CODE so as to not pollute the jwt. 72 | CREATE FUNCTION @extschema@.update_to_app_metadata() returns trigger 73 | LANGUAGE plpgsql SECURITY DEFINER SET search_path = public 74 | as $$ 75 | declare 76 | _properties text[]; 77 | _id UUID; 78 | begin 79 | if (TG_OP = 'DELETE') then _id = old.user_id; 80 | else _id = new.user_id; 81 | end if; 82 | select array_agg(property) into _properties from @extschema@.user_properties where user_id = _id; 83 | update auth.users set raw_app_meta_data = raw_app_meta_data || json_build_object('@extschema@', _properties)::jsonb where id = _id; 84 | return new; 85 | end; 86 | $$; 87 | CREATE TRIGGER on_property_change 88 | after insert or update or delete on @extschema@.user_properties 89 | for each row execute function @extschema@.update_to_app_metadata(); 90 | ALTER TABLE @extschema@.user_properties DISABLE TRIGGER on_property_change; -- Enable the trigger in the Dashboard or remove this if desired 91 | 92 | -- Typical policies to protect user_properites table and allow admin of it. 93 | -- postgres and service role have access by default. 94 | -- If you want to block service role you would need to remove grants for that role from the table. 95 | CREATE policy "User can read own rows" 96 | ON @extschema@.user_properties 97 | FOR select 98 | TO authenticated 99 | USING (auth.uid()=user_id); 100 | CREATE policy "PropertyAdmin can do all operations" 101 | ON @extschema@.user_properties 102 | FOR all 103 | TO authenticated 104 | USING ((select @extschema@.user_has_property('PropertyAdmin'))); 105 | 106 | 107 | -------------------------------------------------------------------------------- /tle-custom-properties/custom_properties.control: -------------------------------------------------------------------------------- 1 | # custom_properties extension 2 | comment = 'custom_properties.' 3 | default_version = '0.0.4' 4 | superuser = false 5 | -------------------------------------------------------------------------------- /tle-custom-roles/README.md: -------------------------------------------------------------------------------- 1 | ### TLE for custom-roles 2 | 3 | Please see https://github.com/GaryAustin1/custom-properties for more info. 4 | 5 | This is a role specific version of custom-properties. It runs in public or any schema you select. 6 | 7 | You can use the TLE install method to install custom-roles. 8 | You need to run the SQL here to install the TLE installer: [dbdev](https://supabase.github.io/dbdev/install-in-db-client/) 9 | Once you have the installer loaded: 10 | 11 | Install the TLE using the SQL editor: 12 | ```sql 13 | select dbdev.install('garyaustin-custom_roles'); 14 | create extension "garyaustin-custom_roles" 15 | schema public 16 | version '0.0.2'; 17 | ``` 18 | 19 | Two tables will be created in the schema. 20 | custom_role_names -- Has a role admin "role" added. Add your role names in the table UI or with SQL inserts. 21 | custom_user_roles -- You insert user UUID, role_name pairs into this table for one or more roles per user. 22 | 23 | Five functions will be created in the schema. 24 | user_has_role('Teacher') - returns boolean 25 | user_role_in('{"Teacher","Staff"}') - returns boolean - {} is string format for array in Postgres 26 | user_roles_match('{"Teacher","Staff"}') - returns boolean - must match all roles in array 27 | get_user_roles() - returns array - if user has over 1000 roles performance should be studied 28 | custom_roles_update_to_app_metadata() - trigger function - updates app_metadata with an array of roles for user 29 | 30 | Check the main readme for more info on how to add policies to your tables. 31 | You MUST use the example methods in the main respository for calling the functions to have performant results. 32 | As an example in an RLS policy you need to wrap the functions with parenthesis and select like `(select user_has_role('Teacher'))`. 33 | 34 | If you want your user JWTs updated with your role data, please enable the trigger custom_role_change. 35 | This can be done in the UI or with SQL. 36 | 37 | All management of your roles is done with standard table selects/inserts/updates/deletes and views. 38 | The custom_user_roles table can only be updated by postgres, service_role and an authenticated user with the RoleAdmin role. 39 | Authenticated users can only read their own roles. 40 | 41 | 42 | 43 | 44 | 45 | 46 | -------------------------------------------------------------------------------- /tle-custom-roles/custom_roles--0.0.3.sql: -------------------------------------------------------------------------------- 1 | -- This is a hardcoded version of custom_properties just for roles. 2 | 3 | -- This table is just used to enforce a set of names for properties. It is a more flexible approach than Postgres enums. 4 | CREATE TABLE custom_role_names ( 5 | role_name text primary key 6 | ); 7 | ALTER TABLE custom_role_names ENABLE ROW LEVEL SECURITY; 8 | 9 | -- Adding admin role. Postgres,service_role and an authenticated user with this property in the properties table can manage the table. 10 | INSERT INTO custom_role_names (role_name) VALUES 11 | ('RoleAdmin'); 12 | 13 | CREATE TABLE custom_user_roles ( 14 | user_id UUID not null, 15 | role text , 16 | constraint fk_rolename foreign key (role) references custom_role_names(role_name) on update cascade on delete cascade, 17 | constraint fk_user foreign key (user_id) references auth.users(id) on delete cascade, -- If you have a profile table you can link to that instead 18 | primary key (user_id,role) 19 | ); 20 | ALTER TABLE custom_user_roles ENABLE ROW LEVEL SECURITY; 21 | --GRANT ALL ON custom_user_properties TO postgres,service_role,authenticated; -- note RLS also protects this table 22 | 23 | -- These are example functions for use in RLS. 24 | -- They depend on the auth.uid() of the user so are secure. 25 | -- They must be called like (select user_has_role('Role')) with the outer parentheses and select or the performance will be greatly impacted. 26 | -- See https://github.com/GaryAustin1/RLS-Performance for more info on performance of functions in RLS. 27 | 28 | -- Match a role for the current user 29 | CREATE FUNCTION user_has_role(_role text) RETURNS boolean 30 | LANGUAGE SQL SECURITY DEFINER SET search_path = public 31 | AS $$ 32 | select exists (select 1 from custom_user_roles where user_id = auth.uid() and role = _role); 33 | $$; 34 | 35 | -- Match any roles in array for the current user 36 | CREATE FUNCTION user_role_in(_roles text[]) RETURNS boolean 37 | LANGUAGE SQL SECURITY DEFINER STABLE SET search_path = public 38 | AS $$ 39 | select exists (select 1 from custom_user_roles where user_id = auth.uid() and role = any (_roles)); 40 | $$; 41 | 42 | -- Match all roles in array for the current user 43 | CREATE FUNCTION user_roles_match(_roles text[]) RETURNS boolean 44 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = public 45 | AS $$ 46 | declare matches int; 47 | begin 48 | select count(*) into matches from custom_user_roles where auth.uid() = user_id and role = any (_roles); 49 | return matches = array_length(_roles,1); 50 | end; 51 | $$; 52 | 53 | -- get all roles the current user has 54 | -- called as (col = any (array(select get_user_roles())) in RLS 55 | 56 | CREATE FUNCTION get_user_roles() RETURNS text[] 57 | LANGUAGE plpgsql SECURITY DEFINER STABLE SET search_path = public 58 | AS $$ 59 | begin 60 | return array (select role from custom_user_roles where user_id = auth.uid()); 61 | end; 62 | $$; 63 | -- If for some reason you want the JWT and associated user object to also reflect the roles(s) for the user then you can use a trigger function. 64 | -- The JWT will reflect the current roles after it is refreshed from the client. 65 | -- WARNING by default this codes sets the role type to the schema name 66 | -- The trigger is initially DISABLED IN THE CODE so as to not pollute the jwt. 67 | CREATE FUNCTION custom_roles_update_to_app_metadata() returns trigger 68 | LANGUAGE plpgsql SECURITY DEFINER SET search_path = public 69 | as $$ 70 | declare 71 | _roles text[]; 72 | _id UUID; 73 | begin 74 | if (TG_OP = 'DELETE') then _id = old.user_id; 75 | else _id = new.user_id; 76 | end if; 77 | select array_agg(role) into _roles from custom_user_roles where user_id = _id; 78 | update auth.users set raw_app_meta_data = raw_app_meta_data || json_build_object('user_roles', _roles)::jsonb where id = _id; 79 | return new; 80 | end; 81 | $$; 82 | CREATE TRIGGER on_custom_role_change 83 | after insert or update or delete on custom_user_roles 84 | for each row execute function custom_roles_update_to_app_metadata(); 85 | ALTER TABLE custom_user_roles DISABLE TRIGGER on_custom_role_change; -- Enable the trigger in the Dashboard or remove this if desired 86 | 87 | -- Typical policies to protect user_roles table and allow admin of it. 88 | -- postgres and service role have access by default. 89 | -- If you want to block service role you would need to remove grants for that role from the table. 90 | CREATE policy "User can read own rows" 91 | ON custom_user_roles 92 | FOR select 93 | TO authenticated 94 | USING (auth.uid()=user_id); 95 | CREATE policy "RoleAdmin can do all operations" 96 | ON custom_user_roles 97 | FOR all 98 | TO authenticated 99 | USING ((select user_has_role('RoleAdmin'))); 100 | 101 | -------------------------------------------------------------------------------- /tle-custom-roles/custom_roles.control: -------------------------------------------------------------------------------- 1 | # custom_roles extension 2 | comment = 'custom_roles.' 3 | default_version = '0.0.4' 4 | superuser = false 5 | --------------------------------------------------------------------------------