summaryrefslogtreecommitdiff
path: root/src/exchangedb/exchange-0001-part.sql
blob: 54b7112f9513e21bb9770fbdd46743b0def65c09 (plain)
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
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
--
-- This file is part of TALER
-- Copyright (C) 2014--2022 Taler Systems SA
--
-- TALER is free software; you can redistribute it and/or modify it under the
-- terms of the GNU General Public License as published by the Free Software
-- Foundation; either version 3, or (at your option) any later version.
--
-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR
-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
--
-- You should have received a copy of the GNU General Public License along with
-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
--

-- ------------------------------ denominations ----------------------------------------

CREATE TABLE IF NOT EXISTS denominations
  (denominations_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,denom_pub_hash BYTEA PRIMARY KEY CHECK (LENGTH(denom_pub_hash)=64)
  ,denom_type INT4 NOT NULL DEFAULT (1) -- 1 == RSA (for now, remove default later!)
  ,age_mask INT4 NOT NULL DEFAULT (0)
  ,denom_pub BYTEA NOT NULL
  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
  ,valid_from INT8 NOT NULL
  ,expire_withdraw INT8 NOT NULL
  ,expire_deposit INT8 NOT NULL
  ,expire_legal INT8 NOT NULL
  ,coin_val INT8 NOT NULL
  ,coin_frac INT4 NOT NULL
  ,fee_withdraw_val INT8 NOT NULL
  ,fee_withdraw_frac INT4 NOT NULL
  ,fee_deposit_val INT8 NOT NULL
  ,fee_deposit_frac INT4 NOT NULL
  ,fee_refresh_val INT8 NOT NULL
  ,fee_refresh_frac INT4 NOT NULL
  ,fee_refund_val INT8 NOT NULL
  ,fee_refund_frac INT4 NOT NULL
  );
COMMENT ON TABLE denominations
  IS 'Main denominations table. All the valid denominations the exchange knows about.';
COMMENT ON COLUMN denominations.denom_type
  IS 'determines cipher type for blind signatures used with this denomination; 0 is for RSA';
COMMENT ON COLUMN denominations.age_mask
  IS 'bitmask with the age restrictions that are being used for this denomination; 0 if denomination does not support the use of age restrictions';
COMMENT ON COLUMN denominations.denominations_serial
  IS 'needed for exchange-auditor replication logic';

CREATE INDEX IF NOT EXISTS denominations_by_expire_legal_index
  ON denominations
  (expire_legal);


-- ------------------------------ denomination_revocations ----------------------------------------

CREATE TABLE IF NOT EXISTS denomination_revocations
  (denom_revocations_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,denominations_serial INT8 PRIMARY KEY REFERENCES denominations (denominations_serial) ON DELETE CASCADE
  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
  );
COMMENT ON TABLE denomination_revocations
  IS 'remembering which denomination keys have been revoked';


-- ------------------------------ profit drains ----------------------------------------

CREATE TABLE IF NOT EXISTS profit_drains
  (profit_drain_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,wtid BYTEA PRIMARY KEY CHECK (LENGTH(wtid)=32)
  ,account_section VARCHAR NOT NULL
  ,payto_uri VARCHAR NOT NULL
  ,trigger_date INT8 NOT NULL
  ,amount_val INT8 NOT NULL
  ,amount_frac INT8 NOT NULL
  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
  ,executed BOOLEAN NOT NULL DEFAULT FALSE
  );
COMMENT ON TABLE profit_drains
  IS 'transactions to be performed to move profits from the escrow account of the exchange to a regular account';
COMMENT ON COLUMN profit_drains.wtid
  IS 'randomly chosen nonce, unique to prevent double-submission';
COMMENT ON COLUMN profit_drains.account_section
  IS 'specifies the configuration section in the taler-exchange-drain configuration with the wire account to drain';
COMMENT ON COLUMN profit_drains.payto_uri
  IS 'specifies the account to be credited';
COMMENT ON COLUMN profit_drains.trigger_date
  IS 'set by taler-exchange-offline at the time of making the signature; not necessarily the exact date of execution of the wire transfer, just for orientation';
COMMENT ON COLUMN profit_drains.amount_val
  IS 'amount to be transferred';
COMMENT ON COLUMN profit_drains.master_sig
  IS 'EdDSA signature of type TALER_SIGNATURE_MASTER_DRAIN_PROFIT';
COMMENT ON COLUMN profit_drains.executed
  IS 'set to TRUE by taler-exchange-drain on execution of the transaction, not replicated to auditor';


-- ------------------------------ wire_targets ----------------------------------------

SELECT create_table_wire_targets();

COMMENT ON TABLE wire_targets
  IS 'All senders and recipients of money via the exchange';
COMMENT ON COLUMN wire_targets.payto_uri
  IS 'Can be a regular bank account, or also be a URI identifying a reserve-account (for P2P payments)';
COMMENT ON COLUMN wire_targets.wire_target_h_payto
  IS 'Unsalted hash of payto_uri';
-- FIXME: remove:
COMMENT ON COLUMN wire_targets.kyc_ok
  IS 'true if the KYC check was passed successfully';
-- FIXME: remove:
COMMENT ON COLUMN wire_targets.external_id
  IS 'Name of the user that was used for OAuth 2.0-based legitimization';

CREATE TABLE IF NOT EXISTS wire_targets_default
  PARTITION OF wire_targets
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_wire_targets_partition('default');


-- ------------------------------ legitimizations ----------------------------------------

SELECT create_table_legitimizations();

COMMENT ON TABLE legitimizations
  IS 'List of legitimizations (required and completed) by account and provider';
COMMENT ON COLUMN legitimizations.legitimization_serial_id
  IS 'unique ID for this legitimization process at the exchange';
COMMENT ON COLUMN legitimizations.h_payto
  IS 'foreign key linking the entry to the wire_targets table, NOT a primary key (multiple legitimizations are possible per wire target)';
COMMENT ON COLUMN legitimizations.expiration_time
  IS 'in the future if the respective KYC check was passed successfully';
COMMENT ON COLUMN legitimizations.provider_section
  IS 'Configuration file section with details about this provider';
COMMENT ON COLUMN legitimizations.provider_user_id
  IS 'Identifier for the user at the provider that was used for the legitimization. NULL if provider is unaware.';
COMMENT ON COLUMN legitimizations.provider_legitimization_id
  IS 'Identifier for the specific legitimization process at the provider. NULL if legitimization was not started.';

CREATE TABLE IF NOT EXISTS legitimizations_default
  PARTITION OF legitimizations
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_legitimizations_partition('default');



-- ------------------------------ reserves ----------------------------------------

SELECT create_table_reserves();

COMMENT ON TABLE reserves
  IS 'Summarizes the balance of a reserve. Updated when new funds are added or withdrawn.';
COMMENT ON COLUMN reserves.reserve_pub
  IS 'EdDSA public key of the reserve. Knowledge of the private key implies ownership over the balance.';
COMMENT ON COLUMN reserves.current_balance_val
  IS 'Current balance remaining with the reserve.';
COMMENT ON COLUMN reserves.purses_active
  IS 'Number of purses that were created by this reserve that are not expired and not fully paid.';
COMMENT ON COLUMN reserves.purses_allowed
  IS 'Number of purses that this reserve is allowed to have active at most.';
COMMENT ON COLUMN reserves.kyc_required
  IS 'True if a KYC check must have been passed before withdrawing from this reserve. Set to true once a reserve received a P2P payment.';
