-- -- 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 -- -- ------------------------------ denominations ---------------------------------------- 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 ); COMMENT ON TABLE denominations IS 'Main denominations table. All the valid denominations the exchange knows about.'; COMMENT ON COLUMN denominations.denom_type IS 'determines cipher type for blind signatures used with this denomination; 0 is for RSA'; COMMENT ON COLUMN denominations.age_mask IS 'bitmask with the age restrictions that are being used for this denomination; 0 if denomination does not support the use of age restrictions'; COMMENT ON COLUMN denominations.denominations_serial IS 'needed for exchange-auditor replication logic'; CREATE INDEX IF NOT EXISTS denominations_by_expire_legal_index ON denominations (expire_legal); -- ------------------------------ denomination_revocations ---------------------------------------- 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) ); COMMENT ON TABLE denomination_revocations IS 'remembering which denomination keys have been revoked'; -- -------------------------- kyc_alerts ---------------------------------------- CREATE TABLE IF NOT EXISTS kyc_alerts (h_payto BYTEA PRIMARY KEY CHECK (LENGTH(h_payto)=32) ,trigger_type INT4 NOT NULL ,UNIQUE(trigger_type,h_payto) ); COMMENT ON TABLE kyc_alerts IS 'alerts about completed KYC events reliably notifying other components (even if they are not running)'; COMMENT ON COLUMN kyc_alerts.h_payto IS 'hash of the payto://-URI for which the KYC status changed'; COMMENT ON COLUMN kyc_alerts.trigger_type IS 'identifies the receiver of the alert, as the same h_payto may require multiple components to be notified'; -- ------------------------------ profit drains ---------------------------------------- CREATE TABLE IF NOT EXISTS profit_drains (profit_drain_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,wtid BYTEA PRIMARY KEY CHECK (LENGTH(wtid)=32) ,account_section VARCHAR NOT NULL ,payto_uri VARCHAR NOT NULL ,trigger_date INT8 NOT NULL ,amount_val INT8 NOT NULL ,amount_frac INT4 NOT NULL ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64) ,executed BOOLEAN NOT NULL DEFAULT FALSE ); COMMENT ON TABLE profit_drains IS 'transactions to be performed to move profits from the escrow account of the exchange to a regular account'; COMMENT ON COLUMN profit_drains.wtid IS 'randomly chosen nonce, unique to prevent double-submission'; COMMENT ON COLUMN profit_drains.account_section IS 'specifies the configuration section in the taler-exchange-drain configuration with the wire account to drain'; COMMENT ON COLUMN profit_drains.payto_uri IS 'specifies the account to be credited'; COMMENT ON COLUMN profit_drains.trigger_date IS 'set by taler-exchange-offline at the time of making the signature; not necessarily the exact date of execution of the wire transfer, just for orientation'; COMMENT ON COLUMN profit_drains.amount_val IS 'amount to be transferred'; COMMENT ON COLUMN profit_drains.master_sig IS 'EdDSA signature of type TALER_SIGNATURE_MASTER_DRAIN_PROFIT'; COMMENT ON COLUMN profit_drains.executed IS 'set to TRUE by taler-exchange-drain on execution of the transaction, not replicated to auditor'; -- ------------------------------ wire_targets ---------------------------------------- SELECT create_table_wire_targets(); COMMENT ON TABLE wire_targets IS 'All senders and recipients of money via the exchange'; COMMENT ON COLUMN wire_targets.payto_uri IS 'Can be a regular bank account, or also be a URI identifying a reserve-account (for P2P payments)'; COMMENT ON COLUMN wire_targets.wire_target_h_payto IS 'Unsalted hash of payto_uri'; CREATE TABLE IF NOT EXISTS wire_targets_default PARTITION OF wire_targets FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_wire_targets_partition('default'); -- ------------------------------ legitimization_processes ---------------------------------------- SELECT create_table_legitimization_processes(); COMMENT ON TABLE legitimization_processes IS 'List of legitimization processes (ongoing and completed) by account and provider'; COMMENT ON COLUMN legitimization_processes.legitimization_process_serial_id IS 'unique ID for this legitimization process at the exchange'; COMMENT ON COLUMN legitimization_processes.h_payto IS 'foreign key linking the entry to the wire_targets table, NOT a primary key (multiple legitimizations are possible per wire target)'; COMMENT ON COLUMN legitimization_processes.expiration_time IS 'in the future if the respective KYC check was passed successfully'; COMMENT ON COLUMN legitimization_processes.provider_section IS 'Configuration file section with details about this provider'; COMMENT ON COLUMN legitimization_processes.provider_user_id IS 'Identifier for the user at the provider that was used for the legitimization. NULL if provider is unaware.'; COMMENT ON COLUMN legitimization_processes.provider_legitimization_id IS 'Identifier for the specific legitimization process at the provider. NULL if legitimization was not started.'; CREATE TABLE IF NOT EXISTS legitimization_processes_default PARTITION OF legitimization_processes FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_legitimization_processes_partition('default'); -- ------------------------------ legitimization_requirements_ ---------------------------------------- SELECT create_table_legitimization_requirements(); COMMENT ON TABLE legitimization_requirements IS 'List of required legitimization by account'; COMMENT ON COLUMN legitimization_requirements.legitimization_requirement_serial_id IS 'unique ID for this legitimization requirement at the exchange'; COMMENT ON COLUMN legitimization_requirements.h_payto IS 'foreign key linking the entry to the wire_targets table, NOT a primary key (multiple legitimizations are possible per wire target)'; COMMENT ON COLUMN legitimization_requirements.required_checks IS 'space-separated list of required checks'; CREATE TABLE IF NOT EXISTS legitimization_requirements_default PARTITION OF legitimization_requirements FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_legitimization_requirements_partition('default'); -- ------------------------------ reserves ---------------------------------------- SELECT create_table_reserves(); COMMENT ON TABLE reserves IS 'Summarizes the balance of a reserve. Updated when new funds are added or withdrawn.'; COMMENT ON COLUMN reserves.reserve_pub IS 'EdDSA public key of the reserve. Knowledge of the private key implies ownership over the balance.'; COMMENT ON COLUMN reserves.current_balance_val IS 'Current balance remaining with the reserve.'; COMMENT ON COLUMN reserves.purses_active IS 'Number of purses that were created by this reserve that are not expired and not fully paid.'; COMMENT ON COLUMN reserves.purses_allowed IS 'Number of purses that this reserve is allowed to have active at most.'; COMMENT ON COLUMN reserves.expiration_date IS 'Used to trigger closing of reserves that have not been drained after some time'; COMMENT ON COLUMN reserves.gc_date IS 'Used to forget all information about a reserve during garbage collection'; CREATE TABLE IF NOT EXISTS reserves_default PARTITION OF reserves FOR VALUES WITH (MODULUS 1, REMAINDER 0); -- ------------------------------ reserves_in ---------------------------------------- SELECT create_table_reserves_in(); COMMENT ON TABLE reserves_in IS 'list of transfers of funds into the reserves, one per incoming wire transfer'; COMMENT ON COLUMN reserves_in.wire_source_h_payto IS 'Identifies the debited bank account and KYC status'; COMMENT ON COLUMN reserves_in.reserve_pub IS 'Public key of the reserve. Private key signifies ownership of the remaining balance.'; COMMENT ON COLUMN reserves_in.credit_val IS 'Amount that was transferred into the reserve'; CREATE TABLE IF NOT EXISTS reserves_in_default PARTITION OF reserves_in FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_reserves_in_partition('default'); -- ------------------------------ reserves_close ---------------------------------------- SELECT create_table_reserves_close(); COMMENT ON TABLE reserves_close IS 'wire transfers executed by the reserve to close reserves'; COMMENT ON COLUMN reserves_close.wire_target_h_payto IS 'Identifies the credited bank account (and KYC status). Note that closing does not depend on KYC.'; CREATE TABLE IF NOT EXISTS reserves_close_default PARTITION OF reserves_close FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_reserves_close_partition('default'); -- ------------------------------ reserves_open_requests ---------------------------------------- SELECT create_table_reserves_open_requests(); COMMENT ON TABLE reserves_open_requests IS 'requests to keep a reserve open'; COMMENT ON COLUMN reserves_open_requests.reserve_payment_val IS 'Funding to pay for the request from the reserve balance itself.'; CREATE TABLE IF NOT EXISTS reserves_open_requests_default PARTITION OF reserves_open_requests FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_reserves_open_request_partition('default'); -- ------------------------------ reserves_open_deposits ---------------------------------------- SELECT create_table_reserves_open_deposits(); COMMENT ON TABLE reserves_open_deposits IS 'coin contributions paying for a reserve to remain open'; COMMENT ON COLUMN reserves_open_deposits.reserve_pub IS 'Identifies the specific reserve being paid for (possibly together with reserve_sig).'; CREATE TABLE IF NOT EXISTS reserves_open_deposits_default PARTITION OF reserves_open_deposits FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_reserves_open_deposits_partition('default'); -- ------------------------------ reserves_out ---------------------------------------- SELECT create_table_reserves_out(); COMMENT ON TABLE reserves_out IS 'Withdraw operations performed on reserves.'; COMMENT ON COLUMN reserves_out.h_blind_ev IS 'Hash of the blinded coin, used as primary key here so that broken clients that use a non-random coin or blinding factor fail to withdraw (otherwise they would fail on deposit when the coin is not unique there).'; COMMENT ON COLUMN reserves_out.denominations_serial IS 'We do not CASCADE ON DELETE here, we may keep the denomination data alive'; CREATE TABLE IF NOT EXISTS reserves_out_default PARTITION OF reserves_out FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_reserves_out_partition('default'); SELECT create_table_reserves_out_by_reserve(); COMMENT ON TABLE reserves_out_by_reserve IS 'Information in this table is strictly redundant with that of reserves_out, but saved by a different primary key for fast lookups by reserve public key/uuid.'; CREATE TABLE IF NOT EXISTS reserves_out_by_reserve_default PARTITION OF reserves_out_by_reserve FOR VALUES WITH (MODULUS 1, REMAINDER 0); CREATE OR REPLACE FUNCTION reserves_out_by_reserve_insert_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN INSERT INTO exchange.reserves_out_by_reserve (reserve_uuid ,h_blind_ev) VALUES (NEW.reserve_uuid ,NEW.h_blind_ev); RETURN NEW; END $$; COMMENT ON FUNCTION reserves_out_by_reserve_insert_trigger() IS 'Replicate reserve_out inserts into reserve_out_by_reserve table.'; CREATE TRIGGER reserves_out_on_insert AFTER INSERT ON reserves_out FOR EACH ROW EXECUTE FUNCTION reserves_out_by_reserve_insert_trigger(); CREATE OR REPLACE FUNCTION reserves_out_by_reserve_delete_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN DELETE FROM exchange.reserves_out_by_reserve WHERE reserve_uuid = OLD.reserve_uuid; RETURN OLD; END $$; COMMENT ON FUNCTION reserves_out_by_reserve_delete_trigger() IS 'Replicate reserve_out deletions into reserve_out_by_reserve table.'; CREATE TRIGGER reserves_out_on_delete AFTER DELETE ON reserves_out FOR EACH ROW EXECUTE FUNCTION reserves_out_by_reserve_delete_trigger(); -- ------------------------------ auditors ---------------------------------------- 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 ); COMMENT ON TABLE auditors IS 'Table with auditors the exchange uses or has used in the past. Entries never expire as we need to remember the last_change column indefinitely.'; COMMENT ON COLUMN auditors.auditor_pub IS 'Public key of the auditor.'; COMMENT ON COLUMN auditors.auditor_url IS 'The base URL of the auditor.'; COMMENT ON COLUMN auditors.is_active IS 'true if we are currently supporting the use of this auditor.'; COMMENT ON COLUMN auditors.last_change IS 'Latest time when active status changed. Used to detect replays of old messages.'; -- ------------------------------ auditor_denom_sigs ---------------------------------------- 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) ); COMMENT ON TABLE auditor_denom_sigs IS 'Table with auditor signatures on exchange denomination keys.'; COMMENT ON COLUMN auditor_denom_sigs.auditor_uuid IS 'Identifies the auditor.'; COMMENT ON COLUMN auditor_denom_sigs.denominations_serial IS 'Denomination the signature is for.'; COMMENT ON COLUMN auditor_denom_sigs.auditor_sig IS 'Signature of the auditor, of purpose TALER_SIGNATURE_AUDITOR_EXCHANGE_KEYS.'; -- ------------------------------ exchange_sign_keys ---------------------------------------- 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 ); COMMENT ON TABLE exchange_sign_keys IS 'Table with master public key signatures on exchange online signing keys.'; COMMENT ON COLUMN exchange_sign_keys.exchange_pub IS 'Public online signing key of the exchange.'; COMMENT ON COLUMN exchange_sign_keys.master_sig IS 'Signature affirming the validity of the signing key of purpose TALER_SIGNATURE_MASTER_SIGNING_KEY_VALIDITY.'; COMMENT ON COLUMN exchange_sign_keys.valid_from IS 'Time when this online signing key will first be used to sign messages.'; COMMENT ON COLUMN exchange_sign_keys.expire_sign IS 'Time when this online signing key will no longer be used to sign.'; COMMENT ON COLUMN exchange_sign_keys.expire_legal IS 'Time when this online signing key legally expires.'; -- ------------------------------ signkey_revocations ---------------------------------------- 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) ); COMMENT ON TABLE signkey_revocations IS 'Table storing which online signing keys have been revoked'; -- ------------------------------ extensions ---------------------------------------- CREATE TABLE IF NOT EXISTS extensions (extension_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,name VARCHAR NOT NULL UNIQUE ,manifest BYTEA ); COMMENT ON TABLE extensions IS 'Configurations of the activated extensions'; COMMENT ON COLUMN extensions.name IS 'Name of the extension'; COMMENT ON COLUMN extensions.manifest IS 'Manifest of the extension as JSON-blob, maybe NULL. It contains common meta-information and extension-specific configuration.'; -- ------------------------------ known_coins ---------------------------------------- SELECT create_table_known_coins(); COMMENT ON TABLE known_coins IS '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'; COMMENT ON COLUMN known_coins.denominations_serial IS 'Denomination of the coin, determines the value of the original coin and applicable fees for coin-specific operations.'; COMMENT ON COLUMN known_coins.coin_pub IS 'EdDSA public key of the coin'; COMMENT ON COLUMN known_coins.remaining_val IS 'Value of the coin that remains to be spent'; COMMENT ON COLUMN known_coins.age_commitment_hash IS 'Optional hash of the age commitment for age restrictions as per DD 24 (active if denom_type has the respective bit set)'; COMMENT ON COLUMN known_coins.denom_sig IS '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.'; CREATE TABLE IF NOT EXISTS known_coins_default PARTITION OF known_coins FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_known_coins_partition('default'); -- ------------------------------ refresh_commitments ---------------------------------------- SELECT create_table_refresh_commitments(); COMMENT ON TABLE refresh_commitments IS 'Commitments made when melting coins and the gamma value chosen by the exchange.'; COMMENT ON COLUMN refresh_commitments.noreveal_index IS 'The gamma value chosen by the exchange in the cut-and-choose protocol'; COMMENT ON COLUMN refresh_commitments.rc IS 'Commitment made by the client, hash over the various client inputs in the cut-and-choose protocol'; COMMENT ON COLUMN refresh_commitments.old_coin_pub IS 'Coin being melted in the refresh process.'; CREATE TABLE IF NOT EXISTS refresh_commitments_default PARTITION OF refresh_commitments FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_refresh_commitments_partition('default'); -- ------------------------------ refresh_revealed_coins ---------------------------------------- SELECT create_table_refresh_revealed_coins(); COMMENT ON TABLE refresh_revealed_coins IS 'Revelations about the new coins that are to be created during a melting session.'; COMMENT ON COLUMN refresh_revealed_coins.rrc_serial IS 'needed for exchange-auditor replication logic'; COMMENT ON COLUMN refresh_revealed_coins.melt_serial_id IS 'Identifies the refresh commitment (rc) of the melt operation.'; COMMENT ON COLUMN refresh_revealed_coins.freshcoin_index IS 'index of the fresh coin being created (one melt operation may result in multiple fresh coins)'; COMMENT ON COLUMN refresh_revealed_coins.coin_ev IS 'envelope of the new coin to be signed'; COMMENT ON COLUMN refresh_revealed_coins.ewv IS 'exchange contributed values in the creation of the fresh coin (see /csr)'; COMMENT ON COLUMN refresh_revealed_coins.h_coin_ev IS 'hash of the envelope of the new coin to be signed (for lookups)'; COMMENT ON COLUMN refresh_revealed_coins.ev_sig IS 'exchange signature over the envelope'; CREATE TABLE IF NOT EXISTS refresh_revealed_coins_default PARTITION OF refresh_revealed_coins FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_refresh_revealed_coins_partition('default'); -- ------------------------------ refresh_transfer_keys ---------------------------------------- SELECT create_table_refresh_transfer_keys(); COMMENT ON TABLE refresh_transfer_keys IS 'Transfer keys of a refresh operation (the data revealed to the exchange).'; COMMENT ON COLUMN refresh_transfer_keys.rtc_serial IS 'needed for exchange-auditor replication logic'; COMMENT ON COLUMN refresh_transfer_keys.melt_serial_id IS 'Identifies the refresh commitment (rc) of the operation.'; COMMENT ON COLUMN refresh_transfer_keys.transfer_pub IS 'transfer public key for the gamma index'; COMMENT ON COLUMN refresh_transfer_keys.transfer_privs IS 'array of TALER_CNC_KAPPA - 1 transfer private keys that have been revealed, with the gamma entry being skipped'; CREATE TABLE IF NOT EXISTS refresh_transfer_keys_default PARTITION OF refresh_transfer_keys FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_refresh_transfer_keys_partition('default'); -- ------------------------------ policy_fulfillments ------------------------------------- CREATE TABLE IF NOT EXISTS policy_fulfillments (fulfillment_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE PRIMARY KEY ,fulfillment_timestamp INT8 NOT NULL ,fulfillment_proof VARCHAR ,h_fulfillment_proof BYTEA NOT NULL CHECK(LENGTH(h_fulfillment_proof) = 64) UNIQUE ,policy_hash_codes BYTEA NOT NULL CHECK(0 = MOD(LENGTH(policy_hash_codes), 16)) ); COMMENT ON TABLE policy_fulfillments IS 'Proofs of fulfillment of policies that were set in deposits'; COMMENT ON COLUMN policy_fulfillments.fulfillment_timestamp IS 'Timestamp of the arrival of a proof of fulfillment'; COMMENT ON COLUMN policy_fulfillments.fulfillment_proof IS 'JSON object with a proof of the fulfillment of a policy. Supported details depend on the policy extensions supported by the exchange.'; COMMENT ON COLUMN policy_fulfillments.h_fulfillment_proof IS 'Hash of the fulfillment_proof'; COMMENT ON COLUMN policy_fulfillments.policy_hash_codes IS 'Concatenation of the policy_hash_code of all policy_details that are fulfilled by this proof'; -- ------------------------------ policy_details ---------------------------------------- CREATE TABLE IF NOT EXISTS policy_details (policy_details_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY ,policy_hash_code BYTEA PRIMARY KEY CHECK(LENGTH(policy_hash_code)=16) ,policy_json VARCHAR ,deadline INT8 NOT NULL ,commitment_val INT8 NOT NULL ,commitment_frac INT4 NOT NULL ,accumulated_total_val INT8 NOT NULL ,accumulated_total_frac INT4 NOT NULL ,fee_val INT8 NOT NULL ,fee_frac INT4 NOT NULL ,transferable_val INT8 NOT NULL ,transferable_frac INT8 NOT NULL ,fulfillment_state smallint NOT NULL CHECK(fulfillment_state between 0 and 5) ,fulfillment_id BIGINT NULL REFERENCES policy_fulfillments (fulfillment_id) ON DELETE CASCADE ); COMMENT ON TABLE policy_details IS 'Policies that were provided with deposits via policy extensions.'; COMMENT ON COLUMN policy_details.policy_hash_code IS 'ID (GNUNET_HashCode) that identifies a policy. Will be calculated by the policy extension based on the content'; COMMENT ON COLUMN policy_details.policy_json IS 'JSON object with options set that the exchange needs to consider when executing a deposit. Supported details depend on the policy extensions supported by the exchange.'; COMMENT ON COLUMN policy_details.deadline IS 'Deadline until the policy must be marked as fulfilled (maybe "forever")'; COMMENT ON COLUMN policy_details.commitment_val IS 'The amount that this policy commits to. Invariant: commitment >= fee'; COMMENT ON COLUMN policy_details.accumulated_total_val IS 'The sum of all contributions of all deposit that reference this policy. Invariant: The fulfilment_state must be Insufficient as long as accumulated_total < commitment'; COMMENT ON COLUMN policy_details.fee_val IS 'The fee for this policy, due when the policy is fulfilled or timed out'; COMMENT ON COLUMN policy_details.transferable_val IS 'The amount that on fulfillment or timeout will be transferred to the payto-URI''s of the corresponding deposit''s. The policy fees must have been already deducted from it. Invariant: fee+transferable <= accumulated_total. The remaining amount (accumulated_total - fee - transferable) can be refreshed by the owner of the coins when the state is Timeout or Success.'; COMMENT ON COLUMN policy_details.fulfillment_state IS 'State of the fulfillment: - 0 (Failure) - 1 (Insufficient) - 2 (Ready) - 4 (Success) - 5 (Timeout)'; COMMENT ON COLUMN policy_details.fulfillment_id IS 'Reference to the proof of the fulfillment of this policy, if it exists. Invariant: If not NULL, this entry''s .hash_code MUST be part of the corresponding policy_fulfillments.policy_hash_codes array.'; -- ------------------------------ deposits ---------------------------------------- SELECT create_table_deposits(); COMMENT ON TABLE deposits IS 'Deposits we have received and for which we need to make (aggregate) wire transfers (and manage refunds).'; COMMENT ON COLUMN deposits.shard IS 'Used for load sharding in the materialized indices. Should be set based on merchant_pub. 64-bit value because we need an *unsigned* 32-bit value.'; COMMENT ON COLUMN deposits.known_coin_id IS 'Used for garbage collection'; COMMENT ON COLUMN deposits.wire_target_h_payto IS 'Identifies the target bank account and KYC status'; COMMENT ON COLUMN deposits.wire_salt IS 'Salt used when hashing the payto://-URI to get the h_wire'; COMMENT ON COLUMN deposits.done IS 'Set to TRUE once we have included this deposit in some aggregate wire transfer to the merchant'; COMMENT ON COLUMN deposits.policy_blocked IS 'True if the aggregation of the deposit is currently blocked by some policy extension mechanism. Used to filter out deposits that must not be processed by the canonical deposit logic.'; COMMENT ON COLUMN deposits.policy_details_serial_id IS 'References policy extensions table, NULL if extensions are not used'; CREATE TABLE IF NOT EXISTS deposits_default PARTITION OF deposits FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_deposits_partition('default'); SELECT create_table_deposits_by_ready(); COMMENT ON TABLE deposits_by_ready IS 'Enables fast lookups for deposits_get_ready, auto-populated via TRIGGER below'; CREATE TABLE IF NOT EXISTS deposits_by_ready_default PARTITION OF deposits_by_ready DEFAULT; SELECT create_table_deposits_for_matching(); COMMENT ON TABLE deposits_for_matching IS 'Enables fast lookups for deposits_iterate_matching, auto-populated via TRIGGER below'; CREATE TABLE IF NOT EXISTS deposits_for_matching_default PARTITION OF deposits_for_matching DEFAULT; CREATE OR REPLACE FUNCTION deposits_insert_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ DECLARE is_ready BOOLEAN; BEGIN is_ready = NOT (NEW.done OR NEW.policy_blocked); IF (is_ready) THEN INSERT INTO exchange.deposits_by_ready (wire_deadline ,shard ,coin_pub ,deposit_serial_id) VALUES (NEW.wire_deadline ,NEW.shard ,NEW.coin_pub ,NEW.deposit_serial_id); INSERT INTO exchange.deposits_for_matching (refund_deadline ,merchant_pub ,coin_pub ,deposit_serial_id) VALUES (NEW.refund_deadline ,NEW.merchant_pub ,NEW.coin_pub ,NEW.deposit_serial_id); END IF; RETURN NEW; END $$; COMMENT ON FUNCTION deposits_insert_trigger() IS 'Replicate deposit inserts into materialized indices.'; CREATE TRIGGER deposits_on_insert AFTER INSERT ON deposits FOR EACH ROW EXECUTE FUNCTION deposits_insert_trigger(); CREATE OR REPLACE FUNCTION deposits_update_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ DECLARE was_ready BOOLEAN; DECLARE is_ready BOOLEAN; BEGIN was_ready = NOT (OLD.done OR OLD.policy_blocked); is_ready = NOT (NEW.done OR NEW.policy_blocked); IF (was_ready AND NOT is_ready) THEN DELETE FROM exchange.deposits_by_ready WHERE wire_deadline = OLD.wire_deadline AND shard = OLD.shard AND coin_pub = OLD.coin_pub AND deposit_serial_id = OLD.deposit_serial_id; DELETE FROM exchange.deposits_for_matching WHERE refund_deadline = OLD.refund_deadline AND merchant_pub = OLD.merchant_pub AND coin_pub = OLD.coin_pub AND deposit_serial_id = OLD.deposit_serial_id; END IF; IF (is_ready AND NOT was_ready) THEN INSERT INTO exchange.deposits_by_ready (wire_deadline ,shard ,coin_pub ,deposit_serial_id) VALUES (NEW.wire_deadline ,NEW.shard ,NEW.coin_pub ,NEW.deposit_serial_id); INSERT INTO exchange.deposits_for_matching (refund_deadline ,merchant_pub ,coin_pub ,deposit_serial_id) VALUES (NEW.refund_deadline ,NEW.merchant_pub ,NEW.coin_pub ,NEW.deposit_serial_id); END IF; RETURN NEW; END $$; COMMENT ON FUNCTION deposits_update_trigger() IS 'Replicate deposits changes into materialized indices.'; CREATE TRIGGER deposits_on_update AFTER UPDATE ON deposits FOR EACH ROW EXECUTE FUNCTION deposits_update_trigger(); CREATE OR REPLACE FUNCTION deposits_delete_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ DECLARE was_ready BOOLEAN; BEGIN was_ready = NOT (OLD.done OR OLD.policy_blocked); IF (was_ready) THEN DELETE FROM exchange.deposits_by_ready WHERE wire_deadline = OLD.wire_deadline AND shard = OLD.shard AND coin_pub = OLD.coin_pub AND deposit_serial_id = OLD.deposit_serial_id; DELETE FROM exchange.deposits_for_matching WHERE refund_deadline = OLD.refund_deadline AND merchant_pub = OLD.merchant_pub AND coin_pub = OLD.coin_pub AND deposit_serial_id = OLD.deposit_serial_id; END IF; RETURN NEW; END $$; COMMENT ON FUNCTION deposits_delete_trigger() IS 'Replicate deposit deletions into materialized indices.'; CREATE TRIGGER deposits_on_delete AFTER DELETE ON deposits FOR EACH ROW EXECUTE FUNCTION deposits_delete_trigger(); -- ------------------------------ refunds ---------------------------------------- SELECT create_table_refunds(); COMMENT ON TABLE refunds IS 'Data on coins that were refunded. Technically, refunds always apply against specific deposit operations involving a coin. The combination of coin_pub, merchant_pub, h_contract_terms and rtransaction_id MUST be unique, and we usually select by coin_pub so that one goes first.'; COMMENT ON COLUMN refunds.deposit_serial_id IS 'Identifies ONLY the merchant_pub, h_contract_terms and coin_pub. Multiple deposits may match a refund, this only identifies one of them.'; COMMENT ON COLUMN refunds.rtransaction_id IS 'used by the merchant to make refunds unique in case the same coin for the same deposit gets a subsequent (higher) refund'; CREATE TABLE IF NOT EXISTS refunds_default PARTITION OF refunds FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_refunds_partition('default'); -- ------------------------------ wire_out ---------------------------------------- SELECT create_table_wire_out(); COMMENT ON TABLE wire_out IS 'wire transfers the exchange has executed'; COMMENT ON COLUMN wire_out.exchange_account_section IS 'identifies the configuration section with the debit account of this payment'; COMMENT ON COLUMN wire_out.wire_target_h_payto IS 'Identifies the credited bank account and KYC status'; CREATE TABLE IF NOT EXISTS wire_out_default PARTITION OF wire_out FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_wire_out_partition('default'); CREATE OR REPLACE 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 TRIGGER wire_out_on_delete AFTER DELETE ON wire_out FOR EACH ROW EXECUTE FUNCTION wire_out_delete_trigger(); -- ------------------------------ aggregation_transient ---------------------------------------- SELECT create_table_aggregation_transient(); COMMENT ON TABLE aggregation_transient IS 'aggregations currently happening (lacking wire_out, usually because the amount is too low); this table is not replicated'; COMMENT ON COLUMN aggregation_transient.amount_val IS 'Sum of all of the aggregated deposits (without deposit fees)'; COMMENT ON COLUMN aggregation_transient.wtid_raw IS 'identifier of the wire transfer'; CREATE TABLE IF NOT EXISTS aggregation_transient_default PARTITION OF aggregation_transient FOR VALUES WITH (MODULUS 1, REMAINDER 0); -- ------------------------------ aggregation_tracking ---------------------------------------- SELECT create_table_aggregation_tracking(); COMMENT ON TABLE aggregation_tracking IS 'mapping from wire transfer identifiers (WTID) to deposits (and back)'; COMMENT ON COLUMN aggregation_tracking.wtid_raw IS 'identifier of the wire transfer'; CREATE TABLE IF NOT EXISTS aggregation_tracking_default PARTITION OF aggregation_tracking FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_aggregation_tracking_partition('default'); -- ------------------------------ wire_fee ---------------------------------------- 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) ); COMMENT ON TABLE wire_fee IS 'list of the wire fees of this exchange, by date'; COMMENT ON COLUMN wire_fee.wire_fee_serial IS 'needed for exchange-auditor replication logic'; CREATE INDEX IF NOT EXISTS wire_fee_by_end_date_index ON wire_fee (end_date); -- ------------------------------ global_fee ---------------------------------------- CREATE TABLE IF NOT EXISTS global_fee (global_fee_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,start_date INT8 NOT NULL ,end_date INT8 NOT NULL ,history_fee_val INT8 NOT NULL ,history_fee_frac INT4 NOT NULL ,account_fee_val INT8 NOT NULL ,account_fee_frac INT4 NOT NULL ,purse_fee_val INT8 NOT NULL ,purse_fee_frac INT4 NOT NULL ,purse_timeout INT8 NOT NULL ,history_expiration INT8 NOT NULL ,purse_account_limit INT4 NOT NULL ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64) ,PRIMARY KEY (start_date) ); COMMENT ON TABLE global_fee IS 'list of the global fees of this exchange, by date'; COMMENT ON COLUMN global_fee.global_fee_serial IS 'needed for exchange-auditor replication logic'; CREATE INDEX IF NOT EXISTS global_fee_by_end_date_index ON global_fee (end_date); -- ------------------------------ recoup ---------------------------------------- SELECT create_table_recoup(); COMMENT ON TABLE recoup IS 'Information about recoups that were executed between a coin and a reserve. In this type of recoup, the amount is credited back to the reserve from which the coin originated.'; COMMENT ON COLUMN recoup.coin_pub IS 'Coin that is being debited in the recoup. Do not CASCADE ON DROP on the coin_pub, as we may keep the coin alive!'; COMMENT ON COLUMN recoup.reserve_out_serial_id IS 'Identifies the h_blind_ev of the recouped coin and provides the link to the credited reserve.'; COMMENT ON COLUMN recoup.coin_sig IS 'Signature by the coin affirming the recoup, of type TALER_SIGNATURE_WALLET_COIN_RECOUP'; COMMENT ON COLUMN recoup.coin_blind IS 'Denomination blinding key used when creating the blinded coin from the planchet. Secret revealed during the recoup to provide the linkage between the coin and the withdraw operation.'; CREATE TABLE IF NOT EXISTS recoup_default PARTITION OF recoup FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_recoup_partition('default'); SELECT create_table_recoup_by_reserve(); COMMENT ON TABLE recoup_by_reserve IS 'Information in this table is strictly redundant with that of recoup, but saved by a different primary key for fast lookups by reserve_out_serial_id.'; CREATE TABLE IF NOT EXISTS recoup_by_reserve_default PARTITION OF recoup_by_reserve FOR VALUES WITH (MODULUS 1, REMAINDER 0); CREATE OR REPLACE FUNCTION recoup_insert_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN INSERT INTO exchange.recoup_by_reserve (reserve_out_serial_id ,coin_pub) VALUES (NEW.reserve_out_serial_id ,NEW.coin_pub); RETURN NEW; END $$; COMMENT ON FUNCTION recoup_insert_trigger() IS 'Replicate recoup inserts into recoup_by_reserve table.'; CREATE TRIGGER recoup_on_insert AFTER INSERT ON recoup FOR EACH ROW EXECUTE FUNCTION recoup_insert_trigger(); CREATE OR REPLACE FUNCTION recoup_delete_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN DELETE FROM exchange.recoup_by_reserve WHERE reserve_out_serial_id = OLD.reserve_out_serial_id AND coin_pub = OLD.coin_pub; RETURN OLD; END $$; COMMENT ON FUNCTION recoup_delete_trigger() IS 'Replicate recoup deletions into recoup_by_reserve table.'; CREATE TRIGGER recoup_on_delete AFTER DELETE ON recoup FOR EACH ROW EXECUTE FUNCTION recoup_delete_trigger(); -- ------------------------------ recoup_refresh ---------------------------------------- SELECT create_table_recoup_refresh(); COMMENT ON TABLE recoup_refresh IS 'Table of coins that originated from a refresh operation and that were recouped. Links the (fresh) coin to the melted operation (and thus the old coin). A recoup on a refreshed coin credits the old coin and debits the fresh coin.'; COMMENT ON COLUMN recoup_refresh.coin_pub IS 'Refreshed coin of a revoked denomination where the residual value is credited to the old coin. Do not CASCADE ON DROP on the coin_pub, as we may keep the coin alive!'; COMMENT ON COLUMN recoup_refresh.known_coin_id IS 'FIXME: (To be) used for garbage collection (in the future)'; COMMENT ON COLUMN recoup_refresh.rrc_serial IS 'Link to the refresh operation. Also identifies the h_blind_ev of the recouped coin (as h_coin_ev).'; COMMENT ON COLUMN recoup_refresh.coin_blind IS 'Denomination blinding key used when creating the blinded coin from the planchet. Secret revealed during the recoup to provide the linkage between the coin and the refresh operation.'; CREATE TABLE IF NOT EXISTS recoup_refresh_default PARTITION OF recoup_refresh FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_recoup_refresh_partition('default'); -- ------------------------------ prewire ---------------------------------------- SELECT create_table_prewire(); COMMENT ON TABLE prewire IS 'pre-commit data for wire transfers we are about to execute'; COMMENT ON COLUMN prewire.failed IS 'set to TRUE if the bank responded with a non-transient failure to our transfer request'; COMMENT ON COLUMN prewire.finished IS 'set to TRUE once bank confirmed receiving the wire transfer request'; COMMENT ON COLUMN prewire.buf IS 'serialized data to send to the bank to execute the wire transfer'; CREATE TABLE IF NOT EXISTS prewire_default PARTITION OF prewire FOR VALUES WITH (MODULUS 1, REMAINDER 0); -- ------------------------------ wire_accounts ---------------------------------------- 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 ); COMMENT ON TABLE wire_accounts IS 'Table with current and historic bank accounts of the exchange. Entries never expire as we need to remember the last_change column indefinitely.'; COMMENT ON COLUMN wire_accounts.payto_uri IS 'payto URI (RFC 8905) with the bank account of the exchange.'; COMMENT ON COLUMN wire_accounts.master_sig IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS'; COMMENT ON COLUMN wire_accounts.is_active IS 'true if we are currently supporting the use of this account.'; COMMENT ON COLUMN wire_accounts.last_change IS 'Latest time when active status changed. Used to detect replays of old messages.'; -- "wire_accounts" has no sequence because it is a 'mutable' table -- and is of no concern to the auditor -- ------------------------------ cs_nonce_locks ---------------------------------------- SELECT create_table_cs_nonce_locks(); COMMENT ON TABLE cs_nonce_locks IS 'ensures a Clause Schnorr client nonce is locked for use with an operation identified by a hash'; COMMENT ON COLUMN cs_nonce_locks.nonce IS 'actual nonce submitted by the client'; COMMENT ON COLUMN cs_nonce_locks.op_hash IS 'hash (RC for refresh, blind coin hash for withdraw) the nonce may be used with'; COMMENT ON COLUMN cs_nonce_locks.max_denomination_serial IS 'Maximum number of a CS denomination serial the nonce could be used with, for GC'; CREATE TABLE IF NOT EXISTS cs_nonce_locks_default PARTITION OF cs_nonce_locks FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_cs_nonce_locks_partition('default'); -- ------------------------------ work_shards ---------------------------------------- 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) ); COMMENT ON TABLE work_shards IS 'coordinates work between multiple processes working on the same job'; COMMENT ON COLUMN work_shards.shard_serial_id IS 'unique serial number identifying the shard'; COMMENT ON COLUMN work_shards.last_attempt IS 'last time a worker attempted to work on the shard'; COMMENT ON COLUMN work_shards.completed IS 'set to TRUE once the shard is finished by a worker'; COMMENT ON COLUMN work_shards.start_row IS 'row at which the shard scope starts, inclusive'; COMMENT ON COLUMN work_shards.end_row IS 'row at which the shard scope ends, exclusive'; COMMENT ON COLUMN work_shards.job_name IS 'unique name of the job the workers on this shard are performing'; CREATE INDEX IF NOT EXISTS work_shards_by_job_name_completed_last_attempt_index ON work_shards (job_name ,completed ,last_attempt ASC ); -- ------------------------------ revolving_work_shards ---------------------------------------- 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) ); COMMENT ON TABLE revolving_work_shards IS 'coordinates work between multiple processes working on the same job with partitions that need to be repeatedly processed; unlogged because on system crashes the locks represented by this table will have to be cleared anyway, typically using "taler-exchange-dbinit -s"'; COMMENT ON COLUMN revolving_work_shards.shard_serial_id IS 'unique serial number identifying the shard'; COMMENT ON COLUMN revolving_work_shards.last_attempt IS 'last time a worker attempted to work on the shard'; COMMENT ON COLUMN revolving_work_shards.active IS 'set to TRUE when a worker is active on the shard'; COMMENT ON COLUMN revolving_work_shards.start_row IS 'row at which the shard scope starts, inclusive'; COMMENT ON COLUMN revolving_work_shards.end_row IS 'row at which the shard scope ends, exclusive'; COMMENT ON COLUMN revolving_work_shards.job_name IS 'unique name of the job the workers on this shard are performing'; CREATE INDEX IF NOT EXISTS revolving_work_shards_by_job_name_active_last_attempt_index ON revolving_work_shards (job_name ,active ,last_attempt ); -------------------------------------------------------------------------- -- Tables for P2P payments -------------------------------------------------------------------------- -- ------------------------------ partners ---------------------------------------- CREATE TABLE IF NOT EXISTS partners (partner_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE ,partner_master_pub BYTEA NOT NULL CHECK(LENGTH(partner_master_pub)=32) ,start_date INT8 NOT NULL ,end_date INT8 NOT NULL ,next_wad INT8 NOT NULL DEFAULT (0) ,wad_frequency INT8 NOT NULL ,wad_fee_val INT8 NOT NULL ,wad_fee_frac INT4 NOT NULL ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64) ,partner_base_url TEXT NOT NULL ); COMMENT ON TABLE partners IS 'exchanges we do wad transfers to'; COMMENT ON COLUMN partners.partner_master_pub IS 'offline master public key of the partner'; COMMENT ON COLUMN partners.start_date IS 'starting date of the partnership'; COMMENT ON COLUMN partners.end_date IS 'end date of the partnership'; COMMENT ON COLUMN partners.next_wad IS 'at what time should we do the next wad transfer to this partner (frequently updated); set to forever after the end_date'; COMMENT ON COLUMN partners.wad_frequency IS 'how often do we promise to do wad transfers'; COMMENT ON COLUMN partners.wad_fee_val IS 'how high is the fee for a wallet to be added to a wad to this partner'; COMMENT ON COLUMN partners.partner_base_url IS 'base URL of the REST API for this partner'; COMMENT ON COLUMN partners.master_sig IS 'signature of our master public key affirming the partnership, of purpose TALER_SIGNATURE_MASTER_PARTNER_DETAILS'; CREATE INDEX IF NOT EXISTS partner_by_wad_time ON partners (next_wad ASC); -- ------------------------------ purse_requests ---------------------------------------- SELECT create_table_purse_requests(); COMMENT ON TABLE purse_requests IS 'Requests establishing purses, associating them with a contract but without a target reserve'; COMMENT ON COLUMN purse_requests.purse_pub IS 'Public key of the purse'; COMMENT ON COLUMN purse_requests.purse_creation IS 'Local time when the purse was created. Determines applicable purse fees.'; COMMENT ON COLUMN purse_requests.purse_expiration IS 'When the purse is set to expire'; COMMENT ON COLUMN purse_requests.h_contract_terms IS 'Hash of the contract the parties are to agree to'; COMMENT ON COLUMN purse_requests.flags IS 'see the enum TALER_WalletAccountMergeFlags'; COMMENT ON COLUMN purse_requests.in_reserve_quota IS 'set to TRUE if this purse currently counts against the number of free purses in the respective reserve'; COMMENT ON COLUMN purse_requests.amount_with_fee_val IS 'Total amount expected to be in the purse'; COMMENT ON COLUMN purse_requests.purse_fee_val IS 'Purse fee the client agreed to pay from the reserve (accepted by the exchange at the time the purse was created). Zero if in_reserve_quota is TRUE.'; COMMENT ON COLUMN purse_requests.balance_val IS 'Total amount actually in the purse'; COMMENT ON COLUMN purse_requests.purse_sig IS 'Signature of the purse affirming the purse parameters, of type TALER_SIGNATURE_PURSE_REQUEST'; CREATE TABLE IF NOT EXISTS purse_requests_default PARTITION OF purse_requests FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_purse_requests_partition('default'); -- ------------------------------ purse_decisions ---------------------------------------- SELECT create_table_purse_decision(); COMMENT ON TABLE purse_decision IS 'Purses that were decided upon (refund or merge)'; COMMENT ON COLUMN purse_decision.purse_pub IS 'Public key of the purse'; CREATE TABLE IF NOT EXISTS purse_decision_default PARTITION OF purse_decision FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_purse_decision_partition('default'); -- ------------------------------ purse_merges ---------------------------------------- SELECT create_table_purse_merges(); COMMENT ON TABLE purse_merges IS 'Merge requests where a purse-owner requested merging the purse into the account'; COMMENT ON COLUMN purse_merges.partner_serial_id IS 'identifies the partner exchange, NULL in case the target reserve lives at this exchange'; COMMENT ON COLUMN purse_merges.reserve_pub IS 'public key of the target reserve'; COMMENT ON COLUMN purse_merges.purse_pub IS 'public key of the purse'; COMMENT ON COLUMN purse_merges.merge_sig IS 'signature by the purse private key affirming the merge, of type TALER_SIGNATURE_WALLET_PURSE_MERGE'; COMMENT ON COLUMN purse_merges.merge_timestamp IS 'when was the merge message signed'; CREATE TABLE IF NOT EXISTS purse_merges_default PARTITION OF purse_merges FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_purse_merges_partition('default'); -- ------------------------------ account_merges ---------------------------------------- SELECT create_table_account_merges(); COMMENT ON TABLE account_merges IS 'Merge requests where a purse- and account-owner requested merging the purse into the account'; COMMENT ON COLUMN account_merges.reserve_pub IS 'public key of the target reserve'; COMMENT ON COLUMN account_merges.purse_pub IS 'public key of the purse'; COMMENT ON COLUMN account_merges.reserve_sig IS 'signature by the reserve private key affirming the merge, of type TALER_SIGNATURE_WALLET_ACCOUNT_MERGE'; CREATE TABLE IF NOT EXISTS account_merges_default PARTITION OF account_merges FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_account_merges_partition('default'); -- ------------------------------ contracts ---------------------------------------- SELECT create_table_contracts(); COMMENT ON TABLE contracts IS 'encrypted contracts associated with purses'; COMMENT ON COLUMN contracts.purse_pub IS 'public key of the purse that the contract is associated with'; COMMENT ON COLUMN contracts.contract_sig IS 'signature over the encrypted contract by the purse contract key'; COMMENT ON COLUMN contracts.pub_ckey IS 'Public ECDH key used to encrypt the contract, to be used with the purse private key for decryption'; COMMENT ON COLUMN contracts.e_contract IS 'AES-GCM encrypted contract terms (contains gzip compressed JSON after decryption)'; CREATE TABLE IF NOT EXISTS contracts_default PARTITION OF contracts FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_contracts_partition('default'); -- ------------------------------ history_requests ---------------------------------------- SELECT create_table_history_requests(); COMMENT ON TABLE history_requests IS 'Paid history requests issued by a client against a reserve'; COMMENT ON COLUMN history_requests.request_timestamp IS 'When was the history request made'; COMMENT ON COLUMN history_requests.reserve_sig IS 'Signature approving payment for the history request'; COMMENT ON COLUMN history_requests.history_fee_val IS 'History fee approved by the signature'; CREATE TABLE IF NOT EXISTS history_requests_default PARTITION OF history_requests FOR VALUES WITH (MODULUS 1, REMAINDER 0); -- ------------------------------ close_requests ---------------------------------------- SELECT create_table_close_requests(); COMMENT ON TABLE close_requests IS 'Explicit requests by a reserve owner to close a reserve immediately'; COMMENT ON COLUMN close_requests.close_timestamp IS 'When the request was created by the client'; COMMENT ON COLUMN close_requests.reserve_sig IS 'Signature affirming that the reserve is to be closed'; COMMENT ON COLUMN close_requests.close_val IS 'Balance of the reserve at the time of closing, to be wired to the associated bank account (minus the closing fee)'; COMMENT ON COLUMN close_requests.payto_uri IS 'Identifies the credited bank account. Optional.'; CREATE TABLE IF NOT EXISTS close_requests_default PARTITION OF close_requests FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_close_requests_partition('default'); -- ------------------------------ purse_deposits ---------------------------------------- SELECT create_table_purse_deposits(); COMMENT ON TABLE purse_deposits IS 'Requests depositing coins into a purse'; COMMENT ON COLUMN purse_deposits.partner_serial_id IS 'identifies the partner exchange, NULL in case the target purse lives at this exchange'; COMMENT ON COLUMN purse_deposits.purse_pub IS 'Public key of the purse'; COMMENT ON COLUMN purse_deposits.coin_pub IS 'Public key of the coin being deposited'; COMMENT ON COLUMN purse_deposits.amount_with_fee_val IS 'Total amount being deposited'; COMMENT ON COLUMN purse_deposits.coin_sig IS 'Signature of the coin affirming the deposit into the purse, of type TALER_SIGNATURE_PURSE_DEPOSIT'; CREATE TABLE IF NOT EXISTS purse_deposits_default PARTITION OF purse_deposits FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_purse_deposits_partition('default'); -- ------------------------------ wads_out ---------------------------------------- SELECT create_table_wads_out(); COMMENT ON TABLE wads_out IS 'Wire transfers made to another exchange to transfer purse funds'; COMMENT ON COLUMN wads_out.wad_id IS 'Unique identifier of the wad, part of the wire transfer subject'; COMMENT ON COLUMN wads_out.partner_serial_id IS 'target exchange of the wad'; COMMENT ON COLUMN wads_out.amount_val IS 'Amount that was wired'; COMMENT ON COLUMN wads_out.execution_time IS 'Time when the wire transfer was scheduled'; CREATE TABLE IF NOT EXISTS wads_out_default PARTITION OF wads_out FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_wads_out_partition('default'); -- ------------------------------ wads_out_entries ---------------------------------------- SELECT create_table_wad_out_entries(); COMMENT ON TABLE wad_out_entries IS 'Purses combined into a wad'; COMMENT ON COLUMN wad_out_entries.wad_out_serial_id IS 'Wad the purse was part of'; COMMENT ON COLUMN wad_out_entries.reserve_pub IS 'Target reserve for the purse'; COMMENT ON COLUMN wad_out_entries.purse_pub IS 'Public key of the purse'; COMMENT ON COLUMN wad_out_entries.h_contract IS 'Hash of the contract associated with the purse'; COMMENT ON COLUMN wad_out_entries.purse_expiration IS 'Time when the purse expires'; COMMENT ON COLUMN wad_out_entries.merge_timestamp IS 'Time when the merge was approved'; COMMENT ON COLUMN wad_out_entries.amount_with_fee_val IS 'Total amount in the purse'; COMMENT ON COLUMN wad_out_entries.wad_fee_val IS 'Wat fee charged to the purse'; COMMENT ON COLUMN wad_out_entries.deposit_fees_val IS 'Total deposit fees charged to the purse'; COMMENT ON COLUMN wad_out_entries.reserve_sig IS 'Signature by the receiving reserve, of purpose TALER_SIGNATURE_ACCOUNT_MERGE'; COMMENT ON COLUMN wad_out_entries.purse_sig IS 'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE'; CREATE TABLE IF NOT EXISTS wad_out_entries_default PARTITION OF wad_out_entries FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_wad_out_entries_partition('default'); -- ------------------------------ wads_in ---------------------------------------- SELECT create_table_wads_in(); COMMENT ON TABLE wads_in IS 'Incoming exchange-to-exchange wad wire transfers'; COMMENT ON COLUMN wads_in.wad_id IS 'Unique identifier of the wad, part of the wire transfer subject'; COMMENT ON COLUMN wads_in.origin_exchange_url IS 'Base URL of the originating URL, also part of the wire transfer subject'; COMMENT ON COLUMN wads_in.amount_val IS 'Actual amount that was received by our exchange'; COMMENT ON COLUMN wads_in.arrival_time IS 'Time when the wad was received'; CREATE TABLE IF NOT EXISTS wads_in_default PARTITION OF wads_in FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_wads_in_partition('default'); -- ------------------------------ wads_in_entries ---------------------------------------- SELECT create_table_wad_in_entries(); COMMENT ON TABLE wad_in_entries IS 'list of purses aggregated in a wad according to the sending exchange'; COMMENT ON COLUMN wad_in_entries.wad_in_serial_id IS 'wad for which the given purse was included in the aggregation'; COMMENT ON COLUMN wad_in_entries.reserve_pub IS 'target account of the purse (must be at the local exchange)'; COMMENT ON COLUMN wad_in_entries.purse_pub IS 'public key of the purse that was merged'; COMMENT ON COLUMN wad_in_entries.h_contract IS 'hash of the contract terms of the purse'; COMMENT ON COLUMN wad_in_entries.purse_expiration IS 'Time when the purse was set to expire'; COMMENT ON COLUMN wad_in_entries.merge_timestamp IS 'Time when the merge was approved'; COMMENT ON COLUMN wad_in_entries.amount_with_fee_val IS 'Total amount in the purse'; COMMENT ON COLUMN wad_in_entries.wad_fee_val IS 'Total wad fees paid by the purse'; COMMENT ON COLUMN wad_in_entries.deposit_fees_val IS 'Total deposit fees paid when depositing coins into the purse'; COMMENT ON COLUMN wad_in_entries.reserve_sig IS 'Signature by the receiving reserve, of purpose TALER_SIGNATURE_ACCOUNT_MERGE'; COMMENT ON COLUMN wad_in_entries.purse_sig IS 'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE'; CREATE TABLE IF NOT EXISTS wad_in_entries_default PARTITION OF wad_in_entries FOR VALUES WITH (MODULUS 1, REMAINDER 0); SELECT add_constraints_to_wad_in_entries_partition('default'); -- ------------------------------ partner_accounts ---------------------------------------- CREATE TABLE IF NOT EXISTS partner_accounts (payto_uri VARCHAR PRIMARY KEY ,partner_serial_id INT8 REFERENCES partners(partner_serial_id) ON DELETE CASCADE ,partner_master_sig BYTEA CHECK (LENGTH(partner_master_sig)=64) ,last_seen INT8 NOT NULL ); CREATE INDEX IF NOT EXISTS partner_accounts_index_by_partner_and_time ON partner_accounts (partner_serial_id,last_seen); COMMENT ON TABLE partner_accounts IS 'Table with bank accounts of the partner exchange. Entries never expire as we need to remember the signature for the auditor.'; COMMENT ON COLUMN partner_accounts.payto_uri IS 'payto URI (RFC 8905) with the bank account of the partner exchange.'; COMMENT ON COLUMN partner_accounts.partner_master_sig IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS by the partner master public key'; COMMENT ON COLUMN partner_accounts.last_seen IS 'Last time we saw this account as being active at the partner exchange. Used to select the most recent entry, and to detect when we should check again.'; ----------------------- router helper table (not synchronzied) ------------------------ CREATE TABLE IF NOT EXISTS purse_actions (purse_pub BYTEA NOT NULL PRIMARY KEY CHECK(LENGTH(purse_pub)=32) ,action_date INT8 NOT NULL ,partner_serial_id INT8 ); COMMENT ON TABLE purse_actions IS 'purses awaiting some action by the router'; COMMENT ON COLUMN purse_actions.purse_pub IS 'public (contract) key of the purse'; COMMENT ON COLUMN purse_actions.action_date IS 'when is the purse ready for action'; COMMENT ON COLUMN purse_actions.partner_serial_id IS 'wad target of an outgoing wire transfer, 0 for local, NULL if the purse is unmerged and thus the target is still unknown'; CREATE INDEX IF NOT EXISTS purse_action_by_target ON purse_actions (partner_serial_id,action_date); CREATE OR REPLACE FUNCTION purse_requests_insert_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN INSERT INTO purse_actions (purse_pub ,action_date) VALUES (NEW.purse_pub ,NEW.purse_expiration); RETURN NEW; END $$; COMMENT ON FUNCTION purse_requests_insert_trigger() IS 'When a purse is created, insert it into the purse_action table to take action when the purse expires.'; CREATE TRIGGER purse_requests_on_insert AFTER INSERT ON purse_requests FOR EACH ROW EXECUTE FUNCTION purse_requests_insert_trigger(); COMMENT ON TRIGGER purse_requests_on_insert ON purse_requests IS 'Here we install an entry for the purse expiration.';