From 48a7596d309bdcfdcadf702eeb60758157ac0ea0 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20Andr=C3=A9s?= Date: Wed, 18 Dec 2024 19:49:05 +0100 Subject: [PATCH] feat: refs #7709 revision --- .../supplierPackaging_ReportSource.sql | 167 +++++++++--------- 1 file changed, 84 insertions(+), 83 deletions(-) diff --git a/db/routines/vn/procedures/supplierPackaging_ReportSource.sql b/db/routines/vn/procedures/supplierPackaging_ReportSource.sql index 04d0e0f29..65c7f8649 100644 --- a/db/routines/vn/procedures/supplierPackaging_ReportSource.sql +++ b/db/routines/vn/procedures/supplierPackaging_ReportSource.sql @@ -1,5 +1,5 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`supplierPackaging_ReportSource`( +CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`supplierPackaging_reportSource`( vFromDated DATE, vNif VARCHAR(50) ) @@ -12,11 +12,7 @@ BEGIN */ DECLARE vEntityId INT; - SELECT id INTO vEntityId - FROM supplier - WHERE nif = vNif; - - CREATE OR REPLACE TEMPORARY TABLE tSupplierPackaging + CREATE OR REPLACE TEMPORARY TABLE tPackaging SELECT itemFk, longName, `name`, @@ -24,17 +20,17 @@ BEGIN landed, `in`, `out`, - CAST(sref AS CHAR) sref, + CAST(cmrFk AS CHAR) sref, buyingValue FROM ( SELECT s.itemFk, i.longName, c.name, - CONCAT('T',s.ticketFk) entryFk, + CONCAT('T', s.ticketFk) entryFk, DATE(t.shipped) landed, - -LEAST(s.quantity,0) `in`, - GREATEST(s.quantity,0) `out`, - t.cmrFk sref, + -LEAST(s.quantity, 0) `in`, + GREATEST(s.quantity, 0) `out`, + t.cmrFk, s.price * (100 - s.discount) / 100 buyingValue FROM sale s JOIN item i ON i.id = s.itemFk @@ -44,75 +40,78 @@ BEGIN WHERE c.fi = vNif AND t.shipped >= vFromDated AND p.isPackageReturnable - UNION ALL - SELECT s.itemFk, - i.longName, - c.name, - 'T previous', - vFromDated, - SUM(-LEAST(s.quantity,0)) `in`, - SUM(GREATEST(s.quantity,0)) `out`, - NULL, - AVG(s.price * (100 - s.discount) / 100) - FROM sale s - JOIN item i ON i.id = s.itemFk - JOIN packaging p ON p.itemFk = i.id - JOIN ticket t ON t.id = s.ticketFk - JOIN client c ON c.id = t.clientFk - WHERE c.fi = vNif - AND t.shipped < vFromDated - AND p.isPackageReturnable - AND NOT t.isDeleted - GROUP BY s.itemFk - UNION ALL - SELECT p.itemFk, - i.longName, - c.name, - CONCAT('TP',tp.ticketFk) entryFk, - DATE(t.shipped), - -LEAST(tp.quantity,0) `in`, - GREATEST(tp.quantity,0) `out`, - t.cmrFk, - 0 - FROM ticketPackaging tp - JOIN packaging p ON p.id = tp.packagingFk - JOIN item i ON i.id = p.itemFk - JOIN ticket t ON t.id = tp.ticketFk - JOIN client c ON c.id = t.clientFk - WHERE c.fi = vNif - AND t.shipped >= vFromDated - AND p.isPackageReturnable - UNION ALL - SELECT p.itemFk, - i.longName, - c.name, - 'TP previous', - vFromDated, - SUM(-LEAST(tp.quantity,0)) `in`, - SUM(GREATEST(tp.quantity,0)) `out`, - NULL, - 0 - FROM ticketPackaging tp - JOIN packaging p ON p.id = tp.packagingFk - JOIN item i ON i.id = p.itemFk - JOIN ticket t ON t.id = tp.ticketFk - JOIN client c ON c.id = t.clientFk - WHERE c.fi = vNif - AND t.shipped < vFromDated - AND p.isPackageReturnable - AND NOT t.isDeleted - GROUP BY p.itemFk - ORDER BY itemFk , landed, entryFk + UNION ALL + SELECT s.itemFk, + i.longName, + c.name, + 'T previous', + vFromDated, + SUM(-LEAST(s.quantity, 0)), + SUM(GREATEST(s.quantity, 0)), + NULL, + AVG(s.price * (100 - s.discount) / 100) + FROM sale s + JOIN item i ON i.id = s.itemFk + JOIN packaging p ON p.itemFk = i.id + JOIN ticket t ON t.id = s.ticketFk + JOIN client c ON c.id = t.clientFk + WHERE c.fi = vNif + AND t.shipped < vFromDated + AND p.isPackageReturnable + AND NOT t.isDeleted + GROUP BY s.itemFk + UNION ALL + SELECT p.itemFk, + i.longName, + c.name, + CONCAT('TP', tp.ticketFk), + DATE(t.shipped), + -LEAST(tp.quantity, 0), + GREATEST(tp.quantity, 0), + t.cmrFk, + 0 + FROM ticketPackaging tp + JOIN packaging p ON p.id = tp.packagingFk + JOIN item i ON i.id = p.itemFk + JOIN ticket t ON t.id = tp.ticketFk + JOIN client c ON c.id = t.clientFk + WHERE c.fi = vNif + AND t.shipped >= vFromDated + AND p.isPackageReturnable + UNION ALL + SELECT p.itemFk, + i.longName, + c.name, + 'TP previous', + vFromDated, + SUM(-LEAST(tp.quantity, 0)) `in`, + SUM(GREATEST(tp.quantity, 0)) `out`, + NULL, + 0 + FROM ticketPackaging tp + JOIN packaging p ON p.id = tp.packagingFk + JOIN item i ON i.id = p.itemFk + JOIN ticket t ON t.id = tp.ticketFk + JOIN client c ON c.id = t.clientFk + WHERE c.fi = vNif + AND t.shipped < vFromDated + AND p.isPackageReturnable + AND NOT t.isDeleted + GROUP BY p.itemFk + ORDER BY itemFk , landed, entryFk )sub WHERE `out` OR `in`; - IF vEntityId IS NULL THEN + SELECT id INTO vEntityId + FROM supplier + WHERE nif = vNif; + IF vEntityId IS NULL THEN SELECT id INTO vEntityId FROM client WHERE fi = vNif; - INSERT INTO tSupplierPackaging + INSERT INTO tPackaging SELECT itemFk, longName, `name`, @@ -125,12 +124,12 @@ BEGIN FROM ( SELECT sp.itemFk, sp.longName, - sp.supplier name, - CONCAT('E',sp.entryFk) entryFk, + sp.supplier, + CONCAT('E', sp.entryFk), sp.landed, sp.`in`, sp.`out`, - e.invoiceNumber sref, + e.invoiceNumber, sp.buyingValue FROM supplierPackaging sp JOIN entry e ON e.id = sp.entryFk @@ -155,7 +154,6 @@ BEGIN ORDER BY itemFk , landed, entryFk ) sub WHERE `out` OR `in`; - END IF; SELECT vEntityId, @@ -164,15 +162,18 @@ BEGIN name, entryFk, landed, - CAST(`in` AS DECIMAL(10,0)) `in`, - CAST(`out` AS DECIMAL(10,0)) `out`, + CAST(`in` AS DECIMAL(10, 0)) `in`, + CAST(`out` AS DECIMAL(10, 0)) `out`, sref, buyingValue, - CAST(SUM(IF(`in`=0, -`out`, `in`)) OVER (PARTITION BY itemFk ORDER BY itemFk , landed, entryFk) AS DECIMAL(10,2)) balance - FROM tSupplierPackaging - WHERE NOT (landed < util.VN_CURDATE() - INTERVAL 1 YEAR) + CAST(SUM(IF(`in` = 0, -`out`, `in`)) OVER ( + PARTITION BY itemFk + ORDER BY itemFk , landed, entryFk + ) AS DECIMAL(10,2)) balance + FROM tPackaging + WHERE landed >= util.VN_CURDATE() - INTERVAL 1 YEAR ORDER BY itemFk, landed, entryFk; - DROP TEMPORARY TABLE tSupplierPackaging; + DROP TEMPORARY TABLE tPackaging; END$$ -DELIMITER ; \ No newline at end of file +DELIMITER ;