COMMENT ON COLUMN reserves.kyc_passed
  IS 'True once KYC was passed for this reserve. The KYC details are then available via the wire_targets table under the key of wire_target_h_payto which is to be derived from the reserve_pub and the base URL of this exchange.';
COMMENT ON COLUMN reserves.expiration_date
  IS 'Used to trigger closing of reserves that have not been drained after some time';
COMMENT ON COLUMN reserves.gc_date
  IS 'Used to forget all information about a reserve during garbage collection';

CREATE TABLE IF NOT EXISTS reserves_default
  PARTITION OF reserves
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

-- ------------------------------ reserves_in ----------------------------------------

SELECT create_table_reserves_in();

COMMENT ON TABLE reserves_in
  IS 'list of transfers of funds into the reserves, one per incoming wire transfer';
COMMENT ON COLUMN reserves_in.wire_source_h_payto
  IS 'Identifies the debited bank account and KYC status';
COMMENT ON COLUMN reserves_in.reserve_pub
  IS 'Public key of the reserve. Private key signifies ownership of the remaining balance.';
COMMENT ON COLUMN reserves_in.credit_val
  IS 'Amount that was transferred into the reserve';

CREATE TABLE IF NOT EXISTS reserves_in_default
  PARTITION OF reserves_in
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_reserves_in_partition('default');

-- ------------------------------ reserves_close ----------------------------------------

SELECT create_table_reserves_close();

COMMENT ON TABLE reserves_close
  IS 'wire transfers executed by the reserve to close reserves';
COMMENT ON COLUMN reserves_close.wire_target_h_payto
  IS 'Identifies the credited bank account (and KYC status). Note that closing does not depend on KYC.';

CREATE TABLE IF NOT EXISTS reserves_close_default
  PARTITION OF reserves_close
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_reserves_close_partition('default');


-- ------------------------------ reserves_out ----------------------------------------

SELECT create_table_reserves_out();

COMMENT ON TABLE reserves_out
  IS 'Withdraw operations performed on reserves.';
COMMENT ON COLUMN reserves_out.h_blind_ev
  IS 'Hash of the blinded coin, used as primary key here so that broken clients that use a non-random coin or blinding factor fail to withdraw (otherwise they would fail on deposit when the coin is not unique there).';
COMMENT ON COLUMN reserves_out.denominations_serial
  IS 'We do not CASCADE ON DELETE here, we may keep the denomination data alive';

CREATE TABLE IF NOT EXISTS reserves_out_default
  PARTITION OF reserves_out
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_reserves_out_partition('default');


SELECT create_table_reserves_out_by_reserve();

COMMENT ON TABLE reserves_out_by_reserve
  IS 'Information in this table is strictly redundant with that of reserves_out, but saved by a different primary key for fast lookups by reserve public key/uuid.';

CREATE TABLE IF NOT EXISTS reserves_out_by_reserve_default
  PARTITION OF reserves_out_by_reserve
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

CREATE OR REPLACE FUNCTION reserves_out_by_reserve_insert_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  INSERT INTO exchange.reserves_out_by_reserve
    (reserve_uuid
    ,h_blind_ev)
  VALUES
    (NEW.reserve_uuid
    ,NEW.h_blind_ev);
  RETURN NEW;
END $$;
COMMENT ON FUNCTION reserves_out_by_reserve_insert_trigger()
  IS 'Replicate reserve_out inserts into reserve_out_by_reserve table.';

CREATE TRIGGER reserves_out_on_insert
  AFTER INSERT
   ON reserves_out
   FOR EACH ROW EXECUTE FUNCTION reserves_out_by_reserve_insert_trigger();

CREATE OR REPLACE FUNCTION reserves_out_by_reserve_delete_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  DELETE FROM exchange.reserves_out_by_reserve
   WHERE reserve_uuid = OLD.reserve_uuid;
  RETURN OLD;
END $$;
COMMENT ON FUNCTION reserves_out_by_reserve_delete_trigger()
  IS 'Replicate reserve_out deletions into reserve_out_by_reserve table.';

CREATE TRIGGER reserves_out_on_delete
  AFTER DELETE
    ON reserves_out
   FOR EACH ROW EXECUTE FUNCTION reserves_out_by_reserve_delete_trigger();


-- ------------------------------ auditors ----------------------------------------

CREATE TABLE IF NOT EXISTS auditors
  (auditor_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,auditor_pub BYTEA PRIMARY KEY CHECK (LENGTH(auditor_pub)=32)
  ,auditor_name VARCHAR NOT NULL
  ,auditor_url VARCHAR NOT NULL
  ,is_active BOOLEAN NOT NULL
  ,last_change INT8 NOT NULL
  );
COMMENT ON TABLE auditors
  IS 'Table with auditors the exchange uses or has used in the past. Entries never expire as we need to remember the last_change column indefinitely.';
COMMENT ON COLUMN auditors.auditor_pub
  IS 'Public key of the auditor.';
COMMENT ON COLUMN auditors.auditor_url
  IS 'The base URL of the auditor.';
COMMENT ON COLUMN auditors.is_active
  IS 'true if we are currently supporting the use of this auditor.';
COMMENT ON COLUMN auditors.last_change
  IS 'Latest time when active status changed. Used to detect replays of old messages.';


-- ------------------------------ auditor_denom_sigs ----------------------------------------

CREATE TABLE IF NOT EXISTS auditor_denom_sigs
  (auditor_denom_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,auditor_uuid INT8 NOT NULL REFERENCES auditors (auditor_uuid) ON DELETE CASCADE
  ,denominations_serial INT8 NOT NULL REFERENCES denominations (denominations_serial) ON DELETE CASCADE
  ,auditor_sig BYTEA CHECK (LENGTH(auditor_sig)=64)
  ,PRIMARY KEY (denominations_serial, auditor_uuid)
  );
COMMENT ON TABLE auditor_denom_sigs
  IS 'Table with auditor signatures on exchange denomination keys.';
COMMENT ON COLUMN auditor_denom_sigs.auditor_uuid
  IS 'Identifies the auditor.';
COMMENT ON COLUMN auditor_denom_sigs.denominations_serial
  IS 'Denomination the signature is for.';
COMMENT ON COLUMN auditor_denom_sigs.auditor_sig
  IS 'Signature of the auditor, of purpose TALER_SIGNATURE_AUDITOR_EXCHANGE_KEYS.';


-- ------------------------------ exchange_sign_keys ----------------------------------------

CREATE TABLE IF NOT EXISTS exchange_sign_keys
  (esk_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,exchange_pub BYTEA PRIMARY KEY CHECK (LENGTH(exchange_pub)=32)
  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
  ,valid_from INT8 NOT NULL
  ,expire_sign INT8 NOT NULL
  ,expire_legal INT8 NOT NULL
  );
COMMENT ON TABLE exchange_sign_keys
  IS 'Table with master public key signatures on exchange online signing keys.';
COMMENT ON COLUMN exchange_sign_keys.exchange_pub
  IS 'Public online signing key of the exchange.';
COMMENT ON COLUMN exchange_sign_keys.master_sig
  IS 'Signature affirming the validity of the signing key of purpose TALER_SIGNATURE_MASTER_SIGNING_KEY_VALIDITY.';
COMMENT ON COLUMN exchange_sign_keys.valid_from
  IS 'Time when this online signing key will first be used to sign messages.';
COMMENT ON COLUMN exchange_sign_keys.expire_sign
  IS 'Time when this online signing key will no longer be used to sign.';
COMMENT ON COLUMN exchange_sign_keys.expire_legal
  IS 'Time when this online signing key legally expires.';


-- ------------------------------ signkey_revocations ----------------------------------------

