aboutsummaryrefslogtreecommitdiff
path: root/src/exchangedb/plugin_exchangedb_postgres.c
blob: 29ab802cff1dead04c7d4a1780f1b60c005e7c63 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
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
3344
3345
3346
3347
3348
3349
3350
3351
3352
3353
3354
3355
3356
3357
3358
3359
3360
3361
3362
3363
3364
3365
3366
3367
3368
3369
3370
3371
3372
3373
3374
3375
3376
3377
3378
3379
3380
3381
3382
3383
3384
3385
3386
3387
3388
3389
3390
3391
3392
3393
3394
3395
3396
3397
3398
3399
3400
3401
3402
3403
3404
3405
3406
3407
3408
3409
3410
3411
3412
3413
3414
3415
3416
3417
3418
3419
3420
3421
3422
3423
3424
3425
3426
3427
3428
3429
3430
3431
3432
3433
3434
3435
3436
3437
3438
3439
3440
3441
3442
3443
3444
3445
3446
3447
3448
3449
3450
3451
3452
3453
3454
3455
3456
3457
3458
3459
3460
3461
3462
3463
3464
3465
3466
3467
3468
3469
3470
3471
3472
3473
3474
3475
3476
3477
3478
3479
3480
3481
3482
3483
3484
3485
3486
3487
3488
3489
3490
3491
3492
3493
3494
3495
3496
3497
3498
3499
3500
3501
3502
3503
3504
3505
3506
3507
3508
3509
3510
3511
3512
3513
3514
3515
3516
3517
3518
3519
3520
3521
3522
3523
3524
3525
3526
3527
3528
3529
3530
3531
3532
3533
3534
3535
3536
3537
3538
3539
3540
3541
3542
3543
3544
3545
3546
3547
3548
3549
3550
3551
3552
3553
3554
3555
3556
3557
3558
3559
3560
3561
3562
3563
3564
3565
3566
3567
3568
3569
3570
3571
3572
3573
3574
3575
3576
3577
3578
3579
3580
3581
3582
3583
3584
3585
3586
3587
3588
3589
3590
3591
3592
3593
3594
3595
3596
3597
3598
3599
3600
3601
3602
3603
3604
3605
3606
3607
3608
3609
3610
3611
3612
3613
3614
3615
3616
3617
3618
3619
3620
3621
3622
3623
3624
3625
3626
3627
3628
3629
3630
3631
3632
3633
3634
3635
3636
3637
3638
3639
3640
3641
3642
3643
3644
3645
3646
3647
3648
3649
3650
3651
3652
3653
3654
3655
3656
3657
3658
3659
3660
3661
3662
3663
3664
3665
3666
3667
3668
3669
3670
3671
3672
3673
3674
3675
3676
3677
3678
3679
3680
3681
3682
3683
3684
3685
3686
3687
3688
3689
3690
3691
3692
3693
3694
3695
3696
3697
3698
3699
3700
3701
3702
3703
3704
3705
3706
3707
3708
3709
3710
3711
3712
3713
3714
3715
3716
3717
3718
3719
3720
3721
3722
3723
3724
3725
3726
3727
3728
3729
3730
3731
3732
3733
3734
3735
3736
3737
3738
3739
3740
3741
3742
3743
3744
3745
3746
3747
3748
3749
3750
3751
3752
3753
3754
3755
3756
3757
3758
3759
3760
3761
3762
3763
3764
3765
3766
3767
3768
3769
3770
3771
3772
3773
3774
3775
3776
3777
3778
3779
3780
3781
3782
3783
3784
3785
3786
3787
3788
3789
3790
3791
3792
3793
3794
3795
3796
3797
3798
3799
3800
3801
3802
3803
3804
3805
3806
3807
3808
3809
3810
3811
3812
3813
3814
3815
3816
3817
3818
3819
3820
3821
3822
3823
3824
3825
3826
3827
3828
3829
3830
3831
3832
3833
3834
3835
3836
3837
3838
3839
3840
3841
3842
3843
3844
3845
3846
3847
3848
3849
3850
3851
3852
3853
3854
3855
3856
3857
3858
3859
3860
3861
3862
3863
3864
3865
3866
3867
3868
3869
3870
3871
3872
3873
3874
3875
3876
3877
3878
3879
3880
3881
3882
3883
3884
3885
3886
3887
3888
3889
3890
3891
3892
3893
3894
3895
3896
3897
3898
3899
3900
3901
3902
3903
3904
3905
3906
3907
3908
3909
3910
3911
3912
3913
3914
3915
3916
3917
3918
3919
3920
3921
3922
3923
3924
3925
3926
3927
3928
3929
3930
3931
3932
3933
3934
3935
3936
3937
3938
3939
3940
3941
3942
3943
3944
3945
3946
3947
3948
3949
3950
3951
3952
3953
3954
3955
3956
3957
3958
3959
3960
3961
3962
3963
3964
3965
3966
3967
3968
3969
3970
3971
3972
3973
3974
3975
3976
3977
3978
3979
3980
3981
3982
3983
3984
3985
3986
3987
3988
3989
3990
3991
3992
3993
3994
3995
3996
3997
3998
3999
4000
4001
4002
4003
4004
4005
4006
4007
4008
4009
4010
4011
4012
4013
4014
4015
4016
4017
4018
4019
4020
4021
4022
4023
4024
4025
4026
4027
4028
4029
4030
4031
4032
4033
4034
4035
4036
4037
4038
4039
4040
4041
4042
4043
4044
4045
4046
4047
4048
4049
4050
4051
4052
4053
4054
4055
4056
4057
4058
4059
4060
4061
4062
4063
4064
4065
4066
4067
4068
4069
4070
4071
4072
4073
4074
4075
4076
4077
4078
4079
4080
4081
4082
4083
4084
4085
4086
4087
4088
4089
4090
4091
4092
4093
4094
4095
4096
4097
4098
4099
4100
4101
4102
4103
4104
4105
4106
4107
4108
4109
4110
4111
4112
4113
4114
4115
4116
4117
4118
4119
4120
4121
4122
4123
4124
4125
4126
4127
4128
4129
4130
4131
4132
4133
4134
4135
4136
4137
4138
4139
4140
4141
4142
4143
4144
4145
4146
4147
4148
4149
4150
4151
4152
4153
4154
4155
4156
4157
4158
4159
4160
4161
4162
4163
4164
4165
4166
4167
4168
4169
4170
4171
4172
4173
4174
4175
4176
4177
4178
4179
4180
4181
4182
4183
4184
4185
4186
4187
4188
4189
4190
4191
4192
4193
4194
4195
4196
4197
4198
4199
4200
4201
4202
4203
4204
4205
4206
4207
4208
4209
4210
4211
4212
4213
4214
4215
4216
4217
4218
4219
4220
4221
4222
4223
4224
4225
4226
4227
4228
4229
4230
4231
4232
4233
4234
4235
4236
4237
4238
4239
4240
4241
4242
4243
4244
4245
4246
4247
4248
4249
4250
4251
4252
4253
4254
4255
4256
4257
4258
4259
4260
4261
4262
4263
4264
4265
4266
4267
4268
4269
4270
4271
4272
4273
4274
4275
4276
4277
4278
4279
4280
4281
4282
4283
4284
4285
4286
4287
4288
4289
4290
4291
4292
4293
4294
4295
4296
4297
4298
4299
4300
4301
4302
4303
4304
4305
4306
4307
4308
4309
4310
4311
4312
4313
4314
4315
4316
4317
4318
4319
4320
4321
4322
4323
4324
4325
4326
4327
4328
4329
4330
4331
4332
4333
4334
4335
4336
4337
4338
4339
4340
4341
4342
4343
4344
4345
4346
4347
4348
4349
4350
4351
4352
4353
4354
4355
4356
4357
4358
4359
4360
4361
4362
4363
4364
4365
4366
4367
4368
4369
4370
4371
4372
4373
4374
4375
4376
4377
4378
4379
4380
4381
4382
4383
4384
4385
4386
4387
4388
4389
4390
4391
4392
4393
4394
4395
4396
4397
4398
4399
4400
4401
4402
4403
4404
4405
4406
4407
4408
4409
4410
4411
4412
4413
4414
4415
4416
4417
4418
4419
4420
4421
4422
4423
4424
4425
4426
4427
4428
4429
4430
4431
4432
4433
4434
4435
4436
4437
4438
4439
4440
4441
4442
4443
4444
4445
4446
4447
4448
4449
4450
4451
4452
4453
4454
4455
4456
4457
4458
4459
4460
4461
4462
4463
4464
4465
4466
4467
4468
4469
4470
4471
4472
4473
4474
4475
4476
4477
4478
4479
4480
4481
4482
4483
4484
4485
4486
4487
4488
4489
4490
4491
4492
4493
4494
4495
4496
4497
4498
4499
4500
4501
4502
4503
4504
4505
4506
4507
4508
4509
4510
4511
4512
4513
4514
4515
4516
4517
4518
4519
4520
4521
4522
4523
4524
4525
4526
4527
4528
4529
4530
4531
4532
4533
4534
4535
4536
4537
4538
4539
4540
4541
4542
4543
4544
4545
4546
4547
4548
4549
4550
4551
4552
4553
4554
4555
4556
4557
4558
4559
4560
4561
4562
4563
4564
4565
4566
4567
4568
4569
4570
4571
4572
4573
4574
4575
4576
4577
4578
4579
4580
4581
4582
4583
4584
4585
4586
4587
4588
4589
4590
4591
4592
4593
4594
4595
4596
4597
4598
4599
4600
4601
4602
4603
4604
4605
4606
4607
4608
4609
4610
4611
4612
4613
4614
4615
4616
4617
4618
4619
4620
4621
4622
4623
4624
4625
4626
4627
4628
4629
4630
4631
4632
4633
4634
4635
4636
4637
4638
4639
4640
4641
4642
4643
4644
4645
4646
4647
4648
4649
4650
4651
4652
4653
4654
4655
4656
4657
4658
4659
4660
4661
4662
4663
4664
4665
4666
4667
4668
4669
4670
4671
4672
4673
4674
4675
4676
4677
4678
4679
4680
4681
4682
4683
4684
4685
4686
4687
4688
4689
4690
4691
4692
4693
4694
4695
4696
4697
4698
4699
4700
4701
4702
4703
4704
4705
4706
4707
4708
4709
4710
4711
4712
4713
4714
4715
4716
4717
4718
4719
4720
4721
4722
4723
4724
4725
4726
4727
4728
4729
4730
4731
4732
4733
4734
4735
4736
4737
4738
4739
4740
4741
4742
4743
4744
4745
4746
4747
4748
4749
4750
4751
4752
4753
4754
4755
4756
4757
4758
4759
4760
4761
4762
4763
4764
4765
4766
4767
4768
4769
4770
4771
4772
4773
4774
4775
4776
4777
4778
4779
4780
4781
4782
4783
4784
4785
4786
4787
4788
4789
4790
4791
4792
4793
4794
4795
4796
4797
4798
4799
4800
4801
4802
4803
4804
4805
4806
4807
4808
4809
4810
4811
4812
4813
4814
4815
4816
4817
4818
4819
4820
4821
4822
4823
4824
4825
4826
4827
4828
4829
4830
4831
4832
4833
4834
4835
4836
4837
4838
4839
4840
4841
4842
4843
4844
4845
4846
4847
4848
4849
4850
4851
4852
4853
4854
4855
4856
4857
4858
4859
4860
4861
4862
4863
4864
4865
4866
4867
4868
4869
4870
4871
4872
4873
4874
4875
4876
4877
4878
4879
4880
4881
4882
4883
4884
4885
4886
4887
4888
4889
4890
4891
4892
4893
4894
4895
4896
4897
4898
4899
4900
4901
4902
4903
4904
4905
4906
4907
4908
4909
4910
4911
4912
4913
4914
4915
4916
4917
4918
4919
4920
4921
4922
4923
4924
4925
4926
4927
4928
4929
4930
4931
4932
4933
4934
4935
4936
4937
4938
4939
4940
4941
4942
4943
4944
4945
4946
4947
4948
4949
4950
4951
4952
4953
4954
4955
4956
4957
4958
4959
4960
4961
4962
4963
4964
4965
4966
4967
4968
4969
4970
4971
4972
4973
4974
4975
4976
4977
4978
4979
4980
4981
4982
4983
4984
4985
4986
4987
4988
4989
4990
4991
4992
4993
4994
4995
4996
4997
4998
4999
5000
5001
5002
5003
5004
5005
5006
5007
5008
5009
5010
5011
5012
/*
  This file is part of TALER
  Copyright (C) 2014, 2015, 2016 GNUnet e.V.

  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/>
*/

/**
 * @file plugin_exchangedb_postgres.c
 * @brief Low-level (statement-level) Postgres database access for the exchange
 * @author Florian Dold
 * @author Christian Grothoff
 * @author Sree Harsha Totakura
 * @author Marcello Stanisci
 */
#include "platform.h"
#include "taler_pq_lib.h"
#include "taler_exchangedb_plugin.h"
#include <pthread.h>
#include <libpq-fe.h>

#include "plugin_exchangedb_common.c"

/**
 * Log a query error.
 *
 * @param result PQ result object of the query that failed
 */
#define QUERY_ERR(result)                          \
  GNUNET_log (GNUNET_ERROR_TYPE_ERROR, "Query failed at %s:%u: %s (%s)\n", __FILE__, __LINE__, PQresultErrorMessage (result), PQresStatus (PQresultStatus (result)))


/**
 * Log a really unexpected PQ error.
 *
 * @param result PQ result object of the PQ operation that failed
 */
#define BREAK_DB_ERR(result) do { \
    GNUNET_break (0); \
    GNUNET_log (GNUNET_ERROR_TYPE_ERROR, "Database failure: %s (%s)\n", PQresultErrorMessage (result), PQresStatus (PQresultStatus (result))); \
  } while (0)


/**
 * Shorthand for exit jumps.  Logs the current line number
 * and jumps to the "EXITIF_exit" label.
 *
 * @param cond condition that must be TRUE to exit with an error
 */
#define EXITIF(cond)                                              \
  do {                                                            \
    if (cond) { GNUNET_break (0); goto EXITIF_exit; }             \
  } while (0)


/**
 * Execute an SQL statement and log errors on failure. Must be
 * run in a function that has an "SQLEXEC_fail" label to jump
 * to in case the SQL statement failed.
 *
 * @param conn database connection
 * @param sql SQL statement to run
 */
#define SQLEXEC_(conn, sql)                                             \
  do {                                                                  \
    PGresult *result = PQexec (conn, sql);                              \
    if (PGRES_COMMAND_OK != PQresultStatus (result))                    \
    {                                                                   \
      BREAK_DB_ERR (result);                                            \
      PQclear (result);                                                 \
      goto SQLEXEC_fail;                                                \
    }                                                                   \
    PQclear (result);                                                   \
  } while (0)


/**
 * Run an SQL statement, ignoring errors and clearing the result.
 *
 * @param conn database connection
 * @param sql SQL statement to run
 */
#define SQLEXEC_IGNORE_ERROR_(conn, sql)                                \
  do {                                                                  \
    PGresult *result = PQexec (conn, sql);                              \
    PQclear (result);                                                   \
  } while (0)


/**
 * Handle for a database session (per-thread, for transactions).
 */
struct TALER_EXCHANGEDB_Session
{
  /**
   * Postgres connection handle.
   */
  PGconn *conn;
};


/**
 * Type of the "cls" argument given to each of the functions in
 * our API.
 */
struct PostgresClosure
{

  /**
   * Thread-local database connection.
   * Contains a pointer to `PGconn` or NULL.
   */
  pthread_key_t db_conn_threadlocal;

  /**
   * Database connection string, as read from
   * the configuration.
   */
  char *connection_cfg_str;
};


/**
 * Function called by libpq whenever it wants to log something.
 * We already log whenever we care, so this function does nothing
 * and merely exists to silence the libpq logging.
 *
 * @param arg NULL
 * @param res information about some libpq event
 */
static void
pq_notice_receiver_cb (void *arg,
                       const PGresult *res)
{
  /* do nothing, intentionally */
}


/**
 * Function called by libpq whenever it wants to log something.
 * We log those using the Taler logger.
 *
 * @param arg NULL
 * @param message information about some libpq event
 */
static void
pq_notice_processor_cb (void *arg,
                        const char *message)
{
  GNUNET_log_from (GNUNET_ERROR_TYPE_INFO,
                   "pq",
                   "%s",
                   message);
}


/**
 * Establish connection to the Postgres database
 * and initialize callbacks for logging.
 *
 * @param pc configuration to use
 * @return NULL on error
 */
static PGconn *
connect_to_postgres (struct PostgresClosure *pc)
{
  PGconn *conn;

  conn = PQconnectdb (pc->connection_cfg_str);
  if (CONNECTION_OK !=
      PQstatus (conn))
  {
    TALER_LOG_ERROR ("Database connection failed: %s\n",
                     PQerrorMessage (conn));
    return NULL;
  }
  PQsetNoticeReceiver (conn,
                       &pq_notice_receiver_cb,
                       NULL);
  PQsetNoticeProcessor (conn,
                        &pq_notice_processor_cb,
                        NULL);
  return conn;
}


/**
 * Drop all Taler tables.  This should only be used by testcases.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
 */
static int
postgres_drop_tables (void *cls)
{
  struct PostgresClosure *pc = cls;
  PGconn *conn;

  conn = connect_to_postgres (pc);
  if (NULL == conn)
    return GNUNET_SYSERR;
  GNUNET_log (GNUNET_ERROR_TYPE_INFO,
              "Dropping ALL tables\n");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS prewire;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS aggregation_tracking;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS deposits;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS refresh_out;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS refresh_commit_coin;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS refresh_transfer_public_key;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS refunds;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS refresh_order;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS refresh_sessions CASCADE;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS known_coins CASCADE;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS reserves_out;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS reserves_in;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS reserves;");
  SQLEXEC_ (conn,
            "DROP TABLE IF EXISTS denominations CASCADE;");
  PQfinish (conn);
  return GNUNET_OK;
 SQLEXEC_fail:
  PQfinish (conn);
  return GNUNET_SYSERR;
}


/**
 * Create the necessary tables if they are not present
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
 */
