298 lines
7.3 KiB
SQL
298 lines
7.3 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`order_confirmWithUser`(vSelf INT, vUserId INT)
|
|
BEGIN
|
|
/**
|
|
* Confirms an order, creating each of its tickets on the corresponding
|
|
* date, store and user.
|
|
*
|
|
* @param vSelf The order identifier
|
|
* @param vUser The user identifier
|
|
*/
|
|
DECLARE vOk BOOL;
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
DECLARE vWarehouse INT;
|
|
DECLARE vShipment DATE;
|
|
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 vPriceFixed DECIMAL(10,2);
|
|
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 vCalc INT;
|
|
DECLARE vIsLogifloraItem BOOL;
|
|
DECLARE vOldQuantity INT;
|
|
DECLARE vNewQuantity INT;
|
|
DECLARE vIsTaxDataChecked BOOL;
|
|
|
|
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 = vSelf AND r.amount != 0
|
|
GROUP BY r.warehouse_id;
|
|
|
|
DECLARE cRows CURSOR FOR
|
|
SELECT r.id, r.item_id, i.name, r.amount, r.price, r.rate, i.isFloramondo
|
|
FROM order_row r
|
|
JOIN vn.item i ON i.id = r.item_id
|
|
WHERE r.amount != 0
|
|
AND r.warehouse_id = vWarehouse
|
|
AND r.order_id = vSelf
|
|
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, a.clientFk,
|
|
o.company_id, o.agency_id, c.isTaxDataChecked
|
|
INTO vDelivery, vAddress, vNotes, vClientId,
|
|
vCompanyId, vAgencyModeId, vIsTaxDataChecked
|
|
FROM hedera.`order` o
|
|
JOIN vn.address a ON a.id = o.address_id
|
|
JOIN vn.client c ON c.id = a.clientFk
|
|
WHERE o.id = vSelf;
|
|
|
|
-- Verifica si el cliente tiene los datos comprobados
|
|
IF NOT vIsTaxDataChecked THEN
|
|
CALL util.throw ('clientNotVerified');
|
|
END IF;
|
|
|
|
-- Carga las fechas de salida de cada almacen
|
|
CALL vn.zone_getShipped (vDelivery, vAddress, vAgencyModeId, FALSE);
|
|
|
|
-- Trabajador que realiza la accion
|
|
IF vUserId IS NULL THEN
|
|
SELECT employeeFk INTO vUserId FROM orderConfig;
|
|
END IF;
|
|
|
|
START TRANSACTION;
|
|
|
|
CALL order_checkEditable(vSelf);
|
|
|
|
-- Check order is not empty
|
|
|
|
SELECT COUNT(*) > 0 INTO vOk
|
|
FROM order_row WHERE order_id = vSelf AND amount > 0;
|
|
|
|
IF NOT vOk THEN
|
|
CALL util.throw ('ORDER_EMPTY');
|
|
END IF;
|
|
|
|
-- Crea los tickets del pedido
|
|
|
|
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
|
|
WITH tPrevia AS
|
|
(SELECT DISTINCT s.ticketFk
|
|
FROM vn.sale s
|
|
JOIN vn.saleGroupDetail sgd ON sgd.saleFk = s.id
|
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
|
WHERE t.shipped BETWEEN vShipment AND util.dayend(vShipment)
|
|
)
|
|
SELECT t.id INTO vTicket
|
|
FROM vn.ticket t
|
|
JOIN vn.alertLevel al ON al.code = 'FREE'
|
|
LEFT JOIN tPrevia tp ON tp.ticketFk = t.id
|
|
LEFT JOIN vn.ticketState tls on tls.ticketFk = t.id
|
|
JOIN hedera.`order` o
|
|
ON o.address_id = t.addressFk
|
|
AND vWarehouse = t.warehouseFk
|
|
AND o.date_send = t.landed
|
|
AND DATE(t.shipped) = vShipment
|
|
WHERE o.id = vSelf
|
|
AND t.refFk IS NULL
|
|
AND tp.ticketFk IS NULL
|
|
AND (tls.alertLevel IS NULL OR tls.alertLevel = al.id)
|
|
LIMIT 1;
|
|
|
|
-- Crea el ticket en el caso de no existir uno adecuado
|
|
IF vTicket IS NULL
|
|
THEN
|
|
|
|
SET vShipment = IFNULL(vShipment, util.VN_CURDATE());
|
|
|
|
CALL vn.ticket_add(
|
|
vClientId,
|
|
vShipment,
|
|
vWarehouse,
|
|
vCompanyId,
|
|
vAddress,
|
|
vAgencyModeId,
|
|
NULL,
|
|
vDelivery,
|
|
vUserId,
|
|
TRUE,
|
|
vTicket
|
|
);
|
|
ELSE
|
|
INSERT INTO vn.ticketTracking
|
|
SET ticketFk = vTicket,
|
|
userFk = vUserId,
|
|
stateFk = TICKET_FREE;
|
|
END IF;
|
|
|
|
INSERT IGNORE INTO vn.orderTicket
|
|
SET orderFk = vSelf,
|
|
ticketFk = vTicket;
|
|
|
|
-- Añade las notas
|
|
|
|
IF vNotes IS NOT NULL AND vNotes != ''
|
|
THEN
|
|
INSERT INTO vn.ticketObservation SET
|
|
ticketFk = vTicket,
|
|
observationTypeFk = 4 /* salesperson */ ,
|
|
`description` = vNotes
|
|
ON DUPLICATE KEY UPDATE
|
|
`description` = CONCAT(VALUES(`description`),'. ', `description`);
|
|
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, vIsLogifloraItem;
|
|
|
|
IF vDone THEN
|
|
LEAVE lRows;
|
|
END IF;
|
|
|
|
SET vSale = NULL;
|
|
|
|
SELECT s.id, s.quantity INTO vSale, vOldQuantity
|
|
FROM vn.sale s
|
|
WHERE ticketFk = vTicket
|
|
AND price = vPrice
|
|
AND itemFk = vItem
|
|
AND discount = 0
|
|
LIMIT 1;
|
|
|
|
IF vSale THEN
|
|
UPDATE vn.sale
|
|
SET quantity = quantity + vAmount,
|
|
originalQuantity = quantity
|
|
WHERE id = vSale;
|
|
|
|
SELECT s.quantity INTO vNewQuantity
|
|
FROM vn.sale s
|
|
WHERE id = vSale;
|
|
ELSE
|
|
-- Obtiene el coste
|
|
SELECT SUM(rc.`price`) valueSum INTO vPriceFixed
|
|
FROM orderRowComponent rc
|
|
JOIN vn.component c ON c.id = rc.componentFk
|
|
JOIN vn.componentType ct ON ct.id = c.typeFk AND ct.isBase
|
|
WHERE rc.rowFk = vRowId;
|
|
|
|
INSERT INTO vn.sale
|
|
SET itemFk = vItem,
|
|
ticketFk = vTicket,
|
|
concept = vConcept,
|
|
quantity = vAmount,
|
|
price = vPrice,
|
|
priceFixed = vPriceFixed,
|
|
isPriceFixed = TRUE;
|
|
|
|
SET vSale = LAST_INSERT_ID();
|
|
|
|
INSERT INTO vn.saleComponent
|
|
(saleFk, componentFk, `value`)
|
|
SELECT vSale, rc.componentFk, rc.price
|
|
FROM orderRowComponent rc
|
|
JOIN vn.component c ON c.id = rc.componentFk
|
|
WHERE rc.rowFk = vRowId
|
|
GROUP BY vSale, rc.componentFk;
|
|
END IF;
|
|
|
|
UPDATE order_row SET Id_Movimiento = vSale
|
|
WHERE id = vRowId;
|
|
|
|
-- Inserta en putOrder si la compra es de Floramondo
|
|
IF vIsLogifloraItem THEN
|
|
CALL cache.availableNoRaids_refresh(vCalc,FALSE,vWarehouse,vShipment);
|
|
|
|
SET @available := 0;
|
|
|
|
SELECT GREATEST(0,available) INTO @available
|
|
FROM cache.availableNoRaids
|
|
WHERE calc_id = vCalc
|
|
AND item_id = vItem;
|
|
|
|
UPDATE cache.availableNoRaids
|
|
SET available = GREATEST(0,available - vAmount)
|
|
WHERE item_id = vItem
|
|
AND calc_id = vCalc;
|
|
|
|
INSERT INTO edi.putOrder (
|
|
deliveryInformationID,
|
|
supplyResponseId,
|
|
quantity ,
|
|
EndUserPartyId,
|
|
EndUserPartyGLN,
|
|
FHAdminNumber,
|
|
saleFk
|
|
)
|
|
SELECT di.ID,
|
|
i.supplyResponseFk,
|
|
CEIL((vAmount - @available)/ sr.NumberOfItemsPerCask),
|
|
o.address_id ,
|
|
vClientId,
|
|
IFNULL(ca.fhAdminNumber, fhc.defaultAdminNumber),
|
|
vSale
|
|
FROM edi.deliveryInformation di
|
|
JOIN vn.item i ON i.supplyResponseFk = di.supplyResponseID
|
|
JOIN edi.supplyResponse sr ON sr.ID = i.supplyResponseFk
|
|
LEFT JOIN edi.clientFHAdminNumber ca ON ca.clientFk = vClientId
|
|
JOIN edi.floraHollandConfig fhc
|
|
JOIN hedera.`order` o ON o.id = vSelf
|
|
WHERE i.id = vItem
|
|
AND di.LatestOrderDateTime > util.VN_NOW()
|
|
AND vAmount > @available
|
|
LIMIT 1;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
CLOSE cRows;
|
|
END LOOP;
|
|
|
|
CLOSE cDates;
|
|
|
|
UPDATE `order` SET confirmed = TRUE, confirm_date = util.VN_NOW()
|
|
WHERE id = vSelf;
|
|
|
|
COMMIT;
|
|
END$$
|
|
DELIMITER ;
|