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
|
--
-- This file is part of TALER
-- Copyright (C) 2020 Taler Systems SA
--
-- TALER is free software; you can redistribute it and/or modify it under the
-- terms of the GNU General Public License as published by the Free Software
-- Foundation; either version 3, or (at your option) any later version.
--
-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR
-- A PARTICULAR PURPOSE. See the GNU General Public License for more details.
--
-- You should have received a copy of the GNU General Public License along with
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
--
-- Everything in one big transaction
BEGIN;
-- Check patch versioning is in place.
SELECT _v.register_patch('exchange-0002', NULL, NULL);
-- Need 'failed' bit to prevent hanging transfer tool in case
-- bank API fails.
ALTER TABLE prewire
ADD failed BOOLEAN NOT NULL DEFAULT false;
COMMENT ON COLUMN prewire.failed
IS 'set to TRUE if the bank responded with a non-transient failure to our transfer request';
COMMENT ON COLUMN prewire.finished
IS 'set to TRUE once bank confirmed receiving the wire transfer request';
COMMENT ON COLUMN prewire.buf
IS 'serialized data to send to the bank to execute the wire transfer';
-- change comment, existing index is still useful, but only for gc_prewire.
COMMENT ON INDEX prepare_iteration_index
IS 'for gc_prewire';
-- need a new index for updated wire_prepare_data_get statement:
CREATE INDEX IF NOT EXISTS prepare_get_index
ON prewire
(failed,finished);
COMMENT ON INDEX prepare_get_index
IS 'for wire_prepare_data_get';
-- need serial IDs on various tables for exchange-auditor replication
ALTER TABLE denominations
ADD COLUMN denominations_serial BIGSERIAL UNIQUE;
COMMENT ON COLUMN denominations.denominations_serial
IS 'needed for exchange-auditor replication logic';
ALTER TABLE refresh_revealed_coins
ADD COLUMN rrc_serial BIGSERIAL UNIQUE;
COMMENT ON COLUMN refresh_revealed_coins.rrc_serial
IS 'needed for exchange-auditor replication logic';
ALTER TABLE refresh_transfer_keys
ADD COLUMN rtc_serial BIGSERIAL UNIQUE;
COMMENT ON COLUMN refresh_transfer_keys.rtc_serial
IS 'needed for exchange-auditor replication logic';
ALTER TABLE wire_fee
ADD COLUMN wire_fee_serial BIGSERIAL UNIQUE;
COMMENT ON COLUMN wire_fee.wire_fee_serial
IS 'needed for exchange-auditor replication logic';
-- for the reserves, we add the new reserve_uuid, and also
-- change the foreign keys to use the new BIGSERIAL instead
-- of the public key to reference the entry
ALTER TABLE reserves
ADD COLUMN reserve_uuid BIGSERIAL UNIQUE;
ALTER TABLE reserves_in
ADD COLUMN reserve_uuid INT8 REFERENCES reserves (reserve_uuid) ON DELETE CASCADE;
UPDATE reserves_in
SET reserve_uuid=r.reserve_uuid
FROM reserves_in rin
INNER JOIN reserves r USING(reserve_pub);
ALTER TABLE reserves_in
ALTER COLUMN reserve_uuid SET NOT NULL;
ALTER TABLE reserves_in
DROP COLUMN reserve_pub;
ALTER TABLE reserves_out
ADD COLUMN reserve_uuid INT8 REFERENCES reserves (reserve_uuid) ON DELETE CASCADE;
UPDATE reserves_out
SET reserve_uuid=r.reserve_uuid
FROM reserves_out rout
INNER JOIN reserves r USING(reserve_pub);
ALTER TABLE reserves_out
ALTER COLUMN reserve_uuid SET NOT NULL;
ALTER TABLE reserves_out
DROP COLUMN reserve_pub;
ALTER TABLE reserves_close
ADD COLUMN reserve_uuid INT8 REFERENCES reserves (reserve_uuid) ON DELETE CASCADE;
UPDATE reserves_close
SET reserve_uuid=r.reserve_uuid
FROM reserves_close rclose
INNER JOIN reserves r USING(reserve_pub);
ALTER TABLE reserves_close
ALTER COLUMN reserve_uuid SET NOT NULL;
ALTER TABLE reserves_close
DROP COLUMN reserve_pub;
-- change all foreign keys using 'denom_pub_hash' to using 'denominations_serial' instead
ALTER TABLE reserves_out
ADD COLUMN denominations_serial INT8 REFERENCES denominations (denominations_serial) ON DELETE CASCADE;
UPDATE reserves_out
SET denominations_serial=d.denominations_serial
FROM reserves_out o
INNER JOIN denominations d USING(denom_pub_hash);
ALTER TABLE reserves_out
ALTER COLUMN denominations_serial SET NOT NULL;
ALTER TABLE reserves_out
DROP COLUMN denom_pub_hash;
ALTER TABLE known_coins
ADD COLUMN denominations_serial INT8 REFERENCES denominations (denominations_serial) ON DELETE CASCADE;
UPDATE known_coins
SET denominations_serial=d.denominations_serial
FROM known_coins o
INNER JOIN denominations d USING(denom_pub_hash);
ALTER TABLE known_coins
ALTER COLUMN denominations_serial SET NOT NULL;
ALTER TABLE known_coins
DROP COLUMN denom_pub_hash;
ALTER TABLE denomination_revocations
ADD COLUMN denominations_serial INT8 REFERENCES denominations (denominations_serial) ON DELETE CASCADE;
UPDATE denomination_revocations
SET denominations_serial=d.denominations_serial
FROM denomination_revocations o
INNER JOIN denominations d USING(denom_pub_hash);
ALTER TABLE denomination_revocations
ALTER COLUMN denominations_serial SET NOT NULL;
ALTER TABLE denomination_revocations
DROP COLUMN denom_pub_hash;
ALTER TABLE denomination_revocations
ADD CONSTRAINT denominations_serial_pk PRIMARY KEY (denominations_serial);
ALTER TABLE refresh_revealed_coins
ADD COLUMN denominations_serial INT8 REFERENCES denominations (denominations_serial) ON DELETE CASCADE;
UPDATE refresh_revealed_coins
SET denominations_serial=d.denominations_serial
FROM refresh_revealed_coins o
INNER JOIN denominations d USING(denom_pub_hash);
ALTER TABLE refresh_revealed_coins
ALTER COLUMN denominations_serial SET NOT NULL;
ALTER TABLE refresh_revealed_coins
DROP COLUMN denom_pub_hash;
-- Change all foreign keys involving 'coin_pub' to use known_coin_id instead.
ALTER TABLE recoup_refresh
ADD COLUMN known_coin_id INT8 REFERENCES known_coins (known_coin_id) ON DELETE CASCADE;
UPDATE recoup_refresh
SET known_coin_id=d.known_coin_id
FROM recoup_refresh o
INNER JOIN known_coins d USING(coin_pub);
ALTER TABLE recoup_refresh
ALTER COLUMN known_coin_id SET NOT NULL;
ALTER TABLE recoup_refresh
DROP COLUMN coin_pub;
ALTER TABLE recoup
ADD COLUMN known_coin_id INT8 REFERENCES known_coins (known_coin_id) ON DELETE CASCADE;
UPDATE recoup
SET known_coin_id=d.known_coin_id
FROM recoup o
INNER JOIN known_coins d USING(coin_pub);
ALTER TABLE recoup
ALTER COLUMN known_coin_id SET NOT NULL;
ALTER TABLE recoup
DROP COLUMN coin_pub;
ALTER TABLE refresh_commitments
ADD COLUMN old_known_coin_id INT8 REFERENCES known_coins (known_coin_id) ON DELETE CASCADE;
UPDATE refresh_commitments
SET old_known_coin_id=d.known_coin_id
FROM refresh_commitments o
INNER JOIN known_coins d ON(o.old_coin_pub=d.coin_pub);
ALTER TABLE refresh_commitments
ALTER COLUMN old_known_coin_id SET NOT NULL;
ALTER TABLE refresh_commitments
DROP COLUMN old_coin_pub;
ALTER TABLE deposits
ADD COLUMN known_coin_id INT8 REFERENCES known_coins (known_coin_id) ON DELETE CASCADE;
UPDATE deposits
SET known_coin_id=d.known_coin_id
FROM deposits o
INNER JOIN known_coins d USING(coin_pub);
ALTER TABLE deposits
ALTER COLUMN known_coin_id SET NOT NULL;
ALTER TABLE deposits
DROP COLUMN coin_pub;
ALTER TABLE refunds
ADD COLUMN known_coin_id INT8 REFERENCES known_coins (known_coin_id) ON DELETE CASCADE;
UPDATE refunds
SET known_coin_id=d.known_coin_id
FROM refunds o
INNER JOIN known_coins d USING(coin_pub);
ALTER TABLE refunds
ALTER COLUMN known_coin_id SET NOT NULL;
ALTER TABLE refunds
DROP COLUMN coin_pub;
-- Change 'h_blind_ev' in recoup table to 'reserve_out_serial_id'
ALTER TABLE recoup
ADD COLUMN reserve_out_serial_id INT8 REFERENCES reserves_out (reserve_out_serial_id) ON DELETE CASCADE;
UPDATE recoup
SET reserve_out_serial_id=d.reserve_out_serial_id
FROM recoup o
INNER JOIN reserves_out d USING(h_blind_ev);
ALTER TABLE recoup
ALTER COLUMN reserve_out_serial_id SET NOT NULL;
ALTER TABLE recoup
DROP COLUMN h_blind_ev;
COMMENT ON COLUMN recoup.reserve_out_serial_id
IS 'Identifies the h_blind_ev of the recouped coin.';
-- Change 'h_blind_ev' in recoup_refresh table to 'rrc_serial'
ALTER TABLE recoup_refresh
ADD COLUMN rrc_serial INT8 REFERENCES refresh_revealed_coins (rrc_serial) ON DELETE CASCADE;
UPDATE recoup_refresh
SET rrc_serial=d.rrc_serial
FROM recoup_refresh o
INNER JOIN refresh_revealed_coins d ON (d.h_coin_ev = o.h_blind_ev);
ALTER TABLE recoup_refresh
ALTER COLUMN rrc_serial SET NOT NULL;
ALTER TABLE recoup_refresh
DROP COLUMN h_blind_ev;
COMMENT ON COLUMN recoup_refresh.rrc_serial
IS 'Identifies the h_blind_ev of the recouped coin (as h_coin_ev).';
-- Create additional tables...
CREATE TABLE IF NOT EXISTS auditors
(auditor_uuid BIGSERIAL UNIQUE
,auditor_pub BYTEA PRIMARY KEY CHECK (LENGTH(auditor_pub)=32)
,auditor_name VARCHAR NOT NULL
,auditor_url VARCHAR NOT NULL
,is_active BOOLEAN NOT NULL
,last_change INT8 NOT NULL
);
COMMENT ON TABLE auditors
IS 'Table with auditors the exchange uses or has used in the past. Entries never expire as we need to remember the last_change column indefinitely.';
COMMENT ON COLUMN auditors.auditor_pub
IS 'Public key of the auditor.';
COMMENT ON COLUMN auditors.auditor_url
IS 'The base URL of the auditor.';
COMMENT ON COLUMN auditors.is_active
IS 'true if we are currently supporting the use of this auditor.';
COMMENT ON COLUMN auditors.last_change
IS 'Latest time when active status changed. Used to detect replays of old messages.';
CREATE TABLE IF NOT EXISTS auditor_denom_sigs
(auditor_denom_serial BIGSERIAL UNIQUE
,auditor_uuid INT8 NOT NULL REFERENCES auditors (auditor_uuid) ON DELETE CASCADE
,denominations_serial INT8 NOT NULL REFERENCES denominations (denominations_serial) ON DELETE CASCADE
,auditor_sig BYTEA CHECK (LENGTH(auditor_sig)=64)
,PRIMARY KEY (denominations_serial, auditor_uuid)
);
COMMENT ON TABLE auditor_denom_sigs
IS 'Table with auditor signatures on exchange denomination keys.';
COMMENT ON COLUMN auditor_denom_sigs.auditor_uuid
IS 'Identifies the auditor.';
COMMENT ON COLUMN auditor_denom_sigs.denominations_serial
IS 'Denomination the signature is for.';
COMMENT ON COLUMN auditor_denom_sigs.auditor_sig
IS 'Signature of the auditor, of purpose TALER_SIGNATURE_AUDITOR_EXCHANGE_KEYS.';
CREATE TABLE IF NOT EXISTS exchange_sign_keys
(esk_serial BIGSERIAL UNIQUE
,exchange_pub BYTEA PRIMARY KEY CHECK (LENGTH(exchange_pub)=32)
,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
,valid_from INT8 NOT NULL
,expire_sign INT8 NOT NULL
,expire_legal INT8 NOT NULL
);
COMMENT ON TABLE exchange_sign_keys
IS 'Table with master public key signatures on exchange online signing keys.';
COMMENT ON COLUMN exchange_sign_keys.exchange_pub
IS 'Public online signing key of the exchange.';
COMMENT ON COLUMN exchange_sign_keys.master_sig
IS 'Signature affirming the validity of the signing key of purpose TALER_SIGNATURE_MASTER_SIGNING_KEY_VALIDITY.';
COMMENT ON COLUMN exchange_sign_keys.valid_from
IS 'Time when this online signing key will first be used to sign messages.';
COMMENT ON COLUMN exchange_sign_keys.expire_sign
IS 'Time when this online signing key will no longer be used to sign.';
COMMENT ON COLUMN exchange_sign_keys.expire_legal
IS 'Time when this online signing key legally expires.';
CREATE TABLE IF NOT EXISTS wire_accounts
(payto_uri VARCHAR PRIMARY KEY
,master_sig BYTEA CHECK (LENGTH(master_sig)=64)
,is_active BOOLEAN NOT NULL
,last_change INT8 NOT NULL
);
COMMENT ON TABLE wire_accounts
IS 'Table with current and historic bank accounts of the exchange. Entries never expire as we need to remember the last_change column indefinitely.';
COMMENT ON COLUMN wire_accounts.payto_uri
IS 'payto URI (RFC 8905) with the bank account of the exchange.';
COMMENT ON COLUMN wire_accounts.master_sig
IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS';
COMMENT ON COLUMN wire_accounts.is_active
IS 'true if we are currently supporting the use of this account.';
COMMENT ON COLUMN wire_accounts.last_change
IS 'Latest time when active status changed. Used to detect replays of old messages.';
-- "wire_accounts" has no BIGSERIAL because it is a 'mutable' table
-- and is of no concern to the auditor
CREATE TABLE IF NOT EXISTS signkey_revocations
(signkey_revocations_serial_id BIGSERIAL UNIQUE
,esk_serial INT8 PRIMARY KEY REFERENCES exchange_sign_keys (esk_serial) ON DELETE CASCADE
,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
);
COMMENT ON TABLE signkey_revocations
IS 'remembering which online signing keys have been revoked';
-- Complete transaction
COMMIT;
|