189 lines
5.1 KiB
PL/PgSQL
189 lines
5.1 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_wad_in_entries(
|
|
IN partition_suffix VARCHAR DEFAULT NULL
|
|
)
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'wad_in_entries';
|
|
BEGIN
|
|
PERFORM create_partitioned_table(
|
|
'CREATE TABLE %I '
|
|
'(wad_in_entry_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
|
|
',wad_in_serial_id INT8'
|
|
',reserve_pub BYTEA NOT NULL CHECK(LENGTH(reserve_pub)=32)'
|
|
',purse_pub BYTEA PRIMARY KEY CHECK(LENGTH(purse_pub)=32)'
|
|
',h_contract BYTEA NOT NULL CHECK(LENGTH(h_contract)=64)'
|
|
',purse_expiration INT8 NOT NULL'
|
|
',merge_timestamp INT8 NOT NULL'
|
|
',amount_with_fee_val INT8 NOT NULL'
|
|
',amount_with_fee_frac INT4 NOT NULL'
|
|
',wad_fee_val INT8 NOT NULL'
|
|
',wad_fee_frac INT4 NOT NULL'
|
|
',deposit_fees_val INT8 NOT NULL'
|
|
',deposit_fees_frac INT4 NOT NULL'
|
|
',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
|
|
',purse_sig BYTEA NOT NULL CHECK (LENGTH(purse_sig)=64)'
|
|
') %s ;'
|
|
,table_name
|
|
,'PARTITION BY HASH (purse_pub)'
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_table(
|
|
'list of purses aggregated in a wad according to the sending exchange'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'wad for which the given purse was included in the aggregation'
|
|
,'wad_in_serial_id'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'target account of the purse (must be at the local exchange)'
|
|
,'reserve_pub'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'public key of the purse that was merged'
|
|
,'purse_pub'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'hash of the contract terms of the purse'
|
|
,'h_contract'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Time when the purse was set to expire'
|
|
,'purse_expiration'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Time when the merge was approved'
|
|
,'merge_timestamp'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Total amount in the purse'
|
|
,'amount_with_fee_val'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Total wad fees paid by the purse'
|
|
,'wad_fee_val'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Total deposit fees paid when depositing coins into the purse'
|
|
,'deposit_fees_val'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Signature by the receiving reserve, of purpose TALER_SIGNATURE_ACCOUNT_MERGE'
|
|
,'reserve_sig'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE'
|
|
,'purse_sig'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
END $$;
|
|
|
|
|
|
CREATE FUNCTION constrain_table_wad_in_entries(
|
|
IN partition_suffix VARCHAR
|
|
)
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'wad_in_entries';
|
|
BEGIN
|
|
table_name = concat_ws('_', table_name, partition_suffix);
|
|
|
|
-- FIXME: change to materialized index by reserve_pub!
|
|
EXECUTE FORMAT (
|
|
'CREATE INDEX ' || table_name || '_reserve_pub '
|
|
'ON ' || table_name || ' '
|
|
'(reserve_pub);'
|
|
);
|
|
EXECUTE FORMAT (
|
|
'COMMENT ON INDEX ' || table_name || '_reserve_pub '
|
|
'IS ' || quote_literal('needed in reserve history computation') || ';'
|
|
);
|
|
EXECUTE FORMAT (
|
|
'ALTER TABLE ' || table_name ||
|
|
' ADD CONSTRAINT ' || table_name || '_wad_in_entry_serial_id_key'
|
|
' UNIQUE (wad_in_entry_serial_id) '
|
|
);
|
|
END $$;
|
|
|
|
|
|
CREATE FUNCTION foreign_table_wad_in_entries()
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'wad_in_entries';
|
|
BEGIN
|
|
EXECUTE FORMAT (
|
|
'ALTER TABLE ' || table_name ||
|
|
' ADD CONSTRAINT ' || table_name || '_foreign_wad_in'
|
|
' FOREIGN KEY(wad_in_serial_id)'
|
|
' REFERENCES wads_in (wad_in_serial_id) ON DELETE CASCADE'
|
|
);
|
|
END $$;
|
|
|
|
|
|
INSERT INTO exchange_tables
|
|
(name
|
|
,version
|
|
,action
|
|
,partitioned
|
|
,by_range)
|
|
VALUES
|
|
('wad_in_entries'
|
|
,'exchange-0002'
|
|
,'create'
|
|
,TRUE
|
|
,FALSE),
|
|
('wad_in_entries'
|
|
,'exchange-0002'
|
|
,'constrain'
|
|
,TRUE
|
|
,FALSE),
|
|
('wad_in_entries'
|
|
,'exchange-0002'
|
|
,'foreign'
|
|
,TRUE
|
|
,FALSE);
|