libeufin-bank-procedures.sql (62819B)
1 -- 2 -- This file is part of TALER 3 -- Copyright (C) 2023-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 BEGIN; 17 SET search_path TO libeufin_bank; 18 19 -- Remove all existing functions 20 DO 21 $do$ 22 DECLARE 23 _sql text; 24 BEGIN 25 SELECT INTO _sql 26 string_agg(format('DROP %s %s CASCADE;' 27 , CASE prokind 28 WHEN 'f' THEN 'FUNCTION' 29 WHEN 'p' THEN 'PROCEDURE' 30 END 31 , oid::regprocedure) 32 , E'\n') 33 FROM pg_proc 34 WHERE pronamespace = 'libeufin_bank'::regnamespace; 35 36 IF _sql IS NOT NULL THEN 37 EXECUTE _sql; 38 END IF; 39 END 40 $do$; 41 42 CREATE FUNCTION url_encode(input TEXT) 43 RETURNS TEXT 44 LANGUAGE plpgsql IMMUTABLE AS $$ 45 DECLARE 46 result TEXT := ''; 47 char TEXT; 48 BEGIN 49 FOR i IN 1..length(input) LOOP 50 char := substring(input FROM i FOR 1); 51 IF char ~ '[A-Za-z0-9\-._~]' THEN 52 result := result || char; 53 ELSE 54 result := result || '%' || lpad(upper(to_hex(ascii(char))), 2, '0'); 55 END IF; 56 END LOOP; 57 RETURN result; 58 END; 59 $$; 60 61 CREATE OR REPLACE FUNCTION sort_uniq(anyarray) 62 RETURNS anyarray LANGUAGE SQL IMMUTABLE AS $$ 63 SELECT COALESCE(array_agg(DISTINCT x ORDER BY x), $1[0:0]) 64 FROM unnest($1) AS t(x); 65 $$; 66 67 CREATE FUNCTION amount_normalize( 68 IN amount taler_amount 69 ,OUT normalized taler_amount 70 ) 71 LANGUAGE plpgsql IMMUTABLE AS $$ 72 BEGIN 73 normalized.val = amount.val + amount.frac / 100000000; 74 IF (normalized.val > 1::INT8<<52) THEN 75 RAISE EXCEPTION 'amount value overflowed'; 76 END IF; 77 normalized.frac = amount.frac % 100000000; 78 79 END $$; 80 COMMENT ON FUNCTION amount_normalize 81 IS 'Returns the normalized amount by adding to the .val the value of (.frac / 100000000) and removing the modulus 100000000 from .frac.' 82 'It raises an exception when the resulting .val is larger than 2^52'; 83 84 CREATE FUNCTION amount_add( 85 IN l taler_amount 86 ,IN r taler_amount 87 ,OUT sum taler_amount 88 ) 89 LANGUAGE plpgsql IMMUTABLE AS $$ 90 BEGIN 91 sum = (l.val + r.val, l.frac + r.frac); 92 SELECT normalized.val, normalized.frac INTO sum.val, sum.frac FROM amount_normalize(sum) as normalized; 93 END $$; 94 COMMENT ON FUNCTION amount_add 95 IS 'Returns the normalized sum of two amounts. It raises an exception when the resulting .val is larger than 2^52'; 96 97 CREATE FUNCTION amount_left_minus_right( 98 IN l taler_amount 99 ,IN r taler_amount 100 ,OUT diff taler_amount 101 ,OUT ok BOOLEAN 102 ) 103 LANGUAGE plpgsql IMMUTABLE AS $$ 104 BEGIN 105 diff = l; 106 IF diff.frac < r.frac THEN 107 IF diff.val <= 0 THEN 108 diff = (-1, -1); 109 ok = FALSE; 110 RETURN; 111 END IF; 112 diff.frac = diff.frac + 100000000; 113 diff.val = diff.val - 1; 114 END IF; 115 IF diff.val < r.val THEN 116 diff = (-1, -1); 117 ok = FALSE; 118 RETURN; 119 END IF; 120 diff.val = diff.val - r.val; 121 diff.frac = diff.frac - r.frac; 122 ok = TRUE; 123 END $$; 124 COMMENT ON FUNCTION amount_left_minus_right 125 IS 'Subtracts the right amount from the left and returns the difference and TRUE, if the left amount is larger than the right, or an invalid amount and FALSE otherwise.'; 126 127 CREATE FUNCTION account_balance_is_sufficient( 128 IN in_account_id INT8, 129 IN in_amount taler_amount, 130 IN in_wire_transfer_fees taler_amount, 131 IN in_min_amount taler_amount, 132 IN in_max_amount taler_amount, 133 OUT out_balance_insufficient BOOLEAN, 134 OUT out_bad_amount BOOLEAN 135 ) 136 LANGUAGE plpgsql STABLE AS $$ 137 DECLARE 138 account_has_debt BOOLEAN; 139 account_balance taler_amount; 140 account_max_debt taler_amount; 141 amount_with_fee taler_amount; 142 BEGIN 143 144 -- Check min and max 145 SELECT (SELECT in_min_amount IS NOT NULL AND NOT ok FROM amount_left_minus_right(in_amount, in_min_amount)) OR 146 (SELECT in_max_amount IS NOT NULL AND NOT ok FROM amount_left_minus_right(in_max_amount, in_amount)) 147 INTO out_bad_amount; 148 IF out_bad_amount THEN 149 RETURN; 150 END IF; 151 152 -- Add fees to the amount 153 IF in_wire_transfer_fees IS NOT NULL AND in_wire_transfer_fees != (0, 0)::taler_amount THEN 154 SELECT sum.val, sum.frac 155 INTO amount_with_fee.val, amount_with_fee.frac 156 FROM amount_add(in_amount, in_wire_transfer_fees) as sum; 157 ELSE 158 amount_with_fee = in_amount; 159 END IF; 160 161 -- Get account info, we expect the account to exist 162 SELECT 163 has_debt, 164 (balance).val, (balance).frac, 165 (max_debt).val, (max_debt).frac 166 INTO 167 account_has_debt, 168 account_balance.val, account_balance.frac, 169 account_max_debt.val, account_max_debt.frac 170 FROM bank_accounts WHERE bank_account_id=in_account_id; 171 172 -- Check enough funds 173 IF account_has_debt THEN 174 -- debt case: simply checking against the max debt allowed. 175 SELECT sum.val, sum.frac 176 INTO account_balance.val, account_balance.frac 177 FROM amount_add(account_balance, amount_with_fee) as sum; 178 SELECT NOT ok 179 INTO out_balance_insufficient 180 FROM amount_left_minus_right(account_max_debt, account_balance); 181 IF out_balance_insufficient THEN 182 RETURN; 183 END IF; 184 ELSE -- not a debt account 185 SELECT NOT ok 186 INTO out_balance_insufficient 187 FROM amount_left_minus_right(account_balance, amount_with_fee); 188 IF out_balance_insufficient THEN 189 -- debtor will switch to debt: determine their new negative balance. 190 SELECT 191 (diff).val, (diff).frac 192 INTO 193 account_balance.val, account_balance.frac 194 FROM amount_left_minus_right(amount_with_fee, account_balance); 195 SELECT NOT ok 196 INTO out_balance_insufficient 197 FROM amount_left_minus_right(account_max_debt, account_balance); 198 IF out_balance_insufficient THEN 199 RETURN; 200 END IF; 201 END IF; 202 END IF; 203 END $$; 204 COMMENT ON FUNCTION account_balance_is_sufficient IS 'Check if an account have enough fund to transfer an amount.'; 205 206 CREATE FUNCTION account_max_amount( 207 IN in_account_id INT8, 208 IN in_max_amount taler_amount, 209 OUT out_max_amount taler_amount 210 ) 211 LANGUAGE plpgsql STABLE AS $$ 212 BEGIN 213 -- add balance and max_debt 214 WITH computed AS ( 215 SELECT CASE has_debt 216 WHEN false THEN amount_add(balance, max_debt) 217 ELSE (SELECT diff FROM amount_left_minus_right(max_debt, balance)) 218 END AS amount 219 FROM bank_accounts WHERE bank_account_id=in_account_id 220 ) SELECT (amount).val, (amount).frac 221 INTO out_max_amount.val, out_max_amount.frac 222 FROM computed; 223 224 IF in_max_amount.val < out_max_amount.val 225 OR (in_max_amount.val = out_max_amount.val OR in_max_amount.frac < out_max_amount.frac) THEN 226 out_max_amount = in_max_amount; 227 END IF; 228 END $$; 229 230 CREATE FUNCTION create_token( 231 IN in_username TEXT, 232 IN in_content BYTEA, 233 IN in_creation_time INT8, 234 IN in_expiration_time INT8, 235 IN in_scope token_scope_enum, 236 IN in_refreshable BOOLEAN, 237 IN in_description TEXT, 238 IN in_is_tan BOOLEAN, 239 OUT out_tan_required BOOLEAN 240 ) 241 LANGUAGE plpgsql AS $$ 242 DECLARE 243 local_customer_id INT8; 244 BEGIN 245 -- Get account id and check if 2FA is required 246 SELECT customer_id, NOT in_is_tan AND cardinality(tan_channels) > 0 247 INTO local_customer_id, out_tan_required 248 FROM customers JOIN bank_accounts ON owning_customer_id = customer_id 249 WHERE username = in_username AND deleted_at IS NULL; 250 IF out_tan_required THEN 251 RETURN; 252 END IF; 253 INSERT INTO bearer_tokens ( 254 content, 255 creation_time, 256 expiration_time, 257 scope, 258 bank_customer, 259 is_refreshable, 260 description, 261 last_access 262 ) VALUES ( 263 in_content, 264 in_creation_time, 265 in_expiration_time, 266 in_scope, 267 local_customer_id, 268 in_refreshable, 269 in_description, 270 in_creation_time 271 ); 272 END $$; 273 274 CREATE FUNCTION bank_wire_transfer( 275 IN in_creditor_account_id INT8, 276 IN in_debtor_account_id INT8, 277 IN in_subject TEXT, 278 IN in_amount taler_amount, 279 IN in_timestamp INT8, 280 IN in_wire_transfer_fees taler_amount, 281 IN in_min_amount taler_amount, 282 IN in_max_amount taler_amount, 283 -- Error status 284 OUT out_balance_insufficient BOOLEAN, 285 OUT out_bad_amount BOOLEAN, 286 -- Success return 287 OUT out_credit_row_id INT8, 288 OUT out_debit_row_id INT8 289 ) 290 LANGUAGE plpgsql AS $$ 291 DECLARE 292 has_fee BOOLEAN; 293 amount_with_fee taler_amount; 294 admin_account_id INT8; 295 admin_has_debt BOOLEAN; 296 admin_balance taler_amount; 297 admin_payto TEXT; 298 admin_name TEXT; 299 debtor_has_debt BOOLEAN; 300 debtor_balance taler_amount; 301 debtor_max_debt taler_amount; 302 debtor_payto TEXT; 303 debtor_name TEXT; 304 creditor_has_debt BOOLEAN; 305 creditor_balance taler_amount; 306 creditor_payto TEXT; 307 creditor_name TEXT; 308 tmp_balance taler_amount; 309 BEGIN 310 -- Check min and max 311 SELECT (SELECT in_min_amount IS NOT NULL AND NOT ok FROM amount_left_minus_right(in_amount, in_min_amount)) OR 312 (SELECT in_max_amount IS NOT NULL AND NOT ok FROM amount_left_minus_right(in_max_amount, in_amount)) 313 INTO out_bad_amount; 314 IF out_bad_amount THEN 315 RETURN; 316 END IF; 317 318 has_fee = in_wire_transfer_fees IS NOT NULL AND in_wire_transfer_fees != (0, 0)::taler_amount; 319 IF has_fee THEN 320 -- Retrieve admin info 321 SELECT 322 bank_account_id, has_debt, 323 (balance).val, (balance).frac, 324 internal_payto, customers.name 325 INTO 326 admin_account_id, admin_has_debt, 327 admin_balance.val, admin_balance.frac, 328 admin_payto, admin_name 329 FROM bank_accounts 330 JOIN customers ON customer_id=owning_customer_id 331 WHERE username = 'admin'; 332 IF NOT FOUND THEN 333 RAISE EXCEPTION 'No admin'; 334 END IF; 335 END IF; 336 337 -- Retrieve debtor info 338 SELECT 339 has_debt, 340 (balance).val, (balance).frac, 341 (max_debt).val, (max_debt).frac, 342 internal_payto, customers.name 343 INTO 344 debtor_has_debt, 345 debtor_balance.val, debtor_balance.frac, 346 debtor_max_debt.val, debtor_max_debt.frac, 347 debtor_payto, debtor_name 348 FROM bank_accounts 349 JOIN customers ON customer_id=owning_customer_id 350 WHERE bank_account_id=in_debtor_account_id; 351 IF NOT FOUND THEN 352 RAISE EXCEPTION 'Unknown debtor %', in_debtor_account_id; 353 END IF; 354 -- Retrieve creditor info 355 SELECT 356 has_debt, 357 (balance).val, (balance).frac, 358 internal_payto, customers.name 359 INTO 360 creditor_has_debt, 361 creditor_balance.val, creditor_balance.frac, 362 creditor_payto, creditor_name 363 FROM bank_accounts 364 JOIN customers ON customer_id=owning_customer_id 365 WHERE bank_account_id=in_creditor_account_id; 366 IF NOT FOUND THEN 367 RAISE EXCEPTION 'Unknown creditor %', in_creditor_account_id; 368 END IF; 369 370 -- Add fees to the amount 371 IF has_fee AND admin_account_id != in_debtor_account_id THEN 372 SELECT sum.val, sum.frac 373 INTO amount_with_fee.val, amount_with_fee.frac 374 FROM amount_add(in_amount, in_wire_transfer_fees) as sum; 375 ELSE 376 has_fee=false; 377 amount_with_fee = in_amount; 378 END IF; 379 380 -- DEBTOR SIDE 381 -- check debtor has enough funds. 382 IF debtor_has_debt THEN 383 -- debt case: simply checking against the max debt allowed. 384 SELECT sum.val, sum.frac 385 INTO debtor_balance.val, debtor_balance.frac 386 FROM amount_add(debtor_balance, amount_with_fee) as sum; 387 SELECT NOT ok 388 INTO out_balance_insufficient 389 FROM amount_left_minus_right(debtor_max_debt, 390 debtor_balance); 391 IF out_balance_insufficient THEN 392 RETURN; 393 END IF; 394 ELSE -- not a debt account 395 SELECT 396 NOT ok, 397 (diff).val, (diff).frac 398 INTO 399 out_balance_insufficient, 400 tmp_balance.val, 401 tmp_balance.frac 402 FROM amount_left_minus_right(debtor_balance, 403 amount_with_fee); 404 IF NOT out_balance_insufficient THEN -- debtor has enough funds in the (positive) balance. 405 debtor_balance=tmp_balance; 406 ELSE -- debtor will switch to debt: determine their new negative balance. 407 SELECT 408 (diff).val, (diff).frac 409 INTO 410 debtor_balance.val, debtor_balance.frac 411 FROM amount_left_minus_right(amount_with_fee, 412 debtor_balance); 413 debtor_has_debt=TRUE; 414 SELECT NOT ok 415 INTO out_balance_insufficient 416 FROM amount_left_minus_right(debtor_max_debt, 417 debtor_balance); 418 IF out_balance_insufficient THEN 419 RETURN; 420 END IF; 421 END IF; 422 END IF; 423 424 -- CREDITOR SIDE. 425 -- Here we figure out whether the creditor would switch 426 -- from debit to a credit situation, and adjust the balance 427 -- accordingly. 428 IF NOT creditor_has_debt THEN -- easy case. 429 SELECT sum.val, sum.frac 430 INTO creditor_balance.val, creditor_balance.frac 431 FROM amount_add(creditor_balance, in_amount) as sum; 432 ELSE -- creditor had debit but MIGHT switch to credit. 433 SELECT 434 (diff).val, (diff).frac, 435 NOT ok 436 INTO 437 tmp_balance.val, tmp_balance.frac, 438 creditor_has_debt 439 FROM amount_left_minus_right(in_amount, 440 creditor_balance); 441 IF NOT creditor_has_debt THEN 442 creditor_balance=tmp_balance; 443 ELSE 444 -- the amount is not enough to bring the receiver 445 -- to a credit state, switch operators to calculate the new balance. 446 SELECT 447 (diff).val, (diff).frac 448 INTO creditor_balance.val, creditor_balance.frac 449 FROM amount_left_minus_right(creditor_balance, 450 in_amount); 451 END IF; 452 END IF; 453 454 -- ADMIN SIDE. 455 -- Here we figure out whether the administrator would switch 456 -- from debit to a credit situation, and adjust the balance 457 -- accordingly. 458 IF has_fee THEN 459 IF NOT admin_has_debt THEN -- easy case. 460 SELECT sum.val, sum.frac 461 INTO admin_balance.val, admin_balance.frac 462 FROM amount_add(admin_balance, in_wire_transfer_fees) as sum; 463 ELSE -- creditor had debit but MIGHT switch to credit. 464 SELECT (diff).val, (diff).frac, NOT ok 465 INTO 466 tmp_balance.val, tmp_balance.frac, 467 admin_has_debt 468 FROM amount_left_minus_right(in_wire_transfer_fees, admin_balance); 469 IF NOT admin_has_debt THEN 470 admin_balance=tmp_balance; 471 ELSE 472 -- the amount is not enough to bring the receiver 473 -- to a credit state, switch operators to calculate the new balance. 474 SELECT (diff).val, (diff).frac 475 INTO admin_balance.val, admin_balance.frac 476 FROM amount_left_minus_right(admin_balance, in_wire_transfer_fees); 477 END IF; 478 END IF; 479 END IF; 480 481 -- Lock account in order to prevent deadlocks 482 PERFORM FROM bank_accounts 483 WHERE bank_account_id IN (in_debtor_account_id, in_creditor_account_id, admin_account_id) 484 ORDER BY bank_account_id 485 FOR UPDATE; 486 487 -- now actually create the bank transaction. 488 -- debtor side: 489 INSERT INTO bank_account_transactions ( 490 creditor_payto 491 ,creditor_name 492 ,debtor_payto 493 ,debtor_name 494 ,subject 495 ,amount 496 ,transaction_date 497 ,direction 498 ,bank_account_id 499 ) 500 VALUES ( 501 creditor_payto, 502 creditor_name, 503 debtor_payto, 504 debtor_name, 505 in_subject, 506 in_amount, 507 in_timestamp, 508 'debit', 509 in_debtor_account_id 510 ) RETURNING bank_transaction_id INTO out_debit_row_id; 511 512 -- debtor side: 513 INSERT INTO bank_account_transactions ( 514 creditor_payto 515 ,creditor_name 516 ,debtor_payto 517 ,debtor_name 518 ,subject 519 ,amount 520 ,transaction_date 521 ,direction 522 ,bank_account_id 523 ) 524 VALUES ( 525 creditor_payto, 526 creditor_name, 527 debtor_payto, 528 debtor_name, 529 in_subject, 530 in_amount, 531 in_timestamp, 532 'credit', 533 in_creditor_account_id 534 ) RETURNING bank_transaction_id INTO out_credit_row_id; 535 536 -- checks and balances set up, now update bank accounts. 537 UPDATE bank_accounts 538 SET 539 balance=debtor_balance, 540 has_debt=debtor_has_debt 541 WHERE bank_account_id=in_debtor_account_id; 542 543 UPDATE bank_accounts 544 SET 545 balance=creditor_balance, 546 has_debt=creditor_has_debt 547 WHERE bank_account_id=in_creditor_account_id; 548 549 -- Fee part 550 IF has_fee THEN 551 INSERT INTO bank_account_transactions ( 552 creditor_payto 553 ,creditor_name 554 ,debtor_payto 555 ,debtor_name 556 ,subject 557 ,amount 558 ,transaction_date 559 ,direction 560 ,bank_account_id 561 ) 562 VALUES ( 563 admin_payto, 564 admin_name, 565 debtor_payto, 566 debtor_name, 567 'wire transfer fees for tx ' || out_debit_row_id, 568 in_wire_transfer_fees, 569 in_timestamp, 570 'debit', 571 in_debtor_account_id 572 ), ( 573 admin_payto, 574 admin_name, 575 debtor_payto, 576 debtor_name, 577 'wire transfer fees for tx ' || out_debit_row_id, 578 in_amount, 579 in_timestamp, 580 'credit', 581 admin_account_id 582 ); 583 584 UPDATE bank_accounts 585 SET 586 balance=admin_balance, 587 has_debt=admin_has_debt 588 WHERE bank_account_id=admin_account_id; 589 END IF; 590 591 -- notify new transaction 592 PERFORM pg_notify('bank_tx', in_debtor_account_id || ' ' || in_creditor_account_id || ' ' || out_debit_row_id || ' ' || out_credit_row_id); 593 END $$; 594 595 CREATE FUNCTION account_delete( 596 IN in_username TEXT, 597 IN in_timestamp INT8, 598 IN in_is_tan BOOLEAN, 599 OUT out_not_found BOOLEAN, 600 OUT out_balance_not_zero BOOLEAN, 601 OUT out_tan_required BOOLEAN 602 ) 603 LANGUAGE plpgsql AS $$ 604 DECLARE 605 my_customer_id INT8; 606 BEGIN 607 -- check if account exists, has zero balance and if 2FA is required 608 SELECT 609 customer_id 610 ,NOT in_is_tan AND cardinality(tan_channels) > 0 611 ,(balance).val != 0 OR (balance).frac != 0 612 INTO 613 my_customer_id 614 ,out_tan_required 615 ,out_balance_not_zero 616 FROM customers 617 JOIN bank_accounts ON owning_customer_id = customer_id 618 WHERE username = in_username AND deleted_at IS NULL; 619 IF NOT FOUND OR out_balance_not_zero OR out_tan_required THEN 620 out_not_found=NOT FOUND; 621 RETURN; 622 END IF; 623 624 -- actual deletion 625 UPDATE customers SET deleted_at = in_timestamp WHERE customer_id = my_customer_id; 626 END $$; 627 COMMENT ON FUNCTION account_delete IS 'Deletes an account if the balance is zero'; 628 629 CREATE PROCEDURE register_incoming( 630 IN in_tx_row_id INT8, 631 IN in_type taler_incoming_type, 632 IN in_metadata BYTEA, 633 IN in_account_id INT8 634 ) 635 LANGUAGE plpgsql AS $$ 636 DECLARE 637 local_amount taler_amount; 638 BEGIN 639 -- Register incoming transaction 640 INSERT INTO taler_exchange_incoming ( 641 metadata, 642 bank_transaction, 643 type 644 ) VALUES ( 645 in_metadata, 646 in_tx_row_id, 647 in_type 648 ); 649 -- Update stats 650 IF in_type = 'reserve' THEN 651 SELECT (amount).val, (amount).frac 652 INTO local_amount.val, local_amount.frac 653 FROM bank_account_transactions WHERE bank_transaction_id=in_tx_row_id; 654 CALL stats_register_payment('taler_in', NULL, local_amount, null); 655 END IF; 656 -- Notify new incoming transaction 657 PERFORM pg_notify('bank_incoming_tx', in_account_id || ' ' || in_tx_row_id); 658 END $$; 659 COMMENT ON PROCEDURE register_incoming 660 IS 'Register a bank transaction as a taler incoming transaction and announce it'; 661 662 663 CREATE FUNCTION taler_transfer( 664 IN in_request_uid BYTEA, 665 IN in_wtid BYTEA, 666 IN in_subject TEXT, 667 IN in_amount taler_amount, 668 IN in_exchange_base_url TEXT, 669 IN in_credit_account_payto TEXT, 670 IN in_username TEXT, 671 IN in_timestamp INT8, 672 IN in_conversion BOOLEAN, 673 -- Error status 674 OUT out_debtor_not_found BOOLEAN, 675 OUT out_debtor_not_exchange BOOLEAN, 676 OUT out_both_exchanges BOOLEAN, 677 OUT out_creditor_admin BOOLEAN, 678 OUT out_request_uid_reuse BOOLEAN, 679 OUT out_wtid_reuse BOOLEAN, 680 OUT out_exchange_balance_insufficient BOOLEAN, 681 -- Success return 682 OUT out_tx_row_id INT8, 683 OUT out_timestamp INT8 684 ) 685 LANGUAGE plpgsql AS $$ 686 DECLARE 687 exchange_account_id INT8; 688 creditor_account_id INT8; 689 account_conversion_rate_class_id INT8; 690 creditor_name TEXT; 691 creditor_admin BOOLEAN; 692 credit_row_id INT8; 693 debit_row_id INT8; 694 outgoing_id INT8; 695 bounce_tx INT8; 696 bounce_amount taler_amount; 697 BEGIN 698 -- Check for idempotence and conflict 699 SELECT (amount != in_amount 700 OR creditor_payto != in_credit_account_payto 701 OR exchange_base_url != in_exchange_base_url 702 OR wtid != in_wtid) 703 ,transfer_operation_id, transfer_date 704 INTO out_request_uid_reuse, out_tx_row_id, out_timestamp 705 FROM transfer_operations 706 WHERE request_uid = in_request_uid; 707 IF found THEN 708 RETURN; 709 END IF; 710 out_wtid_reuse = EXISTS(SELECT FROM transfer_operations WHERE wtid = in_wtid); 711 IF out_wtid_reuse THEN 712 RETURN; 713 END IF; 714 out_timestamp=in_timestamp; 715 -- Find exchange bank account id 716 SELECT 717 bank_account_id, NOT is_taler_exchange, conversion_rate_class_id 718 INTO exchange_account_id, out_debtor_not_exchange, account_conversion_rate_class_id 719 FROM bank_accounts 720 JOIN customers 721 ON customer_id=owning_customer_id 722 WHERE username = in_username AND deleted_at IS NULL; 723 out_debtor_not_found=NOT FOUND; 724 IF out_debtor_not_found OR out_debtor_not_exchange THEN 725 RETURN; 726 END IF; 727 -- Find creditor bank account id 728 SELECT 729 bank_account_id, is_taler_exchange, username = 'admin' 730 INTO creditor_account_id, out_both_exchanges, creditor_admin 731 FROM bank_accounts 732 JOIN customers ON owning_customer_id=customer_id 733 WHERE internal_payto = in_credit_account_payto; 734 IF NOT FOUND THEN 735 -- Register failure 736 INSERT INTO transfer_operations ( 737 request_uid, 738 wtid, 739 amount, 740 exchange_base_url, 741 transfer_date, 742 exchange_outgoing_id, 743 creditor_payto, 744 status, 745 status_msg, 746 exchange_id 747 ) VALUES ( 748 in_request_uid, 749 in_wtid, 750 in_amount, 751 in_exchange_base_url, 752 in_timestamp, 753 NULL, 754 in_credit_account_payto, 755 'permanent_failure', 756 'Unknown account', 757 exchange_account_id 758 ) RETURNING transfer_operation_id INTO out_tx_row_id; 759 RETURN; 760 ELSIF out_both_exchanges THEN 761 RETURN; 762 END IF; 763 764 IF creditor_admin THEN 765 -- Check conversion is enabled 766 IF NOT in_conversion THEN 767 out_creditor_admin=TRUE; 768 RETURN; 769 END IF; 770 771 -- Find the bounced transaction 772 SELECT (amount).val, (amount).frac, incoming_transaction_id 773 INTO bounce_amount.val, bounce_amount.frac, bounce_tx 774 FROM libeufin_nexus.incoming_transactions 775 JOIN libeufin_nexus.talerable_incoming_transactions USING (incoming_transaction_id) 776 WHERE metadata=in_wtid AND type='reserve'; 777 IF NOT FOUND THEN 778 -- Register failure 779 INSERT INTO transfer_operations ( 780 request_uid, 781 wtid, 782 amount, 783 exchange_base_url, 784 transfer_date, 785 exchange_outgoing_id, 786 creditor_payto, 787 status, 788 status_msg, 789 exchange_id 790 ) VALUES ( 791 in_request_uid, 792 in_wtid, 793 in_amount, 794 in_exchange_base_url, 795 in_timestamp, 796 NULL, 797 in_credit_account_payto, 798 'permanent_failure', 799 'Unknown bounced transaction', 800 exchange_account_id 801 ) RETURNING transfer_operation_id INTO out_tx_row_id; 802 RETURN; 803 END IF; 804 805 -- Bounce the transaction 806 PERFORM libeufin_nexus.bounce_incoming( 807 bounce_tx 808 ,((bounce_amount).val, (bounce_amount).frac)::libeufin_nexus.taler_amount 809 -- use gen_random_uuid to get some randomness 810 -- remove all - characters as they are not random 811 -- capitalise the UUID as some bank may still be case sensitive 812 -- end with 34 random chars which is valid for EBICS (max 35 chars) 813 ,upper(replace(gen_random_uuid()::text, '-', '')) 814 ,in_timestamp 815 ,'exchange bounced' 816 ); 817 END IF; 818 819 -- Check if this is a conversion bounce 820 out_creditor_admin=creditor_admin AND NOT in_conversion; 821 IF out_creditor_admin THEN 822 RETURN; 823 END IF; 824 825 -- Perform bank transfer 826 SELECT 827 out_balance_insufficient, 828 out_debit_row_id, out_credit_row_id 829 INTO 830 out_exchange_balance_insufficient, 831 debit_row_id, credit_row_id 832 FROM bank_wire_transfer( 833 creditor_account_id, 834 exchange_account_id, 835 in_subject, 836 in_amount, 837 in_timestamp, 838 NULL, 839 NULL, 840 NULL 841 ); 842 IF out_exchange_balance_insufficient THEN 843 RETURN; 844 END IF; 845 -- Register outgoing transaction 846 INSERT INTO taler_exchange_outgoing ( 847 bank_transaction 848 ) VALUES ( 849 debit_row_id 850 ) RETURNING exchange_outgoing_id INTO outgoing_id; 851 -- Update stats 852 CALL stats_register_payment('taler_out', NULL, in_amount, null); 853 -- Register success 854 INSERT INTO transfer_operations ( 855 request_uid, 856 wtid, 857 amount, 858 exchange_base_url, 859 transfer_date, 860 exchange_outgoing_id, 861 creditor_payto, 862 status, 863 status_msg, 864 exchange_id 865 ) VALUES ( 866 in_request_uid, 867 in_wtid, 868 in_amount, 869 in_exchange_base_url, 870 in_timestamp, 871 outgoing_id, 872 in_credit_account_payto, 873 'success', 874 NULL, 875 exchange_account_id 876 ) RETURNING transfer_operation_id INTO out_tx_row_id; 877 878 -- Notify new transaction 879 PERFORM pg_notify('bank_outgoing_tx', exchange_account_id || ' ' || creditor_account_id || ' ' || debit_row_id || ' ' || credit_row_id); 880 881 IF creditor_admin THEN 882 -- Create cashout operation 883 INSERT INTO cashout_operations ( 884 request_uid 885 ,amount_debit 886 ,amount_credit 887 ,creation_time 888 ,bank_account 889 ,subject 890 ,local_transaction 891 ) VALUES ( 892 NULL 893 ,in_amount 894 ,bounce_amount 895 ,in_timestamp 896 ,exchange_account_id 897 ,in_subject 898 ,debit_row_id 899 ); 900 901 -- update stats 902 CALL stats_register_payment('cashout', NULL, in_amount, bounce_amount); 903 END IF; 904 END $$; 905 COMMENT ON FUNCTION taler_transfer IS 'Create an outgoing taler transaction and register it'; 906 907 CREATE FUNCTION taler_add_incoming( 908 IN in_key BYTEA, 909 IN in_subject TEXT, 910 IN in_amount taler_amount, 911 IN in_debit_account_payto TEXT, 912 IN in_username TEXT, 913 IN in_timestamp INT8, 914 IN in_type taler_incoming_type, 915 -- Error status 916 OUT out_creditor_not_found BOOLEAN, 917 OUT out_creditor_not_exchange BOOLEAN, 918 OUT out_debtor_not_found BOOLEAN, 919 OUT out_both_exchanges BOOLEAN, 920 OUT out_reserve_pub_reuse BOOLEAN, 921 OUT out_debitor_balance_insufficient BOOLEAN, 922 -- Success return 923 OUT out_tx_row_id INT8 924 ) 925 LANGUAGE plpgsql AS $$ 926 DECLARE 927 exchange_bank_account_id INT8; 928 sender_bank_account_id INT8; 929 BEGIN 930 -- Check conflict 931 IF in_type = 'reserve'::taler_incoming_type THEN 932 SELECT EXISTS(SELECT FROM taler_exchange_incoming WHERE metadata = in_key AND type = 'reserve') OR 933 EXISTS(SELECT FROM taler_withdrawal_operations WHERE reserve_pub = in_key) 934 INTO out_reserve_pub_reuse; 935 IF out_reserve_pub_reuse THEN 936 RETURN; 937 END IF; 938 END IF; 939 -- Find exchange bank account id 940 SELECT 941 bank_account_id, NOT is_taler_exchange 942 INTO exchange_bank_account_id, out_creditor_not_exchange 943 FROM bank_accounts 944 JOIN customers 945 ON customer_id=owning_customer_id 946 WHERE username = in_username AND deleted_at IS NULL; 947 IF NOT FOUND OR out_creditor_not_exchange THEN 948 out_creditor_not_found=NOT FOUND; 949 RETURN; 950 END IF; 951 -- Find sender bank account id 952 SELECT 953 bank_account_id, is_taler_exchange 954 INTO sender_bank_account_id, out_both_exchanges 955 FROM bank_accounts 956 WHERE internal_payto = in_debit_account_payto; 957 IF NOT FOUND OR out_both_exchanges THEN 958 out_debtor_not_found=NOT FOUND; 959 RETURN; 960 END IF; 961 -- Perform bank transfer 962 SELECT 963 out_balance_insufficient, 964 out_credit_row_id 965 INTO 966 out_debitor_balance_insufficient, 967 out_tx_row_id 968 FROM bank_wire_transfer( 969 exchange_bank_account_id, 970 sender_bank_account_id, 971 in_subject, 972 in_amount, 973 in_timestamp, 974 NULL, 975 NULL, 976 NULL 977 ) as transfer; 978 IF out_debitor_balance_insufficient THEN 979 RETURN; 980 END IF; 981 -- Register incoming transaction 982 CALL register_incoming(out_tx_row_id, in_type, in_key, exchange_bank_account_id); 983 END $$; 984 COMMENT ON FUNCTION taler_add_incoming IS 'Create an incoming taler transaction and register it'; 985 986 CREATE FUNCTION bank_transaction( 987 IN in_credit_account_payto TEXT, 988 IN in_debit_account_username TEXT, 989 IN in_subject TEXT, 990 IN in_amount taler_amount, 991 IN in_timestamp INT8, 992 IN in_is_tan BOOLEAN, 993 IN in_request_uid BYTEA, 994 IN in_wire_transfer_fees taler_amount, 995 IN in_min_amount taler_amount, 996 IN in_max_amount taler_amount, 997 -- Error status 998 OUT out_creditor_not_found BOOLEAN, 999 OUT out_debtor_not_found BOOLEAN, 1000 OUT out_same_account BOOLEAN, 1001 OUT out_balance_insufficient BOOLEAN, 1002 OUT out_creditor_admin BOOLEAN, 1003 OUT out_tan_required BOOLEAN, 1004 OUT out_request_uid_reuse BOOLEAN, 1005 OUT out_bad_amount BOOLEAN, 1006 -- Success return 1007 OUT out_credit_bank_account_id INT8, 1008 OUT out_debit_bank_account_id INT8, 1009 OUT out_credit_row_id INT8, 1010 OUT out_debit_row_id INT8, 1011 OUT out_creditor_is_exchange BOOLEAN, 1012 OUT out_debtor_is_exchange BOOLEAN, 1013 OUT out_idempotent BOOLEAN 1014 ) 1015 LANGUAGE plpgsql AS $$ 1016 BEGIN 1017 -- Find credit bank account id and check it's not admin 1018 SELECT bank_account_id, is_taler_exchange, username='admin' 1019 INTO out_credit_bank_account_id, out_creditor_is_exchange, out_creditor_admin 1020 FROM bank_accounts 1021 JOIN customers ON customer_id=owning_customer_id 1022 WHERE internal_payto = in_credit_account_payto AND deleted_at IS NULL; 1023 IF NOT FOUND OR out_creditor_admin THEN 1024 out_creditor_not_found=NOT FOUND; 1025 RETURN; 1026 END IF; 1027 -- Find debit bank account ID and check it's a different account and if 2FA is required 1028 SELECT bank_account_id, is_taler_exchange, out_credit_bank_account_id=bank_account_id, NOT in_is_tan AND cardinality(tan_channels) > 0 1029 INTO out_debit_bank_account_id, out_debtor_is_exchange, out_same_account, out_tan_required 1030 FROM bank_accounts 1031 JOIN customers ON customer_id=owning_customer_id 1032 WHERE username = in_debit_account_username AND deleted_at IS NULL; 1033 IF NOT FOUND OR out_same_account THEN 1034 out_debtor_not_found=NOT FOUND; 1035 RETURN; 1036 END IF; 1037 -- Check for idempotence and conflict 1038 IF in_request_uid IS NOT NULL THEN 1039 SELECT (amount != in_amount 1040 OR subject != in_subject 1041 OR bank_account_id != out_debit_bank_account_id), bank_transaction 1042 INTO out_request_uid_reuse, out_debit_row_id 1043 FROM bank_transaction_operations 1044 JOIN bank_account_transactions ON bank_transaction = bank_transaction_id 1045 WHERE request_uid = in_request_uid; 1046 IF found OR out_tan_required THEN 1047 out_idempotent = found AND NOT out_request_uid_reuse; 1048 RETURN; 1049 END IF; 1050 ELSIF out_tan_required THEN 1051 RETURN; 1052 END IF; 1053 1054 -- Perform bank transfer 1055 SELECT 1056 transfer.out_balance_insufficient, 1057 transfer.out_bad_amount, 1058 transfer.out_credit_row_id, 1059 transfer.out_debit_row_id 1060 INTO 1061 out_balance_insufficient, 1062 out_bad_amount, 1063 out_credit_row_id, 1064 out_debit_row_id 1065 FROM bank_wire_transfer( 1066 out_credit_bank_account_id, 1067 out_debit_bank_account_id, 1068 in_subject, 1069 in_amount, 1070 in_timestamp, 1071 in_wire_transfer_fees, 1072 in_min_amount, 1073 in_max_amount 1074 ) as transfer; 1075 IF out_balance_insufficient OR out_bad_amount THEN 1076 RETURN; 1077 END IF; 1078 1079 -- Store operation 1080 IF in_request_uid IS NOT NULL THEN 1081 INSERT INTO bank_transaction_operations (request_uid, bank_transaction) 1082 VALUES (in_request_uid, out_debit_row_id); 1083 END IF; 1084 END $$; 1085 COMMENT ON FUNCTION bank_transaction IS 'Create a bank transaction'; 1086 1087 CREATE FUNCTION create_taler_withdrawal( 1088 IN in_account_username TEXT, 1089 IN in_withdrawal_uuid UUID, 1090 IN in_amount taler_amount, 1091 IN in_suggested_amount taler_amount, 1092 IN in_no_amount_to_wallet BOOLEAN, 1093 IN in_timestamp INT8, 1094 IN in_wire_transfer_fees taler_amount, 1095 IN in_min_amount taler_amount, 1096 IN in_max_amount taler_amount, 1097 -- Error status 1098 OUT out_account_not_found BOOLEAN, 1099 OUT out_account_is_exchange BOOLEAN, 1100 OUT out_balance_insufficient BOOLEAN, 1101 OUT out_bad_amount BOOLEAN 1102 ) 1103 LANGUAGE plpgsql AS $$ 1104 DECLARE 1105 account_id INT8; 1106 amount_with_fee taler_amount; 1107 BEGIN 1108 -- Check account exists 1109 SELECT bank_account_id, is_taler_exchange 1110 INTO account_id, out_account_is_exchange 1111 FROM bank_accounts 1112 JOIN customers ON bank_accounts.owning_customer_id = customers.customer_id 1113 WHERE username=in_account_username AND deleted_at IS NULL; 1114 IF NOT FOUND OR out_account_is_exchange THEN 1115 out_account_not_found=NOT FOUND; 1116 RETURN; 1117 END IF; 1118 1119 -- Check enough funds 1120 IF in_amount IS NOT NULL OR in_suggested_amount IS NOT NULL THEN 1121 SELECT test.out_balance_insufficient, test.out_bad_amount FROM account_balance_is_sufficient( 1122 account_id, 1123 COALESCE(in_amount, in_suggested_amount), 1124 in_wire_transfer_fees, 1125 in_min_amount, 1126 in_max_amount 1127 ) AS test INTO out_balance_insufficient, out_bad_amount; 1128 IF out_balance_insufficient OR out_bad_amount THEN 1129 RETURN; 1130 END IF; 1131 END IF; 1132 1133 -- Create withdrawal operation 1134 INSERT INTO taler_withdrawal_operations ( 1135 withdrawal_uuid, 1136 wallet_bank_account, 1137 amount, 1138 suggested_amount, 1139 no_amount_to_wallet, 1140 creation_date 1141 ) VALUES ( 1142 in_withdrawal_uuid, 1143 account_id, 1144 in_amount, 1145 in_suggested_amount, 1146 in_no_amount_to_wallet, 1147 in_timestamp 1148 ); 1149 END $$; 1150 COMMENT ON FUNCTION create_taler_withdrawal IS 'Create a new withdrawal operation'; 1151 1152 CREATE FUNCTION select_taler_withdrawal( 1153 IN in_withdrawal_uuid uuid, 1154 IN in_reserve_pub BYTEA, 1155 IN in_subject TEXT, 1156 IN in_selected_exchange_payto TEXT, 1157 IN in_amount taler_amount, 1158 IN in_wire_transfer_fees taler_amount, 1159 IN in_min_amount taler_amount, 1160 IN in_max_amount taler_amount, 1161 -- Error status 1162 OUT out_no_op BOOLEAN, 1163 OUT out_already_selected BOOLEAN, 1164 OUT out_reserve_pub_reuse BOOLEAN, 1165 OUT out_account_not_found BOOLEAN, 1166 OUT out_account_is_not_exchange BOOLEAN, 1167 OUT out_amount_differs BOOLEAN, 1168 OUT out_balance_insufficient BOOLEAN, 1169 OUT out_bad_amount BOOLEAN, 1170 OUT out_aborted BOOLEAN, 1171 -- Success return 1172 OUT out_status TEXT 1173 ) 1174 LANGUAGE plpgsql AS $$ 1175 DECLARE 1176 not_selected BOOLEAN; 1177 account_id int8; 1178 amount_with_fee taler_amount; 1179 BEGIN 1180 -- Check for conflict and idempotence 1181 SELECT 1182 NOT selection_done, 1183 aborted, 1184 CASE 1185 WHEN confirmation_done THEN 'confirmed' 1186 ELSE 'selected' 1187 END, 1188 selection_done 1189 AND (selected_exchange_payto != in_selected_exchange_payto OR reserve_pub != in_reserve_pub OR amount != in_amount), 1190 amount != in_amount, 1191 wallet_bank_account 1192 INTO not_selected, out_aborted, out_status, out_already_selected, out_amount_differs, account_id 1193 FROM taler_withdrawal_operations 1194 WHERE withdrawal_uuid=in_withdrawal_uuid; 1195 out_no_op = NOT FOUND; 1196 IF out_no_op OR out_aborted OR out_already_selected OR out_amount_differs THEN 1197 RETURN; 1198 END IF; 1199 1200 IF not_selected THEN 1201 -- Check reserve_pub reuse 1202 SELECT EXISTS(SELECT FROM taler_exchange_incoming WHERE metadata = in_reserve_pub AND type = 'reserve') OR 1203 EXISTS(SELECT FROM taler_withdrawal_operations WHERE reserve_pub = in_reserve_pub) 1204 INTO out_reserve_pub_reuse; 1205 IF out_reserve_pub_reuse THEN 1206 RETURN; 1207 END IF; 1208 1209 -- Check exchange account 1210 SELECT NOT is_taler_exchange 1211 INTO out_account_is_not_exchange 1212 FROM bank_accounts 1213 WHERE internal_payto=in_selected_exchange_payto; 1214 IF NOT FOUND OR out_account_is_not_exchange THEN 1215 out_account_not_found=NOT FOUND; 1216 RETURN; 1217 END IF; 1218 1219 IF in_amount IS NOT NULL THEN 1220 SELECT test.out_balance_insufficient, test.out_bad_amount FROM account_balance_is_sufficient( 1221 account_id, 1222 in_amount, 1223 in_wire_transfer_fees, 1224 in_min_amount, 1225 in_max_amount 1226 ) AS test INTO out_balance_insufficient, out_bad_amount; 1227 IF out_balance_insufficient OR out_bad_amount THEN 1228 RETURN; 1229 END IF; 1230 END IF; 1231 1232 -- Update withdrawal operation 1233 UPDATE taler_withdrawal_operations 1234 SET selected_exchange_payto=in_selected_exchange_payto, 1235 reserve_pub=in_reserve_pub, 1236 subject=in_subject, 1237 selection_done=true, 1238 amount=COALESCE(amount, in_amount) 1239 WHERE withdrawal_uuid=in_withdrawal_uuid; 1240 1241 -- Notify status change 1242 PERFORM pg_notify('bank_withdrawal_status', in_withdrawal_uuid::text || ' selected'); 1243 END IF; 1244 END $$; 1245 COMMENT ON FUNCTION select_taler_withdrawal IS 'Set details of a withdrawal operation'; 1246 1247 CREATE FUNCTION abort_taler_withdrawal( 1248 IN in_withdrawal_uuid uuid, 1249 IN in_username TEXT, 1250 OUT out_no_op BOOLEAN, 1251 OUT out_already_confirmed BOOLEAN 1252 ) 1253 LANGUAGE plpgsql AS $$ 1254 BEGIN 1255 UPDATE taler_withdrawal_operations 1256 SET aborted = NOT confirmation_done 1257 FROM bank_accounts 1258 JOIN customers ON owning_customer_id=customer_id 1259 WHERE withdrawal_uuid=in_withdrawal_uuid 1260 AND wallet_bank_account=bank_account_id 1261 AND (in_username IS NULL OR username = in_username) 1262 RETURNING confirmation_done 1263 INTO out_already_confirmed; 1264 IF NOT FOUND OR out_already_confirmed THEN 1265 out_no_op=NOT FOUND; 1266 RETURN; 1267 END IF; 1268 1269 -- Notify status change 1270 PERFORM pg_notify('bank_withdrawal_status', in_withdrawal_uuid::text || ' aborted'); 1271 END $$; 1272 COMMENT ON FUNCTION abort_taler_withdrawal IS 'Abort a withdrawal operation.'; 1273 1274 CREATE FUNCTION confirm_taler_withdrawal( 1275 IN in_username TEXT, 1276 IN in_withdrawal_uuid uuid, 1277 IN in_timestamp INT8, 1278 IN in_is_tan BOOLEAN, 1279 IN in_wire_transfer_fees taler_amount, 1280 IN in_min_amount taler_amount, 1281 IN in_max_amount taler_amount, 1282 IN in_amount taler_amount, 1283 OUT out_no_op BOOLEAN, 1284 OUT out_balance_insufficient BOOLEAN, 1285 OUT out_bad_amount BOOLEAN, 1286 OUT out_creditor_not_found BOOLEAN, 1287 OUT out_exchange_not_found BOOLEAN, 1288 OUT out_not_selected BOOLEAN, 1289 OUT out_missing_amount BOOLEAN, 1290 OUT out_amount_differs BOOLEAN, 1291 OUT out_aborted BOOLEAN, 1292 OUT out_tan_required BOOLEAN 1293 ) 1294 LANGUAGE plpgsql AS $$ 1295 DECLARE 1296 already_confirmed BOOLEAN; 1297 subject_local TEXT; 1298 reserve_pub_local BYTEA; 1299 selected_exchange_payto_local TEXT; 1300 wallet_bank_account_local INT8; 1301 amount_local taler_amount; 1302 exchange_bank_account_id INT8; 1303 tx_row_id INT8; 1304 BEGIN 1305 -- Check op exists and conflict 1306 SELECT 1307 confirmation_done, 1308 aborted, NOT selection_done, 1309 reserve_pub, subject, 1310 selected_exchange_payto, 1311 wallet_bank_account, 1312 (amount).val, (amount).frac, 1313 NOT in_is_tan AND cardinality(tan_channels) > 0, 1314 amount IS NULL AND in_amount IS NULL, 1315 amount != in_amount 1316 INTO 1317 already_confirmed, 1318 out_aborted, out_not_selected, 1319 reserve_pub_local, subject_local, 1320 selected_exchange_payto_local, 1321 wallet_bank_account_local, 1322 amount_local.val, amount_local.frac, 1323 out_tan_required, 1324 out_missing_amount, 1325 out_amount_differs 1326 FROM taler_withdrawal_operations 1327 JOIN bank_accounts ON wallet_bank_account=bank_account_id 1328 JOIN customers ON owning_customer_id=customer_id 1329 WHERE withdrawal_uuid=in_withdrawal_uuid AND username=in_username AND deleted_at IS NULL; 1330 out_no_op=NOT FOUND; 1331 IF out_no_op OR already_confirmed OR out_aborted OR out_not_selected OR out_missing_amount OR out_amount_differs THEN 1332 RETURN; 1333 ELSIF in_amount IS NOT NULL THEN 1334 amount_local = in_amount; 1335 END IF; 1336 1337 -- Check exchange account then 2fa 1338 SELECT 1339 bank_account_id 1340 INTO exchange_bank_account_id 1341 FROM bank_accounts 1342 WHERE internal_payto = selected_exchange_payto_local; 1343 IF NOT FOUND OR out_tan_required THEN 1344 out_exchange_not_found=NOT FOUND; 1345 RETURN; 1346 END IF; 1347 1348 SELECT -- not checking for accounts existence, as it was done above. 1349 transfer.out_balance_insufficient, 1350 transfer.out_bad_amount, 1351 out_credit_row_id 1352 INTO out_balance_insufficient, out_bad_amount, tx_row_id 1353 FROM bank_wire_transfer( 1354 exchange_bank_account_id, 1355 wallet_bank_account_local, 1356 subject_local, 1357 amount_local, 1358 in_timestamp, 1359 in_wire_transfer_fees, 1360 in_min_amount, 1361 in_max_amount 1362 ) as transfer; 1363 IF out_balance_insufficient OR out_bad_amount THEN 1364 RETURN; 1365 END IF; 1366 1367 -- Confirm operation and update amount 1368 UPDATE taler_withdrawal_operations 1369 SET amount=amount_local, confirmation_done = true 1370 WHERE withdrawal_uuid=in_withdrawal_uuid; 1371 1372 -- Register incoming transaction 1373 CALL register_incoming(tx_row_id, 'reserve'::taler_incoming_type, reserve_pub_local, exchange_bank_account_id); 1374 1375 -- Notify status change 1376 PERFORM pg_notify('bank_withdrawal_status', in_withdrawal_uuid::text || ' confirmed'); 1377 END $$; 1378 COMMENT ON FUNCTION confirm_taler_withdrawal 1379 IS 'Set a withdrawal operation as confirmed and wire the funds to the exchange.'; 1380 1381 CREATE FUNCTION cashin( 1382 IN in_timestamp INT8, 1383 IN in_reserve_pub BYTEA, 1384 IN in_amount taler_amount, 1385 IN in_subject TEXT, 1386 -- Error status 1387 OUT out_no_account BOOLEAN, 1388 OUT out_too_small BOOLEAN, 1389 OUT out_balance_insufficient BOOLEAN 1390 ) 1391 LANGUAGE plpgsql AS $$ 1392 DECLARE 1393 converted_amount taler_amount; 1394 admin_account_id INT8; 1395 exchange_account_id INT8; 1396 exchange_conversion_rate_class_id INT8; 1397 tx_row_id INT8; 1398 BEGIN 1399 -- TODO check reserve_pub reuse ? 1400 1401 -- Recover exchange account info 1402 SELECT bank_account_id, conversion_rate_class_id 1403 INTO exchange_account_id, exchange_conversion_rate_class_id 1404 FROM bank_accounts 1405 JOIN customers 1406 ON customer_id=owning_customer_id 1407 WHERE username = 'exchange'; 1408 IF NOT FOUND THEN 1409 out_no_account = true; 1410 RETURN; 1411 END IF; 1412 1413 -- Retrieve admin account id 1414 SELECT bank_account_id 1415 INTO admin_account_id 1416 FROM bank_accounts 1417 JOIN customers 1418 ON customer_id=owning_customer_id 1419 WHERE username = 'admin'; 1420 1421 -- Perform conversion 1422 SELECT (converted).val, (converted).frac, too_small 1423 INTO converted_amount.val, converted_amount.frac, out_too_small 1424 FROM conversion_to(in_amount, 'cashin'::text, exchange_conversion_rate_class_id); 1425 IF out_too_small THEN 1426 RETURN; 1427 END IF; 1428 1429 -- Perform bank wire transfer 1430 SELECT 1431 transfer.out_balance_insufficient, 1432 transfer.out_credit_row_id 1433 INTO 1434 out_balance_insufficient, 1435 tx_row_id 1436 FROM bank_wire_transfer( 1437 exchange_account_id, 1438 admin_account_id, 1439 in_subject, 1440 converted_amount, 1441 in_timestamp, 1442 NULL, 1443 NULL, 1444 NULL 1445 ) as transfer; 1446 IF out_balance_insufficient THEN 1447 RETURN; 1448 END IF; 1449 1450 -- Register incoming transaction 1451 CALL register_incoming(tx_row_id, 'reserve'::taler_incoming_type, in_reserve_pub, exchange_account_id); 1452 1453 -- update stats 1454 CALL stats_register_payment('cashin', NULL, converted_amount, in_amount); 1455 1456 END $$; 1457 COMMENT ON FUNCTION cashin IS 'Perform a cashin operation'; 1458 1459 1460 CREATE FUNCTION cashout_create( 1461 IN in_username TEXT, 1462 IN in_request_uid BYTEA, 1463 IN in_amount_debit taler_amount, 1464 IN in_amount_credit taler_amount, 1465 IN in_subject TEXT, 1466 IN in_timestamp INT8, 1467 IN in_is_tan BOOLEAN, 1468 -- Error status 1469 OUT out_bad_conversion BOOLEAN, 1470 OUT out_account_not_found BOOLEAN, 1471 OUT out_account_is_exchange BOOLEAN, 1472 OUT out_balance_insufficient BOOLEAN, 1473 OUT out_request_uid_reuse BOOLEAN, 1474 OUT out_no_cashout_payto BOOLEAN, 1475 OUT out_tan_required BOOLEAN, 1476 OUT out_under_min BOOLEAN, 1477 -- Success return 1478 OUT out_cashout_id INT8 1479 ) 1480 LANGUAGE plpgsql AS $$ 1481 DECLARE 1482 account_id INT8; 1483 account_conversion_rate_class_id INT8; 1484 account_cashout_payto TEXT; 1485 admin_account_id INT8; 1486 tx_id INT8; 1487 BEGIN 1488 1489 -- Check account exists, has all info and if 2FA is required 1490 SELECT 1491 bank_account_id, is_taler_exchange, conversion_rate_class_id, 1492 -- Remove potential residual query string an add the receiver_name 1493 split_part(cashout_payto, '?', 1) || '?receiver-name=' || url_encode(name), 1494 NOT in_is_tan AND cardinality(tan_channels) > 0 1495 INTO 1496 account_id, out_account_is_exchange, account_conversion_rate_class_id, 1497 account_cashout_payto, out_tan_required 1498 FROM bank_accounts 1499 JOIN customers ON owning_customer_id=customer_id 1500 WHERE username=in_username; 1501 IF NOT FOUND THEN 1502 out_account_not_found=TRUE; 1503 RETURN; 1504 ELSIF account_cashout_payto IS NULL THEN 1505 out_no_cashout_payto=TRUE; 1506 RETURN; 1507 ELSIF out_account_is_exchange THEN 1508 RETURN; 1509 END IF; 1510 1511 -- check conversion 1512 SELECT under_min, too_small OR in_amount_credit!=converted 1513 INTO out_under_min, out_bad_conversion 1514 FROM conversion_to(in_amount_debit, 'cashout'::text, account_conversion_rate_class_id); 1515 IF out_bad_conversion THEN 1516 RETURN; 1517 END IF; 1518 1519 -- Retrieve admin account id 1520 SELECT bank_account_id 1521 INTO admin_account_id 1522 FROM bank_accounts 1523 JOIN customers 1524 ON customer_id=owning_customer_id 1525 WHERE username = 'admin'; 1526 1527 -- Check for idempotence and conflict 1528 SELECT (amount_debit != in_amount_debit 1529 OR subject != in_subject 1530 OR bank_account != account_id) 1531 , cashout_id 1532 INTO out_request_uid_reuse, out_cashout_id 1533 FROM cashout_operations 1534 WHERE request_uid = in_request_uid; 1535 IF found OR out_request_uid_reuse OR out_tan_required THEN 1536 RETURN; 1537 END IF; 1538 1539 -- Perform bank wire transfer 1540 SELECT transfer.out_balance_insufficient, out_debit_row_id 1541 INTO out_balance_insufficient, tx_id 1542 FROM bank_wire_transfer( 1543 admin_account_id, 1544 account_id, 1545 in_subject, 1546 in_amount_debit, 1547 in_timestamp, 1548 NULL, 1549 NULL, 1550 NULL 1551 ) as transfer; 1552 IF out_balance_insufficient THEN 1553 RETURN; 1554 END IF; 1555 1556 -- Create cashout operation 1557 INSERT INTO cashout_operations ( 1558 request_uid 1559 ,amount_debit 1560 ,amount_credit 1561 ,creation_time 1562 ,bank_account 1563 ,subject 1564 ,local_transaction 1565 ) VALUES ( 1566 in_request_uid 1567 ,in_amount_debit 1568 ,in_amount_credit 1569 ,in_timestamp 1570 ,account_id 1571 ,in_subject 1572 ,tx_id 1573 ) RETURNING cashout_id INTO out_cashout_id; 1574 1575 -- Initiate libeufin-nexus transaction 1576 INSERT INTO libeufin_nexus.initiated_outgoing_transactions ( 1577 amount 1578 ,subject 1579 ,credit_payto 1580 ,initiation_time 1581 ,end_to_end_id 1582 ) VALUES ( 1583 ((in_amount_credit).val, (in_amount_credit).frac)::libeufin_nexus.taler_amount 1584 ,in_subject 1585 ,account_cashout_payto 1586 ,in_timestamp 1587 -- use gen_random_uuid to get some randomness 1588 -- remove all - characters as they are not random 1589 -- capitalise the UUID as some bank may still be case sensitive 1590 -- end with 34 random chars which is valid for EBICS (max 35 chars) 1591 ,upper(replace(gen_random_uuid()::text, '-', '')) 1592 ); 1593 1594 -- update stats 1595 CALL stats_register_payment('cashout', NULL, in_amount_debit, in_amount_credit); 1596 END $$; 1597 1598 CREATE FUNCTION tan_challenge_mark_sent ( 1599 IN in_uuid UUID, 1600 IN in_timestamp INT8, 1601 IN in_retransmission_period INT8 1602 ) RETURNS void 1603 LANGUAGE sql AS $$ 1604 UPDATE tan_challenges SET 1605 retransmission_date = in_timestamp + in_retransmission_period 1606 WHERE uuid = in_uuid; 1607 $$; 1608 COMMENT ON FUNCTION tan_challenge_mark_sent IS 'Register a challenge as successfully sent'; 1609 1610 CREATE FUNCTION tan_challenge_try ( 1611 IN in_uuid UUID, 1612 IN in_code TEXT, 1613 IN in_timestamp INT8, 1614 -- Error status 1615 OUT out_ok BOOLEAN, 1616 OUT out_no_op BOOLEAN, 1617 OUT out_no_retry BOOLEAN, 1618 OUT out_expired BOOLEAN, 1619 -- Success return 1620 OUT out_op op_enum, 1621 OUT out_channel tan_enum, 1622 OUT out_info TEXT 1623 ) 1624 LANGUAGE plpgsql as $$ 1625 DECLARE 1626 account_id INT8; 1627 token_creation BOOLEAN; 1628 BEGIN 1629 1630 -- Try to solve challenge 1631 UPDATE tan_challenges SET 1632 confirmation_date = CASE 1633 WHEN (retry_counter > 0 AND in_timestamp < expiration_date AND code = in_code) THEN in_timestamp 1634 ELSE confirmation_date 1635 END, 1636 retry_counter = retry_counter - 1 1637 WHERE uuid = in_uuid 1638 RETURNING 1639 confirmation_date IS NOT NULL, 1640 retry_counter <= 0 AND confirmation_date IS NULL, 1641 in_timestamp >= expiration_date AND confirmation_date IS NULL, 1642 op = 'create_token', 1643 customer 1644 INTO out_ok, out_no_retry, out_expired, token_creation, account_id; 1645 out_no_op = NOT FOUND; 1646 1647 IF NOT out_ok AND token_creation THEN 1648 UPDATE customers SET token_creation_counter=token_creation_counter+1 WHERE customer_id=account_id; 1649 END IF; 1650 1651 IF out_no_op OR NOT out_ok OR out_no_retry OR out_expired THEN 1652 RETURN; 1653 END IF; 1654 1655 -- Recover body and op from challenge 1656 SELECT op, tan_channel, tan_info 1657 INTO out_op, out_channel, out_info 1658 FROM tan_challenges WHERE uuid = in_uuid; 1659 END $$; 1660 COMMENT ON FUNCTION tan_challenge_try IS 'Try to confirm a challenge, return true if the challenge have been confirmed'; 1661 1662 CREATE FUNCTION stats_get_frame( 1663 IN date TIMESTAMP, 1664 IN in_timeframe stat_timeframe_enum, 1665 OUT cashin_count INT8, 1666 OUT cashin_regional_volume taler_amount, 1667 OUT cashin_fiat_volume taler_amount, 1668 OUT cashout_count INT8, 1669 OUT cashout_regional_volume taler_amount, 1670 OUT cashout_fiat_volume taler_amount, 1671 OUT taler_in_count INT8, 1672 OUT taler_in_volume taler_amount, 1673 OUT taler_out_count INT8, 1674 OUT taler_out_volume taler_amount 1675 ) 1676 LANGUAGE plpgsql AS $$ 1677 BEGIN 1678 date = date_trunc(in_timeframe::text, date); 1679 SELECT 1680 s.cashin_count 1681 ,(s.cashin_regional_volume).val 1682 ,(s.cashin_regional_volume).frac 1683 ,(s.cashin_fiat_volume).val 1684 ,(s.cashin_fiat_volume).frac 1685 ,s.cashout_count 1686 ,(s.cashout_regional_volume).val 1687 ,(s.cashout_regional_volume).frac 1688 ,(s.cashout_fiat_volume).val 1689 ,(s.cashout_fiat_volume).frac 1690 ,s.taler_in_count 1691 ,(s.taler_in_volume).val 1692 ,(s.taler_in_volume).frac 1693 ,s.taler_out_count 1694 ,(s.taler_out_volume).val 1695 ,(s.taler_out_volume).frac 1696 INTO 1697 cashin_count 1698 ,cashin_regional_volume.val 1699 ,cashin_regional_volume.frac 1700 ,cashin_fiat_volume.val 1701 ,cashin_fiat_volume.frac 1702 ,cashout_count 1703 ,cashout_regional_volume.val 1704 ,cashout_regional_volume.frac 1705 ,cashout_fiat_volume.val 1706 ,cashout_fiat_volume.frac 1707 ,taler_in_count 1708 ,taler_in_volume.val 1709 ,taler_in_volume.frac 1710 ,taler_out_count 1711 ,taler_out_volume.val 1712 ,taler_out_volume.frac 1713 FROM bank_stats AS s 1714 WHERE s.timeframe = in_timeframe 1715 AND s.start_time = date; 1716 END $$; 1717 1718 CREATE PROCEDURE stats_register_payment( 1719 IN name TEXT, 1720 IN now TIMESTAMP, 1721 IN regional_amount taler_amount, 1722 IN fiat_amount taler_amount 1723 ) 1724 LANGUAGE plpgsql AS $$ 1725 BEGIN 1726 IF now IS NULL THEN 1727 now = timezone('utc', now())::TIMESTAMP; 1728 END IF; 1729 IF name = 'taler_in' THEN 1730 INSERT INTO bank_stats AS s ( 1731 timeframe, 1732 start_time, 1733 taler_in_count, 1734 taler_in_volume 1735 ) SELECT 1736 frame, 1737 date_trunc(frame::text, now), 1738 1, 1739 regional_amount 1740 FROM unnest(enum_range(null::stat_timeframe_enum)) AS frame 1741 ON CONFLICT (timeframe, start_time) DO UPDATE 1742 SET taler_in_count=s.taler_in_count+1, 1743 taler_in_volume=(SELECT amount_add(s.taler_in_volume, regional_amount)); 1744 ELSIF name = 'taler_out' THEN 1745 INSERT INTO bank_stats AS s ( 1746 timeframe, 1747 start_time, 1748 taler_out_count, 1749 taler_out_volume 1750 ) SELECT 1751 frame, 1752 date_trunc(frame::text, now), 1753 1, 1754 regional_amount 1755 FROM unnest(enum_range(null::stat_timeframe_enum)) AS frame 1756 ON CONFLICT (timeframe, start_time) DO UPDATE 1757 SET taler_out_count=s.taler_out_count+1, 1758 taler_out_volume=(SELECT amount_add(s.taler_out_volume, regional_amount)); 1759 ELSIF name = 'cashin' THEN 1760 INSERT INTO bank_stats AS s ( 1761 timeframe, 1762 start_time, 1763 cashin_count, 1764 cashin_regional_volume, 1765 cashin_fiat_volume 1766 ) SELECT 1767 frame, 1768 date_trunc(frame::text, now), 1769 1, 1770 regional_amount, 1771 fiat_amount 1772 FROM unnest(enum_range(null::stat_timeframe_enum)) AS frame 1773 ON CONFLICT (timeframe, start_time) DO UPDATE 1774 SET cashin_count=s.cashin_count+1, 1775 cashin_regional_volume=(SELECT amount_add(s.cashin_regional_volume, regional_amount)), 1776 cashin_fiat_volume=(SELECT amount_add(s.cashin_fiat_volume, fiat_amount)); 1777 ELSIF name = 'cashout' THEN 1778 INSERT INTO bank_stats AS s ( 1779 timeframe, 1780 start_time, 1781 cashout_count, 1782 cashout_regional_volume, 1783 cashout_fiat_volume 1784 ) SELECT 1785 frame, 1786 date_trunc(frame::text, now), 1787 1, 1788 regional_amount, 1789 fiat_amount 1790 FROM unnest(enum_range(null::stat_timeframe_enum)) AS frame 1791 ON CONFLICT (timeframe, start_time) DO UPDATE 1792 SET cashout_count=s.cashout_count+1, 1793 cashout_regional_volume=(SELECT amount_add(s.cashout_regional_volume, regional_amount)), 1794 cashout_fiat_volume=(SELECT amount_add(s.cashout_fiat_volume, fiat_amount)); 1795 ELSE 1796 RAISE EXCEPTION 'Unknown stat %', name; 1797 END IF; 1798 END $$; 1799 1800 CREATE FUNCTION conversion_apply_ratio( 1801 IN amount taler_amount 1802 ,IN ratio taler_amount 1803 ,IN fee taler_amount 1804 ,IN tiny taler_amount -- Result is rounded to this amount 1805 ,IN rounding rounding_mode -- With this rounding mode 1806 ,OUT result taler_amount 1807 ,OUT out_too_small BOOLEAN 1808 ) 1809 LANGUAGE plpgsql IMMUTABLE AS $$ 1810 DECLARE 1811 amount_numeric NUMERIC(33, 8); -- 16 digit for val, 8 for frac and 1 for rounding error 1812 tiny_numeric NUMERIC(24); 1813 BEGIN 1814 -- Handle no config case 1815 IF ratio = (0, 0)::taler_amount THEN 1816 out_too_small=TRUE; 1817 RETURN; 1818 END IF; 1819 1820 -- Perform multiplication using big numbers 1821 amount_numeric = (amount.val::numeric(24) * 100000000 + amount.frac::numeric(24)) * (ratio.val::numeric(24, 8) + ratio.frac::numeric(24, 8) / 100000000); 1822 1823 -- Apply fees 1824 amount_numeric = amount_numeric - (fee.val::numeric(24) * 100000000 + fee.frac::numeric(24)); 1825 IF (sign(amount_numeric) != 1) THEN 1826 out_too_small = TRUE; 1827 result = (0, 0); 1828 RETURN; 1829 END IF; 1830 1831 -- Round to tiny amounts 1832 tiny_numeric = (tiny.val::numeric(24) * 100000000 + tiny.frac::numeric(24)); 1833 case rounding 1834 when 'zero' then amount_numeric = trunc(amount_numeric / tiny_numeric) * tiny_numeric; 1835 when 'up' then amount_numeric = ceil(amount_numeric / tiny_numeric) * tiny_numeric; 1836 when 'nearest' then amount_numeric = round(amount_numeric / tiny_numeric) * tiny_numeric; 1837 end case; 1838 1839 -- Extract product parts 1840 result = (trunc(amount_numeric / 100000000)::int8, (amount_numeric % 100000000)::int4); 1841 1842 IF (result.val > 1::INT8<<52) THEN 1843 RAISE EXCEPTION 'amount value overflowed'; 1844 END IF; 1845 END $$; 1846 COMMENT ON FUNCTION conversion_apply_ratio 1847 IS 'Apply a ratio to an amount rounding the result to a tiny amount following a rounding mode. It raises an exception when the resulting .val is larger than 2^52'; 1848 1849 CREATE FUNCTION conversion_revert_ratio( 1850 IN amount taler_amount 1851 ,IN ratio taler_amount 1852 ,IN fee taler_amount 1853 ,IN tiny taler_amount -- Result is rounded to this amount 1854 ,IN rounding rounding_mode -- With this rounding mode 1855 ,IN reverse_tiny taler_amount 1856 ,OUT result taler_amount 1857 ,OUT bad_value BOOLEAN 1858 ) 1859 LANGUAGE plpgsql IMMUTABLE AS $$ 1860 DECLARE 1861 amount_numeric NUMERIC(33, 8); -- 16 digit for val, 8 for frac and 1 for rounding error 1862 tiny_numeric NUMERIC(24); 1863 roundtrip BOOLEAN; 1864 BEGIN 1865 -- Handle no config case 1866 IF ratio = (0, 0)::taler_amount THEN 1867 bad_value=TRUE; 1868 RETURN; 1869 END IF; 1870 1871 -- Apply fees 1872 amount_numeric = (amount.val::numeric(24) * 100000000 + amount.frac::numeric(24)) + (fee.val::numeric(24) * 100000000 + fee.frac::numeric(24)); 1873 1874 -- Perform division using big numbers 1875 amount_numeric = amount_numeric / (ratio.val::numeric(24, 8) + ratio.frac::numeric(24, 8) / 100000000); 1876 1877 -- Round to input digits 1878 tiny_numeric = (reverse_tiny.val::numeric(24) * 100000000 + reverse_tiny.frac::numeric(24)); 1879 amount_numeric = trunc(amount_numeric / tiny_numeric) * tiny_numeric; 1880 1881 -- Extract division parts 1882 result = (trunc(amount_numeric / 100000000)::int8, (amount_numeric % 100000000)::int4); 1883 1884 -- Recover potentially lost tiny amount during rounding 1885 -- There must be a clever way to compute this but I am a little limited with math 1886 -- and revert ratio computation is not a hot function so I just use the apply ratio 1887 -- function to be conservative and correct 1888 SELECT ok INTO roundtrip FROM amount_left_minus_right((SELECT conversion_apply_ratio.result FROM conversion_apply_ratio(result, ratio, fee, tiny, rounding)), amount); 1889 IF NOT roundtrip THEN 1890 amount_numeric = amount_numeric + tiny_numeric; 1891 result = (trunc(amount_numeric / 100000000)::int8, (amount_numeric % 100000000)::int4); 1892 END IF; 1893 1894 IF (result.val > 1::INT8<<52) THEN 1895 RAISE EXCEPTION 'amount value overflowed'; 1896 END IF; 1897 END $$; 1898 COMMENT ON FUNCTION conversion_revert_ratio 1899 IS 'Revert the application of a ratio. This function does not always return the smallest possible amount. It raises an exception when the resulting .val is larger than 2^52'; 1900 1901 1902 CREATE FUNCTION conversion_to( 1903 IN amount taler_amount, 1904 IN direction TEXT, 1905 IN conversion_rate_class_id INT8, 1906 OUT converted taler_amount, 1907 OUT too_small BOOLEAN, 1908 OUT under_min BOOLEAN 1909 ) 1910 LANGUAGE plpgsql STABLE AS $$ 1911 DECLARE 1912 at_ratio taler_amount; 1913 out_fee taler_amount; 1914 tiny_amount taler_amount; 1915 min_amount taler_amount; 1916 mode rounding_mode; 1917 BEGIN 1918 -- Load rate 1919 IF direction='cashin' THEN 1920 SELECT 1921 (cashin_ratio).val, (cashin_ratio).frac, 1922 (cashin_fee).val, (cashin_fee).frac, 1923 (cashin_tiny_amount).val, (cashin_tiny_amount).frac, 1924 (cashin_min_amount).val, (cashin_min_amount).frac, 1925 cashin_rounding_mode 1926 INTO 1927 at_ratio.val, at_ratio.frac, 1928 out_fee.val, out_fee.frac, 1929 tiny_amount.val, tiny_amount.frac, 1930 min_amount.val, min_amount.frac, 1931 mode 1932 FROM get_conversion_class_rate(conversion_rate_class_id); 1933 ELSE 1934 SELECT 1935 (cashout_ratio).val, (cashout_ratio).frac, 1936 (cashout_fee).val, (cashout_fee).frac, 1937 (cashout_tiny_amount).val, (cashout_tiny_amount).frac, 1938 (cashout_min_amount).val, (cashout_min_amount).frac, 1939 cashout_rounding_mode 1940 INTO 1941 at_ratio.val, at_ratio.frac, 1942 out_fee.val, out_fee.frac, 1943 tiny_amount.val, tiny_amount.frac, 1944 min_amount.val, min_amount.frac, 1945 mode 1946 FROM get_conversion_class_rate(conversion_rate_class_id); 1947 END IF; 1948 1949 -- Check min amount 1950 SELECT NOT ok INTO too_small FROM amount_left_minus_right(amount, min_amount); 1951 IF too_small THEN 1952 under_min = true; 1953 converted = (0, 0); 1954 RETURN; 1955 END IF; 1956 1957 -- Perform conversion 1958 SELECT (result).val, (result).frac, out_too_small INTO converted.val, converted.frac, too_small 1959 FROM conversion_apply_ratio(amount, at_ratio, out_fee, tiny_amount, mode); 1960 END $$; 1961 1962 CREATE FUNCTION conversion_from( 1963 IN amount taler_amount, 1964 IN direction TEXT, 1965 IN conversion_rate_class_id INT8, 1966 OUT converted taler_amount, 1967 OUT too_small BOOLEAN, 1968 OUT under_min BOOLEAN 1969 ) 1970 LANGUAGE plpgsql STABLE AS $$ 1971 DECLARE 1972 ratio taler_amount; 1973 out_fee taler_amount; 1974 tiny_amount taler_amount; 1975 reverse_tiny_amount taler_amount; 1976 min_amount taler_amount; 1977 mode rounding_mode; 1978 BEGIN 1979 -- Load rate 1980 IF direction='cashin' THEN 1981 SELECT 1982 (cashin_ratio).val, (cashin_ratio).frac, 1983 (cashin_fee).val, (cashin_fee).frac, 1984 (cashin_tiny_amount).val, (cashin_tiny_amount).frac, 1985 (cashout_tiny_amount).val, (cashout_tiny_amount).frac, 1986 (cashin_min_amount).val, (cashin_min_amount).frac, 1987 cashin_rounding_mode 1988 INTO 1989 ratio.val, ratio.frac, 1990 out_fee.val, out_fee.frac, 1991 tiny_amount.val, tiny_amount.frac, 1992 reverse_tiny_amount.val, reverse_tiny_amount.frac, 1993 min_amount.val, min_amount.frac, 1994 mode 1995 FROM get_conversion_class_rate(conversion_rate_class_id); 1996 ELSE 1997 SELECT 1998 (cashout_ratio).val, (cashout_ratio).frac, 1999 (cashout_fee).val, (cashout_fee).frac, 2000 (cashout_tiny_amount).val, (cashout_tiny_amount).frac, 2001 (cashin_tiny_amount).val, (cashin_tiny_amount).frac, 2002 (cashout_min_amount).val, (cashout_min_amount).frac, 2003 cashout_rounding_mode 2004 INTO 2005 ratio.val, ratio.frac, 2006 out_fee.val, out_fee.frac, 2007 tiny_amount.val, tiny_amount.frac, 2008 reverse_tiny_amount.val, reverse_tiny_amount.frac, 2009 min_amount.val, min_amount.frac, 2010 mode 2011 FROM get_conversion_class_rate(conversion_rate_class_id); 2012 END IF; 2013 2014 -- Perform conversion 2015 SELECT (result).val, (result).frac, bad_value INTO converted.val, converted.frac, too_small 2016 FROM conversion_revert_ratio(amount, ratio, out_fee, tiny_amount, mode, reverse_tiny_amount); 2017 IF too_small THEN 2018 RETURN; 2019 END IF; 2020 2021 -- Check min amount 2022 SELECT NOT ok INTO too_small FROM amount_left_minus_right(converted, min_amount); 2023 IF too_small THEN 2024 under_min = true; 2025 converted = (0, 0); 2026 END IF; 2027 END $$; 2028 2029 CREATE FUNCTION config_get_conversion_rate() 2030 RETURNS TABLE ( 2031 cashin_ratio taler_amount, 2032 cashin_fee taler_amount, 2033 cashin_tiny_amount taler_amount, 2034 cashin_min_amount taler_amount, 2035 cashin_rounding_mode rounding_mode, 2036 cashout_ratio taler_amount, 2037 cashout_fee taler_amount, 2038 cashout_tiny_amount taler_amount, 2039 cashout_min_amount taler_amount, 2040 cashout_rounding_mode rounding_mode 2041 ) 2042 LANGUAGE sql STABLE AS $$ 2043 SELECT 2044 (value->'cashin'->'ratio'->'val', value->'cashin'->'ratio'->'frac')::taler_amount, 2045 (value->'cashin'->'fee'->'val', value->'cashin'->'fee'->'frac')::taler_amount, 2046 (value->'cashin'->'tiny_amount'->'val', value->'cashin'->'tiny_amount'->'frac')::taler_amount, 2047 (value->'cashin'->'min_amount'->'val', value->'cashin'->'min_amount'->'frac')::taler_amount, 2048 (value->'cashin'->>'rounding_mode')::rounding_mode, 2049 (value->'cashout'->'ratio'->'val', value->'cashout'->'ratio'->'frac')::taler_amount, 2050 (value->'cashout'->'fee'->'val', value->'cashout'->'fee'->'frac')::taler_amount, 2051 (value->'cashout'->'tiny_amount'->'val', value->'cashout'->'tiny_amount'->'frac')::taler_amount, 2052 (value->'cashout'->'min_amount'->'val', value->'cashout'->'min_amount'->'frac')::taler_amount, 2053 (value->'cashout'->>'rounding_mode')::rounding_mode 2054 FROM config WHERE key='conversion_rate' 2055 UNION ALL 2056 SELECT (0, 0)::taler_amount, (0, 0)::taler_amount, (0, 1000000)::taler_amount, (0, 0)::taler_amount, 'zero'::rounding_mode, 2057 (0, 0)::taler_amount, (0, 0)::taler_amount, (0, 1000000)::taler_amount, (0, 0)::taler_amount, 'zero'::rounding_mode 2058 LIMIT 1 2059 $$; 2060 2061 CREATE FUNCTION get_conversion_class_rate( 2062 IN in_conversion_rate_class_id INT8 2063 ) 2064 RETURNS TABLE ( 2065 cashin_ratio taler_amount, 2066 cashin_fee taler_amount, 2067 cashin_tiny_amount taler_amount, 2068 cashin_min_amount taler_amount, 2069 cashin_rounding_mode rounding_mode, 2070 cashout_ratio taler_amount, 2071 cashout_fee taler_amount, 2072 cashout_tiny_amount taler_amount, 2073 cashout_min_amount taler_amount, 2074 cashout_rounding_mode rounding_mode 2075 ) 2076 LANGUAGE sql STABLE AS $$ 2077 SELECT 2078 COALESCE(class.cashin_ratio, cfg.cashin_ratio), 2079 COALESCE(class.cashin_fee, cfg.cashin_fee), 2080 cashin_tiny_amount, 2081 COALESCE(class.cashin_min_amount, cfg.cashin_min_amount), 2082 COALESCE(class.cashin_rounding_mode, cfg.cashin_rounding_mode), 2083 COALESCE(class.cashout_ratio, cfg.cashout_ratio), 2084 COALESCE(class.cashout_fee, cfg.cashout_fee), 2085 cashout_tiny_amount, 2086 COALESCE(class.cashout_min_amount, cfg.cashout_min_amount), 2087 COALESCE(class.cashout_rounding_mode, cfg.cashout_rounding_mode) 2088 FROM config_get_conversion_rate() as cfg 2089 LEFT JOIN conversion_rate_classes as class 2090 ON (conversion_rate_class_id=in_conversion_rate_class_id) 2091 $$; 2092 2093 CREATE PROCEDURE config_set_conversion_rate( 2094 IN cashin_ratio taler_amount, 2095 IN cashin_fee taler_amount, 2096 IN cashin_tiny_amount taler_amount, 2097 IN cashin_min_amount taler_amount, 2098 IN cashin_rounding_mode rounding_mode, 2099 IN cashout_ratio taler_amount, 2100 IN cashout_fee taler_amount, 2101 IN cashout_tiny_amount taler_amount, 2102 IN cashout_min_amount taler_amount, 2103 IN cashout_rounding_mode rounding_mode 2104 ) 2105 LANGUAGE sql AS $$ 2106 INSERT INTO config (key, value) VALUES ('conversion_rate', jsonb_build_object( 2107 'cashin', jsonb_build_object( 2108 'ratio', jsonb_build_object('val', cashin_ratio.val, 'frac', cashin_ratio.frac), 2109 'fee', jsonb_build_object('val', cashin_fee.val, 'frac', cashin_fee.frac), 2110 'tiny_amount', jsonb_build_object('val', cashin_tiny_amount.val, 'frac', cashin_tiny_amount.frac), 2111 'min_amount', jsonb_build_object('val', cashin_min_amount.val, 'frac', cashin_min_amount.frac), 2112 'rounding_mode', cashin_rounding_mode 2113 ), 2114 'cashout', jsonb_build_object( 2115 'ratio', jsonb_build_object('val', cashout_ratio.val, 'frac', cashout_ratio.frac), 2116 'fee', jsonb_build_object('val', cashout_fee.val, 'frac', cashout_fee.frac), 2117 'tiny_amount', jsonb_build_object('val', cashout_tiny_amount.val, 'frac', cashout_tiny_amount.frac), 2118 'min_amount', jsonb_build_object('val', cashout_min_amount.val, 'frac', cashout_min_amount.frac), 2119 'rounding_mode', cashout_rounding_mode 2120 ) 2121 )) ON CONFLICT (key) DO UPDATE SET value = excluded.value 2122 $$; 2123 2124 COMMIT;