Add authentication relations, views, and functions for PostgreSQL

Most of them are exactly the same as we use for Numerus, but with the
main application schema changed to tipus.
This commit is contained in:
jordi fita mas 2023-06-04 22:45:44 +02:00
parent af48e1477c
commit 301195efac
86 changed files with 2277 additions and 0 deletions

View File

@ -0,0 +1,13 @@
-- Deploy tipus:available_languages to pg
-- requires: schema_public
-- requires: language
begin;
insert into public.language (lang_tag, name, endonym, selectable, currency_pattern)
values ('und', 'Undefined', 'Undefined', false, '%[3]s%.[1]*[2]f')
, ('ca', 'Catalan', 'català', true, '%.[1]*[2]f %[3]s')
, ('es', 'Spanish', 'español', true, '%.[1]*[2]f %[3]s')
;
commit;

25
deploy/build_cookie.sql Normal file
View File

@ -0,0 +1,25 @@
-- Deploy tipus:build_cookie to pg
-- requires: roles
-- requires: schema_tipus
-- requires: current_user_email
-- requires: current_user_cookie
begin;
set search_path to tipus, public;
create or replace function build_cookie(user_email email default null, user_cookie text default null) returns text as
$$
select coalesce(user_cookie, current_user_cookie()) || '/' || coalesce(user_email, current_user_email());
$$
language sql
stable;
revoke execute on function build_cookie(email, text) from public;
grant execute on function build_cookie(email, text) to publisher;
grant execute on function build_cookie(email, text) to admin;
comment on function build_cookie(email, text) is
'Build the cookie to send to the users browser, either for the given values or for the current user.';
commit;

View File

@ -0,0 +1,30 @@
-- Deploy tipus:change_password to pg
-- requires: roles
-- requires: schema_tipus
-- requires: schema_auth
-- requires: user
begin;
set search_path to tipus, auth, public;
create or replace function change_password(new_password text) returns void as
$$
update "user"
set password = new_password
where email = current_user_email()
and cookie = current_user_cookie()
and cookie_expires_at > current_timestamp
and length(cookie) > 30
$$ language sql
security definer
set search_path to auth, tipus, pg_temp;
revoke execute on function change_password(text) from public;
grant execute on function change_password(text) to publisher;
grant execute on function change_password(text) to admin;
comment on function change_password(text) is
'Changes the password for the current app user';
commit;

48
deploy/check_cookie.sql Normal file
View File

@ -0,0 +1,48 @@
-- Deploy tipus:check_cookie to pg
-- requires: roles
-- requires: schema_public
-- requires: schema_auth
-- requires: user
begin;
set search_path to public, auth;
create or replace function check_cookie(input_cookie text) returns name as
$$
declare
uid text;
user_email text;
user_role name;
user_cookie text;
begin
select user_id::text, email::text, role, cookie
into uid, user_email, user_role, user_cookie
from "user"
where email = split_part(input_cookie, '/', 2)
and cookie_expires_at > current_timestamp
and length(password) > 0
and cookie = split_part(input_cookie, '/', 1);
if user_role is null then
uid := '0';
user_email := '';
user_cookie := '';
user_role := 'guest'::name;
end if;
perform set_config('request.user.email', user_email, false);
perform set_config('request.user.cookie', user_cookie, false);
return user_role;
end;
$$
language plpgsql
security definer
stable
set search_path = auth, pg_temp;
comment on function check_cookie(text) is
'Checks whether a given cookie is for a valid users, returning their role, and setting current_user_email and current_user_cookie';
revoke execute on function check_cookie(text) from public;
grant execute on function check_cookie(text) to authenticator;
commit;

View File

@ -0,0 +1,24 @@
-- Deploy tipus:current_user_cookie to pg
-- requires: roles
-- requires: schema_tipus
begin;
set search_path to tipus;
create or replace function current_user_cookie() returns text as
$$
select current_setting('request.user.cookie', true);
$$
language sql
stable;
comment on function current_user_cookie() is
'Returns the cookie of the current Numerus user';
revoke execute on function current_user_cookie() from public;
grant execute on function current_user_cookie() to guest;
grant execute on function current_user_cookie() to publisher;
grant execute on function current_user_cookie() to admin;
commit;

View File

@ -0,0 +1,24 @@
-- Deploy tipus:current_user_email to pg
-- requires: roles
-- requires: schema_tipus
begin;
set search_path to tipus;
create or replace function current_user_email() returns text as
$$
select current_setting('request.user.email', true);
$$
language sql
stable;
comment on function current_user_email() is
'Returns the email of the current Numerus user';
revoke execute on function current_user_email() from public;
grant execute on function current_user_email() to guest;
grant execute on function current_user_email() to publisher;
grant execute on function current_user_email() to admin;
commit;

16
deploy/email.sql Normal file
View File

@ -0,0 +1,16 @@
-- Deploy tipus:email to pg
-- requires: schema_tipus
-- requires: extension_citext
begin;
set search_path to tipus, 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;

View File

@ -0,0 +1,33 @@
-- Deploy tipus:encrypt_password to pg
-- requires: schema_auth
-- requires: user
-- requires: extension_pgcrypto
begin;
set search_path to auth, 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
set search_path = auth, pg_temp;
comment on function encrypt_password() is
'Encrypts and salts the input password with the blowfish encryption algorithm';
revoke execute on function encrypt_password() from public;
create trigger encrypt_password
before insert or update
on "user"
for each row
execute procedure encrypt_password();
commit;

View File

@ -0,0 +1,31 @@
-- Deploy tipus: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.';
revoke execute on function ensure_role_exists() from public;
create trigger ensure_role_exists
after insert or update
on "user"
for each row
execute procedure ensure_role_exists();
commit;

View File

@ -0,0 +1,8 @@
-- Deploy tipus:extension_citext to pg
-- requires: schema_public
begin;
create extension if not exists citext;
commit;

View File

@ -0,0 +1,8 @@
-- Deploy tipus:extension_pgcrypto to pg
-- requires: schema_auth
begin;
create extension if not exists pgcrypto with schema auth;
commit;

32
deploy/language.sql Normal file
View File

@ -0,0 +1,32 @@
-- Deploy tipus:language to pg
-- requires: roles
-- requires: schema_public
begin;
set search_path to public;
create table language
(
lang_tag text primary key check (length(lang_tag) < 36), -- RFC5646 recommends 35 at least
name text not null,
endonym text not null,
selectable boolean not null,
currency_pattern text not null
);
grant select on table language to guest;
grant select on table language to publisher;
grant select on table language to admin;
grant select on table language to authenticator;
comment on table language is
'Languages/locales available in Tipus';
comment on column language.lang_tag is
'BCP-47 language tag';
comment on column language.selectable is
'Whether the language should be a option in a user-facing select control.';
commit;

63
deploy/login.sql Normal file
View File

