83 lines
2.8 KiB
SQL
83 lines
2.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`desglose_volume`(IN vAgencyFk INT)
|
|
BEGIN
|
|
|
|
DECLARE vStarted DATETIME DEFAULT TIMESTAMP(util.VN_CURDATE());
|
|
DECLARE vEnded DATETIME DEFAULT TIMESTAMP(util.VN_CURDATE(), '23:59:59');
|
|
DECLARE vIsHolland BOOL;
|
|
|
|
SELECT (wa.name = 'Holanda') INTO vIsHolland
|
|
FROM vn.agency a
|
|
JOIN vn.warehouseAlias wa ON wa.id = a.warehouseAliasFk
|
|
WHERE a.id = vAgencyFk;
|
|
|
|
IF vIsHolland THEN
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticket_PackagingEstimated;
|
|
CREATE TEMPORARY TABLE tmp.ticket_PackagingEstimated
|
|
(
|
|
ticketFk INT PRIMARY KEY
|
|
,carros DECIMAL(5,1) DEFAULT 0
|
|
);
|
|
|
|
INSERT INTO tmp.ticket_PackagingEstimated(ticketFk, carros)
|
|
SELECT sv.ticketFk, ROUND(vc.dutchCompressionRate * sum(sv.volume) / vc.trolleyM3,0)
|
|
FROM vn.ticket t
|
|
JOIN vn.saleVolume sv ON sv.ticketFk = t.id
|
|
JOIN vn.agencyMode am ON am.id = t.agencyModeFk
|
|
JOIN vn.volumeConfig vc
|
|
WHERE t.shipped BETWEEN vStarted AND vEnded
|
|
AND am.agencyFk = vAgencyFk
|
|
GROUP BY t.id;
|
|
|
|
SELECT a.nickname Provincia,
|
|
count(*) expediciones,
|
|
0 Bultos,
|
|
sum(tpe.carros) Prevision
|
|
FROM vn.ticket t
|
|
JOIN vn.address a ON a.id = t.addressFk
|
|
JOIN tmp.ticket_PackagingEstimated tpe ON tpe.ticketFk = t.id
|
|
GROUP BY a.nickname;
|
|
|
|
ELSE
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticket_PackagingEstimated;
|
|
CREATE TEMPORARY TABLE tmp.ticket_PackagingEstimated
|
|
(
|
|
ticketFk INT PRIMARY KEY
|
|
,boxes INT DEFAULT 0
|
|
);
|
|
|
|
INSERT INTO tmp.ticket_PackagingEstimated(ticketFk, boxes)
|
|
SELECT sv.ticketFk, CEIL(1000 * sum(sv.volume) / vc.standardFlowerBox)
|
|
FROM vn.ticket t
|
|
JOIN vn.saleVolume sv ON sv.ticketFk = t.id
|
|
JOIN vn.agencyMode am ON am.id = t.agencyModeFk
|
|
JOIN vn.volumeConfig vc
|
|
WHERE t.shipped BETWEEN vStarted AND vEnded
|
|
AND IFNULL(t.packages,0) = 0
|
|
AND am.agencyFk = vAgencyFk
|
|
GROUP BY t.id;
|
|
|
|
|
|
SELECT p.name Provincia,
|
|
count(*) expediciones,
|
|
sum(t.packages) Bultos,
|
|
sum(tpe.boxes) Prevision
|
|
FROM vn.ticket t
|
|
JOIN vn.address a ON a.id = t.addressFk
|
|
JOIN vn.province p ON a.provinceFk = p.id
|
|
JOIN vn.agencyMode am ON am.id = t.agencyModeFk
|
|
JOIN tmp.ticket_PackagingEstimated tpe ON tpe.ticketFk = t.id
|
|
WHERE t.warehouseFk = 60
|
|
AND t.shipped BETWEEN vStarted AND vEnded
|
|
AND am.agencyFk = vAgencyFk
|
|
GROUP BY p.name;
|
|
|
|
END IF;
|
|
SELECT * FROM tmp.ticket_PackagingEstimated;
|
|
DROP TEMPORARY TABLE tmp.ticket_PackagingEstimated;
|
|
|
|
END$$
|
|
DELIMITER ;
|