diff --git a/db/routines/vn/procedures/boxPicking_print.sql b/db/routines/vn/procedures/boxPicking_print.sql new file mode 100644 index 000000000..5eea4ee1e --- /dev/null +++ b/db/routines/vn/procedures/boxPicking_print.sql @@ -0,0 +1,283 @@ +DELIMITER $$ +$$ +CREATE OR REPLACE PROCEDURE vn.sale_boxPickingPrint( + IN vPrinterFk INT, + IN vSaleFk INT, + IN vPacking INT, + IN vSectorFk INT, + IN vUserFk INT, + IN vPackagingFk INT, + IN vPackingSiteFk INT) +BEGIN +/** Splits a line of sale to a different ticket and prints the transport sticker + */ + DECLARE vAgencyModeFk INT; + DECLARE vConcept VARCHAR(30); + DECLARE vExpeditionFk INT; + DECLARE vItemFk INT; + DECLARE vItemShelvingFk INT; + DECLARE vItemShelvingSaleFk INT; + DECLARE vItemShelvingSaleFk_old INT; + DECLARE vLastExpeditionTimeStamp DATETIME; + DECLARE vMaxPhoneLength INT DEFAULT 11; + DECLARE vMaxStreetLength INT DEFAULT 36; + DECLARE vNewSaleFk INT; + DECLARE vNewTicketFk INT; + DECLARE vParkingCode VARCHAR(10); + DECLARE vQuantity INT; + DECLARE vRemainder INT DEFAULT 0; + DECLARE vRemainderSaleFk INT; + DECLARE vShelving VARCHAR(10); + DECLARE vTicketFk INT; + + SELECT s.quantity, + s.quantity MOD vPacking, + s.ticketFk, + s.itemFk, + s.concept + INTO vQuantity, + vRemainder, + vTicketFk, + vItemFk, + vConcept + FROM sale s + WHERE s.id = vSaleFk; + + IF vRemainder THEN + UPDATE sale SET quantity = quantity - vRemainder WHERE id = vSaleFk; + + INSERT INTO sale(ticketFk, itemFk, quantity, price, discount, concept) + SELECT ticketFk, itemFk, vRemainder, price, discount, concept + FROM sale + WHERE id = vSaleFk; + + SET vRemainderSaleFk = LAST_INSERT_ID(); + + INSERT INTO saleComponent(saleFk, componentFk, value) + SELECT vRemainderSaleFk, componentFk, value + FROM saleComponent + WHERE saleFk = vSaleFk; + END IF; + +w1: WHILE vQuantity >= vPacking DO + + SET vItemShelvingFk = NULL; + + SELECT sub.id + INTO vItemShelvingFk + FROM productionConfig pc + JOIN ( + SELECT ish.id, + ish.visible - IFNULL(SUM(iss.quantity),0) available, + p.pickingOrder, + ish.created + FROM itemShelving ish + JOIN shelving sh ON sh.code = ish.shelvingFk + JOIN parking p ON p.id = sh.parkingFk + LEFT JOIN itemShelvingSale iss + ON iss.itemShelvingFk = ish.id + AND iss.created >= CURDATE() + AND iss.isPicked = FALSE + WHERE ish.itemFk = vItemFk + AND p.sectorFk = vSectorFk + GROUP BY ish.id + HAVING available >= vPacking) sub + ORDER BY IF(pc.orderMode = 'Location',sub.pickingOrder, sub.created) + LIMIT 1; + + IF vItemShelvingFk THEN + INSERT INTO itemShelvingSale + SET itemShelvingFk = vItemShelvingFk, + saleFk = vSaleFk, + quantity = vPacking, + userFk = vUserFk, + isPicked = TRUE; + + SET vItemShelvingSaleFk = LAST_INSERT_ID(); + + UPDATE sale SET isPicked = FALSE WHERE id = vSaleFk; + ELSE + LEAVE w1; + END IF; + + SET vNewTicketFk = NULL; + + SELECT MAX(t.id) INTO vNewTicketFk + FROM ticket t + JOIN ticketLastState tls ON tls.ticketFk = t.id + JOIN (SELECT addressFk, clientFk, date(shipped) shipped, warehouseFk + FROM ticket + WHERE id = vTicketFk) tt + ON tt.addressFk = t.addressFk + AND tt.clientFk = t.clientFk + AND t.shipped BETWEEN tt.shipped AND util.dayend(tt.shipped) + AND t.warehouseFk = tt.warehouseFk + WHERE tls.name = 'Encajado' ; + + IF ISNULL(vNewTicketFk) THEN + INSERT INTO ticket( clientFk, + shipped, + addressFk, + agencyModeFk, + nickname, + warehouseFk, + companyFk, + landed, + zoneFk, + zonePrice, + zoneBonus, + routeFk, + priority, + hasPriority, + clonedFrom) + SELECT clientFk, + shipped, + addressFk, + agencyModeFk, + nickname, + warehouseFk, + companyFk, + landed, + zoneFk, + zonePrice, + zoneBonus, + routeFk, + priority, + hasPriority, + id + FROM ticket + WHERE id = vTicketFk; + + SET vNewTicketFk = LAST_INSERT_ID(); + + INSERT INTO ticketTracking(ticketFk, stateFk, userFk) + SELECT vNewTicketFk, id, vUserFk + FROM state + WHERE code = 'PACKED'; + END IF; + + UPDATE sale SET quantity = quantity - vPacking WHERE id = vSaleFk; + + UPDATE itemShelving SET visible = visible - vPacking WHERE id = vItemShelvingFk; + + SET vNewSaleFk = NULL; + + SELECT MAX(id) INTO vNewSaleFk + FROM sale + WHERE ticketFk = vNewTicketFk + AND itemFk = vItemFk; + + IF vNewSaleFk THEN + UPDATE sale + SET quantity = quantity + vPacking + WHERE id = vNewSaleFk; + + SET vItemShelvingSaleFk_old = NULL; + + SELECT MAX(id) INTO vItemShelvingSaleFk_old + FROM itemShelvingSale + WHERE itemShelvingFk = vItemShelvingFk + AND saleFk = vNewSaleFk; + + IF vItemShelvingSaleFk_old THEN + UPDATE itemShelvingSale + SET quantity = quantity + vPacking + WHERE id = vItemShelvingSaleFk_old; + + DELETE FROM itemShelvingSale + WHERE id = vItemShelvingSaleFk; + + SET vItemShelvingSaleFk = vItemShelvingSaleFk_old; + ELSE + UPDATE itemShelvingSale + SET saleFk = vNewSaleFk + WHERE id = vItemShelvingSaleFk; + END IF; + ELSE + INSERT INTO sale(ticketFk, itemFk, concept, quantity, discount, price) + SELECT vNewTicketFk, itemFk, concept, vPacking, discount, price + FROM sale + WHERE id = vSaleFk; + + SET vNewSaleFk = LAST_INSERT_ID(); + + INSERT INTO saleComponent(saleFk, componentFk, value, isGreuge) + SELECT vNewSaleFk, componentFk, value, isGreuge + FROM saleComponent + WHERE saleFk = vSaleFk; + + UPDATE itemShelvingSale + SET saleFk = vNewSaleFk + WHERE id = vItemShelvingSaleFk; + END IF; + + INSERT IGNORE INTO saleTracking(saleFk, isChecked, workerFk, stateFk) + SELECT vNewSaleFk, TRUE, vUserFk, id + FROM state + WHERE code = 'PREPARED'; + + SELECT agencyModeFk INTO vAgencyModeFk + FROM ticket + WHERE id = vNewTicketFk; + + INSERT INTO expedition( + agencyModeFk, + ticketFk, + freightItemFk, + workerFk, + packagingFk, + itemPackingTypeFk, + hostFk, + packingSiteFk, + monitorId, + started, + ended + ) + SELECT vAgencyModeFk, + vNewTicketFk, + i.id, + vUserFk, + vPackagingFk, + ps.code, + h.code, + vPackingSiteFk, + ps.monitorId, + IFNULL(vLastExpeditionTimeStamp, NOW()), + NOW() + FROM packingSite ps + JOIN host h ON h.id = ps.hostFk + JOIN item i ON i.name = 'Shipping cost' + WHERE ps.id = vPackingSiteFk + LIMIT 1; + + SET vExpeditionFk = LAST_INSERT_ID(); + + SET vLastExpeditionTimeStamp = NOW(); + + CALL dipole.expedition_Add(vExpeditionFk,vPrinterFk, TRUE); + + SELECT shelvingFk, p.code + INTO vShelving, vParkingCode + FROM itemShelving ish + JOIN shelving sh ON sh.code = ish.shelvingFk + JOIN parking p ON p.id = sh.parkingFk + WHERE ish.id = vItemShelvingFk; + + UPDATE dipole.expedition_PrintOut + SET isPrinted = FALSE, + itemFk = vItemFk, + quantity = vPacking, + longName = vConcept, + shelvingFk = vShelving, + parkingCode = vParkingCode, + phone = RIGHT(phone,vMaxPhoneLength), + street = RIGHT(street, vMAxStreetLength) + WHERE expeditionFk = vExpeditionFk; + + DELETE FROM sale + WHERE quantity = 0 + AND id = vSaleFk; + END WHILE; + +END$$ +DELIMITER ; \ No newline at end of file diff --git a/db/routines/vn/procedures/sale_getBoxPickingList.sql b/db/routines/vn/procedures/sale_getBoxPickingList.sql index ff0e85259..7466eb9be 100644 --- a/db/routines/vn/procedures/sale_getBoxPickingList.sql +++ b/db/routines/vn/procedures/sale_getBoxPickingList.sql @@ -46,6 +46,7 @@ BEGIN JOIN parking p ON p.id = sh.parkingFk JOIN tmp.productionBuffer pb ON pb.ticketFk = s.ticketFk JOIN agencyMode am ON am.id = pb.agencyModeFk + JOIN agency a ON a .id = am.agencyFk LEFT JOIN routesMonitor rm ON rm.routeFk = pb.routeFk LEFT JOIN saleGroupDetail sgd ON sgd.saleFk = s.id LEFT JOIN ticketState ts ON ts.ticketFk = s.ticketFk @@ -60,6 +61,7 @@ BEGIN AND ((rm.bufferFk AND rm.isPickingAllowed) OR am.code = 'REC_ALG') AND pb.shipped = vDated + AND a.isOwn GROUP BY s.id ORDER BY etd;