static int
postgres_create_tables (void *cls)
{
  struct PostgresClosure *pc = cls;
  PGconn *conn;

  conn = connect_to_postgres (pc);
  if (NULL == conn)
    return GNUNET_SYSERR;
#define SQLEXEC(sql) SQLEXEC_(conn, sql);
#define SQLEXEC_INDEX(sql) SQLEXEC_IGNORE_ERROR_(conn, sql);
  /* Denomination table for holding the publicly available information of
     denominations keys.  The denominations are to be referred to using
     foreign keys. */
  SQLEXEC ("CREATE TABLE IF NOT EXISTS denominations"
           "(denom_pub BYTEA PRIMARY KEY"
           ",master_pub BYTEA NOT NULL CHECK (LENGTH(master_pub)=32)"
           ",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" /* value of this denom */
           ",coin_frac INT4 NOT NULL" /* fractional value of this denom */
           ",coin_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL" /* assuming same currency for fees */
           ",fee_withdraw_val INT8 NOT NULL"
           ",fee_withdraw_frac INT4 NOT NULL"
           ",fee_withdraw_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
           ",fee_deposit_val INT8 NOT NULL"
           ",fee_deposit_frac INT4 NOT NULL"
           ",fee_deposit_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
           ",fee_refresh_val INT8 NOT NULL"
           ",fee_refresh_frac INT4 NOT NULL"
           ",fee_refresh_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
           ",fee_refund_val INT8 NOT NULL"
           ",fee_refund_frac INT4 NOT NULL"
           ",fee_refund_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
           ")");
  /* reserves table is for summarization of a reserve.  It is updated when new
     funds are added and existing funds are withdrawn.  The 'expiration_date'
     can be used to eventually get rid of reserves that have not been used
     for a very long time (either by refunding the owner or by greedily
     grabbing the money, depending on the Exchange's terms of service) */
  SQLEXEC ("CREATE TABLE IF NOT EXISTS reserves"
           "(reserve_pub BYTEA PRIMARY KEY CHECK(LENGTH(reserve_pub)=32)"
           ",current_balance_val INT8 NOT NULL"
           ",current_balance_frac INT4 NOT NULL"
           ",current_balance_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
           ",expiration_date INT8 NOT NULL"
           ")");
  /* index on reserves table */
  SQLEXEC_INDEX ("CREATE INDEX reserves_reserve_pub_index ON "
                 "reserves (reserve_pub)");
  SQLEXEC_INDEX ("CREATE INDEX reserves_expiration_index"
		 " ON reserves (expiration_date);");
  /* reserves_in table collects the transactions which transfer funds
     into the reserve.  The rows of this table correspond to each
     incoming transaction. */
  SQLEXEC("CREATE TABLE IF NOT EXISTS reserves_in"
          "(reserve_in_serial_id BIGSERIAL"
	  ",reserve_pub BYTEA NOT NULL REFERENCES reserves (reserve_pub) ON DELETE CASCADE"
          ",credit_val INT8 NOT NULL"
          ",credit_frac INT4 NOT NULL"
          ",credit_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
          ",sender_account_details TEXT NOT NULL "
          ",transfer_details TEXT NOT NULL "
          ",execution_date INT8 NOT NULL"
          ",PRIMARY KEY (reserve_pub, transfer_details)"
          ");");
  /* Create indices on reserves_in */
  SQLEXEC_INDEX ("CREATE INDEX reserves_in_execution_index"
		 " ON reserves_in (execution_date);");
  /* Table with the withdraw operations that have been performed on a reserve.
     The 'h_blind_ev' is the hash of the blinded coin. It serves as a primary
     key, as (broken) clients that use a non-random coin and blinding factor
     should fail to even withdraw, as otherwise the coins will fail to deposit
     (as they really must be unique). */
  SQLEXEC ("CREATE TABLE IF NOT EXISTS reserves_out"
           "(reserve_out_serial_id BIGSERIAL"
	   ",h_blind_ev BYTEA PRIMARY KEY"
           ",denom_pub BYTEA NOT NULL REFERENCES denominations (denom_pub) ON DELETE CASCADE"
           ",denom_sig BYTEA NOT NULL"
           ",reserve_pub BYTEA NOT NULL REFERENCES reserves (reserve_pub) 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"
           ",amount_with_fee_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
           ");");
  /* Index blindcoins(reserve_pub) for get_reserves_out statement */
  SQLEXEC_INDEX ("CREATE INDEX reserves_out_reserve_pub_index ON"
                 " reserves_out (reserve_pub)");
  SQLEXEC_INDEX ("CREATE INDEX reserves_out_execution_date ON "
                 "reserves_out (execution_date)");
  /* Table with coins that have been (partially) spent, used to track
     coin information only once. */
  SQLEXEC("CREATE TABLE IF NOT EXISTS known_coins "
          "(coin_pub BYTEA NOT NULL PRIMARY KEY CHECK (LENGTH(coin_pub)=32)"
          ",denom_pub BYTEA NOT NULL REFERENCES denominations (denom_pub) ON DELETE CASCADE"
          ",denom_sig BYTEA NOT NULL"
          ")");
  /**
   * The DB will show negative values for some values of the following fields as
   * we use them as 16 bit unsigned integers
   *   @a num_newcoins
   *   @a noreveal_index
   * Do not do arithmetic in SQL on these fields.
   * NOTE: maybe we should instead forbid values >= 2^15 categorically?
   */
  SQLEXEC("CREATE TABLE IF NOT EXISTS refresh_sessions "
          "(melt_serial_id BIGSERIAL"
	  ",session_hash BYTEA PRIMARY KEY CHECK (LENGTH(session_hash)=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"
          ",amount_with_fee_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
          ",num_newcoins INT2 NOT NULL"
          ",noreveal_index INT2 NOT NULL"
          ")");

  /* Table with information about the desired denominations to be created
     during a refresh operation; contains the denomination key for each
     of the coins (for a given refresh session) */
  SQLEXEC("CREATE TABLE IF NOT EXISTS refresh_order "
          "(session_hash BYTEA NOT NULL REFERENCES refresh_sessions (session_hash) ON DELETE CASCADE"
          ",newcoin_index INT2 NOT NULL "
          ",denom_pub BYTEA NOT NULL REFERENCES denominations (denom_pub) ON DELETE CASCADE"
          ",PRIMARY KEY (session_hash, newcoin_index)"
          ")");

  /* Table with the commitments for a refresh operation; includes
     the session_hash for which this is the link information, the
     oldcoin index and the cut-and-choose index (from 0 to #TALER_CNC_KAPPA-1),
     as well as the actual link data (the transfer public key and the encrypted
     link secret) */
  SQLEXEC("CREATE TABLE IF NOT EXISTS refresh_transfer_public_key "
          "(session_hash BYTEA NOT NULL PRIMARY KEY REFERENCES refresh_sessions (session_hash) ON DELETE CASCADE"
          ",transfer_pub BYTEA NOT NULL CHECK(LENGTH(transfer_pub)=32)"
          ")");

  /* Table with the commitments for the new coins that are to be created
     during a melting session.  Includes the session, the cut-and-choose
     index and the index of the new coin, and the envelope of the new
     coin to be signed, as well as the encrypted information about the
     private key and the blinding factor for the coin (for verification
     in case this newcoin_index is chosen to be revealed) */
  SQLEXEC("CREATE TABLE IF NOT EXISTS refresh_commit_coin "
          "(session_hash BYTEA NOT NULL REFERENCES refresh_sessions (session_hash) ON DELETE CASCADE"
          ",newcoin_index INT2 NOT NULL"
          ",coin_ev BYTEA NOT NULL"
          ",UNIQUE (session_hash, newcoin_index)"
          ")");
  SQLEXEC_INDEX("CREATE INDEX refresh_commit_coin_session_hash_index "
                "ON refresh_commit_coin(session_hash, newcoin_index)");


  /* Table with the signatures over coins generated during a refresh
     operation. Needed to answer /refresh/link queries later.  Stores
     the coin signatures under the respective session hash and index. */
  SQLEXEC("CREATE TABLE IF NOT EXISTS refresh_out "
          "(session_hash BYTEA NOT NULL REFERENCES refresh_sessions (session_hash) ON DELETE CASCADE"
          ",newcoin_index INT2 NOT NULL"
          ",ev_sig BYTEA NOT NULL"
          ",UNIQUE (session_hash, newcoin_index)"
          ")");
  SQLEXEC_INDEX("CREATE INDEX refresh_out_session_hash_index "
                "ON refresh_out(session_hash, newcoin_index)");

  /* This table contains the wire transfers the exchange is supposed to
     execute to transmit funds to the merchants (and manage refunds). */
  SQLEXEC("CREATE TABLE IF NOT EXISTS deposits "
          "(deposit_serial_id BIGSERIAL PRIMARY KEY"
          ",coin_pub BYTEA NOT NULL REFERENCES known_coins (coin_pub) ON DELETE CASCADE"
          ",transaction_id INT8 NOT NULL"
          ",amount_with_fee_val INT8 NOT NULL"
          ",amount_with_fee_frac INT4 NOT NULL"
          ",amount_with_fee_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
          ",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 BYTEA NOT NULL CHECK (LENGTH(h_contract)=64)"
          ",h_wire BYTEA NOT NULL CHECK (LENGTH(h_wire)=64)"
          ",coin_sig BYTEA NOT NULL CHECK (LENGTH(coin_sig)=64)"
          ",wire TEXT NOT NULL"
          ",tiny BOOLEAN NOT NULL DEFAULT false"
          ",done BOOLEAN NOT NULL DEFAULT false"
          ",UNIQUE (coin_pub, transaction_id, merchant_pub)"
          ")");
  /* Index for get_deposit statement on coin_pub, transaction_id and merchant_pub */
  SQLEXEC_INDEX("CREATE INDEX deposits_coin_pub_index "
                "ON deposits(coin_pub, transaction_id, merchant_pub)");

  /* Table with information about coins that have been refunded. (Technically
     one of the deposit operations that a coin was involved with is refunded.)*/
  SQLEXEC("CREATE TABLE IF NOT EXISTS refunds "
          "(refund_serial_id BIGSERIAL"
	  ",coin_pub BYTEA NOT NULL REFERENCES known_coins (coin_pub) ON DELETE CASCADE"
          ",merchant_pub BYTEA NOT NULL CHECK(LENGTH(merchant_pub)=32)"
          ",merchant_sig BYTEA NOT NULL CHECK(LENGTH(merchant_sig)=64)"
          ",h_contract BYTEA NOT NULL CHECK(LENGTH(h_contract)=64)"
          ",transaction_id INT8 NOT NULL"
          ",rtransaction_id INT8 NOT NULL"
          ",amount_with_fee_val INT8 NOT NULL"
          ",amount_with_fee_frac INT4 NOT NULL"
          ",amount_with_fee_curr VARCHAR("TALER_CURRENCY_LEN_STR") NOT NULL"
          ",PRIMARY KEY (coin_pub, merchant_pub, transaction_id, rtransaction_id)" /* this combo must be unique, and we usually select by coin_pub */
          ") ");

  /* Table for the tracking API, mapping from wire transfer identifiers
     to transactions and back */
  SQLEXEC("CREATE TABLE IF NOT EXISTS aggregation_tracking "
          "(deposit_serial_id INT8 PRIMARY KEY REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE"
          ",wtid_raw BYTEA NOT NULL CHECK (LENGTH(wtid_raw)=" TALER_WIRE_TRANSFER_IDENTIFIER_LEN_STR ")"
          ",execution_time INT8 NOT NULL"
          ")");
  /* Index for lookup_transactions statement on wtid */
  SQLEXEC_INDEX("CREATE INDEX aggregation_tracking_wtid_index "
                "ON aggregation_tracking(wtid_raw)");

  /* This table contains the pre-commit data for
     wire transfers the exchange is about to execute. */
  SQLEXEC("CREATE TABLE IF NOT EXISTS prewire "
          "(prewire_uuid BIGSERIAL PRIMARY KEY"
          ",type TEXT NOT NULL"
          ",finished BOOLEAN NOT NULL DEFAULT false"
          ",buf BYTEA NOT NULL"
          ")");
  /* Index for prepare_data_iterate statement */
  SQLEXEC_INDEX("CREATE INDEX prepare_iteration_index "
                "ON prewire(type,finished)");


#undef SQLEXEC
#undef SQLEXEC_INDEX

  PQfinish (conn);
  return GNUNET_OK;

 SQLEXEC_fail:
  PQfinish (conn);
  return GNUNET_SYSERR;
}


/**
 * Setup prepared statements.
 *
 * @param db_conn connection handle to initialize
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on failure
 */
