245 lines
5.5 KiB
SQL
245 lines
5.5 KiB
SQL
USE `hedera`;
|
|
DROP procedure IF EXISTS `order_confirmWithUser`;
|
|
|
|
DELIMITER $$
|
|
USE `hedera`$$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `order_confirmWithUser`(IN `vOrder` INT, IN `vUserId` INT)
|
|
BEGIN
|
|
/**
|
|
* Confirms an order, creating each of its tickets on the corresponding
|
|
* date, store and user.
|
|
*
|
|
* @param vOrder The order identifier
|
|
* @param vUser The user identifier
|
|
*/
|
|
DECLARE vOk BOOL;
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
DECLARE vWarehouse INT;
|
|
DECLARE vShipment DATETIME;
|
|
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 vDelivery DATE;
|
|
DECLARE vAddress INT;
|
|
DECLARE vIsConfirmed BOOL;
|
|
DECLARE vClientId INT;
|
|
DECLARE vCompanyId INT;
|
|
DECLARE vAgencyModeId INT;
|
|
|
|
DECLARE TICKET_FREE INT DEFAULT 2;
|
|
|
|
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 = vOrder 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
|
|
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 = vOrder
|
|
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,
|
|
o.confirmed, a.clientFk, o.company_id, o.agency_id
|
|
INTO vDelivery, vAddress, vNotes,
|
|
vIsConfirmed, vClientId, vCompanyId, vAgencyModeId
|
|
FROM hedera.`order` o
|
|
JOIN vn.address a ON a.id = o.address_id
|
|
WHERE o.id = vOrder;
|
|
|
|
-- Comprueba que el pedido no está confirmado
|
|
|
|
IF vIsConfirmed THEN
|
|
CALL util.throw ('ORDER_ALREADY_CONFIRMED');
|
|
END IF;
|
|
|
|
-- Comprueba que el pedido no está vacío
|
|
|
|
SELECT COUNT(*) > 0 INTO vOk
|
|
FROM order_row WHERE order_id = vOrder AND amount > 0;
|
|
|
|
IF !vOk THEN
|
|
CALL util.throw ('ORDER_EMPTY');
|
|
END IF;
|
|
|
|
-- Carga las fechas de salida de cada almacén
|
|
|
|
CALL vn.zone_getShippedWarehouse (vDelivery, vAddress, vAgencyModeId);
|
|
|
|
-- Trabajador que realiza la acción
|
|
|
|
IF vUserId IS NULL THEN
|
|
SELECT employeeFk INTO vUserId FROM orderConfig;
|
|
END IF;
|
|
|
|
-- Crea los tickets del pedido
|
|
|
|
START TRANSACTION;
|
|
|
|
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
|
|
|
|
SELECT t.id INTO vTicket
|
|
FROM vn.ticket t
|
|
LEFT JOIN vn.ticketState tls on tls.ticket = t.id
|
|
JOIN `order` o
|
|
ON o.address_id = t.addressFk
|
|
AND vWarehouse = t.warehouseFk
|
|
AND o.agency_id = t.agencyModeFk
|
|
AND o.date_send = t.landed
|
|
AND vShipment = DATE(t.shipped)
|
|
WHERE o.id = vOrder
|
|
AND t.invoiceOutFk IS NULL
|
|
AND IFNULL(tls.alertLevel,0) = 0
|
|
LIMIT 1;
|
|
|
|
-- Crea el ticket en el caso de no existir uno adecuado
|
|
|
|
IF vTicket IS NULL
|
|
THEN
|
|
CALL vn.ticketCreateWithUser(
|
|
vClientId,
|
|
IFNULL(vShipment, CURDATE()),
|
|
vWarehouse,
|
|
vCompanyId,
|
|
vAddress,
|
|
vAgencyModeId,
|
|
NULL,
|
|
vDelivery,
|
|
vUserId,
|
|
vTicket
|
|
);
|
|
ELSE
|
|
INSERT INTO vncontrol.inter
|
|
SET Id_Ticket = vTicket,
|
|
Id_Trabajador = vUserId,
|
|
state_id = TICKET_FREE;
|
|
END IF;
|
|
|
|
INSERT IGNORE INTO vn.orderTicket
|
|
SET orderFk = vOrder,
|
|
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;
|
|
|
|
IF vDone THEN
|
|
LEAVE lRows;
|
|
END IF;
|
|
|
|
INSERT INTO vn.sale
|
|
SET
|
|
itemFk = vItem,
|
|
ticketFk = vTicket,
|
|
concept = vConcept,
|
|
quantity = vAmount,
|
|
price = vPrice,
|
|
priceFixed = 0,
|
|
isPriceFixed = TRUE;
|
|
|
|
SET vSale = LAST_INSERT_ID();
|
|
|
|
INSERT INTO vn.saleComponent
|
|
(saleFk, componentFk, `value`)
|
|
SELECT vSale, cm.component_id, cm.price
|
|
FROM order_component cm
|
|
JOIN bi.tarifa_componentes tc
|
|
ON tc.Id_Componente = cm.component_id
|
|
WHERE cm.order_row_id = vRowId
|
|
GROUP BY vSale, cm.component_id;
|
|
|
|
UPDATE order_row SET Id_Movimiento = vSale
|
|
WHERE id = vRowId;
|
|
|
|
END LOOP;
|
|
|
|
CLOSE cRows;
|
|
|
|
-- Fija el coste
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tComponents;
|
|
CREATE TEMPORARY TABLE tComponents
|
|
(INDEX (saleFk))
|
|
ENGINE = MEMORY
|
|
SELECT SUM(sc.`value`) valueSum, sc.saleFk
|
|
FROM vn.saleComponent sc
|
|
JOIN bi.tarifa_componentes tc ON tc.Id_Componente = sc.componentFk
|
|
JOIN bi.tarifa_componentes_series tcs
|
|
ON tcs.tarifa_componentes_series_id = tc.tarifa_componentes_series_id
|
|
AND tcs.base
|
|
JOIN vn.sale s
|
|
ON s.id = sc.saleFk
|
|
WHERE s.ticketFk = vTicket
|
|
GROUP BY sc.saleFk;
|
|
|
|
UPDATE vn.sale s
|
|
JOIN tComponents mc ON mc.saleFk = s.id
|
|
SET s.priceFixed = valueSum;
|
|
|
|
DROP TEMPORARY TABLE tComponents;
|
|
END LOOP;
|
|
|
|
CLOSE cDates;
|
|
|
|
DELETE FROM basketOrder WHERE orderFk = vOrder;
|
|
UPDATE `order` SET confirmed = TRUE, confirm_date = NOW()
|
|
WHERE id = vOrder;
|
|
|
|
COMMIT;
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
|