-- -- 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 OR REPLACE FUNCTION create_table_aml_history( IN partition_suffix TEXT DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ DECLARE table_name TEXT DEFAULT 'aml_history'; BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(aml_history_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' ',h_payto BYTEA CHECK (LENGTH(h_payto)=32)' ',new_threshold taler_amount NOT NULL DEFAULT(0,0)' ',new_status INT4 NOT NULL DEFAULT(0)' ',decision_time INT8 NOT NULL DEFAULT(0)' ',justification TEXT NOT NULL' ',kyc_requirements TEXT' ',kyc_req_row INT8 NOT NULL DEFAULT(0)' ',decider_pub BYTEA CHECK (LENGTH(decider_pub)=32)' ',decider_sig BYTEA CHECK (LENGTH(decider_sig)=64)' ') %s ;' ,table_name ,'PARTITION BY HASH (h_payto)' ,partition_suffix ); PERFORM comment_partitioned_table( 'AML decision history for a particular payment destination' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'hash of the payto://-URI this AML history is about' ,'h_payto' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'new monthly inbound transaction limit below which we are OK' ,'new_threshold' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( '0 for all OK, 1 for AML decision required, 2 for account is frozen (prevents further transactions)' ,'new_status' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'when was the status changed' ,'decision_time' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'human-readable justification for the status change' ,'justification' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'Public key of the staff member who made the AML decision' ,'decider_pub' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'Additional KYC requirements imposed by the AML staff member. Serialized JSON array of strings.' ,'kyc_requirements' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'Row in the KYC table for this KYC requirement, 0 for none.' ,'kyc_req_row' ,table_name ,partition_suffix ); PERFORM comment_partitioned_column( 'Signature key of the staff member affirming the AML decision; of type AML_DECISION' ,'decider_sig' ,table_name ,partition_suffix ); END $$; COMMENT ON FUNCTION create_table_aml_history IS 'Creates the aml_history table'; CREATE OR REPLACE FUNCTION constrain_table_aml_history( IN partition_suffix TEXT ) RETURNS void LANGUAGE plpgsql AS $$ DECLARE table_name TEXT DEFAULT 'aml_history'; BEGIN table_name = concat_ws('_', table_name, partition_suffix); EXECUTE FORMAT ( 'ALTER TABLE ' || table_name || ' ADD CONSTRAINT ' || table_name || '_serial_key ' 'UNIQUE (aml_history_serial_id)' ); EXECUTE FORMAT ( 'CREATE INDEX ' || table_name || '_main_index ' 'ON ' || table_name || ' ' '(h_payto, decision_time DESC);' ); END $$; INSERT INTO exchange_tables (name ,version ,action ,partitioned ,by_range) VALUES ('aml_history' ,'exchange-0002' ,'create' ,TRUE ,FALSE), ('aml_history' ,'exchange-0002' ,'constrain' ,TRUE ,FALSE);