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-refresh_commitments.sql | 79 +++++++++++++++++++++++------ 1 file changed, 64 insertions(+), 15 deletions(-) (limited to 'src/exchangedb/0002-refresh_commitments.sql') diff --git a/src/exchangedb/0002-refresh_commitments.sql b/src/exchangedb/0002-refresh_commitments.sql index ce6077c5c..c3d5cfdef 100644 --- a/src/exchangedb/0002-refresh_commitments.sql +++ b/src/exchangedb/0002-refresh_commitments.sql @@ -14,8 +14,8 @@ -- TALER; see the file COPYING. If not, see -- -CREATE OR REPLACE FUNCTION create_table_refresh_commitments( - IN shard_suffix VARCHAR DEFAULT NULL +CREATE FUNCTION create_table_refresh_commitments( + IN partition_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql @@ -23,12 +23,11 @@ AS $$ DECLARE table_name VARCHAR DEFAULT 'refresh_commitments'; BEGIN - PERFORM create_partitioned_table( - 'CREATE TABLE IF NOT EXISTS %I' + 'CREATE TABLE %I' '(melt_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',rc BYTEA PRIMARY KEY CHECK (LENGTH(rc)=64)' - ',old_coin_pub BYTEA NOT NULL' -- REFERENCES known_coins (coin_pub) ON DELETE CASCADE' + ',old_coin_pub BYTEA NOT NULL' ',old_coin_sig BYTEA NOT NULL CHECK(LENGTH(old_coin_sig)=64)' ',amount_with_fee_val INT8 NOT NULL' ',amount_with_fee_frac INT4 NOT NULL' @@ -36,32 +35,72 @@ BEGIN ') %s ;' ,table_name ,'PARTITION BY HASH (rc)' - ,shard_suffix + ,partition_suffix + ); + PERFORM comment_partitioned_table( + 'Commitments made when melting coins and the gamma value chosen by the exchange.' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'The gamma value chosen by the exchange in the cut-and-choose protocol' + ,'noreveal_index' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Commitment made by the client, hash over the various client inputs in the cut-and-choose protocol' + ,'rc' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Coin being melted in the refresh process.' + ,'old_coin_pub' + ,table_name + ,partition_suffix ); +END +$$; - table_name = concat_ws('_', table_name, shard_suffix); + +CREATE FUNCTION constrain_table_refresh_commitments( + IN partition_suffix VARCHAR +) +RETURNS void +LANGUAGE plpgsql +AS $$ +DECLARE + table_name VARCHAR DEFAULT 'refresh_commitments'; +BEGIN + table_name = concat_ws('_', table_name, partition_suffix); -- Note: index spans partitions, may need to be materialized. EXECUTE FORMAT ( - 'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_old_coin_pub_index ' + 'CREATE INDEX ' || table_name || '_by_old_coin_pub_index ' 'ON ' || table_name || ' ' '(old_coin_pub);' ); - + EXECUTE FORMAT ( + 'ALTER TABLE ' || table_name || + ' ADD CONSTRAINT ' || table_name || '_melt_serial_id_key' + ' UNIQUE (melt_serial_id)' + ); END $$; -CREATE OR REPLACE FUNCTION add_constraints_to_refresh_commitments_partition( - IN partition_suffix VARCHAR -) + +CREATE FUNCTION foreign_table_refresh_commitments() RETURNS void LANGUAGE plpgsql AS $$ +DECLARE + table_name VARCHAR DEFAULT 'refresh_commitments'; BEGIN EXECUTE FORMAT ( - 'ALTER TABLE refresh_commitments_' || partition_suffix || ' ' - 'ADD CONSTRAINT refresh_commitments_' || partition_suffix || '_melt_serial_id_key ' - 'UNIQUE (melt_serial_id)' + 'ALTER TABLE ' || table_name || + ' ADD CONSTRAINT ' || table_name || '_foreign_coin_pub' + ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE' ); END $$; @@ -78,4 +117,14 @@ INSERT INTO exchange_tables ,'exchange-0002' ,'create' ,TRUE + ,FALSE), + ('refresh_commitments' + ,'exchange-0002' + ,'constrain' + ,TRUE + ,FALSE), + ('refresh_commitments' + ,'exchange-0002' + ,'foreign' + ,TRUE ,FALSE); -- cgit v1.2.3