@ -0,0 +1,63 @@
-- Deploy tipus:login to pg
-- requires: roles
-- requires: schema_auth
-- requires: schema_tipus
-- requires: extension_pgcrypto
-- requires: email
-- requires: user
-- requires: login_attempt
-- requires: build_cookie
begin;
set search_path to tipus, auth;
create or replace function login(email email, password text, ip_address inet default null) returns text as
$$
declare
user_cookie text;
begin
if not exists (select *
from "user"
where "user".email = login.email
and "user".password = crypt(login.password, "user".password)) then
insert into login_attempt
(user_name, ip_address, success)
values (login.email, login.ip_address, false);
return '';
end if;
select cookie
into user_cookie
from "user"
where "user".email = login.email
and cookie_expires_at > current_timestamp
and length(cookie) > 30;
if user_cookie is null then
select encode(gen_random_bytes(25), 'hex') into user_cookie;
end if;
update "user"
set cookie = user_cookie
, cookie_expires_at = current_timestamp + interval '1 year'
where "user".email = login.email;
insert into login_attempt
(user_name, ip_address, success)
values (login.email, login.ip_address, true);
return build_cookie(email, user_cookie);
end;
$$
language plpgsql
security definer
set search_path = auth, tipus, pg_temp;
comment on function login(email, text, inet) is
'Tries to logs a user in, recording the attempt, and returns the cookie to send back to the user if the authentication was successfull.';
revoke execute on function login(email, text, inet) from public;
grant execute on function login(email, text, inet) to guest;
commit;

18
deploy/login_attempt.sql Normal file
View File

@ -0,0 +1,18 @@
-- Deploy tipus:login_attempt to pg
-- requires: schema_auth
begin;
set search_path to auth;
create table login_attempt
(
attempt_id bigserial primary key,
user_name text not null,
ip_address inet -- just in case we logged from a non web application, somehow
,
success boolean not null,
attempted_at timestamptz not null default current_timestamp
);
commit;

34
deploy/logout.sql Normal file
View File

@ -0,0 +1,34 @@
-- Deploy tipus:logout to pg
-- requires: roles
-- requires: schema_tipus
-- requires: schema_auth
-- requires: user
-- requires: current_user_cookie
-- requires: current_user_email
begin;
set search_path to tipus, auth, public;
create or replace function logout() returns void as
$$
update "user"
set cookie = default
, cookie_expires_at = default
where email = current_user_email()
and cookie = current_user_cookie()
and cookie_expires_at > current_timestamp
and length(cookie) > 30
$$
language sql
security definer
set search_path to auth, tipus, pg_temp;
comment on function logout() is
'Removes the cookie and its expiry data from the current user, as returned by current_user_email and current_user_cookie';
revoke execute on function logout() from public;
grant execute on function logout() to publisher;
grant execute on function logout() to admin;
commit;

27
deploy/roles.sql Normal file
View File

@ -0,0 +1,27 @@
-- Deploy tipus:roles to pg
begin;
do
$$
declare
role name;
roles name[] := array ['guest', 'publisher', '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 publisher to authenticator;
grant admin to authenticator;
commit;

10
deploy/schema_auth.sql Normal file
View File

@ -0,0 +1,10 @@
-- Deploy tipus:schema_auth to pg
-- requires: roles
begin;
create schema auth;
comment on schema auth is 'To keep users passwords safe.';
commit;

14
deploy/schema_public.sql Normal file
View File

@ -0,0 +1,14 @@
-- Deploy tipus:schema_public to pg
-- requires: roles
begin;
revoke create on schema public from public;
revoke usage on schema public from public;
grant usage on schema public to authenticator;
grant usage on schema public to guest;
grant usage on schema public to publisher;
grant usage on schema public to admin;
commit;

14
deploy/schema_tipus.sql Normal file
View File

@ -0,0 +1,14 @@
-- Deploy tipus:schema_tipus to pg
-- requires: roles
begin;
create schema tipus;
comment on schema tipus is 'The main application schema';
grant usage on schema tipus to guest;
grant usage on schema tipus to publisher;
grant usage on schema tipus to admin;
commit;

23
deploy/set_cookie.sql Normal file
View File

@ -0,0 +1,23 @@
-- Deploy tipus:set_cookie to pg
-- requires: roles
-- requires: schema_public
-- requires: check_cookie
begin;
set search_path to public;
create or replace function set_cookie(input_cookie text) returns void as
$$
select set_config('role', check_cookie(input_cookie), false);
$$
language sql
stable;
comment on function set_cookie(text) is
'Sets the user information for the cookie and switches to its role';
revoke execute on function set_cookie(text) from public;
grant execute on function set_cookie(text) to authenticator;
commit;

23
deploy/user.sql Normal file
View File

@ -0,0 +1,23 @@
-- Deploy tipus:user to pg
-- requires: schema_auth
-- requires: email
-- requires: language
begin;
set search_path to auth, tipus, public;
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),
lang_tag text not null default 'und' references language,
cookie text not null default '',
cookie_expires_at timestamptz not null default '-infinity'::timestamp,
created_at timestamptz not null default current_timestamp
);
commit;

71
deploy/user_profile.sql Normal file
View File

@ -0,0 +1,71 @@
-- Deploy tipus:user_profile to pg
-- requires: roles
-- requires: schema_tipus
-- requires: user
-- requires: current_user_email
-- requires: current_user_cookie
begin;
set search_path to tipus, public;
create or replace view user_profile
with (security_barrier)
as
select user_id
, email
, name
, role
, lang_tag
, left(cookie, 10) as csrf_token
from auth."user"
where email = current_user_email()
and cookie = current_user_cookie()
and cookie_expires_at > current_timestamp
and length(cookie) > 30
union all
select 0
, null::email
, ''
, 'guest'::name
, 'und'
, ''
where not exists (select 1
from auth."user"
where email = current_user_email()
and cookie = current_user_cookie()
and cookie_expires_at > current_timestamp
and length(cookie) > 30);
grant select on table user_profile to guest;
grant select, update (email, name, lang_tag) on table user_profile to publisher;
grant select, update (email, name, lang_tag) on table user_profile to admin;
create or replace function update_user_profile() returns trigger as
$$
begin
update auth."user"
set email = new.email
, name = new.name
, lang_tag = new.lang_tag
where email = current_user_email()
and cookie = current_user_cookie()
and cookie_expires_at > current_timestamp
and length(cookie) > 30;
perform set_config('request.user.email', new.email, false);
return new;
end;
$$
language plpgsql
security definer
set search_path to auth, tipus, pg_temp;
create trigger update_user_profile
instead of update
on user_profile
for each row
execute procedure update_user_profile();
commit;

View File

@ -0,0 +1,8 @@
-- Revert tipus:available_languages from pg
begin;
delete
from public.language;
commit;

7
revert/build_cookie.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:build_cookie from pg
begin;
drop function if exists tipus.build_cookie(tipus.email, text);
commit;

View File

@ -0,0 +1,7 @@
-- Revert tipus:change_password from pg
begin;
drop function if exists tipus.change_password(text);
commit;

7
revert/check_cookie.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:check_cookie from pg
begin;
drop function if exists public.check_cookie(text);
commit;

View File

