exchange/src/exchangedb/0003-kyc_attributes.sql
Christian Grothoff 871d010637
-expand tables
2022-12-27 03:31:13 +01:00

141 lines
4.0 KiB
PL/PgSQL

--
-- 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)'
',kyc_prox BYTEA NOT NULL CHECK (LENGTH(kyc_prox)=32)'
',provider VARCHAR NOT NULL'
',birthdate VARCHAR'
',collection_time INT8 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(
'short hash of normalized full name and birthdate; used to efficiently find likely duplicate users'
,'kyc_prox'
,table_name
,partition_suffix
);
PERFORM comment_partitioned_column(
'birth date of the user, in format YYYY-MM-DD where a value of 0 is used to indicate unknown (in official documents); NULL if the birth date was not collected by the provider; used for KYC-driven age restrictions'
,'birthdate'
,table_name
,partition_suffix
);
PERFORM comment_partitioned_column(
'time when the attributes were collected by the provider'
,'collection_time'
,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)'
);
-- To search similar users (e.g. during AML checks)
EXECUTE FORMAT (
'CREATE INDEX ' || table_name || '_similarity_index '
'ON ' || table_name || ' '
'(kyc_prox);'
);
-- For garbage collection
EXECUTE FORMAT (
'CREATE INDEX ' || table_name || '_expiration_time '
'ON ' || table_name || ' '
'(expiration_time ASC);'
);
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);