149 lines
4.1 KiB
PL/PgSQL
149 lines
4.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_reserves(
|
|
IN partition_suffix VARCHAR DEFAULT NULL
|
|
)
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'reserves';
|
|
BEGIN
|
|
PERFORM create_partitioned_table(
|
|
'CREATE TABLE %I'
|
|
'(reserve_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
|
|
',reserve_pub BYTEA PRIMARY KEY CHECK(LENGTH(reserve_pub)=32)'
|
|
',current_balance_val INT8 NOT NULL DEFAULT(0)'
|
|
',current_balance_frac INT4 NOT NULL DEFAULT(0)'
|
|
',purses_active INT8 NOT NULL DEFAULT(0)'
|
|
',purses_allowed INT8 NOT NULL DEFAULT(0)'
|
|
',max_age INT4 NOT NULL DEFAULT(120)'
|
|
',expiration_date INT8 NOT NULL'
|
|
',gc_date INT8 NOT NULL'
|
|
') %s ;'
|
|
,table_name
|
|
,'PARTITION BY HASH (reserve_pub)'
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_table(
|
|
'Summarizes the balance of a reserve. Updated when new funds are added or withdrawn.'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'EdDSA public key of the reserve. Knowledge of the private key implies ownership over the balance.'
|
|
,'reserve_pub'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Current balance remaining with the reserve.'
|
|
,'current_balance_val'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Number of purses that were created by this reserve that are not expired and not fully paid.'
|
|
,'purses_active'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Number of purses that this reserve is allowed to have active at most.'
|
|
,'purses_allowed'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Used to trigger closing of reserves that have not been drained after some time'
|
|
,'expiration_date'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
PERFORM comment_partitioned_column(
|
|
'Used to forget all information about a reserve during garbage collection'
|
|
,'gc_date'
|
|
,table_name
|
|
,partition_suffix
|
|
);
|
|
END
|
|
$$;
|
|
|
|
|
|
CREATE FUNCTION constrain_table_reserves(
|
|
IN partition_suffix VARCHAR
|
|
)
|
|
RETURNS void
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
table_name VARCHAR DEFAULT 'reserves';
|
|
BEGIN
|
|
table_name = concat_ws('_', table_name, partition_suffix);
|
|
EXECUTE FORMAT (
|
|
'ALTER TABLE ' || table_name ||
|
|
' ADD CONSTRAINT ' || table_name || '_unique_uuid'
|
|
' UNIQUE (reserve_uuid)'
|
|
);
|
|
EXECUTE FORMAT (
|
|
'CREATE INDEX ' || table_name || '_by_expiration_index '
|
|
'ON ' || table_name || ' '
|
|
'(expiration_date'
|
|
',current_balance_val'
|
|
',current_balance_frac'
|
|
');'
|
|
);
|
|
EXECUTE FORMAT (
|
|
'COMMENT ON INDEX ' || table_name || '_by_expiration_index '
|
|
'IS ' || quote_literal('used in get_expired_reserves') || ';'
|
|
);
|
|
EXECUTE FORMAT (
|
|
'CREATE INDEX ' || table_name || '_by_reserve_uuid_index '
|
|
'ON ' || table_name || ' '
|
|
'(reserve_uuid);'
|
|
);
|
|
EXECUTE FORMAT (
|
|
'CREATE INDEX ' || table_name || '_by_gc_date_index '
|
|
'ON ' || table_name || ' '
|
|
'(gc_date);'
|
|
);
|
|
EXECUTE FORMAT (
|
|
'COMMENT ON INDEX ' || table_name || '_by_gc_date_index '
|
|
'IS ' || quote_literal('for reserve garbage collection') || ';'
|
|
);
|
|
END
|
|
$$;
|
|
|
|
|
|
INSERT INTO exchange_tables
|
|
(name
|
|
,version
|
|
,action
|
|
,partitioned
|
|
,by_range)
|
|
VALUES
|
|
('reserves'
|
|
,'exchange-0002'
|
|
,'create'
|
|
,TRUE
|
|
,FALSE),
|
|
('reserves'
|
|
,'exchange-0002'
|
|
,'constrain'
|
|
,TRUE
|
|
,FALSE);
|