salix/db/routines/vn/procedures/sale_recalcComponent.sql

116 lines
3.1 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn-admin`@`localhost` PROCEDURE `vn`.`sale_recalcComponent`(vOption VARCHAR(25))
proc: BEGIN
/**
* Este procedimiento recalcula los componentes de un conjunto de sales,
* eliminando los componentes existentes e insertandolos de nuevo
*
* @param vOption si no se quiere forzar llamar con NULL
* @table tmp.recalculateSales (id)
*/
DECLARE vShipped DATE;
DECLARE vWarehouseFk SMALLINT;
DECLARE vAgencyModeFk INT;
DECLARE vAddressFk INT;
DECLARE vTicketFk INT;
DECLARE vLanded DATE;
DECLARE vIsEditable BOOLEAN;
DECLARE vZoneFk INTEGER;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vCur CURSOR FOR
SELECT DISTINCT s.ticketFk
FROM tmp.recalculateSales rs
JOIN vn.sale s ON s.id = rs.id;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
OPEN vCur;
l: LOOP
SET vDone = FALSE;
FETCH vCur INTO vTicketFk;
IF vDone THEN
LEAVE l;
END IF;
SELECT (hasToRecalcPrice OR ts.alertLevel IS NULL) AND t.refFk IS NULL,
t.zoneFk,
t.warehouseFk,
t.shipped,
t.addressFk,
t.agencyModeFk,
t.landed
INTO vIsEditable,
vZoneFk,
vWarehouseFk,
vShipped,
vAddressFk,
vAgencyModeFk,
vLanded
FROM ticket t
LEFT JOIN ticketState ts ON t.id = ts.ticketFk
LEFT JOIN alertLevel al ON al.id = ts.alertLevel
WHERE t.id = vTicketFk;
CALL zone_getLanded(vShipped, vAddressFk, vAgencyModeFk, vWarehouseFk, TRUE);
IF NOT EXISTS (SELECT TRUE FROM tmp.zoneGetLanded LIMIT 1) THEN
CALL util.throw(CONCAT('There is no zone for these parameters ', vTicketFk));
END IF;
IF vLanded IS NULL OR vZoneFk IS NULL THEN
UPDATE ticket t
SET t.landed = (SELECT landed FROM tmp.zoneGetLanded LIMIT 1)
WHERE t.id = vTicketFk AND t.landed IS NULL;
IF vZoneFk IS NULL THEN
SELECT zoneFk INTO vZoneFk FROM tmp.zoneGetLanded LIMIT 1;
UPDATE ticket t
SET t.zoneFk = vZoneFk
WHERE t.id = vTicketFk AND t.zoneFk IS NULL;
END IF;
END IF;
DROP TEMPORARY TABLE tmp.zoneGetLanded;
-- rellena la tabla buyUltimate con la ultima compra
CALL buyUltimate (vWarehouseFk, vShipped);
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
(PRIMARY KEY (saleFk)) ENGINE = MEMORY
SELECT s.id saleFk, vWarehouseFk warehouseFk
FROM sale s
JOIN tmp.recalculateSales rs ON s.id = rs.id
WHERE s.ticketFk = vTicketFk;
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketLot
SELECT vWarehouseFk warehouseFk, NULL available, s.itemFk, bu.buyFk, vZoneFk zoneFk
FROM sale s
JOIN tmp.recalculateSales rs ON s.id = rs.id
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
WHERE s.ticketFk = vTicketFk
GROUP BY s.itemFk;
CALL catalog_componentPrepare();
CALL catalog_componentCalculate(vZoneFk, vAddressFk, vShipped, vWarehouseFk);
IF vOption IS NULL THEN
SET vOption = IF(vIsEditable, 'renewPrices', 'imbalance');
END IF;
CALL ticketComponentUpdateSale(vOption);
CALL catalog_componentPurge();
DROP TEMPORARY TABLE tmp.buyUltimate;
DROP TEMPORARY TABLE tmp.sale;
END LOOP;
CLOSE vCur;
END$$
DELIMITER ;