From 42e2726f43fcc497ca905fcd5f61758aa528f353 Mon Sep 17 00:00:00 2001 From: Christian Grothoff Date: Tue, 27 Dec 2022 02:25:45 +0100 Subject: -work on v3 exchangedb schema --- src/exchangedb/0003-aml_history.sql | 127 ++++++++++++++++++++++++++++++++++++ 1 file changed, 127 insertions(+) create mode 100644 src/exchangedb/0003-aml_history.sql (limited to 'src/exchangedb/0003-aml_history.sql') diff --git a/src/exchangedb/0003-aml_history.sql b/src/exchangedb/0003-aml_history.sql new file mode 100644 index 000000000..60382cc26 --- /dev/null +++ b/src/exchangedb/0003-aml_history.sql @@ -0,0 +1,127 @@ +-- +-- 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 VARCHAR DEFAULT NULL +) +RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE + table_name VARCHAR 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 PRIMARY KEY CHECK (LENGTH(h_payto)=32)' + ',new_threshold_val INT8 NOT NULL DEFAULT(0)' + ',new_threshold_frac INT4 NOT NULL DEFAULT(0)' + ',new_status INT4 NOT NULL DEFAULT(0)' + ',decision_time INT8 NOT NULL DEFAULT(0)' + ',justification VARCHAR NOT NULL' + ',decider VARCHAR NOT NULL' + ') %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_val' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + '0 for AML decision required, 1 for AML is OK, -1 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( + 'Name of the staff member who made the AML decision' + ,'decider' + ,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 VARCHAR +) +RETURNS void +LANGUAGE plpgsql +AS $$ +DECLARE + table_name VARCHAR 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 ASC, decision_time ASC);' + ); +END $$; + + +INSERT INTO exchange_tables + (name + ,version + ,action + ,partitioned + ,by_range) + VALUES + ('aml_history' + ,'exchange-0003' + ,'create' + ,TRUE + ,FALSE), + ('aml_history' + ,'exchange-0003' + ,'constrain' + ,TRUE + ,FALSE); -- cgit v1.2.3