exchange/src/exchangedb/exchange-0001.sql

299 lines
8.4 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/>
--
BEGIN;
2022-11-27 18:40:44 +01:00
SELECT _v.register_patch('exchange-0001', NULL, NULL);
CREATE SCHEMA exchange;
COMMENT ON SCHEMA exchange IS 'taler-exchange data';
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 18:40:44 +01:00
IS 'Action to take on the table (e.g. create, constrain, foreign, or drop). Create is done for the master table 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(
2022-11-27 18:40:44 +01:00
IN table_definition VARCHAR -- SQL template for table creation
,IN table_name VARCHAR -- base name of the table
,IN main_table_partition_str VARCHAR -- declaration for how to partition the table
,IN partition_suffix VARCHAR DEFAULT NULL -- NULL: no partitioning, 0: yes partitioning, no sharding, >0: sharding
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
2022-11-27 18:40:44 +01:00
IF partition_suffix IS NULL
THEN
-- no partitioning, disable option
main_table_partition_str = '';
2022-11-27 18:40:44 +01:00
ELSE
IF partition_suffix > 0
THEN
-- sharding, add shard name
table_name=table_name || '_' || partition_suffix;
END IF;
END IF;
EXECUTE FORMAT(
table_definition,
table_name,
main_table_partition_str
);
2022-11-27 18:40:44 +01:00
END $$;
2022-11-27 02:00:38 +01:00
COMMENT ON FUNCTION create_partitioned_table
2022-11-27 18:40:44 +01:00
IS 'Generic function to create a table that is partitioned or sharded.';
2022-11-27 02:00:38 +01:00
CREATE FUNCTION comment_partitioned_table(
IN table_comment VARCHAR
,IN table_name VARCHAR
2022-11-27 18:40:44 +01:00
,IN partition_suffix VARCHAR DEFAULT NULL
2022-11-27 02:00:38 +01:00
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
2022-11-27 18:40:44 +01:00
IF ( (partition_suffix IS NOT NULL) AND
(partition_suffix > 0) )
THEN
-- sharding, add shard name
table_name=table_name || '_' || partition_suffix;
2022-11-27 02:00:38 +01:00
END IF;
EXECUTE FORMAT(
2022-11-27 18:40:44 +01:00
'COMMENT ON TABLE %s IS %s'
2022-11-27 02:00:38 +01:00
,table_name
2022-11-27 18:40:44 +01:00
,quote_literal(table_comment)
2022-11-27 02:00:38 +01:00
);
2022-11-27 18:40:44 +01:00
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
2022-11-27 18:40:44 +01:00
,IN partition_suffix VARCHAR DEFAULT NULL
2022-11-27 02:00:38 +01:00
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
2022-11-27 18:40:44 +01:00
IF ( (partition_suffix IS NOT NULL) AND
(partition_suffix > 0) )
THEN
-- sharding, add shard name
table_name=table_name || '_' || partition_suffix;
2022-11-27 02:00:38 +01:00
END IF;
EXECUTE FORMAT(
2022-11-27 18:40:44 +01:00
'COMMENT ON COLUMN %s.%s IS %s'
2022-11-27 02:00:38 +01:00
,table_name
,column_name
2022-11-27 18:40:44 +01:00
,quote_literal(table_comment)
2022-11-27 02:00:38 +01:00
);
2022-11-27 18:40:44 +01:00
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
2022-11-27 18:40:44 +01:00
---------------------------------------------------------------------------
-- Main DB setup loop
---------------------------------------------------------------------------
2022-11-27 02:00:38 +01:00
CREATE FUNCTION create_tables(
num_partitions INTEGER
2022-11-27 02:00:38 +01:00
-- 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
2022-11-27 18:40:44 +01:00
,partitioned
,by_range
FROM exchange_tables
WHERE NOT finished
2022-11-27 14:05:47 +01:00
ORDER BY table_serial_id ASC;
BEGIN
FOR rec IN tc
LOOP
2022-11-27 18:40:44 +01:00
CASE rec.action
-- "create" actions apply to master and partitions
WHEN "create"
THEN
2022-11-27 18:40:44 +01:00
IF (rec.partitioned AND
(num_partitions IS NOT NULL))
2022-11-27 02:00:38 +01:00
THEN
2022-11-27 18:40:44 +01:00
-- Create master table with partitioning.
EXECUTE FORMAT(
2022-11-27 18:40:44 +01:00
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
2022-11-27 18:40:44 +01:00
,0
);
IF (rec.by_range OR
(num_partitions = 0))
THEN
-- Create default partition.
IF (rec.by_range)
THEN
-- Range partition
EXECUTE FORMAT(
'CREATE TABLE IF NOT EXISTS %s_default'
' PARTITION OF %s'
' FOR DEFAULT'
,rec.name
,rec.name
);
ELSE
-- Hash 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;
ELSE
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;
ELSE
-- Only create master table. No partitions.
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,NULL
);
END IF;
-- Constrain action apply to master OR each partition
WHEN "constrain"
THEN
ASSERT rec.partitioned, 'constrain action only applies to partitioned tables';
IF (num_partitions IS NULL)
THEN
-- Constrain master table
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
2022-11-27 18:40:44 +01:00
,NULL
);
2022-11-27 02:00:38 +01:00
ELSE
2022-11-27 18:40:44 +01:00
IF (num_partitions = 0)
2022-11-27 02:00:38 +01:00
THEN
2022-11-27 18:40:44 +01:00
-- Constrain default table
2022-11-27 02:00:38 +01:00
EXECUTE FORMAT(
2022-11-27 18:40:44 +01:00
'PERFORM %s_table_%s (%s)'::text
,rec.action
2022-11-27 02:00:38 +01:00
,rec.name
2022-11-27 18:40:44 +01:00
,'default'
2022-11-27 02:00:38 +01:00
);
2022-11-27 18:40:44 +01:00
ELSE
-- Constrain each partition
FOR i IN 1..num_partitions LOOP
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,i
);
END LOOP;
END IF;
2022-11-27 02:00:38 +01:00
END IF;
2022-11-27 18:40:44 +01:00
-- Foreign actions only apply if partitioning is off
WHEN "foreign"
THEN
2022-11-27 18:40:44 +01:00
IF (num_partitions IS NULL)
THEN
-- Only create master table. No partitions.
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,NULL
);
END IF;
WHEN "master"
2022-11-27 02:00:38 +01:00
THEN
EXECUTE FORMAT(
2022-11-27 18:40:44 +01:00
'PERFORM %s_table_%s'::text
2022-11-27 02:00:38 +01:00
,rec.action
,rec.name
);
2022-11-27 18:40:44 +01:00
ELSE
ASSERT FALSE, 'unsupported action type: ' || rec.action;
END CASE; -- END CASE (rec.action)
-- Mark as finished
UPDATE exchange_tables
SET finished=TRUE
WHERE table_serial_id=rec.table_serial_id;
2022-11-27 18:40:44 +01:00
END LOOP; -- create/alter/drop actions
END $$;
2022-11-27 18:40:44 +01:00
COMMENT ON FUNCTION create_tables
IS 'Creates all tables for the given number of partitions that need creating. Does NOT support sharding.';
2022-11-27 18:40:44 +01:00
COMMIT;