From 2eff222c524fa3b5ce2dd4a636aaec8dfb0862c7 Mon Sep 17 00:00:00 2001 From: Christian Grothoff Date: Sun, 27 Nov 2022 15:31:39 +0100 Subject: more work on SQL refactoring --- src/exchangedb/0002-purse_deposits.sql | 100 ++++++++++++++++++++++++++------- 1 file changed, 81 insertions(+), 19 deletions(-) (limited to 'src/exchangedb/0002-purse_deposits.sql') diff --git a/src/exchangedb/0002-purse_deposits.sql b/src/exchangedb/0002-purse_deposits.sql index 0e0c98072..25ccf1aa5 100644 --- a/src/exchangedb/0002-purse_deposits.sql +++ b/src/exchangedb/0002-purse_deposits.sql @@ -14,8 +14,8 @@ -- TALER; see the file COPYING. If not, see -- -CREATE OR REPLACE FUNCTION create_table_purse_deposits( - IN shard_suffix VARCHAR DEFAULT NULL +CREATE FUNCTION create_table_purse_deposits( + IN partition_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql @@ -23,13 +23,12 @@ AS $$ DECLARE table_name VARCHAR DEFAULT 'purse_deposits'; BEGIN - PERFORM create_partitioned_table( - 'CREATE TABLE IF NOT EXISTS %I ' - '(purse_deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE - ',partner_serial_id INT8' -- REFERENCES partners(partner_serial_id) ON DELETE CASCADE' + 'CREATE TABLE %I ' + '(purse_deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' + ',partner_serial_id INT8' ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)' - ',coin_pub BYTEA NOT NULL' -- REFERENCES known_coins (coin_pub) ON DELETE CASCADE' + ',coin_pub BYTEA NOT NULL' ',amount_with_fee_val INT8 NOT NULL' ',amount_with_fee_frac INT4 NOT NULL' ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)' @@ -37,32 +36,85 @@ BEGIN ') %s ;' ,table_name ,'PARTITION BY HASH (purse_pub)' - ,shard_suffix + ,partition_suffix + ); + PERFORM comment_partitioned_table( + 'Requests depositing coins into a purse' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'identifies the partner exchange, NULL in case the target purse lives at this exchange' + ,'partner_serial_id' + ,table_name + ,partition_suffix ); + PERFORM comment_partitioned_column( + 'Public key of the purse' + ,'purse_pub' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Public key of the coin being deposited' + ,'coin_pub' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Total amount being deposited' + ,'amount_with_fee_val' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Signature of the coin affirming the deposit into the purse, of type TALER_SIGNATURE_PURSE_DEPOSIT' + ,'coin_sig' + ,table_name + ,partition_suffix + ); +END +$$; - table_name = concat_ws('_', table_name, shard_suffix); + +CREATE FUNCTION constrain_table_purse_deposits( + IN partition_suffix VARCHAR +) +RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE + table_name VARCHAR DEFAULT 'purse_deposits'; +BEGIN + table_name = concat_ws('_', table_name, partition_suffix); -- FIXME: change to materialized index by coin_pub! EXECUTE FORMAT ( - 'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_coin_pub ' - 'ON ' || table_name || ' ' - '(coin_pub);' + 'CREATE INDEX ' || table_name || '_by_coin_pub' + ' ON ' || table_name || ' (coin_pub);' + ); + EXECUTE FORMAT ( + 'ALTER TABLE ' || table_name || + ' ADD CONSTRAINT ' || table_name || '_purse_deposit_serial_id_key' + ' UNIQUE (purse_deposit_serial_id) ' ); - END $$; -CREATE OR REPLACE FUNCTION add_constraints_to_purse_deposits_partition( - IN partition_suffix VARCHAR -) + +CREATE FUNCTION foreign_table_purse_deposits() RETURNS VOID LANGUAGE plpgsql AS $$ +DECLARE + table_name VARCHAR DEFAULT 'purse_deposits'; BEGIN EXECUTE FORMAT ( - 'ALTER TABLE purse_deposits_' || partition_suffix || ' ' - 'ADD CONSTRAINT purse_deposits_' || partition_suffix || '_purse_deposit_serial_id_key ' - 'UNIQUE (purse_deposit_serial_id) ' + 'ALTER TABLE ' || table_name || + ' ADD CONSTRAINT ' || table_name || '_foreign_partner' + ' REFERENCES partners(partner_serial_id) ON DELETE CASCADE' + ',ADD CONSTRAINT ' || table_name || '_foreign_coin_pub' + ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE' ); END $$; @@ -79,4 +131,14 @@ INSERT INTO exchange_tables ,'exchange-0002' ,'create' ,TRUE + ,FALSE), + ('purse-deposits' + ,'exchange-0002' + ,'constrain' + ,TRUE + ,FALSE), + ('purse-deposits' + ,'exchange-0002' + ,'foreign' + ,TRUE ,FALSE); -- cgit v1.2.3