150 lines
4.0 KiB
PL/PgSQL
150 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_purse_merges(
|
|
IN partition_suffix VARCHAR DEFAULT NULL
|
|
)
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'purse_merges';
|
|
BEGIN
|
|
PERFORM create_partitioned_table(
|
|
'CREATE TABLE %I '
|
|
'(purse_merge_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
|
|
',partner_serial_id INT8'
|
|
',reserve_pub BYTEA NOT NULL CHECK(length(reserve_pub)=32)'
|
|
',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
|
|
',merge_sig BYTEA NOT NULL CHECK (LENGTH(merge_sig)=64)'
|
|
',merge_timestamp INT8 NOT NULL'
|
|
',PRIMARY KEY (purse_pub)'
|
|
') %s ;'
|
|
,table_name
|
|
,'PARTITION BY HASH (purse_pub)'
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_table(
|
|
'Merge requests where a purse-owner requested merging the purse into the account'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'identifies the partner exchange, NULL in case the target reserve lives at this exchange'
|
|
,'partner_serial_id'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'public key of the target reserve'
|
|
,'reserve_pub'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'public key of the purse'
|
|
,'purse_pub'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'signature by the purse private key affirming the merge, of type TALER_SIGNATURE_WALLET_PURSE_MERGE'
|
|
,'merge_sig'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'when was the merge message signed'
|
|
,'merge_timestamp'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
END
|
|
$$;
|
|
|
|
|
|
CREATE FUNCTION constrain_table_purse_merges(
|
|
IN partition_suffix VARCHAR
|
|
)
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'purse_merges';
|
|
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 || '_purse_merge_request_serial_id_key'
|
|
' UNIQUE (purse_merge_request_serial_id) '
|
|
);
|
|
END
|
|
$$;
|
|
|
|
|
|
CREATE FUNCTION foreign_table_purse_merges()
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'purse_merges';
|
|
BEGIN
|
|
EXECUTE FORMAT (
|
|
'ALTER TABLE ' || table_name ||
|
|
' ADD CONSTRAINT ' || table_name || '_foreign_partner_serial_id'
|
|
' FOREIGN KEY (partner_serial_id) '
|
|
' REFERENCES partners(partner_serial_id) ON DELETE CASCADE'
|
|
',ADD CONSTRAINT ' || table_name || '_foreign_purse_pub'
|
|
' FOREIGN KEY (purse_pub) '
|
|
' REFERENCES purse_requests (purse_pub) ON DELETE CASCADE'
|
|
);
|
|
END
|
|
$$;
|
|
|
|
|
|
INSERT INTO exchange_tables
|
|
(name
|
|
,version
|
|
,action
|
|
,partitioned
|
|
,by_range)
|
|
VALUES
|
|
('purse_merges'
|
|
,'exchange-0002'
|
|
,'create'
|
|
,TRUE
|
|
,FALSE),
|
|
('purse_merges'
|
|
,'exchange-0002'
|
|
,'constrain'
|
|
,TRUE
|
|
,FALSE),
|
|
('purse_merges'
|
|
,'exchange-0002'
|
|
,'foreign'
|
|
,TRUE
|
|
,FALSE);
|