85 lines
2.8 KiB
SQL
85 lines
2.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`shelving_getSpam`(vDated DATE, vWarehouseFk INT)
|
|
BEGIN
|
|
/**
|
|
* Devuelve las matrículas con productos que no son necesarios para la venta
|
|
* hasta la fecha señalada.
|
|
*
|
|
* @param vDated Fecha hasta la que se puede pasar sin esos productos
|
|
* @param vWarehouse Identificador único de vn.warehouse
|
|
*/
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.stock;
|
|
|
|
CALL cache.stock_refresh(FALSE);
|
|
|
|
CREATE TEMPORARY TABLE tmp.stock
|
|
SELECT i.id itemFk,
|
|
v.amount - IFNULL(fue.reserva,0) as visible,
|
|
fue.reserva,
|
|
sale.venta,
|
|
IFNULL(buy.compra,0) + IFNULL(mov.traslado,0) as compra,
|
|
IFNULL(v.amount,0) + IFNULL(sale.venta,0) + IFNULL(buy.compra,0) + IFNULL(mov.traslado,0) - IFNULL(fue.reserva,0) as saldo
|
|
FROM vn.item i
|
|
JOIN vn.itemType it ON it.id = i.typeFk
|
|
JOIN vn.itemCategory ic ON ic.id = it.categoryFk
|
|
LEFT JOIN (
|
|
SELECT ish.itemFk, CAST(SUM(ish.visible) AS DECIMAL(10,0)) AS reserva
|
|
FROM vn.itemShelving ish
|
|
JOIN vn.shelving sh ON sh.code = ish.shelvingFk
|
|
JOIN vn.parking p ON p.id = sh.parkingFk
|
|
JOIN vn.sector s ON s.id = p.sectorFk
|
|
WHERE s.code = 'FUENTES_PICASSE'
|
|
OR sh.isSpam
|
|
GROUP BY ish.itemFk
|
|
) fue ON fue.itemFk = i.id
|
|
LEFT JOIN cache.stock v ON i.id = v.item_id AND v.warehouse_id = vWarehouseFk
|
|
LEFT JOIN (
|
|
SELECT item_id, CAST(sum(amount)AS DECIMAL(10,0)) as venta
|
|
FROM vn2008.item_out
|
|
WHERE dat BETWEEN util.VN_CURDATE() AND util.dayend(vDated)
|
|
AND warehouse_id = vWarehouseFk
|
|
GROUP BY item_id
|
|
) sale ON sale.item_id = i.id
|
|
LEFT JOIN (
|
|
SELECT item_id, CAST(sum(amount)AS DECIMAL(10,0)) as compra
|
|
FROM vn2008.item_entry_in
|
|
WHERE dat BETWEEN util.VN_CURDATE() AND util.dayend(vDated)
|
|
AND warehouse_id = vWarehouseFk
|
|
AND isVirtualStock = FALSE
|
|
GROUP BY item_id
|
|
) buy ON buy.item_id = i.id
|
|
LEFT JOIN (
|
|
SELECT item_id, CAST(sum(amount)AS DECIMAL(10,0)) as traslado
|
|
FROM vn2008.item_entry_out
|
|
WHERE dat BETWEEN util.VN_CURDATE() AND util.dayend(vDated)
|
|
AND warehouse_id = vWarehouseFk
|
|
GROUP BY item_id
|
|
) mov ON mov.item_id = i.id
|
|
WHERE v.amount;
|
|
|
|
SELECT ish.shelvingFk matricula,
|
|
i.longName articulo,
|
|
ish.visible,
|
|
count(*) lineas,
|
|
sum(ish.visible <= s.saldo) spam,
|
|
p.code parking,
|
|
s.description sector ,
|
|
w.name AS almacen,
|
|
sh.isSpam
|
|
FROM vn.itemShelving ish
|
|
JOIN vn.item i ON i.id = ish.itemFk
|
|
JOIN vn.shelving sh ON sh.code = ish.shelvingFk
|
|
JOIN vn.parking p ON p.id = sh.parkingFk
|
|
JOIN vn.sector s ON s.id = p.sectorFk
|
|
JOIN vn.warehouse w ON w.id = s.warehouseFk
|
|
LEFT JOIN tmp.stock s ON s.itemFk = ish.itemFk
|
|
WHERE (w.name = 'Algemesi'
|
|
OR (w.name = 'NuncaJamas' AND ish.created < util.VN_CURDATE()))
|
|
AND ish.visible
|
|
GROUP BY ish.shelvingFk
|
|
HAVING lineas = spam OR isSpam;
|
|
|
|
DROP TEMPORARY TABLE tmp.stock;
|
|
END$$
|
|
DELIMITER ;
|