static int
postgres_prepare (PGconn *db_conn)
{
  PGresult *result;

#define PREPARE(name, sql, ...)                                 \
  do {                                                          \
    result = PQprepare (db_conn, name, sql, __VA_ARGS__);       \
    if (PGRES_COMMAND_OK != PQresultStatus (result))            \
    {                                                           \
      BREAK_DB_ERR (result);                                    \
      PQclear (result); result = NULL;                          \
      return GNUNET_SYSERR;                                     \
    }                                                           \
    PQclear (result); result = NULL;                            \
  } while (0);

  /* Used in #postgres_insert_denomination_info() */
  PREPARE ("denomination_insert",
           "INSERT INTO denominations "
           "(denom_pub"
           ",master_pub"
           ",master_sig"
           ",valid_from"
           ",expire_withdraw"
           ",expire_deposit"
           ",expire_legal"
           ",coin_val" /* value of this denom */
           ",coin_frac" /* fractional value of this denom */
           ",coin_curr" /* assuming same currency for fees */
           ",fee_withdraw_val"
           ",fee_withdraw_frac"
           ",fee_withdraw_curr" /* must match coin_curr */
           ",fee_deposit_val"
           ",fee_deposit_frac"
           ",fee_deposit_curr"  /* must match coin_curr */
           ",fee_refresh_val"
           ",fee_refresh_frac"
           ",fee_refresh_curr" /* must match coin_curr */
           ",fee_refund_val"
           ",fee_refund_frac"
           ",fee_refund_curr" /* must match coin_curr */
           ") VALUES "
           "($1, $2, $3, $4, $5, $6, $7, $8, $9, $10,"
           " $11, $12, $13, $14, $15, $16, $17, $18,"
	   " $19, $20, $21, $22);",
           22, NULL);

  /* Used in #postgres_get_denomination_info() */
  PREPARE ("denomination_get",
           "SELECT"
           " master_pub"
           ",master_sig"
           ",valid_from"
           ",expire_withdraw"
           ",expire_deposit"
           ",expire_legal"
           ",coin_val"  /* value of this denom */
           ",coin_frac" /* fractional value of this denom */
           ",coin_curr" /* assuming same currency for fees */
           ",fee_withdraw_val"
           ",fee_withdraw_frac"
           ",fee_withdraw_curr" /* must match coin_curr */
           ",fee_deposit_val"
           ",fee_deposit_frac"
           ",fee_deposit_curr"  /* must match coin_curr */
           ",fee_refresh_val"
           ",fee_refresh_frac"
           ",fee_refresh_curr" /* must match coin_curr */
           ",fee_refund_val"
           ",fee_refund_frac"
           ",fee_refund_curr" /* must match coin_curr */
           " FROM denominations"
           " WHERE denom_pub=$1;",
           1, NULL);

  /* Used in #postgres_reserve_get() */
  PREPARE ("reserve_get",
           "SELECT"
           " current_balance_val"
           ",current_balance_frac"
           ",current_balance_curr"
           ",expiration_date"
           " FROM reserves"
           " WHERE reserve_pub=$1"
           " LIMIT 1;",
           1, NULL);

  /* Used in #postgres_reserves_in_insert() when the reserve is new */
  PREPARE ("reserve_create",
           "INSERT INTO reserves "
           "(reserve_pub"
           ",current_balance_val"
           ",current_balance_frac"
           ",current_balance_curr"
           ",expiration_date"
           ") VALUES "
           "($1, $2, $3, $4, $5);",
           5, NULL);

  /* Used in #postgres_reserves_update() when the reserve is updated */
  PREPARE ("reserve_update",
           "UPDATE reserves"
           " SET"
           " expiration_date=$1 "
           ",current_balance_val=$2 "
           ",current_balance_frac=$3 "
           "WHERE current_balance_curr=$4 AND reserve_pub=$5",
           5, NULL);

  /* Used in #postgres_reserves_in_insert() to store transaction details */
  PREPARE ("reserves_in_add_transaction",
           "INSERT INTO reserves_in "
           "(reserve_pub"
           ",credit_val"
           ",credit_frac"
           ",credit_curr"
           ",sender_account_details"
           ",transfer_details"
           ",execution_date"
           ") VALUES "
           "($1, $2, $3, $4, $5, $6, $7);",
           7, NULL);


  /* Used in postgres_select_reserves_in_above_serial_id() to obtain inbound
     transactions for reserves with serial id '\geq' the given parameter */
  PREPARE ("audit_reserves_in_get_transactions_incr",
           "SELECT"
           " reserve_pub"
           ",credit_val"
           ",credit_frac"
           ",credit_curr"
           ",execution_date"
           ",sender_account_details"
           ",transfer_details"
           " FROM reserves_in"
           " WHERE reserve_in_serial_id>=$1"
           " ORDER BY reserve_in_serial_id",
           1, NULL);

  /* Used in #postgres_get_reserve_history() to obtain inbound transactions
     for a reserve */
  PREPARE ("reserves_in_get_transactions",
           "SELECT"
           " credit_val"
           ",credit_frac"
           ",credit_curr"
           ",execution_date"
           ",sender_account_details"
           ",transfer_details"
           " FROM reserves_in"
           " WHERE reserve_pub=$1",
           1, NULL);

  /* Used in #postgres_insert_withdraw_info() to store
     the signature of a blinded coin with the blinded coin's
     details before returning it during /reserve/withdraw. We store
     the coin's denomination information (public key, signature)
     and the blinded message as well as the reserve that the coin
     is being withdrawn from and the signature of the message
     authorizing the withdrawal. */
  PREPARE ("insert_withdraw_info",
           "INSERT INTO reserves_out "
           "(h_blind_ev"
           ",denom_pub"
           ",denom_sig"
           ",reserve_pub"
           ",reserve_sig"
           ",execution_date"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ") VALUES "
           "($1, $2, $3, $4, $5, $6, $7, $8, $9);",
           9, NULL);

  /* Used in #postgres_get_withdraw_info() to
     locate the response for a /reserve/withdraw request
     using the hash of the blinded message.  Used to
     make sure /reserve/withdraw requests are idempotent. */
  PREPARE ("get_withdraw_info",
           "SELECT"
           " denom_pub"
           ",denom_sig"
           ",reserve_sig"
           ",reserve_pub"
           ",execution_date"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_withdraw_val"
           ",denom.fee_withdraw_frac"
           ",denom.fee_withdraw_curr"
           " FROM reserves_out"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE h_blind_ev=$1",
           1, NULL);

  /* Used during #postgres_get_reserve_history() to
     obtain all of the /reserve/withdraw operations that
     have been performed on a given reserve. (i.e. to
     demonstrate double-spending) */
  PREPARE ("get_reserves_out",
           "SELECT"
           " h_blind_ev"
           ",denom_pub"
           ",denom_sig"
           ",reserve_sig"
           ",execution_date"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_withdraw_val"
           ",denom.fee_withdraw_frac"
           ",denom.fee_withdraw_curr"
           " FROM reserves_out"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE reserve_pub=$1;",
           1, NULL);

  /* Used in #postgres_select_reserves_out_above_serial_id() */
  PREPARE ("audit_get_reserves_out_incr",
           "SELECT"
           " h_blind_ev"
           ",denom_pub"
           ",denom_sig"
           ",reserve_sig"
           ",reserve_pub"
           ",execution_date"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           " FROM reserves_out"
           " WHERE reserve_out_serial_id>=$1"
           " ORDER BY reserve_out_serial_id ASC",
           1, NULL);

  /* Used in #postgres_get_refresh_session() to fetch
     high-level information about a refresh session */
  PREPARE ("get_refresh_session",
           "SELECT"
           " old_coin_pub"
           ",old_coin_sig"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_refresh_val "
           ",denom.fee_refresh_frac "
           ",denom.fee_refresh_curr "
           ",num_newcoins"
           ",noreveal_index"
           " FROM refresh_sessions "
           "    JOIN known_coins ON (refresh_sessions.old_coin_pub = known_coins.coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE session_hash=$1 ",
           1, NULL);

  /* Used in #postgres_select_refreshs_above_serial_id() to fetch
     refresh session with id '\geq' the given parameter */
  PREPARE ("audit_get_refresh_sessions_incr",
           "SELECT"
           " old_coin_pub"
           ",old_coin_sig"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",num_newcoins"
           ",noreveal_index"
           " FROM refresh_sessions"
           " WHERE melt_serial_id>=$1"
           " ORDER BY melt_serial_id ASC",
           1, NULL);

  /* Used in #postgres_create_refresh_session() to store
     high-level information about a refresh session */
  PREPARE ("insert_refresh_session",
           "INSERT INTO refresh_sessions "
           "(session_hash "
           ",old_coin_pub "
           ",old_coin_sig "
           ",amount_with_fee_val "
           ",amount_with_fee_frac "
           ",amount_with_fee_curr "
           ",num_newcoins "
           ",noreveal_index "
           ") VALUES "
           "($1, $2, $3, $4, $5, $6, $7, $8);",
           8, NULL);

  /* Used in #postgres_get_known_coin() to fetch
     the denomination public key and signature for
     a coin known to the exchange. */
  PREPARE ("get_known_coin",
           "SELECT"
           " denom_pub"
           ",denom_sig"
           " FROM known_coins"
           " WHERE coin_pub=$1",
           1, NULL);

  /* Used in #postgres_insert_known_coin() to store
     the denomination public key and signature for
     a coin known to the exchange. */
  PREPARE ("insert_known_coin",
           "INSERT INTO known_coins "
           "(coin_pub"
           ",denom_pub"
           ",denom_sig"
           ") VALUES "
           "($1,$2,$3);",
           3, NULL);

  /* Store information about the desired denominations for a
     refresh operation, used in #postgres_insert_refresh_order() */
  PREPARE ("insert_refresh_order",
           "INSERT INTO refresh_order "
           "(newcoin_index "
           ",session_hash "
           ",denom_pub "
           ") VALUES "
           "($1, $2, $3);",
           3, NULL);

  /* Obtain information about the desired denominations for a
     refresh operation, used in #postgres_get_refresh_order() */
  PREPARE ("get_refresh_order",
           "SELECT denom_pub"
           " FROM refresh_order"
           " WHERE session_hash=$1 AND newcoin_index=$2",
           2, NULL);

  /* Query the 'refresh_sessions' by coin public key */
  PREPARE ("get_refresh_session_by_coin",
           "SELECT"
           " session_hash"
           ",old_coin_sig"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_refresh_val "
           ",denom.fee_refresh_frac "
           ",denom.fee_refresh_curr "
           " FROM refresh_sessions"
           "    JOIN known_coins ON (refresh_sessions.old_coin_pub = known_coins.coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE old_coin_pub=$1",
           1, NULL);

  /* Fetch refunds with rowid '\geq' the given parameter */
  PREPARE ("audit_get_refunds_incr",
           "SELECT"
           " merchant_pub"
           ",merchant_sig"
           ",h_contract"
           ",transaction_id"
           ",rtransaction_id"
           ",coin_pub"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           " FROM refunds"
           " WHERE refund_serial_id>=$1"
           " ORDER BY refund_serial_id ASC",
           1, NULL);

  /* Query the 'refunds' by coin public key */
  PREPARE ("get_refunds_by_coin",
           "SELECT"
           " merchant_pub"
           ",merchant_sig"
           ",h_contract"
           ",transaction_id"
           ",rtransaction_id"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_refund_val "
           ",denom.fee_refund_frac "
           ",denom.fee_refund_curr "
           " FROM refunds"
           "    JOIN known_coins USING (coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE coin_pub=$1",
           1, NULL);



  /* Used in #postgres_insert_transfer_public_key() to
     store commitments */
  PREPARE ("insert_transfer_public_key",
           "INSERT INTO refresh_transfer_public_key "
           "(session_hash"
           ",transfer_pub"
           ") VALUES "
           "($1, $2);",
           3, NULL);

  /* Used in #postgres_get_refresh_transfer_public_key() to
     retrieve original commitments during /refresh/reveal */
  PREPARE ("get_refresh_transfer_public_key",
           "SELECT"
           " transfer_pub"
           " FROM refresh_transfer_public_key"
           " WHERE session_hash=$1",
           1, NULL);

  /* Used in #postgres_insert_refresh_commit_coins() to
     store coin commitments. */
  PREPARE ("insert_refresh_commit_coin",
           "INSERT INTO refresh_commit_coin "
           "(session_hash"
           ",newcoin_index"
           ",coin_ev"
           ") VALUES "
           "($1, $2, $3);",
           3, NULL);

  /* Used in #postgres_get_refresh_commit_coins() to
     retrieve the original coin envelopes, to either be
     verified or signed. */
  PREPARE ("get_refresh_commit_coin",
           "SELECT"
           " coin_ev"
           " FROM refresh_commit_coin"
           " WHERE session_hash=$1 AND newcoin_index=$2",
           2, NULL);

  /* Store information about a /deposit the exchange is to execute.
     Used in #postgres_insert_deposit(). */
  PREPARE ("insert_deposit",
           "INSERT INTO deposits "
           "(coin_pub"
           ",transaction_id"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",timestamp"
           ",refund_deadline"
           ",wire_deadline"
           ",merchant_pub"
           ",h_contract"
           ",h_wire"
           ",coin_sig"
           ",wire"
           ") VALUES "
           "($1, $2, $3, $4, $5, $6, $7, $8, $9, $10,"
           " $11, $12, $13);",
           13, NULL);

  /* Used in #postgres_insert_refund() to store refund information */
  PREPARE ("insert_refund",
           "INSERT INTO refunds "
           "(coin_pub "
           ",merchant_pub "
           ",merchant_sig "
           ",h_contract "
           ",transaction_id "
           ",rtransaction_id "
           ",amount_with_fee_val "
           ",amount_with_fee_frac "
           ",amount_with_fee_curr "
           ") VALUES "
           "($1, $2, $3, $4, $5, $6, $7, $8, $9);",
           9, NULL);

  /* Fetch an existing deposit request, used to ensure idempotency
     during /deposit processing. Used in #postgres_have_deposit(). */
  PREPARE ("get_deposit",
           "SELECT"
           " amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",timestamp"
           ",refund_deadline"
           ",wire_deadline"
           ",h_contract"
           ",h_wire"
           " FROM deposits"
           " WHERE ("
           "  (coin_pub=$1) AND"
           "  (transaction_id=$2) AND"
           "  (merchant_pub=$3)"
           " )",
           3, NULL);

  /* Fetch deposits with rowid '\geq' the given parameter */
  PREPARE ("audit_get_deposits_incr",
           "SELECT"
           " amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",timestamp"
	   ",merchant_pub"
	   ",coin_pub"
	   ",coin_sig"
	   ",transaction_id"
           ",refund_deadline"
           ",wire_deadline"
           ",h_contract"
           ",wire"
           ",done"
           " FROM deposits"
           " WHERE ("
           "  (deposit_serial_id>=$1)"
           " )"
	   " ORDER BY deposit_serial_id ASC",
           1, NULL);

  /* Fetch an existing deposit request.
     Used in #postgres_wire_lookup_deposit_wtid(). */
  PREPARE ("get_deposit_for_wtid",
           "SELECT"
           " amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_deposit_val"
           ",denom.fee_deposit_frac"
           ",denom.fee_deposit_curr"
           ",wire_deadline"
           " FROM deposits"
           "    JOIN known_coins USING (coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE ("
           "  (coin_pub=$1) AND"
           "  (transaction_id=$2) AND"
           "  (merchant_pub=$3) AND"
           "  (h_contract=$4) AND"
           "  (h_wire=$5)"
           " )",
           5, NULL);

  /* Used in #postgres_get_ready_deposit() */
  PREPARE ("deposits_get_ready",
           "SELECT"
           " deposit_serial_id"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_deposit_val"
           ",denom.fee_deposit_frac"
           ",denom.fee_deposit_curr"
           ",wire_deadline"
           ",transaction_id"
           ",h_contract"
           ",wire"
           ",merchant_pub"
           ",coin_pub"
           " FROM deposits"
           "    JOIN known_coins USING (coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE"
           " tiny=false AND"
           " done=false AND"
           " wire_deadline<=$1 AND"
           " refund_deadline<$1"
           " ORDER BY wire_deadline ASC"
           " LIMIT 1",
           1, NULL);

  /* Used in #postgres_iterate_matching_deposits() */
  PREPARE ("deposits_iterate_matching",
           "SELECT"
           " deposit_serial_id"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_deposit_val"
           ",denom.fee_deposit_frac"
           ",denom.fee_deposit_curr"
           ",wire_deadline"
           ",transaction_id"
           ",h_contract"
           ",coin_pub"
           " FROM deposits"
           "    JOIN known_coins USING (coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE"
           " merchant_pub=$1 AND"
           " h_wire=$2 AND"
           " done=false"
           " ORDER BY wire_deadline ASC"
           " LIMIT " TALER_EXCHANGEDB_MATCHING_DEPOSITS_LIMIT_STR,
           2, NULL);

  /* Used in #postgres_mark_deposit_tiny() */
  PREPARE ("mark_deposit_tiny",
           "UPDATE deposits"
           " SET tiny=true"
           " WHERE deposit_serial_id=$1",
           1, NULL);

  /* Used in #postgres_mark_deposit_done() */
  PREPARE ("mark_deposit_done",
           "UPDATE deposits"
           " SET done=true"
           " WHERE deposit_serial_id=$1",
           1, NULL);

  /* Used in #postgres_test_deposit_done() */
  PREPARE ("test_deposit_done",
           "SELECT done"
           " FROM deposits"
           " WHERE coin_pub=$1"
           " AND transaction_id=$2"
           " AND merchant_pub=$3"
           " AND h_contract=$4"
           " AND h_wire=$5",
           5, NULL);

  /* Used in #postgres_get_coin_transactions() to obtain information
     about how a coin has been spend with /deposit requests. */
  PREPARE ("get_deposit_with_coin_pub",
           "SELECT"
           " transaction_id"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_deposit_val"
           ",denom.fee_deposit_frac"
           ",denom.fee_deposit_curr"
           ",timestamp"
           ",refund_deadline"
           ",merchant_pub"
           ",h_contract"
           ",h_wire"
           ",wire"
           ",coin_sig"
           " FROM deposits"
           "    JOIN known_coins USING (coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE coin_pub=$1",
           1, NULL);

  /* Used in #postgres_insert_refresh_out() to store the
     generated signature(s) for future requests, i.e. /refresh/link */
  PREPARE ("insert_refresh_out",
           "INSERT INTO refresh_out "
           "(session_hash"
           ",newcoin_index"
           ",ev_sig"
           ") VALUES "
           "($1, $2, $3)",
           3, NULL);

  /* Used in #postgres_get_link_data_list().  We use the session_hash
     to obtain the "noreveal_index" for that session, and then select the
     corresponding signatures (ev_sig) and the denomination keys from
     the respective tables (namely refresh_melts and refresh_order)
     using the session_hash as the primary filter (on join) and the
     'noreveal_index' to constrain the selection on the commitment.
     We also want to get the triplet for each of the newcoins, so we
     have another constraint to ensure we get each triplet with
     matching "newcoin_index" values.  NOTE: This may return many
     results, both for different sessions and for the different coins
     being exchangeed in the refresh ops.  NOTE: There may be more
     efficient ways to express the same query.  */
  PREPARE ("get_link",
           "SELECT ev_sig,ro.denom_pub"
           " FROM refresh_sessions rs "
           "     JOIN refresh_order ro USING (session_hash)"
           "     JOIN refresh_commit_coin rcc USING (session_hash)"
           "     JOIN refresh_out rc USING (session_hash)"
           " WHERE ro.session_hash=$1"
           "  AND ro.newcoin_index=rcc.newcoin_index"
           "  AND ro.newcoin_index=rc.newcoin_index",
           1, NULL);

  /* Used in #postgres_get_transfer().  Given the public key of a
     melted coin, we obtain the corresponding encrypted link secret
     and the transfer public key.  This is done by first finding
     the session_hash(es) of all sessions the coin was melted into,
     and then constraining the result to the selected "noreveal_index".
     NOTE: This may (in theory) return multiple results, one per session
     that the old coin was melted into. */
  PREPARE ("get_transfer",
           "SELECT transfer_pub,session_hash"
           " FROM refresh_sessions rs"
           "     JOIN refresh_transfer_public_key rcl USING (session_hash)"
           " WHERE rs.old_coin_pub=$1",
           1, NULL);

  /* Used in #postgres_lookup_wire_transfer */
  PREPARE ("lookup_transactions",
           "SELECT"
           " deposits.h_contract"
           ",deposits.h_wire"
           ",deposits.coin_pub"
           ",deposits.merchant_pub"
           ",deposits.transaction_id"
           ",execution_time"
           ",deposits.amount_with_fee_val"
           ",deposits.amount_with_fee_frac"
           ",deposits.amount_with_fee_curr"
           ",denom.fee_deposit_val"
           ",denom.fee_deposit_frac"
           ",denom.fee_deposit_curr"
           " FROM aggregation_tracking"
           "    JOIN deposits USING (deposit_serial_id)"
           "    JOIN known_coins USING (coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE wtid_raw=$1",
           1, NULL);

  /* Used in #postgres_wire_lookup_deposit_wtid */
  PREPARE ("lookup_deposit_wtid",
           "SELECT"
           " aggregation_tracking.wtid_raw"
           ",aggregation_tracking.execution_time"
           ",amount_with_fee_val"
           ",amount_with_fee_frac"
           ",amount_with_fee_curr"
           ",denom.fee_deposit_val"
           ",denom.fee_deposit_frac"
           ",denom.fee_deposit_curr"
           " FROM deposits"
           "    JOIN aggregation_tracking USING (deposit_serial_id)"
           "    JOIN known_coins USING (coin_pub)"
           "    JOIN denominations denom USING (denom_pub)"
           " WHERE coin_pub=$1"
           "  AND h_contract=$2"
           "  AND h_wire=$3"
           "  AND transaction_id=$4"
           "  AND merchant_pub=$5",
           5, NULL);

  /* Used in #postgres_insert_aggregation_tracking */
  PREPARE ("insert_aggregation_tracking",
           "INSERT INTO aggregation_tracking "
           "(deposit_serial_id"
           ",wtid_raw"
           ",execution_time"
           ") VALUES "
           "($1, $2, $3)",
           3, NULL);


  /* Used in #postgres_wire_prepare_data_insert() to store
     wire transfer information before actually committing it with the bank */
  PREPARE ("wire_prepare_data_insert",
           "INSERT INTO prewire "
           "(type"
           ",buf"
           ") VALUES "
           "($1, $2)",
           2, NULL);

  /* Used in #postgres_wire_prepare_data_mark_finished() */
  PREPARE ("wire_prepare_data_mark_done",
           "UPDATE prewire"
           " SET finished=true"
           " WHERE prewire_uuid=$1",
           1, NULL);

  /* Used in #postgres_wire_prepare_data_get() */
  PREPARE ("wire_prepare_data_get",
           "SELECT"
           " prewire_uuid"
           ",type"
           ",buf"
           " FROM prewire"
           " WHERE finished=false"
           " ORDER BY prewire_uuid ASC"
           " LIMIT 1",
           0, NULL);

  /* Used in #postgres_gc() */
  PREPARE ("gc_prewire",
           "DELETE"
           " FROM prewire"
           " WHERE finished=true",
           0, NULL);

  /* Used in #postgres_select_prepare_above_serial_id() */
  PREPARE ("audit_get_wire_incr",
           "SELECT"
           " type"
           ",buf"
           ",finished"
           " FROM prewire"
           " WHERE prewire_uuid>=$1"
           " ORDER BY prewire_uuid ASC",
           1, NULL);

  PREPARE ("gc_denominations",
           "DELETE"
           " FROM denominations"
           " WHERE expire_legal < $1",
           1, NULL);
  PREPARE ("gc_reserves",
           "DELETE"
           " FROM reserves"
           " WHERE expiration_date < $1"
           "   AND current_balance_val = 0"
           "   AND current_balance_frac = 0",
           1, NULL);

  return GNUNET_OK;
#undef PREPARE
}


/**
 * Close thread-local database connection when a thread is destroyed.
 *
 * @param cls closure we get from pthreads (the db handle)
 */
static void
db_conn_destroy (void *cls)
{
  struct TALER_EXCHANGEDB_Session *session = cls;
  PGconn *db_conn = session->conn;

  if (NULL != db_conn)
    PQfinish (db_conn);
  GNUNET_free (session);
}


/**
 * Get the thread-local database-handle.
 * Connect to the db if the connection does not exist yet.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @return the database connection, or NULL on error
 */
static struct TALER_EXCHANGEDB_Session *
postgres_get_session (void *cls)
{
  struct PostgresClosure *pc = cls;
  PGconn *db_conn;
  struct TALER_EXCHANGEDB_Session *session;

  if (NULL != (session = pthread_getspecific (pc->db_conn_threadlocal)))
    return session;
  db_conn = connect_to_postgres (pc);
  if (NULL == db_conn)
    return NULL;
  if (GNUNET_OK !=
      postgres_prepare (db_conn))
  {
    GNUNET_break (0);
    PQfinish (db_conn);
    return NULL;
  }
  session = GNUNET_new (struct TALER_EXCHANGEDB_Session);
  session->conn = db_conn;
  if (0 != pthread_setspecific (pc->db_conn_threadlocal,
                                session))
  {
    GNUNET_break (0);
    PQfinish (db_conn);
    GNUNET_free (session);
    return NULL;
  }
  return session;
}


/**
 * Start a transaction.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session the database connection
 * @return #GNUNET_OK on success
 */
static int
postgres_start (void *cls,
                struct TALER_EXCHANGEDB_Session *session)
{
  PGresult *result;

  result = PQexec (session->conn,
                   "START TRANSACTION ISOLATION LEVEL SERIALIZABLE");
  if (PGRES_COMMAND_OK !=
      PQresultStatus (result))
  {
    TALER_LOG_ERROR ("Failed to start transaction: %s\n",
               PQresultErrorMessage (result));
    GNUNET_break (0);
    PQclear (result);
    return GNUNET_SYSERR;
  }

  PQclear (result);
  return GNUNET_OK;
}


/**
 * Roll back the current transaction of a database connection.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session the database connection
 * @return #GNUNET_OK on success
 */
static void
postgres_rollback (void *cls,
                   struct TALER_EXCHANGEDB_Session *session)
{
  PGresult *result;

  result = PQexec (session->conn,
                   "ROLLBACK");
  GNUNET_break (PGRES_COMMAND_OK ==
                PQresultStatus (result));
  PQclear (result);
}


/**
 * Commit the current transaction of a database connection.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session the database connection
 * @return #GNUNET_OK on success
 */
static int
postgres_commit (void *cls,
                 struct TALER_EXCHANGEDB_Session *session)
{
  PGresult *result;

