salix/db/routines/vn/procedures/supplierPackaging_ReportSou...

178 lines
4.4 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`supplierPackaging_ReportSource`(
vFromDated DATE,
vNif VARCHAR(50)
)
BEGIN
/**
* Create a report with packaging balance
*
* @param vFromDated Starting date
* @param vSupplierFk Supplier ID
*/
DECLARE vEntityId INT;
SELECT id INTO vEntityId
FROM supplier
WHERE nif = vNif;
CREATE OR REPLACE TEMPORARY TABLE tSupplierPackaging
SELECT itemFk,
longName,
`name`,
entryFk,
landed,
`in`,
`out`,
CAST(sref AS CHAR) sref,
buyingValue
FROM (
SELECT s.itemFk,
i.longName,
c.name,
CONCAT('T',s.ticketFk) entryFk,
DATE(t.shipped) landed,
-LEAST(s.quantity,0) `in`,
GREATEST(s.quantity,0) `out`,
t.cmrFk sref,
s.price * (100 - s.discount) / 100 buyingValue
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
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
)sub
WHERE `out` OR `in`;
IF vEntityId IS NULL THEN
SELECT id INTO vEntityId
FROM client
WHERE fi = vNif;
INSERT INTO tSupplierPackaging
SELECT itemFk,
longName,
`name`,
entryFk,
landed,
`in`,
`out`,
sref,
buyingValue
FROM (
SELECT sp.itemFk,
sp.longName,
sp.supplier name,
CONCAT('E',sp.entryFk) entryFk,
sp.landed,
sp.`in`,
sp.`out`,
e.invoiceNumber sref,
sp.buyingValue
FROM supplierPackaging sp
JOIN entry e ON e.id = sp.entryFk
JOIN supplier s ON s.id = sp.supplierFk
WHERE s.nif = vNif
AND sp.landed >= vFromDated
UNION ALL
SELECT itemFk,
longName,
supplier,
'E previous',
vFromDated,
IF(SUM(`in`) + SUM(-`out`)>0, SUM(`in`) + SUM(-`out`), 0) `in`,
-IF(SUM(`in`) + SUM(-`out`)<0, SUM(`in`) + SUM(-`out`), 0) `out`,
NULL,
AVG(buyingValue)
FROM supplierPackaging sp
JOIN supplier s ON s.id = sp.supplierFk
WHERE s.nif = vNif
AND landed < vFromDated
GROUP BY itemFk
ORDER BY itemFk , landed, entryFk
) sub
WHERE `out` OR `in`;
END IF;
SELECT vEntityId,
itemFk,
longName,
name,
entryFk,
landed,
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)
ORDER BY itemFk, landed, entryFk;
DROP TEMPORARY TABLE tSupplierPackaging;
END$$
DELIMITER ;