|
|
|
@ -0,0 +1,589 @@
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_calculateComponent`(vSelf INT, vOption VARCHAR(25))
|
|
|
|
|
proc: BEGIN
|
|
|
|
|
/**
|
|
|
|
|
* Crea tabla temporal para vn.sale_recalcComponent() para recalcular los componentes
|
|
|
|
|
*
|
|
|
|
|
* @param vSelf Id de la venta
|
|
|
|
|
* @param vOption indica en que componente pone el descuadre, NULL en casos habituales
|
|
|
|
|
*/
|
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.recalculateSales
|
|
|
|
|
SELECT s.id
|
|
|
|
|
FROM sale s
|
|
|
|
|
WHERE s.id = vSelf;
|
|
|
|
|
|
|
|
|
|
CALL sale_recalcComponent(vOption);
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.recalculateSales;
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_checkNoComponents`(vCreatedFrom DATETIME, vCreatedTo DATETIME)
|
|
|
|
|
BEGIN
|
|
|
|
|
/**
|
|
|
|
|
* Comprueba que las ventas creadas entre un rango de fechas tienen componentes
|
|
|
|
|
*
|
|
|
|
|
* @param vCreatedFrom inicio del rango
|
|
|
|
|
* @param vCreatedTo fin del rango
|
|
|
|
|
*/
|
|
|
|
|
DECLARE v_done BOOL DEFAULT FALSE;
|
|
|
|
|
DECLARE vSaleFk INTEGER;
|
|
|
|
|
DECLARE vTicketFk INTEGER;
|
|
|
|
|
DECLARE vConcept VARCHAR(50);
|
|
|
|
|
DECLARE vCur CURSOR FOR
|
|
|
|
|
SELECT s.id
|
|
|
|
|
FROM sale s
|
|
|
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
|
|
|
JOIN item i ON i.id = s.itemFk
|
|
|
|
|
JOIN itemType tp ON tp.id = i.typeFk
|
|
|
|
|
JOIN itemCategory ic ON ic.id = tp.categoryFk
|
|
|
|
|
LEFT JOIN tmp.coste c ON c.id = s.id
|
|
|
|
|
WHERE s.created >= vCreatedFrom AND s.created <= vCreatedTo
|
|
|
|
|
AND c.id IS NULL
|
|
|
|
|
AND t.agencyModeFk IS NOT NULL
|
|
|
|
|
AND t.isDeleted IS FALSE
|
|
|
|
|
AND t.warehouseFk = 60
|
|
|
|
|
AND ic.merchandise != FALSE
|
|
|
|
|
GROUP BY s.id;
|
|
|
|
|
|
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
|
|
|
|
SET v_done = TRUE;
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.coste;
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.coste;
|
|
|
|
|
CREATE TEMPORARY TABLE tmp.coste
|
|
|
|
|
(PRIMARY KEY (id)) ENGINE = MEMORY
|
|
|
|
|
SELECT s.id
|
|
|
|
|
FROM sale s
|
|
|
|
|
JOIN item i ON i.id = s.itemFk
|
|
|
|
|
JOIN itemType tp ON tp.id = i.typeFk
|
|
|
|
|
JOIN itemCategory ic ON ic.id = tp.categoryFk
|
|
|
|
|
JOIN saleComponent sc ON sc.saleFk = s.id
|
|
|
|
|
JOIN component c ON c.id = sc.componentFk
|
|
|
|
|
JOIN componentType ct ON ct.id = c.typeFk AND ct.id = 6
|
|
|
|
|
WHERE s.created >= vCreatedFrom
|
|
|
|
|
AND ic.merchandise != FALSE;
|
|
|
|
|
|
|
|
|
|
OPEN vCur;
|
|
|
|
|
|
|
|
|
|
l: LOOP
|
|
|
|
|
SET v_done = FALSE;
|
|
|
|
|
FETCH vCur INTO vSaleFk;
|
|
|
|
|
|
|
|
|
|
IF v_done THEN
|
|
|
|
|
LEAVE l;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
SELECT ticketFk, concept
|
|
|
|
|
INTO vTicketFk, vConcept
|
|
|
|
|
FROM sale
|
|
|
|
|
WHERE id = vSaleFk;
|
|
|
|
|
|
|
|
|
|
CALL sale_calculateComponent(vSaleFk, 'renewPrices');
|
|
|
|
|
END LOOP;
|
|
|
|
|
|
|
|
|
|
CLOSE vCur;
|
|
|
|
|
DROP TEMPORARY TABLE tmp.coste;
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_recalcComponent`(vOption VARCHAR(25))
|
|
|
|
|
proc: BEGIN
|
|
|
|
|
/**
|
|
|
|
|
* Este procedimiento recalcula los componentes de un conjunto de sales,
|
|
|
|
|
* eliminando los componentes existentes e insertandolos de nuevo
|
|
|
|
|
*
|
|
|
|
|
* @param vOption si no se quiere forzar llamar con NULL
|
|
|
|
|
* @table tmp.recalculateSales (id)
|
|
|
|
|
*/
|
|
|
|
|
DECLARE vShipped DATE;
|
|
|
|
|
DECLARE vWarehouseFk SMALLINT;
|
|
|
|
|
DECLARE vAgencyModeFk INT;
|
|
|
|
|
DECLARE vAddressFk INT;
|
|
|
|
|
DECLARE vTicketFk INT;
|
|
|
|
|
DECLARE vLanded DATE;
|
|
|
|
|
DECLARE vIsEditable BOOLEAN;
|
|
|
|
|
DECLARE vZoneFk INTEGER;
|
|
|
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
|
|
|
|
|
|
|
|
DECLARE vCur CURSOR FOR
|
|
|
|
|
SELECT DISTINCT s.ticketFk
|
|
|
|
|
FROM tmp.recalculateSales rs
|
|
|
|
|
JOIN vn.sale s ON s.id = rs.id;
|
|
|
|
|
|
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
|
|
|
|
|
|
OPEN vCur;
|
|
|
|
|
|
|
|
|
|
l: LOOP
|
|
|
|
|
SET vDone = FALSE;
|
|
|
|
|
FETCH vCur INTO vTicketFk;
|
|
|
|
|
|
|
|
|
|
IF vDone THEN
|
|
|
|
|
LEAVE l;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
SELECT (hasToRecalcPrice OR ts.alertLevel IS NULL) AND t.refFk IS NULL,
|
|
|
|
|
t.zoneFk,
|
|
|
|
|
t.warehouseFk,
|
|
|
|
|
t.shipped,
|
|
|
|
|
t.addressFk,
|
|
|
|
|
t.agencyModeFk,
|
|
|
|
|
t.landed
|
|
|
|
|
INTO vIsEditable,
|
|
|
|
|
vZoneFk,
|
|
|
|
|
vWarehouseFk,
|
|
|
|
|
vShipped,
|
|
|
|
|
vAddressFk,
|
|
|
|
|
vAgencyModeFk,
|
|
|
|
|
vLanded
|
|
|
|
|
FROM ticket t
|
|
|
|
|
LEFT JOIN ticketState ts ON t.id = ts.ticket
|
|
|
|
|
LEFT JOIN alertLevel al ON al.id = ts.alertLevel
|
|
|
|
|
WHERE t.id = vTicketFk;
|
|
|
|
|
|
|
|
|
|
CALL zone_getLanded(vShipped, vAddressFk, vAgencyModeFk, vWarehouseFk, TRUE);
|
|
|
|
|
|
|
|
|
|
IF NOT EXISTS (SELECT TRUE FROM tmp.zoneGetLanded LIMIT 1) THEN
|
|
|
|
|
CALL util.throw(CONCAT('There is no zone for these parameters ', vTicketFk));
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
IF vLanded IS NULL OR vZoneFk IS NULL THEN
|
|
|
|
|
|
|
|
|
|
UPDATE ticket t
|
|
|
|
|
SET t.landed = (SELECT landed FROM tmp.zoneGetLanded LIMIT 1)
|
|
|
|
|
WHERE t.id = vTicketFk AND t.landed IS NULL;
|
|
|
|
|
|
|
|
|
|
IF vZoneFk IS NULL THEN
|
|
|
|
|
SELECT zoneFk INTO vZoneFk FROM tmp.zoneGetLanded LIMIT 1;
|
|
|
|
|
UPDATE ticket t
|
|
|
|
|
SET t.zoneFk = vZoneFk
|
|
|
|
|
WHERE t.id = vTicketFk AND t.zoneFk IS NULL;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.zoneGetLanded;
|
|
|
|
|
|
|
|
|
|
-- rellena la tabla buyUltimate con la ultima compra
|
|
|
|
|
CALL buyUltimate (vWarehouseFk, vShipped);
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
|
|
|
|
(PRIMARY KEY (saleFk)) ENGINE = MEMORY
|
|
|
|
|
SELECT s.id saleFk, vWarehouseFk warehouseFk
|
|
|
|
|
FROM sale s
|
|
|
|
|
JOIN tmp.recalculateSales rs ON s.id = rs.id
|
|
|
|
|
WHERE s.ticketFk = vTicketFk;
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketLot
|
|
|
|
|
SELECT vWarehouseFk warehouseFk, NULL available, s.itemFk, bu.buyFk, vZoneFk zoneFk
|
|
|
|
|
FROM sale s
|
|
|
|
|
JOIN tmp.recalculateSales rs ON s.id = rs.id
|
|
|
|
|
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
|
|
|
|
|
WHERE s.ticketFk = vTicketFk
|
|
|
|
|
GROUP BY s.itemFk;
|
|
|
|
|
|
|
|
|
|
CALL catalog_componentPrepare();
|
|
|
|
|
CALL catalog_componentCalculate(vZoneFk, vAddressFk, vShipped, vWarehouseFk);
|
|
|
|
|
|
|
|
|
|
IF vOption IS NULL THEN
|
|
|
|
|
SET vOption = IF(vIsEditable, 'renewPrices', 'imbalance');
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
CALL ticketComponentUpdateSale(vOption);
|
|
|
|
|
CALL catalog_componentPurge();
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.buyUltimate;
|
|
|
|
|
DROP TEMPORARY TABLE tmp.sale;
|
|
|
|
|
|
|
|
|
|
END LOOP;
|
|
|
|
|
CLOSE vCur;
|
|
|
|
|
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticketCalculateClon`(IN vTicketNew INT, vTicketOld INT)
|
|
|
|
|
BEGIN
|
|
|
|
|
/*
|
|
|
|
|
* Recalcula los componentes un ticket clonado,
|
|
|
|
|
* las lineas a precio cero fuerza para que tengan precio, el resto lo respeta
|
|
|
|
|
* @param vTicketNew nuevo ticket clonado
|
|
|
|
|
* @param vTicketOld icket original, a partir del qual se clonara el nuevo
|
|
|
|
|
*/
|
|
|
|
|
|
|
|
|
|
REPLACE INTO orderTicket(orderFk,ticketFk)
|
|
|
|
|
SELECT orderFk, vTicketNew
|
|
|
|
|
FROM orderTicket
|
|
|
|
|
WHERE ticketFk = vTicketOld;
|
|
|
|
|
|
|
|
|
|
-- Bionizamos lineas con Preu = 0
|
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.recalculateSales
|
|
|
|
|
(PRIMARY KEY (id)) ENGINE = MEMORY
|
|
|
|
|
SELECT id
|
|
|
|
|
FROM sale
|
|
|
|
|
WHERE ticketFk = vTicketNew AND price = 0;
|
|
|
|
|
|
|
|
|
|
CALL sale_recalcComponent('renewPrices');
|
|
|
|
|
|
|
|
|
|
-- Bionizamos lineas con Preu > 0
|
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.recalculateSales
|
|
|
|
|
(PRIMARY KEY (id)) ENGINE = MEMORY
|
|
|
|
|
SELECT id
|
|
|
|
|
FROM sale
|
|
|
|
|
WHERE ticketFk = vTicketNew AND price > 0;
|
|
|
|
|
|
|
|
|
|
CALL sale_recalcComponent('imbalance');
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.recalculateSales;
|
|
|
|
|
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticketComponentUpdate`(
|
|
|
|
|
vTicketFk INT,
|
|
|
|
|
vClientFk INT,
|
|
|
|
|
vAgencyModeFk INT,
|
|
|
|
|
vAddressFk INT,
|
|
|
|
|
vWarehouseFk TINYINT,
|
|
|
|
|
vCompanyFk SMALLINT,
|
|
|
|
|
vShipped DATETIME,
|
|
|
|
|
vLanded DATE,
|
|
|
|
|
vIsDeleted BOOLEAN,
|
|
|
|
|
vHasToBeUnrouted BOOLEAN,
|
|
|
|
|
vOption VARCHAR(25))
|
|
|
|
|
BEGIN
|
|
|
|
|
|
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
|
|
|
BEGIN
|
|
|
|
|
ROLLBACK;
|
|
|
|
|
RESIGNAL;
|
|
|
|
|
END;
|
|
|
|
|
|
|
|
|
|
START TRANSACTION;
|
|
|
|
|
|
|
|
|
|
IF (SELECT addressFk FROM ticket WHERE id = vTicketFk) <> vAddressFk THEN
|
|
|
|
|
|
|
|
|
|
UPDATE ticket t
|
|
|
|
|
JOIN address a ON a.id = vAddressFk
|
|
|
|
|
SET t.nickname = a.nickname
|
|
|
|
|
WHERE t.id = vTicketFk;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
UPDATE ticket t
|
|
|
|
|
SET
|
|
|
|
|
t.clientFk = vClientFk,
|
|
|
|
|
t.agencyModeFk = vAgencyModeFk,
|
|
|
|
|
t.addressFk = vAddressFk,
|
|
|
|
|
t.warehouseFk = vWarehouseFk,
|
|
|
|
|
t.companyFk = vCompanyFk,
|
|
|
|
|
t.landed = vLanded,
|
|
|
|
|
t.shipped = vShipped,
|
|
|
|
|
t.isDeleted = vIsDeleted
|
|
|
|
|
WHERE
|
|
|
|
|
t.id = vTicketFk;
|
|
|
|
|
|
|
|
|
|
IF vHasToBeUnrouted THEN
|
|
|
|
|
UPDATE ticket t SET t.routeFk = NULL
|
|
|
|
|
WHERE t.id = vTicketFk;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.sale;
|
|
|
|
|
CREATE TEMPORARY TABLE tmp.sale
|
|
|
|
|
(PRIMARY KEY (saleFk))
|
|
|
|
|
ENGINE = MEMORY
|
|
|
|
|
SELECT id AS saleFk, vWarehouseFk warehouseFk
|
|
|
|
|
FROM sale s WHERE s.ticketFk = vTicketFk;
|
|
|
|
|
|
|
|
|
|
CALL ticketComponentUpdateSale (vOption);
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.sale;
|
|
|
|
|
COMMIT;
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticketComponentUpdateSale`(vCode VARCHAR(25))
|
|
|
|
|
BEGIN
|
|
|
|
|
/**
|
|
|
|
|
* A partir de la tabla tmp.sale, crea los Movimientos_componentes
|
|
|
|
|
* y modifica el campo Preu de la tabla Movimientos
|
|
|
|
|
*
|
|
|
|
|
* @param i_option integer tipo de actualizacion
|
|
|
|
|
* @param table tmp.sale tabla memory con el campo saleFk, warehouseFk
|
|
|
|
|
**/
|
|
|
|
|
DECLARE vComponentFk INT;
|
|
|
|
|
|
|
|
|
|
IF vCode <> 'renewPrices' THEN
|
|
|
|
|
SELECT id INTO vComponentFk FROM component WHERE `code` = vCode;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
DELETE sc.*
|
|
|
|
|
FROM tmp.sale tmps
|
|
|
|
|
JOIN saleComponent sc ON sc.saleFk = tmps.saleFk
|
|
|
|
|
JOIN `component` c ON c.id = sc.componentFk
|
|
|
|
|
WHERE c.isRenewable;
|
|
|
|
|
|
|
|
|
|
REPLACE INTO saleComponent(saleFk, componentFk, value)
|
|
|
|
|
SELECT s.id, tc.componentFk, tc.cost
|
|
|
|
|
FROM sale s
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = s.id
|
|
|
|
|
JOIN tmp.ticketComponent tc ON tc.itemFk = s.itemFk AND tc.warehouseFk = tmps.warehouseFk
|
|
|
|
|
LEFT JOIN saleComponent sc ON sc.saleFk = s.id
|
|
|
|
|
AND sc.componentFk = tc.componentFk
|
|
|
|
|
LEFT JOIN `component` c ON c.id = tc.componentFk
|
|
|
|
|
WHERE IF(sc.componentFk IS NULL AND NOT c.isRenewable, FALSE, TRUE);
|
|
|
|
|
|
|
|
|
|
-- Añadir componente venta por paquete
|
|
|
|
|
REPLACE INTO saleComponent(saleFk, componentFk, value)
|
|
|
|
|
SELECT t.id, t.componentFk, t.cost
|
|
|
|
|
FROM (
|
|
|
|
|
SELECT s.id, tc.componentFk, tc.cost, MOD(s.quantity, b.packing) as resto
|
|
|
|
|
FROM vn.sale s
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = s.id
|
|
|
|
|
JOIN cache.last_buy lb ON lb.item_id = s.itemFk AND tmps.warehouseFk = lb.warehouse_id
|
|
|
|
|
JOIN vn.buy b ON b.id = buy_id
|
|
|
|
|
JOIN tmp.ticketComponent tc ON tc.itemFk = s.itemFk AND tc.warehouseFk = tmps.warehouseFk
|
|
|
|
|
JOIN `component` c ON c.id = tc.componentFk AND c.code = 'salePerPackage'
|
|
|
|
|
LEFT JOIN (
|
|
|
|
|
SELECT s.id
|
|
|
|
|
FROM vn.sale s
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = s.id
|
|
|
|
|
JOIN tmp.ticketComponent tc ON tc.itemFk = s.itemFk AND tc.warehouseFk = tmps.warehouseFk
|
|
|
|
|
JOIN saleComponent sc ON sc.saleFk = s.id AND sc.componentFk = tc.componentFk
|
|
|
|
|
JOIN `component` c ON c.id = sc.componentFk AND c.code = 'lastUnitsDiscount'
|
|
|
|
|
) tp ON tp.id = s.id
|
|
|
|
|
WHERE tp.id IS NULL
|
|
|
|
|
HAVING resto <> 0) t;
|
|
|
|
|
|
|
|
|
|
IF vCode <> 'renewPrices' THEN
|
|
|
|
|
REPLACE INTO saleComponent(saleFk, componentFk, value)
|
|
|
|
|
SELECT s.id, vComponentFk, ROUND((s.price * (100 - s.discount) / 100) - SUM(sc.value), 3) dif
|
|
|
|
|
FROM sale s
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = s.id
|
|
|
|
|
LEFT JOIN saleComponent sc ON sc.saleFk = s.id
|
|
|
|
|
WHERE sc.saleFk <> vComponentFk
|
|
|
|
|
GROUP BY s.id
|
|
|
|
|
HAVING dif <> 0;
|
|
|
|
|
ELSE
|
|
|
|
|
UPDATE sale s
|
|
|
|
|
JOIN item i on i.id = s.itemFk
|
|
|
|
|
JOIN itemType it on it.id = i.typeFk
|
|
|
|
|
JOIN (SELECT SUM(sc.value) sumValue, sc.saleFk
|
|
|
|
|
FROM saleComponent sc
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = sc.saleFk
|
|
|
|
|
GROUP BY sc.saleFk) sc ON sc.saleFk = s.id
|
|
|
|
|
SET s.price = sumValue / ((100 - s.discount) / 100)
|
|
|
|
|
WHERE it.code != 'PRT' ;
|
|
|
|
|
|
|
|
|
|
REPLACE INTO saleComponent(saleFk, componentFk, value)
|
|
|
|
|
SELECT s.id, 21, ROUND((s.price * (100 - s.discount) / 100) - SUM(value), 3) saleValue
|
|
|
|
|
FROM sale s
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = s.id
|
|
|
|
|
LEFT JOIN saleComponent sc ON sc.saleFk = s.id
|
|
|
|
|
WHERE sc.componentFk != 21
|
|
|
|
|
GROUP BY s.id
|
|
|
|
|
HAVING ROUND(saleValue, 4) <> 0;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
UPDATE sale s
|
|
|
|
|
JOIN (
|
|
|
|
|
SELECT SUM(sc.value) sumValue, sc.saleFk
|
|
|
|
|
FROM saleComponent sc
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = sc.saleFk
|
|
|
|
|
JOIN `component` c ON c.id = sc.componentFk
|
|
|
|
|
JOIN componentType ct on ct.id = c.typeFk AND ct.isBase
|
|
|
|
|
GROUP BY sc.saleFk) sc ON sc.saleFk = s.id
|
|
|
|
|
SET s.priceFixed = sumValue, s.isPriceFixed = 1;
|
|
|
|
|
|
|
|
|
|
DELETE sc.*
|
|
|
|
|
FROM saleComponent sc
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = sc.saleFk
|
|
|
|
|
JOIN sale s on s.id = sc.saleFk
|
|
|
|
|
JOIN item i ON i.id = s.itemFk
|
|
|
|
|
JOIN itemType it ON it.id = i.typeFk
|
|
|
|
|
WHERE it.code = 'PRT';
|
|
|
|
|
|
|
|
|
|
INSERT INTO saleComponent(saleFk, componentFk, value)
|
|
|
|
|
SELECT s.id, 15, s.price
|
|
|
|
|
FROM sale s
|
|
|
|
|
JOIN tmp.sale tmps ON tmps.saleFk = s.id
|
|
|
|
|
JOIN item i ON i.id = s.itemFK
|
|
|
|
|
JOIN itemType it ON it.id = i.typeFk
|
|
|
|
|
WHERE it.code = 'PRT' AND s.price > 0;
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_checkNoComponents`(vShippedFrom DATETIME, vShippedTo DATETIME)
|
|
|
|
|
BEGIN
|
|
|
|
|
|
|
|
|
|
/**
|
|
|
|
|
* Comprueba que los tickets entre un rango de fechas tienen componentes
|
|
|
|
|
* y recalcula sus componentes
|
|
|
|
|
*
|
|
|
|
|
* @param vShippedFrom rango inicial de fecha
|
|
|
|
|
* @param vShippedTo rango final de fecha
|
|
|
|
|
*/
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.coste
|
|
|
|
|
(primary key (id)) ENGINE = MEMORY
|
|
|
|
|
SELECT s.id
|
|
|
|
|
FROM ticket t
|
|
|
|
|
JOIN sale s ON s.ticketFk = t.id
|
|
|
|
|
JOIN item i ON i.id = s.itemFk
|
|
|
|
|
JOIN itemType tp ON tp.id = i.typeFk
|
|
|
|
|
JOIN itemCategory ic ON ic.id = tp.categoryFk
|
|
|
|
|
JOIN saleComponent sc ON sc.saleFk = s.id
|
|
|
|
|
JOIN component c ON c.id = sc.componentFk
|
|
|
|
|
JOIN componentType ct ON ct.id = c.typeFk AND ct.id = 1
|
|
|
|
|
WHERE t.shipped BETWEEN vShippedFrom AND vShippedTo
|
|
|
|
|
AND ic.merchandise;
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.recalculateSales
|
|
|
|
|
(primary key (id)) ENGINE = MEMORY
|
|
|
|
|
SELECT DISTINCT s.id
|
|
|
|
|
FROM ticket t
|
|
|
|
|
JOIN sale s ON s.ticketFk = t.id
|
|
|
|
|
JOIN item i ON i.id = s.itemFk
|
|
|
|
|
JOIN itemType tp ON tp.id = i.typeFk
|
|
|
|
|
JOIN itemCategory ic ON ic.id = tp.categoryFk
|
|
|
|
|
LEFT JOIN tmp.coste c ON c.id = s.id
|
|
|
|
|
WHERE t.shipped >= vShippedFrom AND t.shipped <= vShippedTo
|
|
|
|
|
AND c.id IS NULL
|
|
|
|
|
AND ic.merchandise;
|
|
|
|
|
|
|
|
|
|
CALL sale_recalcComponent('renewPrices');
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.recalculateSales;
|
|
|
|
|
DROP TEMPORARY TABLE tmp.coste;
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_componentMakeUpdate`(
|
|
|
|
|
vTicketFk INT,
|
|
|
|
|
vClientFk INT,
|
|
|
|
|
vNickname VARCHAR(50),
|
|
|
|
|
vAgencyModeFk INT,
|
|
|
|
|
vAddressFk INT,
|
|
|
|
|
vZoneFk INT,
|
|
|
|
|
vWarehouseFk INT,
|
|
|
|
|
vCompanyFk INT,
|
|
|
|
|
vShipped DATETIME,
|
|
|
|
|
vLanded DATE,
|
|
|
|
|
vIsDeleted BOOLEAN,
|
|
|
|
|
vHasToBeUnrouted BOOLEAN,
|
|
|
|
|
vOption VARCHAR(25))
|
|
|
|
|
BEGIN
|
|
|
|
|
|
|
|
|
|
/**
|
|
|
|
|
* Modifica en el ticket los campos que se le pasan por parámetro
|
|
|
|
|
* y cambia sus componentes
|
|
|
|
|
*
|
|
|
|
|
* @param vTicketFk Id del ticket a modificar
|
|
|
|
|
* @param vClientFk nuevo cliente
|
|
|
|
|
* @param vNickname nuevo alias
|
|
|
|
|
* @param vAgencyModeFk nueva agencia
|
|
|
|
|
* @param vAddressFk nuevo consignatario
|
|
|
|
|
* @param vZoneFk nueva zona
|
|
|
|
|
* @param vWarehouseFk nuevo almacen
|
|
|
|
|
* @param vCompanyFk nueva empresa
|
|
|
|
|
* @param vShipped nueva fecha del envio de mercancia
|
|
|
|
|
* @param vLanded nueva fecha de recepcion de mercancia
|
|
|
|
|
* @param vIsDeleted si se borra el ticket
|
|
|
|
|
* @param vHasToBeUnrouted si se le elimina la ruta al ticket
|
|
|
|
|
* @param vOption opcion para el case del proc ticketComponentUpdateSale
|
|
|
|
|
*/
|
|
|
|
|
|
|
|
|
|
DECLARE vPrice DECIMAL(10,2);
|
|
|
|
|
DECLARE vBonus DECIMAL(10,2);
|
|
|
|
|
|
|
|
|
|
CALL ticket_componentPreview (vTicketFk, vLanded, vAddressFk, vZoneFk, vWarehouseFk);
|
|
|
|
|
|
|
|
|
|
IF (SELECT addressFk FROM ticket WHERE id = vTicketFk) <> vAddressFk THEN
|
|
|
|
|
|
|
|
|
|
UPDATE ticket t
|
|
|
|
|
JOIN address a ON a.id = vAddressFk
|
|
|
|
|
SET t.nickname = a.nickname
|
|
|
|
|
WHERE t.id = vTicketFk;
|
|
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
CALL zone_getShipped(vLanded, vAddressFk, vAgencyModeFk, TRUE);
|
|
|
|
|
|
|
|
|
|
SELECT zoneFk, price, bonus INTO vZoneFk, vPrice, vBonus
|
|
|
|
|
FROM tmp.zoneGetShipped
|
|
|
|
|
WHERE shipped BETWEEN DATE(vShipped) AND util.dayEnd(vShipped) AND warehouseFk = vWarehouseFk LIMIT 1;
|
|
|
|
|
|
|
|
|
|
UPDATE ticket t
|
|
|
|
|
SET
|
|
|
|
|
t.clientFk = vClientFk,
|
|
|
|
|
t.nickname = vNickname,
|
|
|
|
|
t.agencyModeFk = vAgencyModeFk,
|
|
|
|
|
t.addressFk = vAddressFk,
|
|
|
|
|
t.zoneFk = vZoneFk,
|
|
|
|
|
t.zonePrice = vPrice,
|
|
|
|
|
t.zoneBonus = vBonus,
|
|
|
|
|
t.warehouseFk = vWarehouseFk,
|
|
|
|
|
t.companyFk = vCompanyFk,
|
|
|
|
|
t.landed = vLanded,
|
|
|
|
|
t.shipped = vShipped,
|
|
|
|
|
t.isDeleted = vIsDeleted
|
|
|
|
|
WHERE
|
|
|
|
|
t.id = vTicketFk;
|
|
|
|
|
|
|
|
|
|
IF vHasToBeUnrouted THEN
|
|
|
|
|
UPDATE ticket t SET t.routeFk = NULL
|
|
|
|
|
WHERE t.id = vTicketFk;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.sale;
|
|
|
|
|
CREATE TEMPORARY TABLE tmp.sale
|
|
|
|
|
(PRIMARY KEY (saleFk))
|
|
|
|
|
ENGINE = MEMORY
|
|
|
|
|
SELECT id AS saleFk, vWarehouseFk warehouseFk
|
|
|
|
|
FROM sale s WHERE s.ticketFk = vTicketFk;
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponent;
|
|
|
|
|
CREATE TEMPORARY TABLE tmp.ticketComponent
|
|
|
|
|
SELECT * FROM tmp.ticketComponentPreview;
|
|
|
|
|
|
|
|
|
|
CALL ticketComponentUpdateSale (vOption);
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.sale;
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponent;
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.zoneGetShipped, tmp.ticketComponentPreview;
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
DELIMITER $$
|
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_recalcComponents`(vSelf INT, vOption VARCHAR(25))
|
|
|
|
|
proc: BEGIN
|
|
|
|
|
|
|
|
|
|
/**
|
|
|
|
|
* Crea tabla temporal para sale_recalcComponent() para recalcular los componentes
|
|
|
|
|
*
|
|
|
|
|
* @param vSelf Id del ticket
|
|
|
|
|
* @param vOption si no se quiere forzar llamar con NULL
|
|
|
|
|
*/
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.recalculateSales
|
|
|
|
|
SELECT s.id
|
|
|
|
|
FROM sale s
|
|
|
|
|
WHERE s.ticketFk = vSelf;
|
|
|
|
|
|
|
|
|
|
CALL sale_recalcComponent(vOption);
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.recalculateSales;
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|
|
|
|
|
|
|
|
|
|
TRUNCATE TABLE `vn`.`ticketUpdateAction`;
|
|
|
|
|
INSERT INTO `vn`.`ticketUpdateAction` (id, description, code) VALUES(1, 'Cambiar los precios en el ticket', 'renewPrice');
|
|
|
|
|
INSERT INTO `vn`.`ticketUpdateAction` (id, description, code) VALUES(2, 'Convertir en maná', 'mana');
|