From ec3a448396919636cb32c426ffcc3790eaa9099c Mon Sep 17 00:00:00 2001
From: Bernat <bernat.exposito@gmail.com>
Date: Mon, 8 Oct 2018 07:42:05 +0200
Subject: [PATCH] update structure cau 8409

---
 .../changes/1.2-CHECK/08-itemDiary.sql        | 119 ++++++++++++++++++
 1 file changed, 119 insertions(+)
 create mode 100644 services/db/install/changes/1.2-CHECK/08-itemDiary.sql

diff --git a/services/db/install/changes/1.2-CHECK/08-itemDiary.sql b/services/db/install/changes/1.2-CHECK/08-itemDiary.sql
new file mode 100644
index 0000000000..3994672fb2
--- /dev/null
+++ b/services/db/install/changes/1.2-CHECK/08-itemDiary.sql
@@ -0,0 +1,119 @@
+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();
+    DECLARE vDayEnd DATETIME DEFAULT util.dayEnd(vCurdate);
+    -- traduccion: date, alertLevel, origin, reference, name, In, Out, Balance
+    SELECT  Fechainventario INTO vDateInventory FROM vn2008.tblContadores;
+    SET @a = 0;
+    SELECT sql_no_cache DATE(date) AS date,
+            alertLevel,
+            stateName,
+            origin,
+            reference,
+            clientFk,
+            name,
+			`in`,
+            `out`,
+            @a := @a + IFNULL(`in`,0) - IFNULL(`out`,0) as balance,
+            isPicked,
+            isTicket
+        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,
+                    st.name AS stateName,
+                    s.name as name,
+                    e.ref as reference,
+                    e.id as origin,
+                    s.id as clientFk,
+                    TRUE isPicked,
+                    FALSE AS isTicket
+                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
+                    JOIN vn.alertLevel al ON al.alertLevel = 
+						CASE
+							WHEN tr.isReceived != FALSE THEN 3
+							WHEN tr.isDelivered THEN 1
+                            ELSE 0
+						END
+                    JOIN vn.state st ON st.code = al.code
+                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,
+                    st.name AS stateName,
+                    s.name as name,
+                    e.ref as reference,
+                    e.id as origin,
+                    s.id as clientFk,
+                    TRUE isPicked,
+                    FALSE AS isTicket
+                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
+                    JOIN vn.alertLevel al ON al.alertLevel = 
+						CASE
+							WHEN tr.isReceived != FALSE THEN 3
+							WHEN tr.isDelivered THEN 1
+                            ELSE 0
+						END
+                    JOIN vn.state st ON st.code = al.code
+                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`,
+                al.alertLevel as alertLevel,
+                st.name AS stateName,
+                t.nickname as name,
+                t.refFk as reference,
+                t.id as origin,
+                t.clientFk,
+                TRUE as isPicked, -- stk.id as isPicked
+                TRUE as isTicket
+                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
+                    JOIN vn.alertLevel al ON al.alertLevel = 
+						CASE
+							WHEN t.shipped < vCurdate THEN 3
+							WHEN t.shipped > vDayEnd THEN 0
+                            ELSE IFNULL(ts.alertLevel, 0)
+						END
+                    JOIN vn.state st ON st.code = al.code
+                    -- LEFT JOIN vn.saleTracking stk ON stk.saleFk = s.id AND stk.stateFk = 14
+                WHERE t.shipped >= vDateInventory
+                    AND s.itemFk = vItemId
+                    AND vWarehouse =t.warehouseFk
+            ) AS itemDiary
+        ORDER BY date DESC, alertLevel DESC, isPicked DESC, `in` DESC, `out` DESC;
+END$$
+
+DELIMITER ;
+