  result = PQexec (session->conn,
                   "COMMIT");
  if (PGRES_COMMAND_OK !=
      PQresultStatus (result))
  {
    const char *sqlstate;

    sqlstate = PQresultErrorField (result,
                                   PG_DIAG_SQLSTATE);
    if (NULL == sqlstate)
    {
      /* very unexpected... */
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    /* 40P01: deadlock, 40001: serialization failure */
    if ( (0 == strcmp (sqlstate,
                       "40P01")) ||
         (0 == strcmp (sqlstate,
                       "40001")) )
    {
      /* These two can be retried and have a fair chance of working
         the next time */
      PQclear (result);
      return GNUNET_NO;
    }
    GNUNET_log (GNUNET_ERROR_TYPE_ERROR,
                "Database commit failure: %s\n",
                sqlstate);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Insert a denomination key's public information into the database for
 * reference by auditors and other consistency checks.
 *
 * @param cls the @e cls of this struct with the plugin-specific state
 * @param session connection to use
 * @param denom_pub the public key used for signing coins of this denomination
 * @param issue issuing information with value, fees and other info about the coin
 * @return #GNUNET_OK on success; #GNUNET_SYSERR on failure
 */
static int
postgres_insert_denomination_info (void *cls,
                                   struct TALER_EXCHANGEDB_Session *session,
                                   const struct TALER_DenominationPublicKey *denom_pub,
                                   const struct TALER_EXCHANGEDB_DenominationKeyInformationP *issue)
{
  PGresult *result;
  int ret;

  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_rsa_public_key (denom_pub->rsa_public_key),
    GNUNET_PQ_query_param_auto_from_type (&issue->properties.master),
    GNUNET_PQ_query_param_auto_from_type (&issue->signature),
    GNUNET_PQ_query_param_absolute_time_nbo (&issue->properties.start),
    GNUNET_PQ_query_param_absolute_time_nbo (&issue->properties.expire_withdraw),
    GNUNET_PQ_query_param_absolute_time_nbo (&issue->properties.expire_deposit),
    GNUNET_PQ_query_param_absolute_time_nbo (&issue->properties.expire_legal),
    TALER_PQ_query_param_amount_nbo (&issue->properties.value),
    TALER_PQ_query_param_amount_nbo (&issue->properties.fee_withdraw),
    TALER_PQ_query_param_amount_nbo (&issue->properties.fee_deposit),
    TALER_PQ_query_param_amount_nbo (&issue->properties.fee_refresh),
    TALER_PQ_query_param_amount_nbo (&issue->properties.fee_refund),
    GNUNET_PQ_query_param_end
  };
  /* check fees match coin currency */
  GNUNET_assert (GNUNET_YES ==
                 TALER_amount_cmp_currency_nbo (&issue->properties.value,
                                                &issue->properties.fee_withdraw));
  GNUNET_assert (GNUNET_YES ==
                 TALER_amount_cmp_currency_nbo (&issue->properties.value,
                                                &issue->properties.fee_deposit));
  GNUNET_assert (GNUNET_YES ==
                 TALER_amount_cmp_currency_nbo (&issue->properties.value,
                                                &issue->properties.fee_refresh));
  GNUNET_assert (GNUNET_YES ==
                 TALER_amount_cmp_currency_nbo (&issue->properties.value,
                                               &issue->properties.fee_refund));

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "denomination_insert",
                                   params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    ret = GNUNET_SYSERR;
    BREAK_DB_ERR (result);
  }
  else
  {
    ret = GNUNET_OK;
  }
  PQclear (result);
  return ret;
}


/**
 * Fetch information about a denomination key.
 *
 * @param cls the @e cls of this struct with the plugin-specific state
 * @param session connection to use
 * @param denom_pub the public key used for signing coins of this denomination
 * @param[out] issue set to issue information with value, fees and other info about the coin, can be NULL
 * @return #GNUNET_OK on success; #GNUNET_NO if no record was found, #GNUNET_SYSERR on failure
 */
static int
postgres_get_denomination_info (void *cls,
                                struct TALER_EXCHANGEDB_Session *session,
                                const struct TALER_DenominationPublicKey *denom_pub,
                                struct TALER_EXCHANGEDB_DenominationKeyInformationP *issue)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_rsa_public_key (denom_pub->rsa_public_key),
    GNUNET_PQ_query_param_end
  };

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "denomination_get",
                                   params);
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    QUERY_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == PQntuples (result))
  {
    PQclear (result);
    return GNUNET_NO;
  }
  if (1 != PQntuples (result))
  {
    GNUNET_break (0);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (NULL == issue)
  {
    PQclear (result);
    return GNUNET_OK;
  }
  {
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("master_pub",
                                           &issue->properties.master),
      GNUNET_PQ_result_spec_auto_from_type ("master_sig",
                                           &issue->signature),
      GNUNET_PQ_result_spec_absolute_time_nbo ("valid_from",
                                              &issue->properties.start),
      GNUNET_PQ_result_spec_absolute_time_nbo ("expire_withdraw",
                                              &issue->properties.expire_withdraw),
      GNUNET_PQ_result_spec_absolute_time_nbo ("expire_deposit",
                                              &issue->properties.expire_deposit),
      GNUNET_PQ_result_spec_absolute_time_nbo ("expire_legal",
                                              &issue->properties.expire_legal),
      TALER_PQ_result_spec_amount_nbo ("coin",
                                       &issue->properties.value),
      TALER_PQ_result_spec_amount_nbo ("fee_withdraw",
                                       &issue->properties.fee_withdraw),
      TALER_PQ_result_spec_amount_nbo ("fee_deposit",
                                       &issue->properties.fee_deposit),
      TALER_PQ_result_spec_amount_nbo ("fee_refresh",
                                       &issue->properties.fee_refresh),
      TALER_PQ_result_spec_amount_nbo ("fee_refund",
                                       &issue->properties.fee_refund),
      GNUNET_PQ_result_spec_end
    };

    EXITIF (GNUNET_OK !=
            GNUNET_PQ_extract_result (result,
                                      rs,
                                      0));
  }
  PQclear (result);
  issue->properties.purpose.size = htonl (sizeof (struct TALER_DenominationKeyValidityPS));
  issue->properties.purpose.purpose = htonl (TALER_SIGNATURE_MASTER_DENOMINATION_KEY_VALIDITY);
  GNUNET_CRYPTO_rsa_public_key_hash (denom_pub->rsa_public_key,
                                     &issue->properties.denom_hash);
  return GNUNET_OK;

 EXITIF_exit:
  PQclear (result);
  return GNUNET_SYSERR;
}


/**
 * Get the summary of a reserve.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session the database connection handle
 * @param[in,out] reserve the reserve data.  The public key of the reserve should be
 *          set in this structure; it is used to query the database.  The balance
 *          and expiration are then filled accordingly.
 * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
 */
static int
postgres_reserve_get (void *cls,
                      struct TALER_EXCHANGEDB_Session *session,
                      struct TALER_EXCHANGEDB_Reserve *reserve)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type(&reserve->pub),
    GNUNET_PQ_query_param_end
  };

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "reserve_get",
                                   params);
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    QUERY_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == PQntuples (result))
  {
    PQclear (result);
    return GNUNET_NO;
  }
  {
    struct GNUNET_PQ_ResultSpec rs[] = {
      TALER_PQ_result_spec_amount("current_balance", &reserve->balance),
      GNUNET_PQ_result_spec_absolute_time("expiration_date", &reserve->expiry),
      GNUNET_PQ_result_spec_end
    };

    EXITIF (GNUNET_OK !=
            GNUNET_PQ_extract_result (result,
                                     rs,
                                     0));
  }
  PQclear (result);
  return GNUNET_OK;

 EXITIF_exit:
  PQclear (result);
  return GNUNET_SYSERR;
}


/**
 * Updates a reserve with the data from the given reserve structure.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session the database connection
 * @param reserve the reserve structure whose data will be used to update the
 *          corresponding record in the database.
 * @return #GNUNET_OK upon successful update; #GNUNET_SYSERR upon any error
 */
static int
reserves_update (void *cls,
                 struct TALER_EXCHANGEDB_Session *session,
                 const struct TALER_EXCHANGEDB_Reserve *reserve)
{
  PGresult *result;
  int ret;

  if (NULL == reserve)
    return GNUNET_SYSERR;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_absolute_time (&reserve->expiry),
    TALER_PQ_query_param_amount (&reserve->balance),
    GNUNET_PQ_query_param_auto_from_type (&reserve->pub),
    GNUNET_PQ_query_param_end
  };
  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "reserve_update",
                                   params);
  if (PGRES_COMMAND_OK != PQresultStatus(result))
  {
    QUERY_ERR (result);
    ret = GNUNET_SYSERR;
  }
  else
  {
    ret = GNUNET_OK;
  }
  PQclear (result);
  return ret;
}


/**
 * Insert an incoming transaction into reserves.  New reserves are also created
 * through this function.  Note that this API call starts (and stops) its
 * own transaction scope (so the application must not do so).
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session the database connection handle
 * @param reserve_pub public key of the reserve
 * @param balance the amount that has to be added to the reserve
 * @param execution_time when was the amount added
 * @param sender_account_details account information for the sender
 * @param transfer_details information that uniquely identifies the transfer
 * @return #GNUNET_OK upon success; #GNUNET_NO if the given
 *         @a details are already known for this @a reserve_pub,
 *         #GNUNET_SYSERR upon failures (DB error, incompatible currency)
 */
static int
postgres_reserves_in_insert (void *cls,
                             struct TALER_EXCHANGEDB_Session *session,
                             const struct TALER_ReservePublicKeyP *reserve_pub,
                             const struct TALER_Amount *balance,
                             struct GNUNET_TIME_Absolute execution_time,
                             const json_t *sender_account_details,
                             const json_t *transfer_details)
{
  PGresult *result;
  int reserve_exists;
  struct TALER_EXCHANGEDB_Reserve reserve;
  struct GNUNET_TIME_Absolute expiry;

  if (GNUNET_OK !=
      postgres_start (cls,
                      session))
  {
    GNUNET_break (0);
    return GNUNET_SYSERR;
  }
  reserve.pub = *reserve_pub;
  reserve_exists = postgres_reserve_get (cls,
                                         session,
                                         &reserve);
  if (GNUNET_SYSERR == reserve_exists)
  {
    GNUNET_break (0);
    goto rollback;
  }
  expiry = GNUNET_TIME_absolute_add (execution_time,
                                     TALER_IDLE_RESERVE_EXPIRATION_TIME);
  if (GNUNET_NO == reserve_exists)
  {
    /* New reserve, create balance for the first time; we do this
       before adding the actual transaction to "reserves_in", as
       for a new reserve it can't be a duplicate 'add' operation,
       and as the 'add' operation may need the reserve entry
       as a foreign key. */
    struct GNUNET_PQ_QueryParam params[] = {
      GNUNET_PQ_query_param_auto_from_type (reserve_pub),
      TALER_PQ_query_param_amount (balance),
      GNUNET_PQ_query_param_absolute_time (&expiry),
      GNUNET_PQ_query_param_end
    };

    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "Reserve does not exist; creating a new one\n");
    result = GNUNET_PQ_exec_prepared (session->conn,
                                      "reserve_create",
                                      params);
    if (PGRES_COMMAND_OK != PQresultStatus(result))
    {
      QUERY_ERR (result);
      PQclear (result);
      goto rollback;
    }
    PQclear (result);
  }
  /* Create new incoming transaction, SQL "primary key" logic
     is used to guard against duplicates.  If a duplicate is
     detected, we rollback (which really shouldn't undo
     anything) and return #GNUNET_NO to indicate that this failure
     is kind-of harmless (already executed). */
  {
    struct GNUNET_PQ_QueryParam params[] = {
      GNUNET_PQ_query_param_auto_from_type (&reserve.pub),
      TALER_PQ_query_param_amount (balance),
      TALER_PQ_query_param_json (sender_account_details),
      TALER_PQ_query_param_json (transfer_details),
      GNUNET_PQ_query_param_absolute_time (&execution_time),
      GNUNET_PQ_query_param_end
    };

    result = GNUNET_PQ_exec_prepared (session->conn,
                                      "reserves_in_add_transaction",
                                      params);
  }
  if (PGRES_COMMAND_OK != PQresultStatus(result))
  {
    const char *efield;

    efield = PQresultErrorField (result,
				 PG_DIAG_SQLSTATE);
    if ( (PGRES_FATAL_ERROR == PQresultStatus(result)) &&
	 (NULL != strstr ("23505", /* unique violation */
			  efield)) )
    {
      /* This means we had the same reserve/justification/details
	 before */
      GNUNET_log (GNUNET_ERROR_TYPE_ERROR,
                  "Uniqueness violation, deposit details already known\n");
      PQclear (result);
      postgres_rollback (cls,
			 session);
      return GNUNET_NO;
    }
    QUERY_ERR (result);
    PQclear (result);
    goto rollback;
  }
  PQclear (result);

  if (GNUNET_YES == reserve_exists)
  {
    /* If the reserve already existed, we need to still update the
       balance; we do this after checking for duplication, as
       otherwise we might have to actually pay the cost to roll this
       back for duplicate transactions; like this, we should virtually
       never actually have to rollback anything. */
    struct TALER_EXCHANGEDB_Reserve updated_reserve;

    updated_reserve.pub = reserve.pub;
    if (GNUNET_OK !=
        TALER_amount_add (&updated_reserve.balance,
                          &reserve.balance,
                          balance))
    {
      /* currency overflow or incompatible currency */
      GNUNET_log (GNUNET_ERROR_TYPE_WARNING,
                  "Attempt to deposit incompatible amount into reserve\n");
      goto rollback;
    }
    updated_reserve.expiry = GNUNET_TIME_absolute_max (expiry,
                                                       reserve.expiry);
    if (GNUNET_OK != reserves_update (cls,
                                      session,
                                      &updated_reserve))
      goto rollback;
  }
  if (GNUNET_OK != postgres_commit (cls,
                                    session))
    return GNUNET_SYSERR;
  return GNUNET_OK;

 rollback:
  GNUNET_log (GNUNET_ERROR_TYPE_ERROR,
              "Transaction failed, doing rollback\n");
  postgres_rollback (cls,
                     session);
  return GNUNET_SYSERR;
}


/**
 * Locate the response for a /reserve/withdraw request under the
 * key of the hash of the blinded message.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection to use
 * @param h_blind hash of the blinded coin to be signed (will match
 *                `h_coin_envelope` in the @a collectable to be returned)
 * @param collectable corresponding collectable coin (blind signature)
 *                    if a coin is found
 * @return #GNUNET_SYSERR on internal error
 *         #GNUNET_NO if the collectable was not found
 *         #GNUNET_YES on success
 */
static int
postgres_get_withdraw_info (void *cls,
                            struct TALER_EXCHANGEDB_Session *session,
                            const struct GNUNET_HashCode *h_blind,
                            struct TALER_EXCHANGEDB_CollectableBlindcoin *collectable)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (h_blind),
    GNUNET_PQ_query_param_end
  };
  int ret;

  ret = GNUNET_SYSERR;
  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "get_withdraw_info",
                                   params);

  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    QUERY_ERR (result);
    goto cleanup;
  }
  if (0 == PQntuples (result))
  {
    ret = GNUNET_NO;
    goto cleanup;
  }
  {
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_rsa_public_key ("denom_pub",
                                           &collectable->denom_pub.rsa_public_key),
      GNUNET_PQ_result_spec_rsa_signature ("denom_sig",
                                          &collectable->sig.rsa_signature),
      GNUNET_PQ_result_spec_auto_from_type ("reserve_sig",
                                           &collectable->reserve_sig),
      GNUNET_PQ_result_spec_auto_from_type ("reserve_pub",
                                           &collectable->reserve_pub),
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &collectable->amount_with_fee),
      TALER_PQ_result_spec_amount ("fee_withdraw",
                                   &collectable->withdraw_fee),
      GNUNET_PQ_result_spec_end
    };

    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      goto cleanup;
    }
  }
  collectable->h_coin_envelope = *h_blind;
  ret = GNUNET_YES;

 cleanup:
  PQclear (result);
  return ret;
}


/**
 * Store collectable bit coin under the corresponding
 * hash of the blinded message.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection to use
 * @param collectable corresponding collectable coin (blind signature)
 *                    if a coin is found
 * @return #GNUNET_SYSERR on internal error
 *         #GNUNET_NO if the collectable was not found
 *         #GNUNET_YES on success
 */
static int
postgres_insert_withdraw_info (void *cls,
                               struct TALER_EXCHANGEDB_Session *session,
                               const struct TALER_EXCHANGEDB_CollectableBlindcoin *collectable)
{
  PGresult *result;
  struct TALER_EXCHANGEDB_Reserve reserve;
  int ret = GNUNET_SYSERR;
  struct GNUNET_TIME_Absolute now;
  struct GNUNET_TIME_Absolute expiry;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (&collectable->h_coin_envelope),
    GNUNET_PQ_query_param_rsa_public_key (collectable->denom_pub.rsa_public_key),
    GNUNET_PQ_query_param_rsa_signature (collectable->sig.rsa_signature),
    GNUNET_PQ_query_param_auto_from_type (&collectable->reserve_pub),
    GNUNET_PQ_query_param_auto_from_type (&collectable->reserve_sig),
    GNUNET_PQ_query_param_absolute_time (&now),
    TALER_PQ_query_param_amount (&collectable->amount_with_fee),
    GNUNET_PQ_query_param_end
  };

  now = GNUNET_TIME_absolute_get ();
  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "insert_withdraw_info",
                                   params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    QUERY_ERR (result);
    goto cleanup;
  }
  reserve.pub = collectable->reserve_pub;
  if (GNUNET_OK != postgres_reserve_get (cls,
                                         session,
                                         &reserve))
  {
    /* Should have been checked before we got here... */
    GNUNET_break (0);
    goto cleanup;
  }
  if (GNUNET_SYSERR ==
      TALER_amount_subtract (&reserve.balance,
                             &reserve.balance,
                             &collectable->amount_with_fee))
  {
    /* Should have been checked before we got here... */
    GNUNET_break (0);
    goto cleanup;
  }
  expiry = GNUNET_TIME_absolute_add (now,
                                     TALER_IDLE_RESERVE_EXPIRATION_TIME);
  reserve.expiry = GNUNET_TIME_absolute_max (expiry,
                                             reserve.expiry);
  if (GNUNET_OK != reserves_update (cls,
                                    session,
                                    &reserve))
  {
    GNUNET_break (0);
    goto cleanup;
  }
  ret = GNUNET_OK;
 cleanup:
  PQclear (result);
  return ret;
}


/**
 * Get all of the transaction history associated with the specified
 * reserve.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session connection to use
 * @param reserve_pub public key of the reserve
 * @return known transaction history (NULL if reserve is unknown)
 */
