diff --git a/db/install/changes/17-zone.sql b/db/install/changes/17-zone.sql new file mode 100644 index 000000000..d1fbda571 --- /dev/null +++ b/db/install/changes/17-zone.sql @@ -0,0 +1,559 @@ + +-- ticketCalculateClon----------------------------------------------------------------------- +USE `vn`; +DROP procedure IF EXISTS `ticketCalculateClon`; + +DELIMITER $$ +USE `vn`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `ticketCalculateClon`(IN vTicketNew INT, vTicketOld INT) +BEGIN + /* + * @vTicketNew id del nuevo ticket clonado + * @vTicketOld id ticket original, a partir del qual se clonara el nuevo + * Este procedimiento "rebioniza" una linea, eliminando los componentes existentes e insertandolos de nuevo + */ + DECLARE vShipped DATE; + DECLARE vClient INT; + DECLARE vWarehouse SMALLINT; + DECLARE vAgencyMode INT; + DECLARE vAddress INT; + DECLARE vLanded DATE; + DECLARE vAgency INT; + + REPLACE INTO orderTicket(orderFk,ticketFk) + SELECT orderFk, vTicketNew + FROM orderTicket + WHERE ticketFk = vTicketOld; + + SELECT t.clientFk , t.warehouseFk, date(t.shipped), t.addressFk, t.agencyModeFk, t.landed, a.agencyFk + INTO vClient, vWarehouse, vShipped, vAddress, vAgencyMode, vLanded, vAgency + FROM vn.agencyMode a + JOIN vn.ticket t ON t.agencyModeFk = a.id + WHERE t.id = vTicketNew; + + DROP TEMPORARY TABLE IF EXISTS tmp.agencyHourGetShipped; + CREATE TEMPORARY TABLE tmp.agencyHourGetShipped ENGINE = MEMORY + SELECT vWarehouse warehouseFk, vShipped shipped, vLanded landed; + + CALL buyUltimate(vWarehouse, vShipped); -- rellena la tabla tmp.buyUltimate con la ultima compra + + DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot; + CREATE TEMPORARY TABLE tmp.ticketLot + SELECT vWarehouse warehouseFk,NULL available,s.itemFk, bu.buyFk + FROM sale s + LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk + WHERE s.ticketFk = vTicketOld GROUP BY s.itemFk; + + CALL ticketComponentCalculate(vAddress,vAgencyMode); + + -- Bionizamos lineas con Preu = 0 + DROP TEMPORARY TABLE IF EXISTS tmp.sale; + CREATE TEMPORARY TABLE tmp.sale + (PRIMARY KEY (saleFk)) ENGINE = MEMORY + SELECT s.id saleFk, vWarehouse warehouseFk + FROM sale s + JOIN ticket t on t.id = s.ticketFk WHERE s.ticketFk = vTicketNew AND s.price = 0; + + CALL ticketComponentUpdateSale(1); + + -- Bionizamos lineas con Preu > 0 + DROP TEMPORARY TABLE IF EXISTS tmp.sale; + CREATE TEMPORARY TABLE tmp.sale + (PRIMARY KEY (saleFk)) ENGINE = MEMORY + SELECT s.id saleFk, vWarehouse warehouseFk + FROM sale s + JOIN ticket t on t.id = s.ticketFk WHERE s.ticketFk = vTicketNew + AND s.price > 0; + + CALL ticketComponentUpdateSale(6); + + IF vLanded IS NULL THEN + CALL zoneGetLanded(vShipped, vAddress, vAgency,vWarehouse); + UPDATE ticket t + JOIN tmp.zoneGetLanded zgl ON t.warehouseFk = zgl.warehouseFk + SET t.landed = zgl.landed + WHERE t.id = vTicketNew; + END IF; + + -- Log + CALL `logAdd`(vTicketNew, 'update', ' ticket' , 'Bioniza Ticket'); + + -- Limpieza + DROP TEMPORARY TABLE IF EXISTS tmp.buyUltimate; + DROP TEMPORARY TABLE IF EXISTS tmp.sale; + DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot; + DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetLanded; +END$$ + +DELIMITER ; + +DROP VIEW IF EXISTS `vn`.`agencyWeekDayBonus` ; +USE `vn`; +CREATE + OR REPLACE ALGORITHM = UNDEFINED + DEFINER = `root`@`%` + SQL SECURITY DEFINER +VIEW `vn`.`agencyWeekDayBonusKk` AS + SELECT + `a`.`id` AS `id`, + `a`.`warehouse_id` AS `warehouseFk`, + `a`.`agency_id` AS `agencyFk`, + `a`.`weekDay` AS `weekDay`, + `a`.`zona` AS `zone`, + `a`.`bonus` AS `bonus` + FROM + `vn2008`.`agency_weekday_bonus` `a`; + +ALTER TABLE `vn2008`.`agency_weekday_bonus` +RENAME TO `vn2008`.`agency_weekday_bonusKk` ; + +ALTER TABLE `vn2008`.`preparation_percentage` +RENAME TO `vn2008`.`preparation_percentageKk` ; + +DROP VIEW IF EXISTS `vn`.`preparationPercentage` ; +USE `vn`; +CREATE + OR REPLACE ALGORITHM = UNDEFINED + DEFINER = `root`@`%` + SQL SECURITY DEFINER +VIEW `vn`.`preparationPercentageKk` AS + SELECT + `p`.`week_day` AS `weekDay`, + `p`.`warehouse_id` AS `warehouseFk`, + `p`.`percentage` AS `percentage` + FROM + `vn2008`.`preparation_percentage` `p`; + +-- clonWeeklyTickets----------------------------------------------------------------------- +USE `vn2008`; +DROP procedure IF EXISTS `clonWeeklyTickets`; + +DELIMITER $$ +USE `vn2008`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `clonWeeklyTickets`(IN vWeek INT) +BEGIN + DECLARE done BIT DEFAULT 0; + DECLARE vLanding DATE; + DECLARE vShipment DATE; + DECLARE vWarehouse INT; + DECLARE vTicket INT; + DECLARE vWeekDay INT; + DECLARE vClient INT; + DECLARE vEmpresa INT; + DECLARE vConsignatario INT; + DECLARE vAgencia INT; + DECLARE vNewTicket INT; + DECLARE vYear INT; + + DECLARE rsTicket CURSOR FOR + SELECT tt.Id_Ticket, weekDay, Id_Cliente, warehouse_id, empresa_id, Id_Consigna, Id_Agencia + FROM Tickets_turno tt + JOIN Tickets t ON tt.Id_Ticket = t.Id_Ticket; + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; + + SET done = 0; + SET vYear = YEAR(CURDATE()) + IF(vWeek < WEEK(CURDATE()),1, 0); + + OPEN rsTicket; + + FETCH rsTicket INTO vTicket, vWeekDay, vClient, vWarehouse, vEmpresa, vConsignatario, vAgencia; + + WHILE NOT done DO + + SELECT date INTO vShipment + FROM time + WHERE year = vYear AND week = vWeek + AND WEEKDAY(date) = vWeekDay; + + -- busca si el ticket ya ha sido clonado + IF (select count(*) FROM Tickets t JOIN ticket_observation tob ON t.Id_Ticket = tob.Id_Ticket + WHERE Id_Consigna = vConsignatario AND Fecha = vShipment AND tob.text LIKE CONCAT('%',vTicket,'%')) = 0 + THEN + + IF (SELECT COUNT(*) FROM Agencias WHERE Id_Agencia = vAgencia AND Agencia LIKE '%turno%') THEN + SET vAgencia = NULL; + END IF; + + CALL vn.ticketCreate(vClient, vShipment, vWarehouse, vEmpresa, vConsignatario, vAgencia, NULL, vLanding, vNewTicket); + + INSERT INTO Movimientos (Id_Ticket, Id_Article, Concepte, Cantidad, Preu, Descuento, CostFixat, PrecioFijado) + SELECT vNewTicket, Id_Article, Concepte, Cantidad, Preu, Descuento, CostFixat, PrecioFijado + FROM Movimientos WHERE Id_Ticket = vTicket; + + INSERT INTO Ordenes (orden,datorden,datticket,codvendedor,codcomprador,cantidad,preciomax,preu,id_article,id_cliente,comentario, + ok, total,datcompra,ko,id_movimiento) + SELECT o.orden,o.datorden,vShipment,o.codvendedor,o.codcomprador,o.cantidad,o.preciomax,o.preu,o.id_article,o.id_cliente,o.comentario, + o.ok, o.total,o.datcompra,o.ko,m2.Id_Movimiento + FROM Movimientos m JOIN Ordenes o ON o.Id_Movimiento = m.Id_Movimiento + JOIN Movimientos m2 ON m.Concepte = m2.Concepte AND m.Cantidad = m2.Cantidad AND m.Id_Article = m2.Id_Article + WHERE m.Id_Ticket = vTicket AND m2.Id_Ticket = vNewTicket; + + INSERT INTO ticket_observation(Id_Ticket,observation_type_id,text) VALUES(vNewTicket,4,CONCAT('turno desde ticket: ',vTicket)) + ON DUPLICATE KEY UPDATE text = CONCAT(ticket_observation.text,VALUES(text),' '); + + INSERT INTO ticket_observation(Id_Ticket,observation_type_id,text) VALUES(vNewTicket,1,'ATENCION: Contiene lineas de TURNO') + ON DUPLICATE KEY UPDATE text = CONCAT(ticket_observation.text,VALUES(text),' '); + + CALL vn.ticketCalculateClon(vNewTicket, vTicket); + END IF; + FETCH rsTicket INTO vTicket, vWeekDay, vClient, vWarehouse, vEmpresa, vConsignatario, vAgencia; + + END WHILE; + + CLOSE rsTicket; + +END$$ + +DELIMITER ; + + +-- ticketComponentCalculate----------------------------------------------------------------------- + +USE `vn`; +DROP procedure IF EXISTS `ticketComponentCalculate`; + +DELIMITER $$ +USE `vn`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `ticketComponentCalculate`( + vAddressFk INT, + vAgencyModeFk INT) +proc: BEGIN +/** + * Calcula los componentes de un ticket + * + * @param vAddressFk Id del consignatario + * @param vAgencyModeFk Id del modo de agencia + * @return tmp.ticketComponent, tmp.ticketComponentPrice + */ + + DECLARE vClientFk INT; + DECLARE vGeneralInflationCoefficient INT DEFAULT 1; + DECLARE vMinimumDensityWeight INT DEFAULT 167; + DECLARE vBoxFreightItem INT DEFAULT 71; + DECLARE vBoxVolume BIGINT; -- DEFAULT 138000; + DECLARE vSpecialPriceComponent INT DEFAULT 10; + DECLARE vDeliveryComponent INT DEFAULT 15; + DECLARE vRecoveryComponent INT DEFAULT 17; + DECLARE vSellByPacketComponent INT DEFAULT 22; + DECLARE vBuyValueComponent INT DEFAULT 28; + DECLARE vMarginComponent INT DEFAULT 29; + DECLARE vDiscountLastItemComponent INT DEFAULT 32; + DECLARE vExtraBaggedComponent INT DEFAULT 38; + DECLARE vManaAutoComponent INT DEFAULT 39; + + + SELECT volume INTO vBoxVolume + FROM vn.packaging + WHERE id = '94'; + + SELECT clientFk INTO vClientFK + FROM address + WHERE id = vAddressFk; + + SET @rate2 := 0; + SET @rate3 := 0; + + DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentCalculate; + CREATE TEMPORARY TABLE tmp.ticketComponentCalculate + (PRIMARY KEY (itemFk, warehouseFk)) + ENGINE = MEMORY + SELECT + tl.itemFk, tl.warehouseFk, tl.available, + IF((@rate2 := IFNULL(pf.rate2, b.price2)) < i.minPrice AND i.hasMinPrice, i.minPrice, @rate2) * 1.0 rate2, + IF((@rate3 := IFNULL(pf.rate3, b.price3)) < i.minPrice AND i.hasMinPrice, i.minPrice, @rate3) * 1.0 rate3, + IFNULL(pf.rate3, 0) AS minPrice, + IFNULL(pf.packing, b.packing) packing, + IFNULL(pf.grouping, b.grouping) grouping, + ABS(IFNULL(pf.box, b.groupingMode)) groupingMode, + tl.buyFk, i.typeFk + FROM tmp.ticketLot tl + JOIN buy b ON b.id = tl.buyFk + JOIN item i ON i.id = tl.itemFk + JOIN itemType it ON it.id = i.typeFk + LEFT JOIN itemCategory ic ON ic.id = it.categoryFk + LEFT JOIN specialPrice sp ON sp.itemFk = i.id AND sp.clientFk = vClientFk + LEFT JOIN ( + SELECT * FROM ( + SELECT pf.itemFk, pf.grouping, pf.packing, pf.box, pf.rate2, pf.rate3, aho.warehouseFk + FROM priceFixed pf + JOIN tmp.agencyHourGetShipped aho ON pf.warehouseFk = aho.warehouseFk OR pf.warehouseFk = 0 + WHERE aho.shipped BETWEEN pf.started AND pf.ended ORDER BY pf.itemFk, pf.warehouseFk DESC + ) tpf + GROUP BY tpf.itemFk, tpf.warehouseFk + ) pf ON pf.itemFk = tl.itemFk AND pf.warehouseFk = tl.warehouseFk + WHERE b.buyingValue + b.freightValue + b.packageValue + b.comissionValue > 0.01 AND ic.display <> 0; + + + DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponent; + CREATE TEMPORARY TABLE tmp.ticketComponent ( + `warehouseFk` INT UNSIGNED NOT NULL, + `itemFk` INT NOT NULL, + `componentFk` INT UNSIGNED NOT NULL, + `cost` DECIMAL(10,4) NOT NULL, + INDEX `itemWarehouse` USING BTREE (`itemFk` ASC, `warehouseFk` ASC), + UNIQUE INDEX `itemWarehouseComponent` (`itemFk` ASC, `warehouseFk` ASC, `componentFk` ASC)); + + + + INSERT INTO tmp.ticketComponent (warehouseFk, itemFk, componentFk, cost) + SELECT + tcc.warehouseFk, + tcc.itemFk, + vBuyValueComponent, + b.buyingValue + b.freightValue + b.packageValue + b.comissionValue + FROM tmp.ticketComponentCalculate tcc + JOIN buy b ON b.id = tcc.buyFk; + + INSERT INTO tmp.ticketComponent (warehouseFk, itemFk, componentFk, cost) + SELECT + tcc.warehouseFk, + tcc.itemFk, + vMarginComponent, + tcc.rate3 - b.buyingValue - b.freightValue - b.packageValue - b.comissionValue + FROM tmp.ticketComponentCalculate tcc + JOIN buy b ON b.id = tcc.buyFk; + + DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentBase; + CREATE TEMPORARY TABLE tmp.ticketComponentBase ENGINE = MEMORY + SELECT tc.itemFk, ROUND(SUM(tc.cost), 4) AS base, tc.warehouseFk + FROM tmp.ticketComponent tc + GROUP BY tc.itemFk, warehouseFk; + + INSERT INTO tmp.ticketComponent + SELECT tcb.warehouseFk, tcb.itemFk, vRecoveryComponent, ROUND(tcb.base * LEAST(cr.recobro, 0.25), 3) + FROM tmp.ticketComponentBase tcb + JOIN bi.claims_ratio cr ON cr.Id_Cliente = vClientFk + WHERE cr.recobro > 0.009; + + INSERT INTO tmp.ticketComponent + SELECT tcb.warehouseFk, tcb.itemFk, vManaAutoComponent, ROUND(base * (0.01 + prices_modifier_rate), 3) as manaAuto + FROM tmp.ticketComponentBase tcb + JOIN `client` c on c.id = vClientFk + JOIN bs.mana_spellers ms ON c.salesPersonFk = ms.Id_Trabajador + WHERE ms.prices_modifier_activated + HAVING manaAuto <> 0; + + INSERT INTO tmp.ticketComponent + SELECT + tcb.warehouseFk, + tcb.itemFk, + cr.id, + GREATEST(IFNULL(ROUND(tcb.base * cr.tax, 4), 0), tcc.minPrice - tcc.rate3) + FROM tmp.ticketComponentBase tcb + JOIN componentRate cr + JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tcb.itemFk AND tcc.warehouseFk = tcb.warehouseFk + LEFT JOIN specialPrice sp ON sp.clientFk = vClientFk AND sp.itemFk = tcc.itemFk + WHERE cr.id = vDiscountLastItemComponent AND cr.tax <> 0 AND tcc.minPrice < tcc.rate3 AND sp.value IS NULL; + + INSERT INTO tmp.ticketComponent + SELECT tcc.warehouseFk, tcc.itemFk, vSellByPacketComponent, tcc.rate2 - tcc.rate3 + FROM tmp.ticketComponentCalculate tcc + JOIN buy b ON b.id = tcc.buyFk + LEFT JOIN specialPrice sp ON sp.clientFk = vClientFk AND sp.itemFk = tcc.itemFk + WHERE sp.value IS NULL; + + INSERT INTO tmp.ticketComponent + SELECT + tcc.warehouseFK, + tcc.itemFk, + vDeliveryComponent, + vGeneralInflationCoefficient + * ROUND(( + i.compression + * r.cm3 + * IF(am.deliveryMethodFk = 1, (GREATEST(i.density, vMinimumDensityWeight) / vMinimumDensityWeight), 1) + * IFNULL(amz.price + * amz.inflation, 50)) / vBoxVolume, 4 + ) cost + FROM tmp.ticketComponentCalculate tcc + JOIN item i ON i.id = tcc.itemFk + JOIN agencyMode am ON am.id = vAgencyModeFk + JOIN `address` a ON a.id = vAddressFk + JOIN agencyProvince ap ON ap.agencyFk = am.agencyFk + AND ap.warehouseFk = tcc.warehouseFk AND ap.provinceFk = a.provinceFk + JOIN agencyModeZone amz ON amz.agencyModeFk = vAgencyModeFk + AND amz.zone = ap.zone AND amz.itemFk = 71 AND amz.warehouseFk = tcc.warehouseFk + LEFT JOIN bi.rotacion r ON r.warehouse_id = tcc.warehouseFk + AND r.Id_Article = tcc.itemFk + HAVING cost <> 0; + + IF (SELECT COUNT(*) FROM vn.addressForPackaging WHERE addressFk = vAddressFk) THEN + INSERT INTO tmp.ticketComponent + SELECT tcc.warehouseFk, b.itemFk, vExtraBaggedComponent, ap.packagingValue cost + FROM tmp.ticketComponentCalculate tcc + JOIN vn.addressForPackaging ap + WHERE ap.addressFk = vAddressFk; + END IF; + + DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentCopy; + CREATE TEMPORARY TABLE tmp.ticketComponentCopy ENGINE = MEMORY + SELECT * FROM tmp.ticketComponent; + + INSERT INTO tmp.ticketComponent + SELECT + tcc.warehouseFk, + tcc.itemFk, + vSpecialPriceComponent, + sp.value - SUM(tcc.cost) sumCost + FROM tmp.ticketComponentCopy tcc + JOIN componentRate cr ON cr.id = tcc.componentFk + JOIN specialPrice sp ON sp.clientFk = vClientFK AND sp.itemFk = tcc.itemFk + WHERE cr.classRate IS NULL + GROUP BY tcc.itemFk, tcc.warehouseFk + HAVING ABS(sumCost) > 0.001; + + DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentSum; + CREATE TEMPORARY TABLE tmp.ticketComponentSum + (INDEX (itemFk, warehouseFk)) + ENGINE = MEMORY + SELECT SUM(cost) sumCost, tc.itemFk, tc.warehouseFk, cr.classRate + FROM tmp.ticketComponent tc + JOIN componentRate cr ON cr.id = tc.componentFk + GROUP BY tc.itemFk, tc.warehouseFk, cr.classRate; + + DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentRate; + CREATE TEMPORARY TABLE tmp.ticketComponentRate ENGINE = MEMORY + SELECT + tcc.warehouseFk, + tcc.itemFk, + 1 rate, + IF(tcc.groupingMode = 1, tcc.grouping, 1) grouping, + SUM(tcs.sumCost) price + FROM tmp.ticketComponentCalculate tcc + JOIN tmp.ticketComponentSum tcs ON tcs.itemFk = tcc.itemFk + AND tcs.warehouseFk = tcc.warehouseFk + WHERE IFNULL(tcs.classRate, 1) = 1 + AND tcc.groupingMode < 2 AND (tcc.packing > tcc.grouping or tcc.groupingMode = 0) + GROUP BY tcs.warehouseFk, tcs.itemFk; + + INSERT INTO tmp.ticketComponentRate (warehouseFk, itemFk, rate, grouping, price) + SELECT + tcc.warehouseFk, + tcc.itemFk, + 2 rate, + tcc.packing grouping, + SUM(tcs.sumCost) price + FROM tmp.ticketComponentCalculate tcc + JOIN tmp.ticketComponentSum tcs ON tcs.itemFk = tcc.itemFk + AND tcs.warehouseFk = tcc.warehouseFk + WHERE tcc.available IS NULL OR (IFNULL(tcs.classRate, 2) = 2 + AND tcc.packing > 0 AND tcc.available >= tcc.packing) + GROUP BY tcs.warehouseFk, tcs.itemFk; + + INSERT INTO tmp.ticketComponentRate (warehouseFk, itemFk, rate, grouping, price) + SELECT + tcc.warehouseFk, + tcc.itemFk, + 3 rate, + tcc.available grouping, + SUM(tcs.sumCost) price + FROM tmp.ticketComponentCalculate tcc + JOIN tmp.ticketComponentSum tcs ON tcs.itemFk = tcc.itemFk + AND tcs.warehouseFk = tcc.warehouseFk + WHERE IFNULL(tcs.classRate, 3) = 3 + GROUP BY tcs.warehouseFk, tcs.itemFk; + + DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentPrice; + CREATE TEMPORARY TABLE tmp.ticketComponentPrice ENGINE = MEMORY + SELECT * FROM ( + SELECT * FROM tmp.ticketComponentRate ORDER BY price + ) t + GROUP BY itemFk, warehouseFk, grouping; + + DROP TEMPORARY TABLE + tmp.ticketComponentCalculate, + tmp.ticketComponentSum, + tmp.ticketComponentBase, + tmp.ticketComponentRate, + tmp.ticketComponentCopy; +END$$ + +DELIMITER ; + +-- bionic_calc_clon----------------------------------------------------------------------- + + +USE `vn2008`; +DROP procedure IF EXISTS `vn2008`.`bionic_calc_clon`; + +DELIMITER $$ +USE `vn2008`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `bionic_calc_clonKk`(IN v_ticket BIGINT) +BEGIN + +/* +* DEPRECATED vn.ticketCalculateClon +* +Este procedimiento "rebioniza" una linea, eliminando los componentes existentes e insertandolos de nuevo +*/ + DECLARE v_shipment DATE; + DECLARE v_customer INT; + DECLARE v_wh SMALLINT; + DECLARE v_agencia INT; + DECLARE v_consigna INT; + DECLARE v_landing DATE; + DECLARE v_agency INT; + + REPLACE order_Tickets(order_id,Id_Ticket) VALUES(48, v_ticket); + + SELECT t.Id_Cliente , t.warehouse_id, date(t.Fecha), t.Id_Consigna, t.Id_Agencia, t.landing, a.agency_id + INTO v_customer, v_wh, v_shipment, v_consigna, v_agencia, v_landing, v_agency + FROM vn2008.Agencias a + JOIN vn2008.Tickets t ON t.Id_Agencia = a.Id_Agencia + WHERE t.Id_Ticket = v_ticket; + + DROP TEMPORARY TABLE IF EXISTS tmp.agencyHourGetShipped; + CREATE TEMPORARY TABLE tmp.agencyHourGetShipped ENGINE = MEMORY + SELECT v_wh warehouseFk, v_shipment shipped, v_landing landed; + + CALL item_last_buy_ (v_wh, v_shipment); -- rellena la tabla t_item_last_buy con la ultima compra + + DROP TEMPORARY TABLE IF EXISTS tmp.bionic_lot; + CREATE TEMPORARY TABLE tmp.bionic_lot + SELECT v_wh warehouse_id,NULL available, + m.Id_Article item_id,ilb.buy_id + FROM Movimientos m + LEFT JOIN t_item_last_buy ilb ON ilb.item_id = m.Id_Article + WHERE m.Id_Ticket = v_ticket GROUP BY m.Id_Article; + + CALL bionic_calc_component(v_consigna,v_agencia); + + -- Bionizamos lineas con Preu = 0 + DROP TEMPORARY TABLE IF EXISTS tmp.movement; + CREATE TEMPORARY TABLE tmp.movement + (PRIMARY KEY (Id_Movimiento)) ENGINE = MEMORY + SELECT Id_Movimiento, v_wh warehouse_id FROM Movimientos m + JOIN Tickets t on t.Id_Ticket = m.Id_Ticket WHERE m.Id_Ticket = v_ticket AND Preu = 0; + + CALL bionic_movement_update(1); + + -- Bionizamos lineas con Preu > 0 + DROP TEMPORARY TABLE IF EXISTS tmp.movement; + CREATE TEMPORARY TABLE tmp.movement + (PRIMARY KEY (Id_Movimiento)) ENGINE = MEMORY + SELECT Id_Movimiento, v_wh warehouse_id FROM Movimientos m + JOIN Tickets t on t.Id_Ticket = m.Id_Ticket WHERE m.Id_Ticket = v_ticket AND Preu > 0; + CALL bionic_movement_update(6); + + IF v_landing IS NULL THEN + CALL travel_tree_shipment(v_shipment, v_consigna, v_agency,v_wh); + UPDATE Tickets t + JOIN travel_tree_shipment tts ON t.warehouse_id = tts.warehouse_id + SET t.landing = tts.landing + WHERE Id_Ticket = v_ticket; + END IF; + + -- Log + call Ditacio(v_ticket + ,'Bioniza Ticket' + ,'T' + , 20 + , 'proc bionic_calc_clon' + , NULL); + + -- Limpieza + DROP TEMPORARY TABLE t_item_last_buy; +END$$ + +DELIMITER ; diff --git a/db/install/changes/18-zoneDump.sql b/db/install/changes/18-zoneDump.sql new file mode 100644 index 000000000..d6b7e6e25 --- /dev/null +++ b/db/install/changes/18-zoneDump.sql @@ -0,0 +1,230 @@ +-- zoneGetAgency----------------------------------------------------------------------- + +USE `vn`; +DROP procedure IF EXISTS `zoneGetAgency`; + +DELIMITER $$ +USE `vn`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetAgency`(vAddress INT, vLanded DATE) +BEGIN +/** + * Devuelve el listado de agencias disponibles para la fecha + * y dirección pasadas. + * + * @param vAddress Id de dirección de envío, %NULL si es recogida + * @param vDate Fecha de recogida + * @select Listado de agencias disponibles + */ + + DECLARE vPostalCode varchar(10); + + SELECT postalCode INTO vPostalCode + FROM address WHERE id = vAddress; + + SELECT * FROM ( + SELECT am.id agencyModeFk, + am.name agencyMode, + am.description, + am.deliveryMethodFk, + TIMESTAMPADD(DAY,-z.travelingDays, vLanded) shipped, + zi.isIncluded + FROM zoneGeo zgSon + JOIN zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt + JOIN zoneIncluded zi ON zi.geoFk = zgFather.id + JOIN zone z ON z.id = zi.zoneFk + JOIN zoneCalendar zc ON zc.zoneFk = z.id + JOIN agencyMode am ON am.id = z.agencyModeFk + WHERE zgSon.`name` LIKE vPostalCode + AND zc.delivered = vLanded + AND IF(TIMESTAMPADD(DAY,-z.travelingDays, vLanded) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE) + ORDER BY zgFather.depth DESC) t + GROUP BY agencyModeFk + HAVING isIncluded > 0; + +END$$ + +DELIMITER ; +-- zoneGetFirstShipped----------------------------------------------------------------------- + + +USE `vn`; +DROP procedure IF EXISTS `zoneGetFirstShipped`; + +DELIMITER $$ +USE `vn`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetFirstShipped`(vAgencyModeFk INT, vAddress INT, vWarehouseFk INT) +BEGIN +/** +* Devuelve la primera fecha de envio disponible para una agencia en una direccion y un warehouse +* +* @param vAgencyMode id de la agencia en vn.agencyMode +* @param vAddress id de la direccion +* @param vWarehouse id del warehouse +* @return vShipped la primera fecha disponible y vLanded la fecha de llegada/recojida +*/ + DECLARE vPostalCode varchar(10); + + SELECT postalCode INTO vPostalCode + FROM address WHERE id = vAddress; + + SELECT * FROM ( + SELECT TIMESTAMPADD(DAY,-z.travelingDays, zc.delivered) shipped, + zc.delivered landed + FROM zoneGeo zgSon + JOIN zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt + JOIN zoneIncluded zi ON zi.geoFk = zgFather.id + JOIN zone z ON z.id = zi.zoneFk + JOIN zoneCalendar zc ON zc.zoneFk = z.id + WHERE zgSon.`name` LIKE vPostalCode + AND z.agencyModeFk = vAgencyModeFk + AND z.warehouseFk = vWarehouseFk + AND IF(TIMESTAMPADD(DAY,-z.travelingDays, zc.delivered) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE) + ORDER BY landed ASC, zgFather.depth DESC) t + HAVING isIncluded > 0 LIMIT 1; +END$$ + +DELIMITER ; +-- zoneGetLanded----------------------------------------------------------------------- + + +USE `vn`; +DROP procedure IF EXISTS `zoneGetLanded`; + +DELIMITER $$ +USE `vn`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetLanded`(vShipped DATE, vAddress INT, vAgencyMode INT, vWarehouse INT) +BEGIN +/** +* Devuelve una tabla temporal con el dia de recepcion para vShipped. +* +* @param vShipped Fecha de preparacion de mercancia +* @param vAddress Id de consignatario, %NULL para recogida +* @param vAgencyMode Id agencia +* @table tmp.zoneGetLanded Datos de recepción +*/ + + DECLARE vPostalCode varchar(10); + + SELECT postalCode INTO vPostalCode + FROM address WHERE id = vAddress; + + DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetLanded; + CREATE TEMPORARY TABLE tmp.zoneGetLanded + ENGINE = MEMORY + SELECT vWarehouse warehouseFk,delivered landed, isIncluded FROM ( + SELECT zi.*, zc.delivered + FROM vn.zoneGeo zgSon + JOIN vn.zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt + JOIN zoneIncluded zi ON zi.geoFk = zgFather.id + JOIN zone z ON z.id = zi.zoneFk + JOIN zoneCalendar zc ON zc.zoneFk = z.id + WHERE zgSon.`name` LIKE vPostalCode + AND zc.delivered = TIMESTAMPADD(DAY,z.travelingDays, vShipped) + AND IF(vShipped = CURDATE(), hour(now()) < hour(z.`hour`),TRUE) + AND z.agencyModeFk = vAgencyMode + ORDER BY zgFather.depth DESC) t + GROUP BY zoneFk + HAVING isIncluded > 0 + LIMIT 1; +END$$ + +DELIMITER ; +-- zoneGetShipped----------------------------------------------------------------------- + + +USE `vn`; +DROP procedure IF EXISTS `zoneGetShipped`; + +DELIMITER $$ +USE `vn`$$ +DROP procedure IF EXISTS `zoneGetShipped`; + +CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetShipped`(vLanded DATE, vAddressFk INT, vAgencyModeFk INT, vWarehouseFk INT) +BEGIN +/** + * Devuelve la mínima fecha de envía para cada warehouse + * + * @param vLanded La fecha de recepcion + * @param vAddressFk Id del consignatario + * @param vAgencyModeFk Id de la agencia + * @return tmp.zoneGetShipped + */ + + DECLARE vPostalCode varchar(10); + + SELECT postalCode INTO vPostalCode + FROM address WHERE id = vAddressFk; + + SELECT * FROM ( + SELECT z.id, + TIMESTAMPADD(DAY,-z.travelingDays, vLanded) shipped, + vLanded landed, + zi.isIncluded + FROM zoneGeo zgSon + JOIN zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt + JOIN zoneIncluded zi ON zi.geoFk = zgFather.id + JOIN zone z ON z.id = zi.zoneFk + JOIN zoneCalendar zc ON zc.zoneFk = z.id + WHERE zgSon.`name` LIKE vPostalCode + AND zc.delivered = vLanded + AND z.agencyModeFk = vAgencyModeFk + AND z.warehouseFk = vWarehouseFk + AND IF(TIMESTAMPADD(DAY,-z.travelingDays, vLanded) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE) + ORDER BY z.id, landed ASC, zgFather.depth DESC) t + GROUP BY id + HAVING isIncluded > 0; +END$$ + +DELIMITER ; + +-- zoneGetWarehouse----------------------------------------------------------------------- + +USE `vn`; +DROP procedure IF EXISTS `zoneGetWarehouse`; + +DELIMITER $$ +USE `vn`$$ +CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetWarehouse`(vAddress INT, vLanded DATE, vWarehouse INT) +BEGIN +/** +* Devuelve el listado de agencias disponibles para la fecha, + * dirección y warehouse pasadas + * + * @param vAddress + * @param vWarehouse warehouse + * @param vLanded Fecha de recogida + * @select Listado de agencias disponibles + */ + DECLARE vPostalCode varchar(10); + + SELECT postalCode INTO vPostalCode + FROM address WHERE id = vAddress; + + SELECT * FROM ( + SELECT am.id, + am.name agencyMode, + am.description, + am.deliveryMethodFk, + TIMESTAMPADD(DAY,-z.travelingDays, vLanded) shipped, + z.warehouseFk, + zi.isIncluded + FROM zoneGeo zgSon + JOIN zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt + JOIN zoneIncluded zi ON zi.geoFk = zgFather.id + JOIN zone z ON z.id = zi.zoneFk + JOIN zoneCalendar zc ON zc.zoneFk = z.id + JOIN agencyMode am ON am.id = z.agencyModeFk + WHERE zgSon.`name` LIKE vPostalCode + AND delivered = vLanded + AND z.warehouseFk = vWarehouse + AND IF(TIMESTAMPADD(DAY,-z.travelingDays, vLanded) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE) + ORDER BY zgFather.depth DESC) t + GROUP BY id + HAVING isIncluded > 0; + +END$$ +DELIMITER ; + +-- VIEW `vn`.`item`----------------------------------------------------------------------- + +CREATE OR REPLACE ALGORITHM=UNDEFINED DEFINER=`root`@`%` SQL SECURITY DEFINER VIEW `vn`.`item` AS select `t`.`Id_Article` AS `id`,`t`.`Article` AS `name`,`t`.`tipo_id` AS `typeFk`,`t`.`Medida` AS `size`,`t`.`Color` AS `inkFk`,`t`.`Categoria` AS `category`,`t`.`Tallos` AS `stems`,`t`.`id_origen` AS `originFk`,`t`.`description` AS `description`,`t`.`producer_id` AS `producerFk`,`t`.`Codintrastat` AS `intrastatFk`,`t`.`offer` AS `isOnOffer`,`t`.`caja` AS `box`,`t`.`expenceFk` AS `expenceFk`,`t`.`bargain` AS `isBargain`,`t`.`comments` AS `comment`,`t`.`relevancy` AS `relevancy`,`t`.`Foto` AS `image`,`t`.`generic` AS `generic`,`t`.`density` AS `density`,`t`.`iva_group_id` AS `taxClassFk`,`t`.`PVP` AS `minPrice`,`t`.`Min` AS `hasMinPrice`,`t`.`isActive` AS `isActive`,`t`.`longName` AS `longName`,`t`.`subName` AS `subName`,`t`.`tag5` AS `tag5`,`t`.`value5` AS `value5`,`t`.`tag6` AS `tag6`,`t`.`value6` AS `value6`,`t`.`tag7` AS `tag7`,`t`.`value7` AS `value7`,`t`.`tag8` AS `tag8`,`t`.`value8` AS `value8`,`t`.`tag9` AS `tag9`,`t`.`value9` AS `value9`,`t`.`tag10` AS `tag10`,`t`.`value10` AS `value10`,`t`.`minimum` AS `minimum`,`t`.`upToDown` AS `upToDown`,`t`.`compression` AS `compression` from `vn2008`.`Articles` `t`; diff --git a/modules/ticket/back/methods/ticket/getShipped.js b/modules/ticket/back/methods/ticket/getShipped.js index e60fbef57..6db1827ad 100644 --- a/modules/ticket/back/methods/ticket/getShipped.js +++ b/modules/ticket/back/methods/ticket/getShipped.js @@ -21,13 +21,13 @@ module.exports = Self => { Self.getShipped = async data => { let query = `CALL vn.zoneGetShipped(?, ?, ?, ?)`; - let [shipped] = await Self.rawSql(query, [ + let [response] = await Self.rawSql(query, [ data.landed, data.addressFk, data.agencyModeFk, data.warehouseFk ]); - return shipped[0].shipped || null; + return (response[0] && response[0].shipped) || null; }; }; diff --git a/modules/ticket/front/basic-data/step-one/index.js b/modules/ticket/front/basic-data/step-one/index.js index 515f0ddcb..6462a5e5a 100644 --- a/modules/ticket/front/basic-data/step-one/index.js +++ b/modules/ticket/front/basic-data/step-one/index.js @@ -75,6 +75,11 @@ class Controller { this.$http.post(query, data).then(res => { if (res.data && res.data.landed) this.ticket.landed = res.data.landed; + else { + return this.vnApp.showError( + this.$translate.instant(`There's no available agency for this shipping date`) + ); + } }); } @@ -90,6 +95,11 @@ class Controller { this.$http.post(query, data).then(res => { if (res.data && res.data.shipped) this.ticket.shipped = res.data.shipped; + else { + return this.vnApp.showError( + this.$translate.instant(`There's no available agency for this landing date`) + ); + } }); } diff --git a/modules/ticket/front/basic-data/step-one/locale/es.yml b/modules/ticket/front/basic-data/step-one/locale/es.yml index a8d7d93ce..bc86a397b 100644 --- a/modules/ticket/front/basic-data/step-one/locale/es.yml +++ b/modules/ticket/front/basic-data/step-one/locale/es.yml @@ -1,2 +1,3 @@ There's no available agency for this landing date: No hay ninguna agencia disponible para la fecha de envío seleccionada -Deleted: Eliminado \ No newline at end of file +Deleted: Eliminado +There's no available agency for this shipping date: No hay ninguna agencia disponible para la fecha de preparación seleccionada