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-wire_out.sql | 86 +++++++++++++++++++++++++++++++--------- 1 file changed, 68 insertions(+), 18 deletions(-) (limited to 'src/exchangedb/0002-wire_out.sql') diff --git a/src/exchangedb/0002-wire_out.sql b/src/exchangedb/0002-wire_out.sql index f34998b58..9c459fe95 100644 --- a/src/exchangedb/0002-wire_out.sql +++ b/src/exchangedb/0002-wire_out.sql @@ -14,8 +14,8 @@ -- TALER; see the file COPYING. If not, see -- -CREATE OR REPLACE FUNCTION create_table_wire_out( - IN shard_suffix VARCHAR DEFAULT NULL +CREATE FUNCTION create_table_wire_out( + IN partition_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql @@ -23,10 +23,9 @@ AS $$ DECLARE table_name VARCHAR DEFAULT 'wire_out'; BEGIN - PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' - '(wireout_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- PRIMARY KEY' + '(wireout_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' ',execution_date INT8 NOT NULL' ',wtid_raw BYTEA UNIQUE NOT NULL CHECK (LENGTH(wtid_raw)=32)' ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)' @@ -36,37 +35,78 @@ BEGIN ') %s ;' ,table_name ,'PARTITION BY HASH (wtid_raw)' - ,shard_suffix + ,partition_suffix ); - - table_name = concat_ws('_', table_name, shard_suffix); - - EXECUTE FORMAT ( - 'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_wire_target_h_payto_index ' - 'ON ' || table_name || ' ' - '(wire_target_h_payto);' + PERFORM comment_partitioned_table( + 'wire transfers the exchange has executed' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'identifies the configuration section with the debit account of this payment' + ,'exchange_account_section' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Identifies the credited bank account and KYC status' + ,'wire_target_h_payto' + ,table_name + ,partition_suffix ); - - END $$; -CREATE OR REPLACE FUNCTION add_constraints_to_wire_out_partition( + +CREATE FUNCTION constrain_table_wire_out( IN partition_suffix VARCHAR ) RETURNS void LANGUAGE plpgsql AS $$ +DECLARE + table_name VARCHAR DEFAULT 'wire_out'; BEGIN + table_name = concat_ws('_', table_name, partition_suffix); EXECUTE FORMAT ( - 'ALTER TABLE wire_out_' || partition_suffix || ' ' - 'ADD CONSTRAINT wire_out_' || partition_suffix || '_wireout_uuid_pkey ' - 'PRIMARY KEY (wireout_uuid)' + 'CREATE INDEX ' || table_name || '_by_wire_target_h_payto_index ' + 'ON ' || table_name || ' ' + '(wire_target_h_payto);' + ); + EXECUTE FORMAT ( + 'ALTER TABLE ' || table_name || + ' ADD CONSTRAINT ' || table_name || '_wireout_uuid_pkey' + ' PRIMARY KEY (wireout_uuid)' ); END $$; +CREATE FUNCTION wire_out_delete_trigger() + RETURNS trigger + LANGUAGE plpgsql + AS $$ +BEGIN + DELETE FROM exchange.aggregation_tracking + WHERE wtid_raw = OLD.wtid_raw; + RETURN OLD; +END $$; +COMMENT ON FUNCTION wire_out_delete_trigger() + IS 'Replicate reserve_out deletions into aggregation_tracking. This replaces an earlier use of an ON DELETE CASCADE that required a DEFERRABLE constraint and conflicted with nice partitioning.'; + + +CREATE FUNCTION master_table_wire_out() +RETURNS void +LANGUAGE plpgsql +AS $$ +BEGIN + CREATE TRIGGER wire_out_on_delete + AFTER DELETE + ON wire_out + FOR EACH ROW EXECUTE FUNCTION wire_out_delete_trigger(); +END $$; + + INSERT INTO exchange_tables (name ,version @@ -78,4 +118,14 @@ INSERT INTO exchange_tables ,'exchange-0002' ,'create' ,TRUE + ,FALSE), + ('wire_out' + ,'exchange-0002' + ,'constrain' + ,TRUE + ,FALSE), + ('wire_out' + ,'exchange-0002' + ,'master' + ,TRUE ,FALSE); -- cgit v1.2.3