CREATE TABLE IF NOT EXISTS signkey_revocations
  (signkey_revocations_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,esk_serial INT8 PRIMARY KEY REFERENCES exchange_sign_keys (esk_serial) ON DELETE CASCADE
  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
  );
COMMENT ON TABLE signkey_revocations
  IS 'Table storing which online signing keys have been revoked';


-- ------------------------------ extension ----------------------------------------

CREATE TABLE IF NOT EXISTS extensions
  (extension_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,name VARCHAR NOT NULL UNIQUE
  ,config BYTEA
  );
COMMENT ON TABLE extensions
  IS 'Configurations of the activated extensions';
COMMENT ON COLUMN extensions.name
  IS 'Name of the extension';
COMMENT ON COLUMN extensions.config
  IS 'Configuration of the extension as JSON-blob, maybe NULL';


-- ------------------------------ known_coins ----------------------------------------

SELECT create_table_known_coins();

COMMENT ON TABLE known_coins
  IS 'information about coins and their signatures, so we do not have to store the signatures more than once if a coin is involved in multiple operations';
COMMENT ON COLUMN known_coins.denominations_serial
  IS 'Denomination of the coin, determines the value of the original coin and applicable fees for coin-specific operations.';
COMMENT ON COLUMN known_coins.coin_pub
  IS 'EdDSA public key of the coin';
COMMENT ON COLUMN known_coins.remaining_val
  IS 'Value of the coin that remains to be spent';
COMMENT ON COLUMN known_coins.age_commitment_hash
  IS 'Optional hash of the age commitment for age restrictions as per DD 24 (active if denom_type has the respective bit set)';
COMMENT ON COLUMN known_coins.denom_sig
  IS 'This is the signature of the exchange that affirms that the coin is a valid coin. The specific signature type depends on denom_type of the denomination.';

CREATE TABLE IF NOT EXISTS known_coins_default
  PARTITION OF known_coins
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_known_coins_partition('default');


-- ------------------------------ refresh_commitments ----------------------------------------

SELECT create_table_refresh_commitments();

COMMENT ON TABLE refresh_commitments
  IS 'Commitments made when melting coins and the gamma value chosen by the exchange.';
COMMENT ON COLUMN refresh_commitments.noreveal_index
  IS 'The gamma value chosen by the exchange in the cut-and-choose protocol';
COMMENT ON COLUMN refresh_commitments.rc
  IS 'Commitment made by the client, hash over the various client inputs in the cut-and-choose protocol';
COMMENT ON COLUMN refresh_commitments.old_coin_pub
  IS 'Coin being melted in the refresh process.';

CREATE TABLE IF NOT EXISTS refresh_commitments_default
  PARTITION OF refresh_commitments
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_refresh_commitments_partition('default');


-- ------------------------------ refresh_revealed_coins ----------------------------------------

SELECT create_table_refresh_revealed_coins();

COMMENT ON TABLE refresh_revealed_coins
  IS 'Revelations about the new coins that are to be created during a melting session.';
COMMENT ON COLUMN refresh_revealed_coins.rrc_serial
  IS 'needed for exchange-auditor replication logic';
COMMENT ON COLUMN refresh_revealed_coins.melt_serial_id
  IS 'Identifies the refresh commitment (rc) of the melt operation.';
COMMENT ON COLUMN refresh_revealed_coins.freshcoin_index
  IS 'index of the fresh coin being created (one melt operation may result in multiple fresh coins)';
COMMENT ON COLUMN refresh_revealed_coins.coin_ev
  IS 'envelope of the new coin to be signed';
COMMENT ON COLUMN refresh_revealed_coins.ewv
  IS 'exchange contributed values in the creation of the fresh coin (see /csr)';
COMMENT ON COLUMN refresh_revealed_coins.h_coin_ev
  IS 'hash of the envelope of the new coin to be signed (for lookups)';
COMMENT ON COLUMN refresh_revealed_coins.ev_sig
  IS 'exchange signature over the envelope';

CREATE TABLE IF NOT EXISTS refresh_revealed_coins_default
  PARTITION OF refresh_revealed_coins
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_refresh_revealed_coins_partition('default');


-- ------------------------------ refresh_transfer_keys ----------------------------------------

SELECT create_table_refresh_transfer_keys();

COMMENT ON TABLE refresh_transfer_keys
  IS 'Transfer keys of a refresh operation (the data revealed to the exchange).';
COMMENT ON COLUMN refresh_transfer_keys.rtc_serial
  IS 'needed for exchange-auditor replication logic';
COMMENT ON COLUMN refresh_transfer_keys.melt_serial_id
  IS 'Identifies the refresh commitment (rc) of the operation.';
COMMENT ON COLUMN refresh_transfer_keys.transfer_pub
  IS 'transfer public key for the gamma index';
COMMENT ON COLUMN refresh_transfer_keys.transfer_privs
  IS 'array of TALER_CNC_KAPPA - 1 transfer private keys that have been revealed, with the gamma entry being skipped';

CREATE TABLE IF NOT EXISTS refresh_transfer_keys_default
  PARTITION OF refresh_transfer_keys
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_refresh_transfer_keys_partition('default');


-- ------------------------------ extension_details ----------------------------------------

CREATE TABLE IF NOT EXISTS extension_details
  (extension_details_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY
  ,extension_options VARCHAR)
  PARTITION BY HASH (extension_details_serial_id);
COMMENT ON TABLE extension_details
  IS 'Extensions that were provided with deposits (not yet used).';
COMMENT ON COLUMN extension_details.extension_options
  IS 'JSON object with options set that the exchange needs to consider when executing a deposit. Supported details depend on the extensions supported by the exchange.';

CREATE TABLE IF NOT EXISTS extension_details_default
  PARTITION OF extension_details
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);


-- ------------------------------ deposits ----------------------------------------

SELECT create_table_deposits();

COMMENT ON TABLE deposits
  IS 'Deposits we have received and for which we need to make (aggregate) wire transfers (and manage refunds).';
COMMENT ON COLUMN deposits.shard
  IS 'Used for load sharding in the materialized indices. Should be set based on merchant_pub. 64-bit value because we need an *unsigned* 32-bit value.';
COMMENT ON COLUMN deposits.known_coin_id
  IS 'Used for garbage collection';
COMMENT ON COLUMN deposits.wire_target_h_payto
  IS 'Identifies the target bank account and KYC status';
COMMENT ON COLUMN deposits.wire_salt
  IS 'Salt used when hashing the payto://-URI to get the h_wire';
COMMENT ON COLUMN deposits.done
  IS 'Set to TRUE once we have included this deposit in some aggregate wire transfer to the merchant';
COMMENT ON COLUMN deposits.extension_blocked
  IS 'True if the aggregation of the deposit is currently blocked by some extension mechanism. Used to filter out deposits that must not be processed by the canonical deposit logic.';
COMMENT ON COLUMN deposits.extension_details_serial_id
  IS 'References extensions table, NULL if extensions are not used';

CREATE TABLE IF NOT EXISTS deposits_default
  PARTITION OF deposits
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_deposits_partition('default');


SELECT create_table_deposits_by_ready();

COMMENT ON TABLE deposits_by_ready
  IS 'Enables fast lookups for deposits_get_ready, auto-populated via TRIGGER below';

CREATE TABLE IF NOT EXISTS deposits_by_ready_default
  PARTITION OF deposits_by_ready
  DEFAULT;


SELECT create_table_deposits_for_matching();

COMMENT ON TABLE deposits_for_matching
  IS 'Enables fast lookups for deposits_iterate_matching, auto-populated via TRIGGER below';

