summaryrefslogtreecommitdiff
path: root/src/exchangedb/0002-purse_deposits.sql
blob: 6a07c4b62f946f14c310acd1b0c4982703dc7e19 (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
--
-- 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_purse_deposits(
  IN partition_suffix TEXT DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT DEFAULT 'purse_deposits';
BEGIN
  PERFORM create_partitioned_table(
    'CREATE TABLE %I '
      '(purse_deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
      ',partner_serial_id INT8'
      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
      ',coin_pub BYTEA NOT NULL'
      ',amount_with_fee taler_amount NOT NULL'
      ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)'
      ',PRIMARY KEY (purse_pub,coin_pub)'
    ') %s ;'
    ,table_name
    ,'PARTITION BY HASH (purse_pub)'
    ,partition_suffix
  );
  PERFORM comment_partitioned_table(
     'Requests depositing coins into a purse'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'identifies the partner exchange, NULL in case the target purse lives at this exchange'
    ,'partner_serial_id'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'Public key of the purse'
    ,'purse_pub'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'Public key of the coin being deposited'
    ,'coin_pub'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'Total amount being deposited'
    ,'amount_with_fee'
    ,table_name
    ,partition_suffix
  );
  PERFORM comment_partitioned_column(
     'Signature of the coin affirming the deposit into the purse, of type TALER_SIGNATURE_PURSE_DEPOSIT'
    ,'coin_sig'
    ,table_name
    ,partition_suffix
  );
END
$$;


CREATE FUNCTION constrain_table_purse_deposits(
  IN partition_suffix TEXT
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT DEFAULT 'purse_deposits';
BEGIN
  table_name = concat_ws('_', table_name, partition_suffix);

  EXECUTE FORMAT (
    'ALTER TABLE ' || table_name ||
    ' ADD CONSTRAINT ' || table_name || '_purse_deposit_serial_id_key'
    ' UNIQUE (purse_deposit_serial_id) '
  );
END
$$;


CREATE FUNCTION foreign_table_purse_deposits()
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
  table_name TEXT DEFAULT 'purse_deposits';
BEGIN
  EXECUTE FORMAT (
    'ALTER TABLE ' || table_name ||
    ' ADD CONSTRAINT ' || table_name || '_foreign_partner'
    ' FOREIGN KEY (partner_serial_id) '
    ' REFERENCES partners(partner_serial_id) ON DELETE CASCADE'
    ',ADD CONSTRAINT ' || table_name || '_foreign_coin_pub'
    ' FOREIGN KEY (coin_pub) '
    ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE'
  );
END
$$;


CREATE OR REPLACE FUNCTION purse_deposits_insert_trigger()
  RETURNS trigger
  LANGUAGE plpgsql
  AS $$
BEGIN
  INSERT INTO exchange.coin_history
    (coin_pub
    ,table_name
    ,serial_id)
 VALUES
    (NEW.coin_pub
    ,'purse_deposits'
    ,NEW.purse_deposit_serial_id);
  RETURN NEW;
END $$;
COMMENT ON FUNCTION purse_deposits_insert_trigger()
  IS 'Automatically generate coin history entry.';


CREATE FUNCTION master_table_purse_deposits()
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
  CREATE TRIGGER purse_deposits_on_insert
    AFTER INSERT
     ON purse_deposits
     FOR EACH ROW EXECUTE FUNCTION purse_deposits_insert_trigger();
END $$;


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