From 2e4e2092088f5f4eabdee8d2cd582852c3b89ea4 Mon Sep 17 00:00:00 2001 From: alexm Date: Thu, 23 Jan 2025 15:10:58 +0100 Subject: [PATCH] feat: refs #7984 add currencyDated and use --- db/dump/fixtures.before.sql | 16 +++++++++---- db/routines/vn/functions/currency_getRate.sql | 2 +- .../vn/functions/ticket_getCurrencyDate.sql | 15 ++++++++++++ .../vn/functions/ticket_getCurrencyRate.sql | 23 +++++++++++++++++++ db/routines/vn/procedures/sale_PriceFix.sql | 2 +- .../vn/procedures/ticket_priceDifference.sql | 16 +++++++++---- db/routines/vn/triggers/sale_beforeInsert.sql | 5 ++-- db/routines/vn/triggers/sale_beforeUpdate.sql | 13 +++++++---- .../11307-blackAralia/00-firstScript.sql | 2 ++ 9 files changed, 77 insertions(+), 17 deletions(-) create mode 100644 db/routines/vn/functions/ticket_getCurrencyDate.sql create mode 100644 db/routines/vn/functions/ticket_getCurrencyRate.sql diff --git a/db/dump/fixtures.before.sql b/db/dump/fixtures.before.sql index 59189b16d..fe0069225 100644 --- a/db/dump/fixtures.before.sql +++ b/db/dump/fixtures.before.sql @@ -2692,10 +2692,18 @@ UPDATE `vn`.`invoiceIn` WHERE id IN (5, 7, 8, 9, 10); INSERT INTO vn.referenceRate (currencyFk, dated, value) - VALUES (2, '2000-12-01', 1.0495), - (2, '2001-01-01', 1.0531), - (2, '2001-02-01', 7.6347), - (2, '2000-12-31', 7.6347); + VALUES (2, '2000-12-01', 1), + (2, '2000-12-29', 2), + (2, '2000-12-30', 3), + (2, '2000-12-31', 4), + (2, '2001-01-01', 5), + (2, '2001-02-01', 6), + (3, '2000-12-01', 10), + (3, '2000-12-29', 20), + (3, '2000-12-30', 30), + (3, '2000-12-31', 40), + (3, '2001-01-01', 50), + (3, '2001-02-01', 60); UPDATE vn.ticket t JOIN vn.sale s ON s.ticketFk = t.id diff --git a/db/routines/vn/functions/currency_getRate.sql b/db/routines/vn/functions/currency_getRate.sql index 96816e7e5..5820fb0ff 100644 --- a/db/routines/vn/functions/currency_getRate.sql +++ b/db/routines/vn/functions/currency_getRate.sql @@ -15,7 +15,7 @@ BEGIN * @param vDated The date of exchangue * @return vForeignRate The rate e of currency exchange */ - DECLARE vForeignRate DECIMAL(10,2); + DECLARE vForeignRate FLOAT UNSIGNED; SELECT value INTO vForeignRate FROM referenceRate diff --git a/db/routines/vn/functions/ticket_getCurrencyDate.sql b/db/routines/vn/functions/ticket_getCurrencyDate.sql new file mode 100644 index 000000000..f4720c026 --- /dev/null +++ b/db/routines/vn/functions/ticket_getCurrencyDate.sql @@ -0,0 +1,15 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`vn`@`localhost` FUNCTION `vn`.`ticket_getCurrencyDate`(vSelf INT) + RETURNS INT(11) + DETERMINISTIC +BEGIN + DECLARE vCurrencyDated DATE; + + SELECT IF(DATE(shipped) < util.VN_CURDATE(), shipped, util.yesterday()) INTO vCurrencyDated + FROM ticket + WHERE id = vSelf; + + RETURN vCurrencyDated; +END$$ +DELIMITER ; + diff --git a/db/routines/vn/functions/ticket_getCurrencyRate.sql b/db/routines/vn/functions/ticket_getCurrencyRate.sql new file mode 100644 index 000000000..a08184072 --- /dev/null +++ b/db/routines/vn/functions/ticket_getCurrencyRate.sql @@ -0,0 +1,23 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`vn`@`localhost` FUNCTION `vn`.`ticket_getCurrencyRate`( + vSelf INT, + vCurrencyFk SMALLINT +) + RETURNS DECIMAL(10,2) + NOT DETERMINISTIC + READS SQL DATA +BEGIN +/** + * Returns the rate exchange based on the specified currency for a ticket + * + * @param vSelf The ticket id + * @param vCurrencyFk The currency id, if is null, get the currency of the ticket + * @return The rate of currency exchange + */ + SELECT IFNULL(vCurrencyFk, currencyFk) INTO vCurrencyFk + FROM ticket + WHERE id = vSelf; + + RETURN currency_getRate(vCurrencyFk, ticket_getCurrencyDate(vSelf)); +END$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/sale_PriceFix.sql b/db/routines/vn/procedures/sale_PriceFix.sql index 015c617a5..1e14e3a79 100644 --- a/db/routines/vn/procedures/sale_PriceFix.sql +++ b/db/routines/vn/procedures/sale_PriceFix.sql @@ -19,6 +19,6 @@ BEGIN WHERE t.id = vTicketFk GROUP BY sc.saleFk) sub ON sub.saleFk = s.id SET s.price = sub.price, - s.foreignPrice = currency_getRate(sub.currencyFk, NULL) * sub.price; + s.foreignPrice = ticket_getCurrencyRate(vTicketFk) * sub.price; END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/ticket_priceDifference.sql b/db/routines/vn/procedures/ticket_priceDifference.sql index df9e33a79..761c0f391 100644 --- a/db/routines/vn/procedures/ticket_priceDifference.sql +++ b/db/routines/vn/procedures/ticket_priceDifference.sql @@ -26,9 +26,15 @@ BEGIN i.category, IFNULL(s.quantity, 0) quantity, IFNULL(s.price, 0) price, - IFNULL(s.foreignPrice, 0) foreignPrice, + ROUND(IFNULL( + IFNULL( + s.foreignPrice, + s.price * ticket_getCurrencyRate(vTicketFk, vCurrencyFk) + ) , 0 + ), 2) foreignPrice, ROUND(SUM(tc.cost), 2) newPrice, - s.id saleFk + s.id saleFk, + ticket_getCurrencyRate(vTicketFk, vCurrencyFk) currencyRate FROM vn.sale s JOIN vn.item i ON i.id = s.itemFk JOIN vn.ticket t ON t.id = s.ticketFk @@ -43,9 +49,9 @@ BEGIN GROUP BY s.id ORDER BY s.id ) SELECT *, - currency_getRate(vCurrencyFk, NULL) * newPrice newForeignPrice, - quantity * (price - newPrice) difference, - quantity * (foreignPrice - currency_getRate(vCurrencyFk, NULL) * newPrice) foreignDifference + ROUND(currencyRate * newPrice, 2) newForeignPrice, + quantity * (newPrice - price) difference, + quantity * (ROUND(currencyRate * newPrice, 2) - foreignPrice ) foreignDifference FROM ticketPriceDifference; DROP TEMPORARY TABLE tmp.ticketComponentPreview; diff --git a/db/routines/vn/triggers/sale_beforeInsert.sql b/db/routines/vn/triggers/sale_beforeInsert.sql index 31d5882fc..b840774db 100644 --- a/db/routines/vn/triggers/sale_beforeInsert.sql +++ b/db/routines/vn/triggers/sale_beforeInsert.sql @@ -3,7 +3,8 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`sale_beforeInsert` BEFORE INSERT ON `sale` FOR EACH ROW BEGIN - SET NEW.editorFk = account.myUser_getId(); - SET NEW.originalQuantity = NEW.quantity; + SET NEW.editorFk = account.myUser_getId(), + NEW.originalQuantity = NEW.quantity, + NEW.currencyDated = ticket_getCurrencyDate(NEW.ticketFk); END$$ DELIMITER ; diff --git a/db/routines/vn/triggers/sale_beforeUpdate.sql b/db/routines/vn/triggers/sale_beforeUpdate.sql index fa45dad5c..48b7431c5 100644 --- a/db/routines/vn/triggers/sale_beforeUpdate.sql +++ b/db/routines/vn/triggers/sale_beforeUpdate.sql @@ -3,21 +3,26 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`sale_beforeUpdate` BEFORE UPDATE ON `sale` FOR EACH ROW BEGIN -/* +/* IF (SELECT COUNT(*) from item i WHERE id = NEW.itemFk AND family = 'SER') THEN CALL util.throw('Cannot insert a service item into a ticket'); END IF; */ - SET NEW.editorFk = account.myUser_getId(); - + SET NEW.editorFk = account.myUser_getId(), + NEW.currencyDated = ticket_getCurrencyDate(NEW.ticketFk); + IF NEW.discount > 100 THEN SET NEW.discount = 0; END IF; IF old.discount > 0 AND NEW.discount = 0 THEN INSERT INTO ticketLog - SET originFk = NEW.ticketFk, userFk = account.myUser_getId(), `action` = 'insert', + SET originFk = NEW.ticketFk, userFk = account.myUser_getId(), `action` = 'insert', description = CONCAT('Cambio de descuento del item :', ' ', new.itemFk, ' de ', old.discount ,' a 0 '); END IF; + + IF NOT(NEW.price <=> OLD.price) THEN + SET NEW.currencyDated = ticket_getCurrencyDate(NEW.ticketFk); + END IF; END$$ DELIMITER ; diff --git a/db/versions/11307-blackAralia/00-firstScript.sql b/db/versions/11307-blackAralia/00-firstScript.sql index 6df0c8bfa..ed4a50c38 100644 --- a/db/versions/11307-blackAralia/00-firstScript.sql +++ b/db/versions/11307-blackAralia/00-firstScript.sql @@ -76,6 +76,8 @@ UPDATE vn.client c SET c.defaultCompanyFk = co.companyFk, c.defaultCurrencyFk = co.currencyFk; +ALTER TABLE vn.sale ADD currencyDated DATE DEFAULT NULL; +