Merge pull request '7120-specialPrice' (!2213) from 7120-specialPrice into dev
gitea/salix/pipeline/head Build queued... Details

Reviewed-on: #2213
Reviewed-by: Carlos Andrés <carlosap@verdnatura.es>
This commit is contained in:
Javi Gallego 2024-03-28 08:01:45 +00:00
commit 699883182c
3 changed files with 54 additions and 28 deletions

View File

@ -8,13 +8,16 @@ BEGIN
SELECT rate3 INTO price SELECT rate3 INTO price
FROM vn.priceFixed FROM vn.priceFixed
WHERE itemFk = vItemFk WHERE itemFk = vItemFk
AND util.VN_CURDATE() BETWEEN started AND ended ORDER BY created DESC LIMIT 1; AND util.VN_CURDATE() BETWEEN started AND ended ORDER BY created DESC LIMIT 1;
SELECT `value` INTO price SELECT `value` INTO price
FROM vn.specialPrice FROM vn.specialPrice
WHERE itemFk = vItemFk WHERE itemFk = vItemFk
AND clientFk = vClientFk ; AND (clientFk = vClientFk OR clientFk IS NULL)
AND started <= util.VN_CURDATE()
AND (ended >= util.VN_CURDATE() OR ended IS NULL)
ORDER BY id DESC LIMIT 1;
RETURN price; RETURN price;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -10,7 +10,7 @@ BEGIN
* Calcula los componentes de los articulos de tmp.ticketLot * Calcula los componentes de los articulos de tmp.ticketLot
* *
* @param vZoneFk para calcular el transporte * @param vZoneFk para calcular el transporte
* @param vAddressFk Consignatario * @param vAddressFk Consignatario
* @param vShipped dia de salida del pedido * @param vShipped dia de salida del pedido
* @param vWarehouseFk warehouse de salida del pedido * @param vWarehouseFk warehouse de salida del pedido
* @table tmp.ticketLot (warehouseFk, available, itemFk, buyFk, zoneFk) * @table tmp.ticketLot (warehouseFk, available, itemFk, buyFk, zoneFk)
@ -24,7 +24,20 @@ BEGIN
SELECT clientFk INTO vClientFK SELECT clientFk INTO vClientFK
FROM address FROM address
WHERE id = vAddressFk; WHERE id = vAddressFk;
CREATE OR REPLACE TEMPORARY TABLE tSpecialPrice
(INDEX (itemFk))
ENGINE = MEMORY
SELECT * FROM (
SELECT *
FROM specialPrice
WHERE (clientFk = vClientFk OR clientFk IS NULL)
AND started <= vShipped
AND (ended >= vShipped OR ended IS NULL)
ORDER BY (clientFk = vClientFk) DESC, id DESC
LIMIT 10000000000000000000) t
GROUP BY itemFk;
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketComponentCalculate CREATE OR REPLACE TEMPORARY TABLE tmp.ticketComponentCalculate
(PRIMARY KEY (itemFk, warehouseFk)) (PRIMARY KEY (itemFk, warehouseFk))
ENGINE = MEMORY ENGINE = MEMORY
@ -36,7 +49,7 @@ BEGIN
IFNULL(pf.packing, GREATEST(b.grouping, b.packing)) packing, IFNULL(pf.packing, GREATEST(b.grouping, b.packing)) packing,
IFNULL(pf.`grouping`, b.`grouping`) `grouping`, IFNULL(pf.`grouping`, b.`grouping`) `grouping`,
ABS(IFNULL(pf.box, b.groupingMode)) groupingMode, ABS(IFNULL(pf.box, b.groupingMode)) groupingMode,
tl.buyFk, tl.buyFk,
i.typeFk, i.typeFk,
IF(i.hasKgPrice, b.weight / b.packing, NULL) weightGrouping IF(i.hasKgPrice, b.weight / b.packing, NULL) weightGrouping
FROM tmp.ticketLot tl FROM tmp.ticketLot tl
@ -44,8 +57,7 @@ BEGIN
JOIN item i ON i.id = tl.itemFk JOIN item i ON i.id = tl.itemFk
JOIN itemType it ON it.id = i.typeFk JOIN itemType it ON it.id = i.typeFk
JOIN itemCategory ic ON ic.id = it.categoryFk JOIN itemCategory ic ON ic.id = it.categoryFk
LEFT JOIN specialPrice sp ON sp.itemFk = i.id LEFT JOIN tSpecialPrice sp ON sp.itemFk = i.id
AND sp.clientFk = vClientFk
LEFT JOIN ( LEFT JOIN (
SELECT * FROM ( SELECT * FROM (
SELECT pf.itemFk, SELECT pf.itemFk,
@ -63,7 +75,7 @@ BEGIN
LIMIT 10000000000000000000 LIMIT 10000000000000000000
) tpf ) tpf
GROUP BY tpf.itemFk, tpf.warehouseFk GROUP BY tpf.itemFk, tpf.warehouseFk
) pf ON pf.itemFk = tl.itemFk ) pf ON pf.itemFk = tl.itemFk
AND pf.warehouseFk = tl.warehouseFk AND pf.warehouseFk = tl.warehouseFk
WHERE b.buyingValue + b.freightValue + b.packageValue + b.comissionValue > 0.01 WHERE b.buyingValue + b.freightValue + b.packageValue + b.comissionValue > 0.01
AND ic.merchandise AND ic.merchandise
@ -95,10 +107,10 @@ BEGIN
FROM tmp.ticketComponent tc FROM tmp.ticketComponent tc
JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tc.itemFk AND tcc.warehouseFk = tc.warehouseFk JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tc.itemFk AND tcc.warehouseFk = tc.warehouseFk
GROUP BY tc.itemFk, warehouseFk; GROUP BY tc.itemFk, warehouseFk;
-- RECOBRO -- RECOBRO
INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
SELECT tcb.warehouseFk, tcb.itemFk, c2.id, SELECT tcb.warehouseFk, tcb.itemFk, c2.id,
ROUND(tcb.base * ROUND(tcb.base *
LEAST( LEAST(
MAX(GREATEST(IFNULL(cr.priceIncreasing,0), MAX(GREATEST(IFNULL(cr.priceIncreasing,0),
@ -129,29 +141,29 @@ BEGIN
ROUND(base * wm.pricesModifierRate, 3) manaAuto ROUND(base * wm.pricesModifierRate, 3) manaAuto
FROM tmp.ticketComponentBase tcb FROM tmp.ticketComponentBase tcb
JOIN `client` c on c.id = vClientFk JOIN `client` c on c.id = vClientFk
JOIN workerMana wm ON c.salesPersonFk = wm.workerFk JOIN workerMana wm ON c.salesPersonFk = wm.workerFk
JOIN vn.component c2 ON c2.code = 'autoMana' JOIN vn.component c2 ON c2.code = 'autoMana'
WHERE wm.isPricesModifierActivated WHERE wm.isPricesModifierActivated
HAVING manaAuto <> 0; HAVING manaAuto <> 0;
-- Precios especiales -- Precios especiales
INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
SELECT tcb.warehouseFk, SELECT tcb.warehouseFk,
tcb.itemFk, tcb.itemFk,
c2.id, c2.id,
GREATEST( GREATEST(
IFNULL(ROUND(tcb.base * c2.tax, 4), 0), IFNULL(ROUND(tcb.base * c2.tax, 4), 0),
IF(i.hasMinPrice, i.minPrice,0) - tcc.rate3 IF(i.hasMinPrice, i.minPrice,0) - tcc.rate3
) cost ) cost
FROM tmp.ticketComponentBase tcb FROM tmp.ticketComponentBase tcb
JOIN vn.component c2 ON c2.code = 'lastUnitsDiscount' JOIN vn.component c2 ON c2.code = 'lastUnitsDiscount'
JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tcb.itemFk AND tcc.warehouseFk = tcb.warehouseFk JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tcb.itemFk AND tcc.warehouseFk = tcb.warehouseFk
LEFT JOIN specialPrice sp ON sp.clientFk = vClientFk AND sp.itemFk = tcc.itemFk LEFT JOIN tSpecialPrice sp ON sp.itemFk = tcc.itemFk
JOIN vn.item i ON i.id = tcb.itemFk JOIN vn.item i ON i.id = tcb.itemFk
WHERE sp.value IS NULL WHERE sp.value IS NULL
AND i.supplyResponseFk IS NULL; AND i.supplyResponseFk IS NULL;
-- Individual -- Individual
INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
SELECT tcb.warehouseFk, SELECT tcb.warehouseFk,
tcb.itemFk, tcb.itemFk,
@ -162,14 +174,14 @@ BEGIN
JOIN vn.client c ON c.id = vClientFk JOIN vn.client c ON c.id = vClientFk
JOIN vn.businessType bt ON bt.code = c.businessTypeFk JOIN vn.businessType bt ON bt.code = c.businessTypeFk
WHERE bt.code = 'individual'; WHERE bt.code = 'individual';
-- Venta por paquetes -- Venta por paquetes
INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
SELECT tcc.warehouseFk, tcc.itemFk, c2.id, tcc.rate2 - tcc.rate3 SELECT tcc.warehouseFk, tcc.itemFk, c2.id, tcc.rate2 - tcc.rate3
FROM tmp.ticketComponentCalculate tcc FROM tmp.ticketComponentCalculate tcc
JOIN vn.component c2 ON c2.code = 'salePerPackage' JOIN vn.component c2 ON c2.code = 'salePerPackage'
JOIN buy b ON b.id = tcc.buyFk JOIN buy b ON b.id = tcc.buyFk
LEFT JOIN specialPrice sp ON sp.clientFk = vClientFk AND sp.itemFk = tcc.itemFk LEFT JOIN tSpecialPrice sp ON sp.itemFk = tcc.itemFk
WHERE sp.value IS NULL; WHERE sp.value IS NULL;
CREATE OR REPLACE TEMPORARY TABLE tmp.`zone` (INDEX (id)) CREATE OR REPLACE TEMPORARY TABLE tmp.`zone` (INDEX (id))
@ -177,7 +189,7 @@ BEGIN
SELECT vZoneFk id; SELECT vZoneFk id;
CALL zone_getOptionsForShipment(vShipped, TRUE); CALL zone_getOptionsForShipment(vShipped, TRUE);
-- Reparto -- Reparto
INSERT INTO tmp.ticketComponent INSERT INTO tmp.ticketComponent
SELECT tcc.warehouseFK, SELECT tcc.warehouseFK,
@ -191,7 +203,7 @@ BEGIN
JOIN agencyMode am ON am.id = z.agencyModeFk JOIN agencyMode am ON am.id = z.agencyModeFk
JOIN vn.volumeConfig vc JOIN vn.volumeConfig vc
JOIN vn.component c2 ON c2.code = 'delivery' JOIN vn.component c2 ON c2.code = 'delivery'
LEFT JOIN itemCost ic ON ic.warehouseFk = tcc.warehouseFk LEFT JOIN itemCost ic ON ic.warehouseFk = tcc.warehouseFk
AND ic.itemFk = tcc.itemFk AND ic.itemFk = tcc.itemFk
HAVING cost <> 0; HAVING cost <> 0;
@ -208,7 +220,7 @@ BEGIN
sp.value - SUM(tcc.cost) sumCost sp.value - SUM(tcc.cost) sumCost
FROM tmp.ticketComponentCopy tcc FROM tmp.ticketComponentCopy tcc
JOIN component c ON c.id = tcc.componentFk JOIN component c ON c.id = tcc.componentFk
JOIN specialPrice sp ON sp.clientFk = vClientFK AND sp.itemFk = tcc.itemFk JOIN tSpecialPrice sp ON sp.itemFk = tcc.itemFk
JOIN vn.component c2 ON c2.code = 'specialPrices' JOIN vn.component c2 ON c2.code = 'specialPrices'
WHERE c.classRate IS NULL WHERE c.classRate IS NULL
AND tcc.warehouseFk = vWarehouseFk AND tcc.warehouseFk = vWarehouseFk
@ -244,9 +256,9 @@ BEGIN
CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) price, CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) price,
CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) / weightGrouping priceKg CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) / weightGrouping priceKg
FROM tmp.ticketComponentCalculate tcc FROM tmp.ticketComponentCalculate tcc
JOIN tmp.ticketComponentSum tcs ON tcs.itemFk = tcc.itemFk JOIN tmp.ticketComponentSum tcs ON tcs.itemFk = tcc.itemFk
AND tcs.warehouseFk = tcc.warehouseFk AND tcs.warehouseFk = tcc.warehouseFk
WHERE IFNULL(tcs.classRate, 1) = 1 WHERE IFNULL(tcs.classRate, 1) = 1
AND tcc.groupingMode < 2 AND (tcc.packing > tcc.`grouping` or tcc.groupingMode = 0) AND tcc.groupingMode < 2 AND (tcc.packing > tcc.`grouping` or tcc.groupingMode = 0)
GROUP BY tcs.warehouseFk, tcs.itemFk; GROUP BY tcs.warehouseFk, tcs.itemFk;
@ -283,12 +295,13 @@ BEGIN
SELECT * FROM tmp.ticketComponentRate ORDER BY price LIMIT 10000000000000000000 SELECT * FROM tmp.ticketComponentRate ORDER BY price LIMIT 10000000000000000000
) t ) t
GROUP BY itemFk, warehouseFk, `grouping`; GROUP BY itemFk, warehouseFk, `grouping`;
DROP TEMPORARY TABLE DROP TEMPORARY TABLE
tmp.ticketComponentCalculate, tmp.ticketComponentCalculate,
tmp.ticketComponentSum, tmp.ticketComponentSum,
tmp.ticketComponentBase, tmp.ticketComponentBase,
tmp.ticketComponentRate, tmp.ticketComponentRate,
tmp.ticketComponentCopy; tmp.ticketComponentCopy,
tSpecialPrice;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -0,0 +1,10 @@
ALTER TABLE vn.specialPrice MODIFY COLUMN clientFk int(11) NULL;
ALTER TABLE vn.specialPrice ADD started date NOT NULL DEFAULT '2024-01-01';
ALTER TABLE vn.specialPrice ADD ended date NULL;
ALTER TABLE vn.specialPrice MODIFY COLUMN itemFk int(11) NOT NULL;
ALTER TABLE vn.specialPrice MODIFY COLUMN value DECIMAL(10,2) NOT NULL;
ALTER TABLE vn.`specialPrice`
ADD CONSTRAINT `check_date_range`
CHECK (`ended` IS NULL OR `ended` >= `started`);