100 lines
2.6 KiB
SQL
100 lines
2.6 KiB
SQL
|
|
DROP procedure IF EXISTS `vn`.`sale_calculateComponent`;
|
|
|
|
DELIMITER $$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`sale_calculateComponent`(vSale INT, vOption INT)
|
|
proc: BEGIN
|
|
/**
|
|
* Actualiza los componentes
|
|
*
|
|
* @param vSale Delivery date
|
|
* @param vOption indica en que componente pone el descuadre, NULL en casos habituales
|
|
*/
|
|
DECLARE vShipped DATE;
|
|
DECLARE vWarehouseFk SMALLINT;
|
|
DECLARE vAgencyModeFk INT;
|
|
DECLARE vAddressFk INT;
|
|
DECLARE vTicketFk BIGINT;
|
|
DECLARE vItemFk BIGINT;
|
|
DECLARE vLanded DATE;
|
|
DECLARE vIsEditable BOOLEAN;
|
|
DECLARE vZoneFk INTEGER;
|
|
|
|
SELECT t.refFk IS NULL AND (IFNULL(ts.alertLevel, 0) = 0 OR s.price = 0),
|
|
s.ticketFk,
|
|
s.itemFk ,
|
|
t.zoneFk,
|
|
t.warehouseFk,
|
|
t.shipped,
|
|
t.addressFk,
|
|
t.agencyModeFk,
|
|
t.landed
|
|
INTO vIsEditable,
|
|
vTicketFk,
|
|
vItemFk,
|
|
vZoneFk,
|
|
vWarehouseFk,
|
|
vShipped,
|
|
vAddressFk,
|
|
vAgencyModeFk,
|
|
vLanded
|
|
FROM ticket t
|
|
JOIN sale s ON s.ticketFk = t.id
|
|
LEFT JOIN ticketState ts ON ts.ticketFk = t.id
|
|
WHERE s.id = vSale;
|
|
|
|
IF vLanded IS NULL OR vZoneFk IS NULL THEN
|
|
|
|
CALL zone_getLanded(vShipped, vAddressFk, vAgencyModeFk, vWarehouseFk, TRUE);
|
|
|
|
IF (SELECT COUNT(*) FROM tmp.zoneGetLanded LIMIT 1) = 0 THEN
|
|
CALL util.throw('There is no zone for these parameters');
|
|
END IF;
|
|
|
|
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;
|
|
DROP TEMPORARY TABLE tmp.zoneGetLanded;
|
|
|
|
END IF;
|
|
|
|
-- rellena la tabla buyUltimate con la ultima compra
|
|
CALL buyUltimate (vWarehouseFk, vShipped);
|
|
|
|
DELETE FROM tmp.buyUltimate WHERE itemFk != vItemFk;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot;
|
|
CREATE TEMPORARY TABLE tmp.ticketLot
|
|
SELECT vWarehouseFk warehouseFk, NULL available, vItemFk itemFk, buyFk, vZoneFk zoneFk
|
|
FROM tmp.buyUltimate
|
|
WHERE itemFk = vItemFk;
|
|
|
|
CALL catalog_componentPrepare();
|
|
CALL catalog_componentCalculate(vZoneFk, vAddressFk, vShipped, vWarehouseFk);
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.sale;
|
|
CREATE TEMPORARY TABLE tmp.sale
|
|
(PRIMARY KEY (saleFk)) ENGINE = MEMORY
|
|
SELECT vSale saleFk,vWarehouseFk warehouseFk;
|
|
|
|
IF vOption IS NULL THEN
|
|
SET vOption = IF(vIsEditable, 1, 6);
|
|
END IF;
|
|
|
|
CALL ticketComponentUpdateSale(vOption);
|
|
CALL catalog_componentPurge();
|
|
|
|
DROP TEMPORARY TABLE tmp.buyUltimate;
|
|
DROP TEMPORARY TABLE tmp.sale;
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
|