CREATE TABLE IF NOT EXISTS deposits_for_matching_default
  PARTITION OF deposits_for_matching
  DEFAULT;


CREATE OR REPLACE FUNCTION deposits_insert_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
DECLARE
  is_ready BOOLEAN;
BEGIN
  is_ready  = NOT (NEW.done OR NEW.extension_blocked);

  IF (is_ready)
  THEN
    INSERT INTO exchange.deposits_by_ready
      (wire_deadline
      ,shard
      ,coin_pub
      ,deposit_serial_id)
    VALUES
      (NEW.wire_deadline
      ,NEW.shard
      ,NEW.coin_pub
      ,NEW.deposit_serial_id);
    INSERT INTO exchange.deposits_for_matching
      (refund_deadline
      ,merchant_pub
      ,coin_pub
      ,deposit_serial_id)
    VALUES
      (NEW.refund_deadline
      ,NEW.merchant_pub
      ,NEW.coin_pub
      ,NEW.deposit_serial_id);
  END IF;
  RETURN NEW;
END $$;
COMMENT ON FUNCTION deposits_insert_trigger()
  IS 'Replicate deposit inserts into materialized indices.';

CREATE TRIGGER deposits_on_insert
  AFTER INSERT
   ON deposits
   FOR EACH ROW EXECUTE FUNCTION deposits_insert_trigger();

CREATE OR REPLACE FUNCTION deposits_update_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
DECLARE
  was_ready BOOLEAN;
DECLARE
  is_ready BOOLEAN;
BEGIN
  was_ready = NOT (OLD.done OR OLD.extension_blocked);
  is_ready  = NOT (NEW.done OR NEW.extension_blocked);
  IF (was_ready AND NOT is_ready)
  THEN
    DELETE FROM exchange.deposits_by_ready
     WHERE wire_deadline = OLD.wire_deadline
       AND shard = OLD.shard
       AND coin_pub = OLD.coin_pub
       AND deposit_serial_id = OLD.deposit_serial_id;
    DELETE FROM exchange.deposits_for_matching
     WHERE refund_deadline = OLD.refund_deadline
       AND merchant_pub = OLD.merchant_pub
       AND coin_pub = OLD.coin_pub
       AND deposit_serial_id = OLD.deposit_serial_id;
  END IF;
  IF (is_ready AND NOT was_ready)
  THEN
    INSERT INTO exchange.deposits_by_ready
      (wire_deadline
      ,shard
      ,coin_pub
      ,deposit_serial_id)
    VALUES
      (NEW.wire_deadline
      ,NEW.shard
      ,NEW.coin_pub
      ,NEW.deposit_serial_id);
    INSERT INTO exchange.deposits_for_matching
      (refund_deadline
      ,merchant_pub
      ,coin_pub
      ,deposit_serial_id)
    VALUES
      (NEW.refund_deadline
      ,NEW.merchant_pub
      ,NEW.coin_pub
      ,NEW.deposit_serial_id);
  END IF;
  RETURN NEW;
END $$;
COMMENT ON FUNCTION deposits_update_trigger()
  IS 'Replicate deposits changes into materialized indices.';

CREATE TRIGGER deposits_on_update
  AFTER UPDATE
    ON deposits
   FOR EACH ROW EXECUTE FUNCTION deposits_update_trigger();

CREATE OR REPLACE FUNCTION deposits_delete_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
DECLARE
  was_ready BOOLEAN;
BEGIN
  was_ready  = NOT (OLD.done OR OLD.extension_blocked);

  IF (was_ready)
  THEN
    DELETE FROM exchange.deposits_by_ready
     WHERE wire_deadline = OLD.wire_deadline
       AND shard = OLD.shard
       AND coin_pub = OLD.coin_pub
       AND deposit_serial_id = OLD.deposit_serial_id;
    DELETE FROM exchange.deposits_for_matching
     WHERE refund_deadline = OLD.refund_deadline
       AND merchant_pub = OLD.merchant_pub
       AND coin_pub = OLD.coin_pub
       AND deposit_serial_id = OLD.deposit_serial_id;
  END IF;
  RETURN NEW;
END $$;
COMMENT ON FUNCTION deposits_delete_trigger()
  IS 'Replicate deposit deletions into materialized indices.';

CREATE TRIGGER deposits_on_delete
  AFTER DELETE
   ON deposits
   FOR EACH ROW EXECUTE FUNCTION deposits_delete_trigger();


-- ------------------------------ refunds ----------------------------------------

SELECT create_table_refunds();

COMMENT ON TABLE refunds
  IS 'Data on coins that were refunded. Technically, refunds always apply against specific deposit operations involving a coin. The combination of coin_pub, merchant_pub, h_contract_terms and rtransaction_id MUST be unique, and we usually select by coin_pub so that one goes first.';
COMMENT ON COLUMN refunds.deposit_serial_id
  IS 'Identifies ONLY the merchant_pub, h_contract_terms and coin_pub. Multiple deposits may match a refund, this only identifies one of them.';
COMMENT ON COLUMN refunds.rtransaction_id
  IS 'used by the merchant to make refunds unique in case the same coin for the same deposit gets a subsequent (higher) refund';

CREATE TABLE IF NOT EXISTS refunds_default
  PARTITION OF refunds
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_refunds_partition('default');


-- ------------------------------ wire_out ----------------------------------------

SELECT create_table_wire_out();

COMMENT ON TABLE wire_out
  IS 'wire transfers the exchange has executed';
COMMENT ON COLUMN wire_out.exchange_account_section
  IS 'identifies the configuration section with the debit account of this payment';
COMMENT ON COLUMN wire_out.wire_target_h_payto
  IS 'Identifies the credited bank account and KYC status';

CREATE TABLE IF NOT EXISTS wire_out_default
  PARTITION OF wire_out
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_wire_out_partition('default');

CREATE OR REPLACE FUNCTION wire_out_delete_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  DELETE FROM exchange.aggregation_tracking
   WHERE wtid_raw = OLD.wtid_raw;
  RETURN OLD;
END $$;
COMMENT ON FUNCTION wire_out_delete_trigger()
  IS 'Replicate reserve_out deletions into aggregation_tracking. This replaces an earlier use of an ON DELETE CASCADE that required a DEFERRABLE constraint and conflicted with nice partitioning.';

CREATE TRIGGER wire_out_on_delete
  AFTER DELETE
    ON wire_out
   FOR EACH ROW EXECUTE FUNCTION wire_out_delete_trigger();



-- ------------------------------ aggregation_transient ----------------------------------------

SELECT create_table_aggregation_transient();

COMMENT ON TABLE aggregation_transient
  IS 'aggregations currently happening (lacking wire_out, usually because the amount is too low); this table is not replicated';
COMMENT ON COLUMN aggregation_transient.amount_val
  IS 'Sum of all of the aggregated deposits (without deposit fees)';
COMMENT ON COLUMN aggregation_transient.wtid_raw
  IS 'identifier of the wire transfer';

CREATE TABLE IF NOT EXISTS aggregation_transient_default
  PARTITION OF aggregation_transient
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);


-- ------------------------------ aggregation_tracking ----------------------------------------

SELECT create_table_aggregation_tracking();

COMMENT ON TABLE aggregation_tracking
  IS 'mapping from wire transfer identifiers (WTID) to deposits (and back)';
COMMENT ON COLUMN aggregation_tracking.wtid_raw
  IS 'identifier of the wire transfer';

