-- -- 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_coin_history ( IN partition_suffix TEXT DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ DECLARE table_name TEXT DEFAULT 'coin_history'; BEGIN PERFORM create_partitioned_table( 'CREATE TABLE %I' '(coin_history_serial_id INT8 GENERATED BY DEFAULT AS IDENTITY' ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)' ',table_name TEXT NOT NULL' ',serial_id INT8 NOT NULL' ') %s ;' ,table_name ,'PARTITION BY HASH (coin_pub)' ,partition_suffix ); PERFORM comment_partitioned_table( 'Links to tables with entries that affected the transaction history of a coin.' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'For which coin is this a history entry' ,'coin_pub' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'In which table is the history entry' ,'table_name' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'Which is the generated serial ID of the entry in the table' ,'serial_id' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'Monotonic counter, used to generate Etags for caching' ,'coin_history_serial_id' ,table_name ,partition_suffix ); END $$; CREATE FUNCTION constrain_table_coin_history( IN partition_suffix TEXT ) RETURNS void LANGUAGE plpgsql AS $$ DECLARE table_name TEXT DEFAULT 'coin_history'; BEGIN table_name = concat_ws('_', table_name, partition_suffix); EXECUTE FORMAT ( 'ALTER TABLE ' || table_name || ' ADD CONSTRAINT ' || table_name || '_coin_history_serial_id_pkey' ' PRIMARY KEY (coin_history_serial_id) ' ',ADD CONSTRAINT ' || table_name || '_coin_entry_key' ' UNIQUE (coin_pub, table_name, serial_id)' ); EXECUTE FORMAT ( 'CREATE INDEX ' || table_name || '_coin_by_time' ' ON ' || table_name || ' ' '(coin_pub' ',coin_history_serial_id DESC' ');' ); END $$; CREATE FUNCTION foreign_table_coin_history() RETURNS void LANGUAGE plpgsql AS $$ DECLARE table_name TEXT DEFAULT 'coin_history'; 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' ); END $$; INSERT INTO exchange_tables (name ,version ,action ,partitioned ,by_range) VALUES ('coin_history' ,'exchange-0002' ,'create' ,TRUE ,FALSE), ('coin_history' ,'exchange-0002' ,'constrain' ,TRUE ,FALSE), ('coin_history' ,'exchange-0002' ,'foreign' ,TRUE ,FALSE) ;