-- -- This file is part of TALER -- Copyright (C) 2014--2022 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_purse_deposits( IN partition_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ DECLARE table_name VARCHAR 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_val INT8 NOT NULL' ',amount_with_fee_frac INT4 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_val' ,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 VARCHAR ) RETURNS VOID LANGUAGE plpgsql AS $$ DECLARE table_name VARCHAR DEFAULT 'purse_deposits'; BEGIN table_name = concat_ws('_', table_name, partition_suffix); -- FIXME: change to materialized index by coin_pub! EXECUTE FORMAT ( 'CREATE INDEX ' || table_name || '_by_coin_pub' ' ON ' || table_name || ' (coin_pub);' ); 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 VARCHAR 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 $$; 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);