@ -0,0 +1,7 @@
-- Revert tipus:current_user_cookie from pg
begin;
drop function if exists tipus.current_user_cookie();
commit;

View File

@ -0,0 +1,7 @@
-- Revert tipus:current_user_email from pg
begin;
drop function if exists tipus.current_user_email();
commit;

7
revert/email.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:email from pg
begin;
drop domain if exists tipus.email;
commit;

View File

@ -0,0 +1,8 @@
-- Revert tipus:encrypt_password from pg
begin;
drop trigger if exists encrypt_password on auth."user";
drop function if exists auth.encrypt_password();
commit;

View File

@ -0,0 +1,8 @@
-- Revert tipus: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;

View File

@ -0,0 +1,7 @@
-- Revert tipus:extension_citext from pg
begin;
drop extension if exists citext;
commit;

View File

@ -0,0 +1,7 @@
-- Revert tipus:extension_pgcrypto from pg
begin;
drop extension if exists pgcrypto;
commit;

7
revert/language.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:language from pg
begin;
drop table if exists public.language;
commit;

7
revert/login.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:login from pg
begin;
drop function if exists tipus.login(tipus.email, text, inet);
commit;

7
revert/login_attempt.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:login_attempt from pg
begin;
drop table if exists auth.login_attempt;
commit;

7
revert/logout.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:logout from pg
begin;
drop function if exists tipus.logout();
commit;

10
revert/roles.sql Normal file
View File

@ -0,0 +1,10 @@
-- Revert tipus:roles from pg
begin;
drop role authenticator;
drop role admin;
drop role publisher;
drop role guest;
commit;

7
revert/schema_auth.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:schema_auth from pg
begin;
drop schema if exists auth;
commit;

12
revert/schema_public.sql Normal file
View File

@ -0,0 +1,12 @@
-- Revert tipus: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 publisher;
revoke usage on schema public from guest;
commit;

7
revert/schema_tipus.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:schema_tipus from pg
begin;
drop schema if exists tipus;
commit;

7
revert/set_cookie.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:set_cookie from pg
begin;
drop function if exists public.set_cookie(text);
commit;

7
revert/user.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert tipus:user from pg
begin;
drop table if exists auth."user";
commit;

9
revert/user_profile.sql Normal file
View File

@ -0,0 +1,9 @@
-- Revert tipus:user_profile from pg
begin;
drop trigger if exists update_user_profile on tipus.user_profile;
drop function if exists tipus.update_user_profile();
drop view if exists tipus.user_profile;
commit;

8
sqitch.conf Normal file
View File

@ -0,0 +1,8 @@
[core]
engine = pg
[engine "pg"]
target = db:pg:tipus
[deploy]
verify = true
[rebase]
verify = true

26
sqitch.plan Normal file
View File

@ -0,0 +1,26 @@
%syntax-version=1.0.0
%project=tipus
%uri=https://dev.tandem.ws/tandem/tipus
roles 2023-06-04T19:01:41Z jordi fita mas <jordi@tandem.blog> # Add database roles
schema_auth [roles] 2023-06-04T19:08:37Z jordi fita mas <jordi@tandem.blog> # Add authentication schema
schema_public [roles] 2023-06-04T19:11:16Z jordi fita mas <jordi@tandem.blog> # Set privileges to public schema
schema_tipus [roles] 2023-06-04T19:13:28Z jordi fita mas <jordi@tandem.blog> # Add application schema
extension_citext [schema_public] 2023-06-04T19:15:31Z jordi fita mas <jordi@tandem.blog> # Add citext extension
email [schema_tipus extension_citext] 2023-06-04T19:18:12Z jordi fita mas <jordi@tandem.blog> # Add citext extension
language [roles schema_public] 2023-06-04T19:20:29Z jordi fita mas <jordi@tandem.blog> # Add relation of available languages
available_languages [schema_public language] 2023-06-04T19:23:35Z jordi fita mas <jordi@tandem.blog> # Add the initial available languages
user [schema_auth email language] 2023-06-04T19:26:15Z jordi fita mas <jordi@tandem.blog> # Add user relation
ensure_role_exists [schema_auth user] 2023-06-04T19:28:20Z jordi fita mas <jordi@tandem.blog> # Add trigger to ensure the users role exists
extension_pgcrypto [schema_auth] 2023-06-04T19:30:11Z jordi fita mas <jordi@tandem.blog> # Add pgcrypto extension
encrypt_password [schema_auth user extension_pgcrypto] 2023-06-04T19:32:12Z jordi fita mas <jordi@tandem.blog> # Add trigger to encrypt users password
login_attempt [schema_auth] 2023-06-04T19:35:24Z jordi fita mas <jordi@tandem.blog> # Add relation to log login attempts
check_cookie [roles schema_public schema_auth user] 2023-06-04T19:47:48Z jordi fita mas <jordi@tandem.blog> # Add function to check if a user cookie is valid
current_user_cookie [roles schema_tipus] 2023-06-04T19:40:43Z jordi fita mas <jordi@tandem.blog> # Add function to get the cookie of the current Tipus user
current_user_email [roles schema_tipus] 2023-06-04T19:42:44Z jordi fita mas <jordi@tandem.blog> # Add function to get the email of the current Tipus user
build_cookie [roles schema_tipus current_user_email current_user_cookie] 2023-06-04T19:44:45Z jordi fita mas <jordi@tandem.blog> # Add function to build the cookie for the current user
set_cookie [roles schema_public check_cookie] 2023-06-04T19:50:49Z jordi fita mas <jordi@tandem.blog> # Add function to set the role based on the cookie
login [roles schema_auth schema_tipus extension_pgcrypto email user login_attempt build_cookie] 2023-06-04T19:53:03Z jordi fita mas <jordi@tandem.blog> # Add function to login
logout [roles schema_auth schema_tipus current_user_email current_user_cookie user] 2023-06-04T19:56:18Z jordi fita mas <jordi@tandem.blog> # Add function to logout
user_profile [roles schema_tipus user current_user_email current_user_cookie] 2023-06-04T19:58:34Z jordi fita mas <jordi@tandem.blog> # Add view for user profile
change_password [roles schema_auth schema_tipus user] 2023-06-04T20:00:49Z jordi fita mas <jordi@tandem.blog> # Add function to change the current users password

72
test/build_cookie.sql Normal file
View File

