-- -- 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 -- -- Everything in one big transaction BEGIN; -- Check patch versioning is in place. SELECT _v.register_patch('exchange-0001', NULL, NULL); CREATE OR REPLACE FUNCTION create_partitioned_table( IN table_definition VARCHAR ,IN table_name VARCHAR ,IN main_table_partition_str VARCHAR ,IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN IF shard_suffix IS NOT NULL THEN table_name=table_name || '_' || shard_suffix; main_table_partition_str = ''; END IF; EXECUTE FORMAT( table_definition, table_name, main_table_partition_str ); END $$; COMMENT ON FUNCTION create_partitioned_table IS 'Create a table which may be partitioned. If shard_suffix is null, it is assumed that the table is a main table. Which means that it will be partitioned by main_table_partition_str. If it is not null a table named `table_name_shard_suffix` (not partitioned) will be created. The table must include `%I` as placeholder for the table name, and `%s ;` as placeholder for the partitioning method'; CREATE OR REPLACE FUNCTION create_table_denominations() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS denominations (denominations_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,denom_pub_hash BYTEA PRIMARY KEY CHECK (LENGTH(denom_pub_hash)=64) ,denom_type INT4 NOT NULL DEFAULT (1) -- 1 == RSA (for now, remove default later!) ,age_mask INT4 NOT NULL DEFAULT (0) ,denom_pub BYTEA NOT NULL ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64) ,valid_from INT8 NOT NULL ,expire_withdraw INT8 NOT NULL ,expire_deposit INT8 NOT NULL ,expire_legal INT8 NOT NULL ,coin_val INT8 NOT NULL ,coin_frac INT4 NOT NULL ,fee_withdraw_val INT8 NOT NULL ,fee_withdraw_frac INT4 NOT NULL ,fee_deposit_val INT8 NOT NULL ,fee_deposit_frac INT4 NOT NULL ,fee_refresh_val INT8 NOT NULL ,fee_refresh_frac INT4 NOT NULL ,fee_refund_val INT8 NOT NULL ,fee_refund_frac INT4 NOT NULL ); END $$; CREATE OR REPLACE FUNCTION create_table_denominations_revocations() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS denomination_revocations (denom_revocations_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,denominations_serial INT8 PRIMARY KEY REFERENCES denominations (denominations_serial) ON DELETE CASCADE ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64) ); END $$; CREATE OR REPLACE FUNCTION create_table_wire_targets( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(wire_target_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',h_payto BYTEA PRIMARY KEY CHECK (LENGTH(h_payto)=64)' ',payto_uri VARCHAR NOT NULL' ',kyc_ok BOOLEAN NOT NULL DEFAULT (FALSE)' ',external_id VARCHAR' ') %s ;' ,'wire_targets' ,'PARTITION BY HASH (h_payto)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS wire_targets ADD CONSTRAINT wire_targets_wire_target_serial_id_key UNIQUE (wire_target_serial_id) ; END IF; END $$; COMMENT ON FUNCTION create_table_wire_targets IS 'Create the wire_targets table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_reserves( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(reserve_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' ',reserve_pub BYTEA PRIMARY KEY CHECK(LENGTH(reserve_pub)=32)' ',current_balance_val INT8 NOT NULL' ',current_balance_frac INT4 NOT NULL' ',expiration_date INT8 NOT NULL' ',gc_date INT8 NOT NULL' ') %s ;' ,'reserves' ,'PARTITION BY HASH (reserve_pub)' ,shard_suffix ); END $$; COMMENT ON FUNCTION create_table_reserves IS 'Create the reserves table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_reserves_in( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(reserve_in_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',reserve_pub BYTEA PRIMARY KEY' -- REFERENCES reserves (reserve_pub) ON DELETE CASCADE' ',wire_reference INT8 NOT NULL' ',credit_val INT8 NOT NULL' ',credit_frac INT4 NOT NULL' ',wire_source_serial_id INT8 NOT NULL' -- REFERENCES wire_targets (wire_target_serial_id)' ',exchange_account_section TEXT NOT NULL' ',execution_date INT8 NOT NULL' ') %s ;' ,'reserves_in' ,'PARTITION BY HASH (reserve_pub)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS reserves_in ADD CONSTRAINT reserves_in_reserve_serial_id_key UNIQUE (reserve_in_serial_id) ; ELSE ALTER TABLE IF EXISTS reserves_in ADD CONSTRAINT reserves_in_reserve_pub_fkey FOREIGN KEY (reserve_pub) REFERENCES reserves (reserve_pub) ON DELETE CASCADE ; END IF; END $$; COMMENT ON FUNCTION create_table_reserves_in IS 'Create the reserves_in table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_reserves_close( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(close_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE / PRIMARY KEY' ',reserve_pub BYTEA NOT NULL' -- REFERENCES reserves (reserve_pub) ON DELETE CASCADE' ',execution_date INT8 NOT NULL' ',wtid BYTEA NOT NULL CHECK (LENGTH(wtid)=32)' ',wire_target_serial_id INT8 NOT NULL' -- REFERENCES wire_targets (wire_target_serial_id)' ',amount_val INT8 NOT NULL' ',amount_frac INT4 NOT NULL' ',closing_fee_val INT8 NOT NULL' ',closing_fee_frac INT4 NOT NULL' ') %s ;' ,'reserves_close' ,'PARTITION BY HASH (reserve_pub)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS reserves_close ADD CONSTRAINT reserves_close_close_uuid_pkey PRIMARY KEY (close_uuid) ; ELSE ALTER TABLE IF EXISTS reserves_close ADD CONSTRAINT reserves_close_reserve_pub_fkey FOREIGN KEY (reserve_pub) REFERENCES reserves (reserve_pub) ON DELETE CASCADE ; END IF; END $$; COMMENT ON FUNCTION create_table_reserves_close IS 'Create the reserves_close table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_reserves_out( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(reserve_out_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',h_blind_ev BYTEA CHECK (LENGTH(h_blind_ev)=64) UNIQUE' ',denominations_serial INT8 NOT NULL' -- REFERENCES denominations (denominations_serial)' ',denom_sig BYTEA NOT NULL' ',reserve_uuid INT8 NOT NULL' -- REFERENCES reserves (reserve_uuid) ON DELETE CASCADE' ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)' ',execution_date INT8 NOT NULL' ',amount_with_fee_val INT8 NOT NULL' ',amount_with_fee_frac INT4 NOT NULL' ') %s ;' ,'reserves_out' ,'PARTITION BY HASH (h_blind_ev)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS reserves_out ADD CONSTRAINT reserves_out_reserve_out_serial_id_key UNIQUE (reserve_out_serial_id) ; ELSE -- FIXME once denominations are replicated we can safely add the fkey on table creation ALTER TABLE IF EXISTS reserves_out ADD CONSTRAINT reserves_out_denominations_serial_fkey FOREIGN KEY (denominations_serial) REFERENCES denominations (denominations_serial) ; END IF; END $$; COMMENT ON FUNCTION create_table_reserves_out IS 'Create the reserves_out table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_auditors() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS auditors (auditor_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,auditor_pub BYTEA PRIMARY KEY CHECK (LENGTH(auditor_pub)=32) ,auditor_name VARCHAR NOT NULL ,auditor_url VARCHAR NOT NULL ,is_active BOOLEAN NOT NULL ,last_change INT8 NOT NULL ); END $$; CREATE OR REPLACE FUNCTION create_table_auditor_denom_sigs() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS auditor_denom_sigs (auditor_denom_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,auditor_uuid INT8 NOT NULL REFERENCES auditors (auditor_uuid) ON DELETE CASCADE ,denominations_serial INT8 NOT NULL REFERENCES denominations (denominations_serial) ON DELETE CASCADE ,auditor_sig BYTEA CHECK (LENGTH(auditor_sig)=64) ,PRIMARY KEY (denominations_serial, auditor_uuid) ); END $$; CREATE OR REPLACE FUNCTION create_table_exchange_sign_keys() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS exchange_sign_keys (esk_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,exchange_pub BYTEA PRIMARY KEY CHECK (LENGTH(exchange_pub)=32) ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64) ,valid_from INT8 NOT NULL ,expire_sign INT8 NOT NULL ,expire_legal INT8 NOT NULL ); END $$; CREATE OR REPLACE FUNCTION create_table_signkey_revocations() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS signkey_revocations (signkey_revocations_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,esk_serial INT8 PRIMARY KEY REFERENCES exchange_sign_keys (esk_serial) ON DELETE CASCADE ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64) ); END $$; CREATE OR REPLACE FUNCTION create_table_extensions() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS extensions (extension_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,name VARCHAR NOT NULL UNIQUE ,config BYTEA ); END $$; CREATE OR REPLACE FUNCTION create_table_known_coins( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ 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' ',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' ',remaining_val INT8 NOT NULL' ',remaining_frac INT4 NOT NULL' ') %s ;' ,'known_coins' ,'PARTITION BY HASH (coin_pub)' -- FIXME: or include denominations_serial? or multi-level partitioning?; ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS known_coins ADD CONSTRAINT known_coins_known_coin_id_key UNIQUE (known_coin_id) ; ELSE -- FIXME once denominations are replicated we can safely add the fkey on table creation ALTER TABLE IF EXISTS known_coins ADD CONSTRAINT known_coins_denominations_serial_fkey FOREIGN KEY (denominations_serial) REFERENCES denominations (denominations_serial) ON DELETE CASCADE ; END IF; END $$; COMMENT ON FUNCTION create_table_known_coins IS 'Create the known_coins table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_refresh_commitments( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %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' ',h_age_commitment BYTEA CHECK(LENGTH(h_age_commitment)=32)' ',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' ',noreveal_index INT4 NOT NULL' ') %s ;' ,'refresh_commitments' ,'PARTITION BY HASH (rc)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS refresh_commitments ADD CONSTRAINT refresh_commitments_melt_serial_id_key UNIQUE (melt_serial_id) ; ELSE ALTER TABLE IF EXISTS refresh_commitments ADD CONSTRAINT refresh_commitments_old_coin_pub_fkey FOREIGN KEY (old_coin_pub) REFERENCES known_coins (coin_pub) ON DELETE CASCADE ; END IF; END $$; COMMENT ON FUNCTION create_table_refresh_commitments IS 'Create the refresh_commitments table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_refresh_revealed_coins( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(rrc_serial BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',melt_serial_id INT8 NOT NULL' -- REFERENCES refresh_commitments (melt_serial_id) ON DELETE CASCADE' ',freshcoin_index INT4 NOT NULL' ',link_sig BYTEA NOT NULL CHECK(LENGTH(link_sig)=64)' ',denominations_serial INT8 NOT NULL' -- REFERENCES denominations (denominations_serial) ON DELETE CASCADE' ',coin_ev BYTEA NOT NULL' -- UNIQUE' ',h_coin_ev BYTEA NOT NULL CHECK(LENGTH(h_coin_ev)=64)' -- UNIQUE' ',ev_sig BYTEA NOT NULL' ',ewv BYTEA NOT NULL' -- ,PRIMARY KEY (melt_serial_id, freshcoin_index) -- done per shard ') %s ;' ,'refresh_revealed_coins' ,'PARTITION BY HASH (melt_serial_id)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS refresh_revealed_coins ADD CONSTRAINT refresh_revealed_coins_rrc_serial_key UNIQUE (rrc_serial) ,ADD CONSTRAINT refresh_revealed_coins_coin_ev_key UNIQUE (coin_ev) ,ADD CONSTRAINT refresh_revealed_coins_h_coin_ev_key UNIQUE (h_coin_ev) ,ADD CONSTRAINT refresh_revealed_coins_melt_serial_id_freshcoin_index_pkey PRIMARY KEY (melt_serial_id, freshcoin_index) ; ELSE -- FIXME once denominations are replicated we can safely add the fkey on table creation ALTER TABLE IF EXISTS refresh_revealed_coins ADD CONSTRAINT refresh_revealed_coins_denominations_serial_fkey FOREIGN KEY (denominations_serial) REFERENCES denominations (denominations_serial) ON DELETE CASCADE ; END IF; END $$; COMMENT ON FUNCTION create_table_refresh_revealed_coins IS 'Create the refresh_revealed_coins table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_refresh_transfer_keys( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(rtc_serial BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',melt_serial_id INT8 PRIMARY KEY' -- REFERENCES refresh_commitments (melt_serial_id) ON DELETE CASCADE' ',transfer_pub BYTEA NOT NULL CHECK(LENGTH(transfer_pub)=32)' ',transfer_privs BYTEA NOT NULL' ') %s ;' ,'refresh_transfer_keys' ,'PARTITION BY HASH (melt_serial_id)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS refresh_transfer_keys ADD CONSTRAINT refresh_transfer_keys_rtx_serial_key UNIQUE (rtc_serial) ; END IF; END $$; COMMENT ON FUNCTION create_table_refresh_transfer_keys IS 'Create the refresh_transfer_keys table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_extension_details() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS extension_details (extension_details_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY ,extension_options VARCHAR); END $$; CREATE OR REPLACE FUNCTION create_table_deposits( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- PRIMARY KEY' ',shard INT8 NOT NULL' ',known_coin_id INT8 NOT NULL' -- REFERENCES known_coins (known_coin_id) ON DELETE CASCADE' ',amount_with_fee_val INT8 NOT NULL' ',amount_with_fee_frac INT4 NOT NULL' ',wallet_timestamp INT8 NOT NULL' ',exchange_timestamp INT8 NOT NULL' ',refund_deadline INT8 NOT NULL' ',wire_deadline INT8 NOT NULL' ',merchant_pub BYTEA NOT NULL CHECK (LENGTH(merchant_pub)=32)' ',h_contract_terms BYTEA NOT NULL CHECK (LENGTH(h_contract_terms)=64)' ',coin_sig BYTEA NOT NULL CHECK (LENGTH(coin_sig)=64)' ',wire_salt BYTEA NOT NULL CHECK (LENGTH(wire_salt)=16)' ',wire_target_serial_id INT8 NOT NULL' -- REFERENCES wire_targets (wire_target_serial_id)' ',tiny BOOLEAN NOT NULL DEFAULT FALSE' ',done BOOLEAN NOT NULL DEFAULT FALSE' ',extension_blocked BOOLEAN NOT NULL DEFAULT FALSE' ',extension_details_serial_id INT8' -- REFERENCES extension_details (extension_details_serial_id) ON DELETE CASCADE' ',UNIQUE (shard, known_coin_id, merchant_pub, h_contract_terms)' ') %s ;' ,'deposits' ,'PARTITION BY HASH (shard)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS deposits ADD CONSTRAINT deposits_deposit_by_serial_id_pkey PRIMARY KEY (deposit_serial_id) ; ELSE ALTER TABLE IF EXISTS Deposits ADD CONSTRAINT deposits_extension_details_serial_id_fkey FOREIGN KEY (extension_details_serial_id) REFERENCES extension_details (extension_details_serial_id) ON DELETE CASCADE ; END IF; END $$; COMMENT ON FUNCTION create_table_deposits IS 'Create the deposits table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_refunds( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(refund_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',deposit_serial_id INT8 NOT NULL' -- REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE' ',merchant_sig BYTEA NOT NULL CHECK(LENGTH(merchant_sig)=64)' ',rtransaction_id INT8 NOT NULL' ',amount_with_fee_val INT8 NOT NULL' ',amount_with_fee_frac INT4 NOT NULL' -- ,PRIMARY KEY (deposit_serial_id, rtransaction_id) -- done per shard! ') %s ;' ,'refunds' ,'PARTITION BY HASH (deposit_serial_id)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS refunds ADD CONSTRAINT refunds_refund_serial_id_key UNIQUE (refund_serial_id) ,ADD CONSTRAINT refunds_deposit_serial_id_rtransaction_id_pkey PRIMARY KEY (deposit_serial_id, rtransaction_id) ; END IF; END $$; COMMENT ON FUNCTION create_table_refunds IS 'Create the refunds table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_wire_out( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(wireout_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- PRIMARY KEY' ',execution_date INT8 NOT NULL' ',wtid_raw BYTEA UNIQUE NOT NULL CHECK (LENGTH(wtid_raw)=32)' ',wire_target_serial_id INT8 NOT NULL' -- REFERENCES wire_targets (wire_target_serial_id)' ',exchange_account_section TEXT NOT NULL' ',amount_val INT8 NOT NULL' ',amount_frac INT4 NOT NULL' ') %s ;' ,'wire_out' ,'PARTITION BY HASH (wtid_raw)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS wire_out ADD CONSTRAINT wire_out_wireout_uuid_pkey PRIMARY KEY (wireout_uuid) ; END IF; END $$; COMMENT ON FUNCTION create_table_wire_out IS 'Create the wire_out table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_aggregation_tracking( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(aggregation_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',deposit_serial_id INT8 PRIMARY KEY' -- REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE' ',wtid_raw BYTEA NOT NULL' -- CONSTRAINT wire_out_ref REFERENCES wire_out(wtid_raw) ON DELETE CASCADE DEFERRABLE' ') %s ;' ,'aggregation_tracking' ,'PARTITION BY HASH (deposit_serial_id)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS aggregation_tracking ADD CONSTRAINT aggregation_tracking_aggregation_tracking_serial_id_key UNIQUE (aggergation_tracking_serial_id) ; ELSE ALTER TABLE IF EXISTS aggregation_tracking ADD CONSTRAINT wire_out_ref FOREIGN KEY (wtid_raw) REFERENCES wire_out (wtid_raw) ON DELETE CASCADE DEFERRABLE ; END IF; END $$; COMMENT ON FUNCTION create_table_aggregation_tracking IS 'Create the aggregation_tracking table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_wire_fee() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS wire_fee (wire_fee_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,wire_method VARCHAR NOT NULL ,start_date INT8 NOT NULL ,end_date INT8 NOT NULL ,wire_fee_val INT8 NOT NULL ,wire_fee_frac INT4 NOT NULL ,closing_fee_val INT8 NOT NULL ,closing_fee_frac INT4 NOT NULL ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64) ,PRIMARY KEY (wire_method, start_date) ); END $$; CREATE OR REPLACE FUNCTION create_table_recoup( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(recoup_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',known_coin_id INT8 NOT NULL' -- REFERENCES known_coins (known_coin_id)' ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)' ',coin_blind BYTEA NOT NULL CHECK(LENGTH(coin_blind)=32)' ',amount_val INT8 NOT NULL' ',amount_frac INT4 NOT NULL' ',recoup_timestamp INT8 NOT NULL' ',reserve_out_serial_id INT8 NOT NULL' -- REFERENCES reserves_out (reserve_out_serial_id) ON DELETE CASCADE' ') %s ;' ,'recoup' ,'PARTITION BY HASH (known_coin_id);' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS recoup ADD CONSTRAINT recoup_refresh_recoup_uuid_key UNIQUE (recoup_uuid) ; END IF; END $$; COMMENT ON FUNCTION create_table_recoup IS 'Create the recoup table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_recoup_refresh( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(recoup_refresh_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',known_coin_id INT8 NOT NULL' -- REFERENCES known_coins (known_coin_id)' ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)' ',coin_blind BYTEA NOT NULL CHECK(LENGTH(coin_blind)=32)' ',amount_val INT8 NOT NULL' ',amount_frac INT4 NOT NULL' ',recoup_timestamp INT8 NOT NULL' ',rrc_serial INT8 NOT NULL' -- REFERENCES refresh_revealed_coins (rrc_serial) ON DELETE CASCADE -- UNIQUE' ') %s ;' ,'recoup_refresh' ,'PARTITION BY HASH (known_coin_id)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS recoup_refresh ADD CONSTRAINT recoup_refresh_recoup_refresh_uuid_key UNIQUE (recoup_refresh_uuid) ,ADD CONSTRAINT recoup_refresh_rrc_serial_key UNIQUE (rrc_serial) ; END IF; END $$; COMMENT ON FUNCTION create_table_recoup_refresh IS 'Create the recoup_refresh table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_prewire( IN shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(prewire_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY' ',wire_method TEXT NOT NULL' ',finished BOOLEAN NOT NULL DEFAULT false' ',failed BOOLEAN NOT NULL DEFAULT false' ',buf BYTEA NOT NULL' ') %s ;' ,'prewire' ,'PARTITION BY HASH (prewire_uuid)' ,shard_suffix ); END $$; COMMENT ON FUNCTION create_table_prewire IS 'Create the prewire table, if argument `shard_suffix` is empty, a partitioned master table without partitions will be created. If not empty, a shard table will be created'; CREATE OR REPLACE FUNCTION create_table_wire_accounts() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS wire_accounts (payto_uri VARCHAR PRIMARY KEY ,master_sig BYTEA CHECK (LENGTH(master_sig)=64) ,is_active BOOLEAN NOT NULL ,last_change INT8 NOT NULL ); END $$; CREATE OR REPLACE FUNCTION create_table_cs_nonce_locks( shard_suffix VARCHAR DEFAULT NULL ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_partitioned_table( 'CREATE TABLE IF NOT EXISTS %I' '(cs_nonce_lock_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE' ',nonce BYTEA PRIMARY KEY CHECK (LENGTH(nonce)=32)' ',op_hash BYTEA NOT NULL CHECK (LENGTH(op_hash)=64)' ',max_denomination_serial INT8 NOT NULL' ') %s ;' ,'cs_nonce_locks' ,'PARTITION BY HASH (nonce)' ,shard_suffix ); IF shard_suffix IS NOT NULL THEN ALTER TABLE IF EXISTS cs_nonce_locks ADD CONSTRAINT cs_nonce_locks_cs_nonce_lock_serial_id_key UNIQUE (cs_nonce_lock_serial_id) ; END IF; END $$; CREATE OR REPLACE FUNCTION create_table_work_shards() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE TABLE IF NOT EXISTS work_shards (shard_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,last_attempt INT8 NOT NULL ,start_row INT8 NOT NULL ,end_row INT8 NOT NULL ,completed BOOLEAN NOT NULL DEFAULT FALSE ,job_name VARCHAR NOT NULL ,PRIMARY KEY (job_name, start_row) ); END $$; CREATE OR REPLACE FUNCTION create_table_revolving_work_shards() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN CREATE UNLOGGED TABLE IF NOT EXISTS revolving_work_shards (shard_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,last_attempt INT8 NOT NULL ,start_row INT4 NOT NULL ,end_row INT4 NOT NULL ,active BOOLEAN NOT NULL DEFAULT FALSE ,job_name VARCHAR NOT NULL ,PRIMARY KEY (job_name, start_row) ); END $$; CREATE OR REPLACE FUNCTION create_foreign_table( source_table_name VARCHAR ,modulus INTEGER ,shard_suffix VARCHAR ,current_shard_num INTEGER ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN RAISE NOTICE 'Creating %_% on %', source_table_name, shard_suffix, shard_suffix; EXECUTE FORMAT( 'CREATE FOREIGN TABLE IF NOT EXISTS %I ' 'PARTITION OF %I ' 'FOR VALUES WITH (MODULUS %s, REMAINDER %s) ' 'SERVER %I' ,source_table_name || '_' || shard_suffix ,source_table_name ,modulus ,current_shard_num-1 ,shard_suffix ); EXECUTE FORMAT( 'ALTER FOREIGN TABLE %I OWNER TO "taler-exchange-httpd"', source_table_name || '_' || shard_suffix ); END $$; CREATE OR REPLACE FUNCTION create_table_partition( source_table_name VARCHAR ,modulus INTEGER ,num_partitions INTEGER ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN RAISE NOTICE 'Creating partition %_%', source_table_name, num_partitions; EXECUTE FORMAT( 'CREATE TABLE IF NOT EXISTS %I ' 'PARTITION OF %I ' 'FOR VALUES WITH (MODULUS %s, REMAINDER %s)' ,source_table_name || '_' || num_partitions ,source_table_name ,modulus ,num_partitions-1 ); END $$; CREATE OR REPLACE FUNCTION detach_default_partitions() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN RAISE NOTICE 'Detaching all default table partitions'; ALTER TABLE IF EXISTS wire_targets DETACH PARTITION wire_targets_default; ALTER TABLE IF EXISTS reserves DETACH PARTITION reserves_default; ALTER TABLE IF EXISTS reserves_in DETACH PARTITION reserves_in_default; ALTER TABLE IF EXISTS reserves_close DETACH PARTITION reserves_close_default; ALTER TABLE IF EXISTS reserves_out DETACH PARTITION reserves_out_default; ALTER TABLE IF EXISTS known_coins DETACH PARTITION known_coins_default; ALTER TABLE IF EXISTS refresh_commitments DETACH PARTITION refresh_commitments_default; ALTER TABLE IF EXISTS refresh_revealed_coins DETACH PARTITION refresh_revealed_coins_default; ALTER TABLE IF EXISTS refresh_transfer_keys DETACH PARTITION refresh_transfer_keys_default; ALTER TABLE IF EXISTS deposits DETACH PARTITION deposits_default; ALTER TABLE IF EXISTS refunds DETACH PARTITION refunds_default; ALTER TABLE IF EXISTS wire_out DETACH PARTITION wire_out_default; ALTER TABLE IF EXISTS aggregation_tracking DETACH PARTITION aggregation_tracking_default; ALTER TABLE IF EXISTS recoup DETACH PARTITION recoup_default; ALTER TABLE IF EXISTS recoup_refresh DETACH PARTITION recoup_refresh_default; ALTER TABLE IF EXISTS prewire DETACH PARTITION prewire_default; ALTER TABLE IF EXISTS cs_nonce_locks DETACH partition cs_nonce_locks_default; END $$; COMMENT ON FUNCTION detach_default_partitions IS 'We need to drop default and create new one before deleting the default partitions otherwise constraints get lost too'; CREATE OR REPLACE FUNCTION drop_default_partitions() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN RAISE NOTICE 'Dropping default table partitions'; DROP TABLE IF EXISTS wire_targets_default; DROP TABLE IF EXISTS reserves_default; DROP TABLE IF EXISTS reserves_in_default; DROP TABLE IF EXISTS reserves_close_default; DROP TABLE IF EXISTS reserves_out_default; DROP TABLE IF EXISTS known_coins_default; DROP TABLE IF EXISTS refresh_commitments_default; DROP TABLE IF EXISTS refresh_revealed_coins_default; DROP TABLE IF EXISTS refresh_transfer_keys_default; DROP TABLE IF EXISTS deposits_default; DROP TABLE IF EXISTS refunds_default; DROP TABLE IF EXISTS wire_out_default; DROP TABLE IF EXISTS aggregation_tracking_default; DROP TABLE IF EXISTS recoup_default; DROP TABLE IF EXISTS recoup_refresh_default; DROP TABLE IF EXISTS prewire_default; DROP TABLE IF EXISTS cs_nonce_locks_default; END $$; CREATE OR REPLACE FUNCTION create_partitions( num_partitions INTEGER ) RETURNS VOID LANGUAGE plpgsql AS $$ DECLARE modulus INTEGER; BEGIN modulus := num_partitions; PERFORM detach_default_partitions(); LOOP PERFORM create_table_partition( 'wire_targets' ,modulus ,num_partitions ); PERFORM create_table_partition( 'reserves' ,modulus ,num_partitions ); PERFORM create_table_partition( 'reserves_in' ,modulus ,num_partitions ); PERFORM create_table_partition( 'reserves_close' ,modulus ,num_partitions ); PERFORM create_table_partition( 'reserves_out' ,modulus ,num_partitions ); PERFORM create_table_partition( 'known_coins' ,modulus ,num_partitions ); PERFORM create_table_partition( 'refresh_commitments' ,modulus ,num_partitions ); PERFORM create_table_partition( 'refresh_revealed_coins' ,modulus ,num_partitions ); PERFORM create_table_partition( 'refresh_transfer_keys' ,modulus ,num_partitions ); PERFORM create_table_partition( 'deposits' ,modulus ,num_partitions ); PERFORM create_table_partition( 'refunds' ,modulus ,num_partitions ); PERFORM create_table_partition( 'wire_out' ,modulus ,num_partitions ); PERFORM create_table_partition( 'aggregation_tracking' ,modulus ,num_partitions ); PERFORM create_table_partition( 'recoup' ,modulus ,num_partitions ); PERFORM create_table_partition( 'recoup_refresh' ,modulus ,num_partitions ); PERFORM create_table_partition( 'prewire' ,modulus ,num_partitions ); PERFORM create_table_partition( 'cs_nonce_locks' ,modulus ,num_partitions ); num_partitions=num_partitions-1; EXIT WHEN num_partitions=0; END LOOP; PERFORM drop_default_partitions(); END $$; CREATE OR REPLACE FUNCTION master_prepare_sharding() RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM detach_default_partitions(); ALTER TABLE IF EXISTS wire_targets DROP CONSTRAINT IF EXISTS wire_targets_pkey CASCADE ; ALTER TABLE IF EXISTS reserves DROP CONSTRAINT IF EXISTS reserves_pkey CASCADE ; ALTER TABLE IF EXISTS reserves_in DROP CONSTRAINT IF EXISTS reserves_in_pkey CASCADE ; ALTER TABLE IF EXISTS reserves_close DROP CONSTRAINT IF EXISTS reserves_close_pkey CASCADE ; ALTER TABLE IF EXISTS reserves_out DROP CONSTRAINT IF EXISTS reserves_out_pkey CASCADE ,DROP CONSTRAINT IF EXISTS reserves_out_denominations_serial_fkey ,DROP CONSTRAINT IF EXISTS reserves_out_h_blind_ev_key ; ALTER TABLE IF EXISTS known_coins DROP CONSTRAINT IF EXISTS known_coins_pkey CASCADE ,DROP CONSTRAINT IF EXISTS known_coins_denominations_serial_fkey ; ALTER TABLE IF EXISTS refresh_commitments DROP CONSTRAINT IF EXISTS refresh_commitments_pkey CASCADE ,DROP CONSTRAINT IF EXISTS refresh_old_coin_pub_fkey ; ALTER TABLE IF EXISTS refresh_revealed_coins DROP CONSTRAINT IF EXISTS refresh_revealed_coins_pkey CASCADE ,DROP CONSTRAINT IF EXISTS refresh_revealed_coins_denominations_serial_fkey ; ALTER TABLE IF EXISTS refresh_transfer_keys DROP CONSTRAINT IF EXISTS refresh_transfer_keys_pkey CASCADE ; ALTER TABLE IF EXISTS deposits DROP CONSTRAINT IF EXISTS deposits_pkey CASCADE ,DROP CONSTRAINT IF EXISTS deposits_extension_details_serial_id_fkey ,DROP CONSTRAINT IF EXISTS deposits_shard_known_coin_id_merchant_pub_h_contract_terms_key CASCADE ; ALTER TABLE IF EXISTS refunds DROP CONSTRAINT IF EXISTS refunds_pkey CASCADE ; ALTER TABLE IF EXISTS wire_out DROP CONSTRAINT IF EXISTS wire_out_pkey CASCADE ,DROP CONSTRAINT IF EXISTS wire_out_wtid_raw_key CASCADE ; ALTER TABLE IF EXISTS aggregation_tracking DROP CONSTRAINT IF EXISTS aggregation_tracking_pkey CASCADE ,DROP CONSTRAINT IF EXISTS aggregation_tracking_wtid_raw_fkey ; ALTER TABLE IF EXISTS recoup DROP CONSTRAINT IF EXISTS recoup_pkey CASCADE ; ALTER TABLE IF EXISTS recoup_refresh DROP CONSTRAINT IF EXISTS recoup_refresh_pkey CASCADE ; ALTER TABLE IF EXISTS prewire DROP CONSTRAINT IF EXISTS prewire_pkey CASCADE ; ALTER TABLE IF EXISTS cs_nonce_locks DROP CONSTRAINT IF EXISTS cs_nonce_locks_pkey CASCADE ; END $$; CREATE OR REPLACE FUNCTION create_shard_server( shard_suffix VARCHAR ,total_num_shards INTEGER ,current_shard_num INTEGER ,remote_host VARCHAR ,remote_user VARCHAR ,remote_user_password VARCHAR ,remote_db_name VARCHAR DEFAULT 'taler-exchange' ,remote_port INTEGER DEFAULT '5432' ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN RAISE NOTICE 'Creating server %s', remote_host; EXECUTE FORMAT( 'CREATE SERVER IF NOT EXISTS %I ' 'FOREIGN DATA WRAPPER postgres_fdw ' 'OPTIONS (dbname %L, host %L, port %L)' ,shard_suffix ,remote_db_name ,remote_host ,remote_port ); EXECUTE FORMAT( 'CREATE USER MAPPING IF NOT EXISTS ' 'FOR "taler-exchange-httpd" SERVER %I ' 'OPTIONS (user %L, password %L)' ,shard_suffix ,remote_user ,remote_user_password ); PERFORM create_foreign_table( 'wire_targets' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'reserves' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'reserves_in' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'reserves_out' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'reserves_close' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'known_coins' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'refresh_commitments' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'refresh_revealed_coins' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'refresh_transfer_keys' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'deposits' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'refunds' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'wire_out' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'aggregation_tracking' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'recoup' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'recoup_refresh' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'prewire' ,total_num_shards ,shard_suffix ,current_shard_num ); PERFORM create_foreign_table( 'cs_nonce_locks' ,total_num_shards ,shard_suffix ,current_shard_num ); END $$; CREATE OR REPLACE FUNCTION setup_shard_db( shard_suffix VARCHAR ) RETURNS VOID LANGUAGE plpgsql AS $$ BEGIN PERFORM create_table_wire_targets(shard_suffix); PERFORM create_table_reserves(shard_suffix); PERFORM create_table_reserves_in(shard_suffix); PERFORM create_table_reserves_out(shard_suffix); PERFORM create_table_reserves_close(shard_suffix); PERFORM create_table_known_coins(shard_suffix); PERFORM create_table_refresh_commitments(shard_suffix); PERFORM create_table_refresh_revealed_coins(shard_suffix); PERFORM create_table_refresh_transfer_keys(shard_suffix); PERFORM create_table_deposits(shard_suffix); PERFORM create_table_refunds(shard_suffix); PERFORM create_table_wire_out(shard_suffix); PERFORM create_table_aggregation_tracking(shard_suffix); PERFORM create_table_recoup(shard_suffix); PERFORM create_table_recoup_refresh(shard_suffix); PERFORM create_table_prewire(shard_suffix); PERFORM create_table_cs_nonce_locks(shard_suffix); END $$; COMMIT;