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
This commit is contained in:
parent
51ad6f8102
commit
c17662ec6b
|
@ -0,0 +1,15 @@
|
|||
-- Deploy numerus:email to pg
|
||||
-- requires: schema_numerus
|
||||
-- requires: extension_citext
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
-- regular expression from https://html.spec.whatwg.org/multipage/input.html#valid-e-mail-address
|
||||
create domain email as citext
|
||||
check ( value ~ '^[a-zA-Z0-9.!#$%&''*+/=?^_`{|}~-]+@[a-zA-Z0-9](?:[a-zA-Z0-9-]{0,61}[a-zA-Z0-9])?(?:\.[a-zA-Z0-9](?:[a-zA-Z0-9-]{0,61}[a-zA-Z0-9])?)*$' );
|
||||
|
||||
comment on domain email is 'A valid email address according to HTML5 spec.';
|
||||
|
||||
commit;
|
|
@ -0,0 +1,29 @@
|
|||
-- Deploy numerus:encrypt_password to pg
|
||||
-- requires: schema_auth
|
||||
-- requires: user
|
||||
-- requires: extension_pgcrypto
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to auth, numerus, public;
|
||||
|
||||
create or replace function encrypt_password() returns trigger as
|
||||
$$
|
||||
begin
|
||||
if tg_op = 'INSERT' or new.password <> old.password then
|
||||
new.password = crypt(new.password, gen_salt('bf'));
|
||||
end if;
|
||||
return new;
|
||||
end;
|
||||
$$
|
||||
language plpgsql;
|
||||
|
||||
comment on function encrypt_password() is
|
||||
'Encrypts and salts the input password with the blowfish encryption algorithm';
|
||||
|
||||
create trigger encrypt_password
|
||||
before insert or update
|
||||
on "user"
|
||||
for each row execute procedure encrypt_password();
|
||||
|
||||
commit;
|
|
@ -0,0 +1,28 @@
|
|||
-- Deploy numerus:ensure_role_exists to pg
|
||||
-- requires: schema_auth
|
||||
-- requires: user
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to auth, public;
|
||||
|
||||
create or replace function ensure_role_exists() returns trigger as
|
||||
$$
|
||||
begin
|
||||
if not exists (select 1 from pg_roles where rolname = new.role) then
|
||||
raise foreign_key_violation using message = 'role not found: ' || new.role;
|
||||
end if;
|
||||
return new;
|
||||
end;
|
||||
$$
|
||||
language plpgsql;
|
||||
|
||||
comment on function ensure_role_exists() is
|
||||
'Makes sure that a role given to a user is a valid, existing role in the cluster.';
|
||||
|
||||
create trigger ensure_role_exists
|
||||
after insert or update
|
||||
on "user"
|
||||
for each row execute procedure ensure_role_exists();
|
||||
|
||||
commit;
|
|
@ -0,0 +1,8 @@
|
|||
-- Deploy numerus:extension_citext to pg
|
||||
-- requires: schema_public
|
||||
|
||||
begin;
|
||||
|
||||
create extension if not exists citext;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,8 @@
|
|||
-- Deploy numerus:extension_pgcrypto to pg
|
||||
-- requires: schema_public
|
||||
|
||||
begin;
|
||||
|
||||
create extension if not exists pgcrypto;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,30 @@
|
|||
-- Deploy numerus:find_user_role to pg
|
||||
-- requires: schema_auth
|
||||
-- requires: user
|
||||
-- requires: email
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to auth, numerus, public;
|
||||
|
||||
create or replace function find_user_role(email email, password text) returns name
|
||||
as
|
||||
$$
|
||||
declare
|
||||
found_role name;
|
||||
begin
|
||||
select role
|
||||
into found_role
|
||||
from auth."user"
|
||||
where "user".email = find_user_role.email
|
||||
and "user".password = crypt(find_user_role.password, "user".password);
|
||||
|
||||
return found_role;
|
||||
end;
|
||||
$$
|
||||
language plpgsql;
|
||||
|
||||
comment on function find_user_role(email, text) is
|
||||
'Return the database role assigned to the user with the given email and password';
|
||||
|
||||
commit;
|
|
@ -0,0 +1,32 @@
|
|||
-- Deploy numerus:login to pg
|
||||
-- requires: roles
|
||||
-- requires: schema_numerus
|
||||
-- requires: email
|
||||
-- requires: user
|
||||
-- requires: find_user_role
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to numerus, auth;
|
||||
|
||||
create or replace function login(email email, password text) returns name as
|
||||
$$
|
||||
declare
|
||||
role name;
|
||||
begin
|
||||
select auth.find_user_role(email, password) into role;
|
||||
if role is null then
|
||||
raise invalid_password using message = 'invalid user or password';
|
||||
end if;
|
||||
return role;
|
||||
end;
|
||||
$$
|
||||
language plpgsql
|
||||
security definer;
|
||||
|
||||
comment on function login(email, text) is
|
||||
'Checks that the email and password pair is valid and returns the user’s databasse role.';
|
||||
|
||||
grant execute on function login(email, text) to guest;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,27 @@
|
|||
-- Deploy numerus:roles to pg
|
||||
|
||||
begin;
|
||||
|
||||
do
|
||||
$$
|
||||
declare
|
||||
role name;
|
||||
roles name[] := array['guest', 'invoicer', 'admin', 'authenticator'];
|
||||
begin
|
||||
foreach role in array roles
|
||||
loop
|
||||
begin
|
||||
execute 'create role ' || role || ' noinherit nologin';
|
||||
exception
|
||||
when duplicate_object then
|
||||
raise notice '%, skipping', sqlerrm using errcode = sqlstate;
|
||||
end;
|
||||
end loop;
|
||||
end
|
||||
$$;
|
||||
|
||||
grant guest to authenticator;
|
||||
grant invoicer to authenticator;
|
||||
grant admin to authenticator;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,10 @@
|
|||
-- Deploy numerus:schema_auth to pg
|
||||
-- requires: roles
|
||||
|
||||
begin;
|
||||
|
||||
create schema auth;
|
||||
|
||||
comment on schema auth is 'To keep user’s passwords safe.';
|
||||
|
||||
commit;
|
|
@ -0,0 +1,14 @@
|
|||
-- Deploy numerus:schema_numerus to pg
|
||||
-- requires: roles
|
||||
|
||||
begin;
|
||||
|
||||
create schema numerus;
|
||||
|
||||
comment on schema numerus is 'The main application schema';
|
||||
|
||||
grant usage on schema numerus to guest;
|
||||
grant usage on schema numerus to invoicer;
|
||||
grant usage on schema numerus to admin;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,15 @@
|
|||
-- Deploy numerus:schema_public to pg
|
||||
-- requires: roles
|
||||
|
||||
begin;
|
||||
|
||||
revoke create on schema public from public;
|
||||
revoke usage on schema public from public;
|
||||
|
||||
alter default privileges revoke execute on functions from public;
|
||||
|
||||
grant usage on schema public to guest;
|
||||
grant usage on schema public to invoicer;
|
||||
grant usage on schema public to admin;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,19 @@
|
|||
-- Deploy numerus:user to pg
|
||||
-- requires: roles
|
||||
-- requires: schema_auth
|
||||
-- requires: email
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to auth, numerus;
|
||||
|
||||
create table "user" (
|
||||
user_id serial primary key,
|
||||
email email not null unique,
|
||||
name text not null,
|
||||
password text not null check (length(password) < 512),
|
||||
role name not null check (length(role) < 512),
|
||||
created_at timestamptz not null default current_timestamp
|
||||
);
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:email from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop domain if exists numerus.email;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,8 @@
|
|||
-- Revert numerus:encrypt_password from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop trigger if exists encrypt_password on auth."user";
|
||||
drop function if exists auth.encrypt_password();
|
||||
|
||||
commit;
|
|
@ -0,0 +1,8 @@
|
|||
-- Revert numerus:ensure_role_exists from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop trigger if exists ensure_role_exists on auth."user";
|
||||
drop function if exists auth.ensure_role_exists();
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:extension_citext from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop extension if exists citext;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:extension_pgcrypto from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop extension if exists pgcrypto;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:find_user_role from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop function if exists auth.find_user_role(numerus.email, text);
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:login from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop function if exists numerus.login(numerus.email, text);
|
||||
|
||||
commit;
|
|
@ -0,0 +1,10 @@
|
|||
-- Revert numerus:roles from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop role authenticator;
|
||||
drop role admin;
|
||||
drop role invoicer;
|
||||
drop role guest;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:schema_auth from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop schema if exists auth;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:schema_numerus from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop schema if exists numerus;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,12 @@
|
|||
-- Revert numerus:schema_public from pg
|
||||
|
||||
begin;
|
||||
|
||||
alter default privileges grant execute on functions to public;
|
||||
|
||||
revoke usage on schema public from authenticator;
|
||||
revoke usage on schema public from admin;
|
||||
revoke usage on schema public from invoicer;
|
||||
revoke usage on schema public from guest;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:user from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop table if exists auth."user";
|
||||
|
||||
commit;
|
|
@ -1,7 +1,7 @@
|
|||
[core]
|
||||
engine = pg
|
||||
[engine "pg"]
|
||||
target = db:pg:factura
|
||||
target = db:pg:numerus
|
||||
[deploy]
|
||||
verify = true
|
||||
[rebase]
|
||||
|
|
16
sqitch.plan
16
sqitch.plan
|
@ -1,4 +1,16 @@
|
|||
%syntax-version=1.0.0
|
||||
%project=factura
|
||||
%uri=https://factura.tandem.blog/
|
||||
%project=numerus
|
||||
%uri=https://numerus.tandem.blog/
|
||||
|
||||
roles 2023-01-12T18:42:16Z jordi fita i mas <jfita@infoblitz.com> # Add database roles
|
||||
schema_auth [roles] 2023-01-12T19:15:55Z jordi fita i mas <jfita@infoblitz.com> # Add authentication schema
|
||||
schema_public [roles] 2023-01-12T19:24:29Z jordi fita i mas <jfita@infoblitz.com> # Set privileges to public schema
|
||||
schema_numerus [roles] 2023-01-12T22:57:22Z jordi fita i mas <jfita@infoblitz.com> # Add application schema
|
||||
extension_citext [schema_public] 2023-01-12T23:03:33Z jordi fita i mas <jfita@infoblitz.com> # Add citext extension
|
||||
email [schema_numerus extension_citext] 2023-01-12T23:09:59Z jordi fita i mas <jfita@infoblitz.com> # Add email domain
|
||||
user [roles schema_auth email] 2023-01-12T23:44:03Z jordi fita i mas <jfita@infoblitz.com> # Create user table
|
||||
ensure_role_exists [schema_auth user] 2023-01-12T23:57:59Z jordi fita i mas <jfita@infoblitz.com> # Add trigger to ensure the user’s role exists
|
||||
extension_pgcrypto [schema_public] 2023-01-13T00:11:50Z jordi fita i mas <jfita@infoblitz.com> # Add pgcrypto extension
|
||||
encrypt_password [schema_auth user extension_pgcrypto] 2023-01-13T00:14:30Z jordi fita i mas <jfita@infoblitz.com> # Add trigger to encrypt user’s password
|
||||
find_user_role [schema_auth user email] 2023-01-13T00:22:34Z jordi fita i mas <jfita@infoblitz.com> # Add function to find a user’s role given its email and password
|
||||
login [roles schema_numerus email user find_user_role] 2023-01-13T00:32:32Z jordi fita i mas <jfita@infoblitz.com> # Add function to login
|
||||
|
|
|
@ -0,0 +1,33 @@
|
|||
-- Test email
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(5);
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
select has_domain('email');
|
||||
select domain_type_is('email', 'citext');
|
||||
|
||||
select lives_ok($$ SELECT 'test@tandem.com'::email $$, 'Should be able to cast strings to email');
|
||||
|
||||
select throws_ok(
|
||||
$$ SELECT 'test@tandem,,co.uk'::email $$,
|
||||
23514, null,
|
||||
'Should reject email addresses with wrong domain'
|
||||
);
|
||||
|
||||
select throws_ok(
|
||||
$$ SELECT 'test@a@tandem.com'::email $$,
|
||||
23514, null,
|
||||
'Should reject email address with two @ signs'
|
||||
);
|
||||
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,40 @@
|
|||
-- Test encrypt_password
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(11);
|
||||
|
||||
set search_path to auth, numerus, public;
|
||||
|
||||
select has_function('encrypt_password');
|
||||
select function_lang_is('encrypt_password', array []::name[], 'plpgsql');
|
||||
select function_returns('encrypt_password', array []::name[], 'trigger');
|
||||
select isnt_definer('encrypt_password', array []::name[]);
|
||||
select volatility_is('encrypt_password', array []::name[], 'volatile');
|
||||
select function_privs_are('encrypt_password', array []::name[], 'guest', array []::text[]);
|
||||
select function_privs_are('encrypt_password', array []::name[], 'invoicer', array []::text[]);
|
||||
select function_privs_are('encrypt_password', array []::name[], 'admin', array []::text[]);
|
||||
select function_privs_are('encrypt_password', array []::name[], 'authenticator', array []::text[]);
|
||||
|
||||
select trigger_is('user', 'encrypt_password', 'encrypt_password');
|
||||
|
||||
set client_min_messages to warning;
|
||||
truncate "user" cascade;
|
||||
reset client_min_messages;
|
||||
|
||||
insert into "user" (email, name, password, role)
|
||||
values ('info@tandem.blog', 'Perita', 'test', 'guest');
|
||||
|
||||
select row_eq(
|
||||
$$ select email from "user" where password = crypt('test', password) $$,
|
||||
row ('info@tandem.blog'::email),
|
||||
'Should find the new user using its encrypted password'
|
||||
);
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,54 @@
|
|||
-- 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('ensure_role_exists');
|
||||
select function_lang_is('ensure_role_exists', array []::name[], 'plpgsql');
|
||||
select function_returns('ensure_role_exists', array []::name[], 'trigger');
|
||||
select isnt_definer('ensure_role_exists', array []::name[]);
|
||||
select volatility_is('ensure_role_exists', array []::name[], 'volatile');
|
||||
select function_privs_are('ensure_role_exists', array []::name[], 'guest', array []::text[]);
|
||||
select function_privs_are('ensure_role_exists', array []::name[], 'invoicer', array []::text[]);
|
||||
select function_privs_are('ensure_role_exists', array []::name[], 'admin', array []::text[]);
|
||||
select function_privs_are('ensure_role_exists', array []::name[], 'authenticator', array []::text[]);
|
||||
|
||||
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;
|
|
@ -0,0 +1,20 @@
|
|||
-- Test extension_citext
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(1);
|
||||
|
||||
select extensions_are(array[
|
||||
'citext'
|
||||
, 'pgtap'
|
||||
, 'pgcrypto'
|
||||
, 'plpgsql'
|
||||
]);
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,51 @@
|
|||
-- Test find_user_role
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(12);
|
||||
|
||||
set search_path to auth, numerus, public;
|
||||
|
||||
select has_function('find_user_role');
|
||||
select function_lang_is('find_user_role', array ['email', 'text'], 'plpgsql');
|
||||
select function_returns('find_user_role', array ['email', 'text'], 'name');
|
||||
select isnt_definer('find_user_role', array ['email', 'text']);
|
||||
select volatility_is('find_user_role', array ['email', 'text'], 'volatile');
|
||||
select function_privs_are('find_user_role', array ['email', 'text'], 'guest', array []::text[]);
|
||||
select function_privs_are('find_user_role', array ['email', 'text'], 'invoicer', array []::text[]);
|
||||
select function_privs_are('find_user_role', array ['email', 'text'], 'admin', array []::text[]);
|
||||
select function_privs_are('find_user_role', array ['email', 'text'], 'authenticator', array []::text[]);
|
||||
|
||||
set client_min_messages to warning;
|
||||
truncate "user" cascade;
|
||||
reset client_min_messages;
|
||||
|
||||
insert into "user" (email, name, password, role)
|
||||
values ('info@tandem.blog', 'Perita', 'test', 'guest');
|
||||
|
||||
select is(
|
||||
find_user_role('info@tandem.blog', 'test'),
|
||||
'guest'::name,
|
||||
'Should find the role with the correct email and password'
|
||||
);
|
||||
|
||||
select is(
|
||||
find_user_role('info@tandem.blog', 'mah password'),
|
||||
NULL::name,
|
||||
'Should not find any role with an invalid password'
|
||||
);
|
||||
|
||||
select is(
|
||||
find_user_role('nope@tandem.blog', 'test'),
|
||||
NULL::name,
|
||||
'Should not find any role with an invalid email'
|
||||
);
|
||||
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,53 @@
|
|||
-- Test login
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(12);
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
select has_function('login');
|
||||
select function_lang_is('login', array ['email', 'text'], 'plpgsql');
|
||||
select function_returns('login', array ['email', 'text'], 'name');
|
||||
select is_definer('login', array ['email', 'text']);
|
||||
select volatility_is('login', array ['email', 'text'], 'volatile');
|
||||
select function_privs_are('login', array ['email', 'text'], 'guest', array ['EXECUTE']);
|
||||
select function_privs_are('login', array ['email', 'text'], 'invoicer', array []::text[]);
|
||||
select function_privs_are('login', array ['email', 'text'], 'admin', array []::text[]);
|
||||
select function_privs_are('login', array ['email', 'text'], 'authenticator', array []::text[]);
|
||||
|
||||
set client_min_messages to warning;
|
||||
truncate auth."user" cascade;
|
||||
reset client_min_messages;
|
||||
|
||||
insert into auth."user" (email, name, password, role)
|
||||
values ('info@tandem.blog', 'Perita', 'test', 'guest');
|
||||
|
||||
select is(
|
||||
login('info@tandem.blog'::email, 'test'),
|
||||
'guest'::name,
|
||||
'Should find the role with the correct email and password'
|
||||
);
|
||||
|
||||
select throws_ok(
|
||||
$$ select login('info@tandem.blog'::email, 'mah password') $$,
|
||||
'28P01',
|
||||
'invalid user or password',
|
||||
'Should not find any role with an invalid password'
|
||||
);
|
||||
|
||||
select throws_ok(
|
||||
$$ select login('nope@tandem.blog'::email, 'test') $$,
|
||||
'28P01',
|
||||
'invalid user or password',
|
||||
'Should not find any role with an invalid email'
|
||||
);
|
||||
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,22 @@
|
|||
-- Test roles
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(7);
|
||||
|
||||
select has_role('guest');
|
||||
select has_role('invoicer');
|
||||
select has_role('admin');
|
||||
select has_role('authenticator');
|
||||
|
||||
select is_member_of('guest', 'authenticator');
|
||||
select is_member_of('invoicer', 'authenticator');
|
||||
select is_member_of('admin', 'authenticator');
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,40 @@
|
|||
-- Test schemas
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(17);
|
||||
|
||||
select schemas_are(array[
|
||||
'auth',
|
||||
'numerus',
|
||||
'public',
|
||||
'sqitch'
|
||||
]);
|
||||
|
||||
select schema_privs_are('auth', 'guest', array[]::text[]);
|
||||
select schema_privs_are('auth', 'invoicer', array[]::text[]);
|
||||
select schema_privs_are('auth', 'admin', array[]::text[]);
|
||||
select schema_privs_are('auth', 'authenticator', array[]::text[]);
|
||||
|
||||
select schema_privs_are('numerus', 'guest', array['USAGE']);
|
||||
select schema_privs_are('numerus', 'invoicer', array['USAGE']);
|
||||
select schema_privs_are('numerus', 'admin', array['USAGE']);
|
||||
select schema_privs_are('numerus', 'authenticator', array[]::text[]);
|
||||
|
||||
select schema_privs_are('public', 'guest', array['USAGE']);
|
||||
select schema_privs_are('public', 'invoicer', array['USAGE']);
|
||||
select schema_privs_are('public', 'admin', array['USAGE']);
|
||||
select schema_privs_are('public', 'authenticator', array[]::text[]);
|
||||
|
||||
select schema_privs_are('sqitch', 'guest', array[]::text[]);
|
||||
select schema_privs_are('sqitch', 'invoicer', array[]::text[]);
|
||||
select schema_privs_are('sqitch', 'admin', array[]::text[]);
|
||||
select schema_privs_are('sqitch', 'authenticator', array[]::text[]);
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,57 @@
|
|||
-- Test user
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(34);
|
||||
|
||||
set search_path to auth, public;
|
||||
|
||||
select has_table('user');
|
||||
select has_pk('user');
|
||||
select table_privs_are('user', 'guest', array []::text[]);
|
||||
select table_privs_are('user', 'invoicer', array []::text[]);
|
||||
select table_privs_are('user', 'admin', array []::text[]);
|
||||
select table_privs_are('user', 'authenticator', array []::text[]);
|
||||
|
||||
select has_column('user', 'user_id');
|
||||
select col_is_pk('user', 'user_id');
|
||||
select col_type_is('user', 'user_id', 'integer');
|
||||
select col_not_null('user', 'user_id');
|
||||
select col_has_default('user', 'user_id');
|
||||
select col_default_is('user', 'user_id', 'nextval(''user_user_id_seq''::regclass)');
|
||||
|
||||
select has_column('user', 'email');
|
||||
select col_is_unique('user', 'email');
|
||||
select col_type_is('user', 'email', 'numerus.email');
|
||||
select col_not_null('user', 'email');
|
||||
select col_hasnt_default('user', 'email');
|
||||
|
||||
select has_column('user', 'name');
|
||||
select col_type_is('user', 'name', 'text');
|
||||
select col_not_null('user', 'name');
|
||||
select col_hasnt_default('user', 'name');
|
||||
|
||||
select has_column('user', 'password');
|
||||
select col_type_is('user', 'password', 'text');
|
||||
select col_not_null('user', 'password');
|
||||
select col_hasnt_default('user', 'password');
|
||||
|
||||
select has_column('user', 'role');
|
||||
select col_type_is('user', 'role', 'name');
|
||||
select col_not_null('user', 'role');
|
||||
select col_hasnt_default('user', 'role');
|
||||
|
||||
select has_column('user', 'created_at');
|
||||
select col_type_is('user', 'created_at', 'timestamp with time zone');
|
||||
select col_not_null('user', 'created_at');
|
||||
select col_has_default('user', 'created_at');
|
||||
select col_default_is('user', 'created_at', current_timestamp);
|
||||
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:email on pg
|
||||
|
||||
begin;
|
||||
|
||||
select pg_catalog.has_type_privilege('numerus.email', 'usage');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,22 @@
|
|||
-- Verify numerus:encrypt_password on pg
|
||||
|
||||
begin;
|
||||
|
||||
select has_function_privilege('auth.encrypt_password()', 'execute');
|
||||
|
||||
select 1/count(*)
|
||||
from pg_trigger
|
||||
where not tgisinternal
|
||||
and tgname = 'encrypt_password'
|
||||
and tgrelid = 'auth.user'::regclass
|
||||
and tgtype = b'00010111'::int;
|
||||
-- │││││││
|
||||
-- ││││││└─> row
|
||||
-- │││││└──> before
|
||||
-- ││││└───> insert
|
||||
-- │││└────> delete
|
||||
-- ││└─────> update
|
||||
-- │└──────> truncate
|
||||
-- └───────> instead
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,23 @@
|
|||
-- Verify numerus:ensure_role_exists on pg
|
||||
|
||||
begin;
|
||||
|
||||
select has_function_privilege('auth.ensure_role_exists()', 'execute');
|
||||
|
||||
select 1/count(*)
|
||||
from pg_trigger
|
||||
where not tgisinternal
|
||||
and tgname = 'ensure_role_exists'
|
||||
and tgrelid = 'auth.user'::regclass
|
||||
and tgtype = b'00010101'::int;
|
||||
-- │││││││
|
||||
-- ││││││└─> row
|
||||
-- │││││└──> before
|
||||
-- ││││└───> insert
|
||||
-- │││└────> delete
|
||||
-- ││└─────> update
|
||||
-- │└──────> truncate
|
||||
-- └───────> instead
|
||||
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:extension_citext on pg
|
||||
|
||||
begin;
|
||||
|
||||
select 1/count(*) from pg_extension where extname = 'citext';
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:extension_pgcrypto on pg
|
||||
|
||||
begin;
|
||||
|
||||
select 1/count(*) from pg_extension where extname = 'pgcrypto';
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:find_user_role on pg
|
||||
|
||||
begin;
|
||||
|
||||
select has_function_privilege('auth.find_user_role(numerus.email, text)', 'execute');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:login on pg
|
||||
|
||||
begin;
|
||||
|
||||
select has_function_privilege('numerus.login(numerus.email, text)', 'execute');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,10 @@
|
|||
-- Verify numerus:roles on pg
|
||||
|
||||
begin;
|
||||
|
||||
select pg_catalog.pg_has_role('guest', 'usage');
|
||||
select pg_catalog.pg_has_role('invoicer', 'usage');
|
||||
select pg_catalog.pg_has_role('admin', 'usage');
|
||||
select pg_catalog.pg_has_role('authenticator', 'usage');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:schema_auth on pg
|
||||
|
||||
begin;
|
||||
|
||||
select pg_catalog.has_schema_privilege('auth', 'usage');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:schema_numerus on pg
|
||||
|
||||
begin;
|
||||
|
||||
select pg_catalog.has_schema_privilege('numerus', 'usage');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:schema_public on pg
|
||||
|
||||
begin;
|
||||
|
||||
select pg_catalog.has_schema_privilege('public', 'usage');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,15 @@
|
|||
-- Verify numerus:user on pg
|
||||
|
||||
begin;
|
||||
|
||||
select
|
||||
user_id
|
||||
, email
|
||||
, name
|
||||
, password
|
||||
, role
|
||||
, created_at
|
||||
from auth."user"
|
||||
where false;
|
||||
|
||||
rollback;
|
Loading…
Reference in New Issue