aboutsummaryrefslogtreecommitdiff
path: root/src/exchangedb/exchange-0001.sql
blob: f7bf15f6ae512b5787b217e2c07deb7816ae5078 (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
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
--
-- 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/>
--

-- Everything in one big transaction
BEGIN;

SET search_path TO exchange;

---------------------------------------------------------------------------
--                   General procedures for DB setup
---------------------------------------------------------------------------

CREATE TABLE exchange_tables
  (table_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY
  ,name VARCHAR NOT NULL
  ,version VARCHAR NOT NULL
  ,action VARCHAR NOT NULL
  ,partitioned BOOL NOT NULL
  ,by_range BOOL NOT NULL
  ,finished BOOL NOT NULL DEFAULT(FALSE));
COMMENT ON TABLE exchange_tables
  IS 'Tables of the exchange and their status';
COMMENT ON COLUMN exchange_tables.name
  IS 'Base name of the table (without partition/shard)';
COMMENT ON COLUMN exchange_tables.version
  IS 'Version of the DB in which the given action happened';
COMMENT ON COLUMN exchange_tables.action
  IS 'Action to take on the table (e.g. create, alter, constrain, foreign, or drop). Create, alter and drop are done for master and partitions; constrain is only for partitions or for master if there are no partitions; foreign only on master if there are no partitions.';
COMMENT ON COLUMN exchange_tables.partitioned
  IS 'TRUE if the table is partitioned';
COMMENT ON COLUMN exchange_tables.by_range
  IS 'TRUE if the table is partitioned by range';
COMMENT ON COLUMN exchange_tables.finished
  IS 'TRUE if the respective migration has been run';


CREATE FUNCTION create_partitioned_table(
   IN table_definition VARCHAR
  ,IN table_name VARCHAR
  ,IN main_table_partition_str VARCHAR -- Used only when it is the main table - we do not partition shard tables
  ,IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
  IF shard_suffix IS NOT NULL THEN
    table_name=table_name || '_' || shard_suffix;
    main_table_partition_str = '';
  END IF;
  EXECUTE FORMAT(
    table_definition,
    table_name,
    main_table_partition_str
  );
END
$$;

COMMENT ON FUNCTION create_partitioned_table
  IS 'Generic function to create a table that is partitioned.';


CREATE FUNCTION comment_partitioned_table(
   IN table_comment VARCHAR
  ,IN table_name VARCHAR
  ,IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
  IF shard_suffix IS NOT NULL THEN
    table_name=table_name || '_' || shard_suffix;
    main_table_partition_str = '';
  END IF;
  EXECUTE FORMAT(
     COMMENT ON TABLE %s IS '%s'
    ,table_name
    ,table_comment
  );
END
$$;

COMMENT ON FUNCTION create_partitioned_table
  IS 'Generic function to create a comment on table that is partitioned.';


CREATE FUNCTION comment_partitioned_column(
   IN table_comment VARCHAR
  ,IN column_name VARCHAR
  ,IN table_name VARCHAR
  ,IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
  IF shard_suffix IS NOT NULL THEN
    table_name=table_name || '_' || shard_suffix;
    main_table_partition_str = '';
  END IF;
  EXECUTE FORMAT(
     COMMENT ON COLUMN %s.%s IS '%s'
    ,table_name
    ,column_name
    ,table_comment
  );
END
$$;

COMMENT ON FUNCTION create_partitioned_table
  IS 'Generic function to create a comment on column of a table that is partitioned.';




CREATE FUNCTION create_tables(
  num_partitions INTEGER
-- FIXME: not implemented like this, but likely good:
-- NULL: no partitions, add foreign constraints
-- 0: no partitions, no foreign constraints
-- 1: only 1 default partition
-- > 1: normal partitions
)
  RETURNS VOID
  LANGUAGE plpgsql
AS $$
DECLARE
  tc CURSOR FOR
    SELECT table_serial_id
          ,name
          ,action
          ,by_range
      FROM exchange_tables
     WHERE NOT finished
       AND partitioned
       AND (action='create'
         OR action='alter'
         OR action='drop')
     ORDER BY table_serial_id ASC;
DECLARE
  ta CURSOR FOR
    SELECT table_serial_id
          ,name
          ,action
          ,by_range
      FROM exchange_tables
     WHERE NOT finished
       AND partitioned
       AND action='constrain'
     ORDER BY table_serial_id ASC;
DECLARE
  tf CURSOR FOR
    SELECT table_serial_id
          ,name
          ,action
          ,by_range
      FROM exchange_tables
     WHERE NOT finished
       AND partitioned
       AND action='foreign'
     ORDER BY table_serial_id ASC;
BEGIN

  -- run create/alter/drop actions
  FOR rec IN tc
  LOOP
    -- First create the master table, either
    -- completely unpartitioned, or with one
    -- master and the 'default' partition
    IF IS NULL num_partitions
    THEN
      -- No partitions at all.
      EXECUTE FORMAT(
        'PERFORM %s_table_%s (%s)'::text
        ,rec.action
        ,rec.name
        ,NULL
      );
    ELSE
      -- One default partition only.
      EXECUTE FORMAT(
        'PERFORM %s_table_%s (%s)'::text
        ,rec.action
        ,rec.name
        ,0
      );

    IF NOT IS NULL num_partitions
    THEN
      IF rec.by_range
      THEN
        -- range partitions (only create default)
        -- Create default partition.
        EXECUTE FORMAT(
           'CREATE TABLE %s_default PARTITION OF %s DEFAULT'
          ,rec.name
          ,rec.name
        );
      ELSE
        -- hash partitions
        IF 0=num_partitions
        THEN
          -- Create default partition.
          EXECUTE FORMAT(
             'CREATE TABLE IF NOT EXISTS %s_default PARTITION OF %s FOR VALUES WITH (MODULUS 1, REMAINDER 0)'
            ,rec.name
            ,rec.name
          );
        END IF
        FOR i IN 1..num_partitions LOOP
          -- Create num_partitions
          EXECUTE FORMAT(
             'CREATE TABLE IF NOT EXISTS %I'
             ' PARTITION OF %I'
             ' FOR VALUES WITH (MODULUS %s, REMAINDER %s)'
            ,rec.name || '_' || i
            ,rec.name
            ,num_partitions
            ,i-1
          );
        END LOOP;
      END IF;
    END IF;
    UPDATE exchange_tables
       SET finished=TRUE
     WHERE table_serial_id=rec.table_serial_id;
  END LOOP; -- create/alter/drop actions

  -- Run constrain actions
  FOR rec IN ta
  LOOP
    IF IS NULL num_partitions
    THEN
      -- Constrain master
      EXECUTE FORMAT(
        'PERFORM %s_table_%s (%s)'::text
        ,rec.action
        ,rec.name
        ,NULL
      );
    END IF

    IF 0=num_partitions
    THEN
      -- constrain default partition
      EXECUTE FORMAT(
        'PERFORM %s_table_%s (%s)'::text
        ,rec.action
        ,rec.name
        ,0
      );
    END IF
    FOR i IN 1..num_partitions LOOP
      -- constrain each partition
      EXECUTE FORMAT(
        'PERFORM %s_table_%s (%s)'::text
        ,rec.action
        ,rec.name
        ,i::varchar
      );
    END LOOP;
    UPDATE exchange_tables
       SET finished=TRUE
     WHERE table_serial_id=rec.table_serial_id;
  END LOOP;

  -- run foreign actions
  FOR rec IN tf
  LOOP
    IF IS NULL num_partitions
    THEN
      -- Add foreign constraints
      EXECUTE FORMAT(
        'PERFORM %s_table_%s (%s)'::text
        ,rec.action
        ,rec.name
        ,NULL
      );
    END IF
    UPDATE exchange_tables
       SET finished=TRUE
     WHERE table_serial_id=rec.table_serial_id;
  END LOOP;

END
$$;

COMMENT ON FUNCTION create_tables
  IS 'Creates all tables for the given number of partitions that need creating.';