@ -0,0 +1,72 @@
-- Test build_cookie
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(13);
set search_path to tipus, auth, public;
select has_function('tipus', 'build_cookie', array ['email', 'text']);
select function_lang_is('tipus', 'build_cookie', array ['email', 'text'], 'sql');
select function_returns('tipus', 'build_cookie', array ['email', 'text'], 'text');
select isnt_definer('tipus', 'build_cookie', array ['email', 'text']);
select volatility_is('tipus', 'build_cookie', array ['email', 'text'], 'stable');
select function_privs_are('tipus', 'build_cookie', array ['email', 'text'], 'guest', array []::text[]);
select function_privs_are('tipus', 'build_cookie', array ['email', 'text'], 'publisher', array ['EXECUTE']);
select function_privs_are('tipus', 'build_cookie', array ['email', 'text'], 'admin', array ['EXECUTE']);
select function_privs_are('tipus', 'build_cookie', array ['email', 'text'], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', 'publisher', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e',
current_timestamp + interval '1 month')
, (9, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524',
current_timestamp + interval '1 month')
;
select is(
build_cookie('test@example.com'::email, '123abc'),
'123abc/test@example.com',
'Should build the cookie with the given user and cookie value'
);
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
reset role;
select is(
build_cookie(),
'44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog',
'Should build the cookie for the logged in user'
);
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
reset role;
select is(
build_cookie(),
'12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog',
'Should build the cookie for the other logged in user'
);
select set_cookie('ashtasth');
reset role;
select is(
build_cookie(),
'/',
'Should build the cookie for the guest user'
);
select *
from finish();
rollback;

59
test/change_password.sql Normal file
View File

@ -0,0 +1,59 @@
-- Test change_password
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(14);
set search_path to tipus, auth, public;
select has_function('tipus', 'change_password', array ['text']);
select function_lang_is('tipus', 'change_password', array ['text'], 'sql');
select function_returns('tipus', 'change_password', array ['text'], 'void');
select is_definer('tipus', 'change_password', array ['text']);
select volatility_is('tipus', 'change_password', array ['text'], 'volatile');
select function_privs_are('tipus', 'change_password', array ['text'], 'guest', array []::text[]);
select function_privs_are('tipus', 'change_password', array ['text'], 'publisher', array ['EXECUTE']);
select function_privs_are('tipus', 'change_password', array ['text'], 'admin', array ['EXECUTE']);
select function_privs_are('tipus', 'change_password', array ['text'], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', 'publisher', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e',
current_timestamp + interval '1 month')
, (9, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524',
current_timestamp + interval '1 month')
;
select lives_ok($$ select change_password('another') $$, 'Should run even without current user');
select isnt_empty(
$$ select * from auth."user" where password = crypt('test', password) $$,
'Should not have changed any password'
);
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
select lives_ok($$ select change_password('another') $$, 'Should run with the correct user');
reset role;
select isnt_empty(
$$ select * from auth."user" where email = 'demo@tandem.blog' and password = crypt('another', password) $$,
'Should have changed the password of the current user'
);
select isnt_empty(
$$ select * from auth."user" where email = 'admin@tandem.blog' and password = crypt('test', password) $$,
'Should not have changed any other password'
);
select *
from finish();
rollback;

115
test/check_cookie.sql Normal file
View File

