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

135 lines
3.0 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_replaceItem`(vSaleFk INT, vNewItemFk INT, vQuantity INT)
BEGIN
/**
* Añade un nuevo articulo para sustituir a otro, y actualiza la memoria de sustituciones.
*
* @param vSaleFk id de la tabla sale
* @param vNewItemFk articulo sustituto
* @param vQuantity cantidad que se va a sustituir
*/
DECLARE vTicketFk INT;
DECLARE vItemFk INT;
DECLARE vWarehouseFk SMALLINT;
DECLARE vDate DATE;
DECLARE vGrouping INT;
DECLARE vGroupingMode VARCHAR(255);
DECLARE vPacking INT;
DECLARE vRoundQuantity INT DEFAULT 1;
DECLARE vLanded DATE;
DECLARE vAddressFk INT;
DECLARE vAgencyModeFk INT;
DECLARE vNewPrice DECIMAL(10,2);
DECLARE vOldPrice DECIMAL(10,2);
DECLARE vOption VARCHAR(255);
DECLARE vNewSaleFk INT;
DECLARE vFinalPrice DECIMAL(10,2);
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
SELECT s.ticketFk,
LEAST(s.quantity, vQuantity),
s.itemFk,
t.shipped,
t.warehouseFk,
t.landed,
t.addressFk,
t.agencyModeFk,
s.price
INTO vTicketFk,
vQuantity,
vItemFk,
vDate,
vWarehouseFk,
vLanded,
vAddressFk,
vAgencyModeFk,
vOldPrice
FROM sale s
JOIN ticket t ON t.id = s.ticketFk
WHERE s.id = vSaleFk;
CALL buy_getUltimate(vNewItemFk, vWarehouseFk, vDate);
SELECT `grouping`, groupingMode, packing
INTO vGrouping,vGroupingMode,vPacking
FROM buy b
JOIN tmp.buyUltimate tmp ON b.id = tmp.buyFk
WHERE tmp.itemFk = vNewItemFk AND tmp.WarehouseFk = vWarehouseFk;
DROP TEMPORARY TABLE tmp.buyUltimate;
IF vGroupingMode = 'packing' AND vPacking > 0 THEN
SET vRoundQuantity = vPacking;
END IF;
IF vGroupingMode = 'grouping' AND vGrouping > 0 THEN
SET vRoundQuantity = vGrouping;
END IF;
CALL catalog_calcFromItem(
vLanded,
vAddressFk,
vAgencyModeFk,
vNewItemFk);
SELECT price INTO vNewPrice
FROM tmp.ticketComponentPrice
ORDER BY (vQuantity % `grouping`) ASC
LIMIT 1;
IF vNewPrice IS NULL THEN
CALL util.throw('price retrieval failed');
END IF;
IF vNewPrice > vOldPrice THEN
SET vFinalPrice = vOldPrice;
SET vOption = 'substitution';
ELSE
SET vFinalPrice = vNewPrice;
SET vOption = 'renewPrices';
END IF;
START TRANSACTION;
UPDATE sale
SET originalQuantity = quantity - vQuantity,
quantity = quantity - vQuantity
WHERE id = vSaleFk;
INSERT INTO vn.sale(ticketFk,
itemFk,
quantity,
concept,
price)
SELECT vTicketFk,
vNewItemFk,
CEIL(vQuantity / vRoundQuantity) * vRoundQuantity,
CONCAT('+ ', i.name),
vFinalPrice
FROM vn.item i
WHERE id = vNewItemFk;
SELECT LAST_INSERT_ID() INTO vNewSaleFk;
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 id = vNewSaleFk;
CALL ticketComponentUpdateSale(vOption);
CALL catalog_componentPurge();
INSERT INTO itemProposal(itemFk, mateFk, counter)
VALUES(vItemFk, vNewItemFk, 1)
ON DUPLICATE KEY UPDATE counter = counter + 1;
COMMIT;
END$$
DELIMITER ;