diff options
| author | Christian Grothoff <grothoff@gnunet.org> | 2022-12-27 02:25:45 +0100 | 
|---|---|---|
| committer | Christian Grothoff <grothoff@gnunet.org> | 2022-12-27 02:25:45 +0100 | 
| commit | 42e2726f43fcc497ca905fcd5f61758aa528f353 (patch) | |
| tree | 3e58967c263549cb99d3aae36d94b65aaa2f60d9 /src/exchangedb | |
| parent | 0a40f484008e801870871f5a6ddac633dc990cd2 (diff) | |
-work on v3 exchangedb schema
Diffstat (limited to 'src/exchangedb')
| -rw-r--r-- | src/exchangedb/0003-aml_history.sql | 127 | ||||
| -rw-r--r-- | src/exchangedb/0003-aml_status.sql | 101 | ||||
| -rw-r--r-- | src/exchangedb/0003-kyc_attributes.sql | 107 | ||||
| -rw-r--r-- | src/exchangedb/0003-purse_actions.sql | 97 | ||||
| -rw-r--r-- | src/exchangedb/0003-purse_deletion.sql | 74 | ||||
| -rw-r--r-- | src/exchangedb/exchange-0003.sql.in | 3 | 
6 files changed, 458 insertions, 51 deletions
| diff --git a/src/exchangedb/0003-aml_history.sql b/src/exchangedb/0003-aml_history.sql new file mode 100644 index 00000000..60382cc2 --- /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 <http://www.gnu.org/licenses/> +-- + +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); diff --git a/src/exchangedb/0003-aml_status.sql b/src/exchangedb/0003-aml_status.sql new file mode 100644 index 00000000..1e676bc1 --- /dev/null +++ b/src/exchangedb/0003-aml_status.sql @@ -0,0 +1,101 @@ +-- +-- 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 <http://www.gnu.org/licenses/> +-- + +CREATE OR REPLACE FUNCTION create_table_aml_status( +  IN partition_suffix VARCHAR DEFAULT NULL +) +RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'aml_status'; +BEGIN +  PERFORM create_partitioned_table( +    'CREATE TABLE IF NOT EXISTS %I' +      '(aml_status_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' +      ',h_payto BYTEA PRIMARY KEY CHECK (LENGTH(h_payto)=32)' +      ',threshold_val INT8 NOT NULL DEFAULT(0)' +      ',threshold_frac INT4 NOT NULL DEFAULT(0)' +      ',status INT4 NOT NULL DEFAULT(0)' +    ') %s ;' +    ,table_name +    ,'PARTITION BY HASH (h_payto)' +    ,partition_suffix +  ); +  PERFORM comment_partitioned_table( +     'AML status for a particular payment destination' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'hash of the payto://-URI this AML status is about' +    ,'h_payto' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'monthly inbound transaction limit below which we are OK (if status is 1)' +    ,'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)' +    ,'status' +    ,table_name +    ,partition_suffix +  ); +END $$; + +COMMENT ON FUNCTION create_table_aml_status +  IS 'Creates the aml_status table'; + + +CREATE OR REPLACE FUNCTION constrain_table_aml_status( +  IN partition_suffix VARCHAR +) +RETURNS void +LANGUAGE plpgsql +AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'aml_status'; +BEGIN +  table_name = concat_ws('_', table_name, partition_suffix); +  EXECUTE FORMAT ( +    'ALTER TABLE ' || table_name || +      ' ADD CONSTRAINT ' || table_name || '_serial_key ' +        'UNIQUE (aml_status_serial_id)' +  ); +END $$; + + +INSERT INTO exchange_tables +    (name +    ,version +    ,action +    ,partitioned +    ,by_range) +  VALUES +    ('aml_status' +    ,'exchange-0003' +    ,'create' +    ,TRUE +    ,FALSE), +    ('aml_status' +    ,'exchange-0003' +    ,'constrain' +    ,TRUE +    ,FALSE); diff --git a/src/exchangedb/0003-kyc_attributes.sql b/src/exchangedb/0003-kyc_attributes.sql new file mode 100644 index 00000000..db7f2e1e --- /dev/null +++ b/src/exchangedb/0003-kyc_attributes.sql @@ -0,0 +1,107 @@ +-- +-- 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 <http://www.gnu.org/licenses/> +-- + +CREATE OR REPLACE FUNCTION create_table_kyc_attributes( +  IN partition_suffix VARCHAR DEFAULT NULL +) +RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'kyc_attributes'; +BEGIN +  PERFORM create_partitioned_table( +    'CREATE TABLE IF NOT EXISTS %I' +      '(kyc_attributes_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' +      ',h_payto BYTEA PRIMARY KEY CHECK (LENGTH(h_payto)=32)' +      ',provider VARCHAR NOT NULL' +      ',expiration_time INT8 NOT NULL' +      ',encrypted_attributes VARCHAR NOT NULL' +    ') %s ;' +    ,table_name +    ,'PARTITION BY HASH (h_payto)' +    ,partition_suffix +  ); +  PERFORM comment_partitioned_table( +     'KYC data about particular payment addresses' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'hash of payto://-URI the attributes are about' +    ,'h_payto' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'time when the attributes should no longer be considered validated' +    ,'expiration_time' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'configuration section name of the provider that affirmed the attributes' +    ,'provider' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     '(encrypted) JSON object (as string) with the attributes' +    ,'encrypted_attributes' +    ,table_name +    ,partition_suffix +  ); +END $$; + +COMMENT ON FUNCTION create_table_kyc_attributes +  IS 'Creates the kyc_attributes table'; + + +CREATE OR REPLACE FUNCTION constrain_table_kyc_attributes( +  IN partition_suffix VARCHAR +) +RETURNS void +LANGUAGE plpgsql +AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'kyc_attributes'; +BEGIN +  table_name = concat_ws('_', table_name, partition_suffix); +  EXECUTE FORMAT ( +    'ALTER TABLE ' || table_name || +      ' ADD CONSTRAINT ' || table_name || '_serial_key ' +        'UNIQUE (kyc_attributes_serial_id)' +  ); +END $$; + + +INSERT INTO exchange_tables +    (name +    ,version +    ,action +    ,partitioned +    ,by_range) +  VALUES +    ('kyc_attributes' +    ,'exchange-0003' +    ,'create' +    ,TRUE +    ,FALSE), +    ('kyc_attributes' +    ,'exchange-0003' +    ,'constrain' +    ,TRUE +    ,FALSE); diff --git a/src/exchangedb/0003-purse_actions.sql b/src/exchangedb/0003-purse_actions.sql index c77dfb3c..b4e7e132 100644 --- a/src/exchangedb/0003-purse_actions.sql +++ b/src/exchangedb/0003-purse_actions.sql @@ -15,23 +15,49 @@  -- -CREATE TABLE IF NOT EXISTS purse_actions -  (purse_pub BYTEA NOT NULL PRIMARY KEY CHECK(LENGTH(purse_pub)=32) -  ,action_date INT8 NOT NULL -  ,partner_serial_id INT8 +CREATE OR REPLACE FUNCTION create_table_purse_actions( +  IN partition_suffix VARCHAR DEFAULT NULL +) +RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'purse_actions'; +BEGIN +  PERFORM create_partitioned_table( +    'CREATE TABLE IF NOT EXISTS %I' +      '(purse_pub BYTEA NOT NULL PRIMARY KEY CHECK(LENGTH(purse_pub)=32)' +      ',action_date INT8 NOT NULL' +      ',partner_serial_id INT8' +    ') %s ;' +    ,table_name +    ,'PARTITION BY HASH (purse_pub)' +    ,partition_suffix    ); -COMMENT ON TABLE purse_actions -  IS 'purses awaiting some action by the router'; -COMMENT ON COLUMN purse_actions.purse_pub -  IS 'public (contract) key of the purse'; -COMMENT ON COLUMN purse_actions.action_date -  IS 'when is the purse ready for action'; -COMMENT ON COLUMN purse_actions.partner_serial_id -  IS 'wad target of an outgoing wire transfer, 0 for local, NULL if the purse is unmerged and thus the target is still unknown'; - -CREATE INDEX IF NOT EXISTS purse_action_by_target -  ON purse_actions -  (partner_serial_id,action_date); +  PERFORM comment_partitioned_table( +     'purses awaiting some action by the router' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'public (contract) key of the purse' +    ,'purse_pub' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'when is the purse ready for action' +    ,'action_date' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'wad target of an outgoing wire transfer, 0 for local, NULL if the purse is unmerged and thus the target is still unknown' +    ,'partner_serial_id' +    ,table_name +    ,partition_suffix +  ); +END $$;  CREATE OR REPLACE FUNCTION purse_requests_insert_trigger() @@ -48,16 +74,32 @@ BEGIN      ,NEW.purse_expiration);    RETURN NEW;  END $$; +  COMMENT ON FUNCTION purse_requests_insert_trigger()    IS 'When a purse is created, insert it into the purse_action table to take action when the purse expires.'; -CREATE TRIGGER purse_requests_on_insert -  AFTER INSERT -   ON purse_requests -   FOR EACH ROW EXECUTE FUNCTION purse_requests_insert_trigger(); -COMMENT ON TRIGGER purse_requests_on_insert -        ON purse_requests -  IS 'Here we install an entry for the purse expiration.'; + +CREATE OR REPLACE FUNCTION master_table_purse_actions() +RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'purse_actions'; +BEGIN +  -- Create global index +  CREATE INDEX IF NOT EXISTS purse_action_by_target +    ON purse_actions +    (partner_serial_id,action_date); + +  -- Setup trigger +  CREATE TRIGGER purse_requests_on_insert +    AFTER INSERT +    ON purse_requests +    FOR EACH ROW EXECUTE FUNCTION purse_requests_insert_trigger(); +  COMMENT ON TRIGGER purse_requests_on_insert +          ON purse_requests +    IS 'Here we install an entry for the purse expiration.'; +END $$;  INSERT INTO exchange_tables @@ -68,7 +110,12 @@ INSERT INTO exchange_tables      ,by_range)    VALUES      ('purse_actions' -    ,'exchange-0002' +    ,'exchange-0003'      ,'create' -    ,FALSE +    ,TRUE +    ,FALSE), +    ('purse_actions' +    ,'exchange-0003' +    ,'master' +    ,TRUE      ,FALSE); diff --git a/src/exchangedb/0003-purse_deletion.sql b/src/exchangedb/0003-purse_deletion.sql index e655ee61..5434a334 100644 --- a/src/exchangedb/0003-purse_deletion.sql +++ b/src/exchangedb/0003-purse_deletion.sql @@ -15,60 +15,82 @@  --  CREATE OR REPLACE FUNCTION create_table_purse_deletion( -  IN shard_suffix VARCHAR DEFAULT NULL +  IN partition_suffix VARCHAR DEFAULT NULL  )  RETURNS VOID  LANGUAGE plpgsql  AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'purse_deletion';  BEGIN    PERFORM create_partitioned_table(      'CREATE TABLE IF NOT EXISTS %I' -      '(purse_deletion_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' +      '(purse_deletion_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'        ',purse_sig BYTEA CHECK (LENGTH(purse_sig)=64)' -      ',XXX VARCHAR NOT NULL' +      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'      ') %s ;' -    ,'purse_deletion' -    ,'PARTITION BY HASH (XXX)' -    ,shard_suffix +    ,table_name +    ,'PARTITION BY HASH (purse_pub)' +    ,partition_suffix    ); -  COMMENT ON TABLE purse_deletion -    IS 'signatures affirming explicit purse deletions'; -  COMMENT ON COLUMN purse_deletion.purse_sig -    IS 'signature of type XXX'; -END -$$; +  PERFORM comment_partitioned_table( +     'signatures affirming explicit purse deletions' +    ,table_name +    ,partition_suffix +  ); +  PERFORM comment_partitioned_column( +     'signature of type WALLET_PURSE_DELETE' +    ,'purse_sig' +    ,table_name +    ,partition_suffix +  ); +END $$; +  COMMENT ON FUNCTION create_table_purse_deletion    IS 'Creates the purse_deletion table'; +  CREATE OR REPLACE FUNCTION constrain_table_purse_deletion(    IN partition_suffix VARCHAR  )  RETURNS void  LANGUAGE plpgsql  AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'purse_deletion';  BEGIN +  table_name = concat_ws('_', table_name, partition_suffix);    EXECUTE FORMAT ( -    'ALTER TABLE purse_deletion_' || partition_suffix || ' ' -      'ADD CONSTRAINT purse_deletion_' || partition_suffix || '_XXX ' -        'UNIQUE (XXX)' +    'ALTER TABLE ' || table_name || +      ' ADD CONSTRAINT ' || table_name || '_delete_serial_key ' +        'UNIQUE (purse_deletion_serial_id)'    ); -END -$$; +END $$; -CREATE OR REPLACE FUNCTION alter_create_was_deleted_table_purse_requests ( + +CREATE OR REPLACE FUNCTION create_table_purse_requests_was_deleted (    IN partition_suffix VARCHAR  )  RETURNS void  LANGUAGE plpgsql  AS $$ +DECLARE +  table_name VARCHAR DEFAULT 'purse_requests';  BEGIN +  table_name = concat_ws('_', table_name, partition_suffix);    EXECUTE FORMAT ( -    'ALTER TABLE purse_requests_' || partition_suffix || +    'ALTER TABLE ' || table_name ||      ' ADD COLUMN'      ' was_deleted BOOLEAN NOT NULL DEFAULT(FALSE)'    ); -END -$$; +  PERFORM comment_partitioned_column( +     'TRUE if the purse was explicitly deleted (purse must have an entry in the purse_deletion table)' +    ,'was_deleted' +    ,table_name +    ,partition_suffix +  ); +END $$; +  INSERT INTO exchange_tables      (name @@ -78,17 +100,17 @@ INSERT INTO exchange_tables      ,by_range)    VALUES      ('purse_deletion' -    ,'exchange-0002' +    ,'exchange-0003'      ,'create'      ,TRUE      ,FALSE),      ('purse_deletion' -    ,'exchange-0002' +    ,'exchange-0003'      ,'constrain'      ,TRUE      ,FALSE), -    ('purse_requests' -    ,'exchange-0002' -    ,'alter_create_was_deleted' +    ('purse_requests_was_deleted' +    ,'exchange-0003' +    ,'create'      ,TRUE      ,FALSE); diff --git a/src/exchangedb/exchange-0003.sql.in b/src/exchangedb/exchange-0003.sql.in index 7f0a9ef9..59f79968 100644 --- a/src/exchangedb/exchange-0003.sql.in +++ b/src/exchangedb/exchange-0003.sql.in @@ -21,5 +21,8 @@ SET search_path TO exchange;  #include "0003-purse_actions.sql"  #include "0003-purse_deletion.sql" +#include "0003-kyc_attributes.sql" +#include "0003-aml_status.sql" +#include "0003-aml_history.sql"  COMMIT; | 
