292 lines
7.2 KiB
SQL
292 lines
7.2 KiB
SQL
DELIMITER $$
|
|
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.
|
|
*
|
|
* @param vSelf The order identifier
|
|
* @param vUser The user identifier
|
|
*/
|
|
DECLARE vHasRows BOOL;
|
|
DECLARE vDone BOOL;
|
|
DECLARE vWarehouseFk INT;
|
|
DECLARE vShipment DATE;
|
|
DECLARE vShipmentDayEnd DATETIME;
|
|
DECLARE vTicketFk INT;
|
|
DECLARE vNotes VARCHAR(255);
|
|
DECLARE vItemFk INT;
|
|
DECLARE vConcept VARCHAR(30);
|
|
DECLARE vAmount INT;
|
|
DECLARE vAvailable INT;
|
|
DECLARE vPrice DECIMAL(10,2);
|
|
DECLARE vSaleFk INT;
|
|
DECLARE vRowFk INT;
|
|
DECLARE vPriceFixed DECIMAL(10,2);
|
|
DECLARE vLanded DATE;
|
|
DECLARE vAddressFk INT;
|
|
DECLARE vClientFk INT;
|
|
DECLARE vCompanyFk INT;
|
|
DECLARE vAgencyModeFk INT;
|
|
DECLARE vCalcFk INT;
|
|
DECLARE vIsTaxDataChecked BOOL;
|
|
|
|
DECLARE vDates CURSOR FOR
|
|
SELECT zgs.shipped, r.warehouseFk
|
|
FROM `order` o
|
|
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 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 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 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');
|
|
END IF;
|
|
|
|
-- Carga las fechas de salida de cada almacen
|
|
CALL vn.zone_getShipped(vLanded, vAddressFk, vAgencyModeFk, FALSE);
|
|
|
|
-- Trabajador que realiza la accion
|
|
IF vUserFk IS NULL THEN
|
|
SELECT employeeFk INTO vUserFk FROM orderConfig;
|
|
END IF;
|
|
|
|
START TRANSACTION;
|
|
|
|
CALL order_checkEditable(vSelf);
|
|
|
|
-- Check order is not empty
|
|
SELECT COUNT(*) > 0 INTO vHasRows
|
|
FROM orderRow
|
|
WHERE orderFk = vSelf
|
|
AND amount > 0;
|
|
|
|
IF NOT vHasRows THEN
|
|
CALL util.throw('ORDER_EMPTY');
|
|
END IF;
|
|
|
|
-- Crea los tickets del pedido
|
|
OPEN vDates;
|
|
lDates: LOOP
|
|
SET vTicketFk = NULL;
|
|
SET vDone = FALSE;
|
|
FETCH vDates INTO vShipment, vWarehouseFk;
|
|
|
|
IF vDone THEN
|
|
LEAVE lDates;
|
|
END IF;
|
|
|
|
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 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 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 hedera.orderRow oro ON oro.itemFk = i.id
|
|
JOIN hedera.`order` o ON o.id = oro.orderFk
|
|
WHERE oro.orderFk = vSelf
|
|
),
|
|
tItemPackingTypeTicket AS (
|
|
SELECT t.id,
|
|
GROUP_CONCAT(
|
|
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'
|
|
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 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,
|
|
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;
|
|
|
|
-- Añade los movimientos y sus componentes
|
|
OPEN vRows;
|
|
lRows: LOOP
|
|
SET vSaleFk = NULL;
|
|
SET vDone = FALSE;
|
|
FETCH vRows INTO vRowFk, vItemFk, vConcept, vAmount, vPrice;
|
|
|
|
IF vDone THEN
|
|
LEAVE lRows;
|
|
END IF;
|
|
|
|
SELECT s.id INTO vSaleFk
|
|
FROM vn.sale s
|
|
WHERE ticketFk = vTicketFk
|
|
AND price = vPrice
|
|
AND itemFk = vItemFk
|
|
AND discount = 0
|
|
LIMIT 1;
|
|
|
|
IF vSaleFk THEN
|
|
UPDATE vn.sale
|
|
SET quantity = quantity + vAmount,
|
|
originalQuantity = quantity
|
|
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 = vRowFk;
|
|
|
|
INSERT INTO vn.sale
|
|
SET itemFk = vItemFk,
|
|
ticketFk = vTicketFk,
|
|
concept = vConcept,
|
|
quantity = vAmount,
|
|
price = vPrice,
|
|
priceFixed = vPriceFixed,
|
|
isPriceFixed = TRUE;
|
|
|
|
SET vSaleFk = LAST_INSERT_ID();
|
|
|
|
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 = vRowFk
|
|
GROUP BY vSaleFk, rc.componentFk;
|
|
END IF;
|
|
|
|
UPDATE orderRow
|
|
SET saleFk = vSaleFk
|
|
WHERE id = vRowFk;
|
|
END LOOP;
|
|
CLOSE vRows;
|
|
END LOOP;
|
|
CLOSE vDates;
|
|
|
|
UPDATE `order`
|
|
SET confirmed = TRUE,
|
|
confirm_date = util.VN_NOW()
|
|
WHERE id = vSelf;
|
|
|
|
COMMIT;
|
|
END$$
|
|
DELIMITER ;
|