├── README.md └── tests ├── Supabase-Docs-Test ├── readme.md └── sbt.sql ├── cleanup.sql ├── test1-indexed ├── test1.js └── test1.sql ├── test2a-wrappedSQL-uid() ├── test2a.js └── test2a.sql ├── test2b-wrappedSQL-isadmin() ├── test2b.js └── test2b.sql ├── test2c-wrappedSQL-two-functions └── test2c.sql ├── test2d-wrappedSQL-sd-fun └── test2d.sql ├── test2e-wrappedSQL-sd-fun-array └── test2e.sql ├── test2f-wrappedSQL-sdfunarray-1Mrows └── test2f.sql ├── test3-addfilter ├── test3.js └── test3.sql ├── test5-fixed-join └── test5.sql └── test6-To-role └── test6.sql /README.md: -------------------------------------------------------------------------------- 1 | 2 | ## RLS Performance and Best Practices 3 | 4 | Although most of the time spent on thinking about RLS is to get it to handle security needs, the impact of it on performance 5 | of your queries can be massive. 6 | This is especially true on queries that look at every row in a table like for many select operations and updates. 7 | Note that queries that use limit and offset will usually have to query all rows to determine order, not just the limit amount so they are impacted too. 8 | 9 | Please see the [last section](#tools-to-measure-performance) for ways to measure the performance of your queries as you test RLS improvements. 10 | 11 | ### Is RLS causing my performance issue (on a single table query)? 12 | 13 | For very slow queries, or if using the tools at end of article, run a query with RLS enabled on the table and then with it disabled. If the results are similar then your query itself is likely the performance issue. Although, remember any join tables in RLS will also need to run their RLS unless a security definer function is used to bypass them. 14 | 15 | ### How to improve RLS performance. 16 | 17 | The following tips are very broad and each may or may not help the specific case involved. Some changes, like adding indexes, should be backed out if they do not make a difference in RLS performance and you are not using them for filtering performance. 18 | 19 | #### (1) The first thing to try is put an index on columns used in the RLS that are not primary keys or unique already. 20 | For RLS like: 21 | `auth.uid() = user_id` 22 | Add an index like: 23 | `create index userid on test_table using btree (user_id) tablespace pg_default;` 24 | Improvement seen over 100x on large tables. 25 | 26 | #### (2) Another method to improve performance is to wrap your RLS queries and functions in select statements. 27 | This method works well for jwt functions like auth.uid() and auth.jwt() as well as any other functions including security definer type. 28 | Wrapping the function in some SQL causes an initPlan to be run by the optimizer which allows it to "cache" the results versus calling the function 29 | on each row. 30 | WARNING: You can only do this if the results of the query or function do not change based on the row data. 31 | For RLS like this: 32 | `is_admin() or auth.uid() = user_id` 33 | Use this instead: 34 | `(select is_admin()) OR (select auth.uid()) = user_id` 35 | 36 |
37 | is_admin() function: 38 | 39 | ```sql 40 | CREATE OR REPLACE FUNCTION is_admin() 41 | RETURNS boolean as 42 | $$ 43 | begin 44 | return exists(select from rlstest_roles where auth.uid() = user_id and role = 'admin'); 45 | end; 46 | $$ language plpgsql security definer; 47 | ``` 48 |
49 | 50 | #### (3) Do not rely on RLS for filtering but only for security. 51 | Instead of doing this (JS client example): 52 | `.from('table').select()` 53 | With an RLS policy of: 54 | `auth.uid() = user_id` 55 | Add a filter in addition to the RLS: 56 | `.from('table').select().eq('user_id',userId)` 57 | 58 | #### (4) Use security definer functions to do queries on other tables to bypass their RLS when possible. 59 | Instead of having this RLS where the roles_table has an RLS select policy of `auth.uid() = user_id`: 60 | `exists (select 1 from roles_table where auth.uid() = user_id and role = 'good_role')` 61 | Create a security definer function has_role() and do: 62 | `(select has_role())` with code of `exists (select 1 from roles_table where auth.uid() = user_id and role = 'good_role')` 63 | Note that you should wrap your security definer function in select if it is a fixed value per 2. 64 | Remember functions you use in RLS can be called from the API. 65 | Secure your functions in an alternate schema if their results would be a security leak. 66 | Warning: If your security definer function uses row information as an input parameter be sure to test performance as you can't wrap the function as in 2. 67 |
68 | has_role() function: 69 | 70 | ```sql 71 | CREATE OR REPLACE FUNCTION has_role() 72 | RETURNS boolean as 73 | $$ 74 | begin 75 | return exists (select 1 from roles_table where auth.uid() = user_id and role = 'good_role') 76 | end; 77 | $$ language plpgsql security definer; 78 | ``` 79 |
80 | 81 | #### (5) Always optimize join queries to compare row columns to fixed join data. 82 | Instead of querying on a row column in a join table WHERE, organize your query to get all 83 | the column values that meet your query into an array or set. 84 | Then use an IN or ANY operation to filter against the row column. 85 | This RLS to allow select only for rows where the team_id is one the user has access to: 86 | `auth.uid() in (select user_id from team_user where team_user.team_id = table.team_id)` 87 | will be much slower than: 88 | `team_id in (select team_id from team_user where user_id = auth.uid())` 89 | Also consider moving the join query to a security definer function to avoid RLS on join table: 90 | `team_id in (select user_teams())` 91 | Note that if the `in` list gets to be over 10K items, then extra analysis is likely needed. See this follow up testing: https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/Supabase-Docs-Test . 92 | 93 | #### (6) Use role in TO option or roles dropdown in the dashboard. 94 | Never just use RLS involving auth.uid() or auth.jwt() as your way to rule out 'anon' role. 95 | Always add 'authenticated' to the approved roles instead of nothing or public. 96 | Although this does not improve the query performance for the signed in user it does 97 | eliminate 'anon' users without taxing the database to process the rest of the RLS. 98 | 99 | ### Sample results 100 | 101 | The code used for the below tests can be found here: [LINK](/tests): 102 | The tests are doing selects on a 100K row table. Some have an additional join table. 103 | 104 | Show RLS and before after for above examples. 105 | 106 | | Test | RLS Before | RLS After | SQL| SQL 107 | |-----|------------------------|---------------------------|------|------| 108 | | 1 | auth.uid()=user_id |user_id indexed | 171ms| <.1| 109 | | 2a| auth.uid()=user_id |(select auth.uid()) = user_id|179|9| 110 | |2b|is_admin() *table join* | (select is_admin()) *table join*| 11,000 | 7 | 111 | |2c|is_admin() OR auth.uid()=user_id|(select is_admin()) OR (select auth.uid()=user_id)|11,000|10| 112 | |2d|has_role()=role|(select has_role())=role|178,000|12| 113 | |2e|team_id=any(user_teams())|team_id=any(array(select user_teams()))|173000|16| 114 | |3| auth.uid()=user_id| add .eq or where on user_id | 171 | 9 | 115 | |5| auth.uid() in *table join on col* | col in *table join on auth.uid()*| 9,000 | 20 | 116 | |6| No TO policy | TO authenticated (anon accessing) | 170 | <.1 | 117 | 118 | ### Tools to measure performance 119 | 120 | Postgres has tools to analyze the peformance of queries. https://www.postgresql.org/docs/current/sql-explain.html 121 | The use of explain in detail for query analysis is beyond the scope of this discussion. 122 | Here we will use it mainly to get a performance metric to compare times. 123 | In order to do RLS testing you need to setup the user jwt claims and change the running user to `anon` or `authenticated`. 124 | ```sql 125 | set session role authenticated; 126 | set request.jwt.claims to '{"role":"authenticated", "sub":"5950b438-b07c-4012-8190-6ce79e4bd8e5"}'; 127 | 128 | explain analyze SELECT count(*) FROM rlstest; 129 | set session role postgres; 130 | ``` 131 | This will return results like: 132 | ``` 133 | Seq Scan on rlstest (cost=0.00..4334.00 rows=1 width=35) (actual time=170.999..170.999 rows=0 loops=1) 134 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id)" 135 | Rows Removed by Filter: 100000 136 | Planning Time: 0.216 ms 137 | Execution Time: 171.033 ms 138 | ``` 139 | In this case the execution time is the critical number we need to compare. 140 | 141 | 142 | PostgREST allows use of explain to get performance information on your queries with Supabase clients. 143 | 144 | Before using this feature you need to run the following command in the Dashboad SQL editor (should not be used in production): 145 | ```sql 146 | alter role authenticator set pgrst.db_plan_enabled to true; 147 | NOTIFY pgrst, 'reload config'; 148 | ``` 149 | Then you can use the .explain() modifier to get performance metrics. 150 | ```js 151 | const { data, error } = await supabase 152 | .from('projects') 153 | .select('*') 154 | .eq('id', 1) 155 | .explain({ analyze: true }) 156 | 157 | console.log(data) 158 | ``` 159 | This will return a result like: 160 | ``` 161 | Aggregate (cost=8.18..8.20 rows=1 width=112) (actual time=0.017..0.018 rows=1 loops=1) 162 | -> Index Scan using projects_pkey on projects (cost=0.15..8.17 rows=1 width=40) (actual time=0.012..0.012 rows=0 loops=1) 163 | Index Cond: (id = 1) 164 | Filter: false 165 | Rows Removed by Filter: 1 166 | Planning Time: 0.092 ms 167 | Execution Time: 0.046 ms 168 | ``` 169 | 170 | *These two github discussions cover the history that lead to this analysis... 171 | 172 | [Stable functions do not seem to be honored in RLS in basic form](https://github.com/orgs/supabase/discussions/9311) 173 | [current_setting can lead to bad performance when used on RLS](https://github.com/PostgREST/postgrest-docs/issues/609#) 174 | Thanks Steve Chavez and Wolfgang Walther in those threads. 175 | 176 | ### Added example of security definer function having select of a team table, comparing against a column in main table 177 | The example is in the test data as test2f. 178 | In this case we start with a 1M row table with a team_id column. 179 | We have a 1000 row team table that has user_ids and team(s) they belong too. 180 | Basic RLS for a select would be `team_id = ANY(user_teams())` 181 | This case times out with over 3 minutes as 1M rows must be searched and the function is run each time on 1000 rows. 182 | Changing to wrap the function (method 2) `team_id = ANY(ARRAY(select user_teams()))` is a big improvement but can still take seconds. 183 | Adding an index to team_id is the big win, but only with the second case. Without, the index case still times out. 184 | 185 |
186 | user_teams() function returning an array: 187 | 188 | ```sql 189 | CREATE OR REPLACE FUNCTION user_teams() 190 | RETURNS int[] as 191 | $$ 192 | begin 193 | return array( select team_id from team_user where auth.uid() = user_id); 194 | end; 195 | $$ language plpgsql security definer; 196 | ``` 197 |
198 | 199 | Some results: 200 | 201 | | Policy |Index| Main Rs | Team Rs | on 10 teams | 100 | 500 |note| 202 | |-----|--|-----|------|--------|-----|---|---| 203 | |=ANY(user_teams())|no|1M|1000|>2Min|>2Min|>2Min|TO or killed| 204 | |=ANY(user_teams())|yes|1M|1000|>2Min|>2Min|>2Min|TO or killed| 205 | |=ANY(ARRAY(select user_teams()))|no|1M|1000|170ms|700|3300| | 206 | |=ANY(ARRAY(select user_teams()))|yes|1M|1000|2ms|3|3| | 207 | |in(1,2,3...100)|no|1M|NA|130ms|142|x|baseline check| 208 | |=ANY(ARRAY(select user_teams()))|yes|1M|10K|x|x|x|24ms (on 1K teams)| 209 | 210 | 211 | 212 | 213 | 214 | 215 | -------------------------------------------------------------------------------- /tests/Supabase-Docs-Test/readme.md: -------------------------------------------------------------------------------- 1 | Did an additional test on Supabase Docs RLS guide [Advanced policies](https://supabase.com/docs/guides/auth/row-level-security#advanced-policies) 2 | 3 | ![image](https://github.com/GaryAustin1/RLS-Perfomance/assets/54564956/9939ae7a-96a8-4d98-8cb3-953b09ee6213) 4 | 5 | Using method 5 for the comments policy and method 2 for the posts policy had significant impact. 6 | See https://github.com/GaryAustin1/RLS-Perfomance for methods 7 | 8 | Tested with 100K comments, 100k posts and both 10k and 1K posts by the test user. 9 | 10 | |Table|Example Policy|(Method) Policy|Posts by User| 11 | |---------|--------------|-----------|--------------| 12 | |comments|204ms/773ms(JS)|(5) 43ms/43ms(JS)|10000| 13 | |comments|190ms |(5) 29ms |1000| 14 | |posts|173ms/841ms(JS)|(2) 12ms/38ms(JS) |10000| 15 | 16 | comments table policy 17 | Example: `exists (select 1 from posts where posts.id = comments.post_id)` 18 | Method 5: `post_id in (select id from posts where creator_id = (select auth.uid()))` 19 | 20 | posts table policy 21 | Example: `select auth.uid() = posts.creator_id` 22 | Method 2: `(select auth.uid()) = posts.creator_id` 23 | 24 | 25 | Notes: At some point method 5 does not make much sense as the list it builds up can get very large. 26 | The method clearly makes sense for most cases, especially if the join table is smaller than the main table, or the row being filtered on is a small subset. 27 | But I tested 50K Posts by the user and the optimizer still chose that method, but time was up to 80ms. 28 | At 90K posts by the user the optimizer picked another method, but did not break. 29 | Note this article https://www.dbi-services.com/blog/what-is-the-maximum-in-list-size-in-postgresql/ had the list up to 2M for the `in` and then at 3M ran out of memory. 30 | So at a minimum probably need a note to think about the size of the `in` list when it is some % more of the main table rows. 31 | 32 | 33 | Some other "bad" examples from that page... 34 | ``` 35 | create policy "Team members can update team details if they belong to the team." 36 | on teams 37 | for update using ( 38 | auth.uid() in ( 39 | select user_id from members 40 | where team_id = id 41 | ) 42 | ); 43 | ``` 44 | This works because it is on an update, but probably better to show it as: 45 | ``` 46 | create policy "Team members can update team details if they belong to the team." 47 | on teams 48 | for update using ( 49 | id in ( 50 | select team_id from members 51 | where user_id = auth.uid() 52 | ) 53 | ); 54 | ``` 55 | As that would make a huge difference if that policy is used for select also. 56 | 57 | 58 | 59 | -------------------------------------------------------------------------------- /tests/Supabase-Docs-Test/sbt.sql: -------------------------------------------------------------------------------- 1 | -- WARNING CleanUp does not include this test! 2 | -- Checking RLS performance of Supabase docs RLS guide for posts/comment table 3 | -- https://supabase.com/docs/guides/auth/row-level-security#advanced-policies 4 | -- 5 | -- Using 100K posts and comments table with 1000 or 10000 posts for the user being tested. 6 | -- comments > Example 204ms/773ms(JS), Method 5 43ms/43ms(JS) 100k/100k/10000 7 | -- comments > Example 190ms, Method 5 29ms 100k/100k/1000 8 | -- posts > Example 173ms/841ms(JS), Method 2 12ms/38ms(JS) 100K/100k/10000 9 | 10 | drop table if exists posts cascade; 11 | create table posts ( 12 | id serial primary key, 13 | creator_id uuid not null, 14 | title text not null, 15 | body text not null, 16 | publish_date date not null default now(), 17 | audience uuid[] null -- many to many table omitted for brevity 18 | ); 19 | alter table posts ENABLE ROW LEVEL SECURITY; 20 | 21 | drop table if exists comments; 22 | create table comments ( 23 | id serial primary key, 24 | post_id int not null references posts(id) on delete cascade, 25 | user_id uuid not null, 26 | body text not null, 27 | comment_date date not null default now() 28 | ); 29 | alter table comments ENABLE ROW LEVEL SECURITY; 30 | 31 | INSERT INTO posts (creator_id,title,body) 32 | select uuid_generate_v4(),'title-'||x,'body-'||x 33 | from generate_series(1, 100000) x; 34 | 35 | update posts set creator_id = '70225db6-b0ba-4116-9b08-6b25f33bb70a' where id < 10000; 36 | 37 | INSERT INTO comments (post_id,user_id,body) 38 | select (x/10+1)::int,uuid_generate_v4(),'body-'||x 39 | from generate_series(1, 100000) x; 40 | 41 | create policy "Creator can see their own posts" 42 | on posts 43 | for select 44 | using ( 45 | auth.uid() = posts.creator_id 46 | --(select auth.uid()) = posts.creator_id 47 | ); 48 | 49 | create policy "Users can see all comments for posts they have access to." 50 | on comments 51 | for select 52 | using ( 53 | exists (select 1 from posts where posts.id = comments.post_id) -- SB example 54 | --post_id in (select posts.id from posts where posts.creator_id = (select auth.uid())) 55 | ); 56 | 57 | set session role authenticated; 58 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 59 | 60 | explain analyze SELECT * FROM comments; 61 | 62 | set session role postgres; 63 | 64 | /* 65 | -- comments policy in SB example exists (select 1 from posts where posts.id = comments.post_id) 66 | -- 100K posts, 100k comments, 1000 posts by user 67 | 68 | Seq Scan on comments (cost=0.00..195914.94 rows=38364 width=60) (actual time=173.407..189.983 rows=9989 loops=1) 69 | Filter: (hashed SubPlan 2) 70 | Rows Removed by Filter: 90011 71 | SubPlan 2 72 | -> Seq Scan on posts (cost=0.00..2761.20 rows=260 width=4) (actual time=171.283..173.150 rows=999 loops=1) 73 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = creator_id)" 74 | Rows Removed by Filter: 99001 75 | Planning Time: 0.305 ms 76 | Execution Time: 190.433 ms 77 | 78 | ************ 79 | -- comments policy SB example 80 | -- 100K posts, 100k comments, 10000 posts by user 81 | 82 | Seq Scan on comments (cost=0.00..195914.94 rows=38364 width=60) (actual time=176.874..201.639 rows=99989 loops=1) 83 | Filter: (hashed SubPlan 2) 84 | Rows Removed by Filter: 11 85 | SubPlan 2 86 | -> Seq Scan on posts (cost=0.00..3009.82 rows=283 width=4) (actual time=155.791..174.533 rows=9999 loops=1) 87 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = creator_id)" 88 | Rows Removed by Filter: 90001 89 | Planning Time: 0.312 ms 90 | Execution Time: 205.770 ms 91 | JS 92 | Execution Time: 772.951 ms 93 | 94 | *************** 95 | -- comments policy post_id in (select id from posts where creator_id = (select auth.uid())) 96 | -- 100k posts, 100k comments, 10000 posts by user 97 | 98 | Seq Scan on comments (cost=1737.20..3530.30 rows=38364 width=60) (actual time=14.159..39.396 rows=99989 loops=1) 99 | Filter: (hashed SubPlan 2) 100 | Rows Removed by Filter: 11 101 | SubPlan 2 102 | -> Result (cost=0.06..1736.50 rows=283 width=4) (actual time=9.894..12.173 rows=9999 loops=1) 103 | " One-Time Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = $0)" 104 | InitPlan 1 (returns $0) 105 | -> Result (cost=0.00..0.03 rows=1 width=16) (actual time=0.004..0.004 rows=1 loops=1) 106 | -> Seq Scan on posts (cost=0.06..1736.50 rows=283 width=4) (actual time=9.874..11.275 rows=9999 loops=1) 107 | Filter: (creator_id = $0) 108 | Rows Removed by Filter: 90001 109 | Planning Time: 0.250 ms 110 | Execution Time: 43.530 ms 111 | JS (10K row limit) 112 | Execution Time: 43.293 ms 113 | 114 | ************* 115 | -- comments policy post_id in (select posts.id from posts where posts.creator_id = (select auth.uid())) 116 | -- 100k posts, 100k comments, 1000 posts by user 117 | 118 | Seq Scan on comments (cost=0.00..254584.00 rows=50000 width=38) (actual time=17.354..29.686 rows=9 loops=1) 119 | Filter: (hashed SubPlan 2) 120 | Rows Removed by Filter: 99991 121 | SubPlan 2 122 | -> Seq Scan on posts (cost=0.00..444.03 rows=1 width=4) (actual time=17.334..17.337 rows=1 loops=1) 123 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = creator_id)" 124 | Rows Removed by Filter: 10000 125 | Planning Time: 0.445 ms 126 | Execution Time: 29.733 ms 127 | 128 | ******************** 129 | -- posts policy in SB example auth.uid() = posts.creator_id 130 | -- 100K posts, 10000 posts by user 131 | 132 | Seq Scan on posts (cost=0.00..3009.82 rows=283 width=120) (actual time=153.847..172.398 rows=9999 loops=1) 133 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = creator_id)" 134 | Rows Removed by Filter: 90001 135 | Planning Time: 0.230 ms 136 | Execution Time: 172.892 ms 137 | 138 | JS 139 | Execution Time: 841.288 ms 140 | 141 | 142 | ******** 143 | -- posts policy (select auth.uid()) = posts.creator_id 144 | -- 100K posts, 10000 posts by user 145 | 146 | Seq Scan on posts (cost=0.03..1736.47 rows=283 width=120) (actual time=9.947..11.169 rows=9999 loops=1) 147 | Filter: ($0 = creator_id) 148 | Rows Removed by Filter: 90001 149 | InitPlan 1 (returns $0) 150 | -> Result (cost=0.00..0.03 rows=1 width=16) (actual time=0.014..0.015 rows=1 loops=1) 151 | Planning Time: 0.198 ms 152 | Execution Time: 11.617 ms 153 | JS 154 | Execution Time: 37.972 ms 155 | 156 | */ 157 | -------------------------------------------------------------------------------- /tests/cleanup.sql: -------------------------------------------------------------------------------- 1 | drop table if exists rlstest; 2 | drop table if exists rlstest_roles; 3 | drop table if exists rlstest_team_user; 4 | drop function if exists rlstest_is_admin; 5 | drop function if exists rlstest_user_teams; 6 | drop function if exists get_role(); 7 | -------------------------------------------------------------------------------- /tests/test1-indexed/test1.js: -------------------------------------------------------------------------------- 1 | // Test of auth.uid() = user_id. Depends on SQL running first. 2 | const result = await supabase1 3 | .from('rlstest',{head:true}) 4 | .select() 5 | .explain({ analyze: true }) 6 | console.log('explain test', result) 7 | 8 | /* 9 | With no index on user_id: 10 | 11 | Aggregate (cost=2940.18..2940.21 rows=1 width=112) (actual time=731.615..731.616 rows=1 loops=1) 12 | -> Limit (cost=0.00..2935.68 rows=300 width=84) (actual time=731.605..731.605 rows=0 loops=1) 13 | -> Seq Scan on rlstest (cost=0.00..2935.68 rows=300 width=84) (actual time=731.603..731.604 rows=0 loops=1) 14 | Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id) 15 | Rows Removed by Filter: 100000 16 | Planning Time: 0.351 ms 17 | Execution Time: 731.663 ms 18 | 19 | 20 | With index on user_id: 21 | 22 | Aggregate (cost=2.67..2.70 rows=1 width=112) (actual time=0.041..0.042 rows=1 loops=1) 23 | -> Limit (cost=0.44..2.66 rows=1 width=35) (actual time=0.035..0.036 rows=0 loops=1) 24 | -> Index Scan using userid on rlstest (cost=0.44..2.66 rows=1 width=35) (actual time=0.035..0.035 rows=0 loops=1) 25 | Index Cond: (user_id = (COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid) 26 | Planning Time: 0.202 ms 27 | Execution Time: 0.085 ms 28 | */ 29 | -------------------------------------------------------------------------------- /tests/test1-indexed/test1.sql: -------------------------------------------------------------------------------- 1 | --Test indexed column in RLS with auth.uid() 2 | --remove -- in front of create index for second run. 3 | 4 | drop table if exists rlstest; 5 | create table 6 | rlstest as 7 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 8 | from generate_series(1, 100000) x; 9 | 10 | alter table rlstest ENABLE ROW LEVEL SECURITY; 11 | 12 | create policy "rls_test_select" on rlstest 13 | to authenticated 14 | using ( 15 | auth.uid() = user_id 16 | ); 17 | 18 | --create index userid on rlstest using btree (user_id) tablespace pg_default; 19 | 20 | set session role authenticated; 21 | set request.jwt.claims to '{"role":"authenticated", "sub":"5950b438-b07c-4012-8190-6ce79e4bd8e5"}'; 22 | 23 | explain analyze SELECT count(*) FROM rlstest; 24 | set session role postgres; 25 | 26 | /* 27 | Run with index commented out: 28 | 29 | Seq Scan on rlstest (cost=0.00..4334.00 rows=1 width=35) (actual time=170.999..170.999 rows=0 loops=1) 30 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id)" 31 | Rows Removed by Filter: 100000 32 | Planning Time: 0.216 ms 33 | Execution Time: 171.033 ms 34 | 35 | Run with index added in: 36 | 37 | Bitmap Heap Scan on rlstest (cost=6.52..421.36 rows=500 width=84) (actual time=0.024..0.024 rows=0 loops=1) 38 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id)" 39 | -> Bitmap Index Scan on userid (cost=0.00..6.39 rows=500 width=0) (actual time=0.022..0.022 rows=0 loops=1) 40 | " Index Cond: (user_id = (COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid)" 41 | Planning Time: 0.284 ms 42 | Execution Time: 0.054 ms 43 | 44 | */ 45 | 46 | -------------------------------------------------------------------------------- /tests/test2a-wrappedSQL-uid()/test2a.js: -------------------------------------------------------------------------------- 1 | // Wrapping a function in a select. 2a with auth.uid(). 2 | // Run SQL first 3 | 4 | const result = await supabase1 5 | .from('rlstest',{head:true}) 6 | .select() 7 | .explain({ analyze: true }) 8 | console.log('explain test', result) 9 | 10 | /* 11 | Just auth.uid() = user_id in RLS: 12 | 13 | Aggregate (cost=4334.02..4334.04 rows=1 width=112) (actual time=735.015..735.016 rows=1 loops=1) 14 | -> Limit (cost=0.00..4334.00 rows=1 width=35) (actual time=734.987..734.988 rows=1 loops=1) 15 | -> Seq Scan on rlstest (cost=0.00..4334.00 rows=1 width=35) (actual time=734.986..734.987 rows=1 loops=1) 16 | Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id) 17 | Rows Removed by Filter: 99999 18 | Planning Time: 0.416 ms 19 | Execution Time: 735.064 ms 20 | 21 | Using (select auth.uid()) = user_id in RLS 22 | 23 | Aggregate (cost=1589.13..1589.16 rows=1 width=112) (actual time=10.373..10.374 rows=1 loops=1) 24 | -> Limit (cost=0.03..1584.63 rows=300 width=84) (actual time=10.341..10.342 rows=1 loops=1) 25 | InitPlan 1 (returns $0) 26 | -> Result (cost=0.00..0.03 rows=1 width=16) (actual time=0.048..0.049 rows=1 loops=1) 27 | -> Seq Scan on rlstest (cost=0.00..1584.60 rows=300 width=84) (actual time=10.339..10.340 rows=1 loops=1) 28 | Filter: ($0 = user_id) 29 | Rows Removed by Filter: 99999 30 | Planning Time: 0.321 ms 31 | Execution Time: 10.425 ms 32 | */ 33 | -------------------------------------------------------------------------------- /tests/test2a-wrappedSQL-uid()/test2a.sql: -------------------------------------------------------------------------------- 1 | --Wrapping a postgres function in a select. Auth.uid() example. (indexed is better way for this) 2 | --Change using() commented values for tests 3 | 4 | drop table if exists rlstest; 5 | create table 6 | rlstest as 7 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 8 | from generate_series(1, 100000) x; 9 | update rlstest set (user_id,role) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a','admin') where id = 1; 10 | alter table rlstest ENABLE ROW LEVEL SECURITY; 11 | 12 | create policy "rls_test_select" on rlstest 13 | to authenticated 14 | using ( 15 | (select auth.uid()) = user_id 16 | --auth.uid() = user_id 17 | ); 18 | 19 | set session role authenticated; 20 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 21 | 22 | explain analyze SELECT count(*) FROM rlstest; 23 | 24 | set session role postgres; 25 | 26 | /* 27 | Run with just auth.uid() = user_id: 28 | 29 | Aggregate (cost=2936.43..2936.44 rows=1 width=8) (actual time=179.368..179.369 rows=1 loops=1) 30 | -> Seq Scan on rlstest (cost=0.00..2935.68 rows=300 width=0) (actual time=179.362..179.363 rows=1 loops=1) 31 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id)" 32 | Rows Removed by Filter: 99999 33 | Planning Time: 0.180 ms 34 | Execution Time: 179.408 ms 35 | 36 | Run with added filter in query: 37 | 38 | Aggregate (cost=1585.38..1585.38 rows=1 width=8) (actual time=8.709..8.710 rows=1 loops=1) 39 | -> Result (cost=0.02..1584.62 rows=300 width=0) (actual time=8.701..8.702 rows=1 loops=1) 40 | " One-Time Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = '5950b438-b07c-4012-8190-6ce79e4bd8e5'::uuid)" 41 | -> Seq Scan on rlstest (cost=0.02..1584.62 rows=300 width=0) (actual time=8.686..8.687 rows=1 loops=1) 42 | Filter: (user_id = '5950b438-b07c-4012-8190-6ce79e4bd8e5'::uuid) 43 | Rows Removed by Filter: 99999 44 | Planning Time: 0.176 ms 45 | Execution Time: 8.759 ms 46 | 47 | */ 48 | -------------------------------------------------------------------------------- /tests/test2b-wrappedSQL-isadmin()/test2b.js: -------------------------------------------------------------------------------- 1 | // Wrapped is_admin test() 2 | // Run SQL first 3 | // Requires signed in user 4 | 5 | const result = await supabase1 6 | .from('rlstest',{head:true}) 7 | .select() 8 | .explain({ analyze: true }) 9 | console.log('explain test', result) 10 | 11 | /* 12 | Using is_admin(): 13 | Error timeout... canceling statement due to statement timeout 14 | 15 | 16 | Using wrapped (select(is_admin())): 17 | 18 | Aggregate (cost=61.94..61.97 rows=1 width=112) (actual time=7.093..7.094 rows=1 loops=1) 19 | CTE pgrst_source 20 | -> Limit (cost=0.26..36.94 rows=1000 width=35) (actual time=7.081..7.081 rows=0 loops=1) 21 | InitPlan 1 (returns $0) 22 | -> Result (cost=0.00..0.26 rows=1 width=1) (actual time=0.628..0.628 rows=1 loops=1) 23 | -> Seq Scan on rlstest (cost=0.00..1834.00 rows=50000 width=35) (actual time=7.079..7.079 rows=0 loops=1) 24 | Filter: $0 25 | Rows Removed by Filter: 100000 26 | -> CTE Scan on pgrst_source (cost=0.00..20.00 rows=1000 width=84) (actual time=7.082..7.082 rows=0 loops=1) 27 | Planning Time: 0.233 ms 28 | Execution Time: 7.144 ms 29 | 30 | */ 31 | -------------------------------------------------------------------------------- /tests/test2b-wrappedSQL-isadmin()/test2b.sql: -------------------------------------------------------------------------------- 1 | -- Testing wrapping SQL around a typical security definer function that checks if the user has a role from a 2nd table. 2 | -- Change using() between commented testrls_is_admin() and (select(testrls_is_admin())) 3 | 4 | 5 | drop table if exists rlstest; 6 | create table 7 | rlstest as 8 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 9 | from generate_series(1, 100000) x; 10 | update rlstest set (user_id,role) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a','admin') where id = 1; 11 | alter table rlstest ENABLE ROW LEVEL SECURITY; 12 | 13 | drop table if exists rlstest_roles; 14 | create table 15 | rlstest_roles as 16 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 17 | from generate_series(1, 1000) x; 18 | update rlstest_roles set (user_id,role) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a','user') where id = 1; 19 | alter table rlstest_roles ENABLE ROW LEVEL SECURITY; 20 | 21 | CREATE OR REPLACE FUNCTION rlstest_is_admin() 22 | RETURNS boolean as 23 | $$ 24 | begin 25 | return exists(select 1 from rlstest_roles where auth.uid() = user_id and role = 'admin'); 26 | end; 27 | $$ language plpgsql security definer; 28 | 29 | create policy "rls_test_select" on rlstest 30 | to authenticated 31 | using ( 32 | (select rlstest_is_admin()) 33 | --rlstest_is_admin() --very slow! 34 | ); 35 | 36 | set session role authenticated; 37 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 38 | 39 | explain analyze SELECT count(*) FROM rlstest; 40 | 41 | set session role postgres; 42 | 43 | 44 | /* 45 | With is_admin() as RLS: 46 | 47 | Aggregate (cost=16496.52..16496.53 rows=1 width=8) (actual time=11578.737..11578.738 rows=1 loops=1) 48 | -> Seq Scan on rlstest (cost=0.00..16446.48 rows=20016 width=0) (actual time=0.433..11561.735 rows=100000 loops=1) 49 | Filter: is_admin() 50 | Planning Time: 0.087 ms 51 | Execution Time: 11578.815 ms <<< Result (cost=0.00..0.26 rows=1 width=1) (actual time=0.520..0.521 rows=1 loops=1) 58 | -> Seq Scan on rlstest (cost=0.00..1434.48 rows=30024 width=0) (actual time=7.380..7.380 rows=0 loops=1) 59 | Filter: $0 60 | Rows Removed by Filter: 100000 61 | Planning Time: 0.099 ms 62 | Execution Time: 7.429 ms 63 | 64 | */ 65 | -------------------------------------------------------------------------------- /tests/test2c-wrappedSQL-two-functions/test2c.sql: -------------------------------------------------------------------------------- 1 | -- Testing wrapping SQL around two functions 2 | -- Change using() with commented options 3 | 4 | 5 | drop table if exists rlstest; 6 | create table 7 | rlstest as 8 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 9 | from generate_series(1, 100000) x; 10 | update rlstest set (user_id,role) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a','admin') where id = 1; 11 | alter table rlstest ENABLE ROW LEVEL SECURITY; 12 | 13 | drop table if exists rlstest_roles; 14 | create table 15 | rlstest_roles as 16 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 17 | from generate_series(1, 1000) x; 18 | update rlstest_roles set (user_id,role) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a','user') where id = 1; 19 | alter table rlstest_roles ENABLE ROW LEVEL SECURITY; 20 | 21 | CREATE OR REPLACE FUNCTION rlstest_is_admin() 22 | RETURNS boolean as 23 | $$ 24 | begin 25 | return exists(select 1 from rlstest_roles where auth.uid() = user_id and role = 'admin'); 26 | end; 27 | $$ language plpgsql security definer; 28 | 29 | create policy "rls_test_select" on rlstest 30 | to authenticated 31 | using ( 32 | --(select (rlstest_is_admin() OR auth.uid() = user_id)) -- very slow 33 | --rlstest_is_admin() OR auth.uid() = user_id --very slow1 34 | (select rlstest_is_admin()) OR (select auth.uid()) = user_id --fast 35 | ); 36 | 37 | set session role authenticated; 38 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 39 | 40 | explain analyze SELECT count(*) FROM rlstest; 41 | 42 | set session role postgres; 43 | 44 | 45 | /* 46 | With is_admin() or auth.uid() = user_id as RLS: 47 | Note adding select (is_admin() or auth.uid() = user_id gets same result. 48 | 49 | Aggregate (cost=18623.22..18623.23 rows=1 width=8) (actual time=11785.022..11785.023 rows=1 loops=1) 50 | -> Seq Scan on rlstest (cost=0.00..18548.16 rows=30024 width=0) (actual time=11785.017..11785.018 rows=1 loops=1) 51 | Filter: (SubPlan 1) 52 | Rows Removed by Filter: 99999 53 | SubPlan 1 54 | -> Result (cost=0.00..0.29 rows=1 width=1) (actual time=0.117..0.117 rows=1 loops=100000) 55 | Planning Time: 0.180 ms 56 | Execution Time: 11785.109 ms 57 | 58 | 59 | With (select is_admin()) OR (select auth.uid) = user_id as RLS: 60 | 61 | Aggregate (cost=1660.33..1660.34 rows=1 width=8) (actual time=9.999..10.001 rows=1 loops=1) 62 | InitPlan 1 (returns $0) 63 | -> Result (cost=0.00..0.26 rows=1 width=1) (actual time=0.356..0.356 rows=1 loops=1) 64 | InitPlan 2 (returns $1) 65 | -> Result (cost=0.00..0.03 rows=1 width=16) (actual time=0.005..0.006 rows=1 loops=1) 66 | -> Seq Scan on rlstest (cost=0.00..1584.60 rows=30174 width=0) (actual time=9.992..9.993 rows=1 loops=1) 67 | Filter: ($0 OR ($1 = user_id)) 68 | Rows Removed by Filter: 99999 69 | Planning Time: 0.173 ms 70 | Execution Time: 10.049 ms 71 | 72 | */ 73 | -------------------------------------------------------------------------------- /tests/test2d-wrappedSQL-sd-fun/test2d.sql: -------------------------------------------------------------------------------- 1 | -- Testing wrapping SQL around a security definer function getting role based on auth.uid() from a 2nd table. 2 | -- Change using() between commented get_role() and (select(get_role())) 3 | -- Note it is as silly function, but was reusing tables. It could have getting user's teams to match on rows. 4 | 5 | 6 | drop table if exists rlstest; 7 | create table 8 | rlstest as 9 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 10 | from generate_series(1, 100000) x; 11 | update rlstest set (user_id,role) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a','admin') where id = 1; 12 | alter table rlstest ENABLE ROW LEVEL SECURITY; 13 | 14 | drop table if exists rlstest_roles; 15 | create table 16 | rlstest_roles as 17 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 18 | from generate_series(1, 1000) x; 19 | update rlstest_roles set (user_id,role) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a','admin') where id = 1; 20 | alter table rlstest_roles ENABLE ROW LEVEL SECURITY; 21 | 22 | CREATE OR REPLACE FUNCTION get_role() 23 | RETURNS text as 24 | $$ 25 | begin 26 | return (select role from rlstest_roles where auth.uid() = user_id); 27 | end; 28 | $$ language plpgsql security definer; 29 | 30 | create policy "rls_test_select" on rlstest 31 | to authenticated 32 | using ( 33 | --(select get_role())=role 34 | get_role() =role --very slow! 35 | ); 36 | 37 | set session role authenticated; 38 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 39 | 40 | explain analyze SELECT count(*) FROM rlstest; 41 | 42 | set session role postgres; 43 | 44 | 45 | /* 46 | with get_role = role 47 | 48 | Aggregate (cost=16597.35..16597.36 rows=1 width=8) (actual time=173484.219..173484.220 rows=1 loops=1) 49 | -> Seq Scan on rlstest (cost=0.00..16596.60 rows=300 width=0) (actual time=173484.213..173484.214 rows=1 loops=1) 50 | Filter: (get_role() = role) 51 | Rows Removed by Filter: 99999 52 | Planning Time: 0.092 ms 53 | Execution Time: 173484.300 ms !!!!!!!!!!!!!!!!!!!! 54 | 55 | 56 | with (select get_role())=role 57 | 58 | InitPlan 1 (returns $0) 59 | -> Result (cost=0.00..0.26 rows=1 width=32) (actual time=2.047..2.047 rows=1 loops=1) 60 | -> Seq Scan on rlstest (cost=0.00..2084.00 rows=100000 width=0) (actual time=12.425..12.425 rows=1 loops=1) 61 | Filter: ($0 = role) 62 | Rows Removed by Filter: 99999 63 | Planning Time: 0.137 ms 64 | Execution Time: 12.475 ms 65 | 66 | 67 | */ 68 | -------------------------------------------------------------------------------- /tests/test2e-wrappedSQL-sd-fun-array/test2e.sql: -------------------------------------------------------------------------------- 1 | -- Testing wrapping SQL around a security definer function getting role based on auth.uid() from a 2nd table. 2 | -- Change using() between commented policies 3 | 4 | drop table if exists rlstest; 5 | create table 6 | rlstest as 7 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role, x as team_id 8 | from generate_series(1, 100000) x; 9 | alter table rlstest ENABLE ROW LEVEL SECURITY; 10 | 11 | drop table if exists rlstest_team_user; 12 | create table 13 | rlstest_team_user as 14 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id,x as team_id 15 | from generate_series(1, 1000) x; 16 | update rlstest_team_user set (user_id,team_id) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a',1) where id = 1; 17 | update rlstest_team_user set (user_id,team_id) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a',2) where id = 2; 18 | 19 | alter table rlstest_team_user ENABLE ROW LEVEL SECURITY; 20 | create policy "dummy_read_policy" on rlstest_team_user 21 | to authenticated using (auth.uid() = user_id ); 22 | 23 | CREATE OR REPLACE FUNCTION rlstest_user_teams() 24 | RETURNS int[] as 25 | $$ 26 | begin 27 | return array( select team_id from rlstest_team_user where auth.uid() = user_id); 28 | end; 29 | $$ language plpgsql security definer; 30 | 31 | create policy "rls_test_select" on rlstest 32 | to authenticated 33 | using ( 34 | team_id = any ( array(select rlstest_user_teams())) 35 | --team_id = any(rlstest_user_teams()) 36 | ); 37 | 38 | set session role authenticated; 39 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 40 | 41 | explain analyze SELECT * FROM rlstest; 42 | 43 | set session role postgres; 44 | 45 | 46 | /* 47 | With team_id = any(rlstest_user_teams()): 48 | 49 | Seq Scan on rlstest (cost=0.00..16742.55 rows=2854 width=88) (actual time=2.050..173925.695 rows=2 loops=1) 50 | Filter: (team_id = ANY (rlstest_user_teams())) 51 | Rows Removed by Filter: 99998 52 | Planning Time: 0.171 ms 53 | Execution Time: 173925.763 ms 54 | 55 | 56 | With team_id = any ( array(select rlstest_user_teams()))...: 57 | 58 | 59 | Execution Time: 19.676 ms 60 | Seq Scan on rlstest (cost=0.26..2147.81 rows=2854 width=88) (actual time=2.080..16.484 rows=2 loops=1) 61 | Filter: (team_id = ANY ($0)) 62 | Rows Removed by Filter: 99998 63 | InitPlan 1 (returns $0) 64 | -> Result (cost=0.00..0.26 rows=1 width=32) (actual time=2.063..2.063 rows=1 loops=1) 65 | Planning Time: 0.124 ms 66 | Execution Time: 16.520 ms 67 | 68 | 69 | */ 70 | 71 | -------------------------------------------------------------------------------- /tests/test2f-wrappedSQL-sdfunarray-1Mrows/test2f.sql: -------------------------------------------------------------------------------- 1 | -- Testing wrapping SQL around a security definer function getting role based on auth.uid() from a 2nd table. 2 | -- Change using() between commented policies 1MILLON ROWS add/remove index by comment 3 | -- Many minutes without wrapping the function. Adding index does not help on its own without wrapping. 4 | 5 | drop table if exists rlstest; 6 | create table 7 | rlstest as 8 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role, x as team_id 9 | from generate_series(1, 1000000) x; 10 | alter table rlstest ENABLE ROW LEVEL SECURITY; 11 | 12 | create index team on rlstest using btree (user_id) tablespace pg_default; 13 | 14 | drop table if exists rlstest_team_user; 15 | create table 16 | rlstest_team_user as 17 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id,x as team_id 18 | from generate_series(1, 1000) x; 19 | update rlstest_team_user set user_id = '70225db6-b0ba-4116-9b08-6b25f33bb70a' where id <100 ; 20 | 21 | --create index teams2 on rlstest_team_user using btree (user_id,team_id) tablespace pg_default; 22 | 23 | alter table rlstest_team_user ENABLE ROW LEVEL SECURITY; 24 | create policy "dummy_read_policy" on rlstest_team_user 25 | to authenticated using (auth.uid() = user_id ); 26 | 27 | CREATE OR REPLACE FUNCTION rlstest_user_teams() 28 | RETURNS int[] as 29 | $$ 30 | begin 31 | return array( select team_id from rlstest_team_user where auth.uid() = user_id); 32 | end; 33 | $$ language plpgsql security definer; 34 | drop policy rls_test_select on rlstest; 35 | create policy "rls_test_select" on rlstest 36 | to authenticated 37 | using ( 38 | -- team_id in (1,2,3,4,5,6,7,8,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100) 39 | team_id = any ( array(select rlstest_user_teams())) 40 | --team_id = any(rlstest_user_teams()) --VERY VERY LONG 41 | ); 42 | 43 | set session role authenticated; 44 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 45 | 46 | explain analyse select * FROM rlstest order by id limit 1000; 47 | 48 | set session role postgres; 49 | 50 | /* 51 | --Hardcoding:100teams 52 | Gather (cost=1000.25..19078.68 rows=99 width=40) (actual time=0.282..142.843 rows=99 loops=1) 53 | Workers Planned: 1 54 | Workers Launched: 0 55 | -> Parallel Seq Scan on rlstest (cost=0.25..18068.78 rows=58 width=40) (actual time=0.053..142.518 rows=99 loops=1) 56 | " Filter: (team_id = ANY ('{1,2,3,4,5,6,7,8,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100}'::integer[]))" 57 | Rows Removed by Filter: 999901 58 | Planning Time: 0.163 ms 59 | Execution Time: 142.872 ms 60 | 61 | --100teams 62 | Seq Scan on rlstest (cost=0.26..31745.26 rows=10 width=40) (actual time=2.136..721.356 rows=2 loops=1) 63 | Filter: (team_id = ANY ($0)) 64 | Rows Removed by Filter: 999998 65 | InitPlan 1 (returns $0) 66 | -> Result (cost=0.00..0.26 rows=1 width=32) (actual time=2.092..2.092 rows=1 loops=1) 67 | Planning Time: 0.093 ms 68 | Execution Time: 721.392 ms 69 | 70 | --100 teams indexed main table on team_id... 71 | Bitmap Heap Scan on rlstest (cost=534.11..10879.13 rows=48890 width=88) (actual time=3.147..3.150 rows=2 loops=1) 72 | Recheck Cond: (team_id = ANY ($0)) 73 | Heap Blocks: exact=1 74 | InitPlan 1 (returns $0) 75 | -> Result (cost=0.00..0.26 rows=1 width=32) (actual time=2.528..2.528 rows=1 loops=1) 76 | -> Bitmap Index Scan on team (cost=0.00..521.62 rows=48890 width=0) (actual time=3.128..3.128 rows=2 loops=1) 77 | Index Cond: (team_id = ANY ($0)) 78 | Planning Time: 0.939 ms 79 | Execution Time: 3.189 ms 80 | 81 | --10k team table, user in 1000 teams (ANY has 1000 entries), indexed main on team_id... 82 | Index Scan using team on rlstest (cost=0.69..16.79 rows=10 width=40) (actual time=17.623..24.358 rows=999 loops=1) 83 | Index Cond: (team_id = ANY ($0)) 84 | InitPlan 1 (returns $0) 85 | -> Result (cost=0.00..0.26 rows=1 width=32) (actual time=17.579..17.579 rows=1 loops=1) 86 | Planning Time: 0.820 ms 87 | Execution Time: 24.442 ms 88 | 89 | -- 1k team table, 100 teams, add compound index to teams table, no index on main, and no wrap 90 | Limit (cost=187328.11..187330.61 rows=1000 width=88) (actual time=60922.988..60923.003 rows=99 loops=1) 91 | -> Sort (cost=187328.11..187407.20 rows=31639 width=88) (actual time=60922.987..60922.994 rows=99 loops=1) 92 | Sort Key: id 93 | Sort Method: quicksort Memory: 32kB 94 | -> Seq Scan on rlstest (cost=0.00..185593.38 rows=31639 width=88) (actual time=2.812..60922.954 rows=99 loops=1) 95 | Filter: (team_id = ANY (rlstest_user_teams())) 96 | Rows Removed by Filter: 999901 97 | Planning Time: 0.156 ms 98 | Execution Time: 60923.091 ms 99 | 100 | --1k team table, 100 teams, compound index on teams and team_id index on rlstest, no wrap 101 | Limit (cost=284425.59..284428.09 rows=1000 width=88) (actual time=57184.204..57184.219 rows=99 loops=1) 102 | -> Sort (cost=284425.59..284547.81 rows=48890 width=88) (actual time=57184.202..57184.209 rows=99 loops=1) 103 | Sort Key: id 104 | Sort Method: quicksort Memory: 32kB 105 | -> Seq Scan on rlstest (cost=0.00..281745.00 rows=48890 width=88) (actual time=0.473..57184.171 rows=99 loops=1) 106 | Filter: (team_id = ANY (rlstest_user_teams())) 107 | Rows Removed by Filter: 999901 108 | Planning Time: 1.008 ms 109 | Execution Time: 57184.305 ms 110 | 111 | 112 | --Indexed Row only with 100 and 500 teams just calling function 113 | Times out 114 | 115 | */ 116 | -------------------------------------------------------------------------------- /tests/test3-addfilter/test3.js: -------------------------------------------------------------------------------- 1 | // Run test3 SQL first. 2 | 3 | // Without Filter 4 | const result = await supabase1 5 | .from('rlstest',{head:true}) 6 | .select() 7 | .explain({ analyze: true }) 8 | console.log('explain test', result) 9 | 10 | // With filter 11 | const result = await supabase1 12 | .from('rlstest',{head:true}) 13 | .select() 14 | .eq('user_id','70225db6-b0ba-4116-9b08-6b25f33bb70a') // user id of row added in sql and signed in user id. 15 | .explain({ analyze: true }) 16 | console.log('explain test', result) 17 | 18 | /* 19 | Without filter: 20 | 21 | Aggregate (cost=4334.02..4334.04 rows=1 width=112) (actual time=740.389..740.390 rows=1 loops=1) 22 | -> Limit (cost=0.00..4334.00 rows=1 width=35) (actual time=740.363..740.364 rows=1 loops=1) 23 | -> Seq Scan on rlstest (cost=0.00..4334.00 rows=1 width=35) (actual time=740.361..740.362 rows=1 loops=1) 24 | Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id) 25 | Rows Removed by Filter: 99999 26 | Planning Time: 0.172 ms 27 | Execution Time: 740.436 ms 28 | 29 | With filter: 30 | 31 | Aggregate (cost=2084.04..2084.07 rows=1 width=112) (actual time=9.564..9.565 rows=1 loops=1) 32 | -> Limit (cost=0.02..2084.03 rows=1 width=35) (actual time=9.533..9.535 rows=1 loops=1) 33 | -> Result (cost=0.02..2084.03 rows=1 width=35) (actual time=9.532..9.533 rows=1 loops=1) 34 | One-Time Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = '70225db6-b0ba-4116-9b08-6b25f33bb70a'::uuid) 35 | -> Seq Scan on rlstest (cost=0.02..2084.03 rows=1 width=35) (actual time=9.507..9.508 rows=1 loops=1) 36 | Filter: (user_id = '70225db6-b0ba-4116-9b08-6b25f33bb70a'::uuid) 37 | Rows Removed by Filter: 99999 38 | Planning Time: 0.345 ms 39 | Execution Time: 9.619 ms 40 | 41 | 42 | 43 | 44 | 45 | */ 46 | -------------------------------------------------------------------------------- /tests/test3-addfilter/test3.sql: -------------------------------------------------------------------------------- 1 | -- Using a filter even though RLS does filter the results 2 | -- Run this SQL before js tests 3 | -- WARNING You must use the UUID of a real user for this test to work with the javascript client test. 4 | 5 | drop table if exists rlstest; 6 | create table 7 | rlstest as 8 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 9 | from generate_series(1, 100000) x; 10 | update rlstest set (user_id,role) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a','admin') where id = 1; 11 | alter table rlstest ENABLE ROW LEVEL SECURITY; 12 | 13 | create policy "rls_test_select" on rlstest 14 | to authenticated 15 | using ( 16 | auth.uid() = user_id 17 | ); 18 | 19 | set session role authenticated; 20 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 21 | 22 | --explain analyze SELECT count(*) FROM rlstest; 23 | explain analyze SELECT count(*) FROM rlstest where user_id = '70225db6-b0ba-4116-9b08-6b25f33bb70a'; 24 | 25 | set session role postgres; 26 | 27 | /* 28 | Run with just auth.uid() in RLS as filter: 29 | 30 | Aggregate (cost=2936.43..2936.44 rows=1 width=8) (actual time=171.791..171.792 rows=1 loops=1) 31 | -> Seq Scan on rlstest (cost=0.00..2935.68 rows=300 width=0) (actual time=171.784..171.784 rows=1 loops=1) 32 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id)" 33 | Rows Removed by Filter: 99999 34 | Planning Time: 0.175 ms 35 | Execution Time: 171.830 ms 36 | 37 | 38 | Run with added filter in query: 39 | 40 | Aggregate (cost=1585.38..1585.38 rows=1 width=8) (actual time=8.709..8.710 rows=1 loops=1) 41 | -> Result (cost=0.02..1584.62 rows=300 width=0) (actual time=8.701..8.702 rows=1 loops=1) 42 | " One-Time Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = '5950b438-b07c-4012-8190-6ce79e4bd8e5'::uuid)" 43 | -> Seq Scan on rlstest (cost=0.02..1584.62 rows=300 width=0) (actual time=8.686..8.687 rows=1 loops=1) 44 | Filter: (user_id = '5950b438-b07c-4012-8190-6ce79e4bd8e5'::uuid) 45 | Rows Removed by Filter: 99999 46 | Planning Time: 0.176 ms 47 | Execution Time: 8.759 ms 48 | 49 | */ 50 | -------------------------------------------------------------------------------- /tests/test5-fixed-join/test5.sql: -------------------------------------------------------------------------------- 1 | -- Always try and do joins on a table to get fixed results for all rows. 2 | -- Note testing not shown here showed 1000 values in the in compare did not noticibly change good result. 3 | 4 | drop table if exists rlstest; 5 | create table 6 | rlstest as 7 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role, x as team_id 8 | from generate_series(1, 100000) x; 9 | alter table rlstest ENABLE ROW LEVEL SECURITY; 10 | 11 | drop table if exists rlstest_team_user; 12 | create table 13 | rlstest_team_user as 14 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id,x as team_id 15 | from generate_series(1, 1000) x; 16 | update rlstest_team_user set (user_id,team_id) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a',1) where id = 1; 17 | update rlstest_team_user set (user_id,team_id) = ('70225db6-b0ba-4116-9b08-6b25f33bb70a',2) where id = 2; 18 | 19 | alter table rlstest_team_user ENABLE ROW LEVEL SECURITY; 20 | create policy "dummy_read_policy" on rlstest_team_user 21 | to authenticated using (auth.uid() = user_id ); 22 | 23 | create policy "rls_test_select" on rlstest 24 | to authenticated 25 | using ( 26 | --auth.uid() in ( 27 | -- select user_id from rlstest_team_user where rlstest_team_user.team_id = rlstest.team_id 28 | -- ) 29 | team_id in ( 30 | select team_id from rlstest_team_user where user_id = auth.uid() 31 | ) 32 | ); 33 | 34 | set session role authenticated; 35 | set request.jwt.claims to '{"role":"authenticated", "sub":"70225db6-b0ba-4116-9b08-6b25f33bb70a"}'; 36 | 37 | explain analyze SELECT * FROM rlstest; 38 | 39 | set session role postgres; 40 | 41 | 42 | /* 43 | With auth.uid() in....: 44 | 45 | Seq Scan on rlstest (cost=0.00..1356636.52 rows=29190 width=88) (actual time=0.137..8948.499 rows=2 loops=1) 46 | Filter: (SubPlan 1) 47 | Rows Removed by Filter: 99998 48 | SubPlan 1 49 | -> Seq Scan on rlstest_team_user (cost=0.00..46.38 rows=1 width=16) (actual time=0.089..0.089 rows=0 loops=100000) 50 | " Filter: ((team_id = rlstest.team_id) AND ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id))" 51 | Rows Removed by Filter: 1000 52 | Planning Time: 0.528 ms 53 | Execution Time: 8948.541 ms 54 | 55 | 56 | With team_id in....: 57 | 58 | Seq Scan on rlstest (cost=68.20..1631.95 rows=29190 width=88) (actual time=1.801..19.629 rows=2 loops=1) 59 | Filter: (hashed SubPlan 1) 60 | Rows Removed by Filter: 99998 61 | SubPlan 1 62 | -> Seq Scan on rlstest_team_user (cost=0.00..68.20 rows=1 width=4) (actual time=0.240..1.783 rows=2 loops=1) 63 | " Filter: (((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id) AND (user_id = (COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid))" 64 | Rows Removed by Filter: 998 65 | Planning Time: 0.273 ms 66 | Execution Time: 19.676 ms 67 | 68 | 69 | */ 70 | 71 | -------------------------------------------------------------------------------- /tests/test6-To-role/test6.sql: -------------------------------------------------------------------------------- 1 | --Put authenticated in TO role 2 | --remove -- in front of TO authenticated for 2nd test. 3 | 4 | drop table if exists rlstest; 5 | create table 6 | rlstest as 7 | select x as id, 'name-' || x as name, uuid_generate_v4() as user_id, 'user' as role 8 | from generate_series(1, 100000) x; 9 | 10 | alter table rlstest ENABLE ROW LEVEL SECURITY; 11 | 12 | create policy "rls_test_select" on rlstest 13 | --To authenticated 14 | using ( 15 | auth.uid() = user_id 16 | ); 17 | 18 | set session role anon; 19 | set request.jwt.claims to '{"role":"anon", "sub":"5950b438-b07c-4012-8190-6ce79e4bd8e5"}'; 20 | 21 | explain analyze SELECT count(*) FROM rlstest; 22 | set session role postgres; 23 | 24 | 25 | /* 26 | Run with TO set to authenticated: 27 | 28 | Seq Scan on rlstest (cost=0.00..4334.00 rows=1 width=35) (actual time=170.999..170.999 rows=0 loops=1) 29 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id)" 30 | Rows Removed by Filter: 100000 31 | Planning Time: 0.216 ms 32 | Execution Time: 171.033 ms 33 | 34 | Run with no TO role added in: 35 | 36 | Aggregate (cost=2936.43..2936.44 rows=1 width=8) (actual time=167.746..167.747 rows=1 loops=1) 37 | -> Seq Scan on rlstest (cost=0.00..2935.68 rows=300 width=0) (actual time=167.742..167.742 rows=0 loops=1) 38 | " Filter: ((COALESCE(NULLIF(current_setting('request.jwt.claim.sub'::text, true), ''::text), ((NULLIF(current_setting('request.jwt.claims'::text, true), ''::text))::jsonb ->> 'sub'::text)))::uuid = user_id)" 39 | Rows Removed by Filter: 100000 40 | Planning Time: 0.194 ms 41 | Execution Time: 167.785 ms 42 | 43 | */ 44 | --------------------------------------------------------------------------------