refactor: refs #6453 order_confirmWithUser #2694
|
@ -1,36 +1,40 @@
|
|||
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 vIsOk BOOL;
|
||||
DECLARE vDone BOOL;
|
||||
DECLARE vWarehouseFk INT;
|
||||
DECLARE vShipment DATE;
|
||||
DECLARE vTicket INT;
|
||||
DECLARE vTicketFk INT;
|
||||
guillermo marked this conversation as resolved
Outdated
|
||||
DECLARE vNotes VARCHAR(255);
|
||||
DECLARE vItem INT;
|
||||
DECLARE vConcept VARCHAR(30);
|
||||
DECLARE vAmount INT;
|
||||
DECLARE vPrice DECIMAL(10,2);
|
||||
DECLARE vSale INT;
|
||||
DECLARE vSaleFk INT;
|
||||
DECLARE vRate INT;
|
||||
DECLARE vRowId INT;
|
||||
DECLARE vRowFk INT;
|
||||
DECLARE vPriceFixed DECIMAL(10,2);
|
||||
DECLARE vDelivery DATE;
|
||||
DECLARE vAddress INT;
|
||||
DECLARE vAddressFk INT;
|
||||
DECLARE vIsConfirmed BOOL;
|
||||
DECLARE vClientId INT;
|
||||
DECLARE vCompanyId INT;
|
||||
DECLARE vAgencyModeId INT;
|
||||
DECLARE vCalc INT;
|
||||
DECLARE vClientFk INT;
|
||||
DECLARE vCompanyFk INT;
|
||||
DECLARE vAgencyModeFk INT;
|
||||
DECLARE vCalcFk INT;
|
||||
DECLARE vIsLogifloraItem BOOL;
|
||||
DECLARE vIsTaxDataChecked BOOL;
|
||||
DECLARE vAvailable INT;
|
||||
|
||||
DECLARE cDates CURSOR FOR
|
||||
SELECT zgs.shipped, r.warehouse_id
|
||||
|
@ -46,12 +50,11 @@ BEGIN
|
|||
FROM order_row r
|
||||
JOIN vn.item i ON i.id = r.item_id
|
||||
WHERE r.amount
|
||||
AND r.warehouse_id = vWarehouse
|
||||
AND r.warehouse_id = vWarehouseFk
|
||||
AND r.order_id = 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
|
||||
|
@ -68,13 +71,13 @@ BEGIN
|
|||
o.agency_id,
|
||||
c.isTaxDataChecked
|
||||
INTO vDelivery,
|
||||
vAddress,
|
||||
vAddressFk,
|
||||
vNotes,
|
||||
vClientId,
|
||||
vCompanyId,
|
||||
vAgencyModeId,
|
||||
vClientFk,
|
||||
vCompanyFk,
|
||||
vAgencyModeFk,
|
||||
vIsTaxDataChecked
|
||||
FROM hedera.`order` o
|
||||
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;
|
||||
|
@ -85,11 +88,11 @@ BEGIN
|
|||
END IF;
|
||||
|
||||
-- Carga las fechas de salida de cada almacen
|
||||
CALL vn.zone_getShipped(vDelivery, vAddress, vAgencyModeId, FALSE);
|
||||
CALL vn.zone_getShipped(vDelivery, 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;
|
||||
|
@ -97,12 +100,12 @@ BEGIN
|
|||
CALL order_checkEditable(vSelf);
|
||||
|
||||
-- Check order is not empty
|
||||
SELECT COUNT(*) > 0 INTO vOk
|
||||
SELECT COUNT(*) > 0 INTO vIsOk
|
||||
FROM order_row
|
||||
WHERE order_id = vSelf
|
||||
AND amount > 0;
|
||||
|
||||
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.
|
||||
IF NOT vOk THEN
|
||||
IF NOT vIsOk THEN
|
||||
CALL util.throw('ORDER_EMPTY');
|
||||
END IF;
|
||||
|
||||
|
@ -110,9 +113,9 @@ BEGIN
|
|||
OPEN cDates;
|
||||
lDates:
|
||||
LOOP
|
||||
SET vTicket = NULL;
|
||||
SET vTicketFk = NULL;
|
||||
SET vDone = FALSE;
|
||||
FETCH cDates INTO vShipment, vWarehouse;
|
||||
FETCH cDates INTO vShipment, vWarehouseFk;
|
||||
|
||||
IF vDone THEN
|
||||
LEAVE lDates;
|
||||
|
@ -126,13 +129,13 @@ BEGIN
|
|||
JOIN vn.ticket t ON t.id = s.ticketFk
|
||||
WHERE t.shipped BETWEEN vShipment AND util.dayend(vShipment)
|
||||
)
|
||||
SELECT t.id INTO vTicket
|
||||
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 vWarehouseFk = t.warehouseFk
|
||||
AND o.date_send = t.landed
|
||||
AND DATE(t.shipped) = vShipment
|
||||
WHERE o.id = vSelf
|
||||
|
@ -142,36 +145,36 @@ BEGIN
|
|||
LIMIT 1;
|
||||
|
||||
-- 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,
|
||||
vUserFk,
|
||||
TRUE,
|
||||
vTicket
|
||||
vTicketFk
|
||||
);
|
||||
ELSE
|
||||
INSERT INTO vn.ticketTracking
|
||||
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
|
||||
SET ticketFk = vTicket,
|
||||
userFk = vUserId,
|
||||
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;
|
||||
|
||||
-- Añade las notas
|
||||
IF vNotes IS NOT NULL AND vNotes <> '' THEN
|
||||
INSERT INTO vn.ticketObservation SET
|
||||
ticketFk = vTicket,
|
||||
ticketFk = vTicketFk,
|
||||
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
|
||||
observationTypeFk = (SELECT id FROM vn.observationType WHERE code = 'salesPerson'),
|
||||
`description` = vNotes
|
||||
ON DUPLICATE KEY UPDATE
|
||||
|
@ -182,74 +185,71 @@ BEGIN
|
|||
OPEN cRows;
|
||||
lRows: LOOP
|
||||
SET vDone = FALSE;
|
||||
FETCH cRows INTO vRowId, vItem, vConcept, vAmount, vPrice, vRate, vIsLogifloraItem;
|
||||
FETCH cRows INTO vRowFk, vItem, vConcept, vAmount, vPrice, vRate, vIsLogifloraItem;
|
||||
|
||||
IF vDone THEN
|
||||
LEAVE lRows;
|
||||
END IF;
|
||||
|
||||
SET vSale = NULL;
|
||||
SET vSaleFk = NULL;
|
||||
|
||||
SELECT s.id INTO vSale
|
||||
SELECT s.id INTO vSaleFk
|
||||
FROM vn.sale s
|
||||
WHERE ticketFk = vTicket
|
||||
WHERE ticketFk = vTicketFk
|
||||
AND price = vPrice
|
||||
AND itemFk = vItem
|
||||
AND discount = 0
|
||||
LIMIT 1;
|
||||
|
||||
IF vSale THEN
|
||||
IF vSaleFk THEN
|
||||
UPDATE vn.sale
|
||||
SET quantity = quantity + vAmount,
|
||||
originalQuantity = quantity
|
||||
WHERE id = vSale;
|
||||
WHERE id = vSaleFk;
|
||||
ELSE
|
||||
-- Obtiene el coste
|
||||
SELECT SUM(rc.`price`) valueSum INTO vPriceFixed
|
||||
FROM orderRowComponent rc
|
||||
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
|
||||
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;
|
||||
WHERE rc.rowFk = vRowFk;
|
||||
|
||||
INSERT INTO vn.sale
|
||||
SET itemFk = vItem,
|
||||
ticketFk = vTicket,
|
||||
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;
|
||||
SET Id_Movimiento = vSaleFk
|
||||
WHERE id = vRowFk;
|
||||
|
||||
-- Inserta en putOrder si la compra es de Floramondo
|
||||
IF vIsLogifloraItem THEN
|
||||
CALL cache.availableNoRaids_refresh(vCalc,FALSE,vWarehouse,vShipment);
|
||||
CALL cache.availableNoRaids_refresh(vCalcFk, FALSE,vWarehouseFk, vShipment);
|
||||
|
||||
SET @available := 0;
|
||||
|
||||
SELECT GREATEST(0, available) INTO @available
|
||||
SELECT GREATEST(0, available) INTO vAvailable
|
||||
FROM cache.availableNoRaids
|
||||
WHERE calc_id = vCalc
|
||||
WHERE calc_id = vCalcFk
|
||||
AND item_id = vItem;
|
||||
|
||||
UPDATE cache.availableNoRaids
|
||||
SET available = GREATEST(0, available - vAmount)
|
||||
WHERE item_id = vItem
|
||||
AND calc_id = vCalc;
|
||||
AND calc_id = vCalcFk;
|
||||
|
||||
INSERT INTO edi.putOrder (
|
||||
deliveryInformationID,
|
||||
|
@ -262,20 +262,20 @@ BEGIN
|
|||
)
|
||||
SELECT di.ID,
|
||||
i.supplyResponseFk,
|
||||
CEIL((vAmount - @available)/ sr.NumberOfItemsPerCask),
|
||||
CEIL((vAmount - vAvailable)/ sr.NumberOfItemsPerCask),
|
||||
o.address_id ,
|
||||
vClientId,
|
||||
vClientFk,
|
||||
IFNULL(ca.fhAdminNumber, fhc.defaultAdminNumber),
|
||||
vSale
|
||||
vSaleFk
|
||||
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
|
||||
LEFT JOIN edi.clientFHAdminNumber ca ON ca.clientFk = vClientFk
|
||||
JOIN edi.floraHollandConfig fhc
|
||||
JOIN hedera.`order` o ON o.id = vSelf
|
||||
JOIN `order` o ON o.id = vSelf
|
||||
WHERE i.id = vItem
|
||||
AND di.LatestOrderDateTime > util.VN_NOW()
|
||||
AND vAmount > @available
|
||||
AND vAmount > vAvailable
|
||||
LIMIT 1;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
|
si es dayend deu ser DATETIME