98 lines
2.9 KiB
MySQL
98 lines
2.9 KiB
MySQL
|
|
||
|
DROP procedure IF EXISTS `vn`.`clientPackagingOverstock`;
|
||
|
|
||
|
DELIMITER $$
|
||
|
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`clientPackagingOverstock`(vClientFk INT, vGraceDays INT )
|
||
|
BEGIN
|
||
|
DROP TEMPORARY TABLE IF EXISTS tmp.clientPackagingOverstock;
|
||
|
CREATE TEMPORARY TABLE tmp.clientPackagingOverstock
|
||
|
ENGINE = MEMORY
|
||
|
SELECT itemFk,
|
||
|
sum(GotfromClient) - sum(SenttoClient) as devueltos,
|
||
|
sum(InvoicedtoClient) - sum(InvoicedfromClient) as facturados,
|
||
|
LEAST(
|
||
|
sum(GotfromClient) - sum(SenttoClient),
|
||
|
sum(InvoicedtoClient) - sum(InvoicedfromClient)
|
||
|
) as abonables
|
||
|
FROM
|
||
|
(
|
||
|
SELECT t.*,
|
||
|
IF(@month = month, 0, 1) monthEnd,
|
||
|
@month := month
|
||
|
FROM
|
||
|
(
|
||
|
SELECT x.id as ticketFk,
|
||
|
date(x.shipped) as shipped,
|
||
|
x.itemFk,
|
||
|
IFNULL(cast(sum(x.InvoicedtoClient) as DECIMAL(10,0)),0) InvoicedtoClient,
|
||
|
IFNULL(cast(sum(x.InvoicedfromClient) as DECIMAL(10,0)),0) InvoicedfromClient,
|
||
|
IFNULL(cast(sum(x.SenttoClient) as DECIMAL(10,0)),0) SenttoClient,
|
||
|
IFNULL(cast(sum(x.GotfromClient) as DECIMAL(10,0)),0) GotfromClient,
|
||
|
i.name as concept,
|
||
|
x.refFk as invoice,
|
||
|
month(shipped) month,
|
||
|
x.companyFk
|
||
|
FROM
|
||
|
(
|
||
|
SELECT t.id,
|
||
|
t.shipped,
|
||
|
IFNULL(pe.equivalentFk, s.itemFk) itemFk,
|
||
|
IF(s.quantity > 0, s.quantity, NULL) InvoicedtoClient,
|
||
|
IF(s.quantity < 0, -s.quantity, NULL) InvoicedfromClient,
|
||
|
NULL SenttoClient,
|
||
|
NULL GotfromClient,
|
||
|
t.refFk,
|
||
|
@month := 0 month,
|
||
|
t.companyFk
|
||
|
FROM sale s
|
||
|
JOIN ticket t on t.id = s.ticketFk
|
||
|
JOIN packaging p ON p.itemFk = s.itemFk
|
||
|
LEFT JOIN packageEquivalentItem pe ON pe.itemFk = s.itemFk
|
||
|
WHERE t.clientFk = vClientFk
|
||
|
AND t.shipped > '2017-11-30'
|
||
|
AND p.isPackageReturnable
|
||
|
UNION ALL
|
||
|
SELECT NULL,
|
||
|
'2017-11-30',
|
||
|
IFNULL(pe.equivalentFk, tps.itemFk) itemFk,
|
||
|
tps.sent InvoicedtoClient,
|
||
|
tps.returned InvoicedfromClient,
|
||
|
NULL SenttoClient,
|
||
|
NULL GotfromClient,
|
||
|
'Histórico',
|
||
|
NULL,
|
||
|
NULL
|
||
|
|
||
|
FROM ticketPackagingStartingStock tps
|
||
|
LEFT JOIN packageEquivalentItem pe ON pe.itemFk = tps.itemFk
|
||
|
WHERE tps.clientFk = vClientFk
|
||
|
AND tps.isForgetable = FALSE
|
||
|
UNION ALL
|
||
|
SELECT t.id,
|
||
|
t.shipped,
|
||
|
IFNULL(pe.equivalentFk, p.itemFk) itemFk,
|
||
|
NULL,
|
||
|
NULL,
|
||
|
IF(tp.quantity > 0 AND t.shipped <= TIMESTAMPADD(DAY, - vGraceDays, CURDATE()), tp.quantity, NULL) SenttoClient,
|
||
|
IF(tp.quantity < 0, -tp.quantity, NULL) GotfromClient,
|
||
|
NULL AS refFk,
|
||
|
NULL,
|
||
|
t.companyFk
|
||
|
FROM ticketPackaging tp
|
||
|
JOIN ticket t on t.id = tp.ticketFk
|
||
|
JOIN packaging p ON p.id = tp.packagingFk
|
||
|
LEFT JOIN packageEquivalentItem pe ON pe.itemFk = p.itemFk
|
||
|
WHERE t.clientFk = vClientFk
|
||
|
AND t.shipped > '2017-11-21' ) x
|
||
|
|
||
|
JOIN item i ON x.itemFk = i.id
|
||
|
GROUP BY x.id, x.itemFk
|
||
|
) t
|
||
|
ORDER BY itemFk, shipped DESC
|
||
|
) t2
|
||
|
GROUP BY itemFk;
|
||
|
END$$
|
||
|
|
||
|
DELIMITER ;
|
||
|
|