@ -0,0 +1,115 @@
-- Test check_cookie
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(21);
set search_path to auth, tipus, public;
select has_function('public', 'check_cookie', array ['text']);
select function_lang_is('public', 'check_cookie', array ['text'], 'plpgsql');
select function_returns('public', 'check_cookie', array ['text'], 'name');
select is_definer('public', 'check_cookie', array ['text']);
select volatility_is('public', 'check_cookie', array ['text'], 'stable');
select function_privs_are('public', 'check_cookie', array ['text'], 'guest', array []::text[]);
select function_privs_are('public', 'check_cookie', array ['text'], 'publisher', array []::text[]);
select function_privs_are('public', 'check_cookie', array ['text'], 'admin', array []::text[]);
select function_privs_are('public', 'check_cookie', array ['text'], 'authenticator', array ['EXECUTE']);
set client_min_messages to warning;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', 'publisher', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e',
current_timestamp + interval '1 month')
, (9, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524',
current_timestamp + interval '1 month')
;
prepare user_info as
select current_user_email(), current_user_cookie();
select is(
check_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog'),
'publisher'::name,
'Should validate the cookie for the first user'
);
select results_eq(
'user_info',
$$ values ('demo@tandem.blog', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e') $$,
'Should have updated the settings with the user info'
);
select is(
check_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog'),
'admin'::name,
'Should validate the cookie for the second user'
);
select results_eq(
'user_info',
$$ values ('admin@tandem.blog', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524') $$,
'Should have updated the settings with the other user info'
);
select is(
check_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/admin@tandem.blog'),
'guest'::name,
'Should only match with the correct email'
);
select results_eq(
'user_info',
$$ values ('', '') $$,
'Should have updated the settings with a guest user'
);
select is(
check_cookie('aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa/admin@tandem.blog'),
'guest'::name,
'Should only match with the correct cookie value'
);
select results_eq(
'user_info',
$$ values ('', '') $$,
'Should have left the settings with a guest user'
);
update "user"
set cookie_expires_at = current_timestamp - interval '1 minute';
select is(
check_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog'),
'guest'::name,
'Should not allow expired cookies'
);
select results_eq(
'user_info',
$$ values ('', '') $$,
'Should have left the settings with a guest user'
);
select is(
check_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog'),
'guest'::name,
'Should not allow expired cookied for the other user as well'
);
select results_eq(
'user_info',
$$ values ('', '') $$,
'Should have left the settings with a guest user'
);
select *
from finish();
rollback;

View File

@ -0,0 +1,66 @@
-- Test current_user_cookie
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
set search_path to tipus, auth, public;
select plan(15);
select has_function('tipus', 'current_user_cookie', array []::name[]);
select function_lang_is('tipus', 'current_user_cookie', array []::name[], 'sql');
select function_returns('tipus', 'current_user_cookie', array []::name[], 'text');
select isnt_definer('tipus', 'current_user_cookie', array []::name[]);
select volatility_is('tipus', 'current_user_cookie', array []::name[], 'stable');
select function_privs_are('tipus', 'current_user_cookie', array []::name[], 'guest', array ['EXECUTE']);
select function_privs_are('tipus', 'current_user_cookie', array []::name[], 'publisher', array ['EXECUTE']);
select function_privs_are('tipus', 'current_user_cookie', array []::name[], 'admin', array ['EXECUTE']);
select function_privs_are('tipus', 'current_user_cookie', array []::name[], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', 'publisher', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e',
current_timestamp + interval '1 month')
, (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524',
current_timestamp + interval '1 month')
;
select lives_ok(
$$ select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog') $$,
'Should change ok for the first user'
);
select is(current_user_cookie(), '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e',
'Should return the cookie of the first user');
reset role;
select lives_ok(
$$ select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog') $$,
'Should change ok for the second user'
);
select is(current_user_cookie(), '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524',
'Should return the cookie of the second user');
reset role;
select lives_ok(
$$ select set_cookie('') $$,
'Should change ok for a guest user'
);
select is(current_user_cookie(), '', 'Should return an empty string');
reset role;
select *
from finish();
rollback;

View File

@ -0,0 +1,65 @@
-- Test current_user_email
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
set search_path to tipus, auth, public;
select plan(15);
select has_function('tipus', 'current_user_email', array []::name[]);
select function_lang_is('tipus', 'current_user_email', array []::name[], 'sql');
select function_returns('tipus', 'current_user_email', array []::name[], 'text');
select isnt_definer('tipus', 'current_user_email', array []::name[]);
select volatility_is('tipus', 'current_user_email', array []::name[], 'stable');
select function_privs_are('tipus', 'current_user_email', array []::name[], 'guest', array ['EXECUTE']);
select function_privs_are('tipus', 'current_user_email', array []::name[], 'publisher', array ['EXECUTE']);
select function_privs_are('tipus', 'current_user_email', array []::name[], 'admin', array ['EXECUTE']);
select function_privs_are('tipus', 'current_user_email', array []::name[], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', 'publisher', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e',
current_timestamp + interval '1 month')
, (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524',
current_timestamp + interval '1 month')
;
select lives_ok(
$$ select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog') $$,
'Should change ok for the first user'
);
select is(current_user_email(), 'demo@tandem.blog', 'Should return the email of the first user');
reset role;
select lives_ok(
$$ select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog') $$,
'Should change ok for the second user'
);
select is(current_user_email(), 'admin@tandem.blog', 'Should return the email of the second user');
reset role;
select lives_ok(
$$ select set_cookie('') $$,
'Should change ok for a guest user'
);
select is(current_user_email(), '', 'Should return an empty string');
reset role;
select *
from finish();
rollback;

33
test/email.sql Normal file
View File

@ -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 tipus, 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;

40
test/encrypt_password.sql Normal file
View File

@ -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, tipus, public;
select has_function('auth', 'encrypt_password', array []::name[]);
select function_lang_is('auth', 'encrypt_password', array []::name[], 'plpgsql');
select function_returns('auth', 'encrypt_password', array []::name[], 'trigger');
select isnt_definer('auth', 'encrypt_password', array []::name[]);
select volatility_is('auth', 'encrypt_password', array []::name[], 'volatile');
select function_privs_are('auth', 'encrypt_password', array []::name[], 'guest', array []::text[]);
select function_privs_are('auth', 'encrypt_password', array []::name[], 'publisher', array []::text[]);
select function_privs_are('auth', 'encrypt_password', array []::name[], 'admin', array []::text[]);
select function_privs_are('auth', '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;

View File

@ -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('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[], 'publisher', 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[]);
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 = 'publisher' 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;

20
test/extensions.sql Normal file
View File

@ -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;

48
test/language.sql Normal file
View File

@ -0,0 +1,48 @@
-- Test language
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
set search_path to public;
select plan(27);
select has_table('language');
select has_pk('language');
select table_privs_are('language', 'guest', array ['SELECT']);
select table_privs_are('language', 'publisher', array ['SELECT']);
select table_privs_are('language', 'admin', array ['SELECT']);
select table_privs_are('language', 'authenticator', array ['SELECT']::text[]);
select has_column('language', 'lang_tag');
select col_is_pk('language', 'lang_tag');
select col_type_is('language', 'lang_tag', 'text');
select col_not_null('language', 'lang_tag');
select col_hasnt_default('language', 'lang_tag');
select has_column('language', 'name');
select col_type_is('language', 'name', 'text');
select col_not_null('language', 'name');
select col_hasnt_default('language', 'name');
select has_column('language', 'endonym');
select col_type_is('language', 'endonym', 'text');
select col_not_null('language', 'endonym');
select col_hasnt_default('language', 'endonym');
select has_column('language', 'selectable');
select col_type_is('language', 'selectable', 'boolean');
select col_not_null('language', 'selectable');
select col_hasnt_default('language', 'selectable');
select has_column('language', 'currency_pattern');
select col_type_is('language', 'currency_pattern', 'text');
select col_not_null('language', 'currency_pattern');
select col_hasnt_default('language', 'currency_pattern');
select *
from finish();
rollback;

111
test/login.sql Normal file
View File

@ -0,0 +1,111 @@
-- Test login
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(20);
set search_path to auth, tipus, public;
select has_function('tipus', 'login', array ['email', 'text', 'inet']);
select function_lang_is('tipus', 'login', array ['email', 'text', 'inet'], 'plpgsql');
select function_returns('tipus', 'login', array ['email', 'text', 'inet'], 'text');
select is_definer('tipus', 'login', array ['email', 'text', 'inet']);
select volatility_is('tipus', 'login', array ['email', 'text', 'inet'], 'volatile');
select function_privs_are('tipus', 'login', array ['email', 'text', 'inet'], 'guest', array ['EXECUTE']);
select function_privs_are('tipus', 'login', array ['email', 'text', 'inet'], 'publisher', array []::text[]);
select function_privs_are('tipus', 'login', array ['email', 'text', 'inet'], 'admin', array []::text[]);
select function_privs_are('tipus', 'login', array ['email', 'text', 'inet'], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate auth."user" cascade;
truncate auth.login_attempt cascade;
reset client_min_messages;
insert into auth."user" (email, name, password, role)
values ('info@tandem.blog', 'Tandem', 'test', 'publisher');
create temp table _login_test
(
result_num integer,
cookie text not null
);
select lives_ok(
$$ insert into _login_test select 1, split_part(login('info@tandem.blog', 'test', '::1'::inet), '/', 1) $$,
'Should login with a correct user and password'
);
select isnt_empty(
$$ select cookie from _login_test join "user" using (cookie) where email = 'info@tandem.blog' $$,
'Should have returned the cookie that wrote to the user relation.'
);
select results_eq(
$$ select cookie_expires_at > current_timestamp from "user" where email = 'info@tandem.blog' $$,
$$ values (true) $$,
'Should have set an expiry date in the future.'
);
select isnt_empty(
$$ select cookie from _login_test where cookie in (select split_part(login('info@tandem.blog', 'test', '192.168.0.1'::inet), '/', 1)) $$,
'Should return the same cookie if not expired yet.'
);
update "user"
set cookie_expires_at = current_timestamp - interval '1 hour'
where email = 'info@tandem.blog';
select lives_ok(
$$ insert into _login_test select 2, split_part(login('info@tandem.blog', 'test', '::1'::inet), '/', 1) $$,
'Should login with a correct user and password even with an expired cookie'
);
select results_eq(
$$ select count(distinct cookie)::integer from _login_test $$,
$$ values (2) $$,
'Should have returned a new cookie'
);
select isnt_empty(
$$ select cookie from _login_test join "user" using (cookie) where email = 'info@tandem.blog' and result_num = 2 $$,
'Should have updated the users cookie.'
);
select results_eq(
$$ select cookie_expires_at > current_timestamp from "user" where email = 'info@tandem.blog' $$,
$$ values(true) $$,
'Should have set an expiry date in the future, again.'
);
select is(
login('info@tandem.blog'::email, 'mah password', '127.0.0.1'::inet),
''::text,
'Should not find any role with an invalid password'
);
select is(
login('nope@tandem.blog'::email, 'test'),
''::text,
'Should not find any role with an invalid email'
);
select results_eq(
'select user_name, ip_address, success, attempted_at from login_attempt order by attempt_id',
$$ values ('info@tandem.blog', '::1'::inet, true, current_timestamp)
, ('info@tandem.blog', '192.168.0.1'::inet, true, current_timestamp)
, ('info@tandem.blog', '::1'::inet, true, current_timestamp)
, ('info@tandem.blog', '127.0.0.1'::inet, false, current_timestamp)
, ('nope@tandem.blog', null, false, current_timestamp)
$$,
'Should have recorded all login attempts.'
);
select *
from finish();
rollback;

50
test/login_attempt.sql Normal file
View File

@ -0,0 +1,50 @@
-- Test login_attempt
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(29);
set search_path to auth, public;
select has_table('login_attempt');
select has_pk('login_attempt');
select table_privs_are('login_attempt', 'guest', array []::text[]);
select table_privs_are('login_attempt', 'publisher', array []::text[]);
select table_privs_are('login_attempt', 'admin', array []::text[]);
select table_privs_are('login_attempt', 'authenticator', array []::text[]);
select has_column('login_attempt', 'attempt_id');
select col_is_pk('login_attempt', 'attempt_id');
select col_type_is('login_attempt', 'attempt_id', 'bigint');
select col_not_null('login_attempt', 'attempt_id');
select col_has_default('login_attempt', 'attempt_id');
select col_default_is('login_attempt', 'attempt_id', 'nextval(''login_attempt_attempt_id_seq''::regclass)');
select has_column('login_attempt', 'user_name');
select col_type_is('login_attempt', 'user_name', 'text');
select col_not_null('login_attempt', 'user_name');
select col_hasnt_default('login_attempt', 'user_name');
select has_column('login_attempt', 'ip_address');
select col_type_is('login_attempt', 'ip_address', 'inet');
select col_is_null('login_attempt', 'ip_address');
select col_hasnt_default('login_attempt', 'ip_address');
select has_column('login_attempt', 'success');
select col_type_is('login_attempt', 'success', 'boolean');
select col_not_null('login_attempt', 'success');
select col_hasnt_default('login_attempt', 'success');
select has_column('login_attempt', 'attempted_at');
select col_type_is('login_attempt', 'attempted_at', 'timestamp with time zone');
select col_not_null('login_attempt', 'attempted_at');
select col_has_default('login_attempt', 'attempted_at');
select col_default_is('login_attempt', 'attempted_at', current_timestamp);
select *
from finish();
rollback;

90
test/logout.sql Normal file
View File

@ -0,0 +1,90 @@
-- Test logout
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(17);
set search_path to auth, tipus, public;
select has_function('tipus', 'logout', array []::name[]);
select function_lang_is('tipus', 'logout', array []::name[], 'sql');
select function_returns('tipus', 'logout', array []::name[], 'void');
select is_definer('tipus', 'logout', array []::name[]);
select volatility_is('tipus', 'logout', array []::name[], 'volatile');
select function_privs_are('tipus', 'logout', array []::name[], 'guest', array []::text[]);
select function_privs_are('tipus', 'logout', array []::name[], 'publisher', array ['EXECUTE']);
select function_privs_are('tipus', 'logout', array []::name[], 'admin', array ['EXECUTE']);
select function_privs_are('tipus', 'logout', array []::name[], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
values (1, 'info@tandem.blog', 'Tandem', 'test', 'publisher', '8c23d4a8d777775f8fc507676a0d99d3dfa54b03b1b257c838',
current_timestamp + interval '1 day')
, (12, 'admin@tandem.blog', 'Admin', 'test', 'admin', '0169e5f668eec1e6749fd25388b057997358efa8dfd697961a',
current_timestamp + interval '2 day')
;
prepare user_cookies as
select cookie, cookie_expires_at
from "user"
order by user_id
;
select set_config('request.user.cookie', '', false);
select set_config('request.user.email', '', false);
select lives_ok($$ select * from logout() $$, 'Can logout “nobody”');
select results_eq(
'user_cookies',
$$ values ('8c23d4a8d777775f8fc507676a0d99d3dfa54b03b1b257c838', current_timestamp + interval '1 day')
, ('0169e5f668eec1e6749fd25388b057997358efa8dfd697961a', current_timestamp + interval '2 day')
$$,
'Should have changed nothing'
);
select set_config('request.user.cookie', '0169e5f668eec1e6749fd25388b057997358efa8dfd697961a', false);
select set_config('request.user.email', 'info@tandem.blog', false);
select lives_ok($$ select * from logout() $$, 'Can logout even if the email and cookie does not match');
select results_eq(
'user_cookies',
$$ values ('8c23d4a8d777775f8fc507676a0d99d3dfa54b03b1b257c838', current_timestamp + interval '1 day')
, ('0169e5f668eec1e6749fd25388b057997358efa8dfd697961a', current_timestamp + interval '2 day')
$$,
'Should have changed nothing'
);
select set_config('request.user.cookie', '8c23d4a8d777775f8fc507676a0d99d3dfa54b03b1b257c838', false);
select set_config('request.user.email', 'info@tandem.blog', false);
select lives_ok($$ select * from logout() $$, 'Can logout the first user');
select results_eq(
'user_cookies',
$$ values ('', '-infinity'::timestamptz)
, ('0169e5f668eec1e6749fd25388b057997358efa8dfd697961a'::text, current_timestamp + interval '2 day')
$$,
'The first user logged out'
);
select set_config('request.user.cookie', '0169e5f668eec1e6749fd25388b057997358efa8dfd697961a', false);
select set_config('request.user.email', 'admin@tandem.blog', false);
select lives_ok($$ select * from logout() $$, 'Can logout the second user');
select results_eq(
'user_cookies',
$$ values ('', '-infinity'::timestamptz)
, ('', '-infinity'::timestamptz)
$$,
'The second user logged out'
);
select *
from finish();
rollback;

22
test/roles.sql Normal file
View File

@ -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('publisher');
select has_role('admin');
select has_role('authenticator');
select is_member_of('guest', 'authenticator');
select is_member_of('publisher', 'authenticator');
select is_member_of('admin', 'authenticator');
select *
from finish();
rollback;

40
test/schemas.sql Normal file
View File

@ -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',
'tipus',
'public',
'sqitch'
]);
select schema_privs_are('auth', 'guest', array []::text[]);
select schema_privs_are('auth', 'publisher', array []::text[]);
select schema_privs_are('auth', 'admin', array []::text[]);
select schema_privs_are('auth', 'authenticator', array []::text[]);
select schema_privs_are('tipus', 'guest', array ['USAGE']);
select schema_privs_are('tipus', 'publisher', array ['USAGE']);
select schema_privs_are('tipus', 'admin', array ['USAGE']);
select schema_privs_are('tipus', 'authenticator', array []::text[]);
select schema_privs_are('public', 'guest', array ['USAGE']);
select schema_privs_are('public', 'publisher', array ['USAGE']);
select schema_privs_are('public', 'admin', array ['USAGE']);
select schema_privs_are('public', 'authenticator', array ['USAGE']);
select schema_privs_are('sqitch', 'guest', array []::text[]);
select schema_privs_are('sqitch', 'publisher', array []::text[]);
select schema_privs_are('sqitch', 'admin', array []::text[]);
select schema_privs_are('sqitch', 'authenticator', array []::text[]);
select *
from finish();
rollback;

78
test/set_cookie.sql Normal file
View File

@ -0,0 +1,78 @@
-- Test set_cookie
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(15);
set search_path to auth, tipus, public;
select has_function('public', 'set_cookie', array ['text']);
select function_lang_is('public', 'set_cookie', array ['text'], 'sql');
select function_returns('public', 'set_cookie', array ['text'], 'void');
select isnt_definer('public', 'set_cookie', array ['text']);
select volatility_is('public', 'set_cookie', array ['text'], 'stable');
select function_privs_are('public', 'set_cookie', array ['text'], 'guest', array []::text[]);
select function_privs_are('public', 'set_cookie', array ['text'], 'publisher', array []::text[]);
select function_privs_are('public', 'set_cookie', array ['text'], 'admin', array []::text[]);
select function_privs_are('public', 'set_cookie', array ['text'], 'authenticator', array ['EXECUTE']);
set client_min_messages to warning;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', 'publisher', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e',
current_timestamp + interval '1 month')
, (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524',
current_timestamp + interval '1 month')
;
prepare user_info as
select current_user_email(), current_user_cookie(), current_user;
select lives_ok(
$$ select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog') $$,
'Should run ok for a valid cookie'
);
select results_eq(
'user_info',
$$ values ('demo@tandem.blog', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', 'publisher'::name) $$,
'Should have updated the info with the correct user'
);
reset role;
select lives_ok(
$$ select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog') $$,
'Should run ok for a different cookie'
);
select results_eq(
'user_info',
$$ values ('admin@tandem.blog', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', 'admin'::name) $$,
'Should have updated the info with the other user'
);
reset role;
select lives_ok(
$$ select set_cookie('aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa/admin@tandem.blog') $$,
'Should run ok even for an invalid cookie'
);
select results_eq(
'user_info',
$$ values ('', '', 'guest'::name) $$,
'Should have updated the info as a guest user'
);
reset role;
select *
from finish();
rollback;

77
test/user.sql Normal file
View File

@ -0,0 +1,77 @@
-- Test user
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(51);
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', 'publisher', 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', 'tipus.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', 'lang_tag');
select col_is_fk('user', 'lang_tag');
select fk_ok('user', 'lang_tag', 'language', 'lang_tag');
select col_type_is('user', 'lang_tag', 'text');
select col_not_null('user', 'lang_tag');
select col_has_default('user', 'lang_tag');
select col_default_is('user', 'lang_tag', 'und');
select has_column('user', 'cookie');
select col_type_is('user', 'cookie', 'text');
select col_not_null('user', 'cookie');
select col_has_default('user', 'cookie');
select col_default_is('user', 'cookie', '');
select has_column('user', 'cookie_expires_at');
select col_type_is('user', 'cookie_expires_at', 'timestamp with time zone');
select col_not_null('user', 'cookie_expires_at');
select col_has_default('user', 'cookie_expires_at');
select col_default_is('user', 'cookie_expires_at', '-infinity'::timestamp);
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;

171
test/user_profile.sql Normal file
View File

@ -0,0 +1,171 @@
-- Test user_profile
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(53);
set search_path to tipus, auth, public;
select has_view('user_profile');
select table_privs_are('user_profile', 'guest', array ['SELECT']);
select table_privs_are('user_profile', 'publisher', array ['SELECT']);
select table_privs_are('user_profile', 'admin', array ['SELECT']);
select table_privs_are('user_profile', 'authenticator', array []::text[]);
select has_column('user_profile', 'user_id');
select col_type_is('user_profile', 'user_id', 'integer');
select column_privs_are('user_profile', 'user_id', 'guest', array ['SELECT']);
select column_privs_are('user_profile', 'user_id', 'publisher', array ['SELECT']);
select column_privs_are('user_profile', 'user_id', 'admin', array ['SELECT']);
select column_privs_are('user_profile', 'user_id', 'authenticator', array []::text[]);
select has_column('user_profile', 'email');
select col_type_is('user_profile', 'email', 'email');
select column_privs_are('user_profile', 'email', 'guest', array ['SELECT']);
select column_privs_are('user_profile', 'email', 'publisher', array ['SELECT', 'UPDATE']);
select column_privs_are('user_profile', 'email', 'admin', array ['SELECT', 'UPDATE']);
select column_privs_are('user_profile', 'email', 'authenticator', array []::text[]);
select has_column('user_profile', 'name');
select col_type_is('user_profile', 'name', 'text');
select column_privs_are('user_profile', 'name', 'guest', array ['SELECT']);
select column_privs_are('user_profile', 'name', 'publisher', array ['SELECT', 'UPDATE']);
select column_privs_are('user_profile', 'name', 'admin', array ['SELECT', 'UPDATE']);
select column_privs_are('user_profile', 'name', 'authenticator', array []::text[]);
select has_column('user_profile', 'role');
select col_type_is('user_profile', 'role', 'name');
select column_privs_are('user_profile', 'role', 'guest', array ['SELECT']);
select column_privs_are('user_profile', 'role', 'publisher', array ['SELECT']);
select column_privs_are('user_profile', 'role', 'admin', array ['SELECT']);
select column_privs_are('user_profile', 'role', 'authenticator', array []::text[]);
select has_column('user_profile', 'lang_tag');
select col_type_is('user_profile', 'lang_tag', 'text');
select column_privs_are('user_profile', 'lang_tag', 'guest', array ['SELECT']);
select column_privs_are('user_profile', 'lang_tag', 'publisher', array ['SELECT', 'UPDATE']);
select column_privs_are('user_profile', 'lang_tag', 'admin', array ['SELECT', 'UPDATE']);
select column_privs_are('user_profile', 'lang_tag', 'authenticator', array []::text[]);
select has_column('user_profile', 'csrf_token');
select col_type_is('user_profile', 'csrf_token', 'text');
select column_privs_are('user_profile', 'csrf_token', 'guest', array ['SELECT']);
select column_privs_are('user_profile', 'csrf_token', 'publisher', array ['SELECT']);
select column_privs_are('user_profile', 'csrf_token', 'admin', array ['SELECT']);
select column_privs_are('user_profile', 'csrf_token', 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at, lang_tag)
values (1, 'demo@tandem.blog', 'Demo', 'test', 'publisher', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e',
current_timestamp + interval '1 month', 'ca')
, (5, 'admin@tandem.blog', 'Admin', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524',
current_timestamp + interval '1 month', 'es')
, (7, 'another@tandem.blog', 'Another Admin', 'test', 'admin', default, default, default)
;
prepare profile as
select user_id, email, name, role, lang_tag, csrf_token
from user_profile;
select set_config('request.user.cookie', '', false);
select results_eq(
'profile',
$$ values (0, null::email, '', 'guest'::name, 'und', '') $$,
'Should be set up with the guest user when no user logged in yet.'
);
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
select results_eq(
'profile',
$$ values (1, 'demo@tandem.blog'::email, 'Demo', 'publisher'::name, 'ca', '44facbb30d') $$,
'Should only see the profile of the first user'
);
select lives_ok($$
update user_profile
set email = 'demo+update@tandem.blog'
, name = 'Demo Update'
, lang_tag = 'es';
$$,
'Should be able to update the first profile'
);
select throws_ok(
$$ update user_profile set user_id = 123 $$,
'42501', 'permission denied for view user_profile',
'Should not be able to change the ID'
);
select throws_ok(
$$ update user_profile set role = 'admin' $$,
'42501', 'permission denied for view user_profile',
'Should not be able to change the ID'
);
select results_eq(
'profile',
$$ values (1, 'demo+update@tandem.blog'::email, 'Demo Update', 'publisher'::name, 'es', '44facbb30d') $$,
'Should see the changed profile of the first user'
);
reset role;
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
select results_eq(
'profile',
$$ values (5, 'admin@tandem.blog'::email, 'Admin', 'admin'::name, 'es', '12af4c88b5') $$,
'Should only see the profile of the second user'
);
select lives_ok($$
update user_profile
set email = 'admin+update@tandem.blog'
, name = 'Admin Update'
, lang_tag = 'ca';
$$,
'Should be able to update the second profile'
);
select throws_ok(
$$ update user_profile set user_id = 123 $$,
'42501', 'permission denied for view user_profile',
'Should not be able to change the ID'
);
select throws_ok(
$$ update user_profile set role = 'publisher' $$,
'42501', 'permission denied for view user_profile',
'Should not be able to change the ID'
);
select results_eq(
'profile',
$$ values (5, 'admin+update@tandem.blog'::email, 'Admin Update', 'admin'::name, 'ca', '12af4c88b5') $$,
'Should see the changed profile of the first user'
);
reset role;
select results_eq(
$$ select user_id, email, name, lang_tag from auth."user" order by user_id $$,
$$ values (1, 'demo+update@tandem.blog'::email, 'Demo Update', 'es')
, (5, 'admin+update@tandem.blog'::email, 'Admin Update', 'ca')
, (7, 'another@tandem.blog'::email, 'Another Admin', 'und')
$$,
'Should have updated the base tables data'
);
select *
from finish();
rollback;

View File

@ -0,0 +1,31 @@
-- Verify tipus:available_languages on pg
begin;
set search_path to public;
select 1 / count(*)
from language
where lang_tag = 'und'
and name = 'Undefined'
and endonym = 'Undefined'
and not selectable
and currency_pattern = '%[3]s%.[1]*[2]f';
select 1 / count(*)
from language
where lang_tag = 'ca'
and name = 'Catalan'
and endonym = 'català'
and selectable
and currency_pattern = '%.[1]*[2]f %[3]s';
select 1 / count(*)
from language
where lang_tag = 'es'
and name = 'Spanish'
and endonym = 'español'
and selectable
and currency_pattern = '%.[1]*[2]f %[3]s';
rollback;

7
verify/build_cookie.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:build_cookie on pg
begin;
select has_function_privilege('tipus.build_cookie(tipus.email, text)', 'execute');
rollback;

View File

@ -0,0 +1,7 @@
-- Verify tipus:change_password on pg
begin;
select has_function_privilege('tipus.change_password(text)', 'execute');
rollback;

7
verify/check_cookie.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:check_cookie on pg
begin;
select has_function_privilege('public.check_cookie(text)', 'execute');
rollback;

View File

@ -0,0 +1,7 @@
-- Verify tipus:current_user_cookie on pg
begin;
select has_function_privilege('tipus.current_user_cookie()', 'execute');
rollback;

View File

@ -0,0 +1,7 @@
-- Verify tipus:current_user_email on pg
begin;
select has_function_privilege('tipus.current_user_email()', 'execute');
rollback;

7
verify/email.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:email on pg
begin;
select pg_catalog.has_type_privilege('tipus.email', 'usage');
rollback;

View File

@ -0,0 +1,22 @@
-- Verify tipus: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;

View File

@ -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;

View File

@ -0,0 +1,9 @@
-- Verify tipus:extension_citext on pg
begin;
select 1 / count(*)
from pg_extension
where extname = 'citext';
rollback;

View File

@ -0,0 +1,9 @@
-- Verify tipus:extension_pgcrypto on pg
begin;
select 1 / count(*)
from pg_extension
where extname = 'pgcrypto';
rollback;

13
verify/language.sql Normal file
View File

@ -0,0 +1,13 @@
-- Verify tipus:language on pg
begin;
select lang_tag
, name
, endonym
, selectable
, currency_pattern
from public.language
where false;
rollback;

7
verify/login.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:login on pg
begin;
select has_function_privilege('tipus.login(tipus.email, text, inet)', 'execute');
rollback;

13
verify/login_attempt.sql Normal file
View File

@ -0,0 +1,13 @@
-- Verify tipus:login_attempt on pg
begin;
select attempt_id
, user_name
, ip_address
, success
, attempted_at
from auth.login_attempt
where false;
rollback;

7
verify/logout.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:logout on pg
begin;
select has_function_privilege('tipus.logout()', 'execute');
rollback;

10
verify/roles.sql Normal file
View File

@ -0,0 +1,10 @@
-- Verify tipus:roles on pg
begin;
select pg_catalog.pg_has_role('guest', 'usage');
select pg_catalog.pg_has_role('publisher', 'usage');
select pg_catalog.pg_has_role('admin', 'usage');
select pg_catalog.pg_has_role('authenticator', 'usage');
rollback;

7
verify/schema_auth.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:schema_auth on pg
begin;
select pg_catalog.has_schema_privilege('auth', 'usage');
rollback;

7
verify/schema_public.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:schema_public on pg
begin;
select pg_catalog.has_schema_privilege('public', 'usage');
rollback;

7
verify/schema_tipus.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:schema_tipus on pg
begin;
select pg_catalog.has_schema_privilege('tipus', 'usage');
rollback;

7
verify/set_cookie.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify tipus:set_cookie on pg
begin;
select has_function_privilege('public.set_cookie(text)', 'execute');
rollback;

17
verify/user.sql Normal file
View File

@ -0,0 +1,17 @@
-- Verify tipus:user on pg
begin;
select user_id
, email
, name
, password
, role
, lang_tag
, cookie
, cookie_expires_at
, created_at
from auth."user"
where false;
rollback;

45
verify/user_profile.sql Normal file
View File

@ -0,0 +1,45 @@
-- Verify tipus:user_profile on pg
begin;
select user_id
, email
, name
, role
, lang_tag
, csrf_token
from tipus.user_profile
where false;
select has_function_privilege('tipus.update_user_profile()', 'execute');
select 1 / count(*)
from pg_trigger
where not tgisinternal
and tgname = 'update_user_profile'
and tgrelid = 'tipus.user_profile'::regclass
and tgtype = b'01010001'::int;
-- │││││││
-- ││││││└─> row
-- │││││└──> before
-- ││││└───> insert
-- │││└────> delete
-- ││└─────> update
-- │└──────> truncate
-- └───────> instead
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;