numerus/test/ensure_role_exists.sql

55 lines
1.9 KiB
MySQL
Raw Normal View History

Setup authentication schema and user relation User authentication is based on PostgREST’s[0]: There is a noninherit role, authenticator, whose function is only to switch to a different role according to the application’s session. Accordingly, this role has no permission for anything. The roles that this authentication can switch to are guest, invoicer, or admin. Guest is for anonymous users, when they need to login or register; invoicers are regular users; and admin are application’s administrators, that can change other user’s status, when they have to be removed or have they password changed, for example. The user relation is actually inaccessible to all roles and can only be used through a security definer function, login, so that passwords are not accessible from the application. I hesitated on what to use as the user’s primary key. The email seemed a good candiate, because it will be used for login. But something rubs me the wrong way. It is not that they can change because, despite what people on the Internet keeps parroting, they do not need to be “immutable”, PostgreSQL can cascade updates to foreign keys, and people do **not** change email addresses that ofter. What i **do** know is that email addresses should be unique in order to be used for login and password, hovewer i had to decide what “unique” means here, because the domain part is case insensitive, but the local part who knows? I made the arbitrary decision of assuming that the whole address is case sensitive. I have the feeling that this will bite me harder in the ass than using it as the primary key. [0]: https://postgrest.org/en/stable/auth.html
2023-01-13 00:43:20 +00:00
-- Test ensure_role_exists
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(14);
set search_path to auth, public;
select has_function('auth', 'ensure_role_exists', array []::name[]);
select function_lang_is('auth', 'ensure_role_exists', array []::name[], 'plpgsql');
select function_returns('auth', 'ensure_role_exists', array []::name[], 'trigger');
select isnt_definer('auth', 'ensure_role_exists', array []::name[]);
select volatility_is('auth', 'ensure_role_exists', array []::name[], 'volatile');
select function_privs_are('auth', 'ensure_role_exists', array []::name[], 'guest', array []::text[]);
select function_privs_are('auth', 'ensure_role_exists', array []::name[], 'invoicer', array []::text[]);
select function_privs_are('auth', 'ensure_role_exists', array []::name[], 'admin', array []::text[]);
select function_privs_are('auth', 'ensure_role_exists', array []::name[], 'authenticator', array []::text[]);
Setup authentication schema and user relation User authentication is based on PostgREST’s[0]: There is a noninherit role, authenticator, whose function is only to switch to a different role according to the application’s session. Accordingly, this role has no permission for anything. The roles that this authentication can switch to are guest, invoicer, or admin. Guest is for anonymous users, when they need to login or register; invoicers are regular users; and admin are application’s administrators, that can change other user’s status, when they have to be removed or have they password changed, for example. The user relation is actually inaccessible to all roles and can only be used through a security definer function, login, so that passwords are not accessible from the application. I hesitated on what to use as the user’s primary key. The email seemed a good candiate, because it will be used for login. But something rubs me the wrong way. It is not that they can change because, despite what people on the Internet keeps parroting, they do not need to be “immutable”, PostgreSQL can cascade updates to foreign keys, and people do **not** change email addresses that ofter. What i **do** know is that email addresses should be unique in order to be used for login and password, hovewer i had to decide what “unique” means here, because the domain part is case insensitive, but the local part who knows? I made the arbitrary decision of assuming that the whole address is case sensitive. I have the feeling that this will bite me harder in the ass than using it as the primary key. [0]: https://postgrest.org/en/stable/auth.html
2023-01-13 00:43:20 +00:00
select trigger_is('user', 'ensure_role_exists', 'ensure_role_exists');
set client_min_messages to warning;
truncate "user" cascade;
reset client_min_messages;
select lives_ok(
$$ insert into "user" (email, name, password, role) values ('info@tandem.blog', 'Factura', 'test', 'guest') $$,
'Should be able to insert a user with a valid role'
);
select throws_ok(
$$ insert into "user" (email, name, password, role) values ('nope@tandem.blog', 'Factura', 'test', 'non-existing-role') $$,
'23503',
'role not found: non-existing-role',
'Should not allow insert users with invalid roles'
);
select lives_ok($$ update "user" set role = 'invoicer' where email = 'info@tandem.blog' $$,
'Should be able to change the role of a user to another valid role'
);
select throws_ok($$ update "user" set role = 'usurer' where email = 'info@tandem.blog' $$,
'23503',
'role not found: usurer',
'Should not allow update users to invalid roles'
);
select *
from finish();
rollback;