From 61137e214b6de200db36fc14fb639c2d63f5b70b Mon Sep 17 00:00:00 2001 From: Bernat Date: Mon, 4 Jun 2018 08:41:58 +0200 Subject: [PATCH] update itemDiary procedure --- .../db/install/changes/1.0.6/itemDiary.sql | 80 +++++++++++++++++++ 1 file changed, 80 insertions(+) create mode 100644 services/db/install/changes/1.0.6/itemDiary.sql diff --git a/services/db/install/changes/1.0.6/itemDiary.sql b/services/db/install/changes/1.0.6/itemDiary.sql new file mode 100644 index 000000000..deb556280 --- /dev/null +++ b/services/db/install/changes/1.0.6/itemDiary.sql @@ -0,0 +1,80 @@ +USE `vn`; +DROP procedure IF EXISTS `itemDiary`; + +DELIMITER $$ +USE `vn`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `itemDiary`(IN vItemId INT, IN vWarehouse INT) +BEGIN + DECLARE vDateInventory DATETIME; + DECLARE vCurdate DATE DEFAULT CURDATE(); + -- traduccion: date, alertLevel, origin, reference, name, In, Out, Balance + SELECT Fechainventario INTO vDateInventory FROM vn2008.tblContadores; + SET @a = 0; + SELECT DATE(date) AS date, + alertLevel, + origin, + reference, + name, + `in`, + `out`, + @a := @a + IFNULL(`in`,0) - IFNULL(`out`,0) as balance + FROM + ( SELECT tr.landed as date, + b.quantity as `in`, + NULL as `out`, + IF(tr.isReceived != FALSE,3, IF(tr.isDelivered,1,0)) as alertLevel, + s.name as name, + e.ref as reference, + e.id as origin + FROM vn.buy b + JOIN vn.entry e ON e.id = b.entryFk + JOIN vn.travel tr ON tr.id = e.travelFk + JOIN vn.supplier s ON s.id = e.supplierFk + WHERE tr.landed >= vDateInventory + AND vWarehouse = tr.warehouseInFk + AND b.itemFk = vItemId + AND e.isInventory = 0 + + UNION ALL + + SELECT tr.shipped as date, + NULL as `in`, + b.quantity as `out`, + IF(tr.isReceived != FALSE,3, IF(tr.isDelivered,1,0)) as alertLevel, + s.name as name, + e.ref as reference, + e.id as origin + FROM vn.buy b + JOIN vn.entry e ON e.id = b.entryFk + JOIN vn.travel tr ON tr.id = e.travelFk + JOIN vn.warehouse w ON w.id = tr.warehouseOutFk + JOIN vn.supplier s ON s.id = e.supplierFk + WHERE tr.shipped >= vDateInventory + AND vWarehouse =tr.warehouseOutFk + AND s.id <> 4 + AND b.itemFk = vItemId + AND e.isInventory = 0 + AND w.isFeedStock = 0 + + UNION ALL + SELECT t.shipped as date, + NULL as `in`, + s.quantity as `out`, + IF(t.shipped < vCurdate,3,IF(t.shipped > vCurdate, 0, IFNULL(ts.alertLevel,0))) as alertLevel, + t.nickname as name, + t.refFk as reference, + t.id as origin + FROM vn.sale s + JOIN vn.ticket t ON t.id = s.ticketFk + LEFT JOIN vn.ticketState ts ON ts.ticket = t.id + JOIN vn.client c ON c.id = t.clientFk + WHERE t.shipped >= vDateInventory + AND s.itemFk = vItemId + AND vWarehouse =t.warehouseFk + ) AS itemDiary + ORDER BY date, alertLevel, `in` DESC; + +END$$ + +DELIMITER ; +