exchange/src/exchangedb/0002-legitimization_processes.sql
2023-01-11 16:43:22 +01:00

130 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 FUNCTION create_table_legitimization_processes(
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
PERFORM create_partitioned_table(
'CREATE TABLE %I'
'(legitimization_process_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
',h_payto BYTEA NOT NULL CHECK (LENGTH(h_payto)=32)'
',expiration_time INT8 NOT NULL DEFAULT (0)'
',provider_section VARCHAR NOT NULL'
',provider_user_id VARCHAR DEFAULT NULL'
',provider_legitimization_id VARCHAR DEFAULT NULL'
',UNIQUE (h_payto, provider_section)'
') %s ;'
,'legitimization_processes'
,'PARTITION BY HASH (h_payto)'
,shard_suffix
);
PERFORM comment_partitioned_table(
'List of legitimization processes (ongoing and completed) by account and provider'
,'legitimization_processes'
,shard_suffix
);
PERFORM comment_partitioned_column(
'unique ID for this legitimization process at the exchange'
,'legitimization_process_serial_id'
,'legitimization_processes'
,shard_suffix
);
PERFORM comment_partitioned_column(
'foreign key linking the entry to the wire_targets table, NOT a primary key (multiple legitimizations are possible per wire target)'
,'h_payto'
,'legitimization_processes'
,shard_suffix
);
PERFORM comment_partitioned_column(
'in the future if the respective KYC check was passed successfully'
,'expiration_time'
,'legitimization_processes'
,shard_suffix
);
PERFORM comment_partitioned_column(
'Configuration file section with details about this provider'
,'provider_section'
,'legitimization_processes'
,shard_suffix
);
PERFORM comment_partitioned_column(
'Identifier for the user at the provider that was used for the legitimization. NULL if provider is unaware.'
,'provider_user_id'
,'legitimization_processes'
,shard_suffix
);
PERFORM comment_partitioned_column(
'Identifier for the specific legitimization process at the provider. NULL if legitimization was not started.'
,'provider_legitimization_id'
,'legitimization_processes'
,shard_suffix
);
END
$$;
-- We need a separate function for this, as we call create_table only once but need to add
-- those constraints to each partition which gets created
CREATE FUNCTION constrain_table_legitimization_processes(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
partition_name VARCHAR;
BEGIN
partition_name = concat_ws('_', 'legitimization_processes', partition_suffix);
EXECUTE FORMAT (
'ALTER TABLE ' || partition_name
|| ' '
'ADD CONSTRAINT ' || partition_name || '_serial_key '
'UNIQUE (legitimization_process_serial_id)');
EXECUTE FORMAT (
'CREATE INDEX IF NOT EXISTS ' || partition_name || '_by_provider_and_legi_index '
'ON '|| partition_name || ' '
'(provider_section,provider_legitimization_id)'
);
EXECUTE FORMAT (
'COMMENT ON INDEX ' || partition_name || '_by_provider_and_legi_index '
'IS ' || quote_literal('used (rarely) in kyc_provider_account_lookup') || ';'
);
END
$$;
INSERT INTO exchange_tables
(name
,version
,action
,partitioned
,by_range)
VALUES
('legitimization_processes'
,'exchange-0002'
,'create'
,TRUE
,FALSE),
('legitimization_processes'
,'exchange-0002'
,'constrain'
,TRUE
,FALSE);