static struct TALER_EXCHANGEDB_ReserveHistory *
postgres_get_reserve_history (void *cls,
                              struct TALER_EXCHANGEDB_Session *session,
                              const struct TALER_ReservePublicKeyP *reserve_pub)
{
  PGresult *result;
  struct TALER_EXCHANGEDB_ReserveHistory *rh;
  struct TALER_EXCHANGEDB_ReserveHistory *rh_tail;
  int rows;
  int ret;

  rh = NULL;
  rh_tail = NULL;
  ret = GNUNET_SYSERR;
  {
    struct TALER_EXCHANGEDB_BankTransfer *bt;
    struct GNUNET_PQ_QueryParam params[] = {
      GNUNET_PQ_query_param_auto_from_type (reserve_pub),
      GNUNET_PQ_query_param_end
    };

    result = GNUNET_PQ_exec_prepared (session->conn,
                                      "reserves_in_get_transactions",
                                      params);
    if (PGRES_TUPLES_OK != PQresultStatus (result))
    {
      QUERY_ERR (result);
      goto cleanup;
    }
    if (0 == (rows = PQntuples (result)))
    {
      GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                  "Asked to fetch history for an unknown reserve.\n");
      goto cleanup;
    }
    while (0 < rows)
    {
      bt = GNUNET_new (struct TALER_EXCHANGEDB_BankTransfer);
      {
        struct GNUNET_PQ_ResultSpec rs[] = {
          TALER_PQ_result_spec_amount ("credit",
                                       &bt->amount),
          GNUNET_PQ_result_spec_absolute_time ("execution_date",
                                              &bt->execution_date),
          TALER_PQ_result_spec_json ("sender_account_details",
                                     &bt->sender_account_details),
          TALER_PQ_result_spec_json ("transfer_details",
                                     &bt->transfer_details),
          GNUNET_PQ_result_spec_end
        };
        if (GNUNET_OK !=
            GNUNET_PQ_extract_result (result, rs, --rows))
        {
          GNUNET_break (0);
          GNUNET_free (bt);
          PQclear (result);
          goto cleanup;
        }
      }
      bt->reserve_pub = *reserve_pub;
      if (NULL != rh_tail)
      {
        rh_tail->next = GNUNET_new (struct TALER_EXCHANGEDB_ReserveHistory);
        rh_tail = rh_tail->next;
      }
      else
      {
        rh_tail = GNUNET_new (struct TALER_EXCHANGEDB_ReserveHistory);
        rh = rh_tail;
      }
      rh_tail->type = TALER_EXCHANGEDB_RO_BANK_TO_EXCHANGE;
      rh_tail->details.bank = bt;
    }
    PQclear (result);
  }
  {
    struct GNUNET_PQ_QueryParam params[] = {
      GNUNET_PQ_query_param_auto_from_type (reserve_pub),
      GNUNET_PQ_query_param_end
    };

    GNUNET_assert (NULL != rh);
    GNUNET_assert (NULL != rh_tail);
    GNUNET_assert (NULL == rh_tail->next);
    result = GNUNET_PQ_exec_prepared (session->conn,
                                     "get_reserves_out",
                                     params);
    if (PGRES_TUPLES_OK != PQresultStatus (result))
    {
      QUERY_ERR (result);
      PQclear (result);
      goto cleanup;
    }
    rows = PQntuples (result);
    while (0 < rows)
    {
      struct TALER_EXCHANGEDB_CollectableBlindcoin *cbc;

      cbc = GNUNET_new (struct TALER_EXCHANGEDB_CollectableBlindcoin);
      {
        struct GNUNET_PQ_ResultSpec rs[] = {
          GNUNET_PQ_result_spec_auto_from_type ("h_blind_ev",
                                               &cbc->h_coin_envelope),
          GNUNET_PQ_result_spec_rsa_public_key ("denom_pub",
                                               &cbc->denom_pub.rsa_public_key),
          GNUNET_PQ_result_spec_rsa_signature ("denom_sig",
                                              &cbc->sig.rsa_signature),
          GNUNET_PQ_result_spec_auto_from_type ("reserve_sig",
                                               &cbc->reserve_sig),
          TALER_PQ_result_spec_amount ("amount_with_fee",
                                       &cbc->amount_with_fee),
          TALER_PQ_result_spec_amount ("fee_withdraw",
                                       &cbc->withdraw_fee),
          GNUNET_PQ_result_spec_end
        };
        if (GNUNET_OK !=
            GNUNET_PQ_extract_result (result, rs, --rows))
        {
          GNUNET_break (0);
          GNUNET_free (cbc);
          PQclear (result);
          goto cleanup;
        }
        cbc->reserve_pub = *reserve_pub;
      }
      rh_tail->next = GNUNET_new (struct TALER_EXCHANGEDB_ReserveHistory);
      rh_tail = rh_tail->next;
      rh_tail->type = TALER_EXCHANGEDB_RO_WITHDRAW_COIN;
      rh_tail->details.withdraw = cbc;
    }
    ret = GNUNET_OK;
    PQclear (result);
  }
 cleanup:
  if (GNUNET_SYSERR == ret)
  {
    common_free_reserve_history (cls,
                                 rh);
    rh = NULL;
  }
  return rh;
}


/**
 * Check if we have the specified deposit already in the database.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection
 * @param deposit deposit to search for
 * @return #GNUNET_YES if we know this operation,
 *         #GNUNET_NO if this exact deposit is unknown to us
 *         #GNUNET_SYSERR on DB error
 */
static int
postgres_have_deposit (void *cls,
                       struct TALER_EXCHANGEDB_Session *session,
                       const struct TALER_EXCHANGEDB_Deposit *deposit)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (&deposit->coin.coin_pub),
    GNUNET_PQ_query_param_uint64 (&deposit->transaction_id),
    GNUNET_PQ_query_param_auto_from_type (&deposit->merchant_pub),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "get_deposit",
                                   params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == PQntuples (result))
  {
    PQclear (result);
    return GNUNET_NO;
  }

  /* Now we check that the other information in @a deposit
     also matches, and if not report inconsistencies. */
  {
    struct TALER_EXCHANGEDB_Deposit deposit2;
    struct GNUNET_PQ_ResultSpec rs[] = {
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &deposit2.amount_with_fee),
      GNUNET_PQ_result_spec_absolute_time ("timestamp",
                                          &deposit2.timestamp),
      GNUNET_PQ_result_spec_absolute_time ("refund_deadline",
                                          &deposit2.refund_deadline),
      GNUNET_PQ_result_spec_absolute_time ("wire_deadline",
                                          &deposit2.wire_deadline),
      GNUNET_PQ_result_spec_auto_from_type ("h_contract",
                                           &deposit2.h_contract),
      GNUNET_PQ_result_spec_auto_from_type ("h_wire",
                                           &deposit2.h_wire),
      GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    if ( (0 != TALER_amount_cmp (&deposit->amount_with_fee,
                                 &deposit2.amount_with_fee)) ||
         (deposit->timestamp.abs_value_us !=
          deposit2.timestamp.abs_value_us) ||
         (deposit->refund_deadline.abs_value_us !=
          deposit2.refund_deadline.abs_value_us) ||
         (0 != memcmp (&deposit->h_contract,
                       &deposit2.h_contract,
                       sizeof (struct GNUNET_HashCode))) ||
         (0 != memcmp (&deposit->h_wire,
                       &deposit2.h_wire,
                       sizeof (struct GNUNET_HashCode))) )
    {
      /* Inconsistencies detected! Does not match!  (We might want to
         expand the API with a 'get_deposit' function to return the
         original transaction details to be used for an error message
         in the future!) #3838 */
      PQclear (result);
      return GNUNET_NO;
    }
  }
  PQclear (result);
  return GNUNET_YES;
}


/**
 * Mark a deposit as tiny, thereby declaring that it cannot be
 * executed by itself and should no longer be returned by
 * @e iterate_ready_deposits()
 *
 * @param cls the @e cls of this struct with the plugin-specific state
 * @param session connection to the database
 * @param deposit_serial_id identifies the deposit row to modify
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on error
 */
static int
postgres_mark_deposit_tiny (void *cls,
                            struct TALER_EXCHANGEDB_Session *session,
                            unsigned long long rowid)
{
  uint64_t serial_id = rowid;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&serial_id),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "mark_deposit_tiny",
                                   params);
  if (PGRES_COMMAND_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Test if a deposit was marked as done, thereby declaring that it cannot be
 * refunded anymore.
 *
 * @param cls the @e cls of this struct with the plugin-specific state
 * @param session connection to the database
 * @param deposit the deposit to check
 * @return #GNUNET_YES if is is marked done done, #GNUNET_NO if not,
 *         #GNUNET_SYSERR on error (deposit unknown)
 */
static int
postgres_test_deposit_done (void *cls,
                            struct TALER_EXCHANGEDB_Session *session,
                            const struct TALER_EXCHANGEDB_Deposit *deposit)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (&deposit->coin.coin_pub),
    GNUNET_PQ_query_param_uint64 (&deposit->transaction_id),
    GNUNET_PQ_query_param_auto_from_type (&deposit->merchant_pub),
    GNUNET_PQ_query_param_auto_from_type (&deposit->h_contract),
    GNUNET_PQ_query_param_auto_from_type (&deposit->h_wire),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "test_deposit_done",
                                    params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == PQntuples (result))
  {
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (1 != PQntuples (result))
  {
    GNUNET_break (0);
    PQclear (result);
    return GNUNET_SYSERR;
  }

  {
    uint8_t done = 0;
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("done",
                                            &done),
      GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    PQclear (result);
    return (done ? GNUNET_YES : GNUNET_NO);
  }
}


/**
 * Mark a deposit as done, thereby declaring that it cannot be
 * executed at all anymore, and should no longer be returned by
 * @e iterate_ready_deposits() or @e iterate_matching_deposits().
 *
 * @param cls the @e cls of this struct with the plugin-specific state
 * @param session connection to the database
 * @param deposit_serial_id identifies the deposit row to modify
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on error
 */
static int
postgres_mark_deposit_done (void *cls,
                            struct TALER_EXCHANGEDB_Session *session,
                            unsigned long long rowid)
{
  uint64_t serial_id = rowid;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&serial_id),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "mark_deposit_done",
                                   params);
  if (PGRES_COMMAND_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Obtain information about deposits that are ready to be executed.
 * Such deposits must not be marked as "tiny" or "done", and the
 * execution time must be in the past.
 *
 * @param cls the @e cls of this struct with the plugin-specific state
 * @param session connection to the database
 * @param deposit_cb function to call for ONE such deposit
 * @param deposit_cb_cls closure for @a deposit_cb
 * @return number of rows processed, 0 if none exist,
 *         #GNUNET_SYSERR on error
 */
static int
postgres_get_ready_deposit (void *cls,
                            struct TALER_EXCHANGEDB_Session *session,
                            TALER_EXCHANGEDB_DepositIterator deposit_cb,
                            void *deposit_cb_cls)
{
  struct GNUNET_TIME_Absolute now = GNUNET_TIME_absolute_get ();
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_absolute_time (&now),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  unsigned int n;
  int ret;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "deposits_get_ready",
                                   params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == (n = PQntuples (result)))
  {
    PQclear (result);
    return 0;
  }
  GNUNET_break (1 == n);
  {
    struct TALER_Amount amount_with_fee;
    struct TALER_Amount deposit_fee;
    struct GNUNET_TIME_Absolute wire_deadline;
    struct GNUNET_HashCode h_contract;
    struct TALER_MerchantPublicKeyP merchant_pub;
    struct TALER_CoinSpendPublicKeyP coin_pub;
    uint64_t transaction_id;
    uint64_t serial_id;
    json_t *wire;
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_uint64 ("deposit_serial_id",
                                   &serial_id),
      GNUNET_PQ_result_spec_uint64 ("transaction_id",
                                   &transaction_id),
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &amount_with_fee),
      TALER_PQ_result_spec_amount ("fee_deposit",
                                   &deposit_fee),
      GNUNET_PQ_result_spec_absolute_time ("wire_deadline",
                                          &wire_deadline),
      GNUNET_PQ_result_spec_auto_from_type ("h_contract",
                                           &h_contract),
      GNUNET_PQ_result_spec_auto_from_type ("merchant_pub",
                                           &merchant_pub),
      GNUNET_PQ_result_spec_auto_from_type ("coin_pub",
                                           &coin_pub),
      TALER_PQ_result_spec_json ("wire",
                                 &wire),
      GNUNET_PQ_result_spec_end
    };

    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    ret = deposit_cb (deposit_cb_cls,
                      serial_id,
                      &merchant_pub,
                      &coin_pub,
                      &amount_with_fee,
                      &deposit_fee,
                      transaction_id,
                      &h_contract,
                      wire_deadline,
                      wire);
    GNUNET_PQ_cleanup_result (rs);
    PQclear (result);
  }
  return (GNUNET_OK == ret) ? 1 : 0;
}


/**
 * Obtain information about other pending deposits for the same
 * destination.  Those deposits must not already be "done".
 *
 * @param cls the @e cls of this struct with the plugin-specific state
 * @param session connection to the database
 * @param h_wire destination of the wire transfer
 * @param merchant_pub public key of the merchant
 * @param deposit_cb function to call for each deposit
 * @param deposit_cb_cls closure for @a deposit_cb
 * @param limit maximum number of matching deposits to return
 * @return number of rows processed, 0 if none exist,
 *         #GNUNET_SYSERR on error
 */
static int
postgres_iterate_matching_deposits (void *cls,
                                    struct TALER_EXCHANGEDB_Session *session,
                                    const struct GNUNET_HashCode *h_wire,
                                    const struct TALER_MerchantPublicKeyP *merchant_pub,
                                    TALER_EXCHANGEDB_DepositIterator deposit_cb,
                                    void *deposit_cb_cls,
                                    uint32_t limit)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (merchant_pub),
    GNUNET_PQ_query_param_auto_from_type (h_wire),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  unsigned int i;
  unsigned int n;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "deposits_iterate_matching",
                                    params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == (n = PQntuples (result)))
  {
    PQclear (result);
    return 0;
  }
  if (n > limit)
    n = limit;
  for (i=0;i<n;i++)
  {
    struct TALER_Amount amount_with_fee;
    struct TALER_Amount deposit_fee;
    struct GNUNET_TIME_Absolute wire_deadline;
    struct GNUNET_HashCode h_contract;
    struct TALER_CoinSpendPublicKeyP coin_pub;
    uint64_t transaction_id;
    uint64_t serial_id;
    int ret;
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_uint64 ("deposit_serial_id",
                                    &serial_id),
      GNUNET_PQ_result_spec_uint64 ("transaction_id",
                                    &transaction_id),
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &amount_with_fee),
      TALER_PQ_result_spec_amount ("fee_deposit",
                                   &deposit_fee),
      GNUNET_PQ_result_spec_absolute_time ("wire_deadline",
                                           &wire_deadline),
      GNUNET_PQ_result_spec_auto_from_type ("h_contract",
                                            &h_contract),
      GNUNET_PQ_result_spec_auto_from_type ("coin_pub",
                                            &coin_pub),
      GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, i))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    ret = deposit_cb (deposit_cb_cls,
                      serial_id,
                      merchant_pub,
                      &coin_pub,
                      &amount_with_fee,
                      &deposit_fee,
                      transaction_id,
                      &h_contract,
                      wire_deadline,
                      NULL);
    GNUNET_PQ_cleanup_result (rs);
    if (GNUNET_OK != ret)
      break;
  }
  PQclear (result);
  return i;
}


/**
 * Retrieve the record for a known coin.
 *
 * @param cls the plugin closure
 * @param session the database session handle
 * @param coin_pub the public key of the coin to search for
 * @param coin_info place holder for the returned coin information object
 * @return #GNUNET_SYSERR upon error; #GNUNET_NO if no coin is found; #GNUNET_OK
 *           if upon succesfullying retrieving the record data info @a
 *           coin_info
 */
static int
get_known_coin (void *cls,
                struct TALER_EXCHANGEDB_Session *session,
                const struct TALER_CoinSpendPublicKeyP *coin_pub,
                struct TALER_CoinPublicInfo *coin_info)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (coin_pub),
    GNUNET_PQ_query_param_end
  };
  int nrows;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "get_known_coin",
                                   params);
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  nrows = PQntuples (result);
  if (0 == nrows)
  {
    PQclear (result);
    return GNUNET_NO;
  }
  GNUNET_assert (1 == nrows);   /* due to primary key */
  if (NULL == coin_info)
  {
    PQclear (result);
    return GNUNET_YES;
  }
  {
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_rsa_public_key ("denom_pub",
                                            &coin_info->denom_pub.rsa_public_key),
      GNUNET_PQ_result_spec_rsa_signature ("denom_sig",
                                           &coin_info->denom_sig.rsa_signature),
      GNUNET_PQ_result_spec_end
    };

    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      PQclear (result);
      GNUNET_break (0);
      return GNUNET_SYSERR;
    }
  }
  PQclear (result);
  coin_info->coin_pub = *coin_pub;
  return GNUNET_OK;
}


/**
 * Insert a coin we know of into the DB.  The coin can then be referenced by
 * tables for deposits, refresh and refund functionality.
 *
 * @param cls plugin closure
 * @param session the shared database session
 * @param coin_info the public coin info
 * @return #GNUNET_SYSERR upon error; #GNUNET_OK upon success
 */
static int
insert_known_coin (void *cls,
                   struct TALER_EXCHANGEDB_Session *session,
                   const struct TALER_CoinPublicInfo *coin_info)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (&coin_info->coin_pub),
    GNUNET_PQ_query_param_rsa_public_key (coin_info->denom_pub.rsa_public_key),
    GNUNET_PQ_query_param_rsa_signature (coin_info->denom_sig.rsa_signature),
    GNUNET_PQ_query_param_end
  };
  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "insert_known_coin",
                                   params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Insert information about deposited coin into the database.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session connection to the database
 * @param deposit deposit information to store
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on error
 */
static int
postgres_insert_deposit (void *cls,
                         struct TALER_EXCHANGEDB_Session *session,
                         const struct TALER_EXCHANGEDB_Deposit *deposit)
{
  PGresult *result;
  int ret;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (&deposit->coin.coin_pub),
    GNUNET_PQ_query_param_uint64 (&deposit->transaction_id),
    TALER_PQ_query_param_amount (&deposit->amount_with_fee),
    GNUNET_PQ_query_param_absolute_time (&deposit->timestamp),
    GNUNET_PQ_query_param_absolute_time (&deposit->refund_deadline),
    GNUNET_PQ_query_param_absolute_time (&deposit->wire_deadline),
    GNUNET_PQ_query_param_auto_from_type (&deposit->merchant_pub),
    GNUNET_PQ_query_param_auto_from_type (&deposit->h_contract),
    GNUNET_PQ_query_param_auto_from_type (&deposit->h_wire),
    GNUNET_PQ_query_param_auto_from_type (&deposit->csig),
    TALER_PQ_query_param_json (deposit->receiver_wire_account),
    GNUNET_PQ_query_param_end
  };

  /* check if the coin is already known */
  ret = get_known_coin (cls,
                        session,
                        &deposit->coin.coin_pub,
                        NULL);
  if (GNUNET_SYSERR == ret)
  {
    GNUNET_break (0);
    return GNUNET_SYSERR;
  }
  if (GNUNET_NO == ret)         /* if not, insert it */
  {
    if (GNUNET_SYSERR ==
        insert_known_coin (cls,
                           session,
                           &deposit->coin))
    {
      GNUNET_break (0);
      return GNUNET_SYSERR;
    }
  }

  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "insert_deposit",
                                    params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    ret = GNUNET_SYSERR;
  }
  else
  {
    ret = GNUNET_OK;
  }
  PQclear (result);
  return ret;
}


/**
 * Insert information about refunded coin into the database.
 *
 * @param cls the @e cls of this struct with the plugin-specific state
 * @param session connection to the database
 * @param refund refund information to store
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on error
 */
static int
postgres_insert_refund (void *cls,
                        struct TALER_EXCHANGEDB_Session *session,
                        const struct TALER_EXCHANGEDB_Refund *refund)
{
  PGresult *result;
  int ret;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (&refund->coin.coin_pub),
    GNUNET_PQ_query_param_auto_from_type (&refund->merchant_pub),
    GNUNET_PQ_query_param_auto_from_type (&refund->merchant_sig),
    GNUNET_PQ_query_param_auto_from_type (&refund->h_contract),
    GNUNET_PQ_query_param_uint64 (&refund->transaction_id),
    GNUNET_PQ_query_param_uint64 (&refund->rtransaction_id),
    TALER_PQ_query_param_amount (&refund->refund_amount),
    GNUNET_PQ_query_param_end
  };
  GNUNET_assert (GNUNET_YES ==
                 TALER_amount_cmp_currency (&refund->refund_amount,
                                            &refund->refund_fee));
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "insert_refund",
                                    params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    ret = GNUNET_SYSERR;
    BREAK_DB_ERR (result);
  }
  else
  {
    ret = GNUNET_OK;
  }
  PQclear (result);
  return ret;
}


