This repository has been archived by the owner on Feb 8, 2018. It is now read-only.
-
Notifications
You must be signed in to change notification settings - Fork 308
/
schema.sql
2441 lines (1739 loc) · 58.1 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 9.6.2
-- Dumped by pg_dump version 9.6.2
SET statement_timeout = 0;
SET lock_timeout = 0;
SET idle_in_transaction_session_timeout = 0;
SET client_encoding = 'UTF8';
SET standard_conforming_strings = on;
SET check_function_bodies = false;
SET client_min_messages = warning;
SET row_security = off;
--
-- Name: plpgsql; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
--
-- Name: EXTENSION plpgsql; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
--
-- Name: pg_stat_statements; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS pg_stat_statements WITH SCHEMA public;
--
-- Name: EXTENSION pg_stat_statements; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION pg_stat_statements IS 'track execution statistics of all SQL statements executed';
--
-- Name: pg_trgm; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS pg_trgm WITH SCHEMA public;
--
-- Name: EXTENSION pg_trgm; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION pg_trgm IS 'text similarity measurement and index searching based on trigrams';
SET search_path = public, pg_catalog;
--
-- Name: context_type; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE context_type AS ENUM (
'tip',
'take',
'final-gift',
'take-over',
'one-off'
);
--
-- Name: status_of_1_0_payout; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE status_of_1_0_payout AS ENUM (
'too-little',
'pending-application',
'pending-review',
'rejected',
'pending-payout',
'completed'
);
SET default_tablespace = '';
SET default_with_oids = false;
--
-- Name: participants; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE participants (
username text NOT NULL,
session_token text,
session_expires timestamp with time zone DEFAULT (now() + '06:00:00'::interval),
ctime timestamp with time zone DEFAULT now() NOT NULL,
claimed_time timestamp with time zone,
is_admin boolean DEFAULT false NOT NULL,
balance numeric(35,2) DEFAULT 0.0 NOT NULL,
anonymous_giving boolean DEFAULT false NOT NULL,
balanced_customer_href text,
is_suspicious boolean,
id bigint NOT NULL,
username_lower text NOT NULL,
api_key text,
avatar_url text,
is_closed boolean DEFAULT false NOT NULL,
giving numeric(35,2) DEFAULT 0 NOT NULL,
taking numeric(35,2) DEFAULT 0 NOT NULL,
is_free_rider boolean,
email_address text,
email_lang text,
is_searchable boolean DEFAULT true NOT NULL,
old_auth_usage date,
notifications text[] DEFAULT '{}'::text[] NOT NULL,
notify_charge integer DEFAULT 3,
braintree_customer_id text,
ngiving_to integer DEFAULT 0 NOT NULL,
ntaking_from integer DEFAULT 0 NOT NULL,
status_of_1_0_payout status_of_1_0_payout DEFAULT 'completed'::status_of_1_0_payout NOT NULL,
has_verified_identity boolean DEFAULT false NOT NULL,
is_owner boolean DEFAULT false NOT NULL
);
--
-- Name: elsewhere_with_participant; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE elsewhere_with_participant AS (
id integer,
platform text,
user_id text,
user_name text,
display_name text,
email text,
avatar_url text,
is_team boolean,
extra_info json,
token json,
connect_token text,
connect_expires timestamp with time zone,
participant participants
);
--
-- Name: exchange_status; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE exchange_status AS ENUM (
'pre',
'pending',
'failed',
'succeeded',
'unknown'
);
--
-- Name: follow_up; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE follow_up AS ENUM (
'monthly',
'quarterly',
'yearly',
'never'
);
--
-- Name: participant_number; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE participant_number AS ENUM (
'singular',
'plural'
);
--
-- Name: payment_direction; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE payment_direction AS ENUM (
'to-team',
'to-participant'
);
--
-- Name: payment_net; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE payment_net AS ENUM (
'balanced-ba',
'balanced-cc',
'paypal',
'bitcoin',
'braintree-cc',
'cash',
'transferwise',
'dwolla',
'unknown'
);
--
-- Name: status_of_1_0_balance; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE status_of_1_0_balance AS ENUM (
'unresolved',
'pending-payout',
'resolved'
);
--
-- Name: supported_image_types; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE supported_image_types AS ENUM (
'image/png',
'image/jpeg'
);
--
-- Name: complete_1_0_payout(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION complete_1_0_payout() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE participants
SET status_of_1_0_payout='completed'
WHERE id = NEW.id;
RETURN NULL;
END;
$$;
--
-- Name: paydays; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE paydays (
id integer NOT NULL,
ts_start timestamp with time zone DEFAULT now() NOT NULL,
ts_end timestamp with time zone DEFAULT '1970-01-01 00:00:00+00'::timestamp with time zone NOT NULL,
volume numeric(35,2) DEFAULT 0.00 NOT NULL,
nusers bigint DEFAULT 0 NOT NULL,
stage integer DEFAULT 0,
nteams integer DEFAULT 0 NOT NULL
);
--
-- Name: current_payday(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION current_payday() RETURNS paydays
LANGUAGE sql
AS $$
SELECT *
FROM paydays
WHERE ts_end='1970-01-01T00:00:00+00'::timestamptz;
$$;
--
-- Name: current_payday_id(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION current_payday_id() RETURNS integer
LANGUAGE sql
AS $$
-- This is a function so we can use it in DEFAULTS for a column.
SELECT id FROM current_payday();
$$;
--
-- Name: enumerate(anyarray); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION enumerate(anyarray) RETURNS TABLE(rank bigint, value anyelement)
LANGUAGE sql STABLE
AS $_$
SELECT row_number() over() as rank, value FROM unnest($1) value;
$_$;
--
-- Name: fail_if_no_email(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION fail_if_no_email() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
IF (SELECT email_address FROM participants WHERE id=NEW.participant_id) IS NULL THEN
RAISE EXCEPTION
USING ERRCODE=23100
, MESSAGE='This operation requires a verified participant email address.';
END IF;
RETURN NEW;
END;
$$;
--
-- Name: elsewhere; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE elsewhere (
id integer NOT NULL,
platform text NOT NULL,
user_id text NOT NULL,
participant text NOT NULL,
user_name text,
display_name text,
email text,
avatar_url text,
is_team boolean DEFAULT false NOT NULL,
extra_info json,
token json,
connect_token text,
connect_expires timestamp with time zone
);
--
-- Name: load_participant_for_elsewhere(elsewhere); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION load_participant_for_elsewhere(elsewhere) RETURNS elsewhere_with_participant
LANGUAGE sql
AS $_$
SELECT $1.id
, $1.platform
, $1.user_id
, $1.user_name
, $1.display_name
, $1.email
, $1.avatar_url
, $1.is_team
, $1.extra_info
, $1.token
, $1.connect_token
, $1.connect_expires
, participants.*::participants
FROM participants
WHERE participants.username = $1.participant;
$_$;
--
-- Name: park(bigint, bigint, numeric); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION park(bigint, bigint, numeric) RETURNS void
LANGUAGE plpgsql
AS $_$
DECLARE payload json;
BEGIN
IF ($3 = 0) THEN RETURN; END IF;
UPDATE current_payment_instructions
SET due = $3
WHERE participant_id = $1
AND team_id = $2;
payload = '{"action":"due","participant_id":"' || $1 || '", "team_id":"'
|| $2 || '", "due":' || $3 || '}';
INSERT INTO events(type, payload)
VALUES ('payday',payload);
END;
$_$;
--
-- Name: pay(bigint, bigint, numeric, payment_direction); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION pay(bigint, bigint, numeric, payment_direction) RETURNS void
LANGUAGE plpgsql
AS $_$
DECLARE
participant_delta numeric;
team_delta numeric;
payload json;
BEGIN
IF ($3 = 0) THEN RETURN; END IF;
IF ($4 = 'to-team') THEN
participant_delta := -$3;
team_delta := $3;
ELSE
participant_delta := $3;
team_delta := -$3;
END IF;
UPDATE payday_participants
SET new_balance = (new_balance + participant_delta)
WHERE id = $1;
UPDATE payday_teams
SET balance = (balance + team_delta)
WHERE id = $2;
UPDATE current_payment_instructions
SET due = 0
WHERE participant_id = $1
AND team_id = $2
AND due > 0;
IF ($4 = 'to-team') THEN
payload = '{"action":"pay","participant_id":"' || $1 || '", "team_id":"'
|| $2 || '", "amount":' || $3 || '}';
INSERT INTO events(type, payload)
VALUES ('payday',payload);
END IF;
INSERT INTO payday_payments
(participant, team, amount, direction)
VALUES ( ( SELECT p.username
FROM participants p
JOIN payday_participants p2 ON p.id = p2.id
WHERE p2.id = $1 )
, ( SELECT t.slug
FROM teams t
JOIN payday_teams t2 ON t.id = t2.id
WHERE t2.id = $2 )
, $3
, $4
);
END;
$_$;
--
-- Name: process_draw(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION process_draw() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE pay( (SELECT id FROM participants WHERE username=NEW.owner)
, NEW.id
, NEW.balance
, 'to-participant'
);
RETURN NULL;
END;
$$;
--
-- Name: process_payment_instruction(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION process_payment_instruction() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
participant payday_participants;
BEGIN
participant := (
SELECT p.*::payday_participants
FROM payday_participants p
WHERE id = NEW.participant_id
);
IF (NEW.amount + NEW.due <= participant.new_balance OR participant.card_hold_ok) THEN
EXECUTE pay(NEW.participant_id, NEW.team_id, NEW.amount + NEW.due, 'to-team');
RETURN NEW;
ELSIF participant.has_credit_card THEN
EXECUTE park(NEW.participant_id, NEW.team_id, NEW.amount + NEW.due);
RETURN NULL;
END IF;
RETURN NULL;
END;
$$;
--
-- Name: process_take(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION process_take() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
amount numeric(35,2);
available_today_ numeric(35,2);
BEGIN
amount := NEW.amount;
available_today_ := (SELECT available_today FROM payday_teams WHERE id = NEW.team_id);
IF amount > available_today_ THEN
amount := available_today_;
END IF;
IF amount > 0 THEN
UPDATE payday_teams
SET available_today = (available_today - amount)
WHERE id = NEW.team_id;
EXECUTE pay(NEW.participant_id, NEW.team_id, amount, 'to-participant');
END IF;
RETURN NULL;
END;
$$;
--
-- Name: update_payment_instruction(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION update_payment_instruction() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE payment_instructions
SET is_funded = NEW.is_funded
, due = NEW.due
WHERE id = NEW.id;
RETURN NULL;
END;
$$;
--
-- Name: update_tip(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION update_tip() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE tips
SET is_funded = NEW.is_funded
WHERE id = NEW.id;
RETURN NULL;
END;
$$;
--
-- Name: upsert_community(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION upsert_community() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
is_member boolean;
delta int = CASE WHEN NEW.is_member THEN 1 ELSE -1 END;
BEGIN
IF (SELECT is_suspicious FROM participants WHERE id = NEW.participant) THEN
RETURN NULL;
END IF;
is_member := (
SELECT cur.is_member
FROM community_members cur
WHERE slug = NEW.slug
AND participant = NEW.participant
ORDER BY mtime DESC
LIMIT 1
);
IF (is_member IS NULL AND NEW.is_member IS false OR NEW.is_member = is_member) THEN
RETURN NULL;
END IF;
LOOP
UPDATE communities
SET nmembers = nmembers + delta
WHERE slug = NEW.slug
AND nmembers + delta > 0;
EXIT WHEN FOUND;
IF (NEW.is_member) THEN
BEGIN
INSERT INTO communities
VALUES (NEW.slug, NEW.name, 1, NEW.ctime);
EXCEPTION
WHEN unique_violation THEN
IF (CONSTRAINT_NAME = 'communities_slug_pkey') THEN
CONTINUE; -- Try again
ELSE
RAISE;
END IF;
END;
EXIT;
ELSE
DELETE FROM communities WHERE slug = NEW.slug AND nmembers = 1;
EXIT WHEN FOUND;
END IF;
END LOOP;
RETURN NEW;
END;
$$;
--
-- Name: exchange_routes; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE exchange_routes (
id integer NOT NULL,
participant bigint NOT NULL,
network payment_net NOT NULL,
address text NOT NULL,
error text NOT NULL,
fee_cap numeric(35,2),
is_deleted boolean DEFAULT false NOT NULL,
CONSTRAINT exchange_routes_address_check CHECK ((address <> ''::text))
);
--
-- Name: current_exchange_routes; Type: VIEW; Schema: public; Owner: -
--
CREATE VIEW current_exchange_routes AS
SELECT DISTINCT ON (exchange_routes.participant, exchange_routes.network) exchange_routes.id,
exchange_routes.participant,
exchange_routes.network,
exchange_routes.address,
exchange_routes.error,
exchange_routes.fee_cap,
exchange_routes.is_deleted
FROM exchange_routes
WHERE (NOT exchange_routes.is_deleted)
ORDER BY exchange_routes.participant, exchange_routes.network, exchange_routes.id DESC;
SET search_path = pg_catalog;
--
-- Name: CAST (public.current_exchange_routes AS public.exchange_routes); Type: CAST; Schema: pg_catalog; Owner: -
--
CREATE CAST (public.current_exchange_routes AS public.exchange_routes) WITH INOUT;
--
-- Name: CAST (public.elsewhere AS public.elsewhere_with_participant); Type: CAST; Schema: pg_catalog; Owner: -
--
CREATE CAST (public.elsewhere AS public.elsewhere_with_participant) WITH FUNCTION public.load_participant_for_elsewhere(public.elsewhere);
SET search_path = public, pg_catalog;
--
-- Name: absorptions; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE absorptions (
id integer NOT NULL,
"timestamp" timestamp with time zone DEFAULT now() NOT NULL,
absorbed_was text NOT NULL,
absorbed_by text NOT NULL,
archived_as text NOT NULL
);
--
-- Name: absorptions_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE absorptions_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: absorptions_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE absorptions_id_seq OWNED BY absorptions.id;
--
-- Name: balances_at; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE balances_at (
participant bigint NOT NULL,
at timestamp with time zone NOT NULL,
balance numeric(35,2) NOT NULL
);
--
-- Name: claims; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE claims (
nonce text NOT NULL,
package_id bigint NOT NULL
);
--
-- Name: communities; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE communities (
slug text NOT NULL,
name text NOT NULL,
nmembers integer NOT NULL,
ctime timestamp with time zone NOT NULL,
CONSTRAINT communities_nmembers_check CHECK ((nmembers > 0))
);
--
-- Name: community_members; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE community_members (
slug text NOT NULL,
participant bigint NOT NULL,
ctime timestamp with time zone NOT NULL,
mtime timestamp with time zone DEFAULT now() NOT NULL,
name text NOT NULL,
is_member boolean NOT NULL
);
--
-- Name: countries; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE countries (
id bigint NOT NULL,
code text NOT NULL
);
--
-- Name: countries_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE countries_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: countries_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE countries_id_seq OWNED BY countries.id;
--
-- Name: current_community_members; Type: VIEW; Schema: public; Owner: -
--
CREATE VIEW current_community_members AS
SELECT DISTINCT ON (c.participant, c.slug) c.slug,
c.participant,
c.ctime,
c.mtime,
c.name,
c.is_member
FROM community_members c
ORDER BY c.participant, c.slug, c.mtime DESC;
--
-- Name: payment_instructions; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE payment_instructions (
id integer NOT NULL,
ctime timestamp with time zone NOT NULL,
mtime timestamp with time zone DEFAULT now() NOT NULL,
amount numeric(35,2) NOT NULL,
is_funded boolean DEFAULT false NOT NULL,
due numeric(35,2) DEFAULT 0,
participant_id bigint NOT NULL,
team_id bigint NOT NULL
);
--
-- Name: current_payment_instructions; Type: VIEW; Schema: public; Owner: -
--
CREATE VIEW current_payment_instructions AS
SELECT DISTINCT ON (payment_instructions.participant_id, payment_instructions.team_id) payment_instructions.id,
payment_instructions.ctime,
payment_instructions.mtime,
payment_instructions.amount,
payment_instructions.is_funded,
payment_instructions.due,
payment_instructions.participant_id,
payment_instructions.team_id
FROM payment_instructions
ORDER BY payment_instructions.participant_id, payment_instructions.team_id, payment_instructions.mtime DESC;
--
-- Name: takes; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE takes (
id bigint NOT NULL,
ctime timestamp with time zone NOT NULL,
mtime timestamp with time zone DEFAULT now() NOT NULL,
participant_id bigint NOT NULL,
team_id bigint NOT NULL,
amount numeric(35,2) NOT NULL,
recorder_id bigint NOT NULL,
CONSTRAINT not_negative CHECK ((amount >= (0)::numeric))
);
--
-- Name: current_takes; Type: VIEW; Schema: public; Owner: -
--
CREATE VIEW current_takes AS
SELECT anon.id,
anon.ctime,
anon.mtime,
anon.participant_id,
anon.team_id,
anon.amount,
anon.recorder_id
FROM ( SELECT DISTINCT ON (t.participant_id, t.team_id) t.id,
t.ctime,
t.mtime,
t.participant_id,
t.team_id,
t.amount,
t.recorder_id
FROM (takes t
JOIN participants p ON ((p.id = t.participant_id)))
WHERE (p.is_suspicious IS NOT TRUE)
ORDER BY t.participant_id, t.team_id, t.mtime DESC) anon
WHERE (anon.amount > (0)::numeric);
--
-- Name: tips; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE tips (
id integer NOT NULL,
ctime timestamp with time zone NOT NULL,
mtime timestamp with time zone DEFAULT now() NOT NULL,
tipper text NOT NULL,
tippee text NOT NULL,
amount numeric(35,2) NOT NULL,
is_funded boolean DEFAULT false NOT NULL
);
--
-- Name: current_tips; Type: VIEW; Schema: public; Owner: -
--
CREATE VIEW current_tips AS
SELECT DISTINCT ON (tips.tipper, tips.tippee) tips.id,
tips.ctime,
tips.mtime,
tips.tipper,
tips.tippee,
tips.amount,
tips.is_funded
FROM tips
ORDER BY tips.tipper, tips.tippee, tips.mtime DESC;
--
-- Name: elsewhere_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE elsewhere_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: elsewhere_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE elsewhere_id_seq OWNED BY elsewhere.id;
--
-- Name: email_addresses; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE email_addresses (
id integer NOT NULL,
address text NOT NULL,
verified boolean,
nonce text,
verification_start timestamp with time zone DEFAULT now() NOT NULL,
verification_end timestamp with time zone,
participant_id bigint NOT NULL,
CONSTRAINT verified_cant_be_false CHECK ((verified IS NOT FALSE))
);
--
-- Name: email_messages; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE email_messages (
id integer NOT NULL,
participant bigint,
spt_name text NOT NULL,
context bytea NOT NULL,
user_initiated boolean DEFAULT true NOT NULL,
ctime timestamp with time zone DEFAULT now() NOT NULL,
result text,
remote_message_id text,
email_address text,
CONSTRAINT email_or_participant_required CHECK (((participant IS NOT NULL) OR (email_address IS NOT NULL)))
);
--
-- Name: email_queue_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE email_queue_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: email_queue_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE email_queue_id_seq OWNED BY email_messages.id;
--
-- Name: emails_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE emails_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: emails_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE emails_id_seq OWNED BY email_addresses.id;
--
-- Name: events; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE events (
id integer NOT NULL,
ts timestamp without time zone DEFAULT now() NOT NULL,
type text NOT NULL,
payload json
);
--
-- Name: events_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE events_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE