refactor: refs #6453 order_confirmWithUser #2694

Merged
guillermo merged 16 commits from 6453-orderConfirm into dev 2024-08-02 10:15:00 +00:00
1 changed files with 141 additions and 73 deletions
Showing only changes of commit a1d3d2f2f8 - Show all commits

View File

@ -5,8 +5,8 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`order_confirmWi
)
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
@ -25,7 +25,7 @@ BEGIN
DECLARE vRate INT;
DECLARE vRowFk INT;
DECLARE vPriceFixed DECIMAL(10,2);
DECLARE vDelivery DATE;
DECLARE vLanded DATE;
DECLARE vAddressFk INT;
DECLARE vIsConfirmed BOOL;
DECLARE vClientFk INT;
@ -35,8 +35,9 @@ BEGIN
DECLARE vIsLogifloraItem BOOL;
DECLARE vIsTaxDataChecked BOOL;
DECLARE vAvailable INT;
DECLARE vItemPackingTypeFk VARCHAR(1);
DECLARE cDates CURSOR FOR
DECLARE vDates CURSOR FOR
SELECT zgs.shipped, r.warehouseFk
FROM `order` o
JOIN orderRow r ON r.orderFk = o.id
@ -45,8 +46,25 @@ BEGIN
AND r.amount
GROUP BY r.warehouseFk;
DECLARE cRows CURSOR FOR
SELECT r.id, r.itemFk, i.name, r.amount, r.price, r.rate, i.isFloramondo
DECLARE vDistinctItemPackingType CURSOR FOR
SELECT DISTINCT i.itemPackingTypeFk
FROM `order` o
JOIN orderRow r ON r.orderFk = o.id
JOIN vn.item i ON i.id = r.itemFk
WHERE o.id = vSelf
AND r.warehouseFk = vWarehouseFk
AND r.amount
ORDER BY i.itemPackingTypeFk DESC;
DECLARE vRows CURSOR FOR
SELECT r.id,
r.itemFk,
i.name,
r.amount,
r.price,
r.rate,
i.itemPackingTypeFk,
i.isFloramondo
FROM orderRow r
JOIN vn.item i ON i.id = r.itemFk
WHERE r.amount
@ -70,7 +88,7 @@ BEGIN
o.company_id,
o.agency_id,
c.isTaxDataChecked
INTO vDelivery,
INTO vLanded,
vAddressFk,
vNotes,
vClientFk,
@ -88,7 +106,7 @@ BEGIN
END IF;
guillermo marked this conversation as resolved Outdated

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.

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.
-- Carga las fechas de salida de cada almacen
CALL vn.zone_getShipped(vDelivery, vAddressFk, vAgencyModeFk, FALSE);
CALL vn.zone_getShipped(vLanded, vAddressFk, vAgencyModeFk, FALSE);
-- Trabajador que realiza la accion
IF vUserFk IS NULL THEN
@ -110,88 +128,135 @@ BEGIN
END IF;
-- Crea los tickets del pedido
OPEN cDates;
lDates:
LOOP
OPEN vDates;
lDates: LOOP
SET vTicketFk = NULL;
SET vDone = FALSE;
FETCH cDates INTO vShipment, vWarehouseFk;
FETCH vDates INTO vShipment, vWarehouseFk;
IF vDone THEN
LEAVE lDates;
END IF;
CREATE OR REPLACE TEMPORARY TABLE tTicketByItemPackingType(
itemPackingTypeFk VARCHAR(1),
ticketFk INT,
PRIMARY KEY(itemPackingTypeFk, ticketFk)
) ENGINE = MEMORY;
-- 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 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 vWarehouseFk = 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;
OPEN vDistinctItemPackingType;
lDistinctItemPackingType: LOOP
SET vItemPackingTypeFk = NULL;
SET vDone = FALSE;
FETCH vDistinctItemPackingType INTO vItemPackingTypeFk;
-- Crea el ticket en el caso de no existir uno adecuado
IF vTicketFk IS NULL THEN
SET vShipment = IFNULL(vShipment, util.VN_CURDATE());
CALL vn.ticket_add(
vClientFk,
vShipment,
vWarehouseFk,
vCompanyFk,
vAddressFk,
vAgencyModeFk,
NULL,
vDelivery,
vUserFk,
TRUE,
vTicketFk
);
ELSE
INSERT INTO vn.ticketTracking
SET ticketFk = vTicketFk,
userFk = vUserFk,
stateFk = (SELECT id FROM vn.state WHERE code = 'FREE');
END IF;
IF vDone THEN
LEAVE lDistinctItemPackingType;
END IF;
INSERT IGNORE INTO vn.orderTicket
SET orderFk = vSelf,
ticketFk = vTicketFk;
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)
),
guillermo marked this conversation as resolved Outdated

esta linea no veig que es gaste

esta linea no veig que es gaste

Wow, molt ben vist

Wow, molt ben vist
tTicketSameItemPackingType AS (
SELECT t.id, COUNT(*) = SUM(IF(
vItemPackingTypeFk IS NOT NULL,
i.itemPackingTypeFk = vItemPackingTypeFk,
i.itemPackingTypeFk IS NULL
)) hasSameItemPackingType
FROM ticket t
JOIN sale s ON s.ticketFk = t.id
JOIN item i ON i.id = s.itemFk
WHERE t.shipped = vShipment
GROUP BY t.id
HAVING hasSameItemPackingType
)
guillermo marked this conversation as resolved Outdated

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

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
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 t.warehouseFk = vWarehouseFk
AND o.date_send = t.landed
AND DATE(t.shipped) = vShipment
JOIN tTicketSameItemPackingType tt ON tt.id = t.id
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;
-- Añade las notas
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;
-- Crea el ticket en el caso de no existir uno adecuado
IF vTicketFk IS NULL THEN
SET vShipment = IFNULL(vShipment, util.VN_CURDATE());
CALL vn.ticket_add(
vClientFk,
vShipment,
vWarehouseFk,
vCompanyFk,
vAddressFk,
vAgencyModeFk,
NULL,
vLanded,
vUserFk,
TRUE,
vTicketFk
);
ELSE
INSERT INTO vn.ticketTracking
SET ticketFk = vTicketFk,
guillermo marked this conversation as resolved
Review

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.
Review

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
userFk = vUserFk,
stateFk = (SELECT id FROM vn.state WHERE code = 'FREE');
END IF;
INSERT IGNORE INTO vn.orderTicket
SET orderFk = vSelf,
ticketFk = vTicketFk;
-- Añade las notas
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;
INSERT INTO tTicketByItemPackingType
SET itemPackingTypeFk = vItemPackingTypeFk,
ticketFk = vTicketFk;
END LOOP;
CLOSE vDistinctItemPackingType;
-- Añade los movimientos y sus componentes
OPEN cRows;
OPEN vRows;
lRows: LOOP
SET vSaleFk = NULL;
SET vDone = FALSE;
FETCH cRows INTO vRowFk, vItemFk, vConcept, vAmount, vPrice, vRate, vIsLogifloraItem;
FETCH vRows INTO vRowFk,
vItemFk,
vConcept,
vAmount,
vPrice,
vRate,
vItemPackingTypeFk,
vIsLogifloraItem;
IF vDone THEN
LEAVE lRows;
END IF;
SET vSaleFk = NULL;
SELECT ticketFk INTO vTicketFk
FROM tTicketByItemPackingType
WHERE IF(vItemPackingTypeFk IS NOT NULL,
itemPackingTypeFk = vItemPackingTypeFk,
itemPackingTypeFk IS NULL)
SELECT s.id INTO vSaleFk
FROM vn.sale s
@ -211,7 +276,8 @@ BEGIN
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
JOIN vn.componentType ct ON ct.id = c.typeFk
AND ct.isBase
WHERE rc.rowFk = vRowFk;
guillermo marked this conversation as resolved Outdated

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
INSERT INTO vn.sale
@ -279,9 +345,9 @@ BEGIN
LIMIT 1;
END IF;
END LOOP;
CLOSE cRows;
CLOSE vRows;
END LOOP;
CLOSE cDates;
CLOSE vDates;
UPDATE `order`
SET confirmed = TRUE,
@ -289,5 +355,7 @@ BEGIN
WHERE id = vSelf;
COMMIT;
DROP TEMPORARY TABLE tTicketByItemPackingType;
END$$
DELIMITER ;