salix/db/changes/10031-zone/00-zone.sql

2533 lines
84 KiB
SQL
Raw Blame History

This file contains invisible Unicode characters

This file contains invisible Unicode characters that are indistinguishable to humans but may be processed differently by a computer. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- Kkear agencyHourGetShipped ---------------------------------------------------------------
USE `vn`;
DROP procedure IF EXISTS `vn`.`agencyHourGetShipped`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `agencyHourGetShippedKk`(vLanded DATE, vAddressFk INT, vAgencyFk INT)
BEGIN
/**
* DEPRECATED usar zoneGetShipped
* Devuelve las posibles fechas de envío de un ticket
*
* @param vLanded La fecha de recepcion
* @param vAddressFk Id del consignatario
* @param vAgencyFk Id de la agencia
* @return tmp.agencyHourGetShipped
*/
DECLARE vDone BOOL;
DECLARE vWarehouseFk SMALLINT;
DECLARE vCur CURSOR FOR
SELECT w.id warehouseFk
FROM vn.warehouse w
WHERE w.hasAvailable;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
DROP TEMPORARY TABLE IF EXISTS tmp.agencyHourGetShipped;
CREATE TEMPORARY TABLE tmp.agencyHourGetShipped
(
warehouseFk TINYINT NOT NULL PRIMARY KEY,
shipped DATE NOT NULL,
landed DATE NOT NULL
)
ENGINE = MEMORY;
OPEN vCur;
l: LOOP
SET vDone = FALSE;
FETCH vCur INTO vWarehouseFk;
IF vDone THEN
LEAVE l;
END IF;
INSERT INTO tmp.agencyHourGetShipped (warehouseFk, shipped, landed)
SELECT vWarehouseFk, shipping, vLanded FROM (
SELECT TIMESTAMPADD(DAY, -ah.substractDay, vLanded) shipping, ah.maxHour
FROM agencyHour ah
LEFT JOIN address a ON a.id = vAddressFk
WHERE ah.warehouseFk = vWarehouseFk
AND (weekDay = WEEKDAY(vLanded)
OR weekDay IS NULL)
AND (ah.agencyFk = vAgencyFk
OR ah.agencyFk IS NULL)
AND (ah.provinceFk = a.provinceFk
OR ah.provinceFk IS NULL
OR vAddressFk IS NULL)
ORDER BY (
(ah.weekDay IS NOT NULL) +
(ah.agencyFk IS NOT NULL) +
((ah.provinceFk IS NOT NULL) * 3)
) DESC
LIMIT 1
) t
WHERE t.shipping >= CURDATE()
AND IF(t.shipping = CURDATE(), t.maxHour > HOUR(NOW()), TRUE);
END LOOP;
CLOSE vCur;
END$$
DELIMITER ;
;
-- 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.zoneGetShipped;
CALL zoneGetShippedWarehouse(vLanded, vAddress, vAgencyMode);
DELETE FROM tmp.zoneGetShipped WHERE warehouseFk <> vWarehouse;
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` ;
DROP VIEW IF EXISTS `vn`.`agencyHour` ;
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` ;
ALTER TABLE `vn2008`.`agency_hour`
RENAME TO `vn2008`.`agency_hourKk` ;
-- 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(itemFk, warehouseFk, available, rate2, rate3, minPrice,
* packing, grouping, groupingMode, buyFk, typeFk)
* @return tmp.ticketComponentPrice (warehouseFk, itemFk, rate, grouping, price)
*/
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.zoneGetShipped 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((z.price - z.bonus)
* 1/*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 tmp.zoneGetShipped zgs ON zgs.warehouseFk = tcc.warehouseFk
JOIN zone z ON z.id = zgs.id
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,
CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) 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 ;
-- bionic_calc_component-----------------------------------------------------------------------
USE `vn2008`;
DROP procedure IF EXISTS `vn2008`.`bionic_calc_component`;
DELIMITER $$
USE `vn2008`$$
CREATE DEFINER=`root`@`%` PROCEDURE `bionic_calc_component`(IN `v_consigna` INT, IN `v_agencia` INT)
proc: BEGIN
DECLARE v_customer INT;
DECLARE COEFICIENTE_DE_INFLACION_GENERAL INT DEFAULT 1.0;
DECLARE DENSIDAD_MINIMA_PESO_VOLUMETRICO INT DEFAULT 167;
DECLARE VOLUMEN_CAJA_VERDNATURA BIGINT; -- DEFAULT 138000;
-- DECLARE vValorEmbolsado DOUBLE DEFAULT 0.04;
SELECT Volumen INTO VOLUMEN_CAJA_VERDNATURA
FROM Cubos
WHERE Id_Cubo = '94';
SELECT Id_Cliente INTO v_customer FROM Consignatarios WHERE Id_Consigna = v_consigna;
SET @rate2 := 0;
SET @rate3 := 0;
DROP TEMPORARY TABLE IF EXISTS t_bionic_temp;
CREATE TEMPORARY TABLE t_bionic_temp
(PRIMARY KEY (item_id,warehouse_id))
ENGINE = MEMORY
SELECT
b.item_id, b.warehouse_id,available,
IF((@rate2 := IFNULL(pf.rate_2,c.Tarifa2)) < a.PVP AND a.`Min`, a.PVP, @rate2) * 1.0 rate_2,
IF((@rate3 := IFNULL(pf.rate_3,c.Tarifa3)) < a.PVP AND a.`Min`, a.PVP, @rate3) * 1.0 rate_3,
ifnull(pf.rate_3,0) AS min_price,
IFNULL(pf.Packing,c.Packing) packing,
IFNULL(pf.`grouping`,c.`grouping`) `grouping`,
ABS(IFNULL(pf.caja,c.caja)) box,
b.buy_id, a.tipo_id
FROM tmp.bionic_lot b
JOIN vn2008.Compres c ON b.buy_id = c.Id_Compra
JOIN vn2008.Articles a ON b.item_id = a.Id_Article
JOIN vn2008.Tipos t ON t.tipo_id = a.tipo_id
LEFT JOIN vn2008.reinos r ON r.id = t.reino_id
LEFT JOIN vn2008.PreciosEspeciales p ON a.Id_Article = p.Id_Article AND p.Id_Cliente = v_customer
LEFT JOIN (
SELECT * FROM (
SELECT p.item_id, p.`grouping`, p.Packing, p.caja, p.rate_2, p.rate_3, zgs.warehouseFk AS warehouse_id
FROM vn2008.price_fixed p
JOIN tmp.zoneGetShipped zgs ON zgs.warehouseFk = p.warehouse_id OR p.warehouse_id = 0
WHERE zgs.shipped BETWEEN p.date_start AND p.date_end ORDER BY p.item_id, p.warehouse_id DESC
) t
GROUP BY item_id, warehouse_id
) pf ON pf.item_id = b.item_id AND pf.warehouse_id = b.warehouse_id
-- descartamos articulos con coste menor de 0.01
WHERE Costefijo + Portefijo + Embalajefijo + Comisionfija > 0.01 AND r.display <> 0;
-- Creamos la tabla tmp.bionic_component
DROP TEMPORARY TABLE IF EXISTS tmp.bionic_component;
CREATE TEMPORARY TABLE tmp.bionic_component LIKE
template_bionic_component;
-- Componentes del precio, valores absolutos
INSERT INTO tmp.bionic_component ( warehouse_id, item_id, component_id, cost)
SELECT b.warehouse_id, b.item_id, 29, rate_3 - Costefijo - Portefijo - Embalajefijo - Comisionfija
FROM t_bionic_temp b
JOIN vn2008.Compres c ON b.buy_id = c.Id_Compra;
INSERT INTO tmp.bionic_component ( warehouse_id, item_id, component_id, cost)
SELECT b.warehouse_id, b.item_id, 28, Costefijo + Portefijo + Embalajefijo + Comisionfija
FROM t_bionic_temp b
JOIN vn2008.Compres c ON b.buy_id = c.Id_Compra;
-- Ahora los valores en funcion de la base
DROP TEMPORARY TABLE IF EXISTS t_components_base;
CREATE TEMPORARY TABLE t_components_base
SELECT bc.item_id, ROUND(SUM(cost), 4) AS base, bc.warehouse_id
FROM tmp.bionic_component bc
GROUP BY bc.item_id,warehouse_id;
-- La ratio se calcula teniendo en cuenta el valor de las reclamaciones y el saldo de greuge
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, item_id, 17, ROUND(base * LEAST(recobro,0.25), 3)
FROM t_components_base cb
JOIN bi.claims_ratio ON Id_Cliente = v_customer
WHERE recobro > 0.009;
-- PAK 2016-08-31 Componente de maná automático, en función del maná acumulado por el comercial.
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, item_id, 39, ROUND(base * (0.01 + prices_modifier_rate), 3) as manaAuto
FROM t_components_base cb
JOIN Clientes c on c.Id_Cliente = v_customer
JOIN bs.mana_spellers ms ON c.Id_Trabajador = ms.Id_Trabajador
WHERE ms.prices_modifier_activated
AND c.Id_Trabajador != 196 -- Ruben Espinosa
HAVING manaAuto <> 0 ;
/*
-- Vendedor variable
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, item_id, Id_Componente, IFNULL(ROUND(base * tax,4), 0)
FROM t_components_base cb
JOIN bi.tarifa_componentes
WHERE tarifa_componentes_series_id = 2 and IFNULL(tax, 0) > 0;
*/
-- ******* Inicio Bloque para componentes con tarifa_class diferente de NULL
-- Descuento por ultimas unidades
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, b.item_id, Id_Componente, GREATEST(IFNULL(ROUND(base * tax,4), 0), b.min_price - b.rate_3)
FROM t_components_base cb
JOIN bi.tarifa_componentes
JOIN t_bionic_temp b ON b.item_id = cb.item_id AND b.warehouse_id = cb.warehouse_id
LEFT JOIN PreciosEspeciales pe ON pe.Id_Cliente = v_customer AND pe.Id_Article = b.item_id
WHERE Id_Componente = 32 AND tax <> 0 AND b.min_price < b.rate_3 AND PrecioEspecial IS NULL;
-- Incremento por paquete suelto
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id, b.item_id, 22, rate_2 - rate_3
FROM t_bionic_temp b
JOIN vn2008.Compres c ON b.buy_id = c.Id_Compra
LEFT JOIN PreciosEspeciales pe ON pe.Id_Cliente = v_customer AND pe.Id_Article = b.item_id
WHERE PrecioEspecial IS NULL;
-- ******* Fin Bloque para componentes con tarifa_class diferente de NULL
-- Reparto
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id
, b.item_id
, 15
, COEFICIENTE_DE_INFLACION_GENERAL
* ROUND(
r.cm3
* art.compression
* IF(a.Vista = 1, (GREATEST(art.density,DENSIDAD_MINIMA_PESO_VOLUMETRICO) / DENSIDAD_MINIMA_PESO_VOLUMETRICO ) , 1)
* IFNULL(az.price
* az.inflacion ,50)
/ VOLUMEN_CAJA_VERDNATURA, 4
) cost
FROM t_bionic_temp b
JOIN vn2008.Articles art ON art.Id_Article = b.item_id
JOIN vn2008.Agencias a ON a.Id_Agencia = v_agencia
JOIN vn2008.Consignatarios c ON c.Id_Consigna = v_consigna
JOIN vn2008.Agencias_province ap ON ap.agency_id = a.agency_id AND ap.warehouse_id = b.warehouse_id AND ap.province_id = c.province_id
JOIN vn2008.Agencias_zonas az ON az.Id_Agencia = v_agencia AND az.zona = ap.zona AND az.Id_Article = 71 AND az.warehouse_id = b.warehouse_id
LEFT JOIN bi.rotacion r ON r.warehouse_id = b.warehouse_id AND r.Id_Article = b.item_id
HAVING cost <> 0;
-- Reparto bonificado
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id
, b.item_id
, 41
, COEFICIENTE_DE_INFLACION_GENERAL
* ROUND(
r.cm3
* art.compression
* IF(a.Vista = 1, (GREATEST(art.density,DENSIDAD_MINIMA_PESO_VOLUMETRICO) / DENSIDAD_MINIMA_PESO_VOLUMETRICO ) , 1)
* awb.bonus
* az.inflacion
/ VOLUMEN_CAJA_VERDNATURA, 4
) cost
FROM t_bionic_temp b
JOIN vn2008.Articles art ON art.Id_Article = b.item_id
JOIN vn2008.Agencias a ON a.Id_Agencia = v_agencia
JOIN vn2008.Consignatarios c ON c.Id_Consigna = v_consigna
JOIN vn2008.Agencias_province ap ON ap.agency_id = a.agency_id AND ap.warehouse_id = b.warehouse_id AND ap.province_id = c.province_id
JOIN vn2008.Agencias_zonas az ON az.Id_Agencia = v_agencia AND az.zona = ap.zona AND az.Id_Article = 71 AND az.warehouse_id = b.warehouse_id
JOIN vn2008.agency_weekday_bonus awb ON awb.warehouse_id = az.warehouse_id AND awb.zona = az.zona AND a.agency_id = awb.agency_id
LEFT JOIN bi.rotacion r ON r.warehouse_id = b.warehouse_id AND r.Id_Article = b.item_id
JOIN tmp.agencyHourGetShipped ah ON ah.warehouseFk = awb.warehouse_id AND weekday(ah.landed) = awb.weekDay
HAVING cost <> 0
LIMIT 1;
-- PAK 12-05-2015
-- EMBOLSADO
IF (SELECT COUNT(*) FROM vn.addressForPackaging WHERE addressFk = v_consigna) THEN
-- IF v_consigna IN (13690, 3402, 5661, 4233) THEN
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id, b.item_id, 38, ap.packagingValue cost
FROM t_bionic_temp b
JOIN vn.addressForPackaging ap
WHERE ap.addressFk = v_consigna;
END IF;
-- JGF 14-08-2015
-- Modificacion de precio por dia de preparacion del pedido
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, cb.item_id, 14, cb.base * (IFNULL(pe.percentage,pp.percentage)/100)
FROM t_components_base cb
JOIN tmp.agencyHourGetShipped ah ON ah.warehouseFk = cb.warehouse_id
LEFT JOIN vn2008.preparation_percentage pp ON pp.week_day = weekday(ah.shipped) AND cb.warehouse_id = IFNULL(pp.warehouse_id,cb.warehouse_id)
LEFT JOIN vn2008.preparation_exception pe ON pe.exception_day = ah.shipped AND cb.warehouse_id = IFNULL(pe.warehouse_id,cb.warehouse_id)
WHERE IFNULL(pe.percentage,pp.percentage);
-- Creamos la tabla tmp.bionic_component_copy por que mysql no puede reabrir una tabla temporal
DROP TEMPORARY TABLE IF EXISTS tmp.bionic_component_copy;
CREATE TEMPORARY TABLE tmp.bionic_component_copy
SELECT * FROM tmp.bionic_component;
-- JGF 19-01-2016
-- Precios especiales
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id, b.item_id, 10, pe.PrecioEspecial - SUM(cost) sum_cost
FROM tmp.bionic_component_copy b
JOIN bi.tarifa_componentes t ON b.component_id = t.Id_Componente
JOIN PreciosEspeciales pe ON pe.Id_Cliente = v_customer AND pe.Id_Article = b.item_id
WHERE t.tarifa_class IS NULL
GROUP BY b.item_id, b.warehouse_id
HAVING ABS(sum_cost) > 0.001;
-- Lotes
DROP TEMPORARY TABLE IF EXISTS t_component_sum;
CREATE TEMPORARY TABLE t_component_sum
(INDEX (item_id, warehouse_id))
ENGINE = MEMORY
SELECT SUM(cost) sum_cost, b.item_id, b.warehouse_id, t.tarifa_class
FROM tmp.bionic_component b
JOIN bi.tarifa_componentes t ON b.component_id = t.Id_Componente
GROUP BY b.item_id, b.warehouse_id, t.tarifa_class;
-- ***** Inicia Modifica t_bionic_rate las diferentes tarifas
-- Tarifa por unidad minima
DROP TEMPORARY TABLE IF EXISTS t_bionic_rate;
CREATE TEMPORARY TABLE t_bionic_rate
ENGINE = MEMORY
SELECT b.warehouse_id, item_id, 1 rate,
IF(box = 1, `grouping`, 1) `grouping`, SUM(sum_cost) price
FROM t_bionic_temp b
JOIN t_component_sum cs USING(item_id, warehouse_id)
WHERE IFNULL(cs.tarifa_class,1) = 1 AND box < 2 AND (packing > `grouping` or box = 0)
GROUP BY warehouse_id, item_id;
-- Tarifa por caja
INSERT INTO t_bionic_rate (warehouse_id, item_id, rate, `grouping`, price)
SELECT b.warehouse_id, item_id, 2 rate, packing `grouping`,
SUM(sum_cost) price
FROM t_bionic_temp b
JOIN t_component_sum cs USING(item_id, warehouse_id)
WHERE available IS NULL OR (IFNULL(cs.tarifa_class,2) = 2 AND packing > 0 AND available >= packing)
GROUP BY warehouse_id, item_id;
-- Tarifa para toda la cantidad disponible
INSERT INTO t_bionic_rate (warehouse_id, item_id, rate, `grouping`, price)
SELECT b.warehouse_id, item_id, 3 rate, available `grouping`,
SUM(sum_cost) price
FROM t_bionic_temp b
JOIN t_component_sum cs USING(item_id, warehouse_id)
WHERE IFNULL(cs.tarifa_class,3) = 3
GROUP BY warehouse_id, item_id;
-- ***** Fin Modifica t_bionic_rate las diferentes tarifas
DROP TEMPORARY TABLE IF EXISTS tmp.bionic_price;
CREATE TEMPORARY TABLE tmp.bionic_price
LIKE template_bionic_price;
INSERT INTO tmp.bionic_price (warehouse_id, item_id, rate, `grouping`, price)
SELECT * FROM (
SELECT * FROM t_bionic_rate ORDER BY price
) t
GROUP BY item_id, warehouse_id, `grouping`;
DROP TEMPORARY TABLE IF EXISTS tmp.travel_tree;
CREATE TEMPORARY TABLE tmp.travel_tree
ENGINE = MEMORY
SELECT * FROM tmp.agencyHourGetShipped;
-- Limpieza
DROP TEMPORARY TABLE tmp.agencyHourGetShipped;
DROP TEMPORARY TABLE t_bionic_temp;
DROP TEMPORARY TABLE t_component_sum;
DROP TEMPORARY TABLE t_components_base;
DROP TEMPORARY TABLE t_bionic_rate;
DROP TEMPORARY TABLE tmp.bionic_component_copy;
END$$
DELIMITER ;
-- ALTER TABLE `vn2008`.`Tickets`-----------------------------------------------------------------------
/*
ALTER TABLE `vn2008`.`Tickets`
ADD COLUMN `zoneFk` INT(11) NULL DEFAULT NULL AFTER `isDeleted`,
ADD INDEX `Tickets_zoneFk_fk_idx` (`zoneFk` ASC);
;
ALTER TABLE `vn2008`.`Tickets`
ADD CONSTRAINT `Tickets_zoneFk_fk`
FOREIGN KEY (`zoneFk`)
REFERENCES `vn`.`zone` (`id`)
ON DELETE RESTRICT
ON UPDATE CASCADE;
*/
-- ticketCreateWithUser -----------------------------------------------------------------------
USE `vn`;
DROP procedure IF EXISTS `ticketCreateWithUser`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketCreateWithUser`(
vClientId INT
,vShipped DATE
,vWarehouseFk INT
,vCompanyFk INT
,vAddressFk INT
,vAgencyModeFk INT
,vRouteFk INT
,vlanded DATE
,vUserId INT
,OUT vNewTicket INT)
BEGIN
DECLARE vCount INT;
IF vClientId IS NULL THEN
CALL util.throw ('CLIENT_NOT_ESPECIFIED');
END IF;
IF NOT vAddressFk OR vAddressFk IS NULL THEN
SELECT id INTO vAddressFk
FROM address
WHERE clientFk = vClientId AND isDefaultAddress;
END IF;
IF NOT vAgencyModeFk OR vAgencyModeFk IS NULL THEN
SELECT agencyModeFk INTO vAgencyModeFk
FROM address
WHERE clientFk = vClientId AND isDefaultAddress;
END IF;
CALL vn.zoneGetLanded(vShipped, vAddressFk, vAgencyModeFk, vWarehouseFk);
SELECT COUNT(*) INTO vCount FROM tmp.zoneGetLanded
WHERE landed = vlanded;
IF vCount IS NULL OR vCount = 0 THEN
CALL util.throw ('NOT_ZONE_WITH_THIS_PARAMETERS');
END IF;
INSERT INTO vn2008.Tickets (
Id_Cliente,
Fecha,
Id_Consigna,
Id_Agencia,
Alias,
warehouse_id,
Id_Ruta,
empresa_id,
landing
)
SELECT
vClientId,
vShipped,
a.id,
IF(vAgencyModeFk, vAgencyModeFk, a.agencyModeFk),
a.nickname,
vWarehouseFk,
IF(vRouteFk,vRouteFk,NULL),
vCompanyFk,
vlanded
FROM address a
JOIN agencyMode am ON am.id = a.agencyModeFk
WHERE a.id = vAddressFk;
SET vNewTicket = LAST_INSERT_ID();
INSERT INTO ticketObservation(ticketFk, observationTypeFk, description)
SELECT vNewTicket, ao.observationTypeFk, ao.description
FROM addressObservation ao
JOIN address a ON a.id = ao.addressFk
WHERE a.id = vAddressFk;
-- CALL logAddWithUser(vNewTicket, vUserId, 'insert', 'ticket', CONCAT('Ha creado el ticket', ' ', vNewTicket));
INSERT INTO vn.ticketLog
SET originFk = vNewTicket, userFk = vUserId, `action` = 'insert', description = CONCAT('Ha creado el ticket:', ' ', vNewTicket);
IF (SELECT ct.isCreatedAsServed FROM vn.clientType ct JOIN vn.client c ON c.typeFk = ct.code WHERE c.id = vClientId ) <> FALSE THEN
INSERT INTO vncontrol.inter(state_id, Id_Ticket, Id_Trabajador)
SELECT id, vNewTicket, getWorker()
FROM state
WHERE `code` = 'DELIVERED';
END IF;
END$$
DELIMITER ;
-- hasZone -----------------------------------------------------------------------
USE `vn`;
DROP function IF EXISTS `hasZone`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` FUNCTION `hasZone`(vLanded DATE, vAddress INT, vAgencyModeFk INT) RETURNS tinyint(1)
DETERMINISTIC
BEGIN
DECLARE vHasZone BOOLEAN DEFAULT FALSE;
DECLARE vPostalCode varchar(10);
SELECT postalCode INTO vPostalCode
FROM address WHERE id = vAddress;
SELECT COUNT(*), id zoneFk, isIncluded INTO vHasZone, @trash, @trash 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
AND zc.delivered = vLanded
AND z.agencyModeFk = vAgencyModeFk
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 LIMIT 1;
RETURN vHasZone;
END$$
DELIMITER ;
-- zoneGetShippedWarehouse -----------------------------------------------------------------------
USE `vn`;
DROP procedure IF EXISTS `zoneGetShippedWarehouse`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetShippedWarehouse`(vLanded DATE, vAddressFk INT, vAgencyModeFk INT)
BEGIN
/**
* Devuelve la mínima fecha de envío 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;
DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetShipped;
CREATE TEMPORARY TABLE tmp.zoneGetShipped
ENGINE = MEMORY
SELECT * FROM (
SELECT z.id,
TIMESTAMPADD(DAY,-z.travelingDays, vLanded) shipped,
zi.isIncluded,z.warehouseFk
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 IF(TIMESTAMPADD(DAY,-z.travelingDays, vLanded) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE)
ORDER BY z.id, shipped ASC, zgFather.depth DESC) t
GROUP BY warehouseFk
HAVING isIncluded > 0;
END$$
DELIMITER ;
-- bionic_calc -----------------------------------------------------------------------
USE `vn2008`;
DROP procedure IF EXISTS `bionic_calc`;
DELIMITER $$
USE `vn2008`$$
CREATE DEFINER=`root`@`%` PROCEDURE `bionic_calc`(
vLanded DATE,
vAddress INT,
vAgency INT)
proc: BEGIN
-- @DEPRECATED use vn.ticketCalculate
DECLARE vAvailableCalc INT;
DECLARE vShipped DATE;
DECLARE vCustomer INT;
DECLARE vWh SMALLINT;
DECLARE vDone BOOL;
DECLARE cTravelTree CURSOR FOR
SELECT warehouseFk, shipped FROM tmp.zoneGetShippedWarehouse;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
DROP TEMPORARY TABLE IF EXISTS
tmp.bionic_item,
tmp.bionic_component,
tmp.bionic_lot,
tmp.bionic_price;
-- Establece los almacenes y las fechas que van a entrar al disponible
SELECT Id_Cliente INTO vCustomer FROM Consignatarios WHERE Id_Consigna = vAddress;
CALL vn.zoneGetShippedWarehouse(vLanded, vAddress, vAgency);
-- Crea la tabla temporal que almacenará los lotes
CREATE TEMPORARY TABLE tmp.bionic_lot LIKE
template_bionic_lot;
OPEN cTravelTree;
l: LOOP
SET vDone = FALSE;
FETCH cTravelTree INTO vWh, vShipped;
IF vDone THEN
LEAVE l;
END IF;
CALL `cache`.available_refresh (vAvailableCalc, FALSE, vWh, vShipped);
CALL item_last_buy_ (vWh, vShipped);
INSERT INTO tmp.bionic_lot (warehouse_id, item_id, available, buy_id)
SELECT
vWh,
i.item_id,
IFNULL(i.available, 0),
ilb.buy_id
FROM `cache`.available i
JOIN tmp.bionic_calc br ON br.item_id = i.item_id
LEFT JOIN Articles a ON a.Id_Article = i.item_id
LEFT JOIN t_item_last_buy ilb ON ilb.item_id = i.item_id
WHERE i.calc_id = vAvailableCalc
AND a.Id_Article != 100
AND i.available > 0;
DROP TEMPORARY TABLE t_item_last_buy;
END LOOP;
CLOSE cTravelTree;
CALL bionic_calc_component(vAddress, vAgency);
CREATE TEMPORARY TABLE tmp.bionic_item
ENGINE = MEMORY
SELECT b.item_id, SUM(b.available) available, p.name producer,
a.Article item, a.Medida size, a.Tallos stems, a.Categoria category,
a.Color, a.Foto image, o.Abreviatura origin, bl.min_price price
FROM tmp.bionic_lot b
JOIN Articles a ON b.item_id = a.Id_Article
LEFT JOIN producer p ON p.producer_id = a.producer_id AND p.visible
JOIN Origen o ON o.id = a.id_origen
JOIN (
SELECT MIN(price) min_price, item_id
FROM tmp.bionic_price
GROUP BY item_id
) bl ON bl.item_id = b.item_id
GROUP BY b.item_id;
DROP TEMPORARY TABLE tmp.zoneGetShippedWarehouse;
END$$
DELIMITER ;
-- bionic_calc_component -----------------------------------------------------------------------
USE `vn2008`;
DROP procedure IF EXISTS `bionic_calc_component`;
DELIMITER $$
USE `vn2008`$$
CREATE DEFINER=`root`@`%` PROCEDURE `bionic_calc_component`(IN `v_consigna` INT, IN `v_agencia` INT)
proc: BEGIN
DECLARE v_customer INT;
DECLARE COEFICIENTE_DE_INFLACION_GENERAL INT DEFAULT 1.0;
DECLARE DENSIDAD_MINIMA_PESO_VOLUMETRICO INT DEFAULT 167;
DECLARE VOLUMEN_CAJA_VERDNATURA BIGINT; -- DEFAULT 138000;
-- DECLARE vValorEmbolsado DOUBLE DEFAULT 0.04;
SELECT Volumen INTO VOLUMEN_CAJA_VERDNATURA
FROM Cubos
WHERE Id_Cubo = '94';
SELECT Id_Cliente INTO v_customer FROM Consignatarios WHERE Id_Consigna = v_consigna;
SET @rate2 := 0;
SET @rate3 := 0;
DROP TEMPORARY TABLE IF EXISTS t_bionic_temp;
CREATE TEMPORARY TABLE t_bionic_temp
(PRIMARY KEY (item_id,warehouse_id))
ENGINE = MEMORY
SELECT
b.item_id, b.warehouse_id,available,
IF((@rate2 := IFNULL(pf.rate_2,c.Tarifa2)) < a.PVP AND a.`Min`, a.PVP, @rate2) * 1.0 rate_2,
IF((@rate3 := IFNULL(pf.rate_3,c.Tarifa3)) < a.PVP AND a.`Min`, a.PVP, @rate3) * 1.0 rate_3,
ifnull(pf.rate_3,0) AS min_price,
IFNULL(pf.Packing,c.Packing) packing,
IFNULL(pf.`grouping`,c.`grouping`) `grouping`,
ABS(IFNULL(pf.caja,c.caja)) box,
b.buy_id, a.tipo_id
FROM tmp.bionic_lot b
JOIN vn2008.Compres c ON b.buy_id = c.Id_Compra
JOIN vn2008.Articles a ON b.item_id = a.Id_Article
JOIN vn2008.Tipos t ON t.tipo_id = a.tipo_id
LEFT JOIN vn2008.reinos r ON r.id = t.reino_id
LEFT JOIN vn2008.PreciosEspeciales p ON a.Id_Article = p.Id_Article AND p.Id_Cliente = v_customer
LEFT JOIN (
SELECT * FROM (
SELECT p.item_id, p.`grouping`, p.Packing, p.caja, p.rate_2, p.rate_3, zgs.warehouseFk AS warehouse_id
FROM vn2008.price_fixed p
JOIN tmp.zoneGetShipped zgs ON zgs.warehouseFk = p.warehouse_id OR p.warehouse_id = 0
WHERE zgs.shipped BETWEEN p.date_start AND p.date_end ORDER BY p.item_id, p.warehouse_id DESC
) t
GROUP BY item_id, warehouse_id
) pf ON pf.item_id = b.item_id AND pf.warehouse_id = b.warehouse_id
-- descartamos articulos con coste menor de 0.01
WHERE Costefijo + Portefijo + Embalajefijo + Comisionfija > 0.01 AND r.display <> 0;
-- Creamos la tabla tmp.bionic_component
DROP TEMPORARY TABLE IF EXISTS tmp.bionic_component;
CREATE TEMPORARY TABLE tmp.bionic_component LIKE
template_bionic_component;
-- Componentes del precio, valores absolutos
INSERT INTO tmp.bionic_component ( warehouse_id, item_id, component_id, cost)
SELECT b.warehouse_id, b.item_id, 29, rate_3 - Costefijo - Portefijo - Embalajefijo - Comisionfija
FROM t_bionic_temp b
JOIN vn2008.Compres c ON b.buy_id = c.Id_Compra;
INSERT INTO tmp.bionic_component ( warehouse_id, item_id, component_id, cost)
SELECT b.warehouse_id, b.item_id, 28, Costefijo + Portefijo + Embalajefijo + Comisionfija
FROM t_bionic_temp b
JOIN vn2008.Compres c ON b.buy_id = c.Id_Compra;
-- Ahora los valores en funcion de la base
DROP TEMPORARY TABLE IF EXISTS t_components_base;
CREATE TEMPORARY TABLE t_components_base
SELECT bc.item_id, ROUND(SUM(cost), 4) AS base, bc.warehouse_id
FROM tmp.bionic_component bc
GROUP BY bc.item_id,warehouse_id;
-- La ratio se calcula teniendo en cuenta el valor de las reclamaciones y el saldo de greuge
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, item_id, 17, ROUND(base * LEAST(recobro,0.25), 3)
FROM t_components_base cb
JOIN bi.claims_ratio ON Id_Cliente = v_customer
WHERE recobro > 0.009;
-- PAK 2016-08-31 Componente de maná automático, en función del maná acumulado por el comercial.
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, item_id, 39, ROUND(base * (0.01 + prices_modifier_rate), 3) as manaAuto
FROM t_components_base cb
JOIN Clientes c on c.Id_Cliente = v_customer
JOIN bs.mana_spellers ms ON c.Id_Trabajador = ms.Id_Trabajador
WHERE ms.prices_modifier_activated
AND c.Id_Trabajador != 196 -- Ruben Espinosa
HAVING manaAuto <> 0 ;
/*
-- Vendedor variable
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, item_id, Id_Componente, IFNULL(ROUND(base * tax,4), 0)
FROM t_components_base cb
JOIN bi.tarifa_componentes
WHERE tarifa_componentes_series_id = 2 and IFNULL(tax, 0) > 0;
*/
-- ******* Inicio Bloque para componentes con tarifa_class diferente de NULL
-- Descuento por ultimas unidades
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, b.item_id, Id_Componente, GREATEST(IFNULL(ROUND(base * tax,4), 0), b.min_price - b.rate_3)
FROM t_components_base cb
JOIN bi.tarifa_componentes
JOIN t_bionic_temp b ON b.item_id = cb.item_id AND b.warehouse_id = cb.warehouse_id
LEFT JOIN PreciosEspeciales pe ON pe.Id_Cliente = v_customer AND pe.Id_Article = b.item_id
WHERE Id_Componente = 32 AND tax <> 0 AND b.min_price < b.rate_3 AND PrecioEspecial IS NULL;
-- Incremento por paquete suelto
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id, b.item_id, 22, rate_2 - rate_3
FROM t_bionic_temp b
JOIN vn2008.Compres c ON b.buy_id = c.Id_Compra
LEFT JOIN PreciosEspeciales pe ON pe.Id_Cliente = v_customer AND pe.Id_Article = b.item_id
WHERE PrecioEspecial IS NULL;
-- ******* Fin Bloque para componentes con tarifa_class diferente de NULL
-- Reparto
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id
, b.item_id
, 15
, COEFICIENTE_DE_INFLACION_GENERAL
* ROUND(
r.cm3
* art.compression
* IF(a.Vista = 1, (GREATEST(art.density,DENSIDAD_MINIMA_PESO_VOLUMETRICO) / DENSIDAD_MINIMA_PESO_VOLUMETRICO ) , 1)
* IFNULL(az.price
* az.inflacion ,50)
/ VOLUMEN_CAJA_VERDNATURA, 4
) cost
FROM t_bionic_temp b
JOIN vn2008.Articles art ON art.Id_Article = b.item_id
JOIN vn2008.Agencias a ON a.Id_Agencia = v_agencia
JOIN vn2008.Consignatarios c ON c.Id_Consigna = v_consigna
JOIN vn2008.Agencias_province ap ON ap.agency_id = a.agency_id AND ap.warehouse_id = b.warehouse_id AND ap.province_id = c.province_id
JOIN vn2008.Agencias_zonas az ON az.Id_Agencia = v_agencia AND az.zona = ap.zona AND az.Id_Article = 71 AND az.warehouse_id = b.warehouse_id
LEFT JOIN bi.rotacion r ON r.warehouse_id = b.warehouse_id AND r.Id_Article = b.item_id
HAVING cost <> 0;
-- Reparto bonificado
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id
, b.item_id
, 41
, COEFICIENTE_DE_INFLACION_GENERAL
* ROUND(
r.cm3
* art.compression
* IF(a.Vista = 1, (GREATEST(art.density,DENSIDAD_MINIMA_PESO_VOLUMETRICO) / DENSIDAD_MINIMA_PESO_VOLUMETRICO ) , 1)
-- * awb.bonus
* az.inflacion
/ VOLUMEN_CAJA_VERDNATURA, 4
) cost
FROM t_bionic_temp b
JOIN vn2008.Articles art ON art.Id_Article = b.item_id
JOIN vn2008.Agencias a ON a.Id_Agencia = v_agencia
JOIN vn2008.Consignatarios c ON c.Id_Consigna = v_consigna
JOIN vn2008.Agencias_province ap ON ap.agency_id = a.agency_id AND ap.warehouse_id = b.warehouse_id AND ap.province_id = c.province_id
JOIN vn2008.Agencias_zonas az ON az.Id_Agencia = v_agencia AND az.zona = ap.zona AND az.Id_Article = 71 AND az.warehouse_id = b.warehouse_id
-- JOIN vn2008.agency_weekday_bonus awb ON awb.warehouse_id = az.warehouse_id AND awb.zona = az.zona AND a.agency_id = awb.agency_id
LEFT JOIN bi.rotacion r ON r.warehouse_id = b.warehouse_id AND r.Id_Article = b.item_id
JOIN tmp.agencyHourGetShipped ah ON ah.warehouseFk = awb.warehouse_id AND weekday(ah.landed) = awb.weekDay
HAVING cost <> 0
LIMIT 1;
-- PAK 12-05-2015
-- EMBOLSADO
IF (SELECT COUNT(*) FROM vn.addressForPackaging WHERE addressFk = v_consigna) THEN
-- IF v_consigna IN (13690, 3402, 5661, 4233) THEN
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id, b.item_id, 38, ap.packagingValue cost
FROM t_bionic_temp b
JOIN vn.addressForPackaging ap
WHERE ap.addressFk = v_consigna;
END IF;
-- JGF 14-08-2015
-- Modificacion de precio por dia de preparacion del pedido
INSERT INTO tmp.bionic_component
SELECT cb.warehouse_id, cb.item_id, 14, cb.base * (IFNULL(pe.percentage,pp.percentage)/100)
FROM t_components_base cb
JOIN tmp.agencyHourGetShipped ah ON ah.warehouseFk = cb.warehouse_id
LEFT JOIN vn2008.preparation_percentage pp ON pp.week_day = weekday(ah.shipped) AND cb.warehouse_id = IFNULL(pp.warehouse_id,cb.warehouse_id)
LEFT JOIN vn2008.preparation_exception pe ON pe.exception_day = ah.shipped AND cb.warehouse_id = IFNULL(pe.warehouse_id,cb.warehouse_id)
WHERE IFNULL(pe.percentage,pp.percentage);
-- Creamos la tabla tmp.bionic_component_copy por que mysql no puede reabrir una tabla temporal
DROP TEMPORARY TABLE IF EXISTS tmp.bionic_component_copy;
CREATE TEMPORARY TABLE tmp.bionic_component_copy
SELECT * FROM tmp.bionic_component;
-- JGF 19-01-2016
-- Precios especiales
INSERT INTO tmp.bionic_component
SELECT b.warehouse_id, b.item_id, 10, pe.PrecioEspecial - SUM(cost) sum_cost
FROM tmp.bionic_component_copy b
JOIN bi.tarifa_componentes t ON b.component_id = t.Id_Componente
JOIN PreciosEspeciales pe ON pe.Id_Cliente = v_customer AND pe.Id_Article = b.item_id
WHERE t.tarifa_class IS NULL
GROUP BY b.item_id, b.warehouse_id
HAVING ABS(sum_cost) > 0.001;
-- Lotes
DROP TEMPORARY TABLE IF EXISTS t_component_sum;
CREATE TEMPORARY TABLE t_component_sum
(INDEX (item_id, warehouse_id))
ENGINE = MEMORY
SELECT SUM(cost) sum_cost, b.item_id, b.warehouse_id, t.tarifa_class
FROM tmp.bionic_component b
JOIN bi.tarifa_componentes t ON b.component_id = t.Id_Componente
GROUP BY b.item_id, b.warehouse_id, t.tarifa_class;
-- ***** Inicia Modifica t_bionic_rate las diferentes tarifas
-- Tarifa por unidad minima
DROP TEMPORARY TABLE IF EXISTS t_bionic_rate;
CREATE TEMPORARY TABLE t_bionic_rate
ENGINE = MEMORY
SELECT b.warehouse_id, item_id, 1 rate,
IF(box = 1, `grouping`, 1) `grouping`, SUM(sum_cost) price
FROM t_bionic_temp b
JOIN t_component_sum cs USING(item_id, warehouse_id)
WHERE IFNULL(cs.tarifa_class,1) = 1 AND box < 2 AND (packing > `grouping` or box = 0)
GROUP BY warehouse_id, item_id;
-- Tarifa por caja
INSERT INTO t_bionic_rate (warehouse_id, item_id, rate, `grouping`, price)
SELECT b.warehouse_id, item_id, 2 rate, packing `grouping`,
SUM(sum_cost) price
FROM t_bionic_temp b
JOIN t_component_sum cs USING(item_id, warehouse_id)
WHERE available IS NULL OR (IFNULL(cs.tarifa_class,2) = 2 AND packing > 0 AND available >= packing)
GROUP BY warehouse_id, item_id;
-- Tarifa para toda la cantidad disponible
INSERT INTO t_bionic_rate (warehouse_id, item_id, rate, `grouping`, price)
SELECT b.warehouse_id, item_id, 3 rate, available `grouping`,
SUM(sum_cost) price
FROM t_bionic_temp b
JOIN t_component_sum cs USING(item_id, warehouse_id)
WHERE IFNULL(cs.tarifa_class,3) = 3
GROUP BY warehouse_id, item_id;
-- ***** Fin Modifica t_bionic_rate las diferentes tarifas
DROP TEMPORARY TABLE IF EXISTS tmp.bionic_price;
CREATE TEMPORARY TABLE tmp.bionic_price
LIKE template_bionic_price;
INSERT INTO tmp.bionic_price (warehouse_id, item_id, rate, `grouping`, price)
SELECT * FROM (
SELECT * FROM t_bionic_rate ORDER BY price
) t
GROUP BY item_id, warehouse_id, `grouping`;
DROP TEMPORARY TABLE IF EXISTS tmp.travel_tree;
CREATE TEMPORARY TABLE tmp.travel_tree
ENGINE = MEMORY
SELECT * FROM tmp.agencyHourGetShipped;
-- Limpieza
DROP TEMPORARY TABLE tmp.agencyHourGetShipped;
DROP TEMPORARY TABLE t_bionic_temp;
DROP TEMPORARY TABLE t_component_sum;
DROP TEMPORARY TABLE t_components_base;
DROP TEMPORARY TABLE t_bionic_rate;
DROP TEMPORARY TABLE tmp.bionic_component_copy;
END$$
DELIMITER ;
/* -- bionic_from_ticket -----------------------------------------------------------------------
USE `vn2008`;
DROP procedure IF EXISTS `bionic_from_ticket`;
DELIMITER $$
USE `vn2008`$$
CREATE DEFINER=`root`@`%` PROCEDURE `bionic_from_ticket`(
-- DEPRECATED use vn.ticketComponentPreview
vLanded DATE, -- fecha de recepcion de mercancia
v_consigna INT,
v_agencia INT,
v_ticket INT)
BEGIN
DECLARE vWarehouseFk INT;
DECLARE vShipped DATE;
SELECT warehouse_id INTO vWarehouseFk FROM Tickets WHERE Id_Ticket = v_ticket;
CALL bionic_free();
CALL vn.zoneGetShippedWarehouse(vLanded,v_consigna, v_agencia);
SELECT shipped INTO vShipped FROM tmp.zoneGetShipped WHERE warehouseFk = vWarehouseFk;
CALL item_last_buy_ (vWarehouseFk, vShipped);
DROP TEMPORARY TABLE IF EXISTS tmp.bionic_lot;
CREATE TEMPORARY TABLE tmp.bionic_lot
SELECT ilb.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
AND m.Id_Article != 100
GROUP BY warehouse_id, item_id;
DROP TEMPORARY TABLE t_item_last_buy;
CALL bionic_calc_component ( v_consigna, v_agencia);
REPLACE INTO tmp.bionic_component (warehouse_id, item_id, component_id, cost)
SELECT t.warehouse_id, m.Id_Article, mc.Id_Componente, mc.Valor
FROM Movimientos_componentes mc
JOIN Movimientos m ON m.Id_Movimiento = mc.Id_Movimiento
JOIN Tickets t ON t.Id_Ticket = m.Id_Ticket
JOIN tarifa_componentes tc ON tc.Id_componente = mc.Id_Componente
WHERE m.Id_Ticket = v_ticket AND tc.is_renewable = FALSE;
-- para recuperar el shipment en caso de que se necesite
SET @shipment = vShipped;
DROP TEMPORARY TABLE tmp.bionic_lot;
IF IFNULL(vShipped,CURDATE() - 1) < CURDATE() THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'No se puede realizar el cambio';
END IF;
END$$
DELIMITER ;
*/
-- ticketCalculate ----------------------------------------------------------------------
USE `vn`;
DROP procedure IF EXISTS `ticketCalculate`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketCalculate`(
vLanded DATE,
vAddressFk INT,
vAgencyModeFk INT)
proc: BEGIN
/**
* Calcula los articulos disponibles y sus precios
*
* @table tmp.item(itemFk) Listado de artículos a calcular
* @param vLanded Fecha de recepcion de mercancia
* @param vAddressFk Id del consignatario
* @param vAgencyModeFk Id de la agencia
* @return tmp.ticketCalculateItem(itemFk, available, producer,
* item, size, stems, category, inkFk, image, origin, price)
* @return tmp.ticketLot(warehouseFk, itemFk, available, buyFk)
* @return tmp.ticketComponent
* @return tmp.ticketComponentPrice
* @return tmp.zoneGetShipped
**/
DECLARE vAvailableCalc INT;
DECLARE vShipment DATE;
DECLARE vClient INT;
DECLARE vWarehouseFk SMALLINT;
DECLARE vDone BOOL;
DECLARE cTravelTree CURSOR FOR
SELECT warehouseFk, shipped FROM tmp.zoneGetShipped;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
-- Establece los almacenes y las fechas que van a entrar al disponible
SELECT clientFk INTO vClient
FROM address WHERE id = vAddressFk;
CALL vn.zoneGetShippedWarehouse(vLanded, vAddressFk, vAgencyModeFk);
DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot;
CREATE TEMPORARY TABLE tmp.ticketLot(
`warehouseFk` smallint(5) unsigned NOT NULL,
`itemFk` int(11) NOT NULL,
`available` double DEFAULT NULL,
`buyFk` int(11) DEFAULT NULL,
`fix` tinyint(3) unsigned DEFAULT '0',
KEY `itemFk` (`itemFk`),
KEY `item_warehouse` (`itemFk`,`warehouseFk`) USING HASH
) ENGINE=MEMORY DEFAULT CHARSET=utf8;
OPEN cTravelTree;
l: LOOP
SET vDone = FALSE;
FETCH cTravelTree INTO vWarehouseFk, vShipment;
IF vDone THEN
LEAVE l;
END IF;
CALL `cache`.available_refresh (vAvailableCalc, FALSE, vWarehouseFk, vShipment);
CALL buyUltimate (vWarehouseFk, vShipment);
INSERT INTO tmp.ticketLot (warehouseFk, itemFk, available, buyFk)
SELECT vWarehouseFk,
i.item_id,
IFNULL(i.available, 0),
bu.buyFk
FROM `cache`.available i
JOIN tmp.item br ON br.itemFk = i.item_id
LEFT JOIN item it ON it.id = i.item_id
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = i.item_id
WHERE i.calc_id = vAvailableCalc
AND it.id != 100
AND i.available > 0;
DROP TEMPORARY TABLE tmp.buyUltimate;
END LOOP;
CLOSE cTravelTree;
CALL vn.ticketComponentCalculate(vAddressFk, vAgencyModeFk);
DROP TEMPORARY TABLE IF EXISTS tmp.ticketCalculateItem;
CREATE TEMPORARY TABLE tmp.ticketCalculateItem
ENGINE = MEMORY
SELECT
b.itemFk,
SUM(b.available) available,
p.name producer,
i.name item,
i.size size,
i.stems,
i.category,
i.inkFk,
i.image,
o.code origin, bl.price
FROM tmp.ticketLot b
JOIN item i ON b.itemFk = i.id
LEFT JOIN producer p ON p.id = i.producerFk AND p.isVisible
JOIN origin o ON o.id = i.originFk
JOIN (
SELECT MIN(price) price, itemFk
FROM tmp.ticketComponentPrice
GROUP BY itemFk
) bl ON bl.itemFk = b.itemFk
GROUP BY b.itemFk;
END$$
DELIMITER ;
-- ticketCalculateSale ----------------------------------------------------------------------
USE `vn`;
DROP procedure IF EXISTS `ticketCalculateSale`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketCalculateSale`(IN vSale BIGINT)
proc: BEGIN
DECLARE vShipped DATE;
DECLARE vWarehouse SMALLINT;
DECLARE vAgencyMode INT;
DECLARE vAddress INT;
DECLARE vTicket BIGINT;
DECLARE vItem BIGINT;
DECLARE vLanded DATE;
DECLARE vTicketFree BOOLEAN DEFAULT TRUE;
SELECT FALSE
INTO vTicketFree
FROM vn.ticket t
JOIN vn.sale s ON s.ticketFk = t.id
LEFT JOIN vn.ticketState ts ON ts.ticketFk = t.id
WHERE s.id = vSale
AND (t.refFk != "" OR (ts.alertLevel > 0 AND s.price != 0))
LIMIT 1;
SELECT ticketFk, itemFk
INTO vTicket, vItem
FROM sale
WHERE id = vSale;
SELECT t.warehouseFk, DATE(t.shipped), t.addressFk, t.agencyModeFk, t.landed
INTO vWarehouse, vShipped, vAddress, vAgencyMode, vLanded
FROM agencyMode a
JOIN ticket t ON t.agencyModeFk = a.id
WHERE t.id = vTicket;
DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetShipped;
CREATE TEMPORARY TABLE tmp.zoneGetShipped ENGINE = MEMORY
SELECT vWarehouse warehouseFk, vShipped shipped, vLanded landed;
CALL buyUltimate (vWarehouse, vShipped);
DELETE FROM tmp.buyUltimate WHERE itemFk != vItem;
DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot;
CREATE TEMPORARY TABLE tmp.ticketLot
SELECT vWarehouse warehouseFk, NULL available, vItem itemFk, buyFk
FROM tmp.buyUltimate
WHERE itemFk = vItem;
CALL ticketComponentCalculate(vAddress, vAgencyMode);
DROP TEMPORARY TABLE IF EXISTS tmp.sale;
CREATE TEMPORARY TABLE tmp.sale
(PRIMARY KEY (saleFk)) ENGINE = MEMORY
SELECT vSale saleFk,vWarehouse warehouseFk;
CALL ticketComponentUpdateSale(IF(vTicketFree,1,6));
INSERT INTO vn.ticketLog (originFk, userFk, `action`, description)
VALUES (vTicket, account.userGetId(), 'update', CONCAT('Bionizo linea id ', vSale));
DROP TEMPORARY TABLE tmp.buyUltimate;
END$$
DELIMITER ;
-- 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;
DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetAgency;
CREATE TEMPORARY TABLE tmp.zoneGetAgency
(INDEX (agencyModeFk)) ENGINE = MEMORY
SELECT * FROM (
SELECT am.id agencyModeFk,
am.name agencyMode,
am.description,
am.deliveryMethodFk,
TIMESTAMPADD(DAY,-z.travelingDays, vLanded) shipped,
zi.isIncluded,
z.warehouseFk
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 ;
-- bionic_available_type_filters ---------------------------------------------------------------------
USE `vn2008`;
DROP procedure IF EXISTS `bionic_available_types_filter`;
DELIMITER $$
CREATE DEFINER=`root`@`%` PROCEDURE `bionic_available_types_filter`(
v_date DATE,
v_consigna INT,
v_agencia INT)
BEGIN
/**
* Este procedimiento devuelve una tabla t_bionic_available_types
* que debe de ser borrar por quien la llame, y se conecta con la tabla articlelist
* que tambien hay que eliminar.
*
* @param vDatefecha de recepcion de mercancia
* @table t_bionic_available_types
*/
CALL vn.ticketCalculate(v_date, v_consigna, v_agencia);
-- Introducimos los valores en una tabla temporal
DROP TEMPORARY TABLE IF EXISTS t_bionic_available_types;
CALL check_table_existence('articlelist');
IF @table_exists THEN
call util.throw('No usar articlelist');
-- SET v_list = 'JOIN vn2008.articlelist AL ON AL.Id_Article = a.Id_Article ';
END IF;
CREATE TEMPORARY TABLE t_bionic_available_types
SELECT a.tipo_id, t.Tipo, r.reino, count(*) as item_count
FROM tmp.ticketCalculateItem tci
JOIN vn2008.Articles a ON tci.itemFk = a.Id_Article
JOIN vn2008.Tipos t ON t.tipo_id = a.tipo_id
JOIN vn2008.reinos r ON r.id = t.reino_id
WHERE tci.available > 0
GROUP BY a.tipo_id;
DROP TEMPORARY TABLE tmp.ticketCalculateItem;
END$$
DELIMITER ;
-- ticketCalculateFromType ---------------------------------------------------------------------
USE `vn`;
DROP procedure IF EXISTS `ticketCalculateFromType`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketCalculateFromType`( vLanded DATE,
vAddressFk INT,
vAgencyModeFk INT,
vTypeFk INT)
BEGIN
DROP TEMPORARY TABLE IF EXISTS tmp.item;
CREATE TEMPORARY TABLE tmp.item
(INDEX (itemFk))
ENGINE = MEMORY
SELECT id itemFk FROM vn.item
WHERE typeFk = vTypeFk;
CALL ticketCalculate(vLanded, vAddressFk, vAgencyModeFk);
DROP TEMPORARY TABLE tmp.item;
DROP TEMPORARY TABLE tmp.ticketLot;
END$$
DELIMITER ;
-- order_confirmWithUser` ---------------------------------------------------------------------
USE `hedera`;
DROP PROCEDURE IF EXISTS `orderConfirm`;
DROP procedure IF EXISTS `order_confirm_bionic`;
DROP procedure IF EXISTS `orderConfirmWithUser`;
DROP procedure IF EXISTS `order_confirmWithUser`;
DELIMITER $$
USE `hedera`$$
CREATE DEFINER=`root`@`%` PROCEDURE `order_confirmWithUser`(IN `vOrder` INT, IN `vUserId` INT)
BEGIN
/**
* Confirms an order, creating each of its tickets on the corresponding
* date, store and user.
*
* @param vOrder The order identifier
* @param vUser The user identifier
*/
DECLARE vOk BOOL;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vWarehouse INT;
DECLARE vShipment DATETIME;
DECLARE vTicket INT;
DECLARE vNotes VARCHAR(255);
DECLARE vItem INT;
DECLARE vConcept VARCHAR(30);
DECLARE vAmount INT;
DECLARE vPrice DECIMAL(10,2);
DECLARE vSale INT;
DECLARE vRate INT;
DECLARE vRowId INT;
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 SYSTEM_WORKER INT DEFAULT 20;
DECLARE cDates CURSOR FOR
SELECT zgs.shipped, r.warehouse_id
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 = vOrder AND r.amount != 0
GROUP BY r.warehouse_id;
DECLARE cRows CURSOR FOR
SELECT r.id, r.item_id, a.Article, r.amount, r.price, r.rate
FROM order_row r
JOIN vn2008.Articles a ON a.Id_Article = r.item_id
WHERE r.amount != 0
AND r.warehouse_id = vWarehouse
AND r.order_id = vOrder
ORDER BY r.rate DESC;
DECLARE CONTINUE HANDLER FOR NOT FOUND
SET vDone = TRUE;
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
-- Carga los datos del pedido
SELECT o.date_send, o.address_id, o.note,
o.confirmed, cs.Id_Cliente, o.company_id, o.agency_id
INTO vDelivery, vAddress, vNotes,
vIsConfirmed, vClientId, vCompanyId, vAgencyModeId
FROM hedera.`order` o
JOIN vn2008.Consignatarios cs ON cs.Id_Consigna = o.address_id
WHERE id = vOrder;
-- Comprueba que el pedido no está confirmado
IF vIsConfirmed THEN
CALL util.throw ('ORDER_ALREADY_CONFIRMED');
END IF;
-- Comprueba que el pedido no está vacío
SELECT COUNT(*) > 0 INTO vOk
FROM order_row WHERE order_id = vOrder AND amount > 0;
IF !vOk THEN
CALL util.throw ('ORDER_EMPTY');
END IF;
-- Carga las fechas de salida de cada almacén
CALL vn.zoneGetShippedWarehouse (vDelivery, vAddress, vAgencyModeId);
-- Trabajador que realiza la acción
IF vUserId IS NULL THEN
SELECT employeeFk INTO vUserId FROM orderConfig;
END IF;
-- Crea los tickets del pedido
START TRANSACTION;
OPEN cDates;
lDates:
LOOP
SET vTicket = NULL;
SET vDone = FALSE;
FETCH cDates INTO vShipment, vWarehouse;
IF vDone THEN
LEAVE lDates;
END IF;
-- Busca un ticket existente que coincida con los parametros
SELECT Id_Ticket INTO vTicket
FROM vn2008.Tickets t
LEFT JOIN vn.ticketState tls on tls.ticket = t.Id_Ticket
JOIN `order` o
ON o.address_id = t.Id_Consigna
AND vWarehouse = t.warehouse_id
AND o.agency_id = t.Id_Agencia
AND t.landing = o.date_send
AND vShipment = DATE(t.Fecha)
WHERE o.id = vOrder
AND t.Factura IS NULL
AND IFNULL(tls.alertLevel,0) = 0
AND t.Id_Cliente <> 1118
LIMIT 1;
-- Crea el ticket en el caso de no existir uno adecuado
IF vTicket IS NULL
THEN
CALL vn.ticketCreateWithUser(
vClientId,
IFNULL(vShipment, CURDATE()),
vWarehouse,
vCompanyId,
vAddress,
vAgencyModeId,
NULL,
vDelivery,
vUserId,
vTicket
);
ELSE
INSERT INTO vncontrol.inter
SET Id_Ticket = vTicket,
Id_Trabajador = SYSTEM_WORKER,
state_id = TICKET_FREE;
END IF;
INSERT IGNORE INTO vn2008.order_Tickets
SET order_id = vOrder,
Id_Ticket = vTicket;
-- Añade las notas
IF vNotes IS NOT NULL AND vNotes != ''
THEN
INSERT INTO vn2008.ticket_observation SET
Id_Ticket = vTicket,
observation_type_id = 4 /* salesperson */,
`text` = vNotes
ON DUPLICATE KEY UPDATE
`text` = CONCAT(VALUES(`text`),'. ', `text`);
END IF;
-- Añade los movimientos y sus componentes
OPEN cRows;
lRows:
LOOP
SET vDone = FALSE;
FETCH cRows INTO vRowId, vItem, vConcept, vAmount, vPrice, vRate;
IF vDone THEN
LEAVE lRows;
END IF;
INSERT INTO vn2008.Movimientos
SET
Id_Article = vItem,
Id_Ticket = vTicket,
Concepte = vConcept,
Cantidad = vAmount,
Preu = vPrice,
CostFixat = 0,
PrecioFijado = TRUE;
SET vSale = LAST_INSERT_ID();
INSERT INTO vn2008.Movimientos_componentes
(Id_Movimiento, Id_Componente, Valor)
SELECT vSale, cm.component_id, cm.price
FROM order_component cm
JOIN bi.tarifa_componentes tc
ON tc.Id_Componente = cm.component_id
WHERE cm.order_row_id = vRowId
GROUP BY vSale, cm.component_id;
UPDATE order_row SET Id_Movimiento = vSale
WHERE id = vRowId;
END LOOP;
CLOSE cRows;
-- Fija el coste
DROP TEMPORARY TABLE IF EXISTS tComponents;
CREATE TEMPORARY TABLE tComponents
(INDEX (saleFk))
ENGINE = MEMORY
SELECT SUM(mc.Valor) valueSum, mc.Id_Movimiento saleFk
FROM vn2008.Movimientos_componentes mc
JOIN bi.tarifa_componentes tc USING(Id_Componente)
JOIN bi.tarifa_componentes_series tcs
ON tcs.tarifa_componentes_series_id = tc.tarifa_componentes_series_id
AND tcs.base
JOIN vn2008.Movimientos m
ON m.Id_Movimiento = mc.Id_Movimiento
WHERE m.Id_Ticket = vTicket
GROUP BY mc.Id_Movimiento;
UPDATE vn2008.Movimientos m
JOIN tComponents mc ON mc.saleFk = m.Id_Movimiento
SET m.CostFixat = valueSum;
DROP TEMPORARY TABLE tComponents;
END LOOP;
CLOSE cDates;
DELETE FROM basketOrder WHERE orderFk = vOrder;
UPDATE `order` SET confirmed = TRUE, confirm_date = NOW()
WHERE id = vOrder;
COMMIT;
END$$
DELIMITER ;
-- orderConfirmWithUser` ---------------------------------------------------------------------
USE `vn`;
DROP procedure IF EXISTS `vn`.`agencyHourGetAgency`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `agencyHourGetAgencyKk`(vAddress INT, vDate DATE)
BEGIN
/**
* DEPRECATED usar zoneGetAgency
* 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
* @table agencyModeList Listado de agencias disponibles
*/
DECLARE vAgency INT;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vCur CURSOR FOR
SELECT DISTINCT a.id
FROM agency a
JOIN agencyHour ah ON ah.agencyFk = a.id;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
DROP TEMPORARY TABLE IF EXISTS agencyModeList;
CREATE TEMPORARY TABLE agencyModeList (
id INT NOT NULL,
agency VARCHAR(20),
description VARCHAR(45),
deliveryMethodFk VARCHAR(45),
shipped DATE,
warehouse VARCHAR(45),
PRIMARY KEY(id)
)
ENGINE = MEMORY;
OPEN vCur;
FETCH vCur INTO vAgency;
WHILE NOT vDone
DO
CALL vn.agencyHourGetShipped(vDate, vAddress, vAgency);
INSERT INTO agencyModeList
SELECT a.id, a.name, a.description,
a.deliveryMethodFk, ah.shipped, w.name
FROM agencyMode a
JOIN tmp.agencyHourGetShipped ah
JOIN warehouse w on w.id = ah.warehouseFk
WHERE a.agencyFk = vAgency
AND a.web
ON DUPLICATE KEY UPDATE
warehouse = CONCAT(warehouse, ', ', w.name);
FETCH vCur INTO vAgency;
END WHILE;
CLOSE vCur;
DROP TEMPORARY TABLE tmp.agencyHourGetShipped;
SELECT * FROM agencyModeList;
DROP TEMPORARY TABLE IF EXISTS agencyModeList;
END$$
DELIMITER ;
-- ticketComponentPreview` ---------------------------------------------------------------------
USE `vn`;
DROP procedure IF EXISTS `ticketComponentPreview`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketComponentPreview`(
vTicketFk INT,
vLanded DATE,
vAddressFk INT,
vAgencyModeFk INT,
vWarehouseFk SMALLINT)
BEGIN
DECLARE vShipped DATE;
DECLARE vBuyOrderItem INT DEFAULT 100;
DECLARE vHasDataChanged BOOL DEFAULT FALSE;
DECLARE vHasAddressChanged BOOL;
DECLARE vHasAgencyModeChanged BOOL DEFAULT FALSE;
DECLARE vHasWarehouseChanged BOOL DEFAULT FALSE;
DECLARE vAddressTypeRateFk INT DEFAULT NULL;
DECLARE vAgencyModeTypeRateFk INT DEFAULT NULL;
DECLARE vHasChangeAll BOOL DEFAULT FALSE;
SELECT DATE(landed) <> vLanded,
addressFk <> vAddressFk,
agencyModeFk <> vAgencyModeFk,
warehouseFk <> vWarehouseFk
INTO
vHasDataChanged,
vHasAddressChanged,
vHasAgencyModeChanged,
vHasWarehouseChanged
FROM vn.ticket t
WHERE t.id = vTicketFk;
IF vHasDataChanged OR vHasWarehouseChanged THEN
SET vHasChangeAll = TRUE;
END IF;
IF vHasAddressChanged THEN
SET vAddressTypeRateFk = 5;
END IF;
IF vHasAgencyModeChanged THEN
SET vAgencyModeTypeRateFk = 6;
END IF;
CALL zoneGetShippedWarehouse(vLanded, vAddressFk, vAgencyModeFk);
SELECT shipped INTO vShipped
FROM tmp.zoneGetShipped
WHERE warehouseFk = vWarehouseFk;
CALL buyUltimate(vWarehouseFk, vShipped);
DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot;
CREATE TEMPORARY TABLE tmp.ticketLot ENGINE = MEMORY (
SELECT
vWarehouseFk AS warehouseFk,
NULL AS available,
s.itemFk,
bu.buyFk
FROM sale s
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
WHERE s.ticketFk = vTicketFk
AND s.itemFk != vBuyOrderItem
GROUP BY bu.warehouseFk, bu.itemFk);
CALL ticketComponentCalculate(vAddressFk, vAgencyModeFk);
REPLACE INTO tmp.ticketComponent (warehouseFk, itemFk, componentFk, cost)
SELECT t.warehouseFk, s.itemFk, sc.componentFk, sc.value
FROM saleComponent sc
JOIN sale s ON s.id = sc.saleFk
JOIN ticket t ON t.id = s.ticketFk
JOIN componentRate cr ON cr.id = sc.componentFk
WHERE s.ticketFk = vTicketFk
AND (cr.isRenewable = FALSE
OR
(NOT vHasChangeAll
AND (NOT (cr.componentTypeRate <=> vAddressTypeRateFk
OR cr.componentTypeRate <=> vAgencyModeTypeRateFk))));
SET @shipped = vShipped;
DROP TEMPORARY TABLE
tmp.zoneGetShipped,
tmp.buyUltimate,
tmp.ticketLot;
IF IFNULL(vShipped, CURDATE() - 1) < CURDATE() THEN
CALL util.throw('NO_AGENCY_AVAILABLE');
END IF;
END$$
DELIMITER ;
-- orderCheckConfig` ---------------------------------------------------------------------
USE `hedera`;
DROP procedure IF EXISTS `orderCheckConfig`;
DELIMITER $$
USE `hedera`$$
CREATE DEFINER=`root`@`%` PROCEDURE `orderCheckConfig`(vOrder INT)
proc: BEGIN
/**
* Comprueba que la configuración del pedido es correcta.
*
* @param vOrder Identificador del pedido
*/
DECLARE vDeliveryMethod VARCHAR(255);
DECLARE vLanded DATE;
DECLARE vAgencyMode INT;
DECLARE vAddress INT;
DECLARE vIsAvailable BOOL;
-- Obtiene los datos del pedido
SELECT d.code, o.date_send, o.agency_id, o.address_id
INTO vDeliveryMethod, vLanded, vAgencyMode, vAddress
FROM `order` o
JOIN vn.deliveryMethod d ON d.id = o.delivery_method_id
WHERE o.id = vOrder;
-- Comprueba que se ha seleccionado una dirección
IF vDeliveryMethod IN ('AGENCY', 'DELIVERY')
&& vAddress IS NULL
THEN
CALL util.throw ('ORDER_EMPTY_ADDRESS');
END IF;
-- Comprueba que la agencia es correcta
CALL vn.zoneGetAgency(vAddress, vLanded);
SELECT COUNT(*) > 0 INTO vIsAvailable
FROM tmp.zoneGetAgency
WHERE agencyModeFk = vAgencyMode;
IF !vIsAvailable THEN
CALL util.throw ('ORDER_INVALID_AGENCY');
END IF;
DROP TEMPORARY TABLE tmp.zoneGetAgency;
END$$
DELIMITER ;
-- agencyListAvailable` ---------------------------------------------------------------------
DROP procedure IF EXISTS `vn`.`agencyListAvailable`;
DELIMITER $$
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`__agencyListAvailable`(vDate DATE, vAddress INT)
READS SQL DATA
BEGIN
/**
* DEPRECATED usar zoneGetAgency
* Devuelve la lista de almacenes disponibles y la fecha de
* envío desde cada uno.
*
* @param vDate Fecha de recepción de mercancía
* @param vAddress Id consignatario, %NULL para recogida
* @return agencyAvailable Lista de almacenes disponibles
*/
DECLARE vMaxDays INT DEFAULT DATEDIFF(vDate, CURDATE());
DECLARE vWday TINYINT DEFAULT WEEKDAY(vDate);
DECLARE vHour TINYINT DEFAULT HOUR(NOW());
DECLARE vProvince INT;
SELECT provinceFk INTO vProvince
FROM address
WHERE id = vAddress;
DROP TEMPORARY TABLE IF EXISTS tmp.agencyAvailable;
CREATE TEMPORARY TABLE tmp.agencyAvailable
(INDEX (agencyFk))
ENGINE = MEMORY
SELECT agencyFk, warehouseFk
FROM agencyHour h
WHERE (provinceFk = vProvince
OR provinceFk IS NULL)
AND (weekDay = vWday
OR weekDay IS NULL)
AND (substractDay < vMaxDays
OR (substractDay = vMaxDays AND maxHour > vHour));
END$$
DELIMITER ;
-- agencyIsAvailable` ---------------------------------------------------------------------
DROP function IF EXISTS `vn`.`agencyIsAvailable`;
DELIMITER $$
CREATE DEFINER=`root`@`%` FUNCTION `vn`.`__agencyIsAvailable`(vAgency INT, vDate DATE, vAddress INT)
RETURNS tinyint(1)
READS SQL DATA
BEGIN
/**
* Comprueba si la agencia esta disponible para la fecha y
* dirección dadas, es decir, si es posible enviar mercancía
* desde al menos uno de los almacenes por la agencia, fecha
* y direcciones especificadas.
*
* @param vAgency Id de agencia
* @param vDate Fecha de recepción de mercancía
* @param vAddress Id consignatario, %NULL para recogida
* @return %TRUE si la agencia esta disponible, %FALSE en caso contrario
*/
DECLARE vMaxDays INT DEFAULT DATEDIFF(vDate, CURDATE());
DECLARE vWday TINYINT DEFAULT WEEKDAY(vDate);
DECLARE vHour TINYINT DEFAULT HOUR(NOW());
DECLARE vProvince INT;
DECLARE isAvailable BOOL;
SELECT provinceFk INTO vProvince
FROM address
WHERE id = vAddress;
SELECT COUNT(*) > 0 INTO isAvailable
FROM agencyHour h
JOIN agencyMode a
ON a.agencyFk = h.agencyFk
WHERE (h.provinceFk = vProvince
OR h.provinceFk IS NULL)
AND (h.weekDay = vWday
OR h.weekDay IS NULL)
AND (h.substractDay < vMaxDays
OR (h.substractDay = vMaxDays AND h.maxHour > vHour))
AND a.id = vAgency;
RETURN isAvailable;
END$$
DELIMITER ;
-- ticket_recalcComponents` ---------------------------------------------------------------------
USE `vn2008`;
DROP procedure IF EXISTS `vn2008`.`bionic_calc_ticket`;
USE `vn`;
DROP procedure IF EXISTS `ticket_recalcComponents`;
USE `vn`;
DROP procedure IF EXISTS `ticket_recalcComponents`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticket_recalcComponents`(IN vTicketFk BIGINT )
proc: BEGIN
/**
* Este procedimiento trata de "rebionizar" un ticket,
* eliminando los componentes existentes e insertandolos de nuevo
*
* @param vTicketFk Id del ticket
* @return tmp.buyUltimate
*/
DECLARE vShipped DATE;
DECLARE vWarehouseFk SMALLINT;
DECLARE vAgencyModeFk INT;
DECLARE vAddressFk INT;
DECLARE vLanded DATE;
DECLARE vIsTicketEditable BOOLEAN;
SELECT (IFNULL(ts.alertLevel,0) >0 or IFNULL(t.refFk,"") != "") = FALSE
INTO vIsTicketEditable
FROM ticket t LEFT JOIN ticketState ts ON t.id = ts.ticket
WHERE id = vTicketFk;
SELECT warehouseFk, date(shipped), addressFk, agencyModeFk, landed
INTO vWarehouseFk, vShipped, vAddressFk, vAgencyModeFk, vLanded
FROM ticket
WHERE id = vTicketFk;
CALL zoneGetShippedWarehouse(vLanded, vAddressFk , vAgencyModeFk);
CALL vn.buyUltimate (vWarehouseFk, vShipped); -- rellena la tabla buyUltimate con la ultima compra
DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot;
CREATE TEMPORARY TABLE tmp.ticketLot
SELECT vWarehouseFk warehouseFk, NULL available,
s.itemFk, bu.buyFk
FROM sale s
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
WHERE s.ticketFk = vTicketFk
GROUP BY s.itemFk;
CALL vn.ticketComponentCalculate(vAddressFk,vAgencyModeFk);
DROP TEMPORARY TABLE IF EXISTS tmp.sale;
CREATE TEMPORARY TABLE tmp.sale
(PRIMARY KEY (saleFk)) ENGINE = MEMORY
SELECT id saleFk, vWarehouseFk warehouseFk
FROM sale s
WHERE s.ticketFk = vTicketFk;
CALL vn.ticketComponentUpdateSale(IF(vIsTicketEditable,1,6)); -- si el ticket esta facturado, respeta los precios
IF vLanded IS NULL THEN
CALL zoneGetLanded(vShipped, vAddressFk, vAgencyModeFk, vWarehouseFk);
UPDATE vn2008.Tickets t
SET t.landing = (SELECT landed FROM tmp.zoneGetLanded)
WHERE Id_Ticket = vTicketFk;
DROP TEMPORARY TABLE tmp.zoneGetLanded;
END IF;
DROP TEMPORARY TABLE tmp.buyUltimate;
DROP TEMPORARY TABLE tmp.ticketComponentPrice;
DROP TEMPORARY TABLE tmp.ticketComponent;
DROP TEMPORARY TABLE tmp.sale;
END$$
-- ticketCalculatePurge` ---------------------------------------------------------------------
DELIMITER ;
USE `vn`;
DROP procedure IF EXISTS `ticketCalculatePurge`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketCalculatePurge`()
BEGIN
DROP TEMPORARY TABLE
tmp.ticketCalculateItem,
tmp.ticketComponentPrice,
tmp.ticketComponent,
tmp.ticketLot,
tmp.zoneGetShipped;
END$$
DELIMITER ;
-- `vn`.`component` -----------------------------------------------
CREATE OR REPLACE
ALGORITHM = UNDEFINED
DEFINER = `root`@`%`
SQL SECURITY DEFINER
VIEW `vn`.`component` AS
SELECT
`t`.`Id_Componente` AS `id`,
`t`.`Componente` AS `name`,
`t`.`tarifa_componentes_series_id` AS `typeFk`,
`t`.`tarifa_class` AS `classRate`,
`t`.`tax` AS `tax`,
`t`.`is_renewable` AS `isRenewable`
FROM
`bi`.`tarifa_componentes` `t`;
-- componentType --------------------------------------------------------
CREATE OR REPLACE
ALGORITHM = UNDEFINED
DEFINER = `root`@`%`
SQL SECURITY DEFINER
VIEW `vn`.`componentType` AS
SELECT
`t`.`tarifa_componentes_series_id` AS `id`,
`t`.`Serie` AS `type`,
`t`.`base` AS `base`
FROM
`bi`.`tarifa_componentes_series` `t`;