0002-refresh.sql (7642B)
1 -- 2 -- This file is part of TALER 3 -- Copyright (C) 2025 Taler Systems SA 4 -- 5 -- TALER is free software; you can redistribute it and/or modify it under the 6 -- terms of the GNU General Public License as published by the Free Software 7 -- Foundation; either version 3, or (at your option) any later version. 8 -- 9 -- TALER is distributed in the hope that it will be useful, but WITHOUT ANY 10 -- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR 11 -- A PARTICULAR PURPOSE. See the GNU General Public License for more details. 12 -- 13 -- You should have received a copy of the GNU General Public License along with 14 -- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/> 15 -- 16 -- @author Özgür Kesim 17 18 CREATE FUNCTION create_table_refresh( 19 IN partition_suffix TEXT DEFAULT NULL 20 ) 21 RETURNS VOID 22 LANGUAGE plpgsql 23 AS $$ 24 DECLARE 25 table_name TEXT DEFAULT 'refresh'; 26 BEGIN 27 PERFORM create_partitioned_table( 28 'CREATE TABLE %I' 29 '(refresh_id BIGINT GENERATED BY DEFAULT AS IDENTITY' 30 ',rc BYTEA PRIMARY KEY CONSTRAINT rc_length CHECK(LENGTH(rc)=64)' 31 ',execution_date INT8 NOT NULL' 32 ',amount_with_fee taler_amount NOT NULL' 33 ',old_coin_pub BYTEA NOT NULL' 34 ',old_coin_sig BYTEA NOT NULL CHECK(LENGTH(old_coin_sig)=64)' 35 ',refresh_seed BYTEA NOT NULL' 36 ',noreveal_index INT4 NOT NULL CONSTRAINT noreveal_index_positive CHECK(noreveal_index>=0)' 37 ',planchets_h BYTEA CONSTRAINT planchets_h_length CHECK(LENGTH(planchets_h)=64)' 38 ',selected_h BYTEA CONSTRAINT selected_h_length CHECK(LENGTH(selected_h)=64)' 39 ',blinding_seed BYTEA CONSTRAINT blinding_seed_length CHECK(LENGTH(blinding_seed)>=32)' 40 ',cs_r_values BYTEA[]' 41 ',cs_r_choices INT8' 42 ',denom_serials INT8[] NOT NULL CONSTRAINT denom_serials_array_length CHECK(cardinality(denom_serials)=cardinality(denom_sigs))' 43 ',denom_sigs BYTEA[] NOT NULL CONSTRAINT denom_sigs_array_length CHECK(cardinality(denom_sigs)=cardinality(denom_serials))' 44 ') %s ;' 45 ,table_name 46 ,'PARTITION BY HASH (rc)' 47 ,partition_suffix 48 ); 49 PERFORM comment_partitioned_table( 50 'The data provided by the client for the melting operation of an old coin and he choices made by the exchange ' 51 ' with respect to the cut-and-choose protocol: nonreveal_index and the corresponding chosen' 52 ' blinded coin envelope along with the denomination signatures at the moment of the melting.' 53 ,table_name 54 ,partition_suffix 55 ); 56 PERFORM comment_partitioned_column( 57 'The hash over the refresh request, which serves as the primary key' 58 ' for the lookup during the reveal phase.' 59 ,'rc' 60 ,table_name 61 ,partition_suffix 62 ); 63 PERFORM comment_partitioned_column( 64 'The publice nonce from which all other nonces for all n*kappa coin candidates are derived for which' 65 ' the old coin proves ownership via signatures' 66 ,'refresh_seed' 67 ,table_name 68 ,partition_suffix 69 ); 70 PERFORM comment_partitioned_column( 71 'The gamma value chosen by the exchange in the cut-and-choose protocol' 72 ,'noreveal_index' 73 ,table_name 74 ,partition_suffix 75 ); 76 PERFORM comment_partitioned_column( 77 'The date of execution of the melting operation, according to the exchange' 78 ,'execution_date' 79 ,table_name 80 ,partition_suffix 81 ); 82 PERFORM comment_partitioned_column( 83 'Reference to the public key of the old coin which is melted' 84 ,'old_coin_pub' 85 ,table_name 86 ,partition_suffix 87 ); 88 PERFORM comment_partitioned_column( 89 'Signature of the old coin''s private key over the melt request' 90 ,'old_coin_sig' 91 ,table_name 92 ,partition_suffix 93 ); 94 PERFORM comment_partitioned_column( 95 'Array of references to the denominations' 96 ,'denom_serials' 97 ,table_name 98 ,partition_suffix 99 ); 100 PERFORM comment_partitioned_column( 101 'The master seed for the blinding nonces, needed for blind CS signatures; maybe NULL' 102 ,'blinding_seed' 103 ,table_name 104 ,partition_suffix 105 ); 106 PERFORM comment_partitioned_column( 107 'The public pairs of R-values provided by the exchange for the CS denominations; might be NULL' 108 ,'cs_r_values' 109 ,table_name 110 ,partition_suffix 111 ); 112 PERFORM comment_partitioned_column( 113 'The bitvector of choices made by the exchange for each of the pairs in cs_r_values; maybe NULL.' 114 'The vector is stored in network byte order and the lowest bit corresponds to the 0-th entry in cs_r_values (pair)' 115 ,'cs_r_choices' 116 ,table_name 117 ,partition_suffix 118 ); 119 PERFORM comment_partitioned_column( 120 'The hash over all kappa*n blinded planchets that were provided by the client' 121 ,'planchets_h' 122 ,table_name 123 ,partition_suffix 124 ); 125 PERFORM comment_partitioned_column( 126 'The hash over the n blinded planchets that were selected by the exchange.' 127 ,'selected_h' 128 ,table_name 129 ,partition_suffix 130 ); 131 PERFORM comment_partitioned_column( 132 'Array of signatures, one for each blinded envelope' 133 ,'denom_sigs' 134 ,table_name 135 ,partition_suffix 136 ); 137 END 138 $$; 139 140 141 CREATE FUNCTION constrain_table_refresh( 142 IN partition_suffix TEXT 143 ) 144 RETURNS void 145 LANGUAGE plpgsql 146 AS $$ 147 DECLARE 148 table_name TEXT DEFAULT 'refresh'; 149 BEGIN 150 table_name = concat_ws('_', table_name, partition_suffix); 151 -- Note: index spans partitions, may need to be materialized. 152 EXECUTE FORMAT ( 153 'CREATE INDEX ' || table_name || '_by_old_coin_pub_index ' 154 'ON ' || table_name || ' ' 155 '(old_coin_pub);' 156 ); 157 EXECUTE FORMAT ( 158 'ALTER TABLE ' || table_name || 159 ' ADD CONSTRAINT ' || table_name || '_refresh_id_key' 160 ' UNIQUE (refresh_id);' 161 ); 162 END 163 $$; 164 165 166 CREATE FUNCTION foreign_table_refresh() 167 RETURNS void 168 LANGUAGE plpgsql 169 AS $$ 170 DECLARE 171 table_name TEXT DEFAULT 'refresh'; 172 BEGIN 173 EXECUTE FORMAT ( 174 'ALTER TABLE ' || table_name || 175 ' ADD CONSTRAINT ' || table_name || '_foreign_coin_pub' 176 ' FOREIGN KEY (old_coin_pub) ' 177 ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE' 178 ); 179 END 180 $$; 181 182 183 -- Trigger to update the reserve_history table 184 CREATE FUNCTION refresh_insert_trigger() 185 RETURNS trigger 186 LANGUAGE plpgsql 187 AS $$ 188 BEGIN 189 INSERT INTO coin_history 190 (coin_pub 191 ,table_name 192 ,serial_id) 193 VALUES 194 (NEW.old_coin_pub 195 ,'refresh' 196 ,NEW.refresh_id); 197 RETURN NEW; 198 END $$; 199 COMMENT ON FUNCTION refresh_insert_trigger() 200 IS 'Keep track of a particular refresh in the coin_history table.'; 201 202 -- Trigger to update the unique_refresh_blinding_seed table 203 CREATE FUNCTION refresh_delete_trigger() 204 RETURNS trigger 205 LANGUAGE plpgsql 206 AS $$ 207 BEGIN 208 DELETE FROM unique_refresh_blinding_seed 209 WHERE blinding_seed = OLD.blinding_seed; 210 RETURN OLD; 211 END $$; 212 COMMENT ON FUNCTION refresh_delete_trigger() 213 IS 'Delete blinding_seed from unique_refresh_blinding_seed table.'; 214 215 -- Put the triggers into the master table 216 CREATE FUNCTION master_table_refresh() 217 RETURNS void 218 LANGUAGE plpgsql 219 AS $$ 220 BEGIN 221 CREATE TRIGGER refresh_on_insert 222 AFTER INSERT 223 ON refresh 224 FOR EACH ROW EXECUTE FUNCTION refresh_insert_trigger(); 225 226 CREATE TRIGGER refresh_on_delete 227 AFTER DELETE 228 ON refresh 229 FOR EACH ROW EXECUTE FUNCTION refresh_delete_trigger(); 230 END $$; 231 COMMENT ON FUNCTION master_table_refresh() 232 IS 'Setup triggers to replicate refresh into coin_history and delete blinding_seed from unique_refresh_blinding_seed.'; 233 234 235 INSERT INTO exchange_tables 236 (name 237 ,version 238 ,action 239 ,partitioned 240 ,by_range) 241 VALUES 242 ('refresh', 'exchange-0002', 'create', TRUE ,FALSE), 243 ('refresh', 'exchange-0002', 'constrain',TRUE ,FALSE), 244 ('refresh', 'exchange-0002', 'foreign', TRUE ,FALSE), 245 ('refresh', 'exchange-0002', 'master', TRUE ,FALSE); 246