/**
 * Lookup refresh session data under the given @a session_hash.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database handle to use
 * @param session_hash hash over the melt to use to locate the session
 * @param[out] refresh_session where to store the result, can be NULL
 *             to just check if the session exists
 * @return #GNUNET_YES on success,
 *         #GNUNET_NO if not found,
 *         #GNUNET_SYSERR on DB failure
 */
static int
postgres_get_refresh_session (void *cls,
                              struct TALER_EXCHANGEDB_Session *session,
                              const struct GNUNET_HashCode *session_hash,
                              struct TALER_EXCHANGEDB_RefreshSession *refresh_session)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (session_hash),
    GNUNET_PQ_query_param_end
  };

  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "get_refresh_session",
                                    params);
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == PQntuples (result))
  {
    PQclear (result);
    return GNUNET_NO;
  }
  GNUNET_assert (1 == PQntuples (result));
  if (NULL == refresh_session)
  {
    /* We're done if the caller is only interested in whether the
     * session exists or not */
    PQclear (result);
    return GNUNET_YES;
  }
  memset (refresh_session,
          0,
          sizeof (struct TALER_EXCHANGEDB_RefreshSession));
  {
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_uint16 ("num_newcoins",
                                    &refresh_session->num_newcoins),
      GNUNET_PQ_result_spec_uint16 ("noreveal_index",
                                    &refresh_session->noreveal_index),
      GNUNET_PQ_result_spec_auto_from_type ("old_coin_pub",
                                            &refresh_session->melt.coin.coin_pub),
      GNUNET_PQ_result_spec_auto_from_type ("old_coin_sig",
                                            &refresh_session->melt.coin_sig),
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &refresh_session->melt.amount_with_fee),
      TALER_PQ_result_spec_amount ("fee_refresh",
                                   &refresh_session->melt.melt_fee),
      GNUNET_PQ_result_spec_end
    };

    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
  }
  PQclear (result);
  if (GNUNET_OK !=
      get_known_coin (cls,
                      session,
                      &refresh_session->melt.coin.coin_pub,
                      &refresh_session->melt.coin))
  {
    GNUNET_break (0);
    return GNUNET_SYSERR;
  }
  refresh_session->melt.session_hash = *session_hash;
  return GNUNET_YES;
}


/**
 * Store new refresh session data under the given @a session_hash.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database handle to use
 * @param session_hash hash over the melt to use to locate the session
 * @param refresh_session session data to store
 * @return #GNUNET_YES on success,
 *         #GNUNET_SYSERR on DB failure
 */
static int
postgres_create_refresh_session (void *cls,
                                 struct TALER_EXCHANGEDB_Session *session,
                                 const struct GNUNET_HashCode *session_hash,
                                 const struct TALER_EXCHANGEDB_RefreshSession *refresh_session)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (session_hash),
    GNUNET_PQ_query_param_auto_from_type (&refresh_session->melt.coin.coin_pub),
    GNUNET_PQ_query_param_auto_from_type (&refresh_session->melt.coin_sig),
    TALER_PQ_query_param_amount (&refresh_session->melt.amount_with_fee),
    GNUNET_PQ_query_param_uint16 (&refresh_session->num_newcoins),
    GNUNET_PQ_query_param_uint16 (&refresh_session->noreveal_index),
    GNUNET_PQ_query_param_end
  };
  int ret;

  /* check if the coin is already known */
  ret = get_known_coin (cls,
                        session,
                        &refresh_session->melt.coin.coin_pub,
                        NULL);
  if (GNUNET_SYSERR == ret)
  {
    GNUNET_break (0);
    return GNUNET_SYSERR;
  }
  if (GNUNET_NO == ret)         /* if not, insert it */
  {
    if (GNUNET_SYSERR ==
        insert_known_coin (cls,
                           session,
                           &refresh_session->melt.coin))
    {
      GNUNET_break (0);
      return GNUNET_SYSERR;
    }
  }
  /* insert session */
  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "insert_refresh_session",
                                   params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Store in the database which coin(s) we want to create
 * in a given refresh operation.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection
 * @param session_hash hash to identify refresh session
 * @param num_newcoins number of coins to generate, size of the @a denom_pubs array
 * @param denom_pubs array denominations of the coins to create
 * @return #GNUNET_OK on success
 *         #GNUNET_SYSERR on internal error
 */
static int
postgres_insert_refresh_order (void *cls,
                               struct TALER_EXCHANGEDB_Session *session,
                               const struct GNUNET_HashCode *session_hash,
                               uint16_t num_newcoins,
                               const struct TALER_DenominationPublicKey *denom_pubs)
{
  unsigned int i;

  for (i=0;i<(unsigned int) num_newcoins;i++)
  {
    uint16_t newcoin_off = (uint16_t) i;
    PGresult *result;

    {
      struct GNUNET_PQ_QueryParam params[] = {
        GNUNET_PQ_query_param_uint16 (&newcoin_off),
        GNUNET_PQ_query_param_auto_from_type (session_hash),
        GNUNET_PQ_query_param_rsa_public_key (denom_pubs[i].rsa_public_key),
        GNUNET_PQ_query_param_end
      };
      result = GNUNET_PQ_exec_prepared (session->conn,
                                       "insert_refresh_order",
                                       params);
    }
    if (PGRES_COMMAND_OK != PQresultStatus (result))
    {
      BREAK_DB_ERR (result);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    if (0 != strcmp ("1", PQcmdTuples (result)))
    {
      GNUNET_break (0);
      return GNUNET_SYSERR;
    }
    PQclear (result);
  }
  return GNUNET_OK;
}


/**
 * We allocated some @a denom_pubs information, but now need
 * to abort. Free allocated memory.
 *
 * @param denom_pubs data to free (but not the array itself)
 * @param denom_pubs_len length of @a denom_pubs array
 */
static void
free_dpk_result (struct TALER_DenominationPublicKey *denom_pubs,
                 unsigned int denom_pubs_len)
{
  unsigned int i;

  for (i=0;i<denom_pubs_len;i++)
  {
    GNUNET_CRYPTO_rsa_public_key_free (denom_pubs[i].rsa_public_key);
    denom_pubs[i].rsa_public_key = NULL;
  }
}


/**
 * Lookup in the database the coins that we want to
 * create in the given refresh operation.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection
 * @param session_hash hash to identify refresh session
 * @param num_newcoins size of the array of the @a denom_pubs array
 * @param denom_pubs where to store the deomination keys
 * @return #GNUNET_OK on success
 *         #GNUNET_SYSERR on internal error
 */
static int
postgres_get_refresh_order (void *cls,
                            struct TALER_EXCHANGEDB_Session *session,
                            const struct GNUNET_HashCode *session_hash,
                            uint16_t num_newcoins,
                            struct TALER_DenominationPublicKey *denom_pubs)
{
  unsigned int i;

  for (i=0;i<(unsigned int) num_newcoins;i++)
  {
    uint16_t newcoin_off = (uint16_t) i;
    PGresult *result;

    {
      struct GNUNET_PQ_QueryParam params[] = {
        GNUNET_PQ_query_param_auto_from_type (session_hash),
        GNUNET_PQ_query_param_uint16 (&newcoin_off),
        GNUNET_PQ_query_param_end
      };

      result = GNUNET_PQ_exec_prepared (session->conn,
                                       "get_refresh_order",
                                       params);
    }
    if (PGRES_TUPLES_OK != PQresultStatus (result))
    {
      BREAK_DB_ERR (result);
      PQclear (result);
      free_dpk_result (denom_pubs, i);
      return GNUNET_SYSERR;
    }
    if (0 == PQntuples (result))
    {
      PQclear (result);
      /* FIXME: may want to distinguish between different error cases! */
      free_dpk_result (denom_pubs, i);
      return GNUNET_SYSERR;
    }
    GNUNET_assert (1 == PQntuples (result));
    {
      struct GNUNET_PQ_ResultSpec rs[] = {
        GNUNET_PQ_result_spec_rsa_public_key ("denom_pub",
                                             &denom_pubs[i].rsa_public_key),
        GNUNET_PQ_result_spec_end
      };
      if (GNUNET_OK !=
          GNUNET_PQ_extract_result (result, rs, 0))
      {
        PQclear (result);
        GNUNET_break (0);
        free_dpk_result (denom_pubs, i);
        return GNUNET_SYSERR;
      }
      PQclear (result);
    }
  }
  return GNUNET_OK;
}


/**
 * Store information about the commitment of the
 * given coin for the given refresh session in the database.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection to use
 * @param session_hash hash to identify refresh session
 * @param num_newcoins coin index size of the @a commit_coins array
 * @param commit_coins array of coin commitments to store
 * @return #GNUNET_OK on success
 *         #GNUNET_SYSERR on error
 */
static int
postgres_insert_refresh_commit_coins (void *cls,
                                      struct TALER_EXCHANGEDB_Session *session,
                                      const struct GNUNET_HashCode *session_hash,
                                      uint16_t num_newcoins,
                                      const struct TALER_EXCHANGEDB_RefreshCommitCoin *commit_coins)
{
  PGresult *result;
  unsigned int i;
  uint16_t coin_off;

  for (i=0;i<(unsigned int) num_newcoins;i++)
  {
    coin_off = (uint16_t) i;
    {
      struct GNUNET_PQ_QueryParam params[] = {
        GNUNET_PQ_query_param_auto_from_type (session_hash),
        GNUNET_PQ_query_param_uint16 (&coin_off),
        GNUNET_PQ_query_param_fixed_size (commit_coins[i].coin_ev,
					  commit_coins[i].coin_ev_size),
        GNUNET_PQ_query_param_end
      };
      result = GNUNET_PQ_exec_prepared (session->conn,
                                       "insert_refresh_commit_coin",
                                       params);
    }
    if (PGRES_COMMAND_OK != PQresultStatus (result))
    {
      BREAK_DB_ERR (result);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    if (0 != strcmp ("1", PQcmdTuples (result)))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    PQclear (result);
  }
  return GNUNET_OK;
}


/**
 * We allocated some @a commit_coin information, but now need
 * to abort. Free allocated memory.
 *
 * @param cls unused
 * @param commit_coins_len length of @a commit_coins array
 * @param commit_coins data to free (but not the array itself)
 */
static void
postgres_free_refresh_commit_coins (void *cls,
                                    unsigned int commit_coins_len,
                                    struct TALER_EXCHANGEDB_RefreshCommitCoin *commit_coins)
{
  unsigned int i;

  for (i=0;i<commit_coins_len;i++)
  {
    GNUNET_free (commit_coins[i].coin_ev);
    commit_coins[i].coin_ev = NULL;
    commit_coins[i].coin_ev_size = 0;
  }
}


/**
 * Obtain information about the commitment of the
 * given coin of the given refresh session from the database.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection to use
 * @param session_hash hash to identify refresh session
 * @param num_newcoins size of the @a commit_coins array
 * @param[out] commit_coins array of coin commitments to return
 * @return #GNUNET_OK on success
 *         #GNUNET_NO if not found
 *         #GNUNET_SYSERR on error
 */
static int
postgres_get_refresh_commit_coins (void *cls,
                                   struct TALER_EXCHANGEDB_Session *session,
                                   const struct GNUNET_HashCode *session_hash,
                                   uint16_t num_newcoins,
                                   struct TALER_EXCHANGEDB_RefreshCommitCoin *commit_coins)
{
  unsigned int i;

  for (i=0;i<(unsigned int) num_newcoins;i++)
  {
    uint16_t newcoin_off = (uint16_t) i;
    struct GNUNET_PQ_QueryParam params[] = {
      GNUNET_PQ_query_param_auto_from_type (session_hash),
      GNUNET_PQ_query_param_uint16 (&newcoin_off),
      GNUNET_PQ_query_param_end
    };
    void *c_buf;
    size_t c_buf_size;
    PGresult *result;

    result = GNUNET_PQ_exec_prepared (session->conn,
                                     "get_refresh_commit_coin",
                                     params);
    if (PGRES_TUPLES_OK != PQresultStatus (result))
    {
      BREAK_DB_ERR (result);
      PQclear (result);
      postgres_free_refresh_commit_coins (cls, i, commit_coins);
      return GNUNET_SYSERR;
    }
    if (0 == PQntuples (result))
    {
      PQclear (result);
      postgres_free_refresh_commit_coins (cls, i, commit_coins);
      return GNUNET_NO;
    }
    {
      struct GNUNET_PQ_ResultSpec rs[] = {
        GNUNET_PQ_result_spec_variable_size ("coin_ev",
					     &c_buf,
					     &c_buf_size),
        GNUNET_PQ_result_spec_end
      };

      if (GNUNET_YES !=
          GNUNET_PQ_extract_result (result, rs, 0))
      {
        PQclear (result);
        postgres_free_refresh_commit_coins (cls, i, commit_coins);
        return GNUNET_SYSERR;
      }
    }
    PQclear (result);
    commit_coins[i].coin_ev = c_buf;
    commit_coins[i].coin_ev_size = c_buf_size;
  }
  return GNUNET_YES;
}


/**
 * Store the commitment to the given (encrypted) refresh link data
 * for the given refresh session.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection to use
 * @param session_hash hash to identify refresh session
 * @param tp transfer public key to store
 * @return #GNUNET_SYSERR on internal error, #GNUNET_OK on success
 */
static int
postgres_insert_refresh_transfer_public_key (void *cls,
                                             struct TALER_EXCHANGEDB_Session *session,
                                             const struct GNUNET_HashCode *session_hash,
                                             const struct TALER_TransferPublicKeyP *tp)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (session_hash),
    GNUNET_PQ_query_param_auto_from_type (tp),
    GNUNET_PQ_query_param_end
  };

  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "insert_transfer_public_key",
                                    params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }

  if (0 != strcmp ("1", PQcmdTuples (result)))
  {
    GNUNET_break (0);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Obtain the commited (encrypted) refresh link data
 * for the given refresh session.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection to use
 * @param session_hash hash to identify refresh session
 * @param[out] tp information to return
 * @return #GNUNET_SYSERR on internal error,
 *         #GNUNET_NO if commitment was not found
 *         #GNUNET_OK on success
 */
static int
postgres_get_refresh_transfer_public_key (void *cls,
                                          struct TALER_EXCHANGEDB_Session *session,
                                          const struct GNUNET_HashCode *session_hash,
                                          struct TALER_TransferPublicKeyP *tp)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (session_hash),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "get_refresh_transfer_public_key",
                                    params);
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == PQntuples (result))
  {
    PQclear (result);
    return GNUNET_NO;
  }
  {
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("transfer_pub",
                                            tp),
      GNUNET_PQ_result_spec_end
    };

    if (GNUNET_YES !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      PQclear (result);
      return GNUNET_SYSERR;
    }
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Insert signature of a new coin generated during refresh into
 * the database indexed by the refresh session and the index
 * of the coin.  This data is later used should an old coin
 * be used to try to obtain the private keys during "/refresh/link".
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection
 * @param session_hash hash to identify refresh session
 * @param newcoin_index coin index
 * @param ev_sig coin signature
 * @return #GNUNET_OK on success
 */
static int
postgres_insert_refresh_out (void *cls,
                             struct TALER_EXCHANGEDB_Session *session,
                             const struct GNUNET_HashCode *session_hash,
                             uint16_t newcoin_index,
                             const struct TALER_DenominationSignature *ev_sig)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (session_hash),
    GNUNET_PQ_query_param_uint16 (&newcoin_index),
    GNUNET_PQ_query_param_rsa_signature (ev_sig->rsa_signature),
    GNUNET_PQ_query_param_end
  };

  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "insert_refresh_out",
                                    params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Obtain the link data of a coin, that is the encrypted link
 * information, the denomination keys and the signatures.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection
 * @param session_hash refresh session to get linkage data for
 * @return all known link data for the session
 */
static struct TALER_EXCHANGEDB_LinkDataList *
postgres_get_link_data_list (void *cls,
                             struct TALER_EXCHANGEDB_Session *session,
                             const struct GNUNET_HashCode *session_hash)
{
  struct TALER_EXCHANGEDB_LinkDataList *ldl;
  int i;
  int nrows;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (session_hash),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "get_link",
                                   params);
  ldl = NULL;
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return NULL;
  }
  nrows = PQntuples (result);
  if (0 == nrows)
  {
    PQclear (result);
    return NULL;
  }

  for (i = nrows-1; i >= 0; i--)
  {
    struct GNUNET_CRYPTO_RsaPublicKey *denom_pub;
    struct GNUNET_CRYPTO_RsaSignature *sig;
    struct TALER_EXCHANGEDB_LinkDataList *pos;

    pos = GNUNET_new (struct TALER_EXCHANGEDB_LinkDataList);
    {
      struct GNUNET_PQ_ResultSpec rs[] = {
	GNUNET_PQ_result_spec_rsa_signature ("ev_sig",
					     &sig),
	GNUNET_PQ_result_spec_rsa_public_key ("denom_pub",
					      &denom_pub),
	GNUNET_PQ_result_spec_end
      };

      if (GNUNET_OK !=
	  GNUNET_PQ_extract_result (result,
                                    rs,
                                    i))
      {
	PQclear (result);
	GNUNET_break (0);
	common_free_link_data_list (cls,
				    ldl);
	GNUNET_free (pos);
	return NULL;
      }
    }
    pos->next = ldl;
    pos->denom_pub.rsa_public_key = denom_pub;
    pos->ev_sig.rsa_signature = sig;
    ldl = pos;
  }
  PQclear (result);
  return ldl;
}


/**
 * Obtain shared secret and transfer public key from the public key of
 * the coin.  This information and the link information returned by
 * #postgres_get_link_data_list() enable the owner of an old coin to
 * determine the private keys of the new coins after the melt.
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection
 * @param coin_pub public key of the coin
 * @param tdc function to call for each session the coin was melted into
 * @param tdc_cls closure for @a tdc
 * @return #GNUNET_OK on success,
 *         #GNUNET_NO on failure (not found)
 *         #GNUNET_SYSERR on internal failure (database issue)
 */
static int
postgres_get_transfer (void *cls,
                       struct TALER_EXCHANGEDB_Session *session,
                       const struct TALER_CoinSpendPublicKeyP *coin_pub,
                       TALER_EXCHANGEDB_TransferDataCallback tdc,
                       void *tdc_cls)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (coin_pub),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  int nrows;
  int i;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "get_transfer",
                                   params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  nrows = PQntuples (result);
  if (0 == nrows)
  {
    /* no matches found */
    PQclear (result);
    return GNUNET_NO;
  }
  for (i=0;i<nrows;i++)
  {
    struct GNUNET_HashCode session_hash;
    struct TALER_TransferPublicKeyP transfer_pub;
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("transfer_pub", &transfer_pub),
      GNUNET_PQ_result_spec_auto_from_type ("session_hash", &session_hash),
      GNUNET_PQ_result_spec_end
    };

    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      PQclear (result);
      GNUNET_break (0);
      return GNUNET_SYSERR;
    }
    tdc (tdc_cls,
         &session_hash,
         &transfer_pub);
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Compile a list of all (historic) transactions performed
 * with the given coin (/refresh/melt, /deposit and /refund operations).
 *
 * @param cls the `struct PostgresClosure` with the plugin-specific state
 * @param session database connection
 * @param coin_pub coin to investigate
 * @return list of transactions, NULL if coin is fresh
 */
