-- -- 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 -- CREATE FUNCTION create_table_refunds( IN partition_suffix TEXT DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ DECLARE table_name TEXT DEFAULT 'refunds'; BEGIN PERFORM create_partitioned_table( 'CREATE TABLE %I' '(refund_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)' ',batch_deposit_serial_id INT8 NOT NULL' ',merchant_sig BYTEA NOT NULL CHECK(LENGTH(merchant_sig)=64)' ',rtransaction_id INT8 NOT NULL' ',amount_with_fee taler_amount NOT NULL' ') %s ;' ,table_name ,'PARTITION BY HASH (coin_pub)' ,partition_suffix ); PERFORM comment_partitioned_table( 'Data on coins that were refunded. Technically, refunds always apply against specific deposit operations involving a coin. The combination of coin_pub, merchant_pub, h_contract_terms and rtransaction_id MUST be unique, and we usually select by coin_pub so that one goes first.' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'Identifies ONLY the merchant_pub, h_contract_terms and coin_pub. Multiple deposits may match a refund, this only identifies one of them.' ,'batch_deposit_serial_id' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'used by the merchant to make refunds unique in case the same coin for the same deposit gets a subsequent (higher) refund' ,'rtransaction_id' ,table_name ,partition_suffix ); END $$; CREATE FUNCTION constrain_table_refunds ( IN partition_suffix TEXT DEFAULT NULL ) RETURNS void LANGUAGE plpgsql AS $$ DECLARE table_name TEXT DEFAULT 'refunds'; BEGIN table_name = concat_ws('_', table_name, partition_suffix); EXECUTE FORMAT ( 'CREATE INDEX ' || table_name || '_by_coin_pub_index ' 'ON ' || table_name || ' ' '(coin_pub);' ); EXECUTE FORMAT ( 'ALTER TABLE ' || table_name || ' ADD CONSTRAINT ' || table_name || '_refund_serial_id_key' ' UNIQUE (refund_serial_id) ' ',ADD PRIMARY KEY (batch_deposit_serial_id, rtransaction_id) ' ); END $$; CREATE FUNCTION foreign_table_refunds () RETURNS void LANGUAGE plpgsql AS $$ DECLARE table_name TEXT DEFAULT 'refunds'; BEGIN EXECUTE FORMAT ( 'ALTER TABLE ' || table_name || ' ADD CONSTRAINT ' || table_name || '_foreign_coin_pub' ' FOREIGN KEY (coin_pub) ' ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE' ',ADD CONSTRAINT ' || table_name || '_foreign_deposit' ' FOREIGN KEY (batch_deposit_serial_id) ' ' REFERENCES batch_deposits (batch_deposit_serial_id) ON DELETE CASCADE' ); END $$; CREATE OR REPLACE FUNCTION refunds_insert_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN INSERT INTO exchange.coin_history (coin_pub ,table_name ,serial_id) VALUES (NEW.coin_pub ,'refunds' ,NEW.refund_serial_id); RETURN NEW; END $$; COMMENT ON FUNCTION refunds_insert_trigger() IS 'Automatically generate coin history entry.'; CREATE FUNCTION master_table_refunds() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TRIGGER refunds_on_insert AFTER INSERT ON refunds FOR EACH ROW EXECUTE FUNCTION refunds_insert_trigger(); END $$; INSERT INTO exchange_tables (name ,version ,action ,partitioned ,by_range) VALUES ('refunds' ,'exchange-0002' ,'create' ,TRUE ,FALSE), ('refunds' ,'exchange-0002' ,'constrain' ,TRUE ,FALSE), ('refunds' ,'exchange-0002' ,'foreign' ,TRUE ,FALSE), ('refunds' ,'exchange-0002' ,'master' ,TRUE ,FALSE);