├── .github └── workflows │ ├── pg_tap.yml │ └── update_readme.yml ├── .gitignore ├── LICENSE.md ├── README.md ├── supabase ├── .gitignore ├── migrations │ └── 20231210185106_enable_pg_tle.sql └── tests │ ├── 01-rls-enabled.sql │ ├── 02-create-supabase-users.sql │ ├── 03-authenticate-as.sql │ ├── 04-authenticate-as-service-role.sql │ ├── 05-frozen-time.sql │ ├── 06-frozen-time-cleanup.sql │ └── 99-blog-example.sql ├── supabase_test_helpers--0.0.1--0.0.2.sql ├── supabase_test_helpers--0.0.1.sql ├── supabase_test_helpers--0.0.2--0.0.3.sql ├── supabase_test_helpers--0.0.2.sql ├── supabase_test_helpers--0.0.3--0.0.4.sql ├── supabase_test_helpers--0.0.3.sql ├── supabase_test_helpers--0.0.4--0.0.5.sql ├── supabase_test_helpers--0.0.4--0.0.6.sql ├── supabase_test_helpers--0.0.4.sql ├── supabase_test_helpers--0.0.5.sql ├── supabase_test_helpers--0.0.6.sql └── supabase_test_helpers.control /.github/workflows/pg_tap.yml: -------------------------------------------------------------------------------- 1 | name: PGTap Tests 2 | on: 3 | pull_request: 4 | branches: [ main ] 5 | jobs: 6 | build: 7 | runs-on: ubuntu-latest 8 | steps: 9 | - uses: actions-rs/toolchain@v1 10 | with: 11 | toolchain: stable 12 | - uses: actions-rs/cargo@v1 13 | with: 14 | command: install 15 | args: --git https://github.com/supabase/dbdev.git dbdev 16 | - uses: actions/checkout@v3 17 | - uses: supabase/setup-cli@v1 18 | with: 19 | version: latest 20 | - name: Supabase Start 21 | run: supabase init && supabase start 22 | - name: Install supabase_test_helpers extension using dbdev cli 23 | run: dbdev install --connection postgres://postgres:postgres@localhost:54322/postgres --path . 24 | - name: Run Tests 25 | run: supabase test db -------------------------------------------------------------------------------- /.github/workflows/update_readme.yml: -------------------------------------------------------------------------------- 1 | name: Update README 2 | on: 3 | pull_request: 4 | branches: [ main ] 5 | jobs: 6 | build: 7 | runs-on: ubuntu-latest 8 | steps: 9 | - uses: actions/checkout@v3 10 | - name: Install doctoc and mdextract 11 | run: npm install -g doctoc mdextract 12 | - name: Update README 13 | run: | 14 | mdextract --update README.md 15 | doctoc --github --notitle README.md 16 | - uses: stefanzweifel/git-auto-commit-action@v4 17 | with: 18 | file_pattern: README.md 19 | commit_message: Apply README changes -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | .idea 2 | .DS_Store 3 | supabase_test_helpers_pglet.sql 4 | supabase/config.toml 5 | supabase/functions 6 | supabase/seed.sql -------------------------------------------------------------------------------- /LICENSE.md: -------------------------------------------------------------------------------- 1 | Copyright 2023 usebasejump.com 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: 4 | 5 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. 6 | 7 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 8 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Supabase Test Helpers 2 | A collection of functions designed to make testing Supabase projects easier. Created as part of our [open source SaaS starter for Supabase](https://usebasejump.com). 3 | 4 | ## Quick Start (recommended) 5 | If you're using Supabase: 6 | 7 | 1) Install dbdev following the instructions here: [github.com/supabase/dbdev](https://github.com/supabase/dbdev) 8 | 2) Install the test helpers as an extension: 9 | 10 | ```sql 11 | select dbdev.install('basejump-supabase_test_helpers'); 12 | ``` 13 | 14 | I don't recommend activating the extension in production directly, instead you can activate it as part of your test suite. For example: 15 | 16 | ```sql 17 | BEGIN; 18 | CREATE EXTENSION "basejump-supabase_test_helpers"; 19 | 20 | select plan(1); 21 | -- create a table, which will have RLS disabled by default 22 | CREATE TABLE public.tb1 (id int, data text); 23 | ALTER TABLE public.tb1 ENABLE ROW LEVEL SECURITY; 24 | 25 | -- test to make sure RLS check works 26 | select check_test(tests.rls_enabled('public', 'tb1'), true); 27 | 28 | SELECT * FROM finish(); 29 | ROLLBACK; 30 | ``` 31 | 32 | For a basic example, check out the [example blog tests](https://github.com/usebasejump/supabase-test-helpers/blob/main/supabase/tests/99-blog-example.sql). 33 | 34 | ## Manual Installation (not recommended) 35 | Copy the contents of the most recent version into the very first alphabetical test in your test suite, such as `00000-supabase_test_helpers.sql`. This will ensure that the test helpers are removed after your tests have run. for it to work, you need to create some fake tests at the bottom of the file for pgtap to not complain. Here's an example: 36 | ```sql 37 | 38 | -- we have to run some tests to get this to pass as the first test file. 39 | -- investigating options to make this better. Maybe a dedicated test harness 40 | -- but we dont' want these functions to always exist on the database. 41 | BEGIN; 42 | 43 | select plan(7); 44 | select function_returns('tests', 'create_supabase_user', Array['text', 'text', 'text', 'jsonb'], 'uuid'); 45 | select function_returns('tests', 'get_supabase_uid', Array['text'], 'uuid'); 46 | select function_returns('tests', 'get_supabase_user', Array['text'], 'json'); 47 | select function_returns('tests', 'authenticate_as', Array['text'], 'void'); 48 | select function_returns('tests', 'clear_authentication', Array[null], 'void'); 49 | select function_returns('tests', 'rls_enabled', Array['text', 'text'], 'text'); 50 | select function_returns('tests', 'rls_enabled', Array['text'], 'text'); 51 | select * from finish(); 52 | ROLLBACK; 53 | ``` 54 | 55 | ## Writing tests 56 | Check out the docs below for available helpers. To view a comprehensive example, check out our [blog tests](https://github.com/usebasejump/supabase-test-helpers/blob/main/supabase/tests/99-blog-example.sql). 57 | 58 | ## Test Helpers 59 | The following is auto-generated off of comments in the `supabase_test_helpers--0.0.2.sql` file. Any changes added to the README directly will be overwritten. 60 | 61 | 62 | 63 | 64 | - [tests.create_supabase_user(identifier text, email text, phone text)](#testscreate_supabase_useridentifier-text-email-text-phone-text) 65 | - [tests.get_supabase_user(identifier text)](#testsget_supabase_useridentifier-text) 66 | - [tests.get_supabase_uid(identifier text)](#testsget_supabase_uididentifier-text) 67 | - [tests.authenticate_as(identifier text)](#testsauthenticate_asidentifier-text) 68 | - [tests.authenticate_as_service_role()](#testsauthenticate_as_service_role) 69 | - [tests.clear_authentication()](#testsclear_authentication) 70 | - [tests.rls_enabled(testing_schema text)](#testsrls_enabledtesting_schema-text) 71 | - [tests.rls_enabled(testing_schema text, testing_table text)](#testsrls_enabledtesting_schema-text-testing_table-text) 72 | - [tests.freeze_time(frozen_time timestamp with time zone)](#testsfreeze_timefrozen_time-timestamp-with-time-zone) 73 | - [tests.unfreeze_time()](#testsunfreeze_time) 74 | - [Contributing](#contributing) 75 | 76 | 77 | 78 | 79 | 80 | ### tests.create_supabase_user(identifier text, email text, phone text) 81 | 82 | Creates a new user in the `auth.users` table. 83 | You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 84 | 85 | Parameters: 86 | - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 87 | - `email` - (Optional) The email address of the user 88 | - `phone` - (Optional) The phone number of the user 89 | - `metadata` - (Optional) Additional metadata to be added to the user 90 | 91 | Returns: 92 | - `user_id` - The UUID of the user in the `auth.users` table 93 | 94 | Example: 95 | ```sql 96 | SELECT tests.create_supabase_user('test_owner'); 97 | SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 98 | SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 99 | ``` 100 | 101 | ### tests.get_supabase_user(identifier text) 102 | 103 | Returns the user info for a user created with `tests.create_supabase_user`. 104 | 105 | Parameters: 106 | - `identifier` - The unique identifier for the user 107 | 108 | Returns: 109 | - `user_id` - The UUID of the user in the `auth.users` table 110 | 111 | Example: 112 | ```sql 113 | SELECT posts where posts.user_id = tests.get_supabase_user('test_owner') -> 'id'; 114 | ``` 115 | 116 | ### tests.get_supabase_uid(identifier text) 117 | 118 | Returns the user UUID for a user created with `tests.create_supabase_user`. 119 | 120 | Parameters: 121 | - `identifier` - The unique identifier for the user 122 | 123 | Returns: 124 | - `user_id` - The UUID of the user in the `auth.users` table 125 | 126 | Example: 127 | ```sql 128 | SELECT posts where posts.user_id = tests.get_supabase_uid('test_owner') -> 'id'; 129 | ``` 130 | 131 | ### tests.authenticate_as(identifier text) 132 | Authenticates as a user created with `tests.create_supabase_user`. 133 | 134 | Parameters: 135 | - `identifier` - The unique identifier for the user 136 | 137 | Returns: 138 | - `void` 139 | 140 | Example: 141 | ```sql 142 | SELECT tests.create_supabase_user('test_owner'); 143 | SELECT tests.authenticate_as('test_owner'); 144 | ``` 145 | 146 | ### tests.authenticate_as_service_role() 147 | Clears authentication object and sets role to service_role. 148 | 149 | Returns: 150 | - `void` 151 | 152 | Example: 153 | ```sql 154 | SELECT tests.authenticate_as_service_role(); 155 | ``` 156 | 157 | ### tests.clear_authentication() 158 | Clears out the authentication and sets role to anon 159 | 160 | Returns: 161 | - `void` 162 | 163 | Example: 164 | ```sql 165 | SELECT tests.create_supabase_user('test_owner'); 166 | SELECT tests.authenticate_as('test_owner'); 167 | SELECT tests.clear_authentication(); 168 | ``` 169 | 170 | ### tests.rls_enabled(testing_schema text) 171 | pgTAP function to check if RLS is enabled on all tables in a provided schema 172 | 173 | Parameters: 174 | - schema_name text - The name of the schema to check 175 | 176 | Example: 177 | ```sql 178 | BEGIN; 179 | select plan(1); 180 | select tests.rls_enabled('public'); 181 | SELECT * FROM finish(); 182 | ROLLBACK; 183 | ``` 184 | 185 | ### tests.rls_enabled(testing_schema text, testing_table text) 186 | pgTAP function to check if RLS is enabled on a specific table 187 | 188 | Parameters: 189 | - schema_name text - The name of the schema to check 190 | - testing_table text - The name of the table to check 191 | 192 | Example: 193 | ```sql 194 | BEGIN; 195 | select plan(1); 196 | select tests.rls_enabled('public', 'accounts'); 197 | SELECT * FROM finish(); 198 | ROLLBACK; 199 | ``` 200 | 201 | ### tests.freeze_time(frozen_time timestamp with time zone) 202 | 203 | Overwrites the current time from now() to the provided time. 204 | 205 | Works out of the box for any normal usage of now(), if you have a function that sets its own search path, such as security definers, then you will need to alter the function to set the search path to include test_overrides BEFORE pg_catalog. 206 | **ONLY do this inside of a pgtap test transaction.** 207 | Example: 208 | 209 | ```sql 210 | ALTER FUNCTION auth.your_function() SET search_path = test_overrides, public, pg_temp, pg_catalog; 211 | ``` 212 | View a test example in 05-frozen-time.sql: https://github.com/usebasejump/supabase-test-helpers/blob/main/supabase/tests/05-frozen-time.sql 213 | 214 | Parameters: 215 | - `frozen_time` - The time to freeze to. Supports timestamp with time zone, without time zone, date or any other value that can be coerced into a timestamp with time zone. 216 | 217 | Returns: 218 | - void 219 | 220 | Example: 221 | ```sql 222 | SELECT tests.freeze_time('2020-01-01 00:00:00'); 223 | ``` 224 | 225 | ### tests.unfreeze_time() 226 | 227 | Unfreezes the time and restores the original now() function. 228 | 229 | Returns: 230 | - void 231 | 232 | Example: 233 | ```sql 234 | SELECT tests.unfreeze_time(); 235 | ``` 236 | 237 | 238 | 239 | ## Contributing 240 | Yes, please! Anything you've found helpful for testing Supabase projects is welcome. To contribute: 241 | 242 | * Create a new version of supabase_test_helpers `supabase_test_helpers--{major}-{minor}-{patch}.sql` 243 | * New versions are intended to be a fresh install, so copy the contents of the previous version into the new version. 244 | * Add [pgTAP compliant test functions](https://pgtap.org/documentation.html#composeyourself) to the new version 245 | * Comments should be added above each function, follow the examples in the file. 246 | * Create a migration file `supabase_test_helpers--{oldMajor}-{oldMinor}-{oldPatch}--{newMajor}-{newMinor}-{newPatch}.sql` to upgrade to the new version. Include ONLY your migration code, not the entire contents of the new version. 247 | * Add tests for your functions in `supabase/tests/XX-your-function-name.sql` 248 | * You can verify tests work by running `supabase init` to create a config file, `supabase start` to launch it 249 | * Install your updated version with `dbdev install --connection postgres://postgres:postgres@localhost:54322/postgres --path .` 250 | * Run `supabase test db` to run the tests. 251 | * Submit a PR 252 | -------------------------------------------------------------------------------- /supabase/.gitignore: -------------------------------------------------------------------------------- 1 | # Supabase 2 | .branches 3 | .temp 4 | .env 5 | -------------------------------------------------------------------------------- /supabase/migrations/20231210185106_enable_pg_tle.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION IF NOT EXISTS pg_tle; -------------------------------------------------------------------------------- /supabase/tests/01-rls-enabled.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | CREATE EXTENSION supabase_test_helpers; 3 | 4 | select plan(4); 5 | -- create a table, which will have RLS disabled by default 6 | CREATE TABLE public.tb1 (id int, data text); 7 | -- test to make sure RLS check works 8 | select check_test(tests.rls_enabled('public'), false); 9 | select check_test(tests.rls_enabled('public', 'tb1'), false); 10 | 11 | -- enable RLS for the table 12 | ALTER TABLE public.tb1 ENABLE ROW LEVEL SECURITY; 13 | -- test to make sure RLS check works 14 | select check_test(tests.rls_enabled('public'), true); 15 | select check_test(tests.rls_enabled('public', 'tb1'), true); 16 | 17 | SELECT * FROM finish(); 18 | ROLLBACK; -------------------------------------------------------------------------------- /supabase/tests/02-create-supabase-users.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | CREATE EXTENSION supabase_test_helpers; 4 | 5 | select plan(18); 6 | 7 | -- test creating a user 8 | select tests.create_supabase_user('testuser'); 9 | select tests.create_supabase_user('testuser2', 'testuser2@test.com'); 10 | select tests.create_supabase_user('testuser3', null, '555-555-5555'); 11 | select tests.create_supabase_user('testuser4', null, null, '{"has": "or has not"}'::jsonb); 12 | 13 | select is((select count(*)::integer from auth.users), 4, 'create_supabase_user should have created 4 users'); 14 | 15 | select is((select tests.get_supabase_uid('testuser')), (select id from auth.users where raw_user_meta_data ->> 'test_identifier' = 'testuser'), 'get_supabase_uid should return a user'); 16 | select is((select (tests.get_supabase_user('testuser') ->> 'id')::uuid), (select id from auth.users where raw_user_meta_data ->> 'test_identifier' = 'testuser'), 'get_supabase_user should return a user id'); 17 | select is(auth.users.raw_app_meta_data, '{}'::jsonb, 'raw_app_meta_data should not be null') from auth.users where raw_user_meta_data ->> 'test_identifier' = 'testuser'; 18 | select ok((select auth.users.created_at IS NOT NULL), 'created_at should not be null') from auth.users where raw_user_meta_data ->> 'test_identifier' = 'testuser'; 19 | select ok((select auth.users.updated_at IS NOT NULL), 'updated_at should not be null') from auth.users where raw_user_meta_data ->> 'test_identifier' = 'testuser'; 20 | select is((select tests.get_supabase_user('testuser2') ->> 'email'), (select email::text from auth.users where raw_user_meta_data ->> 'test_identifier' = 'testuser2'), 'get_supabase_user should return a user email'); 21 | select is((select tests.get_supabase_user('testuser3') ->> 'phone'), (select phone::text from auth.users where raw_user_meta_data ->> 'test_identifier' = 'testuser3'), 'get_supabase_user should return a user phone'); 22 | select is((select tests.get_supabase_user('testuser4') -> 'raw_user_meta_data' ->> 'has'), (select raw_user_meta_data ->> 'has' from auth.users where raw_user_meta_data ->> 'test_identifier' = 'testuser4'), 'get_supabase_user should return custom metadata'); 23 | select throws_ok($$ select tests.get_supabase_user('testuser5') $$, 'User with identifier testuser5 not found'); 24 | 25 | -- should not mess with transactions current role 26 | set role anon; 27 | select ok((select tests.create_supabase_user('testuser5') is not null), 'create_supabase_user should be callable by any test role'); 28 | select throws_ok($$ select * from auth.users$$, 'permission denied for table users'); 29 | select ok((select tests.get_supabase_uid('testuser2') IS NOT NULL), 'get_supabase_user should return a user for anon role'); 30 | -- make sure we're still anon 31 | select is((select current_role::text), 'anon', 'current_role should still be anon'); 32 | 33 | set role authenticated; 34 | select ok((select tests.create_supabase_user('testuser5') is not null), 'create_supabase_user should be callable by any test role'); 35 | select throws_ok($$ select * from auth.users$$, 'permission denied for table users'); 36 | select ok((select tests.get_supabase_uid('testuser2') IS NOT NULL), 'get_supabase_user should return a user for anon role'); 37 | -- make sure we're still authenticated 38 | select is((select current_role::text), 'authenticated', 'current_role should still be authenticated'); 39 | select * from finish(); 40 | 41 | ROLLBACK; 42 | -------------------------------------------------------------------------------- /supabase/tests/03-authenticate-as.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | CREATE EXTENSION supabase_test_helpers; 4 | 5 | select plan(9); 6 | 7 | select tests.create_supabase_user('test'); 8 | 9 | select throws_ok($$ select tests.authenticate_as('test-fake') $$, 'User with identifier test-fake not found'::text); 10 | select lives_ok($$ select tests.authenticate_as('test') $$, 'Successfully authenticated as test user'); 11 | 12 | select is((select tests.get_supabase_uid('test')), auth.uid(), 'Authenticates as the correct user'); 13 | select is((select current_role::text), 'authenticated', 'Sets the current role to authenticated'); 14 | select is( 15 | current_setting('request.jwt.claims')::jsonb ?& array['sub', 'email', 'phone', 'user_metadata', 'app_metadata'], 16 | true, 17 | 'Claims should contain correct keys for authenticated user' 18 | ); 19 | 20 | select lives_ok($$ select tests.clear_authentication() $$, 'should clear authentication'); 21 | select is((select current_role::text), 'anon', 'Sets the current role to anonymous'); 22 | select is((select auth.uid()), null, 'Clears out authentication'); 23 | select is( 24 | current_setting('request.jwt.claims'), 25 | '', 26 | 'Empties request claims' 27 | ); 28 | 29 | select * from finish(); 30 | ROLLBACK; -------------------------------------------------------------------------------- /supabase/tests/04-authenticate-as-service-role.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | CREATE EXTENSION supabase_test_helpers; 4 | 5 | select plan(8); 6 | 7 | select tests.create_supabase_user('test'); 8 | 9 | select lives_ok($$ select tests.authenticate_as('test') $$, 'Successfully authenticated as test user'); 10 | select is((select tests.get_supabase_uid('test')), auth.uid(), 'Authenticates as the correct user'); 11 | select is((select current_role::text), 'authenticated', 'Sets the current role to authenticated'); 12 | 13 | select tests.authenticate_as_service_role(); 14 | 15 | select is((select current_role::text), 'service_role', 'Sets the current role to service_role'); 16 | select is((select auth.uid()), null, 'Clears out authentication'); 17 | 18 | select lives_ok($$ select tests.authenticate_as('test') $$, 'Successfully authenticated as test user'); 19 | select is((select tests.get_supabase_uid('test')), auth.uid(), 'Authenticates as the correct user'); 20 | select is((select current_role::text), 'authenticated', 'Sets the current role to authenticated'); 21 | 22 | 23 | 24 | select * from finish(); 25 | ROLLBACK; -------------------------------------------------------------------------------- /supabase/tests/05-frozen-time.sql: -------------------------------------------------------------------------------- 1 | --- function that specifically sets the search path so we can test how it handles overriden functions 2 | CREATE OR REPLACE FUNCTION search_path_setting_function() 3 | RETURNS timestamp with time zone 4 | AS $$ 5 | SELECT now() 6 | $$ LANGUAGE sql 7 | SECURITY DEFINER 8 | SET search_path = public, pg_catalog; 9 | 10 | 11 | BEGIN; 12 | CREATE EXTENSION supabase_test_helpers; 13 | 14 | select plan(12); 15 | 16 | -- freeze the time 17 | SELECT tests.freeze_time('2020-01-01 00:00:00'); 18 | 19 | -- search_path now include test_overrides at the front 20 | select ok( 21 | (SELECT current_setting('search_path')::text LIKE 'test_overrides,%'), 22 | 'search_path includes test_overrides at the front' 23 | ); 24 | 25 | -- verify frozen time 26 | select is( 27 | (SELECT now()), 28 | '2020-01-01 00:00:00'::timestamp with time zone, 29 | 'now() is frozen in time' 30 | ); 31 | 32 | 33 | -- create a test table to verify that now() is overwritten on tables 34 | CREATE TABLE public.test_table ( 35 | id int, 36 | key text, 37 | created_at timestamp with time zone default now(), 38 | updated_at timestamp with time zone default now() 39 | ); 40 | 41 | -- add a trigger to update updated_at when the row is updated 42 | CREATE OR REPLACE FUNCTION update_updated_at() 43 | RETURNS trigger 44 | AS $$ 45 | BEGIN 46 | NEW.updated_at = now(); 47 | RETURN NEW; 48 | END 49 | $$ LANGUAGE plpgsql; 50 | 51 | CREATE TRIGGER update_updated_at 52 | BEFORE UPDATE ON test_table 53 | FOR EACH ROW 54 | EXECUTE PROCEDURE update_updated_at(); 55 | 56 | -- insert a row and verify that the created_at and updated_at are frozen in time 57 | INSERT INTO test_table (id, key) VALUES (1, 'test'); 58 | select is( 59 | (SELECT created_at FROM test_table WHERE id = 1), 60 | '2020-01-01 00:00:00'::timestamp with time zone, 61 | 'created_at is frozen in time' 62 | ); 63 | select is( 64 | (SELECT updated_at FROM test_table WHERE id = 1), 65 | '2020-01-01 00:00:00'::timestamp with time zone, 66 | 'updated_at is frozen in time' 67 | ); 68 | 69 | -- change frozen time to test updated_at timestamp 70 | SELECT tests.freeze_time('2021-01-01 00:00:00'); 71 | 72 | -- update the row and verify that the updated_at is frozen in time 73 | UPDATE test_table SET key = 'test2' WHERE id = 1; 74 | 75 | select is( 76 | (SELECT updated_at FROM test_table WHERE id = 1), 77 | '2021-01-01 00:00:00'::timestamp with time zone, 78 | 'updated_at is frozen in time' 79 | ); 80 | 81 | -- verify supports many different inputs correctly 82 | SELECT tests.freeze_time('2020-02-02 00:00:00'::timestamp without time zone); 83 | select is( 84 | (SELECT now()), 85 | '2020-02-02 00:00:00'::timestamp with time zone, 86 | 'Supports timestamp without time zone' 87 | ); 88 | 89 | SELECT tests.freeze_time('2020-03-03'::date); 90 | select is( 91 | (SELECT now()), 92 | '2020-03-03 00:00:00'::timestamp with time zone, 93 | 'Supports date' 94 | ); 95 | 96 | SELECT tests.freeze_time(CURRENT_DATE); 97 | select is( 98 | (SELECT now()), 99 | CURRENT_DATE::timestamp with time zone, 100 | 'Supports CURRENT_DATE' 101 | ); 102 | 103 | SELECT tests.unfreeze_time(); 104 | 105 | select is( 106 | (SELECT now()), 107 | (SELECT pg_catalog.now()), 108 | 'unfreeze_time() restores now() to the original function' 109 | ); 110 | 111 | 112 | ---- working with functions that have set their own search_path 113 | 114 | SELECT tests.freeze_time('2020-01-01 00:00:00'); 115 | 116 | -- function still returns the non frozen time 117 | select is( 118 | (SELECT search_path_setting_function()), 119 | (SELECT pg_catalog.now()), 120 | 'function still returns the non frozen time' 121 | ); 122 | 123 | -- we can run an alter command to alter it specifically 124 | ALTER FUNCTION search_path_setting_function() 125 | SET search_path = test_overrides, public, pg_catalog; 126 | 127 | -- now it returns the frozen time 128 | select is( 129 | (SELECT search_path_setting_function()), 130 | '2020-01-01 00:00:00'::timestamp with time zone, 131 | 'function returns the frozen time' 132 | ); 133 | 134 | 135 | select tests.unfreeze_time(); 136 | 137 | -- working with an authenticated user freezing time. 138 | 139 | select tests.create_supabase_user('test'); 140 | select tests.authenticate_as('test'); 141 | 142 | -- freeze time 143 | SELECT tests.freeze_time('2020-05-05 00:00:00'); 144 | 145 | -- verify frozen time by creating a table row 146 | insert into test_table (id, key) values (2, 'test2'); 147 | 148 | select is( 149 | (SELECT created_at FROM test_table WHERE id = 2), 150 | '2020-05-05 00:00:00'::timestamp with time zone, 151 | 'created_at is frozen in time' 152 | ); 153 | 154 | SELECT * FROM finish(); 155 | ROLLBACK; -------------------------------------------------------------------------------- /supabase/tests/06-frozen-time-cleanup.sql: -------------------------------------------------------------------------------- 1 | --- secondary test to confirm that the search_path is restored after a rollback 2 | BEGIN; 3 | CREATE EXTENSION supabase_test_helpers; 4 | 5 | select plan(2); 6 | 7 | -- confirm test_overrides no longer in search path 8 | select ok( 9 | (SELECT current_setting('search_path') NOT LIKE 'test_overrides,%'), 10 | 'test_overrides no longer in search path' 11 | ); 12 | 13 | 14 | -- freeze the time 15 | SELECT tests.freeze_time('2020-01-01 00:00:00'); 16 | 17 | -- function still returns the non frozen time 18 | select is( 19 | (SELECT search_path_setting_function()), 20 | (SELECT pg_catalog.now()), 21 | 'function still returns the non frozen time' 22 | ); 23 | 24 | SELECT * FROM finish(); 25 | ROLLBACK; -------------------------------------------------------------------------------- /supabase/tests/99-blog-example.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | CREATE EXTENSION supabase_test_helpers; 3 | 4 | select plan(12); 5 | 6 | -- create a posts table that references the auth.users table 7 | create table public.posts 8 | ( 9 | -- post id 10 | id uuid primary key default uuid_generate_v4(), 11 | -- the user's ID from the auth.users table out of supabase 12 | user_id uuid references auth.users not null default auth.uid(), 13 | -- post content 14 | content text 15 | ); 16 | 17 | -- won't be protected by default 18 | select check_test(tests.rls_enabled('public', 'posts'), false); 19 | 20 | 21 | -- Setup RLS on the posts table 22 | ALTER TABLE public.posts ENABLE ROW LEVEL SECURITY; 23 | 24 | create policy "All users can view their own posts" on public.posts 25 | for select 26 | to authenticated 27 | using ( 28 | true 29 | ); 30 | 31 | create policy "Users can create their own posts" on public.posts 32 | for insert 33 | to authenticated 34 | with check ( 35 | user_id = auth.uid() 36 | ); 37 | 38 | create policy "Users can update their own posts" on public.posts 39 | for update 40 | to authenticated 41 | using ( 42 | user_id = auth.uid() 43 | ); 44 | 45 | create policy "Users can delete their own posts" on public.posts 46 | for delete 47 | to authenticated 48 | using ( 49 | user_id = auth.uid() 50 | ); 51 | 52 | -- RLS should be enabled now with policies in place 53 | -- Let's give it a test! 54 | 55 | select tests.create_supabase_user('post_owner'); 56 | select tests.create_supabase_user('post_viewer'); 57 | 58 | ----------- 59 | -- Acting as post_owner 60 | ----------- 61 | select tests.authenticate_as('post_owner'); 62 | 63 | -- insert a post 64 | SELECT 65 | results_eq( 66 | $$ insert into public.posts (content) values ('Post created') returning user_id $$, 67 | $$ VALUES(tests.get_supabase_uid('post_owner')) $$, 68 | 'authenticated users can insert a post' 69 | ); 70 | 71 | -- owner can view their own posts 72 | SELECT 73 | results_eq( 74 | $$ select content from posts limit 1 $$, 75 | $$ VALUES('Post created') $$, 76 | 'Post owners can view their own posts' 77 | ); 78 | 79 | -- owner can update the post 80 | SELECT 81 | results_eq( 82 | $$ update posts set content = 'Post updated' returning content $$, 83 | $$ VALUES('Post updated') $$, 84 | 'Post owners can update their own posts' 85 | ); 86 | 87 | ---------- 88 | -- Acting as post_viewer 89 | ---------- 90 | SELECT tests.authenticate_as('post_viewer'); 91 | 92 | -- post viewer cannot update the post 93 | SELECT 94 | is_empty( 95 | $$ update posts set content = 'Post updated by viewer' returning content $$, 96 | 'Post viewers cannot update posts' 97 | ); 98 | 99 | -- post viewer cannot delete the post 100 | SELECT 101 | is_empty( 102 | $$ delete from posts returning 1 $$, 103 | 'Post viewers cannot delete posts' 104 | ); 105 | 106 | -- post viewer can view the post 107 | SELECT 108 | results_eq( 109 | $$ select content from posts limit 1 $$, 110 | $$ VALUES('Post updated') $$, 111 | 'Post owners can view their own posts' 112 | ); 113 | 114 | --------- 115 | -- Acting as anon 116 | --------- 117 | SELECT tests.clear_authentication(); 118 | 119 | -- anon cannot view the post 120 | SELECT 121 | is_empty( 122 | $$ select * from posts $$, 123 | 'Anon cannot view posts' 124 | ); 125 | 126 | -- anon cannot update the post 127 | SELECT 128 | is_empty( 129 | $$ update posts set content = 'Post updated by viewer' returning content $$, 130 | 'Anon cannot update posts' 131 | ); 132 | 133 | -- anon cannot delete the post 134 | SELECT 135 | is_empty( 136 | $$ delete from posts returning 1 $$, 137 | 'Anon cannot delete posts' 138 | ); 139 | 140 | -- anon cannot insert new posts 141 | SELECT 142 | throws_ok( 143 | $$ insert into posts (content) values ('Post created by anon') $$, 144 | 'new row violates row-level security policy for table "posts"' 145 | ); 146 | 147 | -------- 148 | -- Acting as post_owner 149 | -------- 150 | SELECT tests.authenticate_as('post_owner'); 151 | 152 | -- post owner can delete the post 153 | SELECT 154 | results_eq( 155 | $$ delete from posts returning 1 $$, 156 | $$ VALUES(1) $$, 157 | 'Post owners can delete their own posts' 158 | ); 159 | 160 | select * from finish(); 161 | 162 | ROLLBACK; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.1--0.0.2.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION supabase_test_helpers" to load this file. \quit 3 | 4 | /** 5 | * ### tests.authenticate_as_service_role() 6 | * Clears authentication object and sets role to service_role. 7 | * 8 | * Returns: 9 | * - `void` 10 | * 11 | * Example: 12 | * ```sql 13 | * SELECT tests.authenticate_as_service_role(); 14 | * ``` 15 | */ 16 | CREATE OR REPLACE FUNCTION tests.authenticate_as_service_role () 17 | RETURNS void 18 | AS $$ 19 | BEGIN 20 | perform set_config('role', 'service_role', true); 21 | perform set_config('request.jwt.claims', null, true); 22 | END 23 | $$ LANGUAGE plpgsql; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.1.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION supabase_test_helpers" to load this file. \quit 3 | 4 | -- We want to store all of this in the tests schema to keep it 5 | -- separate from any application data 6 | CREATE SCHEMA IF NOT EXISTS tests; 7 | 8 | -- anon, authenticated, and service_role should have access to tests schema 9 | GRANT USAGE ON SCHEMA tests TO anon, authenticated, service_role; 10 | -- Don't allow public to execute any functions in the tests schema 11 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests REVOKE EXECUTE ON FUNCTIONS FROM public; 12 | -- Grant execute to anon, authenticated, and service_role for testing purposes 13 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 14 | 15 | /** 16 | * ### tests.create_supabase_user(identifier text, email text, phone text) 17 | * 18 | * Creates a new user in the `auth.users` table. 19 | * You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 20 | * 21 | * Parameters: 22 | * - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 23 | * - `email` - (Optional) The email address of the user 24 | * - `phone` - (Optional) The phone number of the user 25 | * - `metadata` - (Optional) Additional metadata to be added to the user 26 | * 27 | * Returns: 28 | * - `user_id` - The UUID of the user in the `auth.users` table 29 | * 30 | * Example: 31 | * ```sql 32 | * SELECT tests.create_supabase_user('test_owner'); 33 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 34 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 35 | * ``` 36 | */ 37 | CREATE OR REPLACE FUNCTION tests.create_supabase_user(identifier text, email text default null, phone text default null, metadata jsonb default null) 38 | RETURNS uuid 39 | SECURITY DEFINER 40 | SET search_path = auth, pg_temp 41 | AS $$ 42 | DECLARE 43 | user_id uuid; 44 | BEGIN 45 | 46 | -- create the user 47 | user_id := extensions.uuid_generate_v4(); 48 | INSERT INTO auth.users (id, email, phone, raw_user_meta_data) 49 | VALUES (user_id, coalesce(email, concat(user_id, '@test.com')), phone, jsonb_build_object('test_identifier', identifier) || coalesce(metadata, '{}'::jsonb)) 50 | RETURNING id INTO user_id; 51 | 52 | RETURN user_id; 53 | END; 54 | $$ LANGUAGE plpgsql; 55 | 56 | /** 57 | * ### tests.get_supabase_user(identifier text) 58 | * 59 | * Returns the user info for a user created with `tests.create_supabase_user`. 60 | * 61 | * Parameters: 62 | * - `identifier` - The unique identifier for the user 63 | * 64 | * Returns: 65 | * - `user_id` - The UUID of the user in the `auth.users` table 66 | * 67 | * Example: 68 | * ```sql 69 | * SELECT posts where posts.user_id = tests.get_supabase_user('test_owner') -> 'id'; 70 | * ``` 71 | */ 72 | CREATE OR REPLACE FUNCTION tests.get_supabase_user(identifier text) 73 | RETURNS json 74 | SECURITY DEFINER 75 | SET search_path = auth, pg_temp 76 | AS $$ 77 | DECLARE 78 | supabase_user json; 79 | BEGIN 80 | SELECT json_build_object('id', id, 'email', email, 'phone', phone, 'raw_user_meta_data', raw_user_meta_data) into supabase_user FROM auth.users WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 81 | if supabase_user is null OR supabase_user -> 'id' IS NULL then 82 | RAISE EXCEPTION 'User with identifier % not found', identifier; 83 | end if; 84 | RETURN supabase_user; 85 | END; 86 | $$ LANGUAGE plpgsql; 87 | 88 | /** 89 | * ### tests.get_supabase_uid(identifier text) 90 | * 91 | * Returns the user UUID for a user created with `tests.create_supabase_user`. 92 | * 93 | * Parameters: 94 | * - `identifier` - The unique identifier for the user 95 | * 96 | * Returns: 97 | * - `user_id` - The UUID of the user in the `auth.users` table 98 | * 99 | * Example: 100 | * ```sql 101 | * SELECT posts where posts.user_id = tests.get_supabase_uid('test_owner') -> 'id'; 102 | * ``` 103 | */ 104 | CREATE OR REPLACE FUNCTION tests.get_supabase_uid(identifier text) 105 | RETURNS uuid 106 | SECURITY DEFINER 107 | SET search_path = auth, pg_temp 108 | AS $$ 109 | DECLARE 110 | supabase_user uuid; 111 | BEGIN 112 | SELECT id into supabase_user FROM auth.users WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 113 | if supabase_user is null then 114 | RAISE EXCEPTION 'User with identifier % not found', identifier; 115 | end if; 116 | RETURN supabase_user; 117 | END; 118 | $$ LANGUAGE plpgsql; 119 | 120 | /** 121 | * ### tests.authenticate_as(identifier text) 122 | * Authenticates as a user created with `tests.create_supabase_user`. 123 | * 124 | * Parameters: 125 | * - `identifier` - The unique identifier for the user 126 | * 127 | * Returns: 128 | * - `void` 129 | * 130 | * Example: 131 | * ```sql 132 | * SELECT tests.create_supabase_user('test_owner'); 133 | * SELECT tests.authenticate_as('test_owner'); 134 | * ``` 135 | */ 136 | CREATE OR REPLACE FUNCTION tests.authenticate_as (identifier text) 137 | RETURNS void 138 | AS $$ 139 | DECLARE 140 | user_data json; 141 | original_auth_data text; 142 | BEGIN 143 | -- store the request.jwt.claims in a variable in case we need it 144 | original_auth_data := current_setting('request.jwt.claims', true); 145 | user_data := tests.get_supabase_user(identifier); 146 | 147 | if user_data is null OR user_data ->> 'id' IS NULL then 148 | RAISE EXCEPTION 'User with identifier % not found', identifier; 149 | end if; 150 | 151 | 152 | perform set_config('role', 'authenticated', true); 153 | perform set_config('request.jwt.claims', json_build_object('sub', user_data ->> 'id', 'email', user_data ->> 'email', 'phone', user_data ->> 'phone')::text, true); 154 | 155 | EXCEPTION 156 | -- revert back to original auth data 157 | WHEN OTHERS THEN 158 | set local role authenticated; 159 | set local "request.jwt.claims" to original_auth_data; 160 | RAISE; 161 | END 162 | $$ LANGUAGE plpgsql; 163 | 164 | 165 | /** 166 | * ### tests.clear_authentication() 167 | * Clears out the authentication and sets role to anon 168 | * 169 | * Returns: 170 | * - `void` 171 | * 172 | * Example: 173 | * ```sql 174 | * SELECT tests.create_supabase_user('test_owner'); 175 | * SELECT tests.authenticate_as('test_owner'); 176 | * SELECT tests.clear_authentication(); 177 | * ``` 178 | */ 179 | CREATE OR REPLACE FUNCTION tests.clear_authentication() 180 | RETURNS void AS $$ 181 | BEGIN 182 | perform set_config('role', 'anon', true); 183 | perform set_config('request.jwt.claims', null, true); 184 | END 185 | $$ LANGUAGE plpgsql; 186 | 187 | /** 188 | * ### tests.rls_enabled(testing_schema text) 189 | * pgTAP function to check if RLS is enabled on all tables in a provided schema 190 | * 191 | * Parameters: 192 | * - schema_name text - The name of the schema to check 193 | * 194 | * Example: 195 | * ```sql 196 | * BEGIN; 197 | * select plan(1); 198 | * select tests.rls_enabled('public'); 199 | * SELECT * FROM finish(); 200 | * ROLLBACK; 201 | * ``` 202 | */ 203 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text) 204 | RETURNS text AS $$ 205 | select is( 206 | (select 207 | count(pc.relname)::integer 208 | from pg_class pc 209 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema 210 | join pg_type pt on pt.oid = pc.reltype 211 | where relrowsecurity = FALSE) 212 | , 213 | 0, 214 | 'All tables in the' || testing_schema || ' schema should have row level security enabled'); 215 | $$ LANGUAGE sql; 216 | 217 | /** 218 | * ### tests.rls_enabled(testing_schema text, testing_table text) 219 | * pgTAP function to check if RLS is enabled on a specific table 220 | * 221 | * Parameters: 222 | * - schema_name text - The name of the schema to check 223 | * - testing_table text - The name of the table to check 224 | * 225 | * Example: 226 | * ```sql 227 | * BEGIN; 228 | * select plan(1); 229 | * select tests.rls_enabled('public', 'accounts'); 230 | * SELECT * FROM finish(); 231 | * ROLLBACK; 232 | * ``` 233 | */ 234 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text, testing_table text) 235 | RETURNS TEXT AS $$ 236 | select is( 237 | (select 238 | count(*)::integer 239 | from pg_class pc 240 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema and pc.relname = rls_enabled.testing_table 241 | join pg_type pt on pt.oid = pc.reltype 242 | where relrowsecurity = TRUE), 243 | 1, 244 | testing_table || 'table in the' || testing_schema || ' schema should have row level security enabled' 245 | ); 246 | $$ LANGUAGE sql; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.2--0.0.3.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * ### tests.create_supabase_user(identifier text, email text, phone text) 3 | * 4 | * Creates a new user in the `auth.users` table. 5 | * You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 6 | * 7 | * Parameters: 8 | * - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 9 | * - `email` - (Optional) The email address of the user 10 | * - `phone` - (Optional) The phone number of the user 11 | * - `metadata` - (Optional) Additional user metadata to be added to the user 12 | * 13 | * Returns: 14 | * - `user_id` - The UUID of the user in the `auth.users` table 15 | * 16 | * Example: 17 | * ```sql 18 | * SELECT tests.create_supabase_user('test_owner'); 19 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 20 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 21 | * ``` 22 | */ 23 | CREATE OR REPLACE FUNCTION tests.create_supabase_user(identifier text, email text default null, phone text default null, metadata jsonb default null) 24 | RETURNS uuid 25 | SECURITY DEFINER 26 | SET search_path = auth, pg_temp 27 | AS $$ 28 | DECLARE 29 | user_id uuid; 30 | BEGIN 31 | 32 | -- create the user 33 | user_id := extensions.uuid_generate_v4(); 34 | INSERT INTO auth.users (id, email, phone, raw_user_meta_data, raw_app_meta_data) 35 | VALUES (user_id, coalesce(email, concat(user_id, '@test.com')), phone, jsonb_build_object('test_identifier', identifier) || coalesce(metadata, '{}'::jsonb), '{}'::jsonb) 36 | RETURNING id INTO user_id; 37 | 38 | RETURN user_id; 39 | END; 40 | $$ LANGUAGE plpgsql; 41 | 42 | 43 | /** 44 | * ### tests.authenticate_as(identifier text) 45 | * Authenticates as a user created with `tests.create_supabase_user`. 46 | * 47 | * Parameters: 48 | * - `identifier` - The unique identifier for the user 49 | * 50 | * Returns: 51 | * - `void` 52 | * 53 | * Example: 54 | * ```sql 55 | * SELECT tests.create_supabase_user('test_owner'); 56 | * SELECT tests.authenticate_as('test_owner'); 57 | * ``` 58 | */ 59 | CREATE OR REPLACE FUNCTION tests.authenticate_as (identifier text) 60 | RETURNS void 61 | AS $$ 62 | DECLARE 63 | user_data json; 64 | original_auth_data text; 65 | BEGIN 66 | -- store the request.jwt.claims in a variable in case we need it 67 | original_auth_data := current_setting('request.jwt.claims', true); 68 | user_data := tests.get_supabase_user(identifier); 69 | 70 | if user_data is null OR user_data ->> 'id' IS NULL then 71 | RAISE EXCEPTION 'User with identifier % not found', identifier; 72 | end if; 73 | 74 | 75 | perform set_config('role', 'authenticated', true); 76 | perform set_config('request.jwt.claims', json_build_object( 77 | 'sub', user_data ->> 'id', 78 | 'email', user_data ->> 'email', 79 | 'phone', user_data ->> 'phone', 80 | 'user_metadata', user_data -> 'raw_user_meta_data', 81 | 'app_metadata', user_data -> 'raw_app_meta_data' 82 | )::text, true); 83 | 84 | EXCEPTION 85 | -- revert back to original auth data 86 | WHEN OTHERS THEN 87 | set local role authenticated; 88 | set local "request.jwt.claims" to original_auth_data; 89 | RAISE; 90 | END 91 | $$ LANGUAGE plpgsql; 92 | 93 | 94 | /** 95 | * ### tests.get_supabase_user(identifier text) 96 | * 97 | * Returns the user info for a user created with `tests.create_supabase_user`. 98 | * 99 | * Parameters: 100 | * - `identifier` - The unique identifier for the user 101 | * 102 | * Returns: 103 | * - `user_id` - The UUID of the user in the `auth.users` table 104 | * 105 | * Example: 106 | * ```sql 107 | * SELECT posts where posts.user_id = tests.get_supabase_user('test_owner') -> 'id'; 108 | * ``` 109 | */ 110 | CREATE OR REPLACE FUNCTION tests.get_supabase_user(identifier text) 111 | RETURNS json 112 | SECURITY DEFINER 113 | SET search_path = auth, pg_temp 114 | AS $$ 115 | DECLARE 116 | supabase_user json; 117 | BEGIN 118 | SELECT json_build_object( 119 | 'id', id, 120 | 'email', email, 121 | 'phone', phone, 122 | 'raw_user_meta_data', raw_user_meta_data, 123 | 'raw_app_meta_data', raw_app_meta_data 124 | ) into supabase_user 125 | FROM auth.users 126 | WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 127 | 128 | if supabase_user is null OR supabase_user -> 'id' IS NULL then 129 | RAISE EXCEPTION 'User with identifier % not found', identifier; 130 | end if; 131 | RETURN supabase_user; 132 | END; 133 | $$ LANGUAGE plpgsql; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.2.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION supabase_test_helpers" to load this file. \quit 3 | 4 | -- We want to store all of this in the tests schema to keep it 5 | -- separate from any application data 6 | CREATE SCHEMA IF NOT EXISTS tests; 7 | 8 | -- anon, authenticated, and service_role should have access to tests schema 9 | GRANT USAGE ON SCHEMA tests TO anon, authenticated, service_role; 10 | -- Don't allow public to execute any functions in the tests schema 11 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests REVOKE EXECUTE ON FUNCTIONS FROM public; 12 | -- Grant execute to anon, authenticated, and service_role for testing purposes 13 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 14 | 15 | /** 16 | * ### tests.create_supabase_user(identifier text, email text, phone text) 17 | * 18 | * Creates a new user in the `auth.users` table. 19 | * You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 20 | * 21 | * Parameters: 22 | * - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 23 | * - `email` - (Optional) The email address of the user 24 | * - `phone` - (Optional) The phone number of the user 25 | * - `metadata` - (Optional) Additional metadata to be added to the user 26 | * 27 | * Returns: 28 | * - `user_id` - The UUID of the user in the `auth.users` table 29 | * 30 | * Example: 31 | * ```sql 32 | * SELECT tests.create_supabase_user('test_owner'); 33 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 34 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 35 | * ``` 36 | */ 37 | CREATE OR REPLACE FUNCTION tests.create_supabase_user(identifier text, email text default null, phone text default null, metadata jsonb default null) 38 | RETURNS uuid 39 | SECURITY DEFINER 40 | SET search_path = auth, pg_temp 41 | AS $$ 42 | DECLARE 43 | user_id uuid; 44 | BEGIN 45 | 46 | -- create the user 47 | user_id := extensions.uuid_generate_v4(); 48 | INSERT INTO auth.users (id, email, phone, raw_user_meta_data) 49 | VALUES (user_id, coalesce(email, concat(user_id, '@test.com')), phone, jsonb_build_object('test_identifier', identifier) || coalesce(metadata, '{}'::jsonb)) 50 | RETURNING id INTO user_id; 51 | 52 | RETURN user_id; 53 | END; 54 | $$ LANGUAGE plpgsql; 55 | 56 | /** 57 | * ### tests.get_supabase_user(identifier text) 58 | * 59 | * Returns the user info for a user created with `tests.create_supabase_user`. 60 | * 61 | * Parameters: 62 | * - `identifier` - The unique identifier for the user 63 | * 64 | * Returns: 65 | * - `user_id` - The UUID of the user in the `auth.users` table 66 | * 67 | * Example: 68 | * ```sql 69 | * SELECT posts where posts.user_id = tests.get_supabase_user('test_owner') -> 'id'; 70 | * ``` 71 | */ 72 | CREATE OR REPLACE FUNCTION tests.get_supabase_user(identifier text) 73 | RETURNS json 74 | SECURITY DEFINER 75 | SET search_path = auth, pg_temp 76 | AS $$ 77 | DECLARE 78 | supabase_user json; 79 | BEGIN 80 | SELECT json_build_object('id', id, 'email', email, 'phone', phone, 'raw_user_meta_data', raw_user_meta_data) into supabase_user FROM auth.users WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 81 | if supabase_user is null OR supabase_user -> 'id' IS NULL then 82 | RAISE EXCEPTION 'User with identifier % not found', identifier; 83 | end if; 84 | RETURN supabase_user; 85 | END; 86 | $$ LANGUAGE plpgsql; 87 | 88 | /** 89 | * ### tests.get_supabase_uid(identifier text) 90 | * 91 | * Returns the user UUID for a user created with `tests.create_supabase_user`. 92 | * 93 | * Parameters: 94 | * - `identifier` - The unique identifier for the user 95 | * 96 | * Returns: 97 | * - `user_id` - The UUID of the user in the `auth.users` table 98 | * 99 | * Example: 100 | * ```sql 101 | * SELECT posts where posts.user_id = tests.get_supabase_uid('test_owner') -> 'id'; 102 | * ``` 103 | */ 104 | CREATE OR REPLACE FUNCTION tests.get_supabase_uid(identifier text) 105 | RETURNS uuid 106 | SECURITY DEFINER 107 | SET search_path = auth, pg_temp 108 | AS $$ 109 | DECLARE 110 | supabase_user uuid; 111 | BEGIN 112 | SELECT id into supabase_user FROM auth.users WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 113 | if supabase_user is null then 114 | RAISE EXCEPTION 'User with identifier % not found', identifier; 115 | end if; 116 | RETURN supabase_user; 117 | END; 118 | $$ LANGUAGE plpgsql; 119 | 120 | /** 121 | * ### tests.authenticate_as(identifier text) 122 | * Authenticates as a user created with `tests.create_supabase_user`. 123 | * 124 | * Parameters: 125 | * - `identifier` - The unique identifier for the user 126 | * 127 | * Returns: 128 | * - `void` 129 | * 130 | * Example: 131 | * ```sql 132 | * SELECT tests.create_supabase_user('test_owner'); 133 | * SELECT tests.authenticate_as('test_owner'); 134 | * ``` 135 | */ 136 | CREATE OR REPLACE FUNCTION tests.authenticate_as (identifier text) 137 | RETURNS void 138 | AS $$ 139 | DECLARE 140 | user_data json; 141 | original_auth_data text; 142 | BEGIN 143 | -- store the request.jwt.claims in a variable in case we need it 144 | original_auth_data := current_setting('request.jwt.claims', true); 145 | user_data := tests.get_supabase_user(identifier); 146 | 147 | if user_data is null OR user_data ->> 'id' IS NULL then 148 | RAISE EXCEPTION 'User with identifier % not found', identifier; 149 | end if; 150 | 151 | 152 | perform set_config('role', 'authenticated', true); 153 | perform set_config('request.jwt.claims', json_build_object('sub', user_data ->> 'id', 'email', user_data ->> 'email', 'phone', user_data ->> 'phone')::text, true); 154 | 155 | EXCEPTION 156 | -- revert back to original auth data 157 | WHEN OTHERS THEN 158 | set local role authenticated; 159 | set local "request.jwt.claims" to original_auth_data; 160 | RAISE; 161 | END 162 | $$ LANGUAGE plpgsql; 163 | 164 | /** 165 | * ### tests.authenticate_as_service_role() 166 | * Clears authentication object and sets role to service_role. 167 | * 168 | * Returns: 169 | * - `void` 170 | * 171 | * Example: 172 | * ```sql 173 | * SELECT tests.authenticate_as_service_role(); 174 | * ``` 175 | */ 176 | CREATE OR REPLACE FUNCTION tests.authenticate_as_service_role () 177 | RETURNS void 178 | AS $$ 179 | BEGIN 180 | perform set_config('role', 'service_role', true); 181 | perform set_config('request.jwt.claims', null, true); 182 | END 183 | $$ LANGUAGE plpgsql; 184 | 185 | 186 | /** 187 | * ### tests.clear_authentication() 188 | * Clears out the authentication and sets role to anon 189 | * 190 | * Returns: 191 | * - `void` 192 | * 193 | * Example: 194 | * ```sql 195 | * SELECT tests.create_supabase_user('test_owner'); 196 | * SELECT tests.authenticate_as('test_owner'); 197 | * SELECT tests.clear_authentication(); 198 | * ``` 199 | */ 200 | CREATE OR REPLACE FUNCTION tests.clear_authentication() 201 | RETURNS void AS $$ 202 | BEGIN 203 | perform set_config('role', 'anon', true); 204 | perform set_config('request.jwt.claims', null, true); 205 | END 206 | $$ LANGUAGE plpgsql; 207 | 208 | /** 209 | * ### tests.rls_enabled(testing_schema text) 210 | * pgTAP function to check if RLS is enabled on all tables in a provided schema 211 | * 212 | * Parameters: 213 | * - schema_name text - The name of the schema to check 214 | * 215 | * Example: 216 | * ```sql 217 | * BEGIN; 218 | * select plan(1); 219 | * select tests.rls_enabled('public'); 220 | * SELECT * FROM finish(); 221 | * ROLLBACK; 222 | * ``` 223 | */ 224 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text) 225 | RETURNS text AS $$ 226 | select is( 227 | (select 228 | count(pc.relname)::integer 229 | from pg_class pc 230 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema 231 | join pg_type pt on pt.oid = pc.reltype 232 | where relrowsecurity = FALSE) 233 | , 234 | 0, 235 | 'All tables in the' || testing_schema || ' schema should have row level security enabled'); 236 | $$ LANGUAGE sql; 237 | 238 | /** 239 | * ### tests.rls_enabled(testing_schema text, testing_table text) 240 | * pgTAP function to check if RLS is enabled on a specific table 241 | * 242 | * Parameters: 243 | * - schema_name text - The name of the schema to check 244 | * - testing_table text - The name of the table to check 245 | * 246 | * Example: 247 | * ```sql 248 | * BEGIN; 249 | * select plan(1); 250 | * select tests.rls_enabled('public', 'accounts'); 251 | * SELECT * FROM finish(); 252 | * ROLLBACK; 253 | * ``` 254 | */ 255 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text, testing_table text) 256 | RETURNS TEXT AS $$ 257 | select is( 258 | (select 259 | count(*)::integer 260 | from pg_class pc 261 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema and pc.relname = rls_enabled.testing_table 262 | join pg_type pt on pt.oid = pc.reltype 263 | where relrowsecurity = TRUE), 264 | 1, 265 | testing_table || 'table in the' || testing_schema || ' schema should have row level security enabled' 266 | ); 267 | $$ LANGUAGE sql; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.3--0.0.4.sql: -------------------------------------------------------------------------------- 1 | --- Create a specific schema for override functions so we don't have to worry about 2 | --- anything else be adding to the tests schema 3 | CREATE SCHEMA IF NOT EXISTS test_overrides; 4 | 5 | /** 6 | * ### tests.create_supabase_user(identifier text, email text, phone text) 7 | * 8 | * Creates a new user in the `auth.users` table. 9 | * You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 10 | * 11 | * Parameters: 12 | * - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 13 | * - `email` - (Optional) The email address of the user 14 | * - `phone` - (Optional) The phone number of the user 15 | * - `metadata` - (Optional) Additional metadata to be added to the user 16 | * 17 | * Returns: 18 | * - `user_id` - The UUID of the user in the `auth.users` table 19 | * 20 | * Example: 21 | * ```sql 22 | * SELECT tests.create_supabase_user('test_owner'); 23 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 24 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 25 | * ``` 26 | */ 27 | CREATE OR REPLACE FUNCTION tests.create_supabase_user(identifier text, email text default null, phone text default null, metadata jsonb default null) 28 | RETURNS uuid 29 | SECURITY DEFINER 30 | SET search_path = auth, pg_temp 31 | AS $$ 32 | DECLARE 33 | user_id uuid; 34 | BEGIN 35 | 36 | -- create the user 37 | user_id := extensions.uuid_generate_v4(); 38 | INSERT INTO auth.users (id, email, phone, raw_user_meta_data, raw_app_meta_data, created_at, updated_at) 39 | VALUES (user_id, coalesce(email, concat(user_id, '@test.com')), phone, jsonb_build_object('test_identifier', identifier) || coalesce(metadata, '{}'::jsonb), '{}'::jsonb, now(), now()) 40 | RETURNING id INTO user_id; 41 | 42 | RETURN user_id; 43 | END; 44 | $$ LANGUAGE plpgsql; 45 | 46 | -- 47 | -- Generated now() function used to replace pg_catalog.now() for the purpose 48 | -- of freezing time in tests. This should not be used directly. 49 | -- 50 | CREATE OR REPLACE FUNCTION test_overrides.now() 51 | RETURNS timestamp with time zone 52 | AS $$ 53 | BEGIN 54 | 55 | 56 | -- check if a frozen time is set 57 | IF nullif(current_setting('tests.frozen_time'), '') IS NOT NULL THEN 58 | RETURN current_setting('tests.frozen_time')::timestamptz; 59 | END IF; 60 | 61 | RETURN pg_catalog.now(); 62 | END 63 | $$ LANGUAGE plpgsql; 64 | 65 | 66 | /** 67 | * ### tests.freeze_time(frozen_time timestamp with time zone) 68 | * 69 | * Overwrites the current time from now() to the provided time. 70 | * 71 | * Parameters: 72 | * - `frozen_time` - The time to freeze to. Supports timestamp with time zone, without time zone, date or any other value that can be coerced into a timestamp with time zone. 73 | * 74 | * Returns: 75 | * - void 76 | * 77 | * Example: 78 | * ```sql 79 | * SELECT tests.freeze_time('2020-01-01 00:00:00'); 80 | * ``` 81 | */ 82 | 83 | CREATE OR REPLACE FUNCTION tests.freeze_time(frozen_time timestamp with time zone) 84 | RETURNS void 85 | AS $$ 86 | BEGIN 87 | 88 | -- Add test_overrides to search path if needed 89 | IF current_setting('search_path') NOT LIKE 'test_overrides,%' THEN 90 | -- store search path for later 91 | PERFORM set_config('tests.original_search_path', current_setting('search_path'), true); 92 | 93 | -- add tests schema to start of search path 94 | PERFORM set_config('search_path', 'test_overrides,' || current_setting('tests.original_search_path') || ',pg_catalog', true); 95 | END IF; 96 | 97 | -- create an overwriting now function 98 | PERFORM set_config('tests.frozen_time', frozen_time::text, true); 99 | 100 | END 101 | $$ LANGUAGE plpgsql; 102 | 103 | /** 104 | * ### tests.unfreeze_time() 105 | * 106 | * Unfreezes the time and restores the original now() function. 107 | * 108 | * Returns: 109 | * - void 110 | * 111 | * Example: 112 | * ```sql 113 | * SELECT tests.unfreeze_time(); 114 | * ``` 115 | */ 116 | 117 | CREATE OR REPLACE FUNCTION tests.unfreeze_time() 118 | RETURNS void 119 | AS $$ 120 | BEGIN 121 | -- restore the original now function 122 | PERFORM set_config('tests.frozen_time', null, true); 123 | -- restore the original search path 124 | PERFORM set_config('search_path', current_setting('tests.original_search_path'), true); 125 | END 126 | $$ LANGUAGE plpgsql; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.3.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION supabase_test_helpers" to load this file. \quit 3 | 4 | -- We want to store all of this in the tests schema to keep it 5 | -- separate from any application data 6 | CREATE SCHEMA IF NOT EXISTS tests; 7 | 8 | -- anon, authenticated, and service_role should have access to tests schema 9 | GRANT USAGE ON SCHEMA tests TO anon, authenticated, service_role; 10 | -- Don't allow public to execute any functions in the tests schema 11 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests REVOKE EXECUTE ON FUNCTIONS FROM public; 12 | -- Grant execute to anon, authenticated, and service_role for testing purposes 13 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 14 | 15 | /** 16 | * ### tests.create_supabase_user(identifier text, email text, phone text) 17 | * 18 | * Creates a new user in the `auth.users` table. 19 | * You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 20 | * 21 | * Parameters: 22 | * - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 23 | * - `email` - (Optional) The email address of the user 24 | * - `phone` - (Optional) The phone number of the user 25 | * - `metadata` - (Optional) Additional metadata to be added to the user 26 | * 27 | * Returns: 28 | * - `user_id` - The UUID of the user in the `auth.users` table 29 | * 30 | * Example: 31 | * ```sql 32 | * SELECT tests.create_supabase_user('test_owner'); 33 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 34 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 35 | * ``` 36 | */ 37 | CREATE OR REPLACE FUNCTION tests.create_supabase_user(identifier text, email text default null, phone text default null, metadata jsonb default null) 38 | RETURNS uuid 39 | SECURITY DEFINER 40 | SET search_path = auth, pg_temp 41 | AS $$ 42 | DECLARE 43 | user_id uuid; 44 | BEGIN 45 | 46 | -- create the user 47 | user_id := extensions.uuid_generate_v4(); 48 | INSERT INTO auth.users (id, email, phone, raw_user_meta_data, raw_app_meta_data) 49 | VALUES (user_id, coalesce(email, concat(user_id, '@test.com')), phone, jsonb_build_object('test_identifier', identifier) || coalesce(metadata, '{}'::jsonb), '{}'::jsonb) 50 | RETURNING id INTO user_id; 51 | 52 | RETURN user_id; 53 | END; 54 | $$ LANGUAGE plpgsql; 55 | 56 | 57 | /** 58 | * ### tests.get_supabase_user(identifier text) 59 | * 60 | * Returns the user info for a user created with `tests.create_supabase_user`. 61 | * 62 | * Parameters: 63 | * - `identifier` - The unique identifier for the user 64 | * 65 | * Returns: 66 | * - `user_id` - The UUID of the user in the `auth.users` table 67 | * 68 | * Example: 69 | * ```sql 70 | * SELECT posts where posts.user_id = tests.get_supabase_user('test_owner') -> 'id'; 71 | * ``` 72 | */ 73 | CREATE OR REPLACE FUNCTION tests.get_supabase_user(identifier text) 74 | RETURNS json 75 | SECURITY DEFINER 76 | SET search_path = auth, pg_temp 77 | AS $$ 78 | DECLARE 79 | supabase_user json; 80 | BEGIN 81 | SELECT json_build_object( 82 | 'id', id, 83 | 'email', email, 84 | 'phone', phone, 85 | 'raw_user_meta_data', raw_user_meta_data, 86 | 'raw_app_meta_data', raw_app_meta_data 87 | ) into supabase_user 88 | FROM auth.users 89 | WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 90 | 91 | if supabase_user is null OR supabase_user -> 'id' IS NULL then 92 | RAISE EXCEPTION 'User with identifier % not found', identifier; 93 | end if; 94 | RETURN supabase_user; 95 | END; 96 | $$ LANGUAGE plpgsql; 97 | 98 | /** 99 | * ### tests.get_supabase_uid(identifier text) 100 | * 101 | * Returns the user UUID for a user created with `tests.create_supabase_user`. 102 | * 103 | * Parameters: 104 | * - `identifier` - The unique identifier for the user 105 | * 106 | * Returns: 107 | * - `user_id` - The UUID of the user in the `auth.users` table 108 | * 109 | * Example: 110 | * ```sql 111 | * SELECT posts where posts.user_id = tests.get_supabase_uid('test_owner') -> 'id'; 112 | * ``` 113 | */ 114 | CREATE OR REPLACE FUNCTION tests.get_supabase_uid(identifier text) 115 | RETURNS uuid 116 | SECURITY DEFINER 117 | SET search_path = auth, pg_temp 118 | AS $$ 119 | DECLARE 120 | supabase_user uuid; 121 | BEGIN 122 | SELECT id into supabase_user FROM auth.users WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 123 | if supabase_user is null then 124 | RAISE EXCEPTION 'User with identifier % not found', identifier; 125 | end if; 126 | RETURN supabase_user; 127 | END; 128 | $$ LANGUAGE plpgsql; 129 | 130 | /** 131 | * ### tests.authenticate_as(identifier text) 132 | * Authenticates as a user created with `tests.create_supabase_user`. 133 | * 134 | * Parameters: 135 | * - `identifier` - The unique identifier for the user 136 | * 137 | * Returns: 138 | * - `void` 139 | * 140 | * Example: 141 | * ```sql 142 | * SELECT tests.create_supabase_user('test_owner'); 143 | * SELECT tests.authenticate_as('test_owner'); 144 | * ``` 145 | */ 146 | CREATE OR REPLACE FUNCTION tests.authenticate_as (identifier text) 147 | RETURNS void 148 | AS $$ 149 | DECLARE 150 | user_data json; 151 | original_auth_data text; 152 | BEGIN 153 | -- store the request.jwt.claims in a variable in case we need it 154 | original_auth_data := current_setting('request.jwt.claims', true); 155 | user_data := tests.get_supabase_user(identifier); 156 | 157 | if user_data is null OR user_data ->> 'id' IS NULL then 158 | RAISE EXCEPTION 'User with identifier % not found', identifier; 159 | end if; 160 | 161 | 162 | perform set_config('role', 'authenticated', true); 163 | perform set_config('request.jwt.claims', json_build_object( 164 | 'sub', user_data ->> 'id', 165 | 'email', user_data ->> 'email', 166 | 'phone', user_data ->> 'phone', 167 | 'user_metadata', user_data -> 'raw_user_meta_data', 168 | 'app_metadata', user_data -> 'raw_app_meta_data' 169 | )::text, true); 170 | 171 | EXCEPTION 172 | -- revert back to original auth data 173 | WHEN OTHERS THEN 174 | set local role authenticated; 175 | set local "request.jwt.claims" to original_auth_data; 176 | RAISE; 177 | END 178 | $$ LANGUAGE plpgsql; 179 | 180 | /** 181 | * ### tests.authenticate_as_service_role() 182 | * Clears authentication object and sets role to service_role. 183 | * 184 | * Returns: 185 | * - `void` 186 | * 187 | * Example: 188 | * ```sql 189 | * SELECT tests.authenticate_as_service_role(); 190 | * ``` 191 | */ 192 | CREATE OR REPLACE FUNCTION tests.authenticate_as_service_role () 193 | RETURNS void 194 | AS $$ 195 | BEGIN 196 | perform set_config('role', 'service_role', true); 197 | perform set_config('request.jwt.claims', null, true); 198 | END 199 | $$ LANGUAGE plpgsql; 200 | 201 | 202 | /** 203 | * ### tests.clear_authentication() 204 | * Clears out the authentication and sets role to anon 205 | * 206 | * Returns: 207 | * - `void` 208 | * 209 | * Example: 210 | * ```sql 211 | * SELECT tests.create_supabase_user('test_owner'); 212 | * SELECT tests.authenticate_as('test_owner'); 213 | * SELECT tests.clear_authentication(); 214 | * ``` 215 | */ 216 | CREATE OR REPLACE FUNCTION tests.clear_authentication() 217 | RETURNS void AS $$ 218 | BEGIN 219 | perform set_config('role', 'anon', true); 220 | perform set_config('request.jwt.claims', null, true); 221 | END 222 | $$ LANGUAGE plpgsql; 223 | 224 | /** 225 | * ### tests.rls_enabled(testing_schema text) 226 | * pgTAP function to check if RLS is enabled on all tables in a provided schema 227 | * 228 | * Parameters: 229 | * - schema_name text - The name of the schema to check 230 | * 231 | * Example: 232 | * ```sql 233 | * BEGIN; 234 | * select plan(1); 235 | * select tests.rls_enabled('public'); 236 | * SELECT * FROM finish(); 237 | * ROLLBACK; 238 | * ``` 239 | */ 240 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text) 241 | RETURNS text AS $$ 242 | select is( 243 | (select 244 | count(pc.relname)::integer 245 | from pg_class pc 246 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema 247 | join pg_type pt on pt.oid = pc.reltype 248 | where relrowsecurity = FALSE) 249 | , 250 | 0, 251 | 'All tables in the' || testing_schema || ' schema should have row level security enabled'); 252 | $$ LANGUAGE sql; 253 | 254 | /** 255 | * ### tests.rls_enabled(testing_schema text, testing_table text) 256 | * pgTAP function to check if RLS is enabled on a specific table 257 | * 258 | * Parameters: 259 | * - schema_name text - The name of the schema to check 260 | * - testing_table text - The name of the table to check 261 | * 262 | * Example: 263 | * ```sql 264 | * BEGIN; 265 | * select plan(1); 266 | * select tests.rls_enabled('public', 'accounts'); 267 | * SELECT * FROM finish(); 268 | * ROLLBACK; 269 | * ``` 270 | */ 271 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text, testing_table text) 272 | RETURNS TEXT AS $$ 273 | select is( 274 | (select 275 | count(*)::integer 276 | from pg_class pc 277 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema and pc.relname = rls_enabled.testing_table 278 | join pg_type pt on pt.oid = pc.reltype 279 | where relrowsecurity = TRUE), 280 | 1, 281 | testing_table || 'table in the' || testing_schema || ' schema should have row level security enabled' 282 | ); 283 | $$ LANGUAGE sql; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.4--0.0.5.sql: -------------------------------------------------------------------------------- 1 | -- anon, authenticated, and service_role should have access to test_overrides schema 2 | GRANT USAGE ON SCHEMA test_overrides TO anon, authenticated, service_role; 3 | -- Don't allow public to execute any functions in the test_overrides schema 4 | ALTER DEFAULT PRIVILEGES IN SCHEMA test_overrides REVOKE EXECUTE ON FUNCTIONS FROM public; 5 | -- Grant execute to anon, authenticated, and service_role for testing purposes 6 | ALTER DEFAULT PRIVILEGES IN SCHEMA test_overrides GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 7 | 8 | GRANT EXECUTE ON FUNCTION test_overrides.now() TO anon, authenticated, service_role; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.4--0.0.6.sql: -------------------------------------------------------------------------------- 1 | -- anon, authenticated, and service_role should have access to test_overrides schema 2 | GRANT USAGE ON SCHEMA test_overrides TO anon, authenticated, service_role; 3 | -- Don't allow public to execute any functions in the test_overrides schema 4 | ALTER DEFAULT PRIVILEGES IN SCHEMA test_overrides REVOKE EXECUTE ON FUNCTIONS FROM public; 5 | -- Grant execute to anon, authenticated, and service_role for testing purposes 6 | ALTER DEFAULT PRIVILEGES IN SCHEMA test_overrides GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 7 | 8 | GRANT EXECUTE ON FUNCTION test_overrides.now() TO anon, authenticated, service_role; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.4.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION supabase_test_helpers" to load this file. \quit 3 | 4 | -- We want to store all of this in the tests schema to keep it 5 | -- separate from any application data 6 | CREATE SCHEMA IF NOT EXISTS tests; 7 | 8 | --- Create a specific schema for override functions so we don't have to worry about 9 | --- anything else be adding to the tests schema 10 | CREATE SCHEMA IF NOT EXISTS test_overrides; 11 | 12 | -- anon, authenticated, and service_role should have access to tests schema 13 | GRANT USAGE ON SCHEMA tests TO anon, authenticated, service_role; 14 | -- Don't allow public to execute any functions in the tests schema 15 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests REVOKE EXECUTE ON FUNCTIONS FROM public; 16 | -- Grant execute to anon, authenticated, and service_role for testing purposes 17 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 18 | 19 | /** 20 | * ### tests.create_supabase_user(identifier text, email text, phone text) 21 | * 22 | * Creates a new user in the `auth.users` table. 23 | * You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 24 | * 25 | * Parameters: 26 | * - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 27 | * - `email` - (Optional) The email address of the user 28 | * - `phone` - (Optional) The phone number of the user 29 | * - `metadata` - (Optional) Additional metadata to be added to the user 30 | * 31 | * Returns: 32 | * - `user_id` - The UUID of the user in the `auth.users` table 33 | * 34 | * Example: 35 | * ```sql 36 | * SELECT tests.create_supabase_user('test_owner'); 37 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 38 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 39 | * ``` 40 | */ 41 | CREATE OR REPLACE FUNCTION tests.create_supabase_user(identifier text, email text default null, phone text default null, metadata jsonb default null) 42 | RETURNS uuid 43 | SECURITY DEFINER 44 | SET search_path = auth, pg_temp 45 | AS $$ 46 | DECLARE 47 | user_id uuid; 48 | BEGIN 49 | 50 | -- create the user 51 | user_id := extensions.uuid_generate_v4(); 52 | INSERT INTO auth.users (id, email, phone, raw_user_meta_data, raw_app_meta_data, created_at, updated_at) 53 | VALUES (user_id, coalesce(email, concat(user_id, '@test.com')), phone, jsonb_build_object('test_identifier', identifier) || coalesce(metadata, '{}'::jsonb), '{}'::jsonb, now(), now()) 54 | RETURNING id INTO user_id; 55 | 56 | RETURN user_id; 57 | END; 58 | $$ LANGUAGE plpgsql; 59 | 60 | 61 | /** 62 | * ### tests.get_supabase_user(identifier text) 63 | * 64 | * Returns the user info for a user created with `tests.create_supabase_user`. 65 | * 66 | * Parameters: 67 | * - `identifier` - The unique identifier for the user 68 | * 69 | * Returns: 70 | * - `user_id` - The UUID of the user in the `auth.users` table 71 | * 72 | * Example: 73 | * ```sql 74 | * SELECT posts where posts.user_id = tests.get_supabase_user('test_owner') -> 'id'; 75 | * ``` 76 | */ 77 | CREATE OR REPLACE FUNCTION tests.get_supabase_user(identifier text) 78 | RETURNS json 79 | SECURITY DEFINER 80 | SET search_path = auth, pg_temp 81 | AS $$ 82 | DECLARE 83 | supabase_user json; 84 | BEGIN 85 | SELECT json_build_object( 86 | 'id', id, 87 | 'email', email, 88 | 'phone', phone, 89 | 'raw_user_meta_data', raw_user_meta_data, 90 | 'raw_app_meta_data', raw_app_meta_data 91 | ) into supabase_user 92 | FROM auth.users 93 | WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 94 | 95 | if supabase_user is null OR supabase_user -> 'id' IS NULL then 96 | RAISE EXCEPTION 'User with identifier % not found', identifier; 97 | end if; 98 | RETURN supabase_user; 99 | END; 100 | $$ LANGUAGE plpgsql; 101 | 102 | /** 103 | * ### tests.get_supabase_uid(identifier text) 104 | * 105 | * Returns the user UUID for a user created with `tests.create_supabase_user`. 106 | * 107 | * Parameters: 108 | * - `identifier` - The unique identifier for the user 109 | * 110 | * Returns: 111 | * - `user_id` - The UUID of the user in the `auth.users` table 112 | * 113 | * Example: 114 | * ```sql 115 | * SELECT posts where posts.user_id = tests.get_supabase_uid('test_owner') -> 'id'; 116 | * ``` 117 | */ 118 | CREATE OR REPLACE FUNCTION tests.get_supabase_uid(identifier text) 119 | RETURNS uuid 120 | SECURITY DEFINER 121 | SET search_path = auth, pg_temp 122 | AS $$ 123 | DECLARE 124 | supabase_user uuid; 125 | BEGIN 126 | SELECT id into supabase_user FROM auth.users WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 127 | if supabase_user is null then 128 | RAISE EXCEPTION 'User with identifier % not found', identifier; 129 | end if; 130 | RETURN supabase_user; 131 | END; 132 | $$ LANGUAGE plpgsql; 133 | 134 | /** 135 | * ### tests.authenticate_as(identifier text) 136 | * Authenticates as a user created with `tests.create_supabase_user`. 137 | * 138 | * Parameters: 139 | * - `identifier` - The unique identifier for the user 140 | * 141 | * Returns: 142 | * - `void` 143 | * 144 | * Example: 145 | * ```sql 146 | * SELECT tests.create_supabase_user('test_owner'); 147 | * SELECT tests.authenticate_as('test_owner'); 148 | * ``` 149 | */ 150 | CREATE OR REPLACE FUNCTION tests.authenticate_as (identifier text) 151 | RETURNS void 152 | AS $$ 153 | DECLARE 154 | user_data json; 155 | original_auth_data text; 156 | BEGIN 157 | -- store the request.jwt.claims in a variable in case we need it 158 | original_auth_data := current_setting('request.jwt.claims', true); 159 | user_data := tests.get_supabase_user(identifier); 160 | 161 | if user_data is null OR user_data ->> 'id' IS NULL then 162 | RAISE EXCEPTION 'User with identifier % not found', identifier; 163 | end if; 164 | 165 | 166 | perform set_config('role', 'authenticated', true); 167 | perform set_config('request.jwt.claims', json_build_object( 168 | 'sub', user_data ->> 'id', 169 | 'email', user_data ->> 'email', 170 | 'phone', user_data ->> 'phone', 171 | 'user_metadata', user_data -> 'raw_user_meta_data', 172 | 'app_metadata', user_data -> 'raw_app_meta_data' 173 | )::text, true); 174 | 175 | EXCEPTION 176 | -- revert back to original auth data 177 | WHEN OTHERS THEN 178 | set local role authenticated; 179 | set local "request.jwt.claims" to original_auth_data; 180 | RAISE; 181 | END 182 | $$ LANGUAGE plpgsql; 183 | 184 | /** 185 | * ### tests.authenticate_as_service_role() 186 | * Clears authentication object and sets role to service_role. 187 | * 188 | * Returns: 189 | * - `void` 190 | * 191 | * Example: 192 | * ```sql 193 | * SELECT tests.authenticate_as_service_role(); 194 | * ``` 195 | */ 196 | CREATE OR REPLACE FUNCTION tests.authenticate_as_service_role () 197 | RETURNS void 198 | AS $$ 199 | BEGIN 200 | perform set_config('role', 'service_role', true); 201 | perform set_config('request.jwt.claims', null, true); 202 | END 203 | $$ LANGUAGE plpgsql; 204 | 205 | 206 | /** 207 | * ### tests.clear_authentication() 208 | * Clears out the authentication and sets role to anon 209 | * 210 | * Returns: 211 | * - `void` 212 | * 213 | * Example: 214 | * ```sql 215 | * SELECT tests.create_supabase_user('test_owner'); 216 | * SELECT tests.authenticate_as('test_owner'); 217 | * SELECT tests.clear_authentication(); 218 | * ``` 219 | */ 220 | CREATE OR REPLACE FUNCTION tests.clear_authentication() 221 | RETURNS void AS $$ 222 | BEGIN 223 | perform set_config('role', 'anon', true); 224 | perform set_config('request.jwt.claims', null, true); 225 | END 226 | $$ LANGUAGE plpgsql; 227 | 228 | /** 229 | * ### tests.rls_enabled(testing_schema text) 230 | * pgTAP function to check if RLS is enabled on all tables in a provided schema 231 | * 232 | * Parameters: 233 | * - schema_name text - The name of the schema to check 234 | * 235 | * Example: 236 | * ```sql 237 | * BEGIN; 238 | * select plan(1); 239 | * select tests.rls_enabled('public'); 240 | * SELECT * FROM finish(); 241 | * ROLLBACK; 242 | * ``` 243 | */ 244 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text) 245 | RETURNS text AS $$ 246 | select is( 247 | (select 248 | count(pc.relname)::integer 249 | from pg_class pc 250 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema 251 | join pg_type pt on pt.oid = pc.reltype 252 | where relrowsecurity = FALSE) 253 | , 254 | 0, 255 | 'All tables in the' || testing_schema || ' schema should have row level security enabled'); 256 | $$ LANGUAGE sql; 257 | 258 | /** 259 | * ### tests.rls_enabled(testing_schema text, testing_table text) 260 | * pgTAP function to check if RLS is enabled on a specific table 261 | * 262 | * Parameters: 263 | * - schema_name text - The name of the schema to check 264 | * - testing_table text - The name of the table to check 265 | * 266 | * Example: 267 | * ```sql 268 | * BEGIN; 269 | * select plan(1); 270 | * select tests.rls_enabled('public', 'accounts'); 271 | * SELECT * FROM finish(); 272 | * ROLLBACK; 273 | * ``` 274 | */ 275 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text, testing_table text) 276 | RETURNS TEXT AS $$ 277 | select is( 278 | (select 279 | count(*)::integer 280 | from pg_class pc 281 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema and pc.relname = rls_enabled.testing_table 282 | join pg_type pt on pt.oid = pc.reltype 283 | where relrowsecurity = TRUE), 284 | 1, 285 | testing_table || 'table in the' || testing_schema || ' schema should have row level security enabled' 286 | ); 287 | $$ LANGUAGE sql; 288 | 289 | -- 290 | -- Generated now() function used to replace pg_catalog.now() for the purpose 291 | -- of freezing time in tests. This should not be used directly. 292 | -- 293 | CREATE OR REPLACE FUNCTION test_overrides.now() 294 | RETURNS timestamp with time zone 295 | AS $$ 296 | BEGIN 297 | 298 | 299 | -- check if a frozen time is set 300 | IF nullif(current_setting('tests.frozen_time'), '') IS NOT NULL THEN 301 | RETURN current_setting('tests.frozen_time')::timestamptz; 302 | END IF; 303 | 304 | RETURN pg_catalog.now(); 305 | END 306 | $$ LANGUAGE plpgsql; 307 | 308 | 309 | /** 310 | * ### tests.freeze_time(frozen_time timestamp with time zone) 311 | * 312 | * Overwrites the current time from now() to the provided time. 313 | * 314 | * Works out of the box for any normal usage of now(), if you have a function that sets its own search path, such as security definers, then you will need to alter the function to set the search path to include test_overrides BEFORE pg_catalog. 315 | * **ONLY do this inside of a pgtap test transaction.** 316 | * Example: 317 | * 318 | * ```sql 319 | * ALTER FUNCTION auth.your_function() SET search_path = test_overrides, public, pg_temp, pg_catalog; 320 | * ``` 321 | * View a test example in 05-frozen-time.sql: https://github.com/usebasejump/supabase-test-helpers/blob/main/supabase/tests/05-frozen-time.sql 322 | * 323 | * Parameters: 324 | * - `frozen_time` - The time to freeze to. Supports timestamp with time zone, without time zone, date or any other value that can be coerced into a timestamp with time zone. 325 | * 326 | * Returns: 327 | * - void 328 | * 329 | * Example: 330 | * ```sql 331 | * SELECT tests.freeze_time('2020-01-01 00:00:00'); 332 | * ``` 333 | */ 334 | 335 | CREATE OR REPLACE FUNCTION tests.freeze_time(frozen_time timestamp with time zone) 336 | RETURNS void 337 | AS $$ 338 | BEGIN 339 | 340 | -- Add test_overrides to search path if needed 341 | IF current_setting('search_path') NOT LIKE 'test_overrides,%' THEN 342 | -- store search path for later 343 | PERFORM set_config('tests.original_search_path', current_setting('search_path'), true); 344 | 345 | -- add tests schema to start of search path 346 | PERFORM set_config('search_path', 'test_overrides,' || current_setting('tests.original_search_path') || ',pg_catalog', true); 347 | END IF; 348 | 349 | -- create an overwriting now function 350 | PERFORM set_config('tests.frozen_time', frozen_time::text, true); 351 | 352 | END 353 | $$ LANGUAGE plpgsql; 354 | 355 | /** 356 | * ### tests.unfreeze_time() 357 | * 358 | * Unfreezes the time and restores the original now() function. 359 | * 360 | * Returns: 361 | * - void 362 | * 363 | * Example: 364 | * ```sql 365 | * SELECT tests.unfreeze_time(); 366 | * ``` 367 | */ 368 | 369 | CREATE OR REPLACE FUNCTION tests.unfreeze_time() 370 | RETURNS void 371 | AS $$ 372 | BEGIN 373 | -- restore the original now function 374 | PERFORM set_config('tests.frozen_time', null, true); 375 | -- restore the original search path 376 | PERFORM set_config('search_path', current_setting('tests.original_search_path'), true); 377 | END 378 | $$ LANGUAGE plpgsql; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.5.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION supabase_test_helpers" to load this file. \quit 3 | 4 | -- We want to store all of this in the tests schema to keep it 5 | -- separate from any application data 6 | CREATE SCHEMA IF NOT EXISTS tests; 7 | 8 | --- Create a specific schema for override functions so we don't have to worry about 9 | --- anything else be adding to the tests schema 10 | CREATE SCHEMA IF NOT EXISTS test_overrides; 11 | 12 | -- anon, authenticated, and service_role should have access to tests schema 13 | GRANT USAGE ON SCHEMA tests TO anon, authenticated, service_role; 14 | -- Don't allow public to execute any functions in the tests schema 15 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests REVOKE EXECUTE ON FUNCTIONS FROM public; 16 | -- Grant execute to anon, authenticated, and service_role for testing purposes 17 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 18 | 19 | -- anon, authenticated, and service_role should have access to test_overrides schema 20 | GRANT USAGE ON SCHEMA test_overrides TO anon, authenticated, service_role; 21 | -- Don't allow public to execute any functions in the test_overrides schema 22 | ALTER DEFAULT PRIVILEGES IN SCHEMA test_overrides REVOKE EXECUTE ON FUNCTIONS FROM public; 23 | -- Grant execute to anon, authenticated, and service_role for testing purposes 24 | ALTER DEFAULT PRIVILEGES IN SCHEMA test_overrides GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 25 | 26 | /** 27 | * ### tests.create_supabase_user(identifier text, email text, phone text) 28 | * 29 | * Creates a new user in the `auth.users` table. 30 | * You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 31 | * 32 | * Parameters: 33 | * - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 34 | * - `email` - (Optional) The email address of the user 35 | * - `phone` - (Optional) The phone number of the user 36 | * - `metadata` - (Optional) Additional metadata to be added to the user 37 | * 38 | * Returns: 39 | * - `user_id` - The UUID of the user in the `auth.users` table 40 | * 41 | * Example: 42 | * ```sql 43 | * SELECT tests.create_supabase_user('test_owner'); 44 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 45 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 46 | * ``` 47 | */ 48 | CREATE OR REPLACE FUNCTION tests.create_supabase_user(identifier text, email text default null, phone text default null, metadata jsonb default null) 49 | RETURNS uuid 50 | SECURITY DEFINER 51 | SET search_path = auth, pg_temp 52 | AS $$ 53 | DECLARE 54 | user_id uuid; 55 | BEGIN 56 | 57 | -- create the user 58 | user_id := extensions.uuid_generate_v4(); 59 | INSERT INTO auth.users (id, email, phone, raw_user_meta_data, raw_app_meta_data, created_at, updated_at) 60 | VALUES (user_id, coalesce(email, concat(user_id, '@test.com')), phone, jsonb_build_object('test_identifier', identifier) || coalesce(metadata, '{}'::jsonb), '{}'::jsonb, now(), now()) 61 | RETURNING id INTO user_id; 62 | 63 | RETURN user_id; 64 | END; 65 | $$ LANGUAGE plpgsql; 66 | 67 | 68 | /** 69 | * ### tests.get_supabase_user(identifier text) 70 | * 71 | * Returns the user info for a user created with `tests.create_supabase_user`. 72 | * 73 | * Parameters: 74 | * - `identifier` - The unique identifier for the user 75 | * 76 | * Returns: 77 | * - `user_id` - The UUID of the user in the `auth.users` table 78 | * 79 | * Example: 80 | * ```sql 81 | * SELECT posts where posts.user_id = tests.get_supabase_user('test_owner') -> 'id'; 82 | * ``` 83 | */ 84 | CREATE OR REPLACE FUNCTION tests.get_supabase_user(identifier text) 85 | RETURNS json 86 | SECURITY DEFINER 87 | SET search_path = auth, pg_temp 88 | AS $$ 89 | DECLARE 90 | supabase_user json; 91 | BEGIN 92 | SELECT json_build_object( 93 | 'id', id, 94 | 'email', email, 95 | 'phone', phone, 96 | 'raw_user_meta_data', raw_user_meta_data, 97 | 'raw_app_meta_data', raw_app_meta_data 98 | ) into supabase_user 99 | FROM auth.users 100 | WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 101 | 102 | if supabase_user is null OR supabase_user -> 'id' IS NULL then 103 | RAISE EXCEPTION 'User with identifier % not found', identifier; 104 | end if; 105 | RETURN supabase_user; 106 | END; 107 | $$ LANGUAGE plpgsql; 108 | 109 | /** 110 | * ### tests.get_supabase_uid(identifier text) 111 | * 112 | * Returns the user UUID for a user created with `tests.create_supabase_user`. 113 | * 114 | * Parameters: 115 | * - `identifier` - The unique identifier for the user 116 | * 117 | * Returns: 118 | * - `user_id` - The UUID of the user in the `auth.users` table 119 | * 120 | * Example: 121 | * ```sql 122 | * SELECT posts where posts.user_id = tests.get_supabase_uid('test_owner') -> 'id'; 123 | * ``` 124 | */ 125 | CREATE OR REPLACE FUNCTION tests.get_supabase_uid(identifier text) 126 | RETURNS uuid 127 | SECURITY DEFINER 128 | SET search_path = auth, pg_temp 129 | AS $$ 130 | DECLARE 131 | supabase_user uuid; 132 | BEGIN 133 | SELECT id into supabase_user FROM auth.users WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 134 | if supabase_user is null then 135 | RAISE EXCEPTION 'User with identifier % not found', identifier; 136 | end if; 137 | RETURN supabase_user; 138 | END; 139 | $$ LANGUAGE plpgsql; 140 | 141 | /** 142 | * ### tests.authenticate_as(identifier text) 143 | * Authenticates as a user created with `tests.create_supabase_user`. 144 | * 145 | * Parameters: 146 | * - `identifier` - The unique identifier for the user 147 | * 148 | * Returns: 149 | * - `void` 150 | * 151 | * Example: 152 | * ```sql 153 | * SELECT tests.create_supabase_user('test_owner'); 154 | * SELECT tests.authenticate_as('test_owner'); 155 | * ``` 156 | */ 157 | CREATE OR REPLACE FUNCTION tests.authenticate_as (identifier text) 158 | RETURNS void 159 | AS $$ 160 | DECLARE 161 | user_data json; 162 | original_auth_data text; 163 | BEGIN 164 | -- store the request.jwt.claims in a variable in case we need it 165 | original_auth_data := current_setting('request.jwt.claims', true); 166 | user_data := tests.get_supabase_user(identifier); 167 | 168 | if user_data is null OR user_data ->> 'id' IS NULL then 169 | RAISE EXCEPTION 'User with identifier % not found', identifier; 170 | end if; 171 | 172 | 173 | perform set_config('role', 'authenticated', true); 174 | perform set_config('request.jwt.claims', json_build_object( 175 | 'sub', user_data ->> 'id', 176 | 'email', user_data ->> 'email', 177 | 'phone', user_data ->> 'phone', 178 | 'user_metadata', user_data -> 'raw_user_meta_data', 179 | 'app_metadata', user_data -> 'raw_app_meta_data' 180 | )::text, true); 181 | 182 | EXCEPTION 183 | -- revert back to original auth data 184 | WHEN OTHERS THEN 185 | set local role authenticated; 186 | set local "request.jwt.claims" to original_auth_data; 187 | RAISE; 188 | END 189 | $$ LANGUAGE plpgsql; 190 | 191 | /** 192 | * ### tests.authenticate_as_service_role() 193 | * Clears authentication object and sets role to service_role. 194 | * 195 | * Returns: 196 | * - `void` 197 | * 198 | * Example: 199 | * ```sql 200 | * SELECT tests.authenticate_as_service_role(); 201 | * ``` 202 | */ 203 | CREATE OR REPLACE FUNCTION tests.authenticate_as_service_role () 204 | RETURNS void 205 | AS $$ 206 | BEGIN 207 | perform set_config('role', 'service_role', true); 208 | perform set_config('request.jwt.claims', null, true); 209 | END 210 | $$ LANGUAGE plpgsql; 211 | 212 | 213 | /** 214 | * ### tests.clear_authentication() 215 | * Clears out the authentication and sets role to anon 216 | * 217 | * Returns: 218 | * - `void` 219 | * 220 | * Example: 221 | * ```sql 222 | * SELECT tests.create_supabase_user('test_owner'); 223 | * SELECT tests.authenticate_as('test_owner'); 224 | * SELECT tests.clear_authentication(); 225 | * ``` 226 | */ 227 | CREATE OR REPLACE FUNCTION tests.clear_authentication() 228 | RETURNS void AS $$ 229 | BEGIN 230 | perform set_config('role', 'anon', true); 231 | perform set_config('request.jwt.claims', null, true); 232 | END 233 | $$ LANGUAGE plpgsql; 234 | 235 | /** 236 | * ### tests.rls_enabled(testing_schema text) 237 | * pgTAP function to check if RLS is enabled on all tables in a provided schema 238 | * 239 | * Parameters: 240 | * - schema_name text - The name of the schema to check 241 | * 242 | * Example: 243 | * ```sql 244 | * BEGIN; 245 | * select plan(1); 246 | * select tests.rls_enabled('public'); 247 | * SELECT * FROM finish(); 248 | * ROLLBACK; 249 | * ``` 250 | */ 251 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text) 252 | RETURNS text AS $$ 253 | select is( 254 | (select 255 | count(pc.relname)::integer 256 | from pg_class pc 257 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema 258 | join pg_type pt on pt.oid = pc.reltype 259 | where relrowsecurity = FALSE) 260 | , 261 | 0, 262 | 'All tables in the' || testing_schema || ' schema should have row level security enabled'); 263 | $$ LANGUAGE sql; 264 | 265 | /** 266 | * ### tests.rls_enabled(testing_schema text, testing_table text) 267 | * pgTAP function to check if RLS is enabled on a specific table 268 | * 269 | * Parameters: 270 | * - schema_name text - The name of the schema to check 271 | * - testing_table text - The name of the table to check 272 | * 273 | * Example: 274 | * ```sql 275 | * BEGIN; 276 | * select plan(1); 277 | * select tests.rls_enabled('public', 'accounts'); 278 | * SELECT * FROM finish(); 279 | * ROLLBACK; 280 | * ``` 281 | */ 282 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text, testing_table text) 283 | RETURNS TEXT AS $$ 284 | select is( 285 | (select 286 | count(*)::integer 287 | from pg_class pc 288 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema and pc.relname = rls_enabled.testing_table 289 | join pg_type pt on pt.oid = pc.reltype 290 | where relrowsecurity = TRUE), 291 | 1, 292 | testing_table || 'table in the' || testing_schema || ' schema should have row level security enabled' 293 | ); 294 | $$ LANGUAGE sql; 295 | 296 | -- 297 | -- Generated now() function used to replace pg_catalog.now() for the purpose 298 | -- of freezing time in tests. This should not be used directly. 299 | -- 300 | CREATE OR REPLACE FUNCTION test_overrides.now() 301 | RETURNS timestamp with time zone 302 | AS $$ 303 | BEGIN 304 | 305 | 306 | -- check if a frozen time is set 307 | IF nullif(current_setting('tests.frozen_time'), '') IS NOT NULL THEN 308 | RETURN current_setting('tests.frozen_time')::timestamptz; 309 | END IF; 310 | 311 | RETURN pg_catalog.now(); 312 | END 313 | $$ LANGUAGE plpgsql; 314 | 315 | 316 | /** 317 | * ### tests.freeze_time(frozen_time timestamp with time zone) 318 | * 319 | * Overwrites the current time from now() to the provided time. 320 | * 321 | * Works out of the box for any normal usage of now(), if you have a function that sets its own search path, such as security definers, then you will need to alter the function to set the search path to include test_overrides BEFORE pg_catalog. 322 | * **ONLY do this inside of a pgtap test transaction.** 323 | * Example: 324 | * 325 | * ```sql 326 | * ALTER FUNCTION auth.your_function() SET search_path = test_overrides, public, pg_temp, pg_catalog; 327 | * ``` 328 | * View a test example in 05-frozen-time.sql: https://github.com/usebasejump/supabase-test-helpers/blob/main/supabase/tests/05-frozen-time.sql 329 | * 330 | * Parameters: 331 | * - `frozen_time` - The time to freeze to. Supports timestamp with time zone, without time zone, date or any other value that can be coerced into a timestamp with time zone. 332 | * 333 | * Returns: 334 | * - void 335 | * 336 | * Example: 337 | * ```sql 338 | * SELECT tests.freeze_time('2020-01-01 00:00:00'); 339 | * ``` 340 | */ 341 | 342 | CREATE OR REPLACE FUNCTION tests.freeze_time(frozen_time timestamp with time zone) 343 | RETURNS void 344 | AS $$ 345 | BEGIN 346 | 347 | -- Add test_overrides to search path if needed 348 | IF current_setting('search_path') NOT LIKE 'test_overrides,%' THEN 349 | -- store search path for later 350 | PERFORM set_config('tests.original_search_path', current_setting('search_path'), true); 351 | 352 | -- add tests schema to start of search path 353 | PERFORM set_config('search_path', 'test_overrides,' || current_setting('tests.original_search_path') || ',pg_catalog', true); 354 | END IF; 355 | 356 | -- create an overwriting now function 357 | PERFORM set_config('tests.frozen_time', frozen_time::text, true); 358 | 359 | END 360 | $$ LANGUAGE plpgsql; 361 | 362 | /** 363 | * ### tests.unfreeze_time() 364 | * 365 | * Unfreezes the time and restores the original now() function. 366 | * 367 | * Returns: 368 | * - void 369 | * 370 | * Example: 371 | * ```sql 372 | * SELECT tests.unfreeze_time(); 373 | * ``` 374 | */ 375 | 376 | CREATE OR REPLACE FUNCTION tests.unfreeze_time() 377 | RETURNS void 378 | AS $$ 379 | BEGIN 380 | -- restore the original now function 381 | PERFORM set_config('tests.frozen_time', null, true); 382 | -- restore the original search path 383 | PERFORM set_config('search_path', current_setting('tests.original_search_path'), true); 384 | END 385 | $$ LANGUAGE plpgsql; -------------------------------------------------------------------------------- /supabase_test_helpers--0.0.6.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION supabase_test_helpers" to load this file. \quit 3 | 4 | -- We want to store all of this in the tests schema to keep it 5 | -- separate from any application data 6 | CREATE SCHEMA IF NOT EXISTS tests; 7 | 8 | --- Create a specific schema for override functions so we don't have to worry about 9 | --- anything else be adding to the tests schema 10 | CREATE SCHEMA IF NOT EXISTS test_overrides; 11 | 12 | -- anon, authenticated, and service_role should have access to tests schema 13 | GRANT USAGE ON SCHEMA tests TO anon, authenticated, service_role; 14 | -- Don't allow public to execute any functions in the tests schema 15 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests REVOKE EXECUTE ON FUNCTIONS FROM public; 16 | -- Grant execute to anon, authenticated, and service_role for testing purposes 17 | ALTER DEFAULT PRIVILEGES IN SCHEMA tests GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 18 | 19 | -- anon, authenticated, and service_role should have access to test_overrides schema 20 | GRANT USAGE ON SCHEMA test_overrides TO anon, authenticated, service_role; 21 | -- Don't allow public to execute any functions in the test_overrides schema 22 | ALTER DEFAULT PRIVILEGES IN SCHEMA test_overrides REVOKE EXECUTE ON FUNCTIONS FROM public; 23 | -- Grant execute to anon, authenticated, and service_role for testing purposes 24 | ALTER DEFAULT PRIVILEGES IN SCHEMA test_overrides GRANT EXECUTE ON FUNCTIONS TO anon, authenticated, service_role; 25 | 26 | /** 27 | * ### tests.create_supabase_user(identifier text, email text, phone text) 28 | * 29 | * Creates a new user in the `auth.users` table. 30 | * You can recall a user's info by using `tests.get_supabase_user(identifier text)`. 31 | * 32 | * Parameters: 33 | * - `identifier` - A unique identifier for the user. We recommend you keep it memorable like "test_owner" or "test_member" 34 | * - `email` - (Optional) The email address of the user 35 | * - `phone` - (Optional) The phone number of the user 36 | * - `metadata` - (Optional) Additional metadata to be added to the user 37 | * 38 | * Returns: 39 | * - `user_id` - The UUID of the user in the `auth.users` table 40 | * 41 | * Example: 42 | * ```sql 43 | * SELECT tests.create_supabase_user('test_owner'); 44 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555'); 45 | * SELECT tests.create_supabase_user('test_member', 'member@test.com', '555-555-5555', '{"key": "value"}'::jsonb); 46 | * ``` 47 | */ 48 | CREATE OR REPLACE FUNCTION tests.create_supabase_user(identifier text, email text default null, phone text default null, metadata jsonb default null) 49 | RETURNS uuid 50 | SECURITY DEFINER 51 | SET search_path = auth, pg_temp 52 | AS $$ 53 | DECLARE 54 | user_id uuid; 55 | BEGIN 56 | 57 | -- create the user 58 | user_id := extensions.uuid_generate_v4(); 59 | INSERT INTO auth.users (id, email, phone, raw_user_meta_data, raw_app_meta_data, created_at, updated_at) 60 | VALUES (user_id, coalesce(email, concat(user_id, '@test.com')), phone, jsonb_build_object('test_identifier', identifier) || coalesce(metadata, '{}'::jsonb), '{}'::jsonb, now(), now()) 61 | RETURNING id INTO user_id; 62 | 63 | RETURN user_id; 64 | END; 65 | $$ LANGUAGE plpgsql; 66 | 67 | 68 | /** 69 | * ### tests.get_supabase_user(identifier text) 70 | * 71 | * Returns the user info for a user created with `tests.create_supabase_user`. 72 | * 73 | * Parameters: 74 | * - `identifier` - The unique identifier for the user 75 | * 76 | * Returns: 77 | * - `user_id` - The UUID of the user in the `auth.users` table 78 | * 79 | * Example: 80 | * ```sql 81 | * SELECT posts where posts.user_id = tests.get_supabase_user('test_owner') -> 'id'; 82 | * ``` 83 | */ 84 | CREATE OR REPLACE FUNCTION tests.get_supabase_user(identifier text) 85 | RETURNS json 86 | SECURITY DEFINER 87 | SET search_path = auth, pg_temp 88 | AS $$ 89 | DECLARE 90 | supabase_user json; 91 | BEGIN 92 | SELECT json_build_object( 93 | 'id', id, 94 | 'email', email, 95 | 'phone', phone, 96 | 'raw_user_meta_data', raw_user_meta_data, 97 | 'raw_app_meta_data', raw_app_meta_data 98 | ) into supabase_user 99 | FROM auth.users 100 | WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 101 | 102 | if supabase_user is null OR supabase_user -> 'id' IS NULL then 103 | RAISE EXCEPTION 'User with identifier % not found', identifier; 104 | end if; 105 | RETURN supabase_user; 106 | END; 107 | $$ LANGUAGE plpgsql; 108 | 109 | /** 110 | * ### tests.get_supabase_uid(identifier text) 111 | * 112 | * Returns the user UUID for a user created with `tests.create_supabase_user`. 113 | * 114 | * Parameters: 115 | * - `identifier` - The unique identifier for the user 116 | * 117 | * Returns: 118 | * - `user_id` - The UUID of the user in the `auth.users` table 119 | * 120 | * Example: 121 | * ```sql 122 | * SELECT posts where posts.user_id = tests.get_supabase_uid('test_owner') -> 'id'; 123 | * ``` 124 | */ 125 | CREATE OR REPLACE FUNCTION tests.get_supabase_uid(identifier text) 126 | RETURNS uuid 127 | SECURITY DEFINER 128 | SET search_path = auth, pg_temp 129 | AS $$ 130 | DECLARE 131 | supabase_user uuid; 132 | BEGIN 133 | SELECT id into supabase_user FROM auth.users WHERE raw_user_meta_data ->> 'test_identifier' = identifier limit 1; 134 | if supabase_user is null then 135 | RAISE EXCEPTION 'User with identifier % not found', identifier; 136 | end if; 137 | RETURN supabase_user; 138 | END; 139 | $$ LANGUAGE plpgsql; 140 | 141 | /** 142 | * ### tests.authenticate_as(identifier text) 143 | * Authenticates as a user created with `tests.create_supabase_user`. 144 | * 145 | * Parameters: 146 | * - `identifier` - The unique identifier for the user 147 | * 148 | * Returns: 149 | * - `void` 150 | * 151 | * Example: 152 | * ```sql 153 | * SELECT tests.create_supabase_user('test_owner'); 154 | * SELECT tests.authenticate_as('test_owner'); 155 | * ``` 156 | */ 157 | CREATE OR REPLACE FUNCTION tests.authenticate_as (identifier text) 158 | RETURNS void 159 | AS $$ 160 | DECLARE 161 | user_data json; 162 | original_auth_data text; 163 | BEGIN 164 | -- store the request.jwt.claims in a variable in case we need it 165 | original_auth_data := current_setting('request.jwt.claims', true); 166 | user_data := tests.get_supabase_user(identifier); 167 | 168 | if user_data is null OR user_data ->> 'id' IS NULL then 169 | RAISE EXCEPTION 'User with identifier % not found', identifier; 170 | end if; 171 | 172 | 173 | perform set_config('role', 'authenticated', true); 174 | perform set_config('request.jwt.claims', json_build_object( 175 | 'sub', user_data ->> 'id', 176 | 'email', user_data ->> 'email', 177 | 'phone', user_data ->> 'phone', 178 | 'user_metadata', user_data -> 'raw_user_meta_data', 179 | 'app_metadata', user_data -> 'raw_app_meta_data' 180 | )::text, true); 181 | 182 | EXCEPTION 183 | -- revert back to original auth data 184 | WHEN OTHERS THEN 185 | set local role authenticated; 186 | set local "request.jwt.claims" to original_auth_data; 187 | RAISE; 188 | END 189 | $$ LANGUAGE plpgsql; 190 | 191 | /** 192 | * ### tests.authenticate_as_service_role() 193 | * Clears authentication object and sets role to service_role. 194 | * 195 | * Returns: 196 | * - `void` 197 | * 198 | * Example: 199 | * ```sql 200 | * SELECT tests.authenticate_as_service_role(); 201 | * ``` 202 | */ 203 | CREATE OR REPLACE FUNCTION tests.authenticate_as_service_role () 204 | RETURNS void 205 | AS $$ 206 | BEGIN 207 | perform set_config('role', 'service_role', true); 208 | perform set_config('request.jwt.claims', null, true); 209 | END 210 | $$ LANGUAGE plpgsql; 211 | 212 | 213 | /** 214 | * ### tests.clear_authentication() 215 | * Clears out the authentication and sets role to anon 216 | * 217 | * Returns: 218 | * - `void` 219 | * 220 | * Example: 221 | * ```sql 222 | * SELECT tests.create_supabase_user('test_owner'); 223 | * SELECT tests.authenticate_as('test_owner'); 224 | * SELECT tests.clear_authentication(); 225 | * ``` 226 | */ 227 | CREATE OR REPLACE FUNCTION tests.clear_authentication() 228 | RETURNS void AS $$ 229 | BEGIN 230 | perform set_config('role', 'anon', true); 231 | perform set_config('request.jwt.claims', null, true); 232 | END 233 | $$ LANGUAGE plpgsql; 234 | 235 | /** 236 | * ### tests.rls_enabled(testing_schema text) 237 | * pgTAP function to check if RLS is enabled on all tables in a provided schema 238 | * 239 | * Parameters: 240 | * - schema_name text - The name of the schema to check 241 | * 242 | * Example: 243 | * ```sql 244 | * BEGIN; 245 | * select plan(1); 246 | * select tests.rls_enabled('public'); 247 | * SELECT * FROM finish(); 248 | * ROLLBACK; 249 | * ``` 250 | */ 251 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text) 252 | RETURNS text AS $$ 253 | select is( 254 | (select 255 | count(pc.relname)::integer 256 | from pg_class pc 257 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema 258 | join pg_type pt on pt.oid = pc.reltype 259 | where relrowsecurity = FALSE) 260 | , 261 | 0, 262 | 'All tables in the' || testing_schema || ' schema should have row level security enabled'); 263 | $$ LANGUAGE sql; 264 | 265 | /** 266 | * ### tests.rls_enabled(testing_schema text, testing_table text) 267 | * pgTAP function to check if RLS is enabled on a specific table 268 | * 269 | * Parameters: 270 | * - schema_name text - The name of the schema to check 271 | * - testing_table text - The name of the table to check 272 | * 273 | * Example: 274 | * ```sql 275 | * BEGIN; 276 | * select plan(1); 277 | * select tests.rls_enabled('public', 'accounts'); 278 | * SELECT * FROM finish(); 279 | * ROLLBACK; 280 | * ``` 281 | */ 282 | CREATE OR REPLACE FUNCTION tests.rls_enabled (testing_schema text, testing_table text) 283 | RETURNS TEXT AS $$ 284 | select is( 285 | (select 286 | count(*)::integer 287 | from pg_class pc 288 | join pg_namespace pn on pn.oid = pc.relnamespace and pn.nspname = rls_enabled.testing_schema and pc.relname = rls_enabled.testing_table 289 | join pg_type pt on pt.oid = pc.reltype 290 | where relrowsecurity = TRUE), 291 | 1, 292 | testing_table || 'table in the' || testing_schema || ' schema should have row level security enabled' 293 | ); 294 | $$ LANGUAGE sql; 295 | 296 | -- 297 | -- Generated now() function used to replace pg_catalog.now() for the purpose 298 | -- of freezing time in tests. This should not be used directly. 299 | -- 300 | CREATE OR REPLACE FUNCTION test_overrides.now() 301 | RETURNS timestamp with time zone 302 | AS $$ 303 | BEGIN 304 | 305 | 306 | -- check if a frozen time is set 307 | IF nullif(current_setting('tests.frozen_time'), '') IS NOT NULL THEN 308 | RETURN current_setting('tests.frozen_time')::timestamptz; 309 | END IF; 310 | 311 | RETURN pg_catalog.now(); 312 | END 313 | $$ LANGUAGE plpgsql; 314 | 315 | 316 | /** 317 | * ### tests.freeze_time(frozen_time timestamp with time zone) 318 | * 319 | * Overwrites the current time from now() to the provided time. 320 | * 321 | * Works out of the box for any normal usage of now(), if you have a function that sets its own search path, such as security definers, then you will need to alter the function to set the search path to include test_overrides BEFORE pg_catalog. 322 | * **ONLY do this inside of a pgtap test transaction.** 323 | * Example: 324 | * 325 | * ```sql 326 | * ALTER FUNCTION auth.your_function() SET search_path = test_overrides, public, pg_temp, pg_catalog; 327 | * ``` 328 | * View a test example in 05-frozen-time.sql: https://github.com/usebasejump/supabase-test-helpers/blob/main/supabase/tests/05-frozen-time.sql 329 | * 330 | * Parameters: 331 | * - `frozen_time` - The time to freeze to. Supports timestamp with time zone, without time zone, date or any other value that can be coerced into a timestamp with time zone. 332 | * 333 | * Returns: 334 | * - void 335 | * 336 | * Example: 337 | * ```sql 338 | * SELECT tests.freeze_time('2020-01-01 00:00:00'); 339 | * ``` 340 | */ 341 | 342 | CREATE OR REPLACE FUNCTION tests.freeze_time(frozen_time timestamp with time zone) 343 | RETURNS void 344 | AS $$ 345 | BEGIN 346 | 347 | -- Add test_overrides to search path if needed 348 | IF current_setting('search_path') NOT LIKE 'test_overrides,%' THEN 349 | -- store search path for later 350 | PERFORM set_config('tests.original_search_path', current_setting('search_path'), true); 351 | 352 | -- add tests schema to start of search path 353 | PERFORM set_config('search_path', 'test_overrides,' || current_setting('tests.original_search_path') || ',pg_catalog', true); 354 | END IF; 355 | 356 | -- create an overwriting now function 357 | PERFORM set_config('tests.frozen_time', frozen_time::text, true); 358 | 359 | END 360 | $$ LANGUAGE plpgsql; 361 | 362 | /** 363 | * ### tests.unfreeze_time() 364 | * 365 | * Unfreezes the time and restores the original now() function. 366 | * 367 | * Returns: 368 | * - void 369 | * 370 | * Example: 371 | * ```sql 372 | * SELECT tests.unfreeze_time(); 373 | * ``` 374 | */ 375 | 376 | CREATE OR REPLACE FUNCTION tests.unfreeze_time() 377 | RETURNS void 378 | AS $$ 379 | BEGIN 380 | -- restore the original now function 381 | PERFORM set_config('tests.frozen_time', null, true); 382 | -- restore the original search path 383 | PERFORM set_config('search_path', current_setting('tests.original_search_path'), true); 384 | END 385 | $$ LANGUAGE plpgsql; -------------------------------------------------------------------------------- /supabase_test_helpers.control: -------------------------------------------------------------------------------- 1 | default_version = 0.0.5 2 | comment = 'A collection of functions designed to make testing Supabase projects easier' 3 | relocatable = false 4 | requires = pgtap 5 | superuser = false --------------------------------------------------------------------------------