summaryrefslogtreecommitdiff
path: root/src/exchangedb/0002-reserves_out.sql
blob: f0965d222b0e23a987a0d3f1ef1be3af0ab2c034 (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
--
-- 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_reserves_out(
  IN partition_suffix TEXT DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT default 'reserves_out';
BEGIN
  PERFORM create_partitioned_table(
    'CREATE TABLE %I'
      '(reserve_out_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
      ',h_blind_ev BYTEA CHECK (LENGTH(h_blind_ev)=64) UNIQUE'
      ',denominations_serial INT8 NOT NULL'
      ',denom_sig BYTEA NOT NULL'
      ',reserve_uuid INT8 NOT NULL'
      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
      ',execution_date INT8 NOT NULL'
      ',amount_with_fee taler_amount NOT NULL'
    ') %s ;'
    ,'reserves_out'
    ,'PARTITION BY HASH (h_blind_ev)'
    ,partition_suffix
  );
  PERFORM comment_partitioned_table (
     'Withdraw operations performed on reserves.'
    ,'reserves_out'
    ,partition_suffix
  );
  PERFORM comment_partitioned_column (
     'Hash of the blinded coin, used as primary key here so that broken clients that use a non-random coin or blinding factor fail to withdraw (otherwise they would fail on deposit when the coin is not unique there).'
    ,'h_blind_ev'
    ,'reserves_out'
    ,partition_suffix
  );
  PERFORM comment_partitioned_column (
     'We do not CASCADE ON DELETE for the foreign constrain here, as we may keep the denomination data alive'
    ,'denominations_serial'
    ,'reserves_out'
    ,partition_suffix
  );
END
$$;


CREATE FUNCTION constrain_table_reserves_out(
  IN partition_suffix TEXT
)
RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT default 'reserves_out';
BEGIN
  table_name = concat_ws('_', table_name, partition_suffix);
  EXECUTE FORMAT (
    'ALTER TABLE ' || table_name ||
    ' ADD CONSTRAINT ' || table_name || '_reserve_out_serial_id_key'
    ' UNIQUE (reserve_out_serial_id)'
  );
  EXECUTE FORMAT (
    'CREATE INDEX ' || table_name || '_by_reserve_uuid_and_execution_date_index '
    'ON ' || table_name || ' '
    '(reserve_uuid, execution_date);'
  );
  EXECUTE FORMAT (
    'COMMENT ON INDEX ' || table_name || '_by_reserve_uuid_and_execution_date_index '
    'IS ' || quote_literal('for do_gc, do_recoup_by_reserve, select_kyc_relevant_withdraw_events and a few others') || ';'
  );
END
$$;


CREATE FUNCTION foreign_table_reserves_out()
RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT default 'reserves_out';
BEGIN
  EXECUTE FORMAT (
    'ALTER TABLE ' || table_name ||
    ' ADD CONSTRAINT ' || table_name || '_foreign_denom'
    ' FOREIGN KEY (denominations_serial)'
    ' REFERENCES denominations (denominations_serial)'
    ',ADD CONSTRAINT ' || table_name || '_foreign_reserve '
    ' FOREIGN KEY (reserve_uuid)'
    ' REFERENCES reserves (reserve_uuid) ON DELETE CASCADE'
  );
END
$$;


CREATE FUNCTION reserves_out_insert_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  INSERT INTO reserve_history
    (reserve_pub
    ,table_name
    ,serial_id)
  SELECT
     res.reserve_pub
    ,'reserves_out'
    ,NEW.reserve_out_serial_id
  FROM
    reserves res
  WHERE res.reserve_uuid = NEW.reserve_uuid;
  RETURN NEW;
END $$;
COMMENT ON FUNCTION reserves_out_insert_trigger()
  IS 'Replicate reserve_out inserts into reserve_history table.';


CREATE FUNCTION master_table_reserves_out()
RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
  CREATE TRIGGER reserves_out_on_insert
  AFTER INSERT
   ON reserves_out
   FOR EACH ROW EXECUTE FUNCTION reserves_out_insert_trigger();
END $$;
COMMENT ON FUNCTION master_table_reserves_out()
  IS 'Setup triggers to replicate reserve_out into reserve_history.';



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