salix/db/routines/vn/procedures/fustControl.sql

80 lines
3.1 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`fustControl`(vFromDated DATE, vToDated DATE)
BEGIN
DECLARE vSijsnerClientFk INT DEFAULT 19752;
DECLARE vDateStart DATETIME;
DECLARE vDateEnd DATETIME;
SET vDateStart = vFromDated;
SET vDateEnd = util.Dayend(vToDated);
SELECT p.id FustCode,
CAST(sent.stucks AS DECIMAL(10,0)) FH,
CAST(tp.stucks AS DECIMAL(10,0)) Tickets,
CAST(-sj.stucks AS DECIMAL(10,0)) Sijsner,
CAST(IFNULL(sent.stucks,0) - IFNULL(tp.stucks,0) + IFNULL(sj.stucks,0) AS DECIMAL(10,0)) saldo
FROM vn.packaging p
LEFT JOIN (
SELECT FustCode, sum(fustQuantity) stucks
FROM (
SELECT IFNULL(pe.equivalentFk ,b.packagingFk) FustCode, s.quantity / b.packing AS fustQuantity
FROM vn.sale s
JOIN vn.ticket t ON t.id = s.ticketFk
JOIN vn.warehouse w ON w.id = t.warehouseFk
JOIN vn.warehouseAlias wa ON wa.id = w.aliasFk
JOIN cache.last_buy lb ON lb.item_id = s.itemFk AND lb.warehouse_id = t.warehouseFk
JOIN vn.buy b ON b.id = lb.buy_id
JOIN vn.packaging p ON p.id = b.packagingFk
LEFT JOIN vn.packageEquivalent pe ON pe.packagingFk = p.id
JOIN vn.address a ON a.id = t.addressFk
JOIN vn.province p2 ON p2.id = a.provinceFk
JOIN vn.country c ON c.id = p2.countryFk
WHERE t.shipped BETWEEN vDateStart AND vDateEnd
AND wa.name = 'VNH'
AND p.isPackageReturnable
AND c.country = 'FRANCIA') sub
GROUP BY FustCode) sent ON sent.FustCode = p.id
LEFT JOIN (
SELECT FustCode, sum(quantity) stucks
FROM (
SELECT IFNULL(pe.equivalentFk ,tp.packagingFk) FustCode, tp.quantity
FROM vn.ticketPackaging tp
JOIN vn.ticket t ON t.id = tp.ticketFk
JOIN vn.warehouse w ON w.id = t.warehouseFk
JOIN vn.warehouseAlias wa ON wa.id = w.aliasFk
JOIN vn.packaging p ON p.id = tp.packagingFk
LEFT JOIN vn.packageEquivalent pe ON pe.packagingFk = p.id
JOIN vn.address a ON a.id = t.addressFk
JOIN vn.province p2 ON p2.id = a.provinceFk
JOIN vn.country c ON c.id = p2.countryFk
WHERE t.shipped BETWEEN vDateStart AND vDateEnd
AND wa.name = 'VNH'
AND p.isPackageReturnable
AND c.country = 'FRANCIA'
AND t.clientFk != vSijsnerClientFk
AND tp.quantity > 0) sub
GROUP BY FustCode) tp ON tp.FustCode = p.id
LEFT JOIN (
SELECT FustCode, sum(quantity) stucks
FROM (
SELECT IFNULL(pe.equivalentFk ,tp.packagingFk) FustCode, tp.quantity
FROM vn.ticketPackaging tp
JOIN vn.ticket t ON t.id = tp.ticketFk
JOIN vn.warehouse w ON w.id = t.warehouseFk
JOIN vn.warehouseAlias wa ON wa.id = w.aliasFk
JOIN vn.packaging p ON p.id = tp.packagingFk
LEFT JOIN vn.packageEquivalent pe ON pe.packagingFk = p.id
WHERE t.shipped BETWEEN TIMESTAMPADD(DAY, 1, vDateStart ) AND TIMESTAMPADD(DAY, 1, vDateEnd )
AND wa.name = 'VNH'
AND p.isPackageReturnable
AND t.clientFk = vSijsnerClientFk) sub
GROUP BY FustCode) sj ON sj.FustCode = p.id
WHERE sent.stucks
OR tp.stucks
OR sj.stucks;
END$$
DELIMITER ;