summaryrefslogtreecommitdiff
path: root/src/exchangedb/0002-legitimization_processes.sql
blob: 3212b1c06dc42dfe173b4c783b87d6aba92fab7f (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
--
-- 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_legitimization_processes(
  IN shard_suffix TEXT DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
  PERFORM create_partitioned_table(
    'CREATE TABLE %I'
      '(legitimization_process_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
      ',h_payto BYTEA NOT NULL CHECK (LENGTH(h_payto)=32)'
      ',start_time INT8 NOT NULL'
      ',expiration_time INT8 NOT NULL DEFAULT (0)'
      ',provider_section TEXT NOT NULL'
      ',provider_user_id TEXT DEFAULT NULL'
      ',provider_legitimization_id TEXT DEFAULT NULL'
      ',redirect_url TEXT DEFAULT NULL'
      ',finished BOOLEAN DEFAULT (FALSE)'
    ') %s ;'
    ,'legitimization_processes'
    ,'PARTITION BY HASH (h_payto)'
    ,shard_suffix
  );
  PERFORM comment_partitioned_table(
    'List of legitimization processes (ongoing and completed) by account and provider'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'unique ID for this legitimization process at the exchange'
    ,'legitimization_process_serial_id'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'foreign key linking the entry to the wire_targets table, NOT a primary key (multiple legitimizations are possible per wire target)'
    ,'h_payto'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'time when the KYC check was initiated, useful for garbage collection'
    ,'expiration_time'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'URL where the user should go to begin the KYC process'
    ,'redirect_url'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'in the future if the respective KYC check was passed successfully'
    ,'expiration_time'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'Configuration file section with details about this provider'
    ,'provider_section'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'Identifier for the user at the provider that was used for the legitimization. NULL if provider is unaware.'
    ,'provider_user_id'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'Identifier for the specific legitimization process at the provider. NULL if legitimization was not started.'
    ,'provider_legitimization_id'
    ,'legitimization_processes'
    ,shard_suffix
  );
  PERFORM comment_partitioned_column(
     'Set to TRUE when the specific legitimization process is finished.'
    ,'finished'
    ,'legitimization_processes'
    ,shard_suffix
  );
END
$$;

-- We need a separate function for this, as we call create_table only once but need to add
-- those constraints to each partition which gets created
CREATE FUNCTION constrain_table_legitimization_processes(
  IN partition_suffix TEXT
)
RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
  partition_name TEXT;
BEGIN
  partition_name = concat_ws('_', 'legitimization_processes', partition_suffix);

  EXECUTE FORMAT (
    'ALTER TABLE ' || partition_name
    || ' '
      'ADD CONSTRAINT ' || partition_name || '_serial_key '
        'UNIQUE (legitimization_process_serial_id)');
  EXECUTE FORMAT (
    'CREATE INDEX IF NOT EXISTS ' || partition_name || '_by_provider_and_legi_index '
        'ON '|| partition_name || ' '
        '(provider_section,provider_legitimization_id)'
  );
  EXECUTE FORMAT (
    'COMMENT ON INDEX ' || partition_name || '_by_provider_and_legi_index '
    'IS ' || quote_literal('used (rarely) in kyc_provider_account_lookup') || ';'
  );
END
$$;


INSERT INTO exchange_tables
    (name
    ,version
    ,action
    ,partitioned
    ,by_range)
  VALUES
    ('legitimization_processes'
    ,'exchange-0002'
    ,'create'
    ,TRUE
    ,FALSE),
    ('legitimization_processes'
    ,'exchange-0002'
    ,'constrain'
    ,TRUE
    ,FALSE);