168 lines
4.1 KiB
SQL
168 lines
4.1 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`supplierPackaging_ReportSource`(
|
|
vFromDated DATE,
|
|
vSupplierFk INT
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Create a report with packaging balance
|
|
*
|
|
* @param vFromDated Starting date
|
|
* @param vSupplierFk Supplier ID
|
|
*/
|
|
SET @vBalance = 0;
|
|
SET @vItemFk = NULL;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tSupplierPackaging
|
|
SELECT supplierFk,
|
|
itemFk,
|
|
longName,
|
|
supplier,
|
|
entryFk,
|
|
landed,
|
|
`in`,
|
|
`out`,
|
|
sref,
|
|
buyingValue,
|
|
IF (
|
|
NOT (@vItemFk <=> sub.itemFk),
|
|
@vBalance := (`in` - `out`),
|
|
@vBalance := (`in` - `out` + @vBalance)
|
|
) balance,
|
|
@vItemFk := sub.itemFk previousItemFk
|
|
FROM (
|
|
SELECT sp.supplierFk,
|
|
sp.itemFk,
|
|
sp.longName,
|
|
sp.supplier,
|
|
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
|
|
WHERE sp.supplierFk = vSupplierFk
|
|
AND sp.landed >= vFromDated
|
|
UNION ALL
|
|
SELECT vSupplierFk,
|
|
itemFk,
|
|
longName,
|
|
supplier,
|
|
'E previous',
|
|
vFromDated,
|
|
SUM(`in`),
|
|
SUM(`out`),
|
|
NULL,
|
|
AVG(buyingValue)
|
|
FROM supplierPackaging
|
|
WHERE supplierFk = vSupplierFk
|
|
AND landed < vFromDated
|
|
GROUP BY itemFk
|
|
UNION ALL
|
|
SELECT vSupplierFk,
|
|
s.itemFk,
|
|
i.longName,
|
|
c.name,
|
|
CONCAT('T',s.ticketFk),
|
|
DATE(t.shipped),
|
|
-LEAST(s.quantity,0) `in`,
|
|
GREATEST(s.quantity,0) `out`,
|
|
t.cmrFk,
|
|
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
|
|
JOIN supplier su ON su.nif = c.fi
|
|
WHERE su.id = vSupplierFk
|
|
AND t.shipped >= vFromDated
|
|
AND p.isPackageReturnable
|
|
UNION ALL
|
|
SELECT vSupplierFk,
|
|
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
|
|
JOIN supplier su ON su.nif = c.fi
|
|
WHERE su.id = vSupplierFk
|
|
AND t.shipped < vFromDated
|
|
AND p.isPackageReturnable
|
|
AND NOT t.isDeleted
|
|
GROUP BY s.itemFk
|
|
UNION ALL
|
|
SELECT vSupplierFk,
|
|
p.itemFk,
|
|
i.longName,
|
|
c.name,
|
|
CONCAT('TP',tp.ticketFk),
|
|
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
|
|
JOIN supplier su ON su.nif = c.fi
|
|
WHERE su.id = vSupplierFk
|
|
AND t.shipped >= vFromDated
|
|
AND p.isPackageReturnable
|
|
UNION ALL
|
|
SELECT vSupplierFk,
|
|
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
|
|
JOIN supplier su ON su.nif = c.fi
|
|
WHERE su.id = vSupplierFk
|
|
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`;
|
|
|
|
SELECT supplierFk,
|
|
itemFk,
|
|
longName,
|
|
supplier,
|
|
entryFk,
|
|
landed,
|
|
CAST(`in` AS DECIMAL(10,0)) `in`,
|
|
CAST(`out` AS DECIMAL(10,0)) `out`,
|
|
sref,
|
|
buyingValue,
|
|
balance
|
|
FROM tSupplierPackaging
|
|
WHERE NOT (NOT balance AND landed < CURDATE() - INTERVAL 1 YEAR);
|
|
|
|
DROP TEMPORARY TABLE tSupplierPackaging;
|
|
END$$
|
|
DELIMITER ;
|