exchange

Base system with REST service to issue digital coins, run by the payment service provider
Log | Files | Refs | Submodules | README | LICENSE

0002-reserves.sql (4311B)


      1 --
      2 -- This file is part of TALER
      3 -- Copyright (C) 2014--2022 Taler Systems SA
      4 --
      5 -- TALER is free software; you can redistribute it and/or modify it under the
      6 -- terms of the GNU General Public License as published by the Free Software
      7 -- Foundation; either version 3, or (at your option) any later version.
      8 --
      9 -- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
     10 -- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR
     11 -- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
     12 --
     13 -- You should have received a copy of the GNU General Public License along with
     14 -- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
     15 --
     16 
     17 CREATE FUNCTION create_table_reserves(
     18   IN partition_suffix TEXT DEFAULT NULL
     19 )
     20 RETURNS VOID
     21 LANGUAGE plpgsql
     22 AS $$
     23 DECLARE
     24   table_name TEXT DEFAULT 'reserves';
     25 BEGIN
     26   PERFORM create_partitioned_table(
     27     'CREATE TABLE %I'
     28       '(reserve_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
     29       ',reserve_pub BYTEA PRIMARY KEY CHECK(LENGTH(reserve_pub)=32)'
     30       ',current_balance taler_amount NOT NULL DEFAULT (0, 0)'
     31       ',purses_active INT8 NOT NULL DEFAULT(0)'
     32       ',purses_allowed INT8 NOT NULL DEFAULT(0)'
     33       ',birthday INT4 NOT NULL DEFAULT(0)'
     34       ',expiration_date INT8 NOT NULL'
     35       ',gc_date INT8 NOT NULL'
     36     ') %s ;'
     37     ,table_name
     38     ,'PARTITION BY HASH (reserve_pub)'
     39     ,partition_suffix
     40   );
     41   PERFORM comment_partitioned_table(
     42      'Summarizes the balance of a reserve. Updated when new funds are added or withdrawn.'
     43     ,table_name
     44     ,partition_suffix
     45   );
     46   PERFORM comment_partitioned_column(
     47      'EdDSA public key of the reserve. Knowledge of the private key implies ownership over the balance.'
     48     ,'reserve_pub'
     49     ,table_name
     50     ,partition_suffix
     51   );
     52   PERFORM comment_partitioned_column(
     53      'Current balance remaining with the reserve.'
     54     ,'current_balance'
     55     ,table_name
     56     ,partition_suffix
     57   );
     58   PERFORM comment_partitioned_column(
     59      'Number of purses that were created by this reserve that are not expired and not fully paid.'
     60     ,'purses_active'
     61     ,table_name
     62     ,partition_suffix
     63   );
     64   PERFORM comment_partitioned_column(
     65      'Number of purses that this reserve is allowed to have active at most.'
     66     ,'purses_allowed'
     67     ,table_name
     68     ,partition_suffix
     69   );
     70   PERFORM comment_partitioned_column(
     71      'Used to trigger closing of reserves that have not been drained after some time'
     72     ,'expiration_date'
     73     ,table_name
     74     ,partition_suffix
     75   );
     76   PERFORM comment_partitioned_column(
     77      'Used to forget all information about a reserve during garbage collection'
     78     ,'gc_date'
     79     ,table_name
     80     ,partition_suffix
     81   );
     82   PERFORM comment_partitioned_column(
     83      'Birthday of the user in days after 1970, or 0 if user is an adult and is not subject to age restrictions'
     84     ,'birthday'
     85     ,table_name
     86     ,partition_suffix
     87   );
     88 END
     89 $$;
     90 
     91 
     92 CREATE FUNCTION constrain_table_reserves(
     93   IN partition_suffix TEXT
     94 )
     95 RETURNS void
     96 LANGUAGE plpgsql
     97 AS $$
     98 DECLARE
     99   table_name TEXT DEFAULT 'reserves';
    100 BEGIN
    101   table_name = concat_ws('_', table_name, partition_suffix);
    102   EXECUTE FORMAT (
    103     'ALTER TABLE ' || table_name ||
    104     ' ADD CONSTRAINT ' || table_name || '_unique_uuid'
    105     ' UNIQUE (reserve_uuid)'
    106   );
    107   EXECUTE FORMAT (
    108     'CREATE INDEX ' || table_name || '_by_expiration_index '
    109     'ON ' || table_name || ' '
    110     '(expiration_date'
    111     ',current_balance'
    112     ');'
    113   );
    114   EXECUTE FORMAT (
    115     'COMMENT ON INDEX ' || table_name || '_by_expiration_index '
    116     'IS ' || quote_literal('used in get_expired_reserves') || ';'
    117   );
    118   EXECUTE FORMAT (
    119     'CREATE INDEX ' || table_name || '_by_reserve_uuid_index '
    120     'ON ' || table_name || ' '
    121     '(reserve_uuid);'
    122   );
    123   EXECUTE FORMAT (
    124     'CREATE INDEX ' || table_name || '_by_gc_date_index '
    125     'ON ' || table_name || ' '
    126     '(gc_date);'
    127   );
    128   EXECUTE FORMAT (
    129     'COMMENT ON INDEX ' || table_name || '_by_gc_date_index '
    130     'IS ' || quote_literal('for reserve garbage collection') || ';'
    131   );
    132 END
    133 $$;
    134 
    135 
    136 INSERT INTO exchange_tables
    137     (name
    138     ,version
    139     ,action
    140     ,partitioned
    141     ,by_range)
    142   VALUES
    143     ('reserves'
    144     ,'exchange-0002'
    145     ,'create'
    146     ,TRUE
    147     ,FALSE),
    148     ('reserves'
    149     ,'exchange-0002'
    150     ,'constrain'
    151     ,TRUE
    152     ,FALSE);