static struct TALER_EXCHANGEDB_TransactionList *
postgres_get_coin_transactions (void *cls,
                                struct TALER_EXCHANGEDB_Session *session,
                                const struct TALER_CoinSpendPublicKeyP *coin_pub)
{
  struct TALER_EXCHANGEDB_TransactionList *head;

  head = NULL;
  /* check deposits */
  {
    struct GNUNET_PQ_QueryParam params[] = {
      GNUNET_PQ_query_param_auto_from_type (&coin_pub->eddsa_pub),
      GNUNET_PQ_query_param_end
    };
    int nrows;
    int i;
    PGresult *result;
    struct TALER_EXCHANGEDB_TransactionList *tl;

    result = GNUNET_PQ_exec_prepared (session->conn,
                                      "get_deposit_with_coin_pub",
                                      params);
    if (PGRES_TUPLES_OK != PQresultStatus (result))
    {
      QUERY_ERR (result);
      PQclear (result);
      goto cleanup;
    }
    nrows = PQntuples (result);
    for (i = 0; i < nrows; i++)
    {
      struct TALER_EXCHANGEDB_Deposit *deposit;

      deposit = GNUNET_new (struct TALER_EXCHANGEDB_Deposit);
      {
        struct GNUNET_PQ_ResultSpec rs[] = {
          GNUNET_PQ_result_spec_uint64 ("transaction_id",
                                        &deposit->transaction_id),
          TALER_PQ_result_spec_amount ("amount_with_fee",
                                       &deposit->amount_with_fee),
          TALER_PQ_result_spec_amount ("fee_deposit",
                                       &deposit->deposit_fee),
          GNUNET_PQ_result_spec_absolute_time ("timestamp",
                                               &deposit->timestamp),
          GNUNET_PQ_result_spec_absolute_time ("refund_deadline",
                                               &deposit->refund_deadline),
          GNUNET_PQ_result_spec_auto_from_type ("merchant_pub",
                                                &deposit->merchant_pub),
          GNUNET_PQ_result_spec_auto_from_type ("h_contract",
                                                &deposit->h_contract),
          GNUNET_PQ_result_spec_auto_from_type ("h_wire",
                                                &deposit->h_wire),
          TALER_PQ_result_spec_json ("wire",
                                     &deposit->receiver_wire_account),
          GNUNET_PQ_result_spec_auto_from_type ("coin_sig",
                                               &deposit->csig),
          GNUNET_PQ_result_spec_end
        };

        if (GNUNET_OK !=
            GNUNET_PQ_extract_result (result, rs, i))
        {
          GNUNET_break (0);
          GNUNET_free (deposit);
          PQclear (result);
          goto cleanup;
        }
        deposit->coin.coin_pub = *coin_pub;
      }
      tl = GNUNET_new (struct TALER_EXCHANGEDB_TransactionList);
      tl->next = head;
      tl->type = TALER_EXCHANGEDB_TT_DEPOSIT;
      tl->details.deposit = deposit;
      if (GNUNET_SYSERR == get_known_coin (cls,
                                           session,
                                           &deposit->coin.coin_pub,
                                           &deposit->coin))
      {
        GNUNET_break (0);
        GNUNET_free (deposit);
        PQclear (result);
        goto cleanup;
      }
      head = tl;
      continue;
    }
    PQclear (result);
  }
  /* Handle refreshing */
  {
    struct GNUNET_PQ_QueryParam params[] = {
      GNUNET_PQ_query_param_auto_from_type (&coin_pub->eddsa_pub),
      GNUNET_PQ_query_param_end
    };
    int nrows;
    int i;
    PGresult *result;
    struct TALER_EXCHANGEDB_TransactionList *tl;

    /* check if the melt records exist and get them */
    result = GNUNET_PQ_exec_prepared (session->conn,
                                      "get_refresh_session_by_coin",
                                      params);
    if (PGRES_TUPLES_OK != PQresultStatus (result))
    {
      BREAK_DB_ERR (result);
      PQclear (result);
      goto cleanup;
    }
    nrows = PQntuples (result);
    for (i=0;i<nrows;i++)
    {
      struct TALER_EXCHANGEDB_RefreshMelt *melt;

      melt = GNUNET_new (struct TALER_EXCHANGEDB_RefreshMelt);
      {
        struct GNUNET_PQ_ResultSpec rs[] = {
          GNUNET_PQ_result_spec_auto_from_type ("session_hash",
                                                &melt->session_hash),
          /* oldcoin_index not needed */
          GNUNET_PQ_result_spec_auto_from_type ("old_coin_sig",
                                                &melt->coin_sig),
          TALER_PQ_result_spec_amount ("amount_with_fee",
                                       &melt->amount_with_fee),
          TALER_PQ_result_spec_amount ("fee_refresh",
                                       &melt->melt_fee),
          GNUNET_PQ_result_spec_end
        };
        if (GNUNET_OK !=
            GNUNET_PQ_extract_result (result, rs, 0))
        {
          GNUNET_break (0);
          GNUNET_free (melt);
          PQclear (result);
          goto cleanup;
        }
	melt->coin.coin_pub = *coin_pub;
      }
      tl = GNUNET_new (struct TALER_EXCHANGEDB_TransactionList);
      tl->next = head;
      tl->type = TALER_EXCHANGEDB_TT_REFRESH_MELT;
      tl->details.melt = melt;
      if (GNUNET_SYSERR == get_known_coin (cls,
                                           session,
                                           coin_pub,
                                           &melt->coin))
      {
        GNUNET_break (0);
        GNUNET_free (melt);
        PQclear (result);
        goto cleanup;
      }
      head = tl;
      continue;
    }
    PQclear (result);
  }
  /* handle refunds */
  {
    struct GNUNET_PQ_QueryParam params[] = {
      GNUNET_PQ_query_param_auto_from_type (&coin_pub->eddsa_pub),
      GNUNET_PQ_query_param_end
    };
    int nrows;
    int i;
    PGresult *result;
    struct TALER_EXCHANGEDB_TransactionList *tl;

    /* check if a refund records exist and get them */
    result = GNUNET_PQ_exec_prepared (session->conn,
                                      "get_refunds_by_coin",
                                      params);
    if (PGRES_TUPLES_OK != PQresultStatus (result))
    {
      BREAK_DB_ERR (result);
      PQclear (result);
      goto cleanup;
    }
    nrows = PQntuples (result);
    for (i=0;i<nrows;i++)
    {
      struct TALER_EXCHANGEDB_Refund *refund;

      refund = GNUNET_new (struct TALER_EXCHANGEDB_Refund);
      {
        struct GNUNET_PQ_ResultSpec rs[] = {
          GNUNET_PQ_result_spec_auto_from_type ("merchant_pub",
                                                &refund->merchant_pub),
          GNUNET_PQ_result_spec_auto_from_type ("merchant_sig",
                                                &refund->merchant_sig),
          GNUNET_PQ_result_spec_auto_from_type ("h_contract",
                                                &refund->h_contract),
          GNUNET_PQ_result_spec_uint64 ("transaction_id",
                                        &refund->transaction_id),
          GNUNET_PQ_result_spec_uint64 ("rtransaction_id",
                                        &refund->rtransaction_id),
          TALER_PQ_result_spec_amount ("amount_with_fee",
                                       &refund->refund_amount),
          TALER_PQ_result_spec_amount ("fee_refund",
                                       &refund->refund_fee),
          GNUNET_PQ_result_spec_end
        };
        if (GNUNET_OK !=
            GNUNET_PQ_extract_result (result, rs, 0))
        {
          GNUNET_break (0);
          GNUNET_free (refund);
          PQclear (result);
          goto cleanup;
        }
	refund->coin.coin_pub = *coin_pub;
      }
      tl = GNUNET_new (struct TALER_EXCHANGEDB_TransactionList);
      tl->next = head;
      tl->type = TALER_EXCHANGEDB_TT_REFUND;
      tl->details.refund = refund;
      if (GNUNET_SYSERR ==
          get_known_coin (cls,
                          session,
                          coin_pub,
                          &refund->coin))
      {
        GNUNET_break (0);
        GNUNET_free (refund);
        PQclear (result);
        goto cleanup;
      }
      head = tl;
      continue;
    }
    PQclear (result);
  }
  return head;
 cleanup:
  if (NULL != head)
    common_free_coin_transaction_list (cls,
                                       head);
  return NULL;
}


/**
 * Lookup the list of Taler transactions that were aggregated
 * into a wire transfer by the respective @a wtid.
 *
 * @param cls closure
 * @param session database connection
 * @param wtid the raw wire transfer identifier we used
 * @param cb function to call on each transaction found
 * @param cb_cls closure for @a cb
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on database errors,
 *         #GNUNET_NO if we found no results
 */
static int
postgres_lookup_wire_transfer (void *cls,
                               struct TALER_EXCHANGEDB_Session *session,
                               const struct TALER_WireTransferIdentifierRawP *wtid,
                               TALER_EXCHANGEDB_WireTransferDataCallback cb,
                               void *cb_cls)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (wtid),
    GNUNET_PQ_query_param_end
  };
  int nrows;
  int i;

  /* check if the melt record exists and get it */
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "lookup_transactions",
                                    params);
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  nrows = PQntuples (result);
  if (0 == nrows)
  {
    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "lookup_wire_transfer() returned 0 matching rows\n");
    PQclear (result);
    return GNUNET_NO;
  }
  for (i=0;i<nrows;i++)
  {
    struct GNUNET_HashCode h_contract;
    struct GNUNET_HashCode h_wire;
    struct TALER_CoinSpendPublicKeyP coin_pub;
    struct TALER_MerchantPublicKeyP merchant_pub;
    uint64_t transaction_id;
    struct GNUNET_TIME_Absolute exec_time;
    struct TALER_Amount amount_with_fee;
    struct TALER_Amount deposit_fee;
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("h_contract", &h_contract),
      GNUNET_PQ_result_spec_auto_from_type ("h_wire", &h_wire),
      GNUNET_PQ_result_spec_auto_from_type ("coin_pub", &coin_pub),
      GNUNET_PQ_result_spec_auto_from_type ("merchant_pub", &merchant_pub),
      GNUNET_PQ_result_spec_uint64 ("transaction_id", &transaction_id),
      GNUNET_PQ_result_spec_absolute_time ("execution_time", &exec_time),
      TALER_PQ_result_spec_amount ("amount_with_fee", &amount_with_fee),
      TALER_PQ_result_spec_amount ("fee_deposit", &deposit_fee),
       GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result,
                                  rs,
                                  i))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    cb (cb_cls,
        &merchant_pub,
        &h_wire,
        exec_time,
        &h_contract,
        transaction_id,
        &coin_pub,
        &amount_with_fee,
        &deposit_fee);
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Try to find the wire transfer details for a deposit operation.
 * If we did not execute the deposit yet, return when it is supposed
 * to be executed.
 *
 * @param cls closure
 * @param session database connection
 * @param h_contract hash of the contract
 * @param h_wire hash of merchant wire details
 * @param coin_pub public key of deposited coin
 * @param merchant_pub merchant public key
 * @param transaction_id transaction identifier
 * @param cb function to call with the result
 * @param cb_cls closure to pass to @a cb
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on DB errors,
 *         #GNUNET_NO if nothing was found
 */
static int
postgres_wire_lookup_deposit_wtid (void *cls,
                                   struct TALER_EXCHANGEDB_Session *session,
				   const struct GNUNET_HashCode *h_contract,
				   const struct GNUNET_HashCode *h_wire,
				   const struct TALER_CoinSpendPublicKeyP *coin_pub,
				   const struct TALER_MerchantPublicKeyP *merchant_pub,
				   uint64_t transaction_id,
				   TALER_EXCHANGEDB_TrackTransactionCallback cb,
				   void *cb_cls)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_auto_from_type (coin_pub),
    GNUNET_PQ_query_param_auto_from_type (h_contract),
    GNUNET_PQ_query_param_auto_from_type (h_wire),
    GNUNET_PQ_query_param_uint64 (&transaction_id),
    GNUNET_PQ_query_param_auto_from_type (merchant_pub),
    GNUNET_PQ_query_param_end
  };
  int nrows;

  /* check if the melt record exists and get it */
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "lookup_deposit_wtid",
                                    params);
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  nrows = PQntuples (result);
  if (0 == nrows)
  {
    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "lookup_deposit_wtid returned 0 matching rows\n");
    PQclear (result);

    /* Check if transaction exists in deposits, so that we just
       do not have a WTID yet, if so, do call the CB with a NULL wtid
       and return #GNUNET_YES! */
    {
      struct GNUNET_PQ_QueryParam params2[] = {
        GNUNET_PQ_query_param_auto_from_type (coin_pub),
        GNUNET_PQ_query_param_uint64 (&transaction_id),
        GNUNET_PQ_query_param_auto_from_type (merchant_pub),
        GNUNET_PQ_query_param_auto_from_type (h_contract),
        GNUNET_PQ_query_param_auto_from_type (h_wire),
        GNUNET_PQ_query_param_end
      };

      result = GNUNET_PQ_exec_prepared (session->conn,
                                        "get_deposit_for_wtid",
                                        params2);
      if (PGRES_TUPLES_OK != PQresultStatus (result))
      {
        BREAK_DB_ERR (result);
        PQclear (result);
        return GNUNET_SYSERR;
      }
    }
    nrows = PQntuples (result);
    if (0 == nrows)
    {
      GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                  "get_deposit_for_wtid returned 0 matching rows\n");
      PQclear (result);
      return GNUNET_NO;
    }

    /* Ok, we're aware of the transaction, but it has not yet been
       executed */
    {
      struct GNUNET_TIME_Absolute exec_time;
      struct TALER_Amount amount_with_fee;
      struct TALER_Amount deposit_fee;
      struct GNUNET_PQ_ResultSpec rs[] = {
        TALER_PQ_result_spec_amount ("amount_with_fee", &amount_with_fee),
        TALER_PQ_result_spec_amount ("fee_deposit", &deposit_fee),
        GNUNET_PQ_result_spec_absolute_time ("wire_deadline", &exec_time),
        GNUNET_PQ_result_spec_end
      };

      if (GNUNET_OK != GNUNET_PQ_extract_result (result, rs, 0))
      {
        GNUNET_break (0);
        PQclear (result);
        return GNUNET_SYSERR;
      }
      cb (cb_cls,
          NULL,
          &amount_with_fee,
          &deposit_fee,
          exec_time);
      PQclear (result);
      return GNUNET_YES;
    }
  }
  if (1 != nrows)
  {
    GNUNET_break (0);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  {
    struct TALER_WireTransferIdentifierRawP wtid;
    struct GNUNET_TIME_Absolute exec_time;
    struct TALER_Amount amount_with_fee;
    struct TALER_Amount deposit_fee;
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("wtid_raw", &wtid),
      GNUNET_PQ_result_spec_absolute_time ("execution_time", &exec_time),
      TALER_PQ_result_spec_amount ("amount_with_fee", &amount_with_fee),
      TALER_PQ_result_spec_amount ("fee_deposit", &deposit_fee),
      GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK != GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    cb (cb_cls,
        &wtid,
        &amount_with_fee,
        &deposit_fee,
        exec_time);
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Function called to insert aggregation information into the DB.
 *
 * @param cls closure
 * @param session database connection
 * @param wtid the raw wire transfer identifier we used
 * @param deposit_serial_id row in the deposits table for which this is aggregation data
 * @param execution_time when did we execute the transaction
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on DB errors
 */
static int
postgres_insert_aggregation_tracking (void *cls,
                                      struct TALER_EXCHANGEDB_Session *session,
                                      const struct TALER_WireTransferIdentifierRawP *wtid,
                                      unsigned long long deposit_serial_id,
                                      struct GNUNET_TIME_Absolute execution_time)
{
  uint64_t rid = deposit_serial_id;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&rid),
    GNUNET_PQ_query_param_auto_from_type (wtid),
    GNUNET_PQ_query_param_absolute_time (&execution_time),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "insert_aggregation_tracking",
                                   params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 != strcmp ("1", PQcmdTuples (result)))
  {
    GNUNET_break (0);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Function called to insert wire transfer commit data into the DB.
 *
 * @param cls closure
 * @param session database connection
 * @param type type of the wire transfer (i.e. "sepa")
 * @param buf buffer with wire transfer preparation data
 * @param buf_size number of bytes in @a buf
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on DB errors
 */
static int
postgres_wire_prepare_data_insert (void *cls,
                                   struct TALER_EXCHANGEDB_Session *session,
                                   const char *type,
                                   const char *buf,
                                   size_t buf_size)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_string (type),
    GNUNET_PQ_query_param_fixed_size (buf, buf_size),
    GNUNET_PQ_query_param_end
  };

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "wire_prepare_data_insert",
                                   params);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Function called to mark wire transfer commit data as finished.
 *
 * @param cls closure
 * @param session database connection
 * @param rowid which entry to mark as finished
 * @return #GNUNET_OK on success, #GNUNET_SYSERR on DB errors
 */
