-
-
Notifications
You must be signed in to change notification settings - Fork 221
/
schema.sql
2953 lines (2176 loc) · 96.6 KB
/
schema.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
--
-- PostgreSQL database dump
--
-- Dumped from database version 13.4 (Ubuntu 13.4-0ubuntu0.21.04.1)
-- Dumped by pg_dump version 13.4 (Ubuntu 13.4-0ubuntu0.21.04.1)
SET statement_timeout = 0;
SET lock_timeout = 0;
SET idle_in_transaction_session_timeout = 0;
SET client_encoding = 'UTF8';
SET standard_conforming_strings = on;
SELECT pg_catalog.set_config('search_path', '', false);
SET check_function_bodies = false;
SET xmloption = content;
SET client_min_messages = warning;
SET row_security = off;
--
-- Name: app_hidden; Type: SCHEMA; Schema: -; Owner: -
--
CREATE SCHEMA app_hidden;
--
-- Name: app_private; Type: SCHEMA; Schema: -; Owner: -
--
CREATE SCHEMA app_private;
--
-- Name: app_public; Type: SCHEMA; Schema: -; Owner: -
--
CREATE SCHEMA app_public;
--
-- Name: citext; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS citext WITH SCHEMA public;
--
-- Name: EXTENSION citext; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION citext IS 'data type for case-insensitive character strings';
--
-- Name: pgcrypto; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS pgcrypto WITH SCHEMA public;
--
-- Name: EXTENSION pgcrypto; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION pgcrypto IS 'cryptographic functions';
--
-- Name: uuid-ossp; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS "uuid-ossp" WITH SCHEMA public;
--
-- Name: EXTENSION "uuid-ossp"; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION "uuid-ossp" IS 'generate universally unique identifiers (UUIDs)';
--
-- Name: assert_valid_password(text); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.assert_valid_password(new_password text) RETURNS void
LANGUAGE plpgsql
AS $$
begin
-- TODO: add better assertions!
if length(new_password) < 8 then
raise exception 'Password is too weak' using errcode = 'WEAKP';
end if;
end;
$$;
SET default_tablespace = '';
SET default_table_access_method = heap;
--
-- Name: users; Type: TABLE; Schema: app_public; Owner: -
--
CREATE TABLE app_public.users (
id uuid DEFAULT gen_random_uuid() NOT NULL,
username public.citext NOT NULL,
name text,
avatar_url text,
is_admin boolean DEFAULT false NOT NULL,
is_verified boolean DEFAULT false NOT NULL,
created_at timestamp with time zone DEFAULT now() NOT NULL,
updated_at timestamp with time zone DEFAULT now() NOT NULL,
CONSTRAINT users_avatar_url_check CHECK ((avatar_url ~ '^https?://[^/]+'::text)),
CONSTRAINT users_username_check CHECK (((length((username)::text) >= 2) AND (length((username)::text) <= 24) AND (username OPERATOR(public.~) '^[a-zA-Z]([_]?[a-zA-Z0-9])+$'::public.citext)))
);
--
-- Name: TABLE users; Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON TABLE app_public.users IS 'A user who can log in to the application.';
--
-- Name: COLUMN users.id; Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON COLUMN app_public.users.id IS 'Unique identifier for the user.';
--
-- Name: COLUMN users.username; Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON COLUMN app_public.users.username IS 'Public-facing username (or ''handle'') of the user.';
--
-- Name: COLUMN users.name; Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON COLUMN app_public.users.name IS 'Public-facing name (or pseudonym) of the user.';
--
-- Name: COLUMN users.avatar_url; Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON COLUMN app_public.users.avatar_url IS 'Optional avatar URL.';
--
-- Name: COLUMN users.is_admin; Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON COLUMN app_public.users.is_admin IS 'If true, the user has elevated privileges.';
--
-- Name: link_or_register_user(uuid, character varying, character varying, json, json); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.link_or_register_user(f_user_id uuid, f_service character varying, f_identifier character varying, f_profile json, f_auth_details json) RETURNS app_public.users
LANGUAGE plpgsql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
declare
v_matched_user_id uuid;
v_matched_authentication_id uuid;
v_email citext;
v_name text;
v_avatar_url text;
v_user app_public.users;
v_user_email app_public.user_emails;
begin
-- See if a user account already matches these details
select id, user_id
into v_matched_authentication_id, v_matched_user_id
from app_public.user_authentications
where service = f_service
and identifier = f_identifier
limit 1;
if v_matched_user_id is not null and f_user_id is not null and v_matched_user_id <> f_user_id then
raise exception 'A different user already has this account linked.' using errcode = 'TAKEN';
end if;
v_email = f_profile ->> 'email';
v_name := f_profile ->> 'name';
v_avatar_url := f_profile ->> 'avatar_url';
if v_matched_authentication_id is null then
if f_user_id is not null then
-- Link new account to logged in user account
insert into app_public.user_authentications (user_id, service, identifier, details) values
(f_user_id, f_service, f_identifier, f_profile) returning id, user_id into v_matched_authentication_id, v_matched_user_id;
insert into app_private.user_authentication_secrets (user_authentication_id, details) values
(v_matched_authentication_id, f_auth_details);
perform graphile_worker.add_job(
'user__audit',
json_build_object(
'type', 'linked_account',
'user_id', f_user_id,
'extra1', f_service,
'extra2', f_identifier,
'current_user_id', app_public.current_user_id()
));
elsif v_email is not null then
-- See if the email is registered
select * into v_user_email from app_public.user_emails where email = v_email and is_verified is true;
if v_user_email is not null then
-- User exists!
insert into app_public.user_authentications (user_id, service, identifier, details) values
(v_user_email.user_id, f_service, f_identifier, f_profile) returning id, user_id into v_matched_authentication_id, v_matched_user_id;
insert into app_private.user_authentication_secrets (user_authentication_id, details) values
(v_matched_authentication_id, f_auth_details);
perform graphile_worker.add_job(
'user__audit',
json_build_object(
'type', 'linked_account',
'user_id', f_user_id,
'extra1', f_service,
'extra2', f_identifier,
'current_user_id', app_public.current_user_id()
));
end if;
end if;
end if;
if v_matched_user_id is null and f_user_id is null and v_matched_authentication_id is null then
-- Create and return a new user account
return app_private.register_user(f_service, f_identifier, f_profile, f_auth_details, true);
else
if v_matched_authentication_id is not null then
update app_public.user_authentications
set details = f_profile
where id = v_matched_authentication_id;
update app_private.user_authentication_secrets
set details = f_auth_details
where user_authentication_id = v_matched_authentication_id;
update app_public.users
set
name = coalesce(users.name, v_name),
avatar_url = coalesce(users.avatar_url, v_avatar_url)
where id = v_matched_user_id
returning * into v_user;
return v_user;
else
-- v_matched_authentication_id is null
-- -> v_matched_user_id is null (they're paired)
-- -> f_user_id is not null (because the if clause above)
-- -> v_matched_authentication_id is not null (because of the separate if block above creating a user_authentications)
-- -> contradiction.
raise exception 'This should not occur';
end if;
end if;
end;
$$;
--
-- Name: FUNCTION link_or_register_user(f_user_id uuid, f_service character varying, f_identifier character varying, f_profile json, f_auth_details json); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.link_or_register_user(f_user_id uuid, f_service character varying, f_identifier character varying, f_profile json, f_auth_details json) IS 'If you''re logged in, this will link an additional OAuth login to your account if necessary. If you''re logged out it may find if an account already exists (based on OAuth details or email address) and return that, or create a new user account if necessary.';
--
-- Name: sessions; Type: TABLE; Schema: app_private; Owner: -
--
CREATE TABLE app_private.sessions (
uuid uuid DEFAULT gen_random_uuid() NOT NULL,
user_id uuid NOT NULL,
created_at timestamp with time zone DEFAULT now() NOT NULL,
last_active timestamp with time zone DEFAULT now() NOT NULL
);
--
-- Name: login(public.citext, text); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.login(username public.citext, password text) RETURNS app_private.sessions
LANGUAGE plpgsql STRICT
AS $$
declare
v_user app_public.users;
v_user_secret app_private.user_secrets;
v_login_attempt_window_duration interval = interval '5 minutes';
v_session app_private.sessions;
begin
if username like '%@%' then
-- It's an email
select users.* into v_user
from app_public.users
inner join app_public.user_emails
on (user_emails.user_id = users.id)
where user_emails.email = login.username
order by
user_emails.is_verified desc, -- Prefer verified email
user_emails.created_at asc -- Failing that, prefer the first registered (unverified users _should_ verify before logging in)
limit 1;
else
-- It's a username
select users.* into v_user
from app_public.users
where users.username = login.username;
end if;
if not (v_user is null) then
-- Load their secrets
select * into v_user_secret from app_private.user_secrets
where user_secrets.user_id = v_user.id;
-- Have there been too many login attempts?
if (
v_user_secret.first_failed_password_attempt is not null
and
v_user_secret.first_failed_password_attempt > NOW() - v_login_attempt_window_duration
and
v_user_secret.failed_password_attempts >= 3
) then
raise exception 'User account locked - too many login attempts. Try again after 5 minutes.' using errcode = 'LOCKD';
end if;
-- Not too many login attempts, let's check the password.
-- NOTE: `password_hash` could be null, this is fine since `NULL = NULL` is null, and null is falsy.
if v_user_secret.password_hash = crypt(password, v_user_secret.password_hash) then
-- Excellent - they're logged in! Let's reset the attempt tracking
update app_private.user_secrets
set failed_password_attempts = 0, first_failed_password_attempt = null, last_login_at = now()
where user_id = v_user.id;
-- Create a session for the user
insert into app_private.sessions (user_id) values (v_user.id) returning * into v_session;
-- And finally return the session
return v_session;
else
-- Wrong password, bump all the attempt tracking figures
update app_private.user_secrets
set
failed_password_attempts = (case when first_failed_password_attempt is null or first_failed_password_attempt < now() - v_login_attempt_window_duration then 1 else failed_password_attempts + 1 end),
first_failed_password_attempt = (case when first_failed_password_attempt is null or first_failed_password_attempt < now() - v_login_attempt_window_duration then now() else first_failed_password_attempt end)
where user_id = v_user.id;
return null; -- Must not throw otherwise transaction will be aborted and attempts won't be recorded
end if;
else
-- No user with that email/username was found
return null;
end if;
end;
$$;
--
-- Name: FUNCTION login(username public.citext, password text); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.login(username public.citext, password text) IS 'Returns a user that matches the username/password combo, or null on failure.';
--
-- Name: really_create_user(public.citext, text, boolean, text, text, text); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.really_create_user(username public.citext, email text, email_is_verified boolean, name text, avatar_url text, password text DEFAULT NULL::text) RETURNS app_public.users
LANGUAGE plpgsql
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
declare
v_user app_public.users;
v_username citext = username;
begin
if password is not null then
perform app_private.assert_valid_password(password);
end if;
if email is null then
raise exception 'Email is required' using errcode = 'MODAT';
end if;
-- Insert the new user
insert into app_public.users (username, name, avatar_url) values
(v_username, name, avatar_url)
returning * into v_user;
-- Add the user's email
insert into app_public.user_emails (user_id, email, is_verified, is_primary)
values (v_user.id, email, email_is_verified, email_is_verified);
-- Store the password
if password is not null then
update app_private.user_secrets
set password_hash = crypt(password, gen_salt('bf'))
where user_id = v_user.id;
end if;
-- Refresh the user
select * into v_user from app_public.users where id = v_user.id;
return v_user;
end;
$$;
--
-- Name: FUNCTION really_create_user(username public.citext, email text, email_is_verified boolean, name text, avatar_url text, password text); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.really_create_user(username public.citext, email text, email_is_verified boolean, name text, avatar_url text, password text) IS 'Creates a user account. All arguments are optional, it trusts the calling method to perform sanitisation.';
--
-- Name: register_user(character varying, character varying, json, json, boolean); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.register_user(f_service character varying, f_identifier character varying, f_profile json, f_auth_details json, f_email_is_verified boolean DEFAULT false) RETURNS app_public.users
LANGUAGE plpgsql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
declare
v_user app_public.users;
v_email citext;
v_name text;
v_username citext;
v_avatar_url text;
v_user_authentication_id uuid;
begin
-- Extract data from the user’s OAuth profile data.
v_email := f_profile ->> 'email';
v_name := f_profile ->> 'name';
v_username := f_profile ->> 'username';
v_avatar_url := f_profile ->> 'avatar_url';
-- Sanitise the username, and make it unique if necessary.
if v_username is null then
v_username = coalesce(v_name, 'user');
end if;
v_username = regexp_replace(v_username, '^[^a-z]+', '', 'gi');
v_username = regexp_replace(v_username, '[^a-z0-9]+', '_', 'gi');
if v_username is null or length(v_username) < 3 then
v_username = 'user';
end if;
select (
case
when i = 0 then v_username
else v_username || i::text
end
) into v_username from generate_series(0, 1000) i
where not exists(
select 1
from app_public.users
where users.username = (
case
when i = 0 then v_username
else v_username || i::text
end
)
)
limit 1;
-- Create the user account
v_user = app_private.really_create_user(
username => v_username,
email => v_email,
email_is_verified => f_email_is_verified,
name => v_name,
avatar_url => v_avatar_url
);
-- Insert the user’s private account data (e.g. OAuth tokens)
insert into app_public.user_authentications (user_id, service, identifier, details) values
(v_user.id, f_service, f_identifier, f_profile) returning id into v_user_authentication_id;
insert into app_private.user_authentication_secrets (user_authentication_id, details) values
(v_user_authentication_id, f_auth_details);
return v_user;
end;
$$;
--
-- Name: FUNCTION register_user(f_service character varying, f_identifier character varying, f_profile json, f_auth_details json, f_email_is_verified boolean); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.register_user(f_service character varying, f_identifier character varying, f_profile json, f_auth_details json, f_email_is_verified boolean) IS 'Used to register a user from information gleaned from OAuth. Primarily used by link_or_register_user';
--
-- Name: reset_password(uuid, text, text); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.reset_password(user_id uuid, reset_token text, new_password text) RETURNS boolean
LANGUAGE plpgsql STRICT
AS $$
declare
v_user app_public.users;
v_user_secret app_private.user_secrets;
v_token_max_duration interval = interval '3 days';
begin
select users.* into v_user
from app_public.users
where id = user_id;
if not (v_user is null) then
-- Load their secrets
select * into v_user_secret from app_private.user_secrets
where user_secrets.user_id = v_user.id;
-- Have there been too many reset attempts?
if (
v_user_secret.first_failed_reset_password_attempt is not null
and
v_user_secret.first_failed_reset_password_attempt > NOW() - v_token_max_duration
and
v_user_secret.failed_reset_password_attempts >= 20
) then
raise exception 'Password reset locked - too many reset attempts' using errcode = 'LOCKD';
end if;
-- Not too many reset attempts, let's check the token
if v_user_secret.reset_password_token = reset_token then
-- Excellent - they're legit
perform app_private.assert_valid_password(new_password);
-- Let's reset the password as requested
update app_private.user_secrets
set
password_hash = crypt(new_password, gen_salt('bf')),
failed_password_attempts = 0,
first_failed_password_attempt = null,
reset_password_token = null,
reset_password_token_generated = null,
failed_reset_password_attempts = 0,
first_failed_reset_password_attempt = null
where user_secrets.user_id = v_user.id;
-- Revoke the users' sessions
delete from app_private.sessions
where sessions.user_id = v_user.id;
-- Notify user their password was reset
perform graphile_worker.add_job(
'user__audit',
json_build_object(
'type', 'reset_password',
'user_id', v_user.id,
'current_user_id', app_public.current_user_id()
));
return true;
else
-- Wrong token, bump all the attempt tracking figures
update app_private.user_secrets
set
failed_reset_password_attempts = (case when first_failed_reset_password_attempt is null or first_failed_reset_password_attempt < now() - v_token_max_duration then 1 else failed_reset_password_attempts + 1 end),
first_failed_reset_password_attempt = (case when first_failed_reset_password_attempt is null or first_failed_reset_password_attempt < now() - v_token_max_duration then now() else first_failed_reset_password_attempt end)
where user_secrets.user_id = v_user.id;
return null;
end if;
else
-- No user with that id was found
return null;
end if;
end;
$$;
--
-- Name: tg__add_audit_job(); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.tg__add_audit_job() RETURNS trigger
LANGUAGE plpgsql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $_$
declare
v_user_id uuid;
v_type text = TG_ARGV[0];
v_user_id_attribute text = TG_ARGV[1];
v_extra_attribute1 text = TG_ARGV[2];
v_extra_attribute2 text = TG_ARGV[3];
v_extra_attribute3 text = TG_ARGV[4];
v_extra1 text;
v_extra2 text;
v_extra3 text;
begin
if v_user_id_attribute is null then
raise exception 'Invalid tg__add_audit_job call';
end if;
execute 'select ($1.' || quote_ident(v_user_id_attribute) || ')::uuid'
using (case when TG_OP = 'INSERT' then NEW else OLD end)
into v_user_id;
if v_extra_attribute1 is not null then
execute 'select ($1.' || quote_ident(v_extra_attribute1) || ')::text'
using (case when TG_OP = 'DELETE' then OLD else NEW end)
into v_extra1;
end if;
if v_extra_attribute2 is not null then
execute 'select ($1.' || quote_ident(v_extra_attribute2) || ')::text'
using (case when TG_OP = 'DELETE' then OLD else NEW end)
into v_extra2;
end if;
if v_extra_attribute3 is not null then
execute 'select ($1.' || quote_ident(v_extra_attribute3) || ')::text'
using (case when TG_OP = 'DELETE' then OLD else NEW end)
into v_extra3;
end if;
if v_user_id is not null then
perform graphile_worker.add_job(
'user__audit',
json_build_object(
'type', v_type,
'user_id', v_user_id,
'extra1', v_extra1,
'extra2', v_extra2,
'extra3', v_extra3,
'current_user_id', app_public.current_user_id(),
'schema', TG_TABLE_SCHEMA,
'table', TG_TABLE_NAME
));
end if;
return NEW;
end;
$_$;
--
-- Name: FUNCTION tg__add_audit_job(); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.tg__add_audit_job() IS 'For notifying a user that an auditable action has taken place. Call with audit event name, user ID attribute name, and optionally another value to be included (e.g. the PK of the table, or some other relevant information). e.g. `tg__add_audit_job(''added_email'', ''user_id'', ''email'')`';
--
-- Name: tg__add_job(); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.tg__add_job() RETURNS trigger
LANGUAGE plpgsql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
begin
perform graphile_worker.add_job(tg_argv[0], json_build_object('id', NEW.id));
return NEW;
end;
$$;
--
-- Name: FUNCTION tg__add_job(); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.tg__add_job() IS 'Useful shortcut to create a job on insert/update. Pass the task name as the first trigger argument, and optionally the queue name as the second argument. The record id will automatically be available on the JSON payload.';
--
-- Name: tg__timestamps(); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.tg__timestamps() RETURNS trigger
LANGUAGE plpgsql
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
begin
NEW.created_at = (case when TG_OP = 'INSERT' then NOW() else OLD.created_at end);
NEW.updated_at = (case when TG_OP = 'UPDATE' and OLD.updated_at >= NOW() then OLD.updated_at + interval '1 millisecond' else NOW() end);
return NEW;
end;
$$;
--
-- Name: FUNCTION tg__timestamps(); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.tg__timestamps() IS 'This trigger should be called on all tables with created_at, updated_at - it ensures that they cannot be manipulated and that updated_at will always be larger than the previous updated_at.';
--
-- Name: tg_user_email_secrets__insert_with_user_email(); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.tg_user_email_secrets__insert_with_user_email() RETURNS trigger
LANGUAGE plpgsql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
declare
v_verification_token text;
begin
if NEW.is_verified is false then
v_verification_token = encode(gen_random_bytes(7), 'hex');
end if;
insert into app_private.user_email_secrets(user_email_id, verification_token) values(NEW.id, v_verification_token);
return NEW;
end;
$$;
--
-- Name: FUNCTION tg_user_email_secrets__insert_with_user_email(); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.tg_user_email_secrets__insert_with_user_email() IS 'Ensures that every user_email record has an associated user_email_secret record.';
--
-- Name: tg_user_secrets__insert_with_user(); Type: FUNCTION; Schema: app_private; Owner: -
--
CREATE FUNCTION app_private.tg_user_secrets__insert_with_user() RETURNS trigger
LANGUAGE plpgsql
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
begin
insert into app_private.user_secrets(user_id) values(NEW.id);
return NEW;
end;
$$;
--
-- Name: FUNCTION tg_user_secrets__insert_with_user(); Type: COMMENT; Schema: app_private; Owner: -
--
COMMENT ON FUNCTION app_private.tg_user_secrets__insert_with_user() IS 'Ensures that every user record has an associated user_secret record.';
--
-- Name: accept_invitation_to_organization(uuid, text); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.accept_invitation_to_organization(invitation_id uuid, code text DEFAULT NULL::text) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
declare
v_organization app_public.organizations;
begin
v_organization = app_public.organization_for_invitation(invitation_id, code);
-- Accept the user into the organization
insert into app_public.organization_memberships (organization_id, user_id)
values(v_organization.id, app_public.current_user_id())
on conflict do nothing;
-- Delete the invitation
delete from app_public.organization_invitations where id = invitation_id;
end;
$$;
--
-- Name: change_password(text, text); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.change_password(old_password text, new_password text) RETURNS boolean
LANGUAGE plpgsql STRICT SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
declare
v_user app_public.users;
v_user_secret app_private.user_secrets;
begin
select users.* into v_user
from app_public.users
where id = app_public.current_user_id();
if not (v_user is null) then
-- Load their secrets
select * into v_user_secret from app_private.user_secrets
where user_secrets.user_id = v_user.id;
if v_user_secret.password_hash = crypt(old_password, v_user_secret.password_hash) then
perform app_private.assert_valid_password(new_password);
-- Reset the password as requested
update app_private.user_secrets
set
password_hash = crypt(new_password, gen_salt('bf'))
where user_secrets.user_id = v_user.id;
-- Revoke all other sessions
delete from app_private.sessions
where sessions.user_id = v_user.id
and sessions.uuid <> app_public.current_session_id();
-- Notify user their password was changed
perform graphile_worker.add_job(
'user__audit',
json_build_object(
'type', 'change_password',
'user_id', v_user.id,
'current_user_id', app_public.current_user_id()
));
return true;
else
raise exception 'Incorrect password' using errcode = 'CREDS';
end if;
else
raise exception 'You must log in to change your password' using errcode = 'LOGIN';
end if;
end;
$$;
--
-- Name: FUNCTION change_password(old_password text, new_password text); Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON FUNCTION app_public.change_password(old_password text, new_password text) IS 'Enter your old password and a new password to change your password.';
--
-- Name: confirm_account_deletion(text); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.confirm_account_deletion(token text) RETURNS boolean
LANGUAGE plpgsql STRICT SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
declare
v_user_secret app_private.user_secrets;
v_token_max_duration interval = interval '3 days';
begin
if app_public.current_user_id() is null then
raise exception 'You must log in to delete your account' using errcode = 'LOGIN';
end if;
select * into v_user_secret
from app_private.user_secrets
where user_secrets.user_id = app_public.current_user_id();
if v_user_secret is null then
-- Success: they're already deleted
return true;
end if;
-- Check the token
if (
-- token is still valid
v_user_secret.delete_account_token_generated > now() - v_token_max_duration
and
-- token matches
v_user_secret.delete_account_token = token
) then
-- Token passes; delete their account :(
delete from app_public.users where id = app_public.current_user_id();
return true;
end if;
raise exception 'The supplied token was incorrect - perhaps you''re logged in to the wrong account, or the token has expired?' using errcode = 'DNIED';
end;
$$;
--
-- Name: FUNCTION confirm_account_deletion(token text); Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON FUNCTION app_public.confirm_account_deletion(token text) IS 'If you''re certain you want to delete your account, use `requestAccountDeletion` to request an account deletion token, and then supply the token through this mutation to complete account deletion.';
--
-- Name: organizations; Type: TABLE; Schema: app_public; Owner: -
--
CREATE TABLE app_public.organizations (
id uuid DEFAULT gen_random_uuid() NOT NULL,
slug public.citext NOT NULL,
name text NOT NULL,
created_at timestamp with time zone DEFAULT now() NOT NULL
);
--
-- Name: create_organization(public.citext, text); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.create_organization(slug public.citext, name text) RETURNS app_public.organizations
LANGUAGE plpgsql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
declare
v_org app_public.organizations;
begin
if app_public.current_user_id() is null then
raise exception 'You must log in to create an organization' using errcode = 'LOGIN';
end if;
insert into app_public.organizations (slug, name) values (slug, name) returning * into v_org;
insert into app_public.organization_memberships (organization_id, user_id, is_owner, is_billing_contact)
values(v_org.id, app_public.current_user_id(), true, true);
return v_org;
end;
$$;
--
-- Name: current_session_id(); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.current_session_id() RETURNS uuid
LANGUAGE sql STABLE
AS $$
select nullif(pg_catalog.current_setting('jwt.claims.session_id', true), '')::uuid;
$$;
--
-- Name: FUNCTION current_session_id(); Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON FUNCTION app_public.current_session_id() IS 'Handy method to get the current session ID.';
--
-- Name: current_user(); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public."current_user"() RETURNS app_public.users
LANGUAGE sql STABLE
AS $$
select users.* from app_public.users where id = app_public.current_user_id();
$$;
--
-- Name: FUNCTION "current_user"(); Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON FUNCTION app_public."current_user"() IS 'The currently logged in user (or null if not logged in).';
--
-- Name: current_user_id(); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.current_user_id() RETURNS uuid
LANGUAGE sql STABLE SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
select user_id from app_private.sessions where uuid = app_public.current_session_id();
$$;
--
-- Name: FUNCTION current_user_id(); Type: COMMENT; Schema: app_public; Owner: -
--
COMMENT ON FUNCTION app_public.current_user_id() IS 'Handy method to get the current user ID for use in RLS policies, etc; in GraphQL, use `currentUser{id}` instead.';
--
-- Name: current_user_invited_organization_ids(); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.current_user_invited_organization_ids() RETURNS SETOF uuid
LANGUAGE sql STABLE SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
select organization_id from app_public.organization_invitations
where user_id = app_public.current_user_id();
$$;
--
-- Name: current_user_member_organization_ids(); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.current_user_member_organization_ids() RETURNS SETOF uuid
LANGUAGE sql STABLE SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
select organization_id from app_public.organization_memberships
where user_id = app_public.current_user_id();
$$;
--
-- Name: delete_organization(uuid); Type: FUNCTION; Schema: app_public; Owner: -
--
CREATE FUNCTION app_public.delete_organization(organization_id uuid) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'public', 'pg_temp'
AS $$
begin
if exists(
select 1
from app_public.organization_memberships
where user_id = app_public.current_user_id()
and organization_memberships.organization_id = delete_organization.organization_id
and is_owner is true