refactor: refs #6453 order_confirmWithUser #2694
|
@ -1,59 +1,62 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`order_confirmWithUser`(vSelf INT, vUserId INT)
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`order_confirmWithUser`(
|
||||
vSelf INT,
|
||||
vUserFk INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Confirms an order, creating each of its tickets on the corresponding
|
||||
* date, store and user.
|
||||
* 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 vHasRows BOOL;
|
||||
DECLARE vDone BOOL;
|
||||
DECLARE vWarehouseFk INT;
|
||||
DECLARE vShipment DATE;
|
||||
DECLARE vTicket INT;
|
||||
DECLARE vShipmentDayEnd DATETIME;
|
||||
guillermo marked this conversation as resolved
Outdated
|
||||
DECLARE vTicketFk INT;
|
||||
DECLARE vNotes VARCHAR(255);
|
||||
DECLARE vItem INT;
|
||||
DECLARE vItemFk INT;
|
||||
DECLARE vConcept VARCHAR(30);
|
||||
DECLARE vAmount INT;
|
||||
DECLARE vAvailable INT;
|
||||
DECLARE vPrice DECIMAL(10,2);
|
||||
DECLARE vSale INT;
|
||||
DECLARE vRate INT;
|
||||
DECLARE vRowId INT;
|
||||
DECLARE vSaleFk INT;
|
||||
DECLARE vRowFk 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 vLanded DATE;
|
||||
DECLARE vAddressFk INT;
|
||||
DECLARE vClientFk INT;
|
||||
DECLARE vCompanyFk INT;
|
||||
DECLARE vAgencyModeFk INT;
|
||||
DECLARE vCalcFk INT;
|
||||
DECLARE vIsTaxDataChecked BOOL;
|
||||
|
||||
DECLARE cDates CURSOR FOR
|
||||
SELECT zgs.shipped, r.warehouse_id
|
||||
DECLARE vDates CURSOR FOR
|
||||
SELECT zgs.shipped, r.warehouseFk
|
||||
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;
|
||||
JOIN orderRow r ON r.orderFk = o.id
|
||||
LEFT JOIN tmp.zoneGetShipped zgs ON zgs.warehouseFk = r.warehouseFk
|
||||
WHERE o.id = vSelf
|
||||
AND r.amount
|
||||
GROUP BY r.warehouseFk;
|
||||
|
||||
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
|
||||
DECLARE vRows CURSOR FOR
|
||||
SELECT r.id,
|
||||
r.itemFk,
|
||||
i.name,
|
||||
r.amount,
|
||||
r.price
|
||||
FROM orderRow r
|
||||
JOIN vn.item i ON i.id = r.itemFk
|
||||
WHERE r.amount
|
||||
AND r.warehouseFk = vWarehouseFk
|
||||
AND r.orderFk = vSelf
|
||||
ORDER BY r.rate DESC;
|
||||
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
||||
SET vDone = TRUE;
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||
|
||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
|
@ -62,26 +65,36 @@ BEGIN
|
|||
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
|
||||
SELECT o.date_send,
|
||||
o.address_id,
|
||||
o.note,
|
||||
a.clientFk,
|
||||
o.company_id,
|
||||
o.agency_id,
|
||||
c.isTaxDataChecked
|
||||
INTO vLanded,
|
||||
vAddressFk,
|
||||
vNotes,
|
||||
vClientFk,
|
||||
vCompanyFk,
|
||||
vAgencyModeFk,
|
||||
vIsTaxDataChecked
|
||||
FROM `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');
|
||||
CALL util.throw('clientNotVerified');
|
||||
END IF;
|
||||
|
||||
-- Carga las fechas de salida de cada almacen
|
||||
CALL vn.zone_getShipped (vDelivery, vAddress, vAgencyModeId, FALSE);
|
||||
CALL vn.zone_getShipped(vLanded, vAddressFk, vAgencyModeFk, FALSE);
|
||||
|
||||
-- Trabajador que realiza la accion
|
||||
IF vUserId IS NULL THEN
|
||||
SELECT employeeFk INTO vUserId FROM orderConfig;
|
||||
IF vUserFk IS NULL THEN
|
||||
SELECT employeeFk INTO vUserFk FROM orderConfig;
|
||||
END IF;
|
||||
|
||||
START TRANSACTION;
|
||||
|
@ -89,207 +102,188 @@ BEGIN
|
|||
CALL order_checkEditable(vSelf);
|
||||
|
||||
-- Check order is not empty
|
||||
SELECT COUNT(*) > 0 INTO vHasRows
|
||||
FROM orderRow
|
||||
WHERE orderFk = vSelf
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
el isOk es una cosa antiga d'un camp que ja no existeix. el isOk es una cosa antiga d'un camp que ja no existeix.
Jo posaria vHasRows que es molt mes intuitiu per a qui vinga raere.
|
||||
AND amount > 0;
|
||||
|
||||
SELECT COUNT(*) > 0 INTO vOk
|
||||
FROM order_row WHERE order_id = vSelf AND amount > 0;
|
||||
|
||||
IF NOT vOk THEN
|
||||
CALL util.throw ('ORDER_EMPTY');
|
||||
IF NOT vHasRows THEN
|
||||
CALL util.throw('ORDER_EMPTY');
|
||||
END IF;
|
||||
|
||||
-- Crea los tickets del pedido
|
||||
|
||||
OPEN cDates;
|
||||
|
||||
lDates:
|
||||
LOOP
|
||||
SET vTicket = NULL;
|
||||
OPEN vDates;
|
||||
lDates: LOOP
|
||||
SET vTicketFk = NULL;
|
||||
SET vDone = FALSE;
|
||||
FETCH cDates INTO vShipment, vWarehouse;
|
||||
FETCH vDates INTO vShipment, vWarehouseFk;
|
||||
|
||||
IF vDone THEN
|
||||
LEAVE lDates;
|
||||
END IF;
|
||||
|
||||
-- Busca un ticket existente que coincida con los parametros
|
||||
WITH tPrevia AS
|
||||
(SELECT DISTINCT s.ticketFk
|
||||
SET vShipmentDayEnd = util.dayEnd(vShipment);
|
||||
|
||||
-- Busca un ticket libre disponible
|
||||
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
|
||||
WHERE t.shipped BETWEEN vShipment AND vShipmentDayEnd
|
||||
)
|
||||
SELECT t.id INTO vTicketFk
|
||||
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
|
||||
LEFT JOIN vn.ticketState tls ON tls.ticketFk = t.id
|
||||
JOIN hedera.`order` o ON o.address_id = t.addressFk
|
||||
AND t.shipped BETWEEN vShipment AND vShipmentDayEnd
|
||||
AND t.warehouseFk = vWarehouseFk
|
||||
AND o.date_send = t.landed
|
||||
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;
|
||||
|
||||
-- Comprobamos si hay un ticket de previa disponible
|
||||
IF vTicketFk IS NULL THEN
|
||||
WITH tItemPackingTypeOrder AS (
|
||||
SELECT GROUP_CONCAT(
|
||||
DISTINCT i.itemPackingTypeFk ORDER BY i.itemPackingTypeFk
|
||||
) distinctItemPackingTypes,
|
||||
o.address_id
|
||||
FROM vn.item i
|
||||
JOIN orderRow oro ON oro.itemFk = i.id
|
||||
JOIN `order` o ON o.id = oro.orderFk
|
||||
WHERE oro.orderFk = vSelf
|
||||
),
|
||||
tItemPackingTypeTicket AS (
|
||||
SELECT t.id,
|
||||
GROUP_CONCAT(
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
esta linea no veig que es gaste esta linea no veig que es gaste
guillermo
commented
Wow, molt ben vist Wow, molt ben vist
|
||||
DISTINCT i.itemPackingTypeFk ORDER BY i.itemPackingTypeFk
|
||||
) distinctItemPackingTypes
|
||||
FROM vn.ticket t
|
||||
JOIN vn.ticketState tls ON tls.ticketFk = t.id
|
||||
JOIN vn.alertLevel al ON al.id = tls.alertLevel
|
||||
JOIN vn.sale s ON s.ticketFk = t.id
|
||||
JOIN vn.item i ON i.id = s.itemFk
|
||||
JOIN tItemPackingTypeOrder ipto
|
||||
WHERE t.shipped BETWEEN vShipment AND vShipmentDayEnd
|
||||
AND t.refFk IS NULL
|
||||
AND t.warehouseFk = vWarehouseFk
|
||||
AND t.addressFk = ipto.address_id
|
||||
AND al.code = 'ON_PREVIOUS'
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
Este enfoque te un problema: Este enfoque te un problema:
si el confirma una order V,H
i ja existia un ticket H,V encara que es lo mateix, com l'ordre està canviat. No l'agafarà com a igual i crearà un altre,
Li he preguntat a Claude per si t'ajuda..https://claude.ai/chat/9e3efec7-761c-4482-a0df-e0e1fed1c7f2
|
||||
GROUP BY t.id
|
||||
)
|
||||
SELECT iptt.id INTO vTicketFk
|
||||
FROM tItemPackingTypeTicket iptt
|
||||
JOIN tItemPackingTypeOrder ipto
|
||||
WHERE INSTR(iptt.distinctItemPackingTypes, ipto.distinctItemPackingTypes)
|
||||
LIMIT 1;
|
||||
END IF;
|
||||
|
||||
-- Crea el ticket en el caso de no existir uno adecuado
|
||||
IF vTicket IS NULL
|
||||
THEN
|
||||
|
||||
IF vTicketFk IS NULL THEN
|
||||
SET vShipment = IFNULL(vShipment, util.VN_CURDATE());
|
||||
|
||||
CALL vn.ticket_add(
|
||||
vClientId,
|
||||
vClientFk,
|
||||
vShipment,
|
||||
vWarehouse,
|
||||
vCompanyId,
|
||||
vAddress,
|
||||
vAgencyModeId,
|
||||
vWarehouseFk,
|
||||
vCompanyFk,
|
||||
vAddressFk,
|
||||
vAgencyModeFk,
|
||||
NULL,
|
||||
vDelivery,
|
||||
vUserId,
|
||||
vLanded,
|
||||
vUserFk,
|
||||
TRUE,
|
||||
vTicket
|
||||
vTicketFk
|
||||
);
|
||||
ELSE
|
||||
INSERT INTO vn.ticketTracking
|
||||
SET ticketFk = vTicket,
|
||||
userFk = vUserId,
|
||||
stateFk = TICKET_FREE;
|
||||
SET ticketFk = vTicketFk,
|
||||
userFk = vUserFk,
|
||||
stateFk = (SELECT id FROM vn.state WHERE code = 'FREE');
|
||||
END IF;
|
||||
|
||||
INSERT IGNORE INTO vn.orderTicket
|
||||
SET orderFk = vSelf,
|
||||
ticketFk = vTicket;
|
||||
ticketFk = vTicketFk;
|
||||
guillermo marked this conversation as resolved
jgallego
commented
ticket_add que es crida dalt ja fa insert en la taula ticketObservation y es el que realment deuria fer-ho. Fes una proba per confirmar si este codi esta duplicant les observacions i si es així ho lleves. ticket_add que es crida dalt ja fa insert en la taula ticketObservation y es el que realment deuria fer-ho. Fes una proba per confirmar si este codi esta duplicant les observacions i si es així ho lleves.
guillermo
commented
He revisat el codi, i ahí soles se inserta la observació del order, per lo tant, es correcte, no es duplica res He revisat el codi, i ahí soles se inserta la observació del order, per lo tant, es correcte, no es duplica res
|
||||
|
||||
-- Añade las notas
|
||||
|
||||
IF vNotes IS NOT NULL AND vNotes != ''
|
||||
THEN
|
||||
INSERT INTO vn.ticketObservation SET
|
||||
ticketFk = vTicket,
|
||||
observationTypeFk = 4 /* salesperson */ ,
|
||||
IF vNotes IS NOT NULL AND vNotes <> '' THEN
|
||||
INSERT INTO vn.ticketObservation
|
||||
SET ticketFk = vTicketFk,
|
||||
observationTypeFk = (SELECT id FROM vn.observationType WHERE code = 'salesPerson'),
|
||||
`description` = vNotes
|
||||
ON DUPLICATE KEY UPDATE
|
||||
`description` = CONCAT(VALUES(`description`),'. ', `description`);
|
||||
END IF;
|
||||
|
||||
-- Añade los movimientos y sus componentes
|
||||
|
||||
OPEN cRows;
|
||||
|
||||
OPEN vRows;
|
||||
lRows: LOOP
|
||||
SET vSaleFk = NULL;
|
||||
SET vDone = FALSE;
|
||||
FETCH cRows INTO vRowId, vItem, vConcept, vAmount, vPrice, vRate, vIsLogifloraItem;
|
||||
FETCH vRows INTO vRowFk, vItemFk, vConcept, vAmount, vPrice;
|
||||
|
||||
IF vDone THEN
|
||||
LEAVE lRows;
|
||||
END IF;
|
||||
|
||||
SET vSale = NULL;
|
||||
|
||||
SELECT s.id, s.quantity INTO vSale, vOldQuantity
|
||||
SELECT s.id INTO vSaleFk
|
||||
FROM vn.sale s
|
||||
WHERE ticketFk = vTicket
|
||||
WHERE ticketFk = vTicketFk
|
||||
AND price = vPrice
|
||||
AND itemFk = vItem
|
||||
AND itemFk = vItemFk
|
||||
AND discount = 0
|
||||
LIMIT 1;
|
||||
|
||||
IF vSale THEN
|
||||
IF vSaleFk 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;
|
||||
WHERE id = vSaleFk;
|
||||
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;
|
||||
JOIN vn.componentType ct ON ct.id = c.typeFk
|
||||
AND ct.isBase
|
||||
WHERE rc.rowFk = vRowFk;
|
||||
|
||||
INSERT INTO vn.sale
|
||||
SET itemFk = vItem,
|
||||
ticketFk = vTicket,
|
||||
SET itemFk = vItemFk,
|
||||
ticketFk = vTicketFk,
|
||||
concept = vConcept,
|
||||
quantity = vAmount,
|
||||
price = vPrice,
|
||||
priceFixed = vPriceFixed,
|
||||
isPriceFixed = TRUE;
|
||||
|
||||
SET vSale = LAST_INSERT_ID();
|
||||
SET vSaleFk = LAST_INSERT_ID();
|
||||
|
||||
INSERT INTO vn.saleComponent
|
||||
(saleFk, componentFk, `value`)
|
||||
SELECT vSale, rc.componentFk, rc.price
|
||||
INSERT INTO vn.saleComponent (saleFk, componentFk, `value`)
|
||||
SELECT vSaleFk, 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;
|
||||
WHERE rc.rowFk = vRowFk
|
||||
GROUP BY vSaleFk, 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;
|
||||
UPDATE orderRow
|
||||
SET saleFk = vSaleFk
|
||||
WHERE id = vRowFk;
|
||||
END LOOP;
|
||||
|
||||
CLOSE cRows;
|
||||
CLOSE vRows;
|
||||
END LOOP;
|
||||
CLOSE vDates;
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
si ho feres amb Pako, confirma amb ell pero vIsLogifloraItem açò no es gasta i si ho vullguerem gastar no funcionaria tot el procés caldría refer-ho. Pregunta-li i lleves tot el codi del if si ho feres amb Pako, confirma amb ell pero vIsLogifloraItem açò no es gasta i si ho vullguerem gastar no funcionaria tot el procés caldría refer-ho. Pregunta-li i lleves tot el codi del if
|
||||
|
||||
CLOSE cDates;
|
||||
|
||||
UPDATE `order` SET confirmed = TRUE, confirm_date = util.VN_NOW()
|
||||
UPDATE `order`
|
||||
SET confirmed = TRUE,
|
||||
confirm_date = util.VN_NOW()
|
||||
WHERE id = vSelf;
|
||||
|
||||
COMMIT;
|
||||
|
|
si es dayend deu ser DATETIME