From a322770d290cae69e7d2f7629ee575e068254428 Mon Sep 17 00:00:00 2001 From: Christian Grothoff Date: Sun, 27 Nov 2022 14:05:47 +0100 Subject: more work on SQL refactoring --- src/exchangedb/0002-known_coins.sql | 87 +++++++++++++++++++++++++++++++------ 1 file changed, 74 insertions(+), 13 deletions(-) (limited to 'src/exchangedb/0002-known_coins.sql') diff --git a/src/exchangedb/0002-known_coins.sql b/src/exchangedb/0002-known_coins.sql index af2610c66..a45c7bc85 100644 --- a/src/exchangedb/0002-known_coins.sql +++ b/src/exchangedb/0002-known_coins.sql @@ -15,7 +15,7 @@ -- -CREATE OR REPLACE FUNCTION create_table_known_coins( +CREATE FUNCTION create_table_known_coins( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID @@ -24,11 +24,10 @@ AS $$ DECLARE table_name VARCHAR default 'known_coins'; BEGIN - PERFORM create_partitioned_table( - 'CREATE TABLE IF NOT EXISTS %I' - '(known_coin_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' - ',denominations_serial INT8 NOT NULL' -- REFERENCES denominations (denominations_serial) ON DELETE CASCADE' + 'CREATE TABLE %I' + '(known_coin_id BIGINT GENERATED BY DEFAULT AS IDENTITY' + ',denominations_serial INT8 NOT NULL' ',coin_pub BYTEA NOT NULL PRIMARY KEY CHECK (LENGTH(coin_pub)=32)' ',age_commitment_hash BYTEA CHECK (LENGTH(age_commitment_hash)=32)' ',denom_sig BYTEA NOT NULL' @@ -36,26 +35,78 @@ BEGIN ',remaining_frac INT4 NOT NULL DEFAULT(0)' ') %s ;' ,table_name - ,'PARTITION BY HASH (coin_pub)' -- FIXME: or include denominations_serial? or multi-level partitioning?; + ,'PARTITION BY HASH (coin_pub)' + ,shard_suffix + ); + PERFORM comment_partitioned_table( + 'information about coins and their signatures, so we do not have to store the signatures more than once if a coin is involved in multiple operations' + ,table_name + ,shard_suffix + ); + PERFORM comment_partitioned_column( + 'Denomination of the coin, determines the value of the original coin and applicable fees for coin-specific operations.' + ,'denominations_serial' + ,table_name + ,shard_suffix + ); + PERFORM comment_partitioned_column( + 'EdDSA public key of the coin' + ,'coin_pub' + ,table_name + ,shard_suffix + ); + PERFORM comment_partitioned_column( + 'Value of the coin that remains to be spent' + ,'remaining_val' + ,table_name + ,shard_suffix + ); + PERFORM comment_partitioned_column( + 'Optional hash of the age commitment for age restrictions as per DD 24 (active if denom_type has the respective bit set)' + ,'age_commitment_hash' + ,table_name + ,shard_suffix + ); + PERFORM comment_partitioned_column( + 'This is the signature of the exchange that affirms that the coin is a valid coin. The specific signature type depends on denom_type of the denomination.' + ,'denom_sig' + ,table_name ,shard_suffix ); - - table_name = concat_ws('_', table_name, shard_suffix); - END $$; -CREATE OR REPLACE FUNCTION add_constraints_to_known_coins_partition( + +CREATE FUNCTION constrain_table_known_coins( IN partition_suffix VARCHAR ) RETURNS void LANGUAGE plpgsql AS $$ +DECLARE + table_name VARCHAR default 'known_coins'; +BEGIN + table_name = concat_ws('_', table_name, shard_suffix); + EXECUTE FORMAT ( + 'ALTER TABLE ' || table_name || + ' ADD CONSTRAINT ' || table_name || '_known_coin_id_key' + ' UNIQUE (known_coin_id)' + ); +END +$$; + + +CREATE FUNCTION foreign_table_known_coins() +RETURNS void +LANGUAGE plpgsql +AS $$ +DECLARE + table_name VARCHAR default 'known_coins'; BEGIN EXECUTE FORMAT ( - 'ALTER TABLE known_coins_' || partition_suffix || ' ' - 'ADD CONSTRAINT known_coins_' || partition_suffix || '_known_coin_id_key ' - 'UNIQUE (known_coin_id)' + 'ALTER TABLE ' || table_name || + ' ADD CONSTRAINT ' || table_name || '_foreign_denominations' + ' REFERENCES denominations (denominations_serial) ON DELETE CASCADE' ); END $$; @@ -72,4 +123,14 @@ INSERT INTO exchange_tables ,'exchange-0002' ,'create' ,TRUE + ,FALSE), + ('known_coins' + ,'exchange-0002' + ,'constrain' + ,TRUE + ,FALSE), + ('known_coins' + ,'exchange-0002' + ,'foreign' + ,TRUE ,FALSE); -- cgit v1.2.3