diff --git a/db/routines/hedera/procedures/order_confirmWithUser.sql b/db/routines/hedera/procedures/order_confirmWithUser.sql index 9c932aaa1..2b033b704 100644 --- a/db/routines/hedera/procedures/order_confirmWithUser.sql +++ b/db/routines/hedera/procedures/order_confirmWithUser.sql @@ -1,59 +1,62 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`order_confirmWithUser`(vSelf INT, vUserId INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`order_confirmWithUser`( + vSelf INT, + vUserFk INT +) BEGIN /** - * Confirms an order, creating each of its tickets on the corresponding - * date, store and user. + * Confirms an order, creating each of its tickets + * on the corresponding date, store and user. * * @param vSelf The order identifier * @param vUser The user identifier */ - DECLARE vOk BOOL; - DECLARE vDone BOOL DEFAULT FALSE; - DECLARE vWarehouse INT; + DECLARE vHasRows BOOL; + DECLARE vDone BOOL; + DECLARE vWarehouseFk INT; DECLARE vShipment DATE; - DECLARE vTicket INT; + DECLARE vShipmentDayEnd DATETIME; + DECLARE vTicketFk INT; DECLARE vNotes VARCHAR(255); - DECLARE vItem INT; + DECLARE vItemFk INT; DECLARE vConcept VARCHAR(30); DECLARE vAmount INT; + DECLARE vAvailable INT; DECLARE vPrice DECIMAL(10,2); - DECLARE vSale INT; - DECLARE vRate INT; - DECLARE vRowId INT; + DECLARE vSaleFk INT; + DECLARE vRowFk INT; DECLARE vPriceFixed DECIMAL(10,2); - DECLARE vDelivery DATE; - DECLARE vAddress INT; - DECLARE vIsConfirmed BOOL; - DECLARE vClientId INT; - DECLARE vCompanyId INT; - DECLARE vAgencyModeId INT; - DECLARE TICKET_FREE INT DEFAULT 2; - DECLARE vCalc INT; - DECLARE vIsLogifloraItem BOOL; - DECLARE vOldQuantity INT; - DECLARE vNewQuantity INT; + DECLARE vLanded DATE; + DECLARE vAddressFk INT; + DECLARE vClientFk INT; + DECLARE vCompanyFk INT; + DECLARE vAgencyModeFk INT; + DECLARE vCalcFk INT; DECLARE vIsTaxDataChecked BOOL; - DECLARE cDates CURSOR FOR - SELECT zgs.shipped, r.warehouse_id + DECLARE vDates CURSOR FOR + SELECT zgs.shipped, r.warehouseFk FROM `order` o - JOIN order_row r ON r.order_id = o.id - LEFT JOIN tmp.zoneGetShipped zgs ON zgs.warehouseFk = r.warehouse_id - WHERE o.id = vSelf AND r.amount != 0 - GROUP BY r.warehouse_id; + JOIN orderRow r ON r.orderFk = o.id + LEFT JOIN tmp.zoneGetShipped zgs ON zgs.warehouseFk = r.warehouseFk + WHERE o.id = vSelf + AND r.amount + GROUP BY r.warehouseFk; - DECLARE cRows CURSOR FOR - SELECT r.id, r.item_id, i.name, r.amount, r.price, r.rate, i.isFloramondo - FROM order_row r - JOIN vn.item i ON i.id = r.item_id - WHERE r.amount != 0 - AND r.warehouse_id = vWarehouse - AND r.order_id = vSelf + DECLARE vRows CURSOR FOR + SELECT r.id, + r.itemFk, + i.name, + r.amount, + r.price + FROM orderRow r + JOIN vn.item i ON i.id = r.itemFk + WHERE r.amount + AND r.warehouseFk = vWarehouseFk + AND r.orderFk = vSelf ORDER BY r.rate DESC; - DECLARE CONTINUE HANDLER FOR NOT FOUND - SET vDone = TRUE; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN @@ -62,26 +65,36 @@ BEGIN END; -- Carga los datos del pedido - SELECT o.date_send, o.address_id, o.note, a.clientFk, - o.company_id, o.agency_id, c.isTaxDataChecked - INTO vDelivery, vAddress, vNotes, vClientId, - vCompanyId, vAgencyModeId, vIsTaxDataChecked - FROM hedera.`order` o + SELECT o.date_send, + o.address_id, + o.note, + a.clientFk, + o.company_id, + o.agency_id, + c.isTaxDataChecked + INTO vLanded, + vAddressFk, + vNotes, + vClientFk, + vCompanyFk, + vAgencyModeFk, + vIsTaxDataChecked + FROM `order` o JOIN vn.address a ON a.id = o.address_id JOIN vn.client c ON c.id = a.clientFk WHERE o.id = vSelf; -- Verifica si el cliente tiene los datos comprobados IF NOT vIsTaxDataChecked THEN - CALL util.throw ('clientNotVerified'); + CALL util.throw('clientNotVerified'); END IF; -- Carga las fechas de salida de cada almacen - CALL vn.zone_getShipped (vDelivery, vAddress, vAgencyModeId, FALSE); + CALL vn.zone_getShipped(vLanded, vAddressFk, vAgencyModeFk, FALSE); -- Trabajador que realiza la accion - IF vUserId IS NULL THEN - SELECT employeeFk INTO vUserId FROM orderConfig; + IF vUserFk IS NULL THEN + SELECT employeeFk INTO vUserFk FROM orderConfig; END IF; START TRANSACTION; @@ -89,207 +102,188 @@ BEGIN CALL order_checkEditable(vSelf); -- Check order is not empty + SELECT COUNT(*) > 0 INTO vHasRows + FROM orderRow + WHERE orderFk = vSelf + AND amount > 0; - SELECT COUNT(*) > 0 INTO vOk - FROM order_row WHERE order_id = vSelf AND amount > 0; - - IF NOT vOk THEN - CALL util.throw ('ORDER_EMPTY'); + IF NOT vHasRows THEN + CALL util.throw('ORDER_EMPTY'); END IF; -- Crea los tickets del pedido - - OPEN cDates; - - lDates: - LOOP - SET vTicket = NULL; + OPEN vDates; + lDates: LOOP + SET vTicketFk = NULL; SET vDone = FALSE; - FETCH cDates INTO vShipment, vWarehouse; + FETCH vDates INTO vShipment, vWarehouseFk; IF vDone THEN LEAVE lDates; END IF; - -- Busca un ticket existente que coincida con los parametros - WITH tPrevia AS - (SELECT DISTINCT s.ticketFk + SET vShipmentDayEnd = util.dayEnd(vShipment); + + -- Busca un ticket libre disponible + WITH tPrevia AS ( + SELECT DISTINCT s.ticketFk FROM vn.sale s JOIN vn.saleGroupDetail sgd ON sgd.saleFk = s.id JOIN vn.ticket t ON t.id = s.ticketFk - WHERE t.shipped BETWEEN vShipment AND util.dayend(vShipment) - ) - SELECT t.id INTO vTicket + WHERE t.shipped BETWEEN vShipment AND vShipmentDayEnd + ) + SELECT t.id INTO vTicketFk FROM vn.ticket t JOIN vn.alertLevel al ON al.code = 'FREE' LEFT JOIN tPrevia tp ON tp.ticketFk = t.id - LEFT JOIN vn.ticketState tls on tls.ticketFk = t.id - JOIN hedera.`order` o - ON o.address_id = t.addressFk - AND vWarehouse = t.warehouseFk - AND o.date_send = t.landed - AND DATE(t.shipped) = vShipment + LEFT JOIN vn.ticketState tls ON tls.ticketFk = t.id + JOIN hedera.`order` o ON o.address_id = t.addressFk + AND t.shipped BETWEEN vShipment AND vShipmentDayEnd + AND t.warehouseFk = vWarehouseFk + AND o.date_send = t.landed WHERE o.id = vSelf AND t.refFk IS NULL AND tp.ticketFk IS NULL AND (tls.alertLevel IS NULL OR tls.alertLevel = al.id) LIMIT 1; + -- Comprobamos si hay un ticket de previa disponible + IF vTicketFk IS NULL THEN + WITH tItemPackingTypeOrder AS ( + SELECT GROUP_CONCAT( + DISTINCT i.itemPackingTypeFk ORDER BY i.itemPackingTypeFk + ) distinctItemPackingTypes, + o.address_id + FROM vn.item i + JOIN hedera.orderRow oro ON oro.itemFk = i.id + JOIN hedera.`order` o ON o.id = oro.orderFk + WHERE oro.orderFk = vSelf + ), + tItemPackingTypeTicket AS ( + SELECT t.id, + GROUP_CONCAT( + DISTINCT i.itemPackingTypeFk ORDER BY i.itemPackingTypeFk + ) distinctItemPackingTypes + FROM vn.ticket t + JOIN vn.ticketState tls ON tls.ticketFk = t.id + JOIN vn.alertLevel al ON al.id = tls.alertLevel + JOIN vn.sale s ON s.ticketFk = t.id + JOIN vn.item i ON i.id = s.itemFk + JOIN tItemPackingTypeOrder ipto + WHERE t.shipped BETWEEN vShipment AND vShipmentDayEnd + AND t.refFk IS NULL + AND t.warehouseFk = vWarehouseFk + AND t.addressFk = ipto.address_id + AND al.code = 'ON_PREVIOUS' + GROUP BY t.id + ) + SELECT iptt.id INTO vTicketFk + FROM tItemPackingTypeTicket iptt + JOIN tItemPackingTypeOrder ipto + WHERE INSTR(iptt.distinctItemPackingTypes, ipto.distinctItemPackingTypes) + LIMIT 1; + END IF; + -- Crea el ticket en el caso de no existir uno adecuado - IF vTicket IS NULL - THEN - + IF vTicketFk IS NULL THEN SET vShipment = IFNULL(vShipment, util.VN_CURDATE()); - CALL vn.ticket_add( - vClientId, + vClientFk, vShipment, - vWarehouse, - vCompanyId, - vAddress, - vAgencyModeId, + vWarehouseFk, + vCompanyFk, + vAddressFk, + vAgencyModeFk, NULL, - vDelivery, - vUserId, + vLanded, + vUserFk, TRUE, - vTicket + vTicketFk ); ELSE INSERT INTO vn.ticketTracking - SET ticketFk = vTicket, - userFk = vUserId, - stateFk = TICKET_FREE; + SET ticketFk = vTicketFk, + userFk = vUserFk, + stateFk = (SELECT id FROM vn.state WHERE code = 'FREE'); END IF; INSERT IGNORE INTO vn.orderTicket SET orderFk = vSelf, - ticketFk = vTicket; + ticketFk = vTicketFk; -- Añade las notas - - IF vNotes IS NOT NULL AND vNotes != '' - THEN - INSERT INTO vn.ticketObservation SET - ticketFk = vTicket, - observationTypeFk = 4 /* salesperson */ , + IF vNotes IS NOT NULL AND vNotes <> '' THEN + INSERT INTO vn.ticketObservation + SET ticketFk = vTicketFk, + observationTypeFk = (SELECT id FROM vn.observationType WHERE code = 'salesPerson'), `description` = vNotes ON DUPLICATE KEY UPDATE `description` = CONCAT(VALUES(`description`),'. ', `description`); END IF; -- Añade los movimientos y sus componentes - - OPEN cRows; - + OPEN vRows; lRows: LOOP + SET vSaleFk = NULL; SET vDone = FALSE; - FETCH cRows INTO vRowId, vItem, vConcept, vAmount, vPrice, vRate, vIsLogifloraItem; + FETCH vRows INTO vRowFk, vItemFk, vConcept, vAmount, vPrice; IF vDone THEN LEAVE lRows; END IF; - SET vSale = NULL; - - SELECT s.id, s.quantity INTO vSale, vOldQuantity + SELECT s.id INTO vSaleFk FROM vn.sale s - WHERE ticketFk = vTicket + WHERE ticketFk = vTicketFk AND price = vPrice - AND itemFk = vItem + AND itemFk = vItemFk AND discount = 0 LIMIT 1; - IF vSale THEN + IF vSaleFk THEN UPDATE vn.sale SET quantity = quantity + vAmount, originalQuantity = quantity - WHERE id = vSale; - - SELECT s.quantity INTO vNewQuantity - FROM vn.sale s - WHERE id = vSale; + WHERE id = vSaleFk; ELSE -- Obtiene el coste SELECT SUM(rc.`price`) valueSum INTO vPriceFixed FROM orderRowComponent rc JOIN vn.component c ON c.id = rc.componentFk - JOIN vn.componentType ct ON ct.id = c.typeFk AND ct.isBase - WHERE rc.rowFk = vRowId; + JOIN vn.componentType ct ON ct.id = c.typeFk + AND ct.isBase + WHERE rc.rowFk = vRowFk; INSERT INTO vn.sale - SET itemFk = vItem, - ticketFk = vTicket, + SET itemFk = vItemFk, + ticketFk = vTicketFk, concept = vConcept, quantity = vAmount, price = vPrice, priceFixed = vPriceFixed, isPriceFixed = TRUE; - SET vSale = LAST_INSERT_ID(); + SET vSaleFk = LAST_INSERT_ID(); - INSERT INTO vn.saleComponent - (saleFk, componentFk, `value`) - SELECT vSale, rc.componentFk, rc.price + INSERT INTO vn.saleComponent (saleFk, componentFk, `value`) + SELECT vSaleFk, rc.componentFk, rc.price FROM orderRowComponent rc JOIN vn.component c ON c.id = rc.componentFk - WHERE rc.rowFk = vRowId - GROUP BY vSale, rc.componentFk; + WHERE rc.rowFk = vRowFk + GROUP BY vSaleFk, rc.componentFk; END IF; - UPDATE order_row SET Id_Movimiento = vSale - WHERE id = vRowId; - - -- Inserta en putOrder si la compra es de Floramondo - IF vIsLogifloraItem THEN - CALL cache.availableNoRaids_refresh(vCalc,FALSE,vWarehouse,vShipment); - - SET @available := 0; - - SELECT GREATEST(0,available) INTO @available - FROM cache.availableNoRaids - WHERE calc_id = vCalc - AND item_id = vItem; - - UPDATE cache.availableNoRaids - SET available = GREATEST(0,available - vAmount) - WHERE item_id = vItem - AND calc_id = vCalc; - - INSERT INTO edi.putOrder ( - deliveryInformationID, - supplyResponseId, - quantity , - EndUserPartyId, - EndUserPartyGLN, - FHAdminNumber, - saleFk - ) - SELECT di.ID, - i.supplyResponseFk, - CEIL((vAmount - @available)/ sr.NumberOfItemsPerCask), - o.address_id , - vClientId, - IFNULL(ca.fhAdminNumber, fhc.defaultAdminNumber), - vSale - FROM edi.deliveryInformation di - JOIN vn.item i ON i.supplyResponseFk = di.supplyResponseID - JOIN edi.supplyResponse sr ON sr.ID = i.supplyResponseFk - LEFT JOIN edi.clientFHAdminNumber ca ON ca.clientFk = vClientId - JOIN edi.floraHollandConfig fhc - JOIN hedera.`order` o ON o.id = vSelf - WHERE i.id = vItem - AND di.LatestOrderDateTime > util.VN_NOW() - AND vAmount > @available - LIMIT 1; - END IF; + UPDATE orderRow + SET saleFk = vSaleFk + WHERE id = vRowFk; END LOOP; - - CLOSE cRows; + CLOSE vRows; END LOOP; + CLOSE vDates; - CLOSE cDates; - - UPDATE `order` SET confirmed = TRUE, confirm_date = util.VN_NOW() + UPDATE `order` + SET confirmed = TRUE, + confirm_date = util.VN_NOW() WHERE id = vSelf; COMMIT; diff --git a/db/routines/vn/procedures/entry_splitByShelving.sql b/db/routines/vn/procedures/entry_splitByShelving.sql index eb07c12b7..f46278e5a 100644 --- a/db/routines/vn/procedures/entry_splitByShelving.sql +++ b/db/routines/vn/procedures/entry_splitByShelving.sql @@ -110,7 +110,7 @@ BEGIN UPDATE itemShelving SET isSplit = TRUE - WHERE shelvingFk = vShelvingFk; + WHERE shelvingFk = vShelvingFk COLLATE utf8_general_ci; END LOOP; CLOSE cur; END$$ diff --git a/db/routines/vn/procedures/invoiceIn_booking.sql b/db/routines/vn/procedures/invoiceIn_booking.sql index c728085b8..a5dd3a5f1 100644 --- a/db/routines/vn/procedures/invoiceIn_booking.sql +++ b/db/routines/vn/procedures/invoiceIn_booking.sql @@ -16,9 +16,11 @@ BEGIN DECLARE vHasRepeatedTransactions BOOL; SELECT TRUE INTO vHasRepeatedTransactions - FROM invoiceInTax - WHERE invoiceInFk = vSelf - HAVING COUNT(DISTINCT transactionTypeSageFk) > 1 + FROM invoiceInTax iit + JOIN invoiceIn ii ON ii.id = iit.invoiceInFk + WHERE ii.id = vSelf + AND ii.serial = 'E' + HAVING COUNT(DISTINCT iit.transactionTypeSageFk) > 1 LIMIT 1; IF vHasRepeatedTransactions THEN diff --git a/db/routines/vn/procedures/itemShelvingSale_addBySaleGroup.sql b/db/routines/vn/procedures/itemShelvingSale_addBySaleGroup.sql new file mode 100644 index 000000000..285b9f93f --- /dev/null +++ b/db/routines/vn/procedures/itemShelvingSale_addBySaleGroup.sql @@ -0,0 +1,46 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addBySaleGroup`( + vSaleGroupFk INT(11) +) +BEGIN +/** + * Reserva cantidades con ubicaciones para el contenido de una preparación previa + * a través del saleGroup + * + * @param vSaleGroupFk Identificador de saleGroup + */ + DECLARE vDone BOOL DEFAULT FALSE; + DECLARE vSaleFk INT; + DECLARE vSectorFk INT; + DECLARE vSales CURSOR FOR + SELECT s.id + FROM saleGroupDetail sgd + JOIN sale s ON sgd.saleFk = s.id + JOIN saleTracking str ON str.saleFk = s.id + JOIN `state` st ON st.id = str.stateFk + AND st.code = 'PREVIOUS_PREPARATION' + LEFT JOIN itemShelvingSale iss ON iss.saleFk = s.id + WHERE sgd.saleGroupFk = vSaleGroupFk + AND str.workerFk = account.myUser_getId() + AND iss.id IS NULL; + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; + + SELECT sectorFk INTO vSectorFk + FROM operator + WHERE workerFk = account.myUser_getId(); + + OPEN vSales; + l: LOOP + SET vDone = FALSE; + FETCH vSales INTO vSaleFk; + + IF vDone THEN + LEAVE l; + END IF; + + CALL itemShelvingSale_addBySale(vSaleFk, vSectorFk); + END LOOP; + CLOSE vSales; +END$$ +DELIMITER ; \ No newline at end of file diff --git a/db/routines/vn/procedures/itemShelving_get.sql b/db/routines/vn/procedures/itemShelving_get.sql index 1be762f09..d42446b06 100644 --- a/db/routines/vn/procedures/itemShelving_get.sql +++ b/db/routines/vn/procedures/itemShelving_get.sql @@ -16,7 +16,8 @@ BEGIN ish.id, s.priority, ish.isChecked, - ic.url + ic.url, + ish.available FROM itemShelving ish JOIN item i ON i.id = ish.itemFk JOIN shelving s ON vSelf = s.code COLLATE utf8_unicode_ci diff --git a/db/routines/vn/procedures/item_getMinacum.sql b/db/routines/vn/procedures/item_getMinacum.sql index a3ebedb12..1decf881d 100644 --- a/db/routines/vn/procedures/item_getMinacum.sql +++ b/db/routines/vn/procedures/item_getMinacum.sql @@ -1,37 +1,40 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getMinacum`(IN vWarehouseFk TINYINT, IN vDatedFrom DATETIME, IN vRange INT, IN vItemFk INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getMinacum`( + vWarehouseFk TINYINT, + vDated DATE, + vRange INT, + vItemFk INT +) BEGIN /** - * Cálculo del mínimo acumulado, para un item/almacén especificado, en caso de - * NULL para todo. + * Cálculo del mínimo acumulado, para un item/almacén + * especificado, en caso de NULL para todos. * - * @param vWarehouseFk -> warehouseFk - * @param vDatedFrom -> fecha inicio - * @param vRange -> número de días a considerar - * @param vItemFk -> Identificador de item + * @param vWarehouseFk Id warehouse + * @param vDated Fecha inicio + * @param vRange Número de días a considerar + * @param vItemFk Id de artículo * @return tmp.itemMinacum */ - DECLARE vDatedTo DATETIME; + DECLARE vDatedTo DATETIME DEFAULT util.dayEnd(vDated + INTERVAL vRange DAY); - SET vDatedFrom = TIMESTAMP(DATE(vDatedFrom), '00:00:00'); - SET vDatedTo = TIMESTAMP(TIMESTAMPADD(DAY, vRange, vDatedFrom), '23:59:59'); - - DROP TEMPORARY TABLE IF EXISTS tmp.itemCalc; - CREATE TEMPORARY TABLE tmp.itemCalc + CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc (INDEX (itemFk, warehouseFk)) + ENGINE = MEMORY SELECT sub.itemFk, sub.dated, CAST(SUM(sub.quantity) AS SIGNED) quantity, sub.warehouseFk - FROM (SELECT s.itemFk, + FROM ( + SELECT s.itemFk, DATE(t.shipped) dated, -s.quantity quantity, t.warehouseFk FROM sale s JOIN ticket t ON t.id = s.ticketFk - WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo + WHERE t.shipped BETWEEN vDated AND vDatedTo AND t.warehouseFk - AND s.quantity != 0 + AND s.quantity <> 0 AND (vItemFk IS NULL OR s.itemFk = vItemFk) AND (vWarehouseFk IS NULL OR t.warehouseFk = vWarehouseFk) UNION ALL @@ -42,10 +45,10 @@ BEGIN FROM buy b JOIN entry e ON e.id = b.entryFk JOIN travel t ON t.id = e.travelFk - WHERE t.landed BETWEEN vDatedFrom AND vDatedTo + WHERE t.landed BETWEEN vDated AND vDatedTo AND (vWarehouseFk IS NULL OR t.warehouseInFk = vWarehouseFk) - AND !e.isExcludedFromAvailable - AND b.quantity != 0 + AND NOT e.isExcludedFromAvailable + AND b.quantity <> 0 AND (vItemFk IS NULL OR b.itemFk = vItemFk) UNION ALL SELECT b.itemFk, @@ -55,28 +58,45 @@ BEGIN FROM buy b JOIN entry e ON e.id = b.entryFk JOIN travel t ON t.id = e.travelFk - WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo + WHERE t.shipped BETWEEN vDated AND vDatedTo AND (vWarehouseFk IS NULL OR t.warehouseOutFk = vWarehouseFk) - AND !e.isExcludedFromAvailable - AND b.quantity != 0 + AND NOT e.isExcludedFromAvailable + AND b.quantity <> 0 AND (vItemFk IS NULL OR b.itemFk = vItemFk) - AND !e.isRaid + AND NOT e.isRaid + UNION ALL + SELECT r.itemFk, + r.shipment, + -r.amount, + r.warehouseFk + FROM hedera.orderRow r + JOIN hedera.`order` o ON o.id = r.orderFk + JOIN client c ON c.id = o.customer_id + WHERE r.shipment BETWEEN vDated AND vDatedTo + AND (vWarehouseFk IS NULL OR r.warehouseFk = vWarehouseFk) + AND r.created >= ( + SELECT util.VN_NOW() - INTERVAL TIME_TO_SEC(reserveTime) SECOND + FROM hedera.orderConfig + ) + AND NOT o.confirmed + AND (vItemFk IS NULL OR r.itemFk = vItemFk) + AND r.amount <> 0 ) sub GROUP BY sub.itemFk, sub.warehouseFk, sub.dated; - CALL item_getAtp(vDatedFrom); - DROP TEMPORARY TABLE tmp.itemCalc; + CALL item_getAtp(vDated); - DROP TEMPORARY TABLE IF EXISTS tmp.itemMinacum; - CREATE TEMPORARY TABLE tmp.itemMinacum + CREATE OR REPLACE TEMPORARY TABLE tmp.itemMinacum (INDEX(itemFk)) ENGINE = MEMORY - SELECT i.itemFk, - i.warehouseFk, - i.quantity amount - FROM tmp.itemAtp i - HAVING amount != 0; + SELECT itemFk, + warehouseFk, + quantity amount + FROM tmp.itemAtp + WHERE quantity <> 0; - DROP TEMPORARY TABLE tmp.itemAtp; + DROP TEMPORARY TABLE + tmp.itemAtp, + tmp.itemCalc; END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/sale_getProblems.sql b/db/routines/vn/procedures/sale_getProblems.sql index 64ecb898d..c881bcf92 100644 --- a/db/routines/vn/procedures/sale_getProblems.sql +++ b/db/routines/vn/procedures/sale_getProblems.sql @@ -13,7 +13,7 @@ BEGIN DECLARE vAvailableCache INT; DECLARE vVisibleCache INT; DECLARE vDone BOOL; - DECLARE vComponentCount INT; + DECLARE vRequiredComponent INT; DECLARE vCursor CURSOR FOR SELECT DISTINCT tt.warehouseFk, IF(vIsTodayRelative, util.VN_CURDATE(), DATE(tt.shipped)) @@ -54,7 +54,7 @@ BEGIN SELECT ticketFk, clientFk FROM tmp.sale_getProblems; - SELECT COUNT(*) INTO vComponentCount + SELECT COUNT(*) INTO vRequiredComponent FROM component WHERE isRequired; @@ -96,20 +96,18 @@ BEGIN -- Faltan componentes INSERT INTO tmp.sale_problems(ticketFk, hasComponentLack, saleFk) - SELECT ticketFk, (vComponentCount > nComp) hasComponentLack, saleFk - FROM ( - SELECT COUNT(s.id) nComp, tl.ticketFk, s.id saleFk - FROM tmp.ticket_list tl - JOIN sale s ON s.ticketFk = tl.ticketFk - LEFT JOIN saleComponent sc ON sc.saleFk = s.id - LEFT JOIN component c ON c.id = sc.componentFk AND c.isRequired - JOIN ticket t ON t.id = tl.ticketFk - JOIN agencyMode am ON am.id = t.agencyModeFk - JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk - WHERE dm.code IN ('AGENCY','DELIVERY','PICKUP') - AND s.quantity > 0 - GROUP BY s.id - ) sub + SELECT t.id, COUNT(c.id) < vRequiredComponent hasComponentLack, s.id + FROM tmp.ticket_list tl + JOIN ticket t ON t.id = tl.ticketFk + JOIN sale s ON s.ticketFk = t.id + JOIN agencyMode am ON am.id = t.agencyModeFk + JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk + LEFT JOIN saleComponent sc ON sc.saleFk = s.id + LEFT JOIN component c ON c.id = sc.componentFk + AND c.isRequired + WHERE dm.code IN ('AGENCY','DELIVERY','PICKUP') + AND s.quantity > 0 + GROUP BY s.id HAVING hasComponentLack; -- Cliente congelado diff --git a/db/routines/vn/procedures/sale_setProblemComponentLack.sql b/db/routines/vn/procedures/sale_setProblemComponentLack.sql index aa5f5f1be..23eb77c2e 100644 --- a/db/routines/vn/procedures/sale_setProblemComponentLack.sql +++ b/db/routines/vn/procedures/sale_setProblemComponentLack.sql @@ -14,7 +14,7 @@ BEGIN ENGINE = MEMORY SELECT vSelf saleFk, sale_hasComponentLack(vSelf) hasProblem, - ticket_isProblemCalcNeeded(ticketFk) isProblemCalcNeeded + (ticket_isProblemCalcNeeded(ticketFk) AND quantity > 0) isProblemCalcNeeded FROM sale WHERE id = vSelf; diff --git a/db/routines/vn/procedures/sale_setProblemComponentLackByComponent.sql b/db/routines/vn/procedures/sale_setProblemComponentLackByComponent.sql index 2ee49b656..cdf28ac09 100644 --- a/db/routines/vn/procedures/sale_setProblemComponentLackByComponent.sql +++ b/db/routines/vn/procedures/sale_setProblemComponentLackByComponent.sql @@ -14,9 +14,9 @@ BEGIN ENGINE = MEMORY SELECT saleFk, sale_hasComponentLack(saleFk) hasProblem, - ticket_isProblemCalcNeeded(ticketFk) isProblemCalcNeeded + (ticket_isProblemCalcNeeded(ticketFk) AND quantity > 0) isProblemCalcNeeded FROM ( - SELECT s.id saleFk, s.ticketFk + SELECT s.id saleFk, s.ticketFk, s.quantity FROM ticket t JOIN sale s ON s.ticketFk = t.id LEFT JOIN saleComponent sc ON sc.saleFk = s.id diff --git a/db/routines/vn/procedures/ticket_setProblemRiskByClient.sql b/db/routines/vn/procedures/ticket_setProblemRiskByClient.sql new file mode 100644 index 000000000..8479550de --- /dev/null +++ b/db/routines/vn/procedures/ticket_setProblemRiskByClient.sql @@ -0,0 +1,35 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setProblemRiskByClient`( + vClientFk INT +) +BEGIN +/** + * Updates future ticket risk for a client. + * + * @param vClientFk Id client + */ + DECLARE vDone INT DEFAULT FALSE; + DECLARE vTicketFk INT; + DECLARE vTickets CURSOR FOR + SELECT id + FROM ticket + WHERE clientFk = vClientFk + AND shipped >= util.VN_CURDATE() + AND refFk IS NULL; + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; + + OPEN vTickets; + l: LOOP + SET vDone = FALSE; + FETCH vTickets INTO vTicketFk; + + IF vDone THEN + LEAVE l; + END IF; + + CALL vn.ticket_setProblemRisk(vTicketFk); + END LOOP; + CLOSE vTickets; +END$$ +DELIMITER ; \ No newline at end of file diff --git a/db/routines/vn/procedures/ticket_setRisk.sql b/db/routines/vn/procedures/ticket_setRisk.sql index bd5d1e9f9..e3cbaf231 100644 --- a/db/routines/vn/procedures/ticket_setRisk.sql +++ b/db/routines/vn/procedures/ticket_setRisk.sql @@ -1,94 +1,83 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setRisk`( - vClientFk INT) + vClientFk INT +) BEGIN /** - * Update the risk for a client with pending tickets + * Update the risk for a client with pending tickets. * * @param vClientFk Id cliente */ - DECLARE vHasDebt BOOL; - DECLARE vStarted DATETIME; - - SELECT COUNT(*) INTO vHasDebt - FROM `client` - WHERE id = vClientFk - AND typeFk = 'normal'; - - IF vHasDebt THEN - - SELECT util.VN_CURDATE() - INTERVAL riskScope MONTH INTO vStarted - FROM clientConfig; - + IF (SELECT COUNT(*) FROM client WHERE id = vClientFk AND typeFk = 'normal') THEN CREATE OR REPLACE TEMPORARY TABLE tTicketRisk - (KEY (ticketFk)) + (PRIMARY KEY (ticketFk)) ENGINE = MEMORY - WITH ticket AS( - SELECT id ticketFk, - companyFk, - DATE(shipped) dated, - totalWithVat, - ticket_isProblemCalcNeeded(id) isProblemCalcNeeded - FROM vn.ticket - WHERE clientFk = vClientFk - AND refFk IS NULL - AND NOT isDeleted - AND IFNULL(totalWithVat, 0) <> 0 - AND shipped > vStarted - ), balance AS( - SELECT SUM(amount)amount, companyFk - FROM ( - SELECT amount, companyFk - FROM vn.clientRisk - WHERE clientFk = vClientFk - UNION ALL - SELECT -(SUM(amount) / 100) amount, tm.companyFk - FROM hedera.tpvTransaction t - JOIN hedera.tpvMerchant tm ON t.id = t.merchantFk - WHERE clientFk = vClientFk - AND receiptFk IS NULL - AND status = 'ok' - ) sub - WHERE companyFk - GROUP BY companyFk - ), uninvoiced AS( + WITH ticket AS ( + SELECT t.id ticketFk, + t.companyFk, + DATE(t.shipped) dated, + t.totalWithVat, + ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded + FROM vn.ticket t + JOIN vn.clientConfig cc + WHERE t.clientFk = vClientFk + AND t.refFk IS NULL + AND NOT t.isDeleted + AND IFNULL(t.totalWithVat, 0) <> 0 + AND t.shipped > (util.VN_CURDATE() - INTERVAL cc.riskScope MONTH) + ), uninvoiced AS ( SELECT companyFk, dated, SUM(totalWithVat) amount FROM ticket - GROUP BY companyFk, dated - ), receipt AS( - SELECT companyFk, DATE(payed) dated, SUM(amountPaid) amount - FROM vn.receipt - WHERE clientFk = vClientFk - AND payed > util.VN_CURDATE() - GROUP BY companyFk, DATE(payed) - ), risk AS( + GROUP BY companyFk, dated + ), companies AS ( + SELECT DISTINCT companyFk FROM uninvoiced + ), balance AS ( + SELECT SUM(IFNULL(amount, 0))amount, companyFk + FROM ( + SELECT cr.amount, c.companyFk + FROM companies c + LEFT JOIN vn.clientRisk cr ON cr.companyFk = c.companyFk + AND cr.clientFk = vClientFk + UNION ALL + SELECT -(SUM(t.amount) / 100) amount, c.companyFk + FROM companies c + LEFT JOIN hedera.tpvMerchant tm ON tm.companyFk = c.companyFk + LEFT JOIN hedera.tpvTransaction t ON t.merchantFk = tm.id + AND t.clientFk = vClientFk + AND t.receiptFk IS NULL + AND t.`status` = 'ok' + ) sub + WHERE companyFk + GROUP BY companyFk + ), receipt AS ( + SELECT r.companyFk, DATE(r.payed) dated, SUM(r.amountPaid) amount + FROM vn.receipt r + JOIN companies c ON c.companyFk = r.companyFk + WHERE r.clientFk = vClientFk + AND r.payed > util.VN_CURDATE() + GROUP BY r.companyFk, DATE(r.payed) + ), risk AS ( SELECT b.companyFk, - ui.dated, - SUM(ui.amount) OVER (PARTITION BY b.companyFk ORDER BY ui.dated ) + + ui.dated, + SUM(ui.amount) OVER (PARTITION BY b.companyFk ORDER BY ui.dated) + b.amount + SUM(IFNULL(r.amount, 0)) amount FROM balance b JOIN uninvoiced ui ON ui.companyFk = b.companyFk - LEFT JOIN receipt r ON r.dated > ui.dated AND r.companyFk = ui.companyFk + LEFT JOIN receipt r ON r.dated > ui.dated + AND r.companyFk = ui.companyFk GROUP BY b.companyFk, ui.dated - ) - SELECT ti.ticketFk, r.amount, ti.isProblemCalcNeeded - FROM ticket ti - JOIN risk r ON r.dated = ti.dated AND r.companyFk = ti.companyFk; + ) + SELECT ti.ticketFk, r.amount, ti.isProblemCalcNeeded + FROM ticket ti + JOIN risk r ON r.dated = ti.dated + AND r.companyFk = ti.companyFk; UPDATE ticket t JOIN tTicketRisk tr ON tr.ticketFk = t.id - SET t.risk = tr.amount - WHERE tr.isProblemCalcNeeded - ORDER BY t.id; - - UPDATE ticket t - JOIN tTicketRisk tr ON tr.ticketFk = t.id - SET t.risk = NULL - WHERE tr.isProblemCalcNeeded - ORDER BY t.id; + SET t.risk = IF(tr.isProblemCalcNeeded, tr.amount, NULL); DROP TEMPORARY TABLE tTicketRisk; - END IF; + END IF; END$$ DELIMITER ; \ No newline at end of file diff --git a/db/routines/vn/triggers/itemShelving_beforeUpdate.sql b/db/routines/vn/triggers/itemShelving_beforeUpdate.sql index 214c64b45..961d89f65 100644 --- a/db/routines/vn/triggers/itemShelving_beforeUpdate.sql +++ b/db/routines/vn/triggers/itemShelving_beforeUpdate.sql @@ -9,9 +9,5 @@ BEGIN SET NEW.userFk = account.myUser_getId(); END IF; - IF (NEW.visible <> OLD.visible) THEN - SET NEW.available = GREATEST(NEW.available + NEW.visible - OLD.visible, 0); - END IF; - END$$ DELIMITER ; diff --git a/modules/entry/back/methods/entry/getBuys.js b/modules/entry/back/methods/entry/getBuys.js index bd9c5db7a..245dada09 100644 --- a/modules/entry/back/methods/entry/getBuys.js +++ b/modules/entry/back/methods/entry/getBuys.js @@ -101,7 +101,8 @@ module.exports = Self => { 'groupingMode', 'inkFk', 'originFk', - 'producerFk' + 'producerFk', + 'comment' ], include: [ { diff --git a/modules/item/back/models/item-shelving.json b/modules/item/back/models/item-shelving.json index 893a1f81d..5df3b0703 100644 --- a/modules/item/back/models/item-shelving.json +++ b/modules/item/back/models/item-shelving.json @@ -1,9 +1,9 @@ { "name": "ItemShelving", "base": "VnModel", - "mixins": { - "Loggable": true - }, + "mixins": { + "Loggable": true + }, "options": { "mysql": { "table": "itemShelving" @@ -17,27 +17,30 @@ }, "shelvingFk": { "type": "string" - }, + }, "itemFk": { "type": "number" - }, + }, "created": { "type": "date" - }, + }, "grouping": { "type": "number" - }, - "isChecked": { - "type": "boolean" + }, + "isChecked": { + "type": "number" }, "packing": { "type": "number" - }, - "visible": { - "type": "number" }, - "userFk": { - "type": "number" + "visible": { + "type": "number" + }, + "userFk": { + "type": "number" + }, + "available": { + "type": "number" } }, "relations": { @@ -56,6 +59,6 @@ "model": "Shelving", "foreignKey": "shelvingFk", "primaryKey": "code" - } + } } -} +} \ No newline at end of file diff --git a/print/templates/reports/buy-label/buy-label.js b/print/templates/reports/buy-label/buy-label.js index 7d626c052..48ffe336c 100755 --- a/print/templates/reports/buy-label/buy-label.js +++ b/print/templates/reports/buy-label/buy-label.js @@ -15,7 +15,6 @@ module.exports = { }, methods: { getBarcode(id) { - const xmlSerializer = new XMLSerializer(); const document = new DOMImplementation().createDocument('http://www.w3.org/1999/xhtml', 'html', null); const svgNode = document.createElementNS('http://www.w3.org/2000/svg', 'svg'); @@ -26,7 +25,7 @@ module.exports = { width: 3.8, height: 115, }); - return xmlSerializer.serializeToString(svgNode); + return new XMLSerializer().serializeToString(svgNode); } }, props: { diff --git a/print/templates/reports/buy-label/sql/buys.sql b/print/templates/reports/buy-label/sql/buys.sql index 015a74797..44b1b4bad 100644 --- a/print/templates/reports/buy-label/sql/buys.sql +++ b/print/templates/reports/buy-label/sql/buys.sql @@ -21,12 +21,13 @@ SELECT ROW_NUMBER() OVER(ORDER BY b.id, num.n) labelNum, b.id, b.itemFk, p.name producer, - i.comment + IF(i2.id, i2.comment, i.comment) comment FROM buy b JOIN item i ON i.id = b.itemFk LEFT JOIN producer p ON p.id = i.producerFk LEFT JOIN ink ON ink.id = i.inkFk LEFT JOIN origin o ON o.id = i.originFk + LEFT JOIN item i2 ON i2.id = b.itemOriginalFk JOIN numbers num WHERE b.entryFk = ? AND num.n <= b.stickers