CREATE TABLE IF NOT EXISTS aggregation_tracking_default
  PARTITION OF aggregation_tracking
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_aggregation_tracking_partition('default');


-- ------------------------------ wire_fee ----------------------------------------

CREATE TABLE IF NOT EXISTS wire_fee
  (wire_fee_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,wire_method VARCHAR NOT NULL
  ,start_date INT8 NOT NULL
  ,end_date INT8 NOT NULL
  ,wire_fee_val INT8 NOT NULL
  ,wire_fee_frac INT4 NOT NULL
  ,closing_fee_val INT8 NOT NULL
  ,closing_fee_frac INT4 NOT NULL
  ,wad_fee_val INT8 NOT NULL
  ,wad_fee_frac INT4 NOT NULL
  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
  ,PRIMARY KEY (wire_method, start_date)
  );
COMMENT ON TABLE wire_fee
  IS 'list of the wire fees of this exchange, by date';
COMMENT ON COLUMN wire_fee.wire_fee_serial
  IS 'needed for exchange-auditor replication logic';

CREATE INDEX IF NOT EXISTS wire_fee_by_end_date_index
  ON wire_fee
  (end_date);


-- ------------------------------ global_fee ----------------------------------------

CREATE TABLE IF NOT EXISTS global_fee
  (global_fee_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,start_date INT8 NOT NULL
  ,end_date INT8 NOT NULL
  ,history_fee_val INT8 NOT NULL
  ,history_fee_frac INT4 NOT NULL
  ,kyc_fee_val INT8 NOT NULL
  ,kyc_fee_frac INT4 NOT NULL
  ,account_fee_val INT8 NOT NULL
  ,account_fee_frac INT4 NOT NULL
  ,purse_fee_val INT8 NOT NULL
  ,purse_fee_frac INT4 NOT NULL
  ,purse_timeout INT8 NOT NULL
  ,kyc_timeout INT8 NOT NULL
  ,history_expiration INT8 NOT NULL
  ,purse_account_limit INT4 NOT NULL
  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
  ,PRIMARY KEY (start_date)
  );
COMMENT ON TABLE global_fee
  IS 'list of the global fees of this exchange, by date';
COMMENT ON COLUMN global_fee.global_fee_serial
  IS 'needed for exchange-auditor replication logic';

CREATE INDEX IF NOT EXISTS global_fee_by_end_date_index
  ON global_fee
  (end_date);


-- ------------------------------ recoup ----------------------------------------

SELECT create_table_recoup();

COMMENT ON TABLE recoup
  IS 'Information about recoups that were executed between a coin and a reserve. In this type of recoup, the amount is credited back to the reserve from which the coin originated.';
COMMENT ON COLUMN recoup.coin_pub
  IS 'Coin that is being debited in the recoup. Do not CASCADE ON DROP on the coin_pub, as we may keep the coin alive!';
COMMENT ON COLUMN recoup.reserve_out_serial_id
  IS 'Identifies the h_blind_ev of the recouped coin and provides the link to the credited reserve.';
COMMENT ON COLUMN recoup.coin_sig
  IS 'Signature by the coin affirming the recoup, of type TALER_SIGNATURE_WALLET_COIN_RECOUP';
COMMENT ON COLUMN recoup.coin_blind
  IS 'Denomination blinding key used when creating the blinded coin from the planchet. Secret revealed during the recoup to provide the linkage between the coin and the withdraw operation.';

CREATE TABLE IF NOT EXISTS recoup_default
  PARTITION OF recoup
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_recoup_partition('default');


SELECT create_table_recoup_by_reserve();

COMMENT ON TABLE recoup_by_reserve
  IS 'Information in this table is strictly redundant with that of recoup, but saved by a different primary key for fast lookups by reserve_out_serial_id.';

CREATE TABLE IF NOT EXISTS recoup_by_reserve_default
  PARTITION OF recoup_by_reserve
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

CREATE OR REPLACE FUNCTION recoup_insert_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  INSERT INTO exchange.recoup_by_reserve
    (reserve_out_serial_id
    ,coin_pub)
  VALUES
    (NEW.reserve_out_serial_id
    ,NEW.coin_pub);
  RETURN NEW;
END $$;
COMMENT ON FUNCTION recoup_insert_trigger()
  IS 'Replicate recoup inserts into recoup_by_reserve table.';

CREATE TRIGGER recoup_on_insert
  AFTER INSERT
   ON recoup
   FOR EACH ROW EXECUTE FUNCTION recoup_insert_trigger();

CREATE OR REPLACE FUNCTION recoup_delete_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  DELETE FROM exchange.recoup_by_reserve
   WHERE reserve_out_serial_id = OLD.reserve_out_serial_id
     AND coin_pub = OLD.coin_pub;
  RETURN OLD;
END $$;
COMMENT ON FUNCTION recoup_delete_trigger()
  IS 'Replicate recoup deletions into recoup_by_reserve table.';

CREATE TRIGGER recoup_on_delete
  AFTER DELETE
    ON recoup
   FOR EACH ROW EXECUTE FUNCTION recoup_delete_trigger();


-- ------------------------------ recoup_refresh ----------------------------------------

SELECT create_table_recoup_refresh();

COMMENT ON TABLE recoup_refresh
  IS 'Table of coins that originated from a refresh operation and that were recouped. Links the (fresh) coin to the melted operation (and thus the old coin). A recoup on a refreshed coin credits the old coin and debits the fresh coin.';
COMMENT ON COLUMN recoup_refresh.coin_pub
  IS 'Refreshed coin of a revoked denomination where the residual value is credited to the old coin. Do not CASCADE ON DROP on the coin_pub, as we may keep the coin alive!';
COMMENT ON COLUMN recoup_refresh.known_coin_id
  IS 'FIXME: (To be) used for garbage collection (in the future)';
COMMENT ON COLUMN recoup_refresh.rrc_serial
  IS 'Link to the refresh operation. Also identifies the h_blind_ev of the recouped coin (as h_coin_ev).';
COMMENT ON COLUMN recoup_refresh.coin_blind
  IS 'Denomination blinding key used when creating the blinded coin from the planchet. Secret revealed during the recoup to provide the linkage between the coin and the refresh operation.';

CREATE TABLE IF NOT EXISTS recoup_refresh_default
  PARTITION OF recoup_refresh
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_recoup_refresh_partition('default');


-- ------------------------------ prewire ----------------------------------------

SELECT create_table_prewire();

COMMENT ON TABLE prewire
  IS 'pre-commit data for wire transfers we are about to execute';
COMMENT ON COLUMN prewire.failed
  IS 'set to TRUE if the bank responded with a non-transient failure to our transfer request';
COMMENT ON COLUMN prewire.finished
  IS 'set to TRUE once bank confirmed receiving the wire transfer request';
COMMENT ON COLUMN prewire.buf
  IS 'serialized data to send to the bank to execute the wire transfer';

CREATE TABLE IF NOT EXISTS prewire_default
  PARTITION OF prewire
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);


-- ------------------------------ wire_accounts ----------------------------------------

CREATE TABLE IF NOT EXISTS wire_accounts
  (payto_uri VARCHAR PRIMARY KEY
  ,master_sig BYTEA CHECK (LENGTH(master_sig)=64)
  ,is_active BOOLEAN NOT NULL
  ,last_change INT8 NOT NULL
  );
COMMENT ON TABLE wire_accounts
  IS 'Table with current and historic bank accounts of the exchange. Entries never expire as we need to remember the last_change column indefinitely.';
COMMENT ON COLUMN wire_accounts.payto_uri
  IS 'payto URI (RFC 8905) with the bank account of the exchange.';
