exchange/src/exchangedb/exchange-0001.sql

315 lines
8.1 KiB
MySQL
Raw Normal View History

--
-- 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
---------------------------------------------------------------------------
2022-11-27 02:00:38 +01:00
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
2022-11-27 14:05:47 +01:00
IS 'Action to take on the table (e.g. create, alter, constrain, foreign, or drop). Create, alter and drop are done for master and each partition; constrain is only for partitions or for master if there are no partitions; master only on master (takes no argument); 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';
2022-11-27 02:00:38 +01:00
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
);
2022-11-27 02:00:38 +01:00
END
$$;
2022-11-27 02:00:38 +01:00
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
$$;
2022-11-27 14:05:47 +01:00
COMMENT ON FUNCTION comment_partitioned_table
2022-11-27 02:00:38 +01:00
IS 'Generic function to create a comment on table that is partitioned.';
2022-11-27 02:00:38 +01:00
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
$$;
2022-11-27 14:05:47 +01:00
COMMENT ON FUNCTION comment_partitioned_column
2022-11-27 02:00:38 +01:00
IS 'Generic function to create a comment on column of a table that is partitioned.';
2022-11-27 02:00:38 +01:00
CREATE FUNCTION create_tables(
num_partitions INTEGER
2022-11-27 02:00:38 +01:00
-- 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
2022-11-27 14:05:47 +01:00
-- FIXME: use only ONE cursor and then switch on action!
tc CURSOR FOR
SELECT table_serial_id
,name
,action
,by_range
FROM exchange_tables
WHERE NOT finished
2022-11-27 02:00:38 +01:00
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;
2022-11-27 14:05:47 +01:00
DECLARE
tm CURSOR FOR
SELECT table_serial_id
,name
,action
,by_range
FROM exchange_tables
WHERE NOT finished
AND partitioned
AND action='master'
ORDER BY table_serial_id ASC;
BEGIN
2022-11-27 02:00:38 +01:00
-- 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
2022-11-27 02:00:38 +01:00
-- No partitions at all.
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,NULL
);
ELSE
2022-11-27 02:00:38 +01:00
-- One default partition only.
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,0
);
2022-11-27 02:00:38 +01:00
IF NOT IS NULL num_partitions
THEN
2022-11-27 02:00:38 +01:00
IF rec.by_range
THEN
-- range partitions (only create default)
-- Create default partition.
EXECUTE FORMAT(
2022-11-27 02:00:38 +01:00
'CREATE TABLE %s_default PARTITION OF %s DEFAULT'
,rec.name
,rec.name
);
2022-11-27 02:00:38 +01:00
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
2022-11-27 02:00:38 +01:00
-- Run constrain actions
FOR rec IN ta
LOOP
IF IS NULL num_partitions
THEN
2022-11-27 02:00:38 +01:00
-- Constrain master
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,NULL
);
END IF
2022-11-27 02:00:38 +01:00
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;
2022-11-27 02:00:38 +01:00
-- run foreign actions
FOR rec IN tf
LOOP
2022-11-27 02:00:38 +01:00
IF IS NULL num_partitions
THEN
-- Add foreign constraints
EXECUTE FORMAT(
2022-11-27 14:05:47 +01:00
'PERFORM %s_table_%s ()'::text
2022-11-27 02:00:38 +01:00
,rec.action
,rec.name
);
END IF
UPDATE exchange_tables
SET finished=TRUE
WHERE table_serial_id=rec.table_serial_id;
END LOOP;
END
$$;
2022-11-27 02:00:38 +01:00
COMMENT ON FUNCTION create_tables
IS 'Creates all tables for the given number of partitions that need creating.';