Tarea #745 ticket.basic-data al step-two
This commit is contained in:
parent
4d0adb38ff
commit
930c1d4eb1
|
@ -0,0 +1,134 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `ticketComponentPreview`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `ticketComponentPreview`(
|
||||||
|
vTicketFk INT,
|
||||||
|
vLanded DATE,
|
||||||
|
vAddressFk INT,
|
||||||
|
vAgencyModeFk INT,
|
||||||
|
vWarehouseFk SMALLINT)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Devuelve un listado previo de
|
||||||
|
* componentes para un ticket
|
||||||
|
*
|
||||||
|
* @param vTicketFk Id del ticket
|
||||||
|
* @param vLanded Fecha de recepcion
|
||||||
|
* @param vAddressFk Id del consignatario
|
||||||
|
* @param vAgencyModeFk Id del modo de agencia
|
||||||
|
* @param vWarehouseFk Id del almacén
|
||||||
|
*/
|
||||||
|
|
||||||
|
DECLARE vAgencyFk INT;
|
||||||
|
DECLARE vShipped DATE;
|
||||||
|
DECLARE vBuyOrderItem INT DEFAULT 100;
|
||||||
|
|
||||||
|
DECLARE vHasDataChanged BOOL DEFAULT FALSE;
|
||||||
|
DECLARE vHasAddressChanged BOOL;
|
||||||
|
DECLARE vHasAgencyModeChanged BOOL DEFAULT FALSE;
|
||||||
|
DECLARE vHasWarehouseChanged BOOL DEFAULT FALSE;
|
||||||
|
|
||||||
|
DECLARE vAddressTypeRateFk INT DEFAULT NULL;
|
||||||
|
DECLARE vAgencyModeTypeRateFk INT DEFAULT NULL;
|
||||||
|
|
||||||
|
DECLARE vHasChangeAll BOOL DEFAULT FALSE;
|
||||||
|
|
||||||
|
SELECT DATE(landed) <> vLanded,
|
||||||
|
addressFk <> vAddressFk,
|
||||||
|
agencyModeFk <> vAgencyModeFk,
|
||||||
|
warehouseFk <> vWarehouseFk
|
||||||
|
INTO
|
||||||
|
vHasDataChanged,
|
||||||
|
vHasAddressChanged,
|
||||||
|
vHasAgencyModeChanged,
|
||||||
|
vHasWarehouseChanged
|
||||||
|
FROM vn.ticket t
|
||||||
|
WHERE t.id = vTicketFk;
|
||||||
|
/*SELECT vHasDataChanged,
|
||||||
|
vHasAddressChanged,
|
||||||
|
vHasAgencyModeChanged,
|
||||||
|
vHasWarehouseChanged;
|
||||||
|
*/
|
||||||
|
IF vHasDataChanged OR vHasWarehouseChanged THEN
|
||||||
|
SET vHasChangeAll = TRUE;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF vHasAddressChanged THEN
|
||||||
|
SET vAddressTypeRateFk = 5;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF vHasAgencyModeChanged THEN
|
||||||
|
SET vAgencyModeTypeRateFk = 6;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
SELECT agencyFk INTO vAgencyFk
|
||||||
|
FROM agencyMode
|
||||||
|
WHERE id = vAgencyModeFk;
|
||||||
|
|
||||||
|
CALL agencyHourGetShipped(vLanded, vAddressFk, vAgencyFk);
|
||||||
|
|
||||||
|
SELECT shipped INTO vShipped
|
||||||
|
FROM tmp.agencyHourGetShipped
|
||||||
|
WHERE warehouseFk = vWarehouseFK;
|
||||||
|
|
||||||
|
CALL buyUltimate(vWarehouseFK, vShipped);
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot;
|
||||||
|
CREATE TEMPORARY TABLE tmp.ticketLot ENGINE = MEMORY (
|
||||||
|
SELECT
|
||||||
|
vWarehouseFK AS warehouseFk,
|
||||||
|
NULL AS available,
|
||||||
|
s.itemFk,
|
||||||
|
bu.buyFk
|
||||||
|
FROM sale s
|
||||||
|
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
|
||||||
|
WHERE s.ticketFk = vTicketFk
|
||||||
|
AND s.itemFk != vBuyOrderItem
|
||||||
|
GROUP BY bu.warehouseFk, bu.itemFk);
|
||||||
|
|
||||||
|
CALL ticketComponentCalculate(vAddressFk, vAgencyModeFk);
|
||||||
|
|
||||||
|
/*SELECT *,vHasChangeAll,cr.isRenewable = FALSE,vHasChangeAll,
|
||||||
|
NOT (cr.componentTypeRate <=> vAddressTypeRateFk),NOT (cr.componentTypeRate <=> vAgencyModeTypeRateFk),
|
||||||
|
NOT (cr.componentTypeRate <=> vAddressTypeRateFk) OR NOT (cr.componentTypeRate <=> vAgencyModeTypeRateFk)
|
||||||
|
FROM saleComponent sc
|
||||||
|
JOIN sale s ON s.id = sc.saleFk
|
||||||
|
JOIN ticket t ON t.id = s.ticketFk
|
||||||
|
JOIN componentRate cr ON cr.id = sc.componentFk
|
||||||
|
WHERE s.ticketFk = vTicketFk
|
||||||
|
AND (cr.isRenewable = FALSE
|
||||||
|
OR
|
||||||
|
(NOT vHasChangeAll
|
||||||
|
AND (NOT (cr.componentTypeRate <=> vAddressTypeRateFk
|
||||||
|
OR cr.componentTypeRate <=> vAgencyModeTypeRateFk))));*/
|
||||||
|
/*SELECT * FROM tmp.ticketComponent;*/
|
||||||
|
-- Inserta los componentes que NO seran modificados
|
||||||
|
REPLACE INTO tmp.ticketComponent (warehouseFk, itemFk, componentFk, cost)
|
||||||
|
SELECT t.warehouseFk, s.itemFk, sc.componentFk, sc.value
|
||||||
|
FROM saleComponent sc
|
||||||
|
JOIN sale s ON s.id = sc.saleFk
|
||||||
|
JOIN ticket t ON t.id = s.ticketFk
|
||||||
|
JOIN componentRate cr ON cr.id = sc.componentFk
|
||||||
|
WHERE s.ticketFk = vTicketFk
|
||||||
|
AND (cr.isRenewable = FALSE
|
||||||
|
OR
|
||||||
|
(NOT vHasChangeAll
|
||||||
|
AND (NOT (cr.componentTypeRate <=> vAddressTypeRateFk
|
||||||
|
OR cr.componentTypeRate <=> vAgencyModeTypeRateFk))));
|
||||||
|
/*SELECT * FROM tmp.ticketComponent;*/
|
||||||
|
SET @shipped = vShipped;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE
|
||||||
|
tmp.agencyHourGetShipped,
|
||||||
|
tmp.buyUltimate,
|
||||||
|
tmp.ticketLot;
|
||||||
|
|
||||||
|
IF IFNULL(vShipped, CURDATE() - 1) < CURDATE() THEN
|
||||||
|
CALL util.throw('NO_AGENCY_AVAILABLE');
|
||||||
|
END IF;
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
||||||
|
|
|
@ -0,0 +1,54 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `ticketComponentPriceDifference`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `ticketComponentPriceDifference`(
|
||||||
|
vTicketFk INT,
|
||||||
|
vLanded DATE,
|
||||||
|
vAddressFk INT,
|
||||||
|
vAgencyModeFk INT,
|
||||||
|
vWarehouseFk INT)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Devuelve las diferencias de precio
|
||||||
|
* de los movimientos de un ticket.
|
||||||
|
*
|
||||||
|
* @param vTicketFk Id del ticket
|
||||||
|
* @param vLanded Fecha de recepcion
|
||||||
|
* @param vAddressFk Id del consignatario
|
||||||
|
* @param vAgencyModeFk Id del modo de agencia
|
||||||
|
* @param vWarehouseFk Id del almacén
|
||||||
|
*/
|
||||||
|
CALL vn.ticketComponentPreview(vTicketFk, vLanded, vAddressFk, vAgencyModeFk, vWarehouseFk);
|
||||||
|
|
||||||
|
SELECT s.itemFk,
|
||||||
|
i.name,
|
||||||
|
i.size,
|
||||||
|
i.category,
|
||||||
|
IFNULL(s.quantity, 0) AS quantity,
|
||||||
|
IFNULL(s.price, 0) AS price,
|
||||||
|
ROUND(SUM(tc.cost), 2) AS newPrice,
|
||||||
|
s.quantity * (s.price - ROUND(SUM(tc.cost), 2)) difference,
|
||||||
|
s.id AS saleFk
|
||||||
|
FROM sale s
|
||||||
|
JOIN item i ON i.id = s.itemFk
|
||||||
|
JOIN ticket t ON t.id = s.ticketFk
|
||||||
|
LEFT JOIN tmp.ticketComponent tc ON tc.itemFk = s.itemFk
|
||||||
|
AND tc.warehouseFk = t.warehouseFk
|
||||||
|
LEFT JOIN saleComponent sc ON sc.saleFk = s.id
|
||||||
|
AND sc.componentFk = tc.componentFk
|
||||||
|
LEFT JOIN componentRate cr ON cr.id = tc.componentFk
|
||||||
|
WHERE
|
||||||
|
t.id = vTicketFk
|
||||||
|
AND IF(sc.componentFk IS NULL
|
||||||
|
AND cr.classRate IS NOT NULL, FALSE, TRUE)
|
||||||
|
GROUP BY s.id ORDER BY s.id;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE
|
||||||
|
tmp.ticketComponent,
|
||||||
|
tmp.ticketComponentPrice;
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
||||||
|
|
Loading…
Reference in New Issue