COMMENT ON COLUMN wire_accounts.master_sig
  IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS';
COMMENT ON COLUMN wire_accounts.is_active
  IS 'true if we are currently supporting the use of this account.';
COMMENT ON COLUMN wire_accounts.last_change
  IS 'Latest time when active status changed. Used to detect replays of old messages.';
-- "wire_accounts" has no sequence because it is a 'mutable' table
--            and is of no concern to the auditor


-- ------------------------------ cs_nonce_locks ----------------------------------------

SELECT create_table_cs_nonce_locks();

COMMENT ON TABLE cs_nonce_locks
  IS 'ensures a Clause Schnorr client nonce is locked for use with an operation identified by a hash';
COMMENT ON COLUMN cs_nonce_locks.nonce
  IS 'actual nonce submitted by the client';
COMMENT ON COLUMN cs_nonce_locks.op_hash
  IS 'hash (RC for refresh, blind coin hash for withdraw) the nonce may be used with';
COMMENT ON COLUMN cs_nonce_locks.max_denomination_serial
  IS 'Maximum number of a CS denomination serial the nonce could be used with, for GC';

CREATE TABLE IF NOT EXISTS cs_nonce_locks_default
  PARTITION OF cs_nonce_locks
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_cs_nonce_locks_partition('default');


-- ------------------------------ work_shards ----------------------------------------

CREATE TABLE IF NOT EXISTS work_shards
  (shard_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,last_attempt INT8 NOT NULL
  ,start_row INT8 NOT NULL
  ,end_row INT8 NOT NULL
  ,completed BOOLEAN NOT NULL DEFAULT FALSE
  ,job_name VARCHAR NOT NULL
  ,PRIMARY KEY (job_name, start_row)
  );
COMMENT ON TABLE work_shards
  IS 'coordinates work between multiple processes working on the same job';
COMMENT ON COLUMN work_shards.shard_serial_id
  IS 'unique serial number identifying the shard';
COMMENT ON COLUMN work_shards.last_attempt
  IS 'last time a worker attempted to work on the shard';
COMMENT ON COLUMN work_shards.completed
  IS 'set to TRUE once the shard is finished by a worker';
COMMENT ON COLUMN work_shards.start_row
  IS 'row at which the shard scope starts, inclusive';
COMMENT ON COLUMN work_shards.end_row
  IS 'row at which the shard scope ends, exclusive';
COMMENT ON COLUMN work_shards.job_name
  IS 'unique name of the job the workers on this shard are performing';

CREATE INDEX IF NOT EXISTS work_shards_by_job_name_completed_last_attempt_index
  ON work_shards
  (job_name
  ,completed
  ,last_attempt ASC
  );


-- ------------------------------ revolving_work_shards ----------------------------------------

CREATE UNLOGGED TABLE IF NOT EXISTS revolving_work_shards
  (shard_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,last_attempt INT8 NOT NULL
  ,start_row INT4 NOT NULL
  ,end_row INT4 NOT NULL
  ,active BOOLEAN NOT NULL DEFAULT FALSE
  ,job_name VARCHAR NOT NULL
  ,PRIMARY KEY (job_name, start_row)
  );
COMMENT ON TABLE revolving_work_shards
  IS 'coordinates work between multiple processes working on the same job with partitions that need to be repeatedly processed; unlogged because on system crashes the locks represented by this table will have to be cleared anyway, typically using "taler-exchange-dbinit -s"';
COMMENT ON COLUMN revolving_work_shards.shard_serial_id
  IS 'unique serial number identifying the shard';
COMMENT ON COLUMN revolving_work_shards.last_attempt
  IS 'last time a worker attempted to work on the shard';
COMMENT ON COLUMN revolving_work_shards.active
  IS 'set to TRUE when a worker is active on the shard';
COMMENT ON COLUMN revolving_work_shards.start_row
  IS 'row at which the shard scope starts, inclusive';
COMMENT ON COLUMN revolving_work_shards.end_row
  IS 'row at which the shard scope ends, exclusive';
COMMENT ON COLUMN revolving_work_shards.job_name
  IS 'unique name of the job the workers on this shard are performing';

CREATE INDEX IF NOT EXISTS revolving_work_shards_by_job_name_active_last_attempt_index
  ON revolving_work_shards
  (job_name
  ,active
  ,last_attempt
  );

--------------------------------------------------------------------------
--                        Tables for P2P payments
--------------------------------------------------------------------------

-- ------------------------------ partners ----------------------------------------

CREATE TABLE IF NOT EXISTS partners
  (partner_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
  ,partner_master_pub BYTEA NOT NULL CHECK(LENGTH(partner_master_pub)=32)
  ,start_date INT8 NOT NULL
  ,end_date INT8 NOT NULL
  ,next_wad INT8 NOT NULL DEFAULT (0)
  ,wad_frequency INT8 NOT NULL
  ,wad_fee_val INT8 NOT NULL
  ,wad_fee_frac INT4 NOT NULL
  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
  ,partner_base_url TEXT NOT NULL
  );
COMMENT ON TABLE partners
  IS 'exchanges we do wad transfers to';
COMMENT ON COLUMN partners.partner_master_pub
  IS 'offline master public key of the partner';
COMMENT ON COLUMN partners.start_date
  IS 'starting date of the partnership';
COMMENT ON COLUMN partners.end_date
  IS 'end date of the partnership';
COMMENT ON COLUMN partners.next_wad
  IS 'at what time should we do the next wad transfer to this partner (frequently updated); set to forever after the end_date';
COMMENT ON COLUMN partners.wad_frequency
  IS 'how often do we promise to do wad transfers';
COMMENT ON COLUMN partners.wad_fee_val
  IS 'how high is the fee for a wallet to be added to a wad to this partner';
COMMENT ON COLUMN partners.partner_base_url
  IS 'base URL of the REST API for this partner';
COMMENT ON COLUMN partners.master_sig
  IS 'signature of our master public key affirming the partnership, of purpose TALER_SIGNATURE_MASTER_PARTNER_DETAILS';

CREATE INDEX IF NOT EXISTS partner_by_wad_time
  ON partners (next_wad ASC);

-- ------------------------------ purse_requests ----------------------------------------

SELECT create_table_purse_requests();

COMMENT ON TABLE purse_requests
  IS 'Requests establishing purses, associating them with a contract but without a target reserve';
COMMENT ON COLUMN purse_requests.purse_pub
  IS 'Public key of the purse';
COMMENT ON COLUMN purse_requests.purse_creation
  IS 'Local time when the purse was created. Determines applicable purse fees.';
COMMENT ON COLUMN purse_requests.purse_expiration
  IS 'When the purse is set to expire';
COMMENT ON COLUMN purse_requests.h_contract_terms
  IS 'Hash of the contract the parties are to agree to';
COMMENT ON COLUMN purse_requests.flags
  IS 'see the enum TALER_WalletAccountMergeFlags';
COMMENT ON COLUMN purse_requests.finished
  IS 'set to TRUE once the purse has been merged (into reserve or wad) or the coins were refunded (transfer aborted)';
COMMENT ON COLUMN purse_requests.refunded
  IS 'set to TRUE if the purse could not be merged and thus all deposited coins were refunded';
COMMENT ON COLUMN purse_requests.in_reserve_quota
  IS 'set to TRUE if this purse currently counts against the number of free purses in the respective reserve';
COMMENT ON COLUMN purse_requests.amount_with_fee_val
  IS 'Total amount expected to be in the purse';
COMMENT ON COLUMN purse_requests.purse_fee_val
  IS 'Purse fee the client agreed to pay from the reserve (accepted by the exchange at the time the purse was created). Zero if in_reserve_quota is TRUE.';
COMMENT ON COLUMN purse_requests.balance_val
  IS 'Total amount actually in the purse';
COMMENT ON COLUMN purse_requests.purse_sig
  IS 'Signature of the purse affirming the purse parameters, of type TALER_SIGNATURE_PURSE_REQUEST';

CREATE TABLE IF NOT EXISTS purse_requests_default
  PARTITION OF purse_requests
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_purse_requests_partition('default');


-- ------------------------------ purse_refunds ----------------------------------------

SELECT create_table_purse_refunds();

COMMENT ON TABLE purse_refunds
  IS 'Purses that were refunded due to expiration';
COMMENT ON COLUMN purse_refunds.purse_pub
  IS 'Public key of the purse';

CREATE TABLE IF NOT EXISTS purse_refunds_default
  PARTITION OF purse_refunds
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_purse_refunds_partition('default');


-- ------------------------------ purse_merges ----------------------------------------

SELECT create_table_purse_merges();

COMMENT ON TABLE purse_merges
  IS 'Merge requests where a purse-owner requested merging the purse into the account';
COMMENT ON COLUMN purse_merges.partner_serial_id
  IS 'identifies the partner exchange, NULL in case the target reserve lives at this exchange';
COMMENT ON COLUMN purse_merges.reserve_pub
  IS 'public key of the target reserve';
COMMENT ON COLUMN purse_merges.purse_pub
  IS 'public key of the purse';
COMMENT ON COLUMN purse_merges.merge_sig
  IS 'signature by the purse private key affirming the merge, of type TALER_SIGNATURE_WALLET_PURSE_MERGE';
COMMENT ON COLUMN purse_merges.merge_timestamp
  IS 'when was the merge message signed';

CREATE TABLE IF NOT EXISTS purse_merges_default
  PARTITION OF purse_merges
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_purse_merges_partition('default');


-- ------------------------------ account_merges ----------------------------------------

SELECT create_table_account_merges();

COMMENT ON TABLE account_merges
  IS 'Merge requests where a purse- and account-owner requested merging the purse into the account';
COMMENT ON COLUMN account_merges.reserve_pub
  IS 'public key of the target reserve';
COMMENT ON COLUMN account_merges.purse_pub
  IS 'public key of the purse';
COMMENT ON COLUMN account_merges.reserve_sig
  IS 'signature by the reserve private key affirming the merge, of type TALER_SIGNATURE_WALLET_ACCOUNT_MERGE';

CREATE TABLE IF NOT EXISTS account_merges_default
  PARTITION OF account_merges
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_account_merges_partition('default');


-- ------------------------------ contracts ----------------------------------------

SELECT create_table_contracts();

COMMENT ON TABLE contracts
  IS 'encrypted contracts associated with purses';
COMMENT ON COLUMN contracts.purse_pub
  IS 'public key of the purse that the contract is associated with';
COMMENT ON COLUMN contracts.contract_sig
  IS 'signature over the encrypted contract by the purse contract key';
COMMENT ON COLUMN contracts.pub_ckey
  IS 'Public ECDH key used to encrypt the contract, to be used with the purse private key for decryption';
COMMENT ON COLUMN contracts.e_contract
  IS 'AES-GCM encrypted contract terms (contains gzip compressed JSON after decryption)';

CREATE TABLE IF NOT EXISTS contracts_default
  PARTITION OF contracts
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_contracts_partition('default');


-- ------------------------------ history_requests ----------------------------------------

SELECT create_table_history_requests();

COMMENT ON TABLE history_requests
  IS 'Paid history requests issued by a client against a reserve';
COMMENT ON COLUMN history_requests.request_timestamp
  IS 'When was the history request made';
COMMENT ON COLUMN history_requests.reserve_sig
  IS 'Signature approving payment for the history request';
COMMENT ON COLUMN history_requests.history_fee_val
  IS 'History fee approved by the signature';

CREATE TABLE IF NOT EXISTS history_requests_default
  PARTITION OF history_requests
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

-- ------------------------------ close_requests ----------------------------------------

SELECT create_table_close_requests();

COMMENT ON TABLE close_requests
  IS 'Explicit requests by a reserve owner to close a reserve immediately';
COMMENT ON COLUMN close_requests.close_timestamp
  IS 'When the request was created by the client';
COMMENT ON COLUMN close_requests.reserve_sig
  IS 'Signature affirming that the reserve is to be closed';
COMMENT ON COLUMN close_requests.close_val
  IS 'Balance of the reserve at the time of closing, to be wired to the associated bank account (minus the closing fee)';

CREATE TABLE IF NOT EXISTS close_requests_default
  PARTITION OF close_requests
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);


-- ------------------------------ purse_deposits ----------------------------------------

SELECT create_table_purse_deposits();

COMMENT ON TABLE purse_deposits
  IS 'Requests depositing coins into a purse';
COMMENT ON COLUMN purse_deposits.partner_serial_id
  IS 'identifies the partner exchange, NULL in case the target purse lives at this exchange';
COMMENT ON COLUMN purse_deposits.purse_pub
  IS 'Public key of the purse';
COMMENT ON COLUMN purse_deposits.coin_pub
  IS 'Public key of the coin being deposited';
COMMENT ON COLUMN purse_deposits.amount_with_fee_val
  IS 'Total amount being deposited';
COMMENT ON COLUMN purse_deposits.coin_sig
  IS 'Signature of the coin affirming the deposit into the purse, of type TALER_SIGNATURE_PURSE_DEPOSIT';

CREATE TABLE IF NOT EXISTS purse_deposits_default
  PARTITION OF purse_deposits
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_purse_deposits_partition('default');


-- ------------------------------ wads_out ----------------------------------------

SELECT create_table_wads_out();

COMMENT ON TABLE wads_out
  IS 'Wire transfers made to another exchange to transfer purse funds';
COMMENT ON COLUMN wads_out.wad_id
  IS 'Unique identifier of the wad, part of the wire transfer subject';
COMMENT ON COLUMN wads_out.partner_serial_id
  IS 'target exchange of the wad';
COMMENT ON COLUMN wads_out.amount_val
  IS 'Amount that was wired';
COMMENT ON COLUMN wads_out.execution_time
  IS 'Time when the wire transfer was scheduled';

CREATE TABLE IF NOT EXISTS wads_out_default
  PARTITION OF wads_out
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_wads_out_partition('default');


-- ------------------------------ wads_out_entries ----------------------------------------

SELECT create_table_wad_out_entries();

COMMENT ON TABLE wad_out_entries
  IS 'Purses combined into a wad';
COMMENT ON COLUMN wad_out_entries.wad_out_serial_id
  IS 'Wad the purse was part of';
COMMENT ON COLUMN wad_out_entries.reserve_pub
  IS 'Target reserve for the purse';
COMMENT ON COLUMN wad_out_entries.purse_pub
  IS 'Public key of the purse';
COMMENT ON COLUMN wad_out_entries.h_contract
  IS 'Hash of the contract associated with the purse';
COMMENT ON COLUMN wad_out_entries.purse_expiration
  IS 'Time when the purse expires';
COMMENT ON COLUMN wad_out_entries.merge_timestamp
  IS 'Time when the merge was approved';
COMMENT ON COLUMN wad_out_entries.amount_with_fee_val
  IS 'Total amount in the purse';
COMMENT ON COLUMN wad_out_entries.wad_fee_val
  IS 'Wat fee charged to the purse';
COMMENT ON COLUMN wad_out_entries.deposit_fees_val
  IS 'Total deposit fees charged to the purse';
COMMENT ON COLUMN wad_out_entries.reserve_sig
  IS 'Signature by the receiving reserve, of purpose TALER_SIGNATURE_ACCOUNT_MERGE';
COMMENT ON COLUMN wad_out_entries.purse_sig
  IS 'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE';

CREATE TABLE IF NOT EXISTS wad_out_entries_default
  PARTITION OF wad_out_entries
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_wad_out_entries_partition('default');

-- ------------------------------ wads_in ----------------------------------------

SELECT create_table_wads_in();

COMMENT ON TABLE wads_in
  IS 'Incoming exchange-to-exchange wad wire transfers';
COMMENT ON COLUMN wads_in.wad_id
  IS 'Unique identifier of the wad, part of the wire transfer subject';
COMMENT ON COLUMN wads_in.origin_exchange_url
  IS 'Base URL of the originating URL, also part of the wire transfer subject';
COMMENT ON COLUMN wads_in.amount_val
  IS 'Actual amount that was received by our exchange';
COMMENT ON COLUMN wads_in.arrival_time
  IS 'Time when the wad was received';

CREATE TABLE IF NOT EXISTS wads_in_default
  PARTITION OF wads_in
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_wads_in_partition('default');


-- ------------------------------ wads_in_entries ----------------------------------------

SELECT create_table_wad_in_entries();

COMMENT ON TABLE wad_in_entries
  IS 'list of purses aggregated in a wad according to the sending exchange';
COMMENT ON COLUMN wad_in_entries.wad_in_serial_id
  IS 'wad for which the given purse was included in the aggregation';
COMMENT ON COLUMN wad_in_entries.reserve_pub
  IS 'target account of the purse (must be at the local exchange)';
COMMENT ON COLUMN wad_in_entries.purse_pub
  IS 'public key of the purse that was merged';
COMMENT ON COLUMN wad_in_entries.h_contract
  IS 'hash of the contract terms of the purse';
COMMENT ON COLUMN wad_in_entries.purse_expiration
  IS 'Time when the purse was set to expire';
COMMENT ON COLUMN wad_in_entries.merge_timestamp
  IS 'Time when the merge was approved';
COMMENT ON COLUMN wad_in_entries.amount_with_fee_val
  IS 'Total amount in the purse';
COMMENT ON COLUMN wad_in_entries.wad_fee_val
  IS 'Total wad fees paid by the purse';
COMMENT ON COLUMN wad_in_entries.deposit_fees_val
  IS 'Total deposit fees paid when depositing coins into the purse';
COMMENT ON COLUMN wad_in_entries.reserve_sig
  IS 'Signature by the receiving reserve, of purpose TALER_SIGNATURE_ACCOUNT_MERGE';
COMMENT ON COLUMN wad_in_entries.purse_sig
  IS 'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE';

CREATE TABLE IF NOT EXISTS wad_in_entries_default
  PARTITION OF wad_in_entries
  FOR VALUES WITH (MODULUS 1, REMAINDER 0);

SELECT add_constraints_to_wad_in_entries_partition('default');


-- ------------------------------ partner_accounts ----------------------------------------

CREATE TABLE IF NOT EXISTS partner_accounts
  (payto_uri VARCHAR PRIMARY KEY
  ,partner_serial_id INT8 REFERENCES partners(partner_serial_id) ON DELETE CASCADE
  ,partner_master_sig BYTEA CHECK (LENGTH(partner_master_sig)=64)
  ,last_seen INT8 NOT NULL
  );
CREATE INDEX IF NOT EXISTS partner_accounts_index_by_partner_and_time
  ON partner_accounts (partner_serial_id,last_seen);
COMMENT ON TABLE partner_accounts
  IS 'Table with bank accounts of the partner exchange. Entries never expire as we need to remember the signature for the auditor.';
COMMENT ON COLUMN partner_accounts.payto_uri
  IS 'payto URI (RFC 8905) with the bank account of the partner exchange.';
COMMENT ON COLUMN partner_accounts.partner_master_sig
  IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS by the partner master public key';
COMMENT ON COLUMN partner_accounts.last_seen
  IS 'Last time we saw this account as being active at the partner exchange. Used to select the most recent entry, and to detect when we should check again.';


----------------------- router helper table (not synchronzied) ------------------------

CREATE TABLE IF NOT EXISTS purse_actions
  (purse_pub BYTEA NOT NULL PRIMARY KEY CHECK(LENGTH(purse_pub)=32)
  ,action_date INT8 NOT NULL
  ,partner_serial_id INT8
  );
COMMENT ON TABLE purse_actions
  IS 'purses awaiting some action by the router';
COMMENT ON COLUMN purse_actions.purse_pub
  IS 'public (contract) key of the purse';
COMMENT ON COLUMN purse_actions.action_date
  IS 'when is the purse ready for action';
COMMENT ON COLUMN purse_actions.partner_serial_id
  IS 'wad target of an outgoing wire transfer, 0 for local, NULL if the purse is unmerged and thus the target is still unknown';

CREATE INDEX IF NOT EXISTS purse_action_by_target
  ON purse_actions
  (partner_serial_id,action_date);


CREATE OR REPLACE FUNCTION purse_requests_insert_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  ASSERT NOT NEW.finished,'Internal invariant violated';
  INSERT INTO
    purse_actions
    (purse_pub
    ,action_date)
  VALUES
    (NEW.purse_pub
    ,NEW.purse_expiration);
  RETURN NEW;
END $$;
COMMENT ON FUNCTION purse_requests_insert_trigger()
  IS 'When a purse is created, insert it into the purse_action table to take action when the purse expires.';

CREATE TRIGGER purse_requests_on_insert
  AFTER INSERT
   ON purse_requests
   FOR EACH ROW EXECUTE FUNCTION purse_requests_insert_trigger();
COMMENT ON TRIGGER purse_requests_on_insert
        ON purse_requests
  IS 'Here we install an entry for the purse expiration.';


CREATE OR REPLACE FUNCTION purse_requests_on_update_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  IF (NEW.finished AND NOT OLD.finished)
  THEN
    -- If this purse counted against the reserve's
    -- quota of purses, decrement the reserve accounting.
    IF (NEW.in_reserve_quota)
    THEN
      UPDATE reserves
         SET purses_active=purses_active-1
       WHERE reserve_pub IN
         (SELECT reserve_pub
            FROM exchange.purse_merges
           WHERE purse_pub=NEW.purse_pub
           LIMIT 1);
      NEW.in_reserve_quota=FALSE;
    END IF;
    -- Delete from the purse_actions table, we are done
    -- with this purse for good.
    DELETE FROM exchange.purse_actions
          WHERE purse_pub=NEW.purse_pub;
    RETURN NEW;
  END IF;

  RETURN NEW;
END $$;

COMMENT ON FUNCTION purse_requests_on_update_trigger()
  IS 'Trigger the router if the purse is ready. Also removes the entry from the router watchlist once the purse is finished.';

CREATE TRIGGER purse_requests_on_update
  BEFORE UPDATE
   ON purse_requests
   FOR EACH ROW EXECUTE FUNCTION purse_requests_on_update_trigger();
COMMENT ON TRIGGER purse_requests_on_update
  ON purse_requests
  IS 'This covers the case where a deposit is made into a purse, which inherently then changes the purse balance via an UPDATE. If the merge is already present and the balance matches the total, we trigger the router. Once the router sets the purse to finished, the trigger will remove the purse from the watchlist of the router.';