exchange/src/exchangedb/0002-reserves_in.sql
2022-11-27 14:05:47 +01:00

125 lines
3.5 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_reserves_in(
IN partition_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR default 'reserves_in';
BEGIN
PERFORM create_partitioned_table(
'CREATE TABLE %I'
'(reserve_in_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',reserve_pub BYTEA PRIMARY KEY' -- REFERENCES reserves (reserve_pub) ON DELETE CASCADE'
',wire_reference INT8 NOT NULL'
',credit_val INT8 NOT NULL'
',credit_frac INT4 NOT NULL'
',wire_source_h_payto BYTEA CHECK (LENGTH(wire_source_h_payto)=32)'
',exchange_account_section TEXT NOT NULL'
',execution_date INT8 NOT NULL'
') %s ;'
,table_name
,'PARTITION BY HASH (reserve_pub)'
,partition_suffix
);
PERFORM comment_partitioned_table(
'list of transfers of funds into the reserves, one per incoming wire transfer'
,table_name
,partition_suffix
);
PERFORM comment_partitioned_column(
'Identifies the debited bank account and KYC status'
,'wire_source_h_payto'
,table_name
,partition_suffix
);
PERFORM comment_partitioned_column(
'Public key of the reserve. Private key signifies ownership of the remaining balance.'
,'reserve_pub'
,table_name
,partition_suffix
);
PERFORM comment_partitioned_column(
'Amount that was transferred into the reserve'
,'credit_val'
,table_name
,partition_suffix
);
END
$$;
CREATE FUNCTION constrain_table_reserves_in(
IN partition_suffix VARCHAR
)
RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR default 'reserves_in';
BEGIN
table_name = concat_ws('_', table_name, partition_suffix);
EXECUTE FORMAT (
'ALTER TABLE reserves_in_' || partition_suffix || ' '
'ADD CONSTRAINT reserves_in_' || partition_suffix || '_reserve_in_serial_id_key '
'UNIQUE (reserve_in_serial_id)'
);
EXECUTE FORMAT (
'CREATE INDEX ' || table_name || '_by_reserve_in_serial_id_index '
'ON ' || table_name || ' '
'(reserve_in_serial_id);'
);
-- FIXME: where do we need this index? Can we do better?
EXECUTE FORMAT (
'CREATE INDEX ' || table_name || '_by_exch_accnt_section_execution_date_idx '
'ON ' || table_name || ' '
'(exchange_account_section '
',execution_date'
');'
);
-- FIXME: where do we need this index? Can we do better?
EXECUTE FORMAT (
'CREATE INDEX ' || table_name || '_by_exch_accnt_reserve_in_serial_id_idx '
'ON ' || table_name || ' '
'(exchange_account_section'
',reserve_in_serial_id DESC'
');'
);
END
$$;
INSERT INTO exchange_tables
(name
,version
,action
,partitioned
,by_range)
VALUES
('reserves_in'
,'exchange-0002'
,'create'
,TRUE
,FALSE),
('reserves_in'
,'exchange-0002'
,'constrain'
,TRUE
,FALSE);