merchant-0022.sql (6983B)
1 -- 2 -- This file is part of TALER 3 -- Copyright (C) 2025 Taler Systems SA 4 -- 5 -- TALER is free software; you can redistribute it and/or modify it under the 6 -- terms of the GNU General Public License as published by the Free Software 7 -- Foundation; either version 3, or (at your option) any later version. 8 -- 9 -- TALER is distributed in the hope that it will be useful, but WITHOUT ANY 10 -- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR 11 -- A PARTICULAR PURPOSE. See the GNU General Public License for more details. 12 -- 13 -- You should have received a copy of the GNU General Public License along with 14 -- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/> 15 -- 16 17 -- @file merchant-0022.sql 18 -- @brief Add phone number for merchant instances 19 -- @author Christian Grothoff 20 -- 21 -- @brief Create table to store donau related information 22 -- @author Bohdan Potuzhnyi 23 -- @author Vlada Svirsh 24 25 26 BEGIN; 27 28 -- Check patch versioning is in place. 29 SELECT _v.register_patch('merchant-0022', NULL, NULL); 30 31 SET search_path TO merchant; 32 33 ALTER TABLE merchant_used_tokens 34 DROP COLUMN merchant_serial; 35 36 ALTER TABLE merchant_instances 37 ADD COLUMN phone_number TEXT DEFAULT NULL, 38 ADD COLUMN phone_validated BOOL NOT NULL DEFAULT FALSE, 39 ADD COLUMN email_validated BOOL NOT NULL DEFAULT FALSE, 40 ADD COLUMN validation_needed BOOL NOT NULL DEFAULT FALSE, 41 ADD COLUMN validation_expiration INT8 NOT NULL DEFAULT 0, 42 DROP COLUMN user_type; 43 44 COMMENT ON COLUMN merchant_instances.phone_number 45 IS 'Phone number of the merchant to use for password reset (and to contact the merchant as the backend operator); optional if 2-FA is not used and/or for legacy instances'; 46 COMMENT ON COLUMN merchant_instances.phone_validated 47 IS 'TRUE if the merchant backend validated the phone number'; 48 COMMENT ON COLUMN merchant_instances.email_validated 49 IS 'TRUE if the merchant backend validated the e-mail address'; 50 COMMENT ON COLUMN merchant_instances.validation_needed 51 IS 'TRUE if this is a self-provisioned instance that still needs the recovery addresses to be validated'; 52 COMMENT ON COLUMN merchant_instances.validation_expiration 53 IS 'Time when the instance should be garbage collected if the recovery addresses remain unvalidated'; 54 55 CREATE INDEX merchant_instances_validation_expiration_gc 56 ON merchant_instances 57 (validation_expiration ASC) 58 WHERE validation_needed; 59 60 61 -- Create triggers to set confirmed/expected status on UPDATE. 62 CREATE FUNCTION merchant_expected_transfers_update_trigger() 63 RETURNS trigger 64 LANGUAGE plpgsql 65 AS $$ 66 BEGIN 67 UPDATE merchant_transfers 68 SET expected = TRUE 69 WHERE wtid = NEW.wtid 70 AND exchange_url = NEW.exchange_url 71 AND credit_amount = NEW.expected_credit_amount 72 AND NOT expected; 73 NEW.confirmed = NEW.confirmed OR FOUND; 74 RETURN NEW; 75 END $$; 76 COMMENT ON FUNCTION merchant_expected_transfers_update_trigger 77 IS 'Sets "confirmed" to TRUE for the new record if the expected transfer was already confirmed, and updates the already confirmed transfer to "expected"'; 78 79 -- Whenever an expected transfer is added, check if it was already confirmed 80 CREATE TRIGGER merchant_expected_transfers_on_update 81 BEFORE UPDATE 82 ON merchant.merchant_expected_transfers 83 FOR EACH ROW EXECUTE FUNCTION merchant_expected_transfers_update_trigger(); 84 85 86 CREATE TABLE IF NOT EXISTS merchant_donau_keys 87 (donau_keys_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE 88 ,donau_url TEXT PRIMARY KEY 89 ,keys_json TEXT NOT NULL 90 ,first_retry INT8 NOT NULL DEFAULT (0) 91 ); 92 93 COMMENT ON TABLE merchant_donau_keys 94 IS 'Here we store the cached /keys response from Donau in JSON format'; 95 COMMENT ON COLUMN merchant_donau_keys.donau_keys_serial 96 IS 'Unique serial identifier for each cached key entry'; 97 COMMENT ON COLUMN merchant_donau_keys.donau_url 98 IS 'Base URL of Donau associated with these keys'; 99 COMMENT ON COLUMN merchant_donau_keys.keys_json 100 IS 'JSON string of the /keys as generated by Donau'; 101 COMMENT ON COLUMN merchant_donau_keys.first_retry 102 IS 'Absolute time when this merchant may retry to fetch the keys from this donau at the earliest'; 103 104 CREATE TABLE IF NOT EXISTS merchant_donau_instances 105 (donau_instances_serial BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY 106 ,donau_url TEXT NOT NULL 107 ,charity_name TEXT NOT NULL 108 ,merchant_instance_serial INT8 NOT NULL 109 REFERENCES merchant_instances (merchant_serial) ON DELETE CASCADE 110 ,charity_id BIGINT NOT NULL 111 ,charity_max_per_year taler_amount_currency NOT NULL 112 ,charity_receipts_to_date taler_amount_currency NOT NULL 113 ,current_year INT8 NOT NULL 114 ); 115 116 COMMENT ON TABLE merchant_donau_instances 117 IS 'Here we store information about individual Donau instances, including details about associated charities and donation limits'; 118 COMMENT ON COLUMN merchant_donau_instances.donau_instances_serial 119 IS 'Unique serial identifier for each Donau instance'; 120 COMMENT ON COLUMN merchant_donau_instances.donau_url 121 IS 'The URL associated with the Donau system for this instance'; 122 COMMENT ON COLUMN merchant_donau_instances.merchant_instance_serial 123 IS 'The serial from merchant_instances whose public key is public key of the charity organization'; 124 COMMENT ON COLUMN merchant_donau_instances.charity_id 125 IS 'The unique identifier for the charity organization linked to this Donau instance'; 126 COMMENT ON COLUMN merchant_donau_instances.charity_max_per_year 127 IS 'Maximum allowable donation amount per year for the charity associated with this instance, stored in taler_amount_currency'; 128 COMMENT ON COLUMN merchant_donau_instances.charity_receipts_to_date 129 IS 'The total amount of donations received to date for this instance, stored in taler_amount_currency'; 130 COMMENT ON COLUMN merchant_donau_instances.current_year 131 IS 'The current year for tracking donations for this instance, stored as an 8-byte integer'; 132 133 CREATE TABLE IF NOT EXISTS merchant_order_token_blinded_sigs 134 (order_token_bs_serial BIGINT GENERATED BY DEFAULT AS IDENTITY 135 ,order_serial BIGINT NOT NULL 136 REFERENCES merchant_contract_terms (order_serial) ON DELETE CASCADE 137 ,token_index INT4 NOT NULL 138 ,token_blinded_signature BYTEA NOT NULL 139 ,token_hash BYTEA NOT NULL CHECK (LENGTH(token_hash)=64) 140 ,PRIMARY KEY (order_serial, token_index) 141 ); 142 143 COMMENT ON TABLE merchant_order_token_blinded_sigs 144 IS 'Table linking merchant orders with Donau BUDIS information'; 145 COMMENT ON COLUMN merchant_order_token_blinded_sigs.token_index 146 IS 'offset of the given signature in the output token array'; 147 COMMENT ON COLUMN merchant_order_token_blinded_sigs.order_token_bs_serial 148 IS 'Unique serial identifier for token order linkage'; 149 COMMENT ON COLUMN merchant_order_token_blinded_sigs.order_serial 150 IS 'Foreign key linking to the corresponding merchant order'; 151 COMMENT ON COLUMN merchant_order_token_blinded_sigs.token_blinded_signature 152 IS 'Blinded signature of the token associated with the order'; 153 COMMENT ON COLUMN merchant_order_token_blinded_sigs.token_hash 154 IS 'Hash of the token'; 155 156 157 COMMIT;