summaryrefslogtreecommitdiff
path: root/src/exchangedb/0002-batch_deposits.sql
blob: 71a4b420507b9679ac23d8bbb1c125494f5f9adb (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
--
-- This file is part of TALER
-- Copyright (C) 2014--2023 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/>
--

CREATE FUNCTION create_table_batch_deposits(
  IN partition_suffix TEXT DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT DEFAULT 'batch_deposits';
BEGIN
  PERFORM create_partitioned_table(
    'CREATE TABLE %I'
      '(batch_deposit_serial_id INT8 GENERATED BY DEFAULT AS IDENTITY'
      ',shard INT8 NOT NULL'
      ',merchant_pub BYTEA NOT NULL CHECK (LENGTH(merchant_pub)=32)'
      ',wallet_timestamp INT8 NOT NULL'
      ',exchange_timestamp INT8 NOT NULL'
      ',refund_deadline INT8 NOT NULL'
      ',wire_deadline INT8 NOT NULL'
      ',h_contract_terms BYTEA NOT NULL CHECK (LENGTH(h_contract_terms)=64)'
      ',wallet_data_hash BYTEA CHECK (LENGTH(wallet_data_hash)=64) DEFAULT NULL'
      ',wire_salt BYTEA NOT NULL CHECK (LENGTH(wire_salt)=16)'
      ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
      ',policy_details_serial_id INT8'
      ',policy_blocked BOOLEAN NOT NULL DEFAULT FALSE'
      ',done BOOLEAN NOT NULL DEFAULT FALSE'
    ') %s ;'
    ,table_name
    ,'PARTITION BY HASH (shard)'
    ,partition_suffix
  );
  PERFORM comment_partitioned_table(
    'Information about the contracts for which we have received (batch) deposits.'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'Used for load sharding in the materialized indices. Should be set based on merchant_pub. 64-bit value because we need an *unsigned* 32-bit value.'
    ,'shard'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'Unsalted hash of the target bank account; also used to lookup the KYC status'
    ,'wire_target_h_payto'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'hash over data provided by the wallet upon payment to select a more specific contract'
    ,'wallet_data_hash'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'Salt used when hashing the payto://-URI to get the h_wire that was used by the coin deposit signatures; not used to calculate wire_target_h_payto (as that one is unsalted)'
    ,'wire_salt'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'Set to TRUE once we have included this (batch) deposit (and all associated coins) in some aggregate wire transfer to the merchant'
    ,'done'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'True if the aggregation of the (batch) deposit is currently blocked by some policy extension mechanism. Used to filter out deposits that must not be processed by the canonical deposit logic.'
    ,'policy_blocked'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'References policy extensions table, NULL if extensions are not used'
    ,'policy_details_serial_id'
    ,table_name
    ,partition_suffix
  );
END
$$;


CREATE FUNCTION constrain_table_batch_deposits(
  IN partition_suffix TEXT
)
RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT DEFAULT 'batch_deposits';
BEGIN
  table_name = concat_ws('_', table_name, partition_suffix);
  EXECUTE FORMAT (
    'ALTER TABLE ' || table_name ||
    ' ADD CONSTRAINT ' || table_name || '_batch_deposit_serial_id_pkey'
    ' PRIMARY KEY (batch_deposit_serial_id) '
    ',ADD CONSTRAINT ' || table_name || '_merchant_pub_h_contract_terms'
    ' UNIQUE (shard, merchant_pub, h_contract_terms)'
  );
  EXECUTE FORMAT (
    'CREATE INDEX ' || table_name || '_by_ready '
    'ON ' || table_name || ' '
    '(shard ASC'
    ',wire_deadline ASC'
    ') WHERE NOT (done OR policy_blocked);'
  );
  EXECUTE FORMAT (
    'CREATE INDEX ' || table_name || '_for_matching '
    'ON ' || table_name || ' '
    '(shard ASC'
    ',refund_deadline ASC'
    ',wire_target_h_payto'
    ') WHERE NOT (done OR policy_blocked);'
  );
END
$$;

CREATE OR REPLACE FUNCTION foreign_table_batch_deposits()
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT DEFAULT 'batch_deposits';
BEGIN
  EXECUTE FORMAT (
    'ALTER TABLE ' || table_name ||
    ' ADD CONSTRAINT ' || table_name || '_foreign_policy_details'
    ' FOREIGN KEY (policy_details_serial_id) '
    ' REFERENCES policy_details (policy_details_serial_id) ON DELETE RESTRICT'
  );
END
$$;


INSERT INTO exchange_tables
    (name
    ,version
    ,action
    ,partitioned
    ,by_range)
  VALUES
    ('batch_deposits'
    ,'exchange-0002'
    ,'create'
    ,TRUE
    ,FALSE),
    ('batch_deposits'
    ,'exchange-0002'
    ,'constrain'
    ,TRUE
    ,FALSE),
    ('batch_deposits'
    ,'exchange-0002'
    ,'foreign'
    ,TRUE
    ,FALSE)
    ;