128 lines
3.6 KiB
PL/PgSQL
128 lines
3.6 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_refunds(
|
|
IN partition_suffix VARCHAR DEFAULT NULL
|
|
)
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'refunds';
|
|
BEGIN
|
|
PERFORM create_partitioned_table(
|
|
'CREATE TABLE %I'
|
|
'(refund_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
|
|
',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
|
|
',deposit_serial_id INT8 NOT NULL'
|
|
',merchant_sig BYTEA NOT NULL CHECK(LENGTH(merchant_sig)=64)'
|
|
',rtransaction_id INT8 NOT NULL'
|
|
',amount_with_fee_val INT8 NOT NULL'
|
|
',amount_with_fee_frac INT4 NOT NULL'
|
|
') %s ;'
|
|
,table_name
|
|
,'PARTITION BY HASH (coin_pub)'
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_table(
|
|
'Data on coins that were refunded. Technically, refunds always apply against specific deposit operations involving a coin. The combination of coin_pub, merchant_pub, h_contract_terms and rtransaction_id MUST be unique, and we usually select by coin_pub so that one goes first.'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Identifies ONLY the merchant_pub, h_contract_terms and coin_pub. Multiple deposits may match a refund, this only identifies one of them.'
|
|
,'deposit_serial_id'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'used by the merchant to make refunds unique in case the same coin for the same deposit gets a subsequent (higher) refund'
|
|
,'rtransaction_id'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
END
|
|
$$;
|
|
|
|
|
|
CREATE FUNCTION constrain_table_refunds (
|
|
IN partition_suffix VARCHAR DEFAULT NULL
|
|
)
|
|
RETURNS void
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'refunds';
|
|
BEGIN
|
|
table_name = concat_ws('_', table_name, partition_suffix);
|
|
EXECUTE FORMAT (
|
|
'CREATE INDEX ' || table_name || '_by_coin_pub_index '
|
|
'ON ' || table_name || ' '
|
|
'(coin_pub);'
|
|
);
|
|
EXECUTE FORMAT (
|
|
'ALTER TABLE ' || table_name ||
|
|
' ADD CONSTRAINT ' || table_name || '_refund_serial_id_key'
|
|
' UNIQUE (refund_serial_id) '
|
|
',ADD PRIMARY KEY (deposit_serial_id, rtransaction_id) '
|
|
);
|
|
END
|
|
$$;
|
|
|
|
|
|
CREATE FUNCTION foreign_table_refunds ()
|
|
RETURNS void
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'refunds';
|
|
BEGIN
|
|
EXECUTE FORMAT (
|
|
'ALTER TABLE ' || table_name ||
|
|
' ADD CONSTRAINT ' || table_name || '_foreign_coin_pub'
|
|
' FOREIGN KEY (coin_pub) '
|
|
' REFERENCES known_coins (coin_pub) ON DELETE CASCADE'
|
|
',ADD CONSTRAINT ' || table_name || '_foreign_deposit'
|
|
' FOREIGN KEY (deposit_serial_id) '
|
|
' REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE'
|
|
);
|
|
END
|
|
$$;
|
|
|
|
|
|
INSERT INTO exchange_tables
|
|
(name
|
|
,version
|
|
,action
|
|
,partitioned
|
|
,by_range)
|
|
VALUES
|
|
('refunds'
|
|
,'exchange-0002'
|
|
,'create'
|
|
,TRUE
|
|
,FALSE),
|
|
('refunds'
|
|
,'exchange-0002'
|
|
,'constrain'
|
|
,TRUE
|
|
,FALSE),
|
|
('refunds'
|
|
,'exchange-0002'
|
|
,'foreign'
|
|
,TRUE
|
|
,FALSE);
|