static int
postgres_wire_prepare_data_mark_finished (void *cls,
                                          struct TALER_EXCHANGEDB_Session *session,
                                          unsigned long long rowid)
{
  uint64_t prewire_uuid = rowid;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&prewire_uuid),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "wire_prepare_data_mark_done",
                                   params);
  if (PGRES_COMMAND_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Function called to get an unfinished wire transfer
 * preparation data. Fetches at most one item.
 *
 * @param cls closure
 * @param session database connection
 * @param cb function to call for ONE unfinished item
 * @param cb_cls closure for @a cb
 * @return #GNUNET_OK on success,
 *         #GNUNET_NO if there are no entries,
 *         #GNUNET_SYSERR on DB errors
 */
static int
postgres_wire_prepare_data_get (void *cls,
                                struct TALER_EXCHANGEDB_Session *session,
                                TALER_EXCHANGEDB_WirePreparationIterator cb,
                                void *cb_cls)
{
  PGresult *result;
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_end
  };

  result = GNUNET_PQ_exec_prepared (session->conn,
                                   "wire_prepare_data_get",
                                   params);
  if (PGRES_TUPLES_OK != PQresultStatus (result))
  {
    QUERY_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  if (0 == PQntuples (result))
  {
    PQclear (result);
    return GNUNET_NO;
  }
  if (1 != PQntuples (result))
  {
    GNUNET_break (0);
    PQclear (result);
    return GNUNET_SYSERR;
  }

  {
    uint64_t prewire_uuid;
    char *type;
    void *buf = NULL;
    size_t buf_size;
    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_uint64 ("prewire_uuid",
                                    &prewire_uuid),
      GNUNET_PQ_result_spec_string ("type",
                                    &type),
      GNUNET_PQ_result_spec_variable_size ("buf",
                                           &buf,
                                           &buf_size),
      GNUNET_PQ_result_spec_end
    };

    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result,
                                 rs,
                                 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    cb (cb_cls,
        prewire_uuid,
        type,
        buf,
        buf_size);
    GNUNET_PQ_cleanup_result (rs);
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Function called to perform "garbage collection" on the
 * database, expiring records we no longer require.
 *
 * @param cls closure
 * @return #GNUNET_OK on success,
 *         #GNUNET_SYSERR on DB errors
 */
static int
postgres_gc (void *cls)
{
  struct PostgresClosure *pc = cls;
  struct GNUNET_TIME_Absolute now;
  struct GNUNET_PQ_QueryParam params_none[] = {
    GNUNET_PQ_query_param_end
  };
  struct GNUNET_PQ_QueryParam params_time[] = {
    GNUNET_PQ_query_param_absolute_time (&now),
    GNUNET_PQ_query_param_end
  };
  PGconn *conn;
  PGresult *result;

  now = GNUNET_TIME_absolute_get ();
  conn = connect_to_postgres (pc);
  if (NULL == conn)
    return GNUNET_SYSERR;
  if (GNUNET_OK !=
      postgres_prepare (conn))
  {
    PQfinish (conn);
    return GNUNET_SYSERR;
  }
  result = GNUNET_PQ_exec_prepared (conn,
                                    "gc_prewire",
                                    params_none);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    PQfinish (conn);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  result = GNUNET_PQ_exec_prepared (conn,
                                    "gc_denominations",
                                    params_time);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    PQfinish (conn);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  result = GNUNET_PQ_exec_prepared (conn,
                                    "gc_reserves",
                                    params_time);
  if (PGRES_COMMAND_OK != PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    PQfinish (conn);
    return GNUNET_SYSERR;
  }
  PQclear (result);
  PQfinish (conn);
  return GNUNET_OK;
}


/**
 * Select deposits above @a serial_id in monotonically increasing
 * order.
 *
 * @param cls closure
 * @param session database connection
 * @param serial_id highest serial ID to exclude (select strictly larger)
 * @param cb function to call on each result
 * @param cb_cls closure for @a cb
 * @return #GNUNET_OK on success,
 *         #GNUNET_SYSERR on DB errors
 */
static int
postgres_select_deposits_above_serial_id (void *cls,
                                          struct TALER_EXCHANGEDB_Session *session,
                                          uint64_t serial_id,
                                          TALER_EXCHANGEDB_DepositCallback cb,
                                          void *cb_cls)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&serial_id),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "audit_get_deposits_incr",
                                    params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  int nrows;
  int i;

  nrows = PQntuples (result);
  if (0 == nrows)
  {
    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "select_deposits_above_serial_id() returned 0 matching rows\n");
    PQclear (result);
    return GNUNET_NO;
  }
  for (i=0;i<nrows;i++)
  {
    struct TALER_EXCHANGEDB_Deposit deposit;
    uint8_t done = 0;

    struct GNUNET_PQ_ResultSpec rs[] = {
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &deposit.amount_with_fee),
      GNUNET_PQ_result_spec_absolute_time ("timestamp",
                                          &deposit.timestamp),
      GNUNET_PQ_result_spec_auto_from_type ("merchant_pub",
                                            &deposit.merchant_pub),
      GNUNET_PQ_result_spec_auto_from_type ("coin_pub",
                                           &deposit.coin.coin_pub),
      GNUNET_PQ_result_spec_auto_from_type ("coin_sig",
                                           &deposit.csig),
      GNUNET_PQ_result_spec_uint64 ("transaction_id",
                                    &deposit.transaction_id),
      GNUNET_PQ_result_spec_absolute_time ("refund_deadline",
                                           &deposit.refund_deadline),
      GNUNET_PQ_result_spec_absolute_time ("wire_deadline",
                                           &deposit.wire_deadline),
      GNUNET_PQ_result_spec_auto_from_type ("h_contract",
                                           &deposit.h_contract),
      TALER_PQ_result_spec_json ("wire",
                                 &deposit.receiver_wire_account),
      GNUNET_PQ_result_spec_auto_from_type ("done",
                                            &done),
      GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    cb (cb_cls,
        serial_id,
        &deposit.merchant_pub,
        &deposit.coin.coin_pub,
        &deposit.csig,
        &deposit.amount_with_fee,
        deposit.transaction_id,
        &deposit.h_contract,
        deposit.refund_deadline,
        deposit.wire_deadline,
        deposit.receiver_wire_account,
        done);
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Select refresh sessions above @a serial_id in monotonically increasing
 * order.
 *
 * @param cls closure
 * @param session database connection
 * @param serial_id highest serial ID to exclude (select strictly larger)
 * @param cb function to call on each result
 * @param cb_cls closure for @a cb
 * @return #GNUNET_OK on success,
 *         #GNUNET_SYSERR on DB errors
 */
static int
postgres_select_refreshs_above_serial_id (void *cls,
                                          struct TALER_EXCHANGEDB_Session *session,
                                          uint64_t serial_id,
                                          TALER_EXCHANGEDB_RefreshSessionCallback cb,
                                          void *cb_cls)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&serial_id),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "audit_get_refresh_sessions_incr",
                                    params);

  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  int nrows;
  int i;

  nrows = PQntuples (result);
  if (0 == nrows)
  {
    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "select_refreshs_above_serial_id() returned 0 matching rows\n");
    PQclear (result);
    return GNUNET_NO;
  }

  for (i=0;i<nrows;i++)
  {
    struct TALER_CoinSpendPublicKeyP coin_pub;
    struct TALER_CoinSpendSignatureP coin_sig;
    struct TALER_Amount amount_with_fee;
    uint16_t num_newcoins;
    uint16_t noreveal_index;

    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("old_coin_pub",
                                            &coin_pub),
      GNUNET_PQ_result_spec_auto_from_type ("old_coin_sig",
                                            &coin_sig),
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &amount_with_fee),
      GNUNET_PQ_result_spec_uint16 ("num_newcoins",
                                    &num_newcoins),
      GNUNET_PQ_result_spec_uint16 ("noreveal_index",
                                    &noreveal_index),
      GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    cb (cb_cls,
        serial_id,
        &coin_pub,
        &coin_sig,
        &amount_with_fee,
        num_newcoins,
        noreveal_index);
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Select refunds above @a serial_id in monotonically increasing
 * order.
 *
 * @param cls closure
 * @param session database connection
 * @param serial_id highest serial ID to exclude (select strictly larger)
 * @param cb function to call on each result
 * @param cb_cls closure for @a cb
 * @return #GNUNET_OK on success,
 *         #GNUNET_SYSERR on DB errors
 */
static int
postgres_select_refunds_above_serial_id (void *cls,
                                         struct TALER_EXCHANGEDB_Session *session,
                                         uint64_t serial_id,
                                         TALER_EXCHANGEDB_RefundCallback cb,
                                         void *cb_cls)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&serial_id),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "audit_get_refunds_incr",
                                    params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  int nrows;
  int i;

  nrows = PQntuples (result);
  if (0 == nrows)
  {
    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "select_refunds_above_serial_id() returned 0 matching rows\n");
    PQclear (result);
    return GNUNET_NO;
  }
  for (i=0;i<nrows;i++)
  {
    struct TALER_EXCHANGEDB_Refund refund;

    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("merchant_pub",
                                            &refund.merchant_pub),
      GNUNET_PQ_result_spec_auto_from_type ("merchant_sig",
                                           &refund.merchant_sig),
      GNUNET_PQ_result_spec_auto_from_type ("h_contract",
                                           &refund.h_contract),
      GNUNET_PQ_result_spec_uint64 ("transaction_id",
                                    &refund.transaction_id),
      GNUNET_PQ_result_spec_uint64 ("rtransaction_id",
                                    &refund.rtransaction_id),
      GNUNET_PQ_result_spec_auto_from_type ("coin_pub",
                                           &refund.coin.coin_pub),
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &refund.refund_amount),
      GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    cb (cb_cls,
        serial_id,
        &refund.coin.coin_pub,
        &refund.merchant_pub,
        &refund.merchant_sig,
        &refund.h_contract,
        refund.transaction_id,
        refund.rtransaction_id,
        &refund.refund_amount);
  }
  PQclear (result);
  return GNUNET_OK;
}


/**
 * Select inbound wire transfers into reserves_in above @a serial_id
 * in monotonically increasing order.
 *
 * @param cls closure
 * @param session database connection
 * @param serial_id highest serial ID to exclude (select strictly larger)
 * @param cb function to call on each result
 * @param cb_cls closure for @a cb
 * @return #GNUNET_OK on success,
 *         #GNUNET_SYSERR on DB errors
 */
static int
postgres_select_reserves_in_above_serial_id (void *cls,
                                             struct TALER_EXCHANGEDB_Session *session,
                                             uint64_t serial_id,
                                             TALER_EXCHANGEDB_ReserveInCallback cb,
                                             void *cb_cls)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&serial_id),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "audit_reserves_in_get_transactions_incr",
                                    params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  int nrows;
  int i;

  nrows = PQntuples (result);
  if (0 == nrows)
  {
    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "select_reserves_in_above_serial_id() returned 0 matching rows\n");
    PQclear (result);
    return GNUNET_NO;
  }

  for (i=0;i<nrows;i++)
  {
    struct TALER_ReservePublicKeyP reserve_pub;
    struct TALER_Amount credit;
    json_t *sender_account_details;
    json_t *transfer_details;
    struct GNUNET_TIME_Absolute execution_date;

    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("reserve_pub",
                                            &reserve_pub),
      TALER_PQ_result_spec_amount ("credit",
                                   &credit),
      GNUNET_PQ_result_spec_absolute_time("execution_date",
                                          &execution_date),
      TALER_PQ_result_spec_json ("sender_account_details",
                                 &sender_account_details),                                          
      TALER_PQ_result_spec_json ("transfer_details",
                                 &transfer_details),
    };

    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    cb (cb_cls,
        serial_id,
        &reserve_pub,
        &credit,
        sender_account_details,
        transfer_details,
        execution_date);
  }

  PQclear (result);
  return GNUNET_OK;
}


/**
 * Select withdraw operations from reserves_out above @a serial_id
 * in monotonically increasing order.
 *
 * @param cls closure
 * @param session database connection
 * @param serial_id highest serial ID to exclude (select strictly larger)
 * @param cb function to call on each result
 * @param cb_cls closure for @a cb
 * @return #GNUNET_OK on success,
 *         #GNUNET_SYSERR on DB errors
 */
static int
postgres_select_reserves_out_above_serial_id (void *cls,
                                              struct TALER_EXCHANGEDB_Session *session,
                                              uint64_t serial_id,
                                              TALER_EXCHANGEDB_WithdrawCallback cb,
                                              void *cb_cls)
{
  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&serial_id),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "audit_get_reserves_out_incr",
                                    params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  int nrows;
  int i;

  nrows = PQntuples (result);
  if (0 == nrows)
  {
    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "select_reserves_out_above_serial_id() returned 0 matching rows\n");
    PQclear (result);
    return GNUNET_NO;
  }
  for (i=0;i<nrows;i++)
  {
    struct GNUNET_HashCode h_blind_ev;
    struct TALER_DenominationPublicKey denom_pub;
    struct TALER_DenominationSignature denom_sig;
    struct TALER_ReservePublicKeyP reserve_pub;
    struct TALER_ReserveSignatureP reserve_sig;
    struct GNUNET_TIME_Absolute execution_date;
    struct TALER_Amount amount_with_fee;

    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_auto_from_type ("h_blind_ev",
                                            &h_blind_ev),
      GNUNET_PQ_result_spec_rsa_public_key ("denom_pub",
                                            &denom_pub.rsa_public_key),
      GNUNET_PQ_result_spec_rsa_signature ("denom_sig",
                                           &denom_sig.rsa_signature),
      GNUNET_PQ_result_spec_auto_from_type ("reserve_pub",
                                            &reserve_pub),
      GNUNET_PQ_result_spec_auto_from_type ("reserve_sig",
                                            &reserve_sig),
      GNUNET_PQ_result_spec_absolute_time ("execution_date",
                                           &execution_date),
      TALER_PQ_result_spec_amount ("amount_with_fee",
                                   &amount_with_fee),
      GNUNET_PQ_result_spec_end
    };
    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }
    cb (cb_cls,
        serial_id,
        &h_blind_ev,
        &denom_pub,
        &denom_sig,
        &reserve_pub,
        &reserve_sig,
        execution_date,
        &amount_with_fee);
  }

  PQclear (result);
  return GNUNET_OK;
}


/**
 * Function called to select all wire transfers the exchange
 * executed or plans to execute.
 *
 * @param cls closure
 * @param session database connection
 * @param serial_id highest serial ID to exclude (select strictly larger)
 * @param cb function to call for ONE unfinished item
 * @param cb_cls closure for @a cb
 * @return #GNUNET_OK on success,
 *         #GNUNET_NO if there are no entries,
 *         #GNUNET_SYSERR on DB errors
 */
static int
postgres_select_prepare_above_serial_id (void *cls,
                                         struct TALER_EXCHANGEDB_Session *session,
                                         uint64_t serial_id,
                                         TALER_EXCHANGEDB_WirePreparationCallback cb,
                                         void *cb_cls)
{

  struct GNUNET_PQ_QueryParam params[] = {
    GNUNET_PQ_query_param_uint64 (&serial_id),
    GNUNET_PQ_query_param_end
  };
  PGresult *result;
  result = GNUNET_PQ_exec_prepared (session->conn,
                                    "audit_get_wire_incr",
                                    params);
  if (PGRES_TUPLES_OK !=
      PQresultStatus (result))
  {
    BREAK_DB_ERR (result);
    PQclear (result);
    return GNUNET_SYSERR;
  }
  int nrows;
  int i;

  nrows = PQntuples (result);
  if (0 == nrows)
  {
    GNUNET_log (GNUNET_ERROR_TYPE_DEBUG,
                "select_prepare_above_serial_id() returned 0 matching rows\n");
    PQclear (result);
    return GNUNET_NO;
  }
  for (i=0;i<nrows;i++)
  {
    char *wire_method;
    void *buf;
    size_t buf_size;
    uint8_t finished;

    struct GNUNET_PQ_ResultSpec rs[] = {
      GNUNET_PQ_result_spec_string ("type",
                                    &wire_method),
      GNUNET_PQ_result_spec_variable_size ("buf",
                                           &buf,
                                           &buf_size),
      GNUNET_PQ_result_spec_auto_from_type ("finished",
                                            &finished),
      GNUNET_PQ_result_spec_end
    };

    if (GNUNET_OK !=
        GNUNET_PQ_extract_result (result, rs, 0))
    {
      GNUNET_break (0);
      PQclear (result);
      return GNUNET_SYSERR;
    }

    cb (cb_cls,
        serial_id,
        wire_method,
        buf,
        buf_size,
        finished);
  }

  PQclear (result);
  return GNUNET_OK;
}


/**
 * Initialize Postgres database subsystem.
 *
 * @param cls a configuration instance
 * @return NULL on error, otherwise a `struct TALER_EXCHANGEDB_Plugin`
 */
void *
libtaler_plugin_exchangedb_postgres_init (void *cls)
{
  struct GNUNET_CONFIGURATION_Handle *cfg = cls;
  struct PostgresClosure *pg;
  struct TALER_EXCHANGEDB_Plugin *plugin;
  const char *ec;

  pg = GNUNET_new (struct PostgresClosure);

  if (0 != pthread_key_create (&pg->db_conn_threadlocal,
                               &db_conn_destroy))
  {
    TALER_LOG_ERROR ("Cannnot create pthread key.\n");
    GNUNET_free (pg);
    return NULL;
  }
  ec = getenv ("TALER_EXCHANGEDB_POSTGRES_CONFIG");
  if (NULL != ec)
  {
    pg->connection_cfg_str = GNUNET_strdup (ec);
  }
  else
  {
    if (GNUNET_OK !=
        GNUNET_CONFIGURATION_get_value_string (cfg,
                                               "exchangedb-postgres",
                                               "db_conn_str",
                                               &pg->connection_cfg_str))
    {
      GNUNET_log_config_missing (GNUNET_ERROR_TYPE_ERROR,
                                 "exchangedb-postgres",
                                 "db_conn_str");
      GNUNET_free (pg);
      return NULL;
    }
  }
  plugin = GNUNET_new (struct TALER_EXCHANGEDB_Plugin);
  plugin->cls = pg;
  plugin->get_session = &postgres_get_session;
  plugin->drop_tables = &postgres_drop_tables;
  plugin->create_tables = &postgres_create_tables;
  plugin->start = &postgres_start;
  plugin->commit = &postgres_commit;
  plugin->rollback = &postgres_rollback;
  plugin->insert_denomination_info = &postgres_insert_denomination_info;
  plugin->get_denomination_info = &postgres_get_denomination_info;
  plugin->reserve_get = &postgres_reserve_get;
  plugin->reserves_in_insert = &postgres_reserves_in_insert;
  plugin->get_withdraw_info = &postgres_get_withdraw_info;
  plugin->insert_withdraw_info = &postgres_insert_withdraw_info;
  plugin->get_reserve_history = &postgres_get_reserve_history;
  plugin->free_reserve_history = &common_free_reserve_history;
  plugin->have_deposit = &postgres_have_deposit;
  plugin->mark_deposit_tiny = &postgres_mark_deposit_tiny;
  plugin->test_deposit_done = &postgres_test_deposit_done;
  plugin->mark_deposit_done = &postgres_mark_deposit_done;
  plugin->get_ready_deposit = &postgres_get_ready_deposit;
  plugin->iterate_matching_deposits = &postgres_iterate_matching_deposits;
  plugin->insert_deposit = &postgres_insert_deposit;
  plugin->insert_refund = &postgres_insert_refund;
  plugin->get_refresh_session = &postgres_get_refresh_session;
  plugin->create_refresh_session = &postgres_create_refresh_session;
  plugin->insert_refresh_order = &postgres_insert_refresh_order;
  plugin->get_refresh_order = &postgres_get_refresh_order;
  plugin->insert_refresh_commit_coins = &postgres_insert_refresh_commit_coins;
  plugin->get_refresh_commit_coins = &postgres_get_refresh_commit_coins;
  plugin->free_refresh_commit_coins = &postgres_free_refresh_commit_coins;
  plugin->insert_refresh_transfer_public_key = &postgres_insert_refresh_transfer_public_key;
  plugin->get_refresh_transfer_public_key = &postgres_get_refresh_transfer_public_key;
  plugin->insert_refresh_out = &postgres_insert_refresh_out;
  plugin->get_link_data_list = &postgres_get_link_data_list;
  plugin->free_link_data_list = &common_free_link_data_list;
  plugin->get_transfer = &postgres_get_transfer;
  plugin->get_coin_transactions = &postgres_get_coin_transactions;
  plugin->free_coin_transaction_list = &common_free_coin_transaction_list;
  plugin->lookup_wire_transfer = &postgres_lookup_wire_transfer;
  plugin->wire_lookup_deposit_wtid = &postgres_wire_lookup_deposit_wtid;
  plugin->insert_aggregation_tracking = &postgres_insert_aggregation_tracking;
  plugin->wire_prepare_data_insert = &postgres_wire_prepare_data_insert;
  plugin->wire_prepare_data_mark_finished = &postgres_wire_prepare_data_mark_finished;
  plugin->wire_prepare_data_get = &postgres_wire_prepare_data_get;
  plugin->gc = &postgres_gc;
  plugin->select_deposits_above_serial_id = &postgres_select_deposits_above_serial_id;
  plugin->select_refreshs_above_serial_id = &postgres_select_refreshs_above_serial_id;
  plugin->select_refunds_above_serial_id = &postgres_select_refunds_above_serial_id;
  plugin->select_reserves_in_above_serial_id = &postgres_select_reserves_in_above_serial_id;
  plugin->select_reserves_out_above_serial_id = &postgres_select_reserves_out_above_serial_id;
  plugin->select_prepare_above_serial_id = &postgres_select_prepare_above_serial_id;
  return plugin;
}


/**
 * Shutdown Postgres database subsystem.
 *
 * @param cls a `struct TALER_EXCHANGEDB_Plugin`
 * @return NULL (always)
 */
void *
libtaler_plugin_exchangedb_postgres_done (void *cls)
{
  struct TALER_EXCHANGEDB_Plugin *plugin = cls;
  struct PostgresClosure *pg = plugin->cls;

  GNUNET_free (pg->connection_cfg_str);
  GNUNET_free (pg);
  GNUNET_free (plugin);
  return NULL;
}

/* end of plugin_exchangedb_postgres.c */