exchange

Base system with REST service to issue digital coins, run by the payment service provider
Log | Files | Refs | Submodules | README | LICENSE

0002-kyc_attributes.sql (4403B)


      1 --
      2 -- This file is part of TALER
      3 -- Copyright (C) 2014--2022 Taler Systems SA
      4 --
      5 -- TALER is free software; you can redistribute it and/or modify it under the
      6 -- terms of the GNU General Public License as published by the Free Software
      7 -- Foundation; either version 3, or (at your option) any later version.
      8 --
      9 -- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
     10 -- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR
     11 -- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
     12 --
     13 -- You should have received a copy of the GNU General Public License along with
     14 -- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
     15 --
     16 
     17 CREATE OR REPLACE FUNCTION create_table_kyc_attributes(
     18   IN partition_suffix TEXT DEFAULT NULL
     19 )
     20 RETURNS VOID
     21 LANGUAGE plpgsql
     22 AS $$
     23 DECLARE
     24   table_name TEXT DEFAULT 'kyc_attributes';
     25 BEGIN
     26   PERFORM create_partitioned_table(
     27     'CREATE TABLE IF NOT EXISTS %I'
     28       '(kyc_attributes_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
     29       ',h_payto BYTEA CHECK (LENGTH(h_payto)=32)'
     30       ',collection_time INT8 NOT NULL'
     31       ',expiration_time INT8 NOT NULL'
     32       ',encrypted_attributes BYTEA NOT NULL'
     33       ',legitimization_serial INT8 NOT NULL'
     34       ',form_name TEXT DEFAULT(NULL)'
     35       ',by_aml_officer BOOL NOT NULL DEFAULT(FALSE)'
     36     ') %s ;'
     37     ,table_name
     38     ,'PARTITION BY HASH (h_payto)'
     39     ,partition_suffix
     40   );
     41   PERFORM comment_partitioned_table(
     42      'KYC data about particular payment addresses'
     43     ,table_name
     44     ,partition_suffix
     45   );
     46   PERFORM comment_partitioned_column(
     47      'hash of payto://-URI the attributes are about'
     48     ,'h_payto'
     49     ,table_name
     50     ,partition_suffix
     51   );
     52   PERFORM comment_partitioned_column(
     53      'time when the attributes were collected by the provider'
     54     ,'collection_time'
     55     ,table_name
     56     ,partition_suffix
     57   );
     58   PERFORM comment_partitioned_column(
     59      'time when the attributes should no longer be considered validated'
     60     ,'expiration_time'
     61     ,table_name
     62     ,partition_suffix
     63   );
     64   PERFORM comment_partitioned_column(
     65      '(encrypted) JSON object (as string) with the attributes'
     66     ,'encrypted_attributes'
     67     ,table_name
     68     ,partition_suffix
     69   );
     70   PERFORM comment_partitioned_column(
     71      'Reference the legitimization process for which these attributes are gathered for.'
     72     ,'legitimization_serial'
     73     ,table_name
     74     ,partition_suffix
     75   );
     76   PERFORM comment_partitioned_column(
     77      'Name of the form (FORM_ID) that is captured in the attributes.'
     78     ,'form_name'
     79     ,table_name
     80     ,partition_suffix
     81   );
     82   PERFORM comment_partitioned_column(
     83      'TRUE if the attributes were submitted by an AML officer.'
     84     ,'by_aml_officer'
     85     ,table_name
     86     ,partition_suffix
     87   );
     88 END $$;
     89 
     90 COMMENT ON FUNCTION create_table_kyc_attributes
     91   IS 'Creates the kyc_attributes table';
     92 
     93 
     94 CREATE OR REPLACE FUNCTION constrain_table_kyc_attributes(
     95   IN partition_suffix TEXT
     96 )
     97 RETURNS void
     98 LANGUAGE plpgsql
     99 AS $$
    100 DECLARE
    101   table_name TEXT DEFAULT 'kyc_attributes';
    102 BEGIN
    103   table_name = concat_ws('_', table_name, partition_suffix);
    104   EXECUTE FORMAT (
    105     'ALTER TABLE ' || table_name ||
    106       ' ADD CONSTRAINT ' || table_name || '_serial_key '
    107         'UNIQUE (kyc_attributes_serial_id)'
    108   );
    109   -- To search accounts
    110   EXECUTE FORMAT (
    111     'CREATE INDEX ' || table_name || '_h_payto_index '
    112     'ON ' || table_name || ' '
    113     '(h_payto);'
    114   );
    115   -- For garbage collection
    116   EXECUTE FORMAT (
    117     'CREATE INDEX ' || table_name || '_expiration_time '
    118     'ON ' || table_name || ' '
    119     '(expiration_time ASC);'
    120   );
    121 END $$;
    122 
    123 
    124 CREATE OR REPLACE FUNCTION foreign_table_kyc_attributes()
    125 RETURNS void
    126 LANGUAGE plpgsql
    127 AS $$
    128 DECLARE
    129   table_name TEXT DEFAULT 'kyc_attributes';
    130 BEGIN
    131   EXECUTE FORMAT (
    132     'ALTER TABLE ' || table_name ||
    133     ' ADD CONSTRAINT ' || table_name || '_foreign_legitimization_processes'
    134     ' FOREIGN KEY (legitimization_serial) '
    135     ' REFERENCES legitimization_processes (legitimization_process_serial_id)' -- ON DELETE SET NULL?
    136   );
    137 END $$;
    138 
    139 
    140 INSERT INTO exchange_tables
    141     (name
    142     ,version
    143     ,action
    144     ,partitioned
    145     ,by_range)
    146   VALUES
    147     ('kyc_attributes'
    148     ,'exchange-0002'
    149     ,'create'
    150     ,TRUE
    151     ,FALSE),
    152     ('kyc_attributes'
    153     ,'exchange-0002'
    154     ,'constrain'
    155     ,TRUE
    156     ,FALSE),
    157     ('kyc_attributes'
    158     ,'exchange-0002'
    159     ,'foreign'
    160     ,TRUE
    161     ,FALSE);