Skip to content

Instantly share code, notes, and snippets.

@scyclow
Last active December 29, 2018 01:53
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save scyclow/6c1f926a1fa33fc11fa699dc1e172196 to your computer and use it in GitHub Desktop.
Save scyclow/6c1f926a1fa33fc11fa699dc1e172196 to your computer and use it in GitHub Desktop.
postgraphile test
begin;
drop schema friendworld cascade;
drop schema friendworld_private cascade;
drop domain username_domain;
drop role friendworld_root;
drop role friendworld_anonymous;
drop role friendworld_user;
create extension if not exists "uuid-ossp";
create extension if not exists citext;
create extension if not exists "pgcrypto";
create schema friendworld;
create schema friendworld_private;
create domain username_domain as citext check (value ~* '^[A-Za-z0-9._%-]+$');
create table friendworld.users (
id uuid primary key unique default uuid_generate_v4()
, created_at timestamp default now()
, updated_at timestamp default now()
, username username_domain not null unique
, email citext check (email ~* '^.+@.+\..+$')
, tracking_info json
);
comment on table friendworld.users is 'A friendworld user';
comment on column friendworld.users.updated_at is E'@omit';
create table friendworld_private.accounts (
user_id uuid primary key references friendworld.users(id)
, password_hash text not null
);
create table friendworld.threads (
id uuid primary key unique default uuid_generate_v4()
, created_at timestamp default now()
, updated_at timestamp default now()
, title text not null
);
create table friendworld.posts (
id uuid primary key unique default uuid_generate_v4()
, created_at timestamp default now()
, updated_at timestamp default now()
, author_id uuid references friendworld.users(id)
, thread_id uuid references friendworld.threads(id)
, content text not null
);
create type friendworld_private.jwt_token as (
role text
, aud text
, exp integer
, user_id uuid
);
create function friendworld.signup(
username username_domain
, password text
, email text default null
) returns friendworld.users as $$
declare
user friendworld.users;
begin
insert into friendworld.users (username, email)
values (username, email)
returning * into user;
insert into friendworld_private.accounts (user_id, password_hash)
values (user.id, crypt(password, gen_salt('bf')));
return user;
end;
$$ language plpgsql;
create function friendworld.login(
username username_domain
, password text
) returns friendworld_private.jwt_token as $$
#variable_conflict use_variable
declare
account friendworld_private.accounts;
begin
select friendworld_private.accounts.* into account
from friendworld.users
inner join friendworld_private.accounts
on friendworld.users.id = friendworld_private.accounts.user_id
where friendworld.users.username = username;
if account.password_hash = crypt(password, account.password_hash) then
return ('friendworld_user', 'postgraphile', extract(epoch from now())::int + 7776000, account.user_id)::friendworld_private.jwt_token;
else
return null;
end if;
end;
$$ language plpgsql;
create function friendworld.current_user() returns friendworld.users as $$
select *
from friendworld.users
where id = nullif(current_setting('jwt.claims.user_id', true), '')::uuid;
$$ language sql stable;
create function friendworld.current_user_id() returns int as $$
select nullif(current_setting('jwt.claims.exp', true), '')::int;
$$ language sql stable;
create role friendworld_root;
create role friendworld_anonymous;
grant friendworld_anonymous to friendworld_root;
create role friendworld_user;
grant friendworld_user to friendworld_root;
commit;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment