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
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
1821
1822
1823
1824
1825
1826
1827
1828
1829
1830
1831
1832
1833
1834
1835
1836
1837
1838
1839
1840
1841
1842
1843
1844
1845
1846
1847
1848
1849
1850
1851
1852
1853
1854
1855
1856
1857
1858
1859
1860
1861
1862
1863
1864
1865
1866
1867
1868
1869
1870
1871
1872
1873
1874
1875
1876
1877
1878
1879
1880
1881
1882
1883
1884
1885
1886
1887
1888
1889
1890
1891
1892
1893
1894
1895
1896
1897
1898
1899
1900
1901
1902
1903
1904
1905
1906
1907
1908
1909
1910
1911
1912
1913
1914
1915
1916
1917
1918
1919
1920
1921
1922
1923
1924
1925
1926
1927
1928
1929
1930
1931
1932
1933
1934
1935
1936
1937
1938
1939
1940
1941
1942
1943
1944
1945
1946
1947
1948
1949
1950
1951
1952
1953
1954
1955
1956
1957
1958
1959
1960
1961
1962
1963
1964
1965
1966
1967
1968
1969
1970
1971
1972
1973
1974
1975
1976
1977
1978
1979
1980
1981
1982
1983
1984
1985
1986
1987
1988
1989
1990
1991
1992
1993
1994
1995
1996
1997
1998
1999
2000
2001
2002
2003
2004
2005
2006
2007
2008
2009
2010
2011
2012
2013
2014
2015
2016
2017
2018
2019
2020
2021
2022
2023
2024
2025
2026
2027
2028
2029
2030
2031
2032
2033
2034
2035
2036
2037
2038
2039
2040
2041
2042
2043
2044
2045
2046
2047
2048
2049
2050
2051
2052
2053
2054
2055
2056
2057
2058
2059
2060
2061
2062
2063
2064
2065
2066
2067
2068
2069
2070
2071
2072
2073
2074
2075
2076
2077
2078
2079
2080
2081
2082
2083
2084
2085
2086
2087
2088
2089
2090
2091
2092
2093
2094
2095
2096
2097
2098
2099
2100
2101
2102
2103
2104
2105
2106
2107
2108
2109
2110
2111
2112
2113
2114
2115
2116
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
2137
2138
2139
2140
2141
2142
2143
2144
2145
2146
2147
2148
2149
2150
2151
2152
2153
2154
2155
2156
2157
2158
2159
2160
2161
2162
2163
2164
2165
2166
2167
2168
2169
2170
2171
2172
2173
2174
2175
2176
2177
2178
2179
2180
2181
2182
2183
2184
2185
2186
2187
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
2201
2202
2203
2204
2205
2206
2207
2208
2209
2210
2211
2212
2213
2214
2215
2216
2217
2218
2219
2220
2221
2222
2223
2224
2225
2226
2227
2228
2229
2230
2231
2232
2233
2234
2235
2236
2237
2238
2239
2240
2241
2242
2243
2244
2245
2246
2247
2248
2249
2250
2251
2252
2253
2254
2255
2256
2257
2258
2259
2260
2261
2262
2263
2264
2265
2266
2267
2268
2269
2270
2271
2272
2273
2274
2275
2276
2277
2278
2279
2280
2281
2282
2283
2284
2285
2286
2287
2288
2289
2290
2291
2292
2293
2294
2295
2296
2297
2298
2299
2300
2301
2302
2303
2304
2305
2306
2307
2308
2309
2310
2311
2312
2313
2314
2315
2316
2317
2318
2319
2320
2321
2322
2323
2324
2325
2326
2327
2328
2329
2330
2331
2332
2333
2334
2335
2336
2337
2338
2339
2340
2341
2342
2343
2344
2345
2346
2347
2348
2349
2350
2351
2352
2353
2354
2355
2356
2357
2358
2359
2360
2361
2362
2363
2364
2365
2366
2367
2368
2369
2370
2371
2372
2373
2374
2375
2376
2377
2378
2379
2380
2381
2382
2383
2384
2385
2386
2387
2388
2389
2390
2391
2392
2393
2394
2395
2396
2397
2398
2399
2400
2401
2402
2403
2404
2405
2406
2407
2408
2409
2410
2411
2412
2413
2414
2415
2416
2417
2418
2419
2420
2421
2422
2423
2424
2425
2426
2427
2428
2429
2430
2431
2432
2433
2434
2435
2436
2437
2438
2439
2440
2441
2442
2443
2444
2445
2446
2447
2448
2449
2450
2451
2452
2453
2454
2455
2456
2457
2458
2459
2460
2461
2462
2463
2464
2465
2466
2467
2468
2469
2470
2471
2472
2473
2474
2475
2476
2477
2478
2479
2480
2481
2482
2483
2484
2485
2486
2487
2488
2489
2490
2491
2492
2493
2494
2495
2496
2497
2498
2499
2500
2501
2502
2503
2504
2505
2506
2507
2508
2509
2510
2511
2512
2513
2514
2515
2516
2517
2518
2519
2520
2521
2522
2523
2524
2525
2526
2527
2528
2529
2530
2531
2532
2533
2534
2535
2536
2537
2538
2539
2540
2541
2542
2543
2544
2545
2546
2547
2548
2549
2550
2551
2552
2553
2554
2555
2556
2557
2558
2559
2560
2561
2562
2563
2564
2565
2566
2567
2568
2569
2570
2571
2572
2573
2574
2575
2576
2577
2578
2579
2580
2581
2582
2583
2584
2585
2586
2587
2588
2589
2590
2591
2592
2593
2594
2595
2596
2597
2598
2599
2600
2601
2602
2603
2604
2605
2606
2607
2608
2609
2610
2611
2612
2613
2614
2615
2616
2617
2618
2619
2620
2621
2622
2623
2624
2625
2626
2627
2628
2629
2630
2631
2632
2633
2634
2635
2636
2637
2638
2639
2640
2641
2642
2643
2644
2645
2646
2647
2648
2649
2650
2651
2652
2653
2654
2655
2656
2657
2658
2659
2660
2661
2662
2663
2664
2665
2666
2667
2668
2669
2670
2671
2672
2673
2674
2675
2676
2677
2678
2679
2680
2681
2682
2683
2684
2685
2686
2687
2688
2689
2690
2691
2692
2693
2694
2695
2696
2697
2698
2699
2700
2701
2702
2703
2704
2705
2706
2707
2708
2709
2710
2711
2712
2713
2714
2715
2716
2717
2718
2719
2720
2721
2722
2723
2724
2725
2726
2727
2728
2729
2730
2731
2732
2733
2734
2735
2736
2737
2738
2739
2740
2741
2742
2743
2744
2745
2746
2747
2748
2749
2750
2751
2752
2753
2754
2755
2756
2757
2758
2759
2760
2761
2762
2763
2764
2765
2766
2767
2768
2769
2770
2771
2772
2773
2774
2775
2776
2777
2778
2779
2780
2781
2782
2783
2784
2785
2786
2787
2788
2789
2790
2791
2792
2793
2794
2795
2796
2797
2798
2799
2800
2801
2802
2803
2804
2805
2806
2807
2808
2809
2810
2811
2812
2813
2814
2815
2816
2817
2818
2819
2820
2821
2822
2823
2824
2825
2826
2827
2828
2829
2830
2831
2832
2833
2834
2835
2836
2837
2838
2839
2840
2841
2842
2843
2844
2845
2846
2847
2848
2849
2850
2851
2852
2853
2854
2855
2856
2857
2858
2859
2860
2861
2862
2863
2864
2865
2866
2867
2868
2869
2870
2871
2872
2873
2874
2875
2876
2877
2878
2879
2880
2881
2882
2883
2884
2885
2886
2887
2888
2889
2890
2891
2892
2893
2894
2895
2896
2897
2898
2899
2900
2901
2902
2903
2904
2905
2906
2907
2908
2909
2910
2911
2912
2913
2914
2915
2916
2917
2918
2919
2920
2921
2922
2923
2924
2925
2926
2927
2928
2929
2930
2931
2932
2933
2934
2935
2936
2937
2938
2939
2940
2941
2942
2943
2944
2945
2946
2947
2948
2949
2950
2951
2952
2953
2954
2955
2956
2957
2958
2959
2960
2961
2962
2963
2964
2965
2966
2967
2968
2969
2970
2971
2972
2973
2974
2975
2976
2977
2978
2979
2980
2981
2982
2983
2984
2985
2986
2987
2988
2989
2990
2991
2992
2993
2994
2995
2996
2997
2998
2999
3000
3001
3002
3003
3004
3005
3006
3007
3008
3009
3010
3011
3012
3013
3014
3015
3016
3017
3018
3019
3020
3021
3022
3023
3024
3025
3026
3027
3028
3029
3030
3031
3032
3033
3034
3035
3036
3037
3038
3039
3040
3041
3042
3043
3044
3045
3046
3047
3048
3049
3050
3051
3052
3053
3054
3055
3056
3057
3058
3059
3060
3061
3062
3063
3064
3065
3066
3067
3068
3069
3070
3071
3072
3073
3074
3075
3076
3077
3078
3079
3080
3081
3082
3083
3084
3085
3086
3087
3088
3089
3090
3091
3092
3093
3094
3095
3096
3097
3098
3099
3100
3101
3102
3103
3104
3105
3106
3107
3108
3109
3110
3111
3112
3113
3114
3115
3116
3117
3118
3119
3120
3121
3122
3123
3124
3125
3126
3127
3128
3129
3130
3131
3132
3133
3134
3135
3136
3137
3138
3139
3140
3141
3142
3143
3144
3145
3146
3147
3148
3149
3150
3151
3152
3153
3154
3155
3156
3157
3158
3159
3160
3161
3162
3163
3164
3165
3166
3167
3168
3169
3170
3171
3172
3173
3174
3175
3176
3177
3178
3179
3180
3181
3182
3183
3184
3185
3186
3187
3188
3189
3190
3191
3192
3193
3194
3195
3196
3197
3198
3199
3200
3201
3202
3203
3204
3205
3206
3207
3208
3209
3210
3211
3212
3213
3214
3215
3216
3217
3218
3219
3220
3221
3222
3223
3224
3225
3226
3227
3228
3229
3230
3231
3232
3233
3234
3235
3236
3237
3238
3239
3240
3241
3242
3243
3244
3245
3246
3247
3248
3249
3250
3251
3252
3253
3254
3255
3256
3257
3258
3259
3260
3261
3262
3263
3264
3265
3266
3267
3268
3269
3270
3271
3272
3273
3274
3275
3276
3277
3278
3279
3280
3281
3282
3283
3284
3285
3286
3287
3288
3289
3290
3291
3292
3293
3294
3295
3296
3297
3298
3299
3300
3301
3302
3303
3304
3305
3306
3307
3308
3309
3310
3311
3312
3313
3314
3315
3316
3317
3318
3319
3320
3321
3322
3323
3324
3325
3326
3327
3328
3329
3330
3331
3332
3333
3334
3335
3336
3337
3338
3339
3340
3341
3342
3343
|
--
-- 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/>
--
-- Everything in one big transaction
BEGIN;
-- Check patch versioning is in place.
SELECT _v.register_patch('exchange-0001', NULL, NULL);
-- ------------------------------ 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';
-- ------------------------------ wire_targets ----------------------------------------
CREATE TABLE IF NOT EXISTS wire_targets
(wire_target_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,wire_target_h_payto BYTEA PRIMARY KEY CHECK (LENGTH(wire_target_h_payto)=32)
,payto_uri VARCHAR NOT NULL
,kyc_ok BOOLEAN NOT NULL DEFAULT (FALSE)
,external_id VARCHAR
)
PARTITION BY HASH (wire_target_h_payto);
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';
COMMENT ON COLUMN wire_targets.kyc_ok
IS 'true if the KYC check was passed successfully';
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);
CREATE OR REPLACE FUNCTION add_constraints_to_wire_targets_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE wire_targets_' || partition_suffix || ' '
'ADD CONSTRAINT wire_targets_' || partition_suffix || '_wire_target_serial_id_key '
'UNIQUE (wire_target_serial_id)'
);
END
$$;
SELECT add_constraints_to_wire_targets_partition('default');
CREATE INDEX IF NOT EXISTS wire_targets_serial_id_index
ON wire_targets
(wire_target_serial_id);
-- ------------------------------ reserves ----------------------------------------
CREATE TABLE IF NOT EXISTS reserves
(reserve_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY
,reserve_pub BYTEA PRIMARY KEY CHECK(LENGTH(reserve_pub)=32)
,current_balance_val INT8 NOT NULL
,current_balance_frac INT4 NOT NULL
,expiration_date INT8 NOT NULL
,gc_date INT8 NOT NULL
)
PARTITION BY HASH (reserve_pub);
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.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);
CREATE INDEX IF NOT EXISTS reserves_by_expiration_index
ON reserves
(expiration_date
,current_balance_val
,current_balance_frac
);
COMMENT ON INDEX reserves_by_expiration_index
IS 'used in get_expired_reserves';
CREATE INDEX IF NOT EXISTS reserves_by_reserve_uuid_index
ON reserves
(reserve_uuid);
CREATE INDEX IF NOT EXISTS reserves_by_gc_date_index
ON reserves
(gc_date);
COMMENT ON INDEX reserves_by_gc_date_index
IS 'for reserve garbage collection';
-- ------------------------------ reserves_in ----------------------------------------
CREATE TABLE IF NOT EXISTS reserves_in
(reserve_in_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,reserve_pub BYTEA PRIMARY KEY REFERENCES reserves (reserve_pub) ON DELETE CASCADE
,wire_reference INT8 NOT NULL
,credit_val INT8 NOT NULL
,credit_frac INT4 NOT NULL
,wire_source_h_payto BYTEA CHECK (LENGTH(wire_source_h_payto)=32)
,exchange_account_section TEXT NOT NULL
,execution_date INT8 NOT NULL
)
PARTITION BY HASH (reserve_pub);
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);
CREATE OR REPLACE FUNCTION add_constraints_to_reserves_in_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE reserves_in_' || partition_suffix || ' '
'ADD CONSTRAINT reserves_in_' || partition_suffix || '_reserve_in_serial_id_key '
'UNIQUE (reserve_in_serial_id)'
);
END
$$;
SELECT add_constraints_to_reserves_in_partition('default');
CREATE INDEX IF NOT EXISTS reserves_in_by_reserve_in_serial_id_index
ON reserves_in
(reserve_in_serial_id);
-- FIXME: where do we need this index? Can we do better?
CREATE INDEX IF NOT EXISTS reserves_in_by_exchange_account_section_execution_date_index
ON reserves_in
(exchange_account_section
,execution_date
);
-- FIXME: where do we need this index? Can we do better?
CREATE INDEX IF NOT EXISTS reserves_in_by_exchange_account_reserve_in_serial_id_index
ON reserves_in
(exchange_account_section
,reserve_in_serial_id DESC
);
-- ------------------------------ reserves_close ----------------------------------------
CREATE TABLE IF NOT EXISTS reserves_close
(close_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE / PRIMARY KEY
,reserve_pub BYTEA NOT NULL REFERENCES reserves (reserve_pub) ON DELETE CASCADE
,execution_date INT8 NOT NULL
,wtid BYTEA NOT NULL CHECK (LENGTH(wtid)=32)
,wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)
,amount_val INT8 NOT NULL
,amount_frac INT4 NOT NULL
,closing_fee_val INT8 NOT NULL
,closing_fee_frac INT4 NOT NULL)
PARTITION BY HASH (reserve_pub);
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 INDEX IF NOT EXISTS reserves_close_by_close_uuid_index
ON reserves_close
(close_uuid);
CREATE INDEX IF NOT EXISTS reserves_close_by_reserve_pub_index
ON reserves_close
(reserve_pub);
CREATE TABLE IF NOT EXISTS reserves_close_default
PARTITION OF reserves_close
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_reserves_close_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE reserves_close_' || partition_suffix || ' '
'ADD CONSTRAINT reserves_close_' || partition_suffix || '_close_uuid_pkey '
'PRIMARY KEY (close_uuid)'
);
END
$$;
SELECT add_constraints_to_reserves_close_partition('default');
-- ------------------------------ reserves_out ----------------------------------------
CREATE TABLE IF NOT EXISTS reserves_out
(reserve_out_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,h_blind_ev BYTEA CHECK (LENGTH(h_blind_ev)=64) UNIQUE
,denominations_serial INT8 NOT NULL REFERENCES denominations (denominations_serial)
,denom_sig BYTEA NOT NULL
,reserve_uuid INT8 NOT NULL -- REFERENCES reserves (reserve_uuid) ON DELETE CASCADE
,reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)
,execution_date INT8 NOT NULL
,amount_with_fee_val INT8 NOT NULL
,amount_with_fee_frac INT4 NOT NULL
)
PARTITION BY HASH (h_blind_ev);
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 INDEX IF NOT EXISTS reserves_out_by_reserve_out_serial_id_index
ON reserves_out
(reserve_out_serial_id);
-- FIXME: change query to use reserves_out_by_reserve instead and materialize execution_date there as well???
CREATE INDEX IF NOT EXISTS reserves_out_by_reserve_uuid_and_execution_date_index
ON reserves_out
(reserve_uuid, execution_date);
COMMENT ON INDEX reserves_out_by_reserve_uuid_and_execution_date_index
IS 'for get_reserves_out and exchange_do_withdraw_limit_check';
CREATE TABLE IF NOT EXISTS reserves_out_default
PARTITION OF reserves_out
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_reserves_out_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE reserves_out_' || partition_suffix || ' '
'ADD CONSTRAINT reserves_out_' || partition_suffix || '_reserve_out_serial_id_key '
'UNIQUE (reserve_out_serial_id)'
);
END
$$;
SELECT add_constraints_to_reserves_out_partition('default');
CREATE TABLE IF NOT EXISTS reserves_out_by_reserve
(reserve_uuid INT8 NOT NULL -- REFERENCES reserves (reserve_uuid) ON DELETE CASCADE
,h_blind_ev BYTEA CHECK (LENGTH(h_blind_ev)=64)
)
PARTITION BY HASH (reserve_uuid);
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 INDEX IF NOT EXISTS reserves_out_by_reserve_main_index
ON reserves_out_by_reserve
(reserve_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 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 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 ----------------------------------------
CREATE TABLE IF NOT EXISTS known_coins
(known_coin_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,denominations_serial INT8 NOT NULL REFERENCES denominations (denominations_serial) ON DELETE CASCADE
,coin_pub BYTEA NOT NULL PRIMARY KEY CHECK (LENGTH(coin_pub)=32)
,age_commitment_hash BYTEA CHECK (LENGTH(age_commitment_hash)=32)
,denom_sig BYTEA NOT NULL
,remaining_val INT8 NOT NULL
,remaining_frac INT4 NOT NULL
)
PARTITION BY HASH (coin_pub);
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);
CREATE OR REPLACE FUNCTION add_constraints_to_known_coins_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE known_coins_' || partition_suffix || ' '
'ADD CONSTRAINT known_coins_' || partition_suffix || 'k_nown_coin_id_key '
'UNIQUE (known_coin_id)'
);
END
$$;
SELECT add_constraints_to_known_coins_partition('default');
-- ------------------------------ refresh_commitments ----------------------------------------
CREATE TABLE IF NOT EXISTS refresh_commitments
(melt_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,rc BYTEA PRIMARY KEY CHECK (LENGTH(rc)=64)
,old_coin_pub BYTEA NOT NULL REFERENCES known_coins (coin_pub) ON DELETE CASCADE
,old_coin_sig BYTEA NOT NULL CHECK(LENGTH(old_coin_sig)=64)
,amount_with_fee_val INT8 NOT NULL
,amount_with_fee_frac INT4 NOT NULL
,noreveal_index INT4 NOT NULL
)
PARTITION BY HASH (rc);
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.';
-- Note: index spans partitions, may need to be materialized.
CREATE INDEX IF NOT EXISTS refresh_commitments_by_old_coin_pub_index
ON refresh_commitments
(old_coin_pub);
CREATE TABLE IF NOT EXISTS refresh_commitments_default
PARTITION OF refresh_commitments
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_refresh_commitments_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE refresh_commitments_' || partition_suffix || ' '
'ADD CONSTRAINT refresh_commitments_' || partition_suffix || '_melt_serial_id_key '
'UNIQUE (melt_serial_id)'
);
END
$$;
SELECT add_constraints_to_refresh_commitments_partition('default');
-- ------------------------------ refresh_revealed_coins ----------------------------------------
CREATE TABLE IF NOT EXISTS refresh_revealed_coins
(rrc_serial BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,melt_serial_id INT8 NOT NULL -- REFERENCES refresh_commitments (melt_serial_id) ON DELETE CASCADE
,freshcoin_index INT4 NOT NULL
,link_sig BYTEA NOT NULL CHECK(LENGTH(link_sig)=64)
,denominations_serial INT8 NOT NULL REFERENCES denominations (denominations_serial) ON DELETE CASCADE
,coin_ev BYTEA NOT NULL -- UNIQUE
,h_coin_ev BYTEA NOT NULL CHECK(LENGTH(h_coin_ev)=64) -- UNIQUE
,ev_sig BYTEA NOT NULL
,ewv BYTEA NOT NULL
-- ,PRIMARY KEY (melt_serial_id, freshcoin_index) -- done per shard
)
PARTITION BY HASH (melt_serial_id);
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 INDEX IF NOT EXISTS refresh_revealed_coins_by_melt_serial_id_index
ON refresh_revealed_coins
(melt_serial_id);
CREATE TABLE IF NOT EXISTS refresh_revealed_coins_default
PARTITION OF refresh_revealed_coins
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_refresh_revealed_coins_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE refresh_revealed_coins_' || partition_suffix || ' '
'ADD CONSTRAINT refresh_revealed_coins_' || partition_suffix || '_rrc_serial_key '
'UNIQUE (rrc_serial) '
',ADD CONSTRAINT refresh_revealed_coins_' || partition_suffix || '_coin_ev_key '
'UNIQUE (coin_ev) '
',ADD CONSTRAINT refresh_revealed_coins_' || partition_suffix || '_h_coin_ev_key '
'UNIQUE (h_coin_ev) '
',ADD PRIMARY KEY (melt_serial_id, freshcoin_index) '
);
END
$$;
SELECT add_constraints_to_refresh_revealed_coins_partition('default');
-- ------------------------------ refresh_transfer_keys ----------------------------------------
CREATE TABLE IF NOT EXISTS refresh_transfer_keys
(rtc_serial BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,melt_serial_id INT8 PRIMARY KEY -- REFERENCES refresh_commitments (melt_serial_id) ON DELETE CASCADE
,transfer_pub BYTEA NOT NULL CHECK(LENGTH(transfer_pub)=32)
,transfer_privs BYTEA NOT NULL
)
PARTITION BY HASH (melt_serial_id);
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);
CREATE OR REPLACE FUNCTION add_constraints_to_refresh_transfer_keys_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE refresh_transfer_keys_' || partition_suffix || ' '
'ADD CONSTRAINT refresh_transfer_keys_' || partition_suffix || '_rtc_serial_key '
'UNIQUE (rtc_serial)'
);
END
$$;
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 ----------------------------------------
CREATE TABLE IF NOT EXISTS deposits
(deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- PRIMARY KEY
,shard INT8 NOT NULL
,coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32) -- REFERENCES known_coins (coin_pub) ON DELETE CASCADE
,known_coin_id BIGINT NOT NULL -- REFERENCES known_coins (known_coin_id) ON DELETE CASCADE
,amount_with_fee_val INT8 NOT NULL
,amount_with_fee_frac INT4 NOT NULL
,wallet_timestamp INT8 NOT NULL
,exchange_timestamp INT8 NOT NULL
,refund_deadline INT8 NOT NULL
,wire_deadline INT8 NOT NULL
,merchant_pub BYTEA NOT NULL CHECK (LENGTH(merchant_pub)=32)
,h_contract_terms BYTEA NOT NULL CHECK (LENGTH(h_contract_terms)=64)
,coin_sig BYTEA NOT NULL CHECK (LENGTH(coin_sig)=64)
,wire_salt BYTEA NOT NULL CHECK (LENGTH(wire_salt)=16)
,wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)
,tiny BOOLEAN NOT NULL DEFAULT FALSE
,done BOOLEAN NOT NULL DEFAULT FALSE
,extension_blocked BOOLEAN NOT NULL DEFAULT FALSE
,extension_details_serial_id INT8 REFERENCES extension_details (extension_details_serial_id) ON DELETE CASCADE
,UNIQUE (coin_pub, merchant_pub, h_contract_terms)
)
PARTITION BY HASH (coin_pub);
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';
COMMENT ON COLUMN deposits.tiny
IS 'Set to TRUE if we decided that the amount is too small to ever trigger a wire transfer by itself (requires real aggregation)';
CREATE INDEX IF NOT EXISTS deposits_by_coin_pub_index
ON deposits
(coin_pub);
CREATE TABLE IF NOT EXISTS deposits_default
PARTITION OF deposits
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_deposits_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE deposits_' || partition_suffix || ' '
'ADD CONSTRAINT deposits_' || partition_suffix || '_deposit_serial_id_pkey '
'PRIMARY KEY (deposit_serial_id)'
);
END
$$;
SELECT add_constraints_to_deposits_partition('default');
CREATE TABLE IF NOT EXISTS deposits_by_ready
(wire_deadline INT8 NOT NULL
,shard INT8 NOT NULL
,coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)
,deposit_serial_id INT8
)
PARTITION BY RANGE (wire_deadline);
COMMENT ON TABLE deposits_by_ready
IS 'Enables fast lookups for deposits_get_ready, auto-populated via TRIGGER below';
CREATE INDEX IF NOT EXISTS deposits_by_ready_main_index
ON deposits_by_ready
(wire_deadline ASC, shard ASC, coin_pub);
CREATE TABLE IF NOT EXISTS deposits_by_ready_default
PARTITION OF deposits_by_ready
DEFAULT;
CREATE TABLE IF NOT EXISTS deposits_for_matching
(refund_deadline INT8 NOT NULL
,shard INT8 NOT NULL
,coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)
,deposit_serial_id INT8
)
PARTITION BY RANGE (refund_deadline);
COMMENT ON TABLE deposits_for_matching
IS 'Enables fast lookups for deposits_iterate_matching, auto-populated via TRIGGER below';
CREATE INDEX IF NOT EXISTS deposits_for_matching_main_index
ON deposits_for_matching
(refund_deadline ASC, shard, coin_pub);
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;
DECLARE
is_tready BOOLEAN; -- is ready, but may be tiny
BEGIN
is_ready = NOT (NEW.done OR NEW.tiny OR NEW.extension_blocked);
is_tready = NOT (NEW.done OR NEW.extension_blocked);
IF (is_ready)
THEN
INSERT INTO deposits_by_ready
(wire_deadline
,shard
,coin_pub
,deposit_serial_id)
VALUES
(NEW.wire_deadline
,NEW.shard
,NEW.coin_pub
,NEW.deposit_serial_id);
END IF;
IF (is_tready)
THEN
INSERT INTO deposits_for_matching
(refund_deadline
,shard
,coin_pub
,deposit_serial_id)
VALUES
(NEW.refund_deadline
,NEW.shard
,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;
DECLARE
was_tready BOOLEAN; -- was ready, but may be tiny
DECLARE
is_tready BOOLEAN; -- is ready, but may be tiny
BEGIN
was_ready = NOT (OLD.done OR OLD.tiny OR OLD.extension_blocked);
is_ready = NOT (NEW.done OR NEW.tiny OR NEW.extension_blocked);
was_tready = NOT (OLD.done OR OLD.extension_blocked);
is_tready = NOT (NEW.done OR NEW.extension_blocked);
IF (was_ready AND NOT is_ready)
THEN
DELETE FROM 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;
END IF;
IF (was_tready AND NOT is_tready)
THEN
DELETE FROM deposits_for_matching
WHERE refund_deadline = OLD.refund_deadline
AND shard = OLD.shard
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 deposits_by_ready
(wire_deadline
,shard
,coin_pub
,deposit_serial_id)
VALUES
(NEW.wire_deadline
,NEW.shard
,NEW.coin_pub
,NEW.deposit_serial_id);
END IF;
IF (is_tready AND NOT was_tready)
THEN
INSERT INTO deposits_for_matching
(refund_deadline
,shard
,coin_pub
,deposit_serial_id)
VALUES
(NEW.refund_deadline
,NEW.shard
,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;
DECLARE
was_tready BOOLEAN; -- is ready, but may be tiny
BEGIN
was_ready = NOT (OLD.done OR OLD.tiny OR OLD.extension_blocked);
was_tready = NOT (OLD.done OR OLD.extension_blocked);
IF (was_ready)
THEN
DELETE FROM 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;
END IF;
IF (was_tready)
THEN
DELETE FROM deposits_for_matching
WHERE refund_deadline = OLD.refund_deadline
AND shard = OLD.shard
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 ----------------------------------------
-- FIXME-URGENT: very bad structure, should replace 'shard' by 'coin_pub'
-- as deposits is sharded by that now!
CREATE TABLE IF NOT EXISTS refunds
(refund_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,shard INT8 NOT NULL -- REFERENCES deposits (shard)
,deposit_serial_id INT8 NOT NULL -- REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE
,merchant_sig BYTEA NOT NULL CHECK(LENGTH(merchant_sig)=64)
,rtransaction_id INT8 NOT NULL
,amount_with_fee_val INT8 NOT NULL
,amount_with_fee_frac INT4 NOT NULL
-- ,PRIMARY KEY (deposit_serial_id, rtransaction_id) -- done per shard!
)
PARTITION BY HASH (shard);
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);
CREATE OR REPLACE FUNCTION add_constraints_to_refunds_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE refunds_' || partition_suffix || ' '
'ADD CONSTRAINT refunds_' || partition_suffix || '_refund_serial_id_key '
'UNIQUE (refund_serial_id) '
',ADD PRIMARY KEY (deposit_serial_id, rtransaction_id) '
);
END
$$;
SELECT add_constraints_to_refunds_partition('default');
CREATE INDEX IF NOT EXISTS refunds_by_deposit_serial_id_index
ON refunds
(shard,deposit_serial_id);
-- ------------------------------ wire_out ----------------------------------------
CREATE TABLE IF NOT EXISTS wire_out
(wireout_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY -- PRIMARY KEY
,execution_date INT8 NOT NULL
,wtid_raw BYTEA UNIQUE NOT NULL CHECK (LENGTH(wtid_raw)=32)
,wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)
,exchange_account_section TEXT NOT NULL
,amount_val INT8 NOT NULL
,amount_frac INT4 NOT NULL
)
PARTITION BY HASH (wtid_raw);
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 INDEX IF NOT EXISTS wire_out_by_wireout_uuid_index
ON wire_out
(wireout_uuid);
CREATE INDEX IF NOT EXISTS wire_out_by_wire_target_h_payto_index
ON wire_out
(wire_target_h_payto);
CREATE TABLE IF NOT EXISTS wire_out_default
PARTITION OF wire_out
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_wire_out_partition(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE wire_out_' || partition_suffix || ' '
'ADD CONSTRAINT wire_out_' || partition_suffix || '_wireout_uuid_pkey '
'PRIMARY KEY (wireout_uuid)'
);
END
$$;
SELECT add_constraints_to_wire_out_partition('default');
-- ------------------------------ aggregation_tracking ----------------------------------------
-- FIXME-URGENT: add colum coin_pub to select by coin_pub + deposit_serial_id for more efficient deposit lookup!?
-- Or which direction(s) is this table used? Is the partitioning sane??
CREATE TABLE IF NOT EXISTS aggregation_tracking
(aggregation_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,deposit_serial_id INT8 PRIMARY KEY -- REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE
,wtid_raw BYTEA NOT NULL CONSTRAINT wire_out_ref REFERENCES wire_out(wtid_raw) ON DELETE CASCADE DEFERRABLE
)
PARTITION BY HASH (deposit_serial_id);
COMMENT ON TABLE aggregation_tracking
IS 'mapping from wire transfer identifiers (WTID) to deposits (and back)';
COMMENT ON COLUMN aggregation_tracking.wtid_raw
IS 'We first create entries in the aggregation_tracking table and then finally the wire_out entry once we know the total amount. Hence the constraint must be deferrable and we cannot use a wireout_uuid here, because we do not have it when these rows are created. Changing the logic to first INSERT a dummy row into wire_out and then UPDATEing that row in the same transaction would theoretically reduce per-deposit storage costs by 5 percent (24/~460 bytes).';
CREATE TABLE IF NOT EXISTS aggregation_tracking_default
PARTITION OF aggregation_tracking
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_aggregation_tracking_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE aggregation_tracking_' || partition_suffix || ' '
'ADD CONSTRAINT aggregation_tracking_' || partition_suffix || '_aggregation_serial_id_key '
'UNIQUE (aggregation_serial_id) '
);
END
$$;
SELECT add_constraints_to_aggregation_tracking_partition('default');
CREATE INDEX IF NOT EXISTS aggregation_tracking_by_wtid_raw_index
ON aggregation_tracking
(wtid_raw);
COMMENT ON INDEX aggregation_tracking_by_wtid_raw_index
IS 'for lookup_transactions';
-- ------------------------------ 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 ----------------------------------------
CREATE TABLE IF NOT EXISTS recoup
(recoup_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32) -- REFERENCES known_coins (coin_pub)
,coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)
,coin_blind BYTEA NOT NULL CHECK(LENGTH(coin_blind)=32)
,amount_val INT8 NOT NULL
,amount_frac INT4 NOT NULL
,recoup_timestamp INT8 NOT NULL
,reserve_out_serial_id INT8 NOT NULL -- REFERENCES reserves_out (reserve_out_serial_id) ON DELETE CASCADE
)
PARTITION BY HASH (coin_pub);
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 INDEX IF NOT EXISTS recoup_by_coin_pub_index
ON recoup
(coin_pub);
CREATE TABLE IF NOT EXISTS recoup_default
PARTITION OF recoup
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_recoup_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE recoup_' || partition_suffix || ' '
'ADD CONSTRAINT recoup_' || partition_suffix || '_recoup_uuid_key '
'UNIQUE (recoup_uuid) '
);
END
$$;
SELECT add_constraints_to_recoup_partition('default');
CREATE TABLE IF NOT EXISTS recoup_by_reserve
(reserve_out_serial_id INT8 NOT NULL -- REFERENCES reserves (reserve_out_serial_id) ON DELETE CASCADE
,coin_pub BYTEA CHECK (LENGTH(coin_pub)=32)
)
PARTITION BY HASH (reserve_out_serial_id);
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 INDEX IF NOT EXISTS recoup_by_reserve_main_index
ON recoup_by_reserve
(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 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 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 ----------------------------------------
CREATE TABLE IF NOT EXISTS recoup_refresh
(recoup_refresh_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32) -- REFERENCES known_coins (coin_pub)
,known_coin_id BIGINT NOT NULL -- REFERENCES known_coins (known_coin_id) ON DELETE CASCADE
,coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)
,coin_blind BYTEA NOT NULL CHECK(LENGTH(coin_blind)=32)
,amount_val INT8 NOT NULL
,amount_frac INT4 NOT NULL
,recoup_timestamp INT8 NOT NULL
,rrc_serial INT8 NOT NULL -- REFERENCES refresh_revealed_coins (rrc_serial) ON DELETE CASCADE -- UNIQUE
)
PARTITION BY HASH (coin_pub);
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 INDEX IF NOT EXISTS recoup_refresh_by_coin_pub_index
ON recoup_refresh
(coin_pub);
-- FIXME: any query using this index will be slow. Materialize index or change query?
-- Also: which query uses this index?
CREATE INDEX IF NOT EXISTS recoup_refresh_by_rrc_serial_index
ON recoup_refresh
(rrc_serial);
CREATE TABLE IF NOT EXISTS recoup_refresh_default
PARTITION OF recoup_refresh
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_recoup_refresh_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE recoup_refresh_' || partition_suffix || ' '
'ADD CONSTRAINT recoup_refresh_' || partition_suffix || '_recoup_refresh_uuid_key '
'UNIQUE (recoup_refresh_uuid) '
);
END
$$;
SELECT add_constraints_to_recoup_refresh_partition('default');
-- ------------------------------ prewire ----------------------------------------
CREATE TABLE IF NOT EXISTS prewire
(prewire_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY
,wire_method TEXT NOT NULL
,finished BOOLEAN NOT NULL DEFAULT false
,failed BOOLEAN NOT NULL DEFAULT false
,buf BYTEA NOT NULL
)
PARTITION BY HASH (prewire_uuid);
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 INDEX IF NOT EXISTS prewire_by_finished_index
ON prewire
(finished);
COMMENT ON INDEX prewire_by_finished_index
IS 'for gc_prewire';
-- FIXME: find a way to combine these two indices?
CREATE INDEX IF NOT EXISTS prewire_by_failed_finished_index
ON prewire
(failed,finished);
COMMENT ON INDEX prewire_by_failed_finished_index
IS 'for wire_prepare_data_get';
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 ----------------------------------------
CREATE TABLE IF NOT EXISTS cs_nonce_locks
(cs_nonce_lock_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,nonce BYTEA PRIMARY KEY CHECK (LENGTH(nonce)=32)
,op_hash BYTEA NOT NULL CHECK (LENGTH(op_hash)=64)
,max_denomination_serial INT8 NOT NULL
)
PARTITION BY HASH (nonce);
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);
CREATE OR REPLACE FUNCTION add_constraints_to_cs_nonce_locks_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE cs_nonce_locks_' || partition_suffix || ' '
'ADD CONSTRAINT cs_nonce_locks_' || partition_suffix || '_cs_nonce_lock_serial_id_key '
'UNIQUE (cs_nonce_lock_serial_id)'
);
END
$$;
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
);
-- ------------------------------ 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
,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.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';
-- ------------------------------ purse_requests ----------------------------------------
CREATE TABLE IF NOT EXISTS purse_requests
(purse_requests_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY --UNIQUE
,purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)
,merge_pub BYTEA NOT NULL CHECK (LENGTH(merge_pub)=32)
,purse_expiration INT8 NOT NULL
,h_contract_terms BYTEA NOT NULL CHECK (LENGTH(h_contract_terms)=64)
,age_limit INT4 NOT NULL
,amount_with_fee_val INT8 NOT NULL
,amount_with_fee_frac INT4 NOT NULL
,balance_val INT8 NOT NULL DEFAULT (0)
,balance_frac INT4 NOT NULL DEFAULT (0)
,purse_sig BYTEA NOT NULL CHECK(LENGTH(purse_sig)=64)
,PRIMARY KEY (purse_pub)
)
PARTITION BY HASH (purse_pub);
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_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.amount_with_fee_val
IS 'Total amount expected to be in the purse';
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';
-- FIXME: change to materialized index by marge_pub!
CREATE INDEX IF NOT EXISTS purse_requests_merge_pub
ON purse_requests (merge_pub);
CREATE TABLE IF NOT EXISTS purse_requests_default
PARTITION OF purse_requests
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_purse_requests_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE purse_requests_' || partition_suffix || ' '
'ADD CONSTRAINT purse_requests_' || partition_suffix || '_purse_requests_serial_id_key '
'UNIQUE (purse_requests_serial_id) '
);
END
$$;
SELECT add_constraints_to_purse_requests_partition('default');
-- ------------------------------ purse_merges ----------------------------------------
CREATE TABLE IF NOT EXISTS purse_merges
(purse_merge_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,partner_serial_id INT8 REFERENCES partners(partner_serial_id) ON DELETE CASCADE
,reserve_pub BYTEA NOT NULL CHECK(length(reserve_pub)=32)--REFERENCES reserves (reserve_pub) ON DELETE CASCADE
,purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32) --REFERENCES purse_requests (purse_pub) ON DELETE CASCADE
,merge_sig BYTEA NOT NULL CHECK (LENGTH(merge_sig)=64)
,merge_timestamp INT8 NOT NULL
,PRIMARY KEY (purse_pub)
)
PARTITION BY HASH (purse_pub);
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 INDEX IF NOT EXISTS purse_merges_purse_pub
ON purse_merges (purse_pub);
-- FIXME: change to materialized index by reserve_pub!
CREATE INDEX IF NOT EXISTS purse_merges_reserve_pub
ON purse_merges (reserve_pub);
COMMENT ON INDEX purse_merges_reserve_pub
IS 'needed in reserve history computation';
CREATE TABLE IF NOT EXISTS purse_merges_default
PARTITION OF purse_merges
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_purse_merges_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE purse_merges_' || partition_suffix || ' '
'ADD CONSTRAINT purse_merges_' || partition_suffix || '_purse_merge_request_serial_id_key '
'UNIQUE (purse_merge_request_serial_id) '
);
END
$$;
SELECT add_constraints_to_purse_merges_partition('default');
-- ------------------------------ account_merges ----------------------------------------
CREATE TABLE IF NOT EXISTS account_merges
(account_merge_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32) -- REFERENCES reserves (reserve_pub) ON DELETE CASCADE
,reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)
,purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32) -- REFERENCES purse_requests (purse_pub)
,PRIMARY KEY (purse_pub)
)
PARTITION BY HASH (purse_pub);
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 INDEX IF NOT EXISTS account_merges_purse_pub
ON account_merges (purse_pub);
COMMENT ON INDEX account_merges_purse_pub
IS 'needed when checking for a purse merge status';
-- FIXME: change to materialized index by reserve_pub!
CREATE INDEX IF NOT EXISTS account_merges_by_reserve_pub
ON account_merges (reserve_pub);
CREATE TABLE IF NOT EXISTS account_merges_default
PARTITION OF account_merges
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_account_merges_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE account_merges_' || partition_suffix || ' '
'ADD CONSTRAINT account_merges_' || partition_suffix || '_account_merge_request_serial_id_key '
'UNIQUE (account_merge_request_serial_id) '
);
END
$$;
SELECT add_constraints_to_account_merges_partition('default');
-- ------------------------------ contracts ----------------------------------------
CREATE TABLE IF NOT EXISTS contracts
(contract_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY --UNIQUE
,purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)
,pub_ckey BYTEA NOT NULL CHECK (LENGTH(pub_ckey)=32)
,e_contract BYTEA NOT NULL
,purse_expiration INT8 NOT NULL
,PRIMARY KEY (purse_pub)
)
PARTITION BY HASH (purse_pub);
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.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);
CREATE OR REPLACE FUNCTION add_constraints_to_contracts_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE contracts_' || partition_suffix || ' '
'ADD CONSTRAINT contracts_' || partition_suffix || '_contract_serial_id_key '
'UNIQUE (contract_serial_id) '
);
END
$$;
SELECT add_constraints_to_contracts_partition('default');
-- ------------------------------ history_requests ----------------------------------------
CREATE TABLE IF NOT EXISTS history_requests
(reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32) REFERENCES reserves(reserve_pub) ON DELETE CASCADE
,request_timestamp INT8 NOT NULL
,reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)
,history_fee_val INT8 NOT NULL
,history_fee_frac INT4 NOT NULL
,PRIMARY KEY (reserve_pub,request_timestamp)
)
PARTITION BY HASH (reserve_pub);
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 ----------------------------------------
CREATE TABLE IF NOT EXISTS close_requests
(reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32) REFERENCES reserves(reserve_pub) ON DELETE CASCADE
,close_timestamp INT8 NOT NULL
,reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)
,close_val INT8 NOT NULL
,close_frac INT4 NOT NULL
,PRIMARY KEY (reserve_pub,close_timestamp)
)
PARTITION BY HASH (reserve_pub);
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 ----------------------------------------
CREATE TABLE IF NOT EXISTS purse_deposits
(purse_deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY -- UNIQUE
,partner_serial_id INT8 REFERENCES partners(partner_serial_id) ON DELETE CASCADE
,purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)
,coin_pub BYTEA NOT NULL REFERENCES known_coins (coin_pub) ON DELETE CASCADE
,amount_with_fee_val INT8 NOT NULL
,amount_with_fee_frac INT4 NOT NULL
,coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)
-- ,PRIMARY KEY (purse_pub,coin_pub)
)
PARTITION BY HASH (purse_pub);
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';
-- FIXME: change to materialized index by coin_pub!
CREATE INDEX IF NOT EXISTS purse_deposits_by_coin_pub
ON purse_deposits (coin_pub);
CREATE TABLE IF NOT EXISTS purse_deposits_default
PARTITION OF purse_deposits
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_purse_deposits_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE purse_deposits_' || partition_suffix || ' '
'ADD CONSTRAINT purse_deposits_' || partition_suffix || '_purse_deposit_serial_id_key '
'UNIQUE (purse_deposit_serial_id) '
);
END
$$;
SELECT add_constraints_to_purse_deposits_partition('default');
-- ------------------------------ wads_out ----------------------------------------
CREATE TABLE IF NOT EXISTS wads_out
(wad_out_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY --UNIQUE
,wad_id BYTEA PRIMARY KEY CHECK (LENGTH(wad_id)=24)
,partner_serial_id INT8 NOT NULL REFERENCES partners(partner_serial_id) ON DELETE CASCADE
,amount_val INT8 NOT NULL
,amount_frac INT4 NOT NULL
,execution_time INT8 NOT NULL
)
PARTITION BY HASH (wad_id);
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 INDEX IF NOT EXISTS wads_out_index_by_wad_id
ON wads_out (wad_id);
CREATE TABLE IF NOT EXISTS wads_out_default
PARTITION OF wads_out
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_wads_out_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE wads_out_' || partition_suffix || ' '
'ADD CONSTRAINT wads_out_' || partition_suffix || '_wad_out_serial_id_key '
'UNIQUE (wad_out_serial_id) '
);
END
$$;
SELECT add_constraints_to_wads_out_partition('default');
-- ------------------------------ wads_out_entries ----------------------------------------
CREATE TABLE IF NOT EXISTS wad_out_entries
(wad_out_entry_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY --UNIQUE
,wad_out_serial_id INT8 -- REFERENCES wads_out (wad_out_serial_id) ON DELETE CASCADE
,reserve_pub BYTEA NOT NULL CHECK(LENGTH(reserve_pub)=32)
,purse_pub BYTEA PRIMARY KEY CHECK(LENGTH(purse_pub)=32)
,h_contract BYTEA NOT NULL CHECK(LENGTH(h_contract)=64)
,purse_expiration INT8 NOT NULL
,merge_timestamp INT8 NOT NULL
,amount_with_fee_val INT8 NOT NULL
,amount_with_fee_frac INT4 NOT NULL
,wad_fee_val INT8 NOT NULL
,wad_fee_frac INT4 NOT NULL
,deposit_fees_val INT8 NOT NULL
,deposit_fees_frac INT4 NOT NULL
,reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)
,purse_sig BYTEA NOT NULL CHECK (LENGTH(purse_sig)=64)
)
PARTITION BY HASH (purse_pub);
-- FIXME: convert to materialized index!
CREATE INDEX IF NOT EXISTS wad_out_entries_index_by_reserve_pub
ON wad_out_entries (reserve_pub);
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);
CREATE OR REPLACE FUNCTION add_constraints_to_wad_out_entries_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE wad_out_entries_' || partition_suffix || ' '
'ADD CONSTRAINT wad_out_entries_' || partition_suffix || '_wad_out_entry_serial_id_key '
'UNIQUE (wad_out_entry_serial_id) '
);
END
$$;
SELECT add_constraints_to_wad_out_entries_partition('default');
-- ------------------------------ wads_in ----------------------------------------
CREATE TABLE IF NOT EXISTS wads_in
(wad_in_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY --UNIQUE
,wad_id BYTEA PRIMARY KEY CHECK (LENGTH(wad_id)=24)
,origin_exchange_url TEXT NOT NULL
,amount_val INT8 NOT NULL
,amount_frac INT4 NOT NULL
,arrival_time INT8 NOT NULL
,UNIQUE (wad_id, origin_exchange_url)
)
PARTITION BY HASH (wad_id);
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);
CREATE OR REPLACE FUNCTION add_constraints_to_wads_in_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE wads_in_' || partition_suffix || ' '
'ADD CONSTRAINT wads_in_' || partition_suffix || '_wad_in_serial_id_key '
'UNIQUE (wad_in_serial_id) '
);
END
$$;
SELECT add_constraints_to_wads_in_partition('default');
-- ------------------------------ wads_in_entries ----------------------------------------
CREATE TABLE IF NOT EXISTS wad_in_entries
(wad_in_entry_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY --UNIQUE
,wad_in_serial_id INT8 -- REFERENCES wads_in (wad_in_serial_id) ON DELETE CASCADE
,reserve_pub BYTEA NOT NULL CHECK(LENGTH(reserve_pub)=32)
,purse_pub BYTEA PRIMARY KEY CHECK(LENGTH(purse_pub)=32)
,h_contract BYTEA NOT NULL CHECK(LENGTH(h_contract)=64)
,purse_expiration INT8 NOT NULL
,merge_timestamp INT8 NOT NULL
,amount_with_fee_val INT8 NOT NULL
,amount_with_fee_frac INT4 NOT NULL
,wad_fee_val INT8 NOT NULL
,wad_fee_frac INT4 NOT NULL
,deposit_fees_val INT8 NOT NULL
,deposit_fees_frac INT4 NOT NULL
,reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)
,purse_sig BYTEA NOT NULL CHECK (LENGTH(purse_sig)=64)
)
PARTITION BY HASH (purse_pub);
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';
-- FIXME: convert to materialized index!
CREATE INDEX IF NOT EXISTS wad_in_entries_reserve_pub
ON wad_in_entries (reserve_pub);
COMMENT ON INDEX wad_in_entries_reserve_pub
IS 'needed to compute reserve history';
CREATE TABLE IF NOT EXISTS wad_in_entries_default
PARTITION OF wad_in_entries
FOR VALUES WITH (MODULUS 1, REMAINDER 0);
CREATE OR REPLACE FUNCTION add_constraints_to_wad_in_entries_partition(
IN partition_suffix VARCHAR
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE FORMAT (
'ALTER TABLE wad_in_entries_' || partition_suffix || ' '
'ADD CONSTRAINT wad_in_entries_' || partition_suffix || '_wad_in_entry_serial_id_key '
'UNIQUE (wad_in_entry_serial_id) '
);
END
$$;
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.';
---------------------------------------------------------------------------
-- Stored procedures
---------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION exchange_do_withdraw(
IN cs_nonce BYTEA,
IN amount_val INT8,
IN amount_frac INT4,
IN h_denom_pub BYTEA,
IN rpub BYTEA,
IN reserve_sig BYTEA,
IN h_coin_envelope BYTEA,
IN denom_sig BYTEA,
IN now INT8,
IN min_reserve_gc INT8,
OUT reserve_found BOOLEAN,
OUT balance_ok BOOLEAN,
OUT kycok BOOLEAN,
OUT account_uuid INT8,
OUT ruuid INT8)
LANGUAGE plpgsql
AS $$
DECLARE
reserve_gc INT8;
DECLARE
denom_serial INT8;
DECLARE
reserve_val INT8;
DECLARE
reserve_frac INT4;
BEGIN
-- Shards: reserves by reserve_pub (SELECT)
-- reserves_out (INSERT, with CONFLICT detection) by wih
-- reserves by reserve_pub (UPDATE)
-- reserves_in by reserve_pub (SELECT)
-- wire_targets by wire_target_h_payto
SELECT denominations_serial
INTO denom_serial
FROM denominations
WHERE denom_pub_hash=h_denom_pub;
IF NOT FOUND
THEN
-- denomination unknown, should be impossible!
reserve_found=FALSE;
balance_ok=FALSE;
kycok=FALSE;
account_uuid=0;
ruuid=0;
ASSERT false, 'denomination unknown';
RETURN;
END IF;
SELECT
current_balance_val
,current_balance_frac
,gc_date
,reserve_uuid
INTO
reserve_val
,reserve_frac
,reserve_gc
,ruuid
FROM reserves
WHERE reserves.reserve_pub=rpub;
IF NOT FOUND
THEN
-- reserve unknown
reserve_found=FALSE;
balance_ok=FALSE;
kycok=FALSE;
account_uuid=0;
ruuid=2;
RETURN;
END IF;
-- We optimistically insert, and then on conflict declare
-- the query successful due to idempotency.
INSERT INTO reserves_out
(h_blind_ev
,denominations_serial
,denom_sig
,reserve_uuid
,reserve_sig
,execution_date
,amount_with_fee_val
,amount_with_fee_frac)
VALUES
(h_coin_envelope
,denom_serial
,denom_sig
,ruuid
,reserve_sig
,now
,amount_val
,amount_frac)
ON CONFLICT DO NOTHING;
IF NOT FOUND
THEN
-- idempotent query, all constraints must be satisfied
reserve_found=TRUE;
balance_ok=TRUE;
kycok=TRUE;
account_uuid=0;
RETURN;
END IF;
-- Check reserve balance is sufficient.
IF (reserve_val > amount_val)
THEN
IF (reserve_frac >= amount_frac)
THEN
reserve_val=reserve_val - amount_val;
reserve_frac=reserve_frac - amount_frac;
ELSE
reserve_val=reserve_val - amount_val - 1;
reserve_frac=reserve_frac + 100000000 - amount_frac;
END IF;
ELSE
IF (reserve_val = amount_val) AND (reserve_frac >= amount_frac)
THEN
reserve_val=0;
reserve_frac=reserve_frac - amount_frac;
ELSE
reserve_found=TRUE;
balance_ok=FALSE;
kycok=FALSE; -- we do not really know or care
account_uuid=0;
RETURN;
END IF;
END IF;
-- Calculate new expiration dates.
min_reserve_gc=GREATEST(min_reserve_gc,reserve_gc);
-- Update reserve balance.
UPDATE reserves SET
gc_date=min_reserve_gc
,current_balance_val=reserve_val
,current_balance_frac=reserve_frac
WHERE
reserves.reserve_pub=rpub;
reserve_found=TRUE;
balance_ok=TRUE;
-- Special actions needed for a CS withdraw?
IF NOT NULL cs_nonce
THEN
-- Cache CS signature to prevent replays in the future
-- (and check if cached signature exists at the same time).
INSERT INTO cs_nonce_locks
(nonce
,max_denomination_serial
,op_hash)
VALUES
(cs_nonce
,denom_serial
,h_coin_envelope)
ON CONFLICT DO NOTHING;
IF NOT FOUND
THEN
-- See if the existing entry is identical.
SELECT 1
FROM cs_nonce_locks
WHERE nonce=cs_nonce
AND op_hash=h_coin_envelope;
IF NOT FOUND
THEN
reserve_found=FALSE;
balance_ok=FALSE;
kycok=FALSE;
account_uuid=0;
ruuid=1; -- FIXME: return error message more nicely!
ASSERT false, 'nonce reuse attempted by client';
END IF;
END IF;
END IF;
-- Obtain KYC status based on the last wire transfer into
-- this reserve. FIXME: likely not adequate for reserves that got P2P transfers!
SELECT
kyc_ok
,wire_target_serial_id
INTO
kycok
,account_uuid
FROM reserves_in
JOIN wire_targets ON (wire_source_h_payto = wire_target_h_payto)
WHERE reserve_pub=rpub
LIMIT 1; -- limit 1 should not be required (without p2p transfers)
END $$;
COMMENT ON FUNCTION exchange_do_withdraw(BYTEA, INT8, INT4, BYTEA, BYTEA, BYTEA, BYTEA, BYTEA, INT8, INT8)
IS 'Checks whether the reserve has sufficient balance for a withdraw operation (or the request is repeated and was previously approved) and if so updates the database with the result';
CREATE OR REPLACE FUNCTION exchange_do_withdraw_limit_check(
IN ruuid INT8,
IN start_time INT8,
IN upper_limit_val INT8,
IN upper_limit_frac INT4,
OUT below_limit BOOLEAN)
LANGUAGE plpgsql
AS $$
DECLARE
total_val INT8;
DECLARE
total_frac INT8; -- INT4 could overflow during accumulation!
BEGIN
-- NOTE: Read-only, but crosses shards.
-- Shards: reserves by reserve_pub
-- reserves_out by reserve_uuid -- crosses shards!!
SELECT
SUM(amount_with_fee_val) -- overflow here is not plausible
,SUM(CAST(amount_with_fee_frac AS INT8)) -- compute using 64 bits
INTO
total_val
,total_frac
FROM reserves_out
WHERE reserve_uuid=ruuid
AND execution_date > start_time;
-- normalize result
total_val = total_val + total_frac / 100000000;
total_frac = total_frac % 100000000;
-- compare to threshold
below_limit = (total_val < upper_limit_val) OR
( (total_val = upper_limit_val) AND
(total_frac <= upper_limit_frac) );
END $$;
COMMENT ON FUNCTION exchange_do_withdraw_limit_check(INT8, INT8, INT8, INT4)
IS 'Check whether the withdrawals from the given reserve since the given time are below the given threshold';
-- NOTE: experiment, currently dead, see postgres_Start_deferred_wire_out;
-- now done inline. FIXME: Remove code here once inline version is confirmed working nicely!
CREATE OR REPLACE PROCEDURE defer_wire_out()
LANGUAGE plpgsql
AS $$
BEGIN
IF EXISTS (
SELECT 1
FROM information_Schema.constraint_column_usage
WHERE table_name='wire_out'
AND constraint_name='wire_out_ref')
THEN
SET CONSTRAINTS wire_out_ref DEFERRED;
END IF;
END $$;
CREATE OR REPLACE FUNCTION exchange_do_deposit(
IN in_amount_with_fee_val INT8,
IN in_amount_with_fee_frac INT4,
IN in_h_contract_terms BYTEA,
IN in_wire_salt BYTEA,
IN in_wallet_timestamp INT8,
IN in_exchange_timestamp INT8,
IN in_refund_deadline INT8,
IN in_wire_deadline INT8,
IN in_merchant_pub BYTEA,
IN in_receiver_wire_account VARCHAR,
IN in_h_payto BYTEA,
IN in_known_coin_id INT8,
IN in_coin_pub BYTEA,
IN in_coin_sig BYTEA,
IN in_shard INT8,
IN in_extension_blocked BOOLEAN,
IN in_extension_details VARCHAR,
OUT out_exchange_timestamp INT8,
OUT out_balance_ok BOOLEAN,
OUT out_conflict BOOLEAN)
LANGUAGE plpgsql
AS $$
DECLARE
wtsi INT8; -- wire target serial id
DECLARE
xdi INT8; -- eXstension details serial id
BEGIN
-- Shards: INSERT extension_details (by extension_details_serial_id)
-- INSERT wire_targets (by h_payto), on CONFLICT DO NOTHING;
-- INSERT deposits (by coin_pub, shard), ON CONFLICT DO NOTHING;
-- UPDATE known_coins (by coin_pub)
IF NOT NULL in_extension_details
THEN
INSERT INTO extension_details
(extension_options)
VALUES
(in_extension_details)
RETURNING extension_details_serial_id INTO xdi;
ELSE
xdi=NULL;
END IF;
INSERT INTO wire_targets
(wire_target_h_payto
,payto_uri)
VALUES
(in_h_payto
,in_receiver_wire_account)
ON CONFLICT DO NOTHING -- for CONFLICT ON (wire_target_h_payto)
RETURNING wire_target_serial_id INTO wtsi;
IF NOT FOUND
THEN
SELECT wire_target_serial_id
INTO wtsi
FROM wire_targets
WHERE wire_target_h_payto=in_h_payto;
END IF;
INSERT INTO deposits
(shard
,coin_pub
,known_coin_id
,amount_with_fee_val
,amount_with_fee_frac
,wallet_timestamp
,exchange_timestamp
,refund_deadline
,wire_deadline
,merchant_pub
,h_contract_terms
,coin_sig
,wire_salt
,wire_target_h_payto
,extension_blocked
,extension_details_serial_id
)
VALUES
(in_shard
,in_coin_pub
,in_known_coin_id
,in_amount_with_fee_val
,in_amount_with_fee_frac
,in_wallet_timestamp
,in_exchange_timestamp
,in_refund_deadline
,in_wire_deadline
,in_merchant_pub
,in_h_contract_terms
,in_coin_sig
,in_wire_salt
,in_h_payto
,in_extension_blocked
,xdi)
ON CONFLICT DO NOTHING;
IF NOT FOUND
THEN
-- Idempotency check: see if an identical record exists.
-- Note that by checking 'coin_sig', we implicitly check
-- identity over everything that the signature covers.
-- We do select over merchant_pub and wire_target_h_payto
-- primarily here to maximally use the existing index.
SELECT
exchange_timestamp
INTO
out_exchange_timestamp
FROM deposits
WHERE shard=in_shard
AND merchant_pub=in_merchant_pub
AND wire_target_h_payto=in_h_payto
AND coin_pub=in_coin_pub
AND coin_sig=in_coin_sig;
IF NOT FOUND
THEN
-- Deposit exists, but with differences. Not allowed.
out_balance_ok=FALSE;
out_conflict=TRUE;
RETURN;
END IF;
-- Idempotent request known, return success.
out_balance_ok=TRUE;
out_conflict=FALSE;
RETURN;
END IF;
out_exchange_timestamp=in_exchange_timestamp;
-- Check and update balance of the coin.
UPDATE known_coins
SET
remaining_frac=remaining_frac-in_amount_with_fee_frac
+ CASE
WHEN remaining_frac < in_amount_with_fee_frac
THEN 100000000
ELSE 0
END,
remaining_val=remaining_val-in_amount_with_fee_val
- CASE
WHEN remaining_frac < in_amount_with_fee_frac
THEN 1
ELSE 0
END
WHERE coin_pub=in_coin_pub
AND ( (remaining_val > in_amount_with_fee_val) OR
( (remaining_frac >= in_amount_with_fee_frac) AND
(remaining_val >= in_amount_with_fee_val) ) );
IF NOT FOUND
THEN
-- Insufficient balance.
out_balance_ok=FALSE;
out_conflict=FALSE;
RETURN;
END IF;
-- Everything fine, return success!
out_balance_ok=TRUE;
out_conflict=FALSE;
END $$;
CREATE OR REPLACE FUNCTION exchange_do_melt(
IN in_cs_rms BYTEA,
IN in_amount_with_fee_val INT8,
IN in_amount_with_fee_frac INT4,
IN in_rc BYTEA,
IN in_old_coin_pub BYTEA,
IN in_old_coin_sig BYTEA,
IN in_known_coin_id INT8, -- not used, but that's OK
IN in_noreveal_index INT4,
IN in_zombie_required BOOLEAN,
OUT out_balance_ok BOOLEAN,
OUT out_zombie_bad BOOLEAN,
OUT out_noreveal_index INT4)
LANGUAGE plpgsql
AS $$
DECLARE
denom_max INT8;
BEGIN
-- Shards: INSERT refresh_commitments (by rc)
-- (rare:) SELECT refresh_commitments (by old_coin_pub) -- crosses shards!
-- (rare:) SEELCT refresh_revealed_coins (by melt_serial_id)
-- (rare:) PERFORM recoup_refresh (by rrc_serial) -- crosses shards!
-- UPDATE known_coins (by coin_pub)
INSERT INTO refresh_commitments
(rc
,old_coin_pub
,old_coin_sig
,amount_with_fee_val
,amount_with_fee_frac
,noreveal_index
)
VALUES
(in_rc
,in_old_coin_pub
,in_old_coin_sig
,in_amount_with_fee_val
,in_amount_with_fee_frac
,in_noreveal_index)
ON CONFLICT DO NOTHING;
IF NOT FOUND
THEN
-- Idempotency check: see if an identical record exists.
out_noreveal_index=-1;
SELECT
noreveal_index
INTO
out_noreveal_index
FROM refresh_commitments
WHERE rc=in_rc;
out_balance_ok=FOUND;
out_zombie_bad=FALSE; -- zombie is OK
RETURN;
END IF;
IF in_zombie_required
THEN
-- Check if this coin was part of a refresh
-- operation that was subsequently involved
-- in a recoup operation. We begin by all
-- refresh operations our coin was involved
-- with, then find all associated reveal
-- operations, and then see if any of these
-- reveal operations was involved in a recoup.
PERFORM
FROM recoup_refresh
WHERE rrc_serial IN
(SELECT rrc_serial
FROM refresh_revealed_coins
WHERE melt_serial_id IN
(SELECT melt_serial_id
FROM refresh_commitments
WHERE old_coin_pub=in_old_coin_pub));
IF NOT FOUND
THEN
out_zombie_bad=TRUE;
out_balance_ok=FALSE;
RETURN;
END IF;
END IF;
out_zombie_bad=FALSE; -- zombie is OK
-- Check and update balance of the coin.
UPDATE known_coins
SET
remaining_frac=remaining_frac-in_amount_with_fee_frac
+ CASE
WHEN remaining_frac < in_amount_with_fee_frac
THEN 100000000
ELSE 0
END,
remaining_val=remaining_val-in_amount_with_fee_val
- CASE
WHEN remaining_frac < in_amount_with_fee_frac
THEN 1
ELSE 0
END
WHERE coin_pub=in_old_coin_pub
AND ( (remaining_val > in_amount_with_fee_val) OR
( (remaining_frac >= in_amount_with_fee_frac) AND
(remaining_val >= in_amount_with_fee_val) ) );
IF NOT FOUND
THEN
-- Insufficient balance.
out_noreveal_index=-1;
out_balance_ok=FALSE;
RETURN;
END IF;
-- Special actions needed for a CS melt?
IF NOT NULL in_cs_rms
THEN
-- Get maximum denominations serial value in
-- existence, this will determine how long the
-- nonce will be locked.
SELECT
denominations_serial
INTO
denom_max
FROM denominations
ORDER BY denominations_serial DESC
LIMIT 1;
-- Cache CS signature to prevent replays in the future
-- (and check if cached signature exists at the same time).
INSERT INTO cs_nonce_locks
(nonce
,max_denomination_serial
,op_hash)
VALUES
(cs_rms
,denom_serial
,in_rc)
ON CONFLICT DO NOTHING;
IF NOT FOUND
THEN
-- Record exists, make sure it is the same
SELECT 1
FROM cs_nonce_locks
WHERE nonce=cs_rms
AND op_hash=in_rc;
IF NOT FOUND
THEN
-- Nonce reuse detected
out_balance_ok=FALSE;
out_zombie_bad=FALSE;
out_noreveal_index=42; -- FIXME: return error message more nicely!
ASSERT false, 'nonce reuse attempted by client';
END IF;
END IF;
END IF;
-- Everything fine, return success!
out_balance_ok=TRUE;
out_noreveal_index=in_noreveal_index;
END $$;
CREATE OR REPLACE FUNCTION exchange_do_refund(
IN in_amount_with_fee_val INT8,
IN in_amount_with_fee_frac INT4,
IN in_amount_val INT8,
IN in_amount_frac INT4,
IN in_deposit_fee_val INT8,
IN in_deposit_fee_frac INT4,
IN in_h_contract_terms BYTEA,
IN in_rtransaction_id INT8,
IN in_deposit_shard INT8,
IN in_known_coin_id INT8,
IN in_coin_pub BYTEA,
IN in_merchant_pub BYTEA,
IN in_merchant_sig BYTEA,
OUT out_not_found BOOLEAN,
OUT out_refund_ok BOOLEAN,
OUT out_gone BOOLEAN,
OUT out_conflict BOOLEAN)
LANGUAGE plpgsql
AS $$
DECLARE
dsi INT8; -- ID of deposit being refunded
DECLARE
tmp_val INT8; -- total amount refunded
DECLARE
tmp_frac INT8; -- total amount refunded
DECLARE
deposit_val INT8; -- amount that was originally deposited
DECLARE
deposit_frac INT8; -- amount that was originally deposited
BEGIN
-- Shards: SELECT deposits (coin_pub, shard, h_contract_terms, merchant_pub)
-- INSERT refunds (by deposit_serial_id, rtransaction_id) ON CONFLICT DO NOTHING
-- SELECT refunds (by deposit_serial_id)
-- UPDATE known_coins (by coin_pub)
SELECT
deposit_serial_id
,amount_with_fee_val
,amount_with_fee_frac
,done
INTO
dsi
,deposit_val
,deposit_frac
,out_gone
FROM deposits
WHERE coin_pub=in_coin_pub
AND shard=in_deposit_shard
AND merchant_pub=in_merchant_pub
AND h_contract_terms=in_h_contract_terms;
IF NOT FOUND
THEN
-- No matching deposit found!
out_refund_ok=FALSE;
out_conflict=FALSE;
out_not_found=TRUE;
out_gone=FALSE;
RETURN;
END IF;
INSERT INTO refunds
(deposit_serial_id
,shard
,merchant_sig
,rtransaction_id
,amount_with_fee_val
,amount_with_fee_frac
)
VALUES
(dsi
,in_deposit_shard
,in_merchant_sig
,in_rtransaction_id
,in_amount_with_fee_val
,in_amount_with_fee_frac)
ON CONFLICT DO NOTHING;
IF NOT FOUND
THEN
-- Idempotency check: see if an identical record exists.
-- Note that by checking 'coin_sig', we implicitly check
-- identity over everything that the signature covers.
-- We do select over merchant_pub and h_contract_terms
-- primarily here to maximally use the existing index.
PERFORM
FROM refunds
WHERE shard=in_deposit_shard
AND deposit_serial_id=dsi
AND rtransaction_id=in_rtransaction_id
AND amount_with_fee_val=in_amount_with_fee_val
AND amount_with_fee_frac=in_amount_with_fee_frac;
IF NOT FOUND
THEN
-- Deposit exists, but have conflicting refund.
out_refund_ok=FALSE;
out_conflict=TRUE;
out_not_found=FALSE;
RETURN;
END IF;
-- Idempotent request known, return success.
out_refund_ok=TRUE;
out_conflict=FALSE;
out_not_found=FALSE;
out_gone=FALSE;
RETURN;
END IF;
IF out_gone
THEN
-- money already sent to the merchant. Tough luck.
out_refund_ok=FALSE;
out_conflict=FALSE;
out_not_found=FALSE;
RETURN;
END IF;
-- Check refund balance invariant.
SELECT
SUM(amount_with_fee_val) -- overflow here is not plausible
,SUM(CAST(amount_with_fee_frac AS INT8)) -- compute using 64 bits
INTO
tmp_val
,tmp_frac
FROM refunds
WHERE shard=in_deposit_shard
AND deposit_serial_id=dsi;
IF tmp_val IS NULL
THEN
RAISE NOTICE 'failed to sum up existing refunds';
out_refund_ok=FALSE;
out_conflict=FALSE;
out_not_found=FALSE;
RETURN;
END IF;
-- Normalize result before continuing
tmp_val = tmp_val + tmp_frac / 100000000;
tmp_frac = tmp_frac % 100000000;
-- Actually check if the deposits are sufficient for the refund. Verbosely. ;-)
IF (tmp_val < deposit_val)
THEN
out_refund_ok=TRUE;
ELSE
IF (tmp_val = deposit_val) AND (tmp_frac <= deposit_frac)
THEN
out_refund_ok=TRUE;
ELSE
out_refund_ok=FALSE;
END IF;
END IF;
IF (tmp_val = deposit_val) AND (tmp_frac = deposit_frac)
THEN
-- Refunds have reached the full value of the original
-- deposit. Also refund the deposit fee.
in_amount_frac = in_amount_frac + in_deposit_fee_frac;
in_amount_val = in_amount_val + in_deposit_fee_val;
-- Normalize result before continuing
in_amount_val = in_amount_val + in_amount_frac / 100000000;
in_amount_frac = in_amount_frac % 100000000;
END IF;
-- Update balance of the coin.
UPDATE known_coins
SET
remaining_frac=remaining_frac+in_amount_frac
- CASE
WHEN remaining_frac+in_amount_frac >= 100000000
THEN 100000000
ELSE 0
END,
remaining_val=remaining_val+in_amount_val
+ CASE
WHEN remaining_frac+in_amount_frac >= 100000000
THEN 1
ELSE 0
END
WHERE coin_pub=in_coin_pub;
out_conflict=FALSE;
out_not_found=FALSE;
END $$;
-- COMMENT ON FUNCTION exchange_do_refund(INT8, INT4, BYTEA, BOOLEAN, BOOLEAN)
-- IS 'Executes a refund operation, checking that the corresponding deposit was sufficient to cover the refunded amount';
CREATE OR REPLACE FUNCTION exchange_do_recoup_to_reserve(
IN in_reserve_pub BYTEA,
IN in_reserve_out_serial_id INT8,
IN in_coin_blind BYTEA,
IN in_coin_pub BYTEA,
IN in_known_coin_id INT8,
IN in_coin_sig BYTEA,
IN in_reserve_gc INT8,
IN in_reserve_expiration INT8,
IN in_recoup_timestamp INT8,
OUT out_recoup_ok BOOLEAN,
OUT out_internal_failure BOOLEAN,
OUT out_recoup_timestamp INT8)
LANGUAGE plpgsql
AS $$
DECLARE
tmp_val INT8; -- amount recouped
DECLARE
tmp_frac INT8; -- amount recouped
BEGIN
-- Shards: SELECT known_coins (by coin_pub)
-- SELECT recoup (by coin_pub)
-- UPDATE known_coins (by coin_pub)
-- UPDATE reserves (by reserve_pub)
-- INSERT recoup (by coin_pub)
out_internal_failure=FALSE;
-- Check remaining balance of the coin.
SELECT
remaining_frac
,remaining_val
INTO
tmp_frac
,tmp_val
FROM known_coins
WHERE coin_pub=in_coin_pub;
IF NOT FOUND
THEN
out_internal_failure=TRUE;
out_recoup_ok=FALSE;
RETURN;
END IF;
IF tmp_val + tmp_frac = 0
THEN
-- Check for idempotency
SELECT
recoup_timestamp
INTO
out_recoup_timestamp
FROM recoup
WHERE coin_pub=in_coin_pub;
out_recoup_ok=FOUND;
RETURN;
END IF;
-- Update balance of the coin.
UPDATE known_coins
SET
remaining_frac=0
,remaining_val=0
WHERE coin_pub=in_coin_pub;
-- Credit the reserve and update reserve timers.
UPDATE reserves
SET
current_balance_frac=current_balance_frac+tmp_frac
- CASE
WHEN current_balance_frac+tmp_frac >= 100000000
THEN 100000000
ELSE 0
END,
current_balance_val=current_balance_val+tmp_val
+ CASE
WHEN current_balance_frac+tmp_frac >= 100000000
THEN 1
ELSE 0
END,
gc_date=GREATEST(gc_date, in_reserve_gc),
expiration_date=GREATEST(expiration_date, in_reserve_expiration)
WHERE reserve_pub=in_reserve_pub;
IF NOT FOUND
THEN
RAISE NOTICE 'failed to increase reserve balance from recoup';
out_recoup_ok=TRUE;
out_internal_failure=TRUE;
RETURN;
END IF;
INSERT INTO recoup
(coin_pub
,coin_sig
,coin_blind
,amount_val
,amount_frac
,recoup_timestamp
,reserve_out_serial_id
)
VALUES
(in_coin_pub
,in_coin_sig
,in_coin_blind
,tmp_val
,tmp_frac
,in_recoup_timestamp
,in_reserve_out_serial_id);
-- Normal end, everything is fine.
out_recoup_ok=TRUE;
out_recoup_timestamp=in_recoup_timestamp;
END $$;
-- COMMENT ON FUNCTION exchange_do_recoup_to_reserve(INT8, INT4, BYTEA, BOOLEAN, BOOLEAN)
-- IS 'Executes a recoup of a coin that was withdrawn from a reserve';
CREATE OR REPLACE FUNCTION exchange_do_recoup_to_coin(
IN in_old_coin_pub BYTEA,
IN in_rrc_serial INT8,
IN in_coin_blind BYTEA,
IN in_coin_pub BYTEA,
IN in_known_coin_id INT8,
IN in_coin_sig BYTEA,
IN in_recoup_timestamp INT8,
OUT out_recoup_ok BOOLEAN,
OUT out_internal_failure BOOLEAN,
OUT out_recoup_timestamp INT8)
LANGUAGE plpgsql
AS $$
DECLARE
tmp_val INT8; -- amount recouped
DECLARE
tmp_frac INT8; -- amount recouped
BEGIN
-- Shards: UPDATE known_coins (by coin_pub)
-- SELECT recoup_refresh (by coin_pub)
-- UPDATE known_coins (by coin_pub)
-- INSERT recoup_refresh (by coin_pub)
out_internal_failure=FALSE;
-- Check remaining balance of the coin.
SELECT
remaining_frac
,remaining_val
INTO
tmp_frac
,tmp_val
FROM known_coins
WHERE coin_pub=in_coin_pub;
IF NOT FOUND
THEN
out_internal_failure=TRUE;
out_recoup_ok=FALSE;
RETURN;
END IF;
IF tmp_val + tmp_frac = 0
THEN
-- Check for idempotency
SELECT
recoup_timestamp
INTO
out_recoup_timestamp
FROM recoup_refresh
WHERE coin_pub=in_coin_pub;
out_recoup_ok=FOUND;
RETURN;
END IF;
-- Update balance of the coin.
UPDATE known_coins
SET
remaining_frac=0
,remaining_val=0
WHERE coin_pub=in_coin_pub;
-- Credit the old coin.
UPDATE known_coins
SET
remaining_frac=remaining_frac+tmp_frac
- CASE
WHEN remaining_frac+tmp_frac >= 100000000
THEN 100000000
ELSE 0
END,
remaining_val=remaining_val+tmp_val
+ CASE
WHEN remaining_frac+tmp_frac >= 100000000
THEN 1
ELSE 0
END
WHERE coin_pub=in_old_coin_pub;
IF NOT FOUND
THEN
RAISE NOTICE 'failed to increase old coin balance from recoup';
out_recoup_ok=TRUE;
out_internal_failure=TRUE;
RETURN;
END IF;
INSERT INTO recoup_refresh
(coin_pub
,known_coin_id
,coin_sig
,coin_blind
,amount_val
,amount_frac
,recoup_timestamp
,rrc_serial
)
VALUES
(in_coin_pub
,in_known_coin_id
,in_coin_sig
,in_coin_blind
,tmp_val
,tmp_frac
,in_recoup_timestamp
,in_rrc_serial);
-- Normal end, everything is fine.
out_recoup_ok=TRUE;
out_recoup_timestamp=in_recoup_timestamp;
END $$;
-- COMMENT ON FUNCTION exchange_do_recoup_to_coin(INT8, INT4, BYTEA, BOOLEAN, BOOLEAN)
-- IS 'Executes a recoup-refresh of a coin that was obtained from a refresh-reveal process';
CREATE OR REPLACE PROCEDURE exchange_do_gc(
IN in_ancient_date INT8,
IN in_now INT8)
LANGUAGE plpgsql
AS $$
DECLARE
reserve_uuid_min INT8; -- minimum reserve UUID still alive
DECLARE
melt_min INT8; -- minimum melt still alive
DECLARE
coin_min INT8; -- minimum known_coin still alive
DECLARE
deposit_min INT8; -- minimum deposit still alive
DECLARE
reserve_out_min INT8; -- minimum reserve_out still alive
DECLARE
denom_min INT8; -- minimum denomination still alive
BEGIN
DELETE FROM prewire
WHERE finished=TRUE;
DELETE FROM wire_fee
WHERE end_date < in_ancient_date;
-- TODO: use closing fee as threshold?
DELETE FROM reserves
WHERE gc_date < in_now
AND current_balance_val = 0
AND current_balance_frac = 0;
SELECT
reserve_out_serial_id
INTO
reserve_out_min
FROM reserves_out
ORDER BY reserve_out_serial_id ASC
LIMIT 1;
DELETE FROM recoup
WHERE reserve_out_serial_id < reserve_out_min;
-- FIXME: recoup_refresh lacks GC!
SELECT
reserve_uuid
INTO
reserve_uuid_min
FROM reserves
ORDER BY reserve_uuid ASC
LIMIT 1;
DELETE FROM reserves_out
WHERE reserve_uuid < reserve_uuid_min;
-- FIXME: this query will be horribly slow;
-- need to find another way to formulate it...
DELETE FROM denominations
WHERE expire_legal < in_now
AND denominations_serial NOT IN
(SELECT DISTINCT denominations_serial
FROM reserves_out)
AND denominations_serial NOT IN
(SELECT DISTINCT denominations_serial
FROM known_coins
WHERE coin_pub IN
(SELECT DISTINCT coin_pub
FROM recoup))
AND denominations_serial NOT IN
(SELECT DISTINCT denominations_serial
FROM known_coins
WHERE coin_pub IN
(SELECT DISTINCT coin_pub
FROM recoup_refresh));
SELECT
melt_serial_id
INTO
melt_min
FROM refresh_commitments
ORDER BY melt_serial_id ASC
LIMIT 1;
DELETE FROM refresh_revealed_coins
WHERE melt_serial_id < melt_min;
DELETE FROM refresh_transfer_keys
WHERE melt_serial_id < melt_min;
SELECT
known_coin_id
INTO
coin_min
FROM known_coins
ORDER BY known_coin_id ASC
LIMIT 1;
DELETE FROM deposits
WHERE known_coin_id < coin_min;
SELECT
deposit_serial_id
INTO
deposit_min
FROM deposits
ORDER BY deposit_serial_id ASC
LIMIT 1;
DELETE FROM refunds
WHERE deposit_serial_id < deposit_min;
DELETE FROM aggregation_tracking
WHERE deposit_serial_id < deposit_min;
SELECT
denominations_serial
INTO
denom_min
FROM denominations
ORDER BY denominations_serial ASC
LIMIT 1;
DELETE FROM cs_nonce_locks
WHERE max_denomination_serial <= denom_min;
END $$;
CREATE OR REPLACE FUNCTION exchange_do_purse_deposit(
IN in_purse_pub BYTEA,
IN in_amount_with_fee_val INT8,
IN in_amount_with_fee_frac INT4,
IN in_coin_pub BYTEA,
IN in_coin_sig BYTEA,
OUT out_balance_ok BOOLEAN,
OUT out_conflict BOOLEAN)
LANGUAGE plpgsql
AS $$
BEGIN
-- FIXME
END $$;
CREATE OR REPLACE FUNCTION exchange_do_purse_merge(
IN in_purse_pub BYTEA,
IN in_merge_sig BYTEA,
IN in_merge_timestamp INT8,
IN in_partner_url VARCHAR,
IN in_reserve_pub BYTEA,
OUT out_balance_ok BOOLEAN,
OUT out_conflict BOOLEAN)
LANGUAGE plpgsql
AS $$
BEGIN
-- FIXME
END $$;
CREATE OR REPLACE FUNCTION exchange_do_account_merge(
IN in_purse_pub BYTEA,
IN in_reserve_pub BYTEA,
IN in_reserve_sig BYTEA,
OUT out_balance_ok BOOLEAN,
OUT out_conflict BOOLEAN)
LANGUAGE plpgsql
AS $$
BEGIN
-- FIXME
END $$;
CREATE OR REPLACE FUNCTION exchange_do_history_request(
IN in_reserve_pub BYTEA,
IN in_reserve_sig BYTEA,
IN in_request_timestamp INT8,
IN in_history_fee_val INT8,
IN in_history_fee_frac INT4,
OUT out_balance_ok BOOLEAN,
OUT out_conflict BOOLEAN)
LANGUAGE plpgsql
AS $$
BEGIN
-- FIXME
END $$;
CREATE OR REPLACE FUNCTION exchange_do_close_request(
IN in_reserve_pub BYTEA,
IN in_reserve_sig BYTEA,
OUT out_final_balance_val INT8,
OUT out_final_balance_frac INT4,
OUT out_balance_ok BOOLEAN,
OUT out_conflict BOOLEAN)
LANGUAGE plpgsql
AS $$
BEGIN
-- FIXME
END $$;
-------------------------------------------------------------
-- THE END
-------------------------------------------------------------
-- Complete transaction
COMMIT;
|