refactor: refs #7912 Item calc cost Ricardo #3510
|
@ -11,7 +11,7 @@ BEGIN
|
||||||
* @param vDateTo Fecha hasta
|
* @param vDateTo Fecha hasta
|
||||||
*/
|
*/
|
||||||
DECLARE vDaysInYear INT;
|
DECLARE vDaysInYear INT;
|
||||||
SET vDaysInYear = DATEDIFF(util.lastDayOfYear(CURDATE()), util.firstDayOfYear(CURDATE()));
|
SET vDaysInYear = DATEDIFF(util.lastDayOfYear(util.VN_CURDATE()), util.firstDayOfYear(util.VN_CURDATE()));
|
||||||
|
|
||||||
SET vDateFrom = COALESCE(vDateFrom, util.VN_CURDATE());
|
SET vDateFrom = COALESCE(vDateFrom, util.VN_CURDATE());
|
||||||
SET vDateTo = COALESCE(vDateTo, util.VN_CURDATE());
|
SET vDateTo = COALESCE(vDateTo, util.VN_CURDATE());
|
||||||
|
@ -26,7 +26,76 @@ BEGIN
|
||||||
-- Obtiene el último día de la semana de esa fecha
|
-- Obtiene el último día de la semana de esa fecha
|
||||||
SET vDateTo = DATE_ADD(vDateTo, INTERVAL (6 - ((WEEKDAY(vDateTo) + 1) % 7)) DAY);
|
SET vDateTo = DATE_ADD(vDateTo, INTERVAL (6 - ((WEEKDAY(vDateTo) + 1) % 7)) DAY);
|
||||||
|
|
||||||
CALL cache.last_buy_refresh(FALSE);
|
-- !! Cálculo del coste por warehouse y artículo (Reglas Ricardo) !!
|
||||||
|
-- Coste de las compras de la última semana (Sin inventario y arreglos stock)
|
||||||
|
CREATE OR REPLACE TEMPORARY TABLE tItemCalcCost
|
||||||
|
(PRIMARY KEY (warehouseFk, itemFk))
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT w.id warehouseFk,
|
||||||
|
b.itemFk,
|
||||||
|
IF(COUNT(*) > 1,
|
||||||
|
SUM((b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) * b.quantity) / SUM(b.quantity),
|
||||||
|
(b.buyingValue + b.freightValue + b.comissionValue + b.packageValue)
|
||||||
|
) cost
|
||||||
|
FROM vn.buy b
|
||||||
|
JOIN vn.entry e ON e.id = b.entryFk
|
||||||
|
JOIN vn.travel tr ON tr.id = e.travelFk
|
||||||
|
JOIN vn.warehouse w ON w.id = tr.warehouseInFk
|
||||||
|
WHERE tr.landed BETWEEN util.VN_CURDATE() - INTERVAL 1 WEEK AND util.VN_CURDATE()
|
||||||
guillermo marked this conversation as resolved
Outdated
|
|||||||
|
AND e.supplierFk NOT IN (
|
||||||
|
(SELECT supplierFk FROM vn.inventoryConfig),
|
||||||
|
(SELECT id FROM vn.supplier WHERE name = 'ARREGLOS STOCK')
|
||||||
|
)
|
||||||
|
GROUP BY w.id, b.itemFk;
|
||||||
|
|
||||||
|
-- Proveedores reales
|
||||||
|
INSERT IGNORE INTO tItemCalcCost(warehouseFk, itemFk, cost)
|
||||||
|
WITH wBuysNumered AS (
|
||||||
|
SELECT ROW_NUMBER() OVER(
|
||||||
|
PARTITION BY tr.warehouseInFk, b.itemFk
|
||||||
|
ORDER BY tr.landed DESC, b.buyingValue DESC, b.id DESC
|
||||||
|
) num,
|
||||||
|
w.id warehouseFk,
|
||||||
|
b.itemFk,
|
||||||
|
b.id
|
||||||
|
FROM vn.buy b
|
||||||
|
JOIN vn.entry e ON e.id = b.entryFk
|
||||||
|
JOIN vn.travel tr ON tr.id = e.travelFk
|
||||||
|
JOIN vn.warehouse w ON w.id = tr.warehouseInFk
|
||||||
|
JOIN vn.supplier s ON s.id = e.supplierFk
|
||||||
|
WHERE tr.landed BETWEEN util.VN_CURDATE() - INTERVAL 1 YEAR AND util.VN_CURDATE()
|
||||||
|
AND s.isReal
|
||||||
|
)
|
||||||
|
SELECT bn.warehouseFk,
|
||||||
|
b.itemFk,
|
||||||
|
(b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) cost
|
||||||
|
FROM wBuysNumered bn
|
||||||
|
JOIN vn.buy b ON b.id = bn.id
|
||||||
|
WHERE num = 1;
|
||||||
|
|
||||||
|
-- Como último recurso, se coge cualquier compra
|
||||||
|
INSERT IGNORE INTO tItemCalcCost(warehouseFk, itemFk, cost)
|
||||||
|
WITH wBuysNumered AS (
|
||||||
|
SELECT ROW_NUMBER() OVER(
|
||||||
|
PARTITION BY tr.warehouseInFk, b.itemFk
|
||||||
|
ORDER BY tr.landed DESC, b.buyingValue DESC, b.id DESC
|
||||||
|
) num,
|
||||||
|
w.id warehouseFk,
|
||||||
|
b.itemFk,
|
||||||
|
b.id
|
||||||
|
FROM vn.buy b
|
||||||
|
JOIN vn.entry e ON e.id = b.entryFk
|
||||||
|
JOIN vn.travel tr ON tr.id = e.travelFk
|
||||||
|
JOIN vn.warehouse w ON w.id = tr.warehouseInFk
|
||||||
|
JOIN vn.supplier s ON s.id = e.supplierFk
|
||||||
|
WHERE tr.landed BETWEEN util.VN_CURDATE() - INTERVAL 1 YEAR AND util.VN_CURDATE()
|
||||||
|
)
|
||||||
|
SELECT bn.warehouseFk,
|
||||||
|
b.itemFk,
|
||||||
|
(b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) cost
|
||||||
|
FROM wBuysNumered bn
|
||||||
|
JOIN vn.buy b ON b.id = bn.id
|
||||||
|
WHERE num = 1;
|
||||||
|
|
||||||
REPLACE bs.waste
|
REPLACE bs.waste
|
||||||
SELECT YEARWEEK(t.shipped, 6) DIV 100,
|
SELECT YEARWEEK(t.shipped, 6) DIV 100,
|
||||||
|
@ -34,35 +103,35 @@ BEGIN
|
||||||
it.workerFk,
|
it.workerFk,
|
||||||
it.id,
|
it.id,
|
||||||
s.itemFk,
|
s.itemFk,
|
||||||
SUM((b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) * s.quantity),
|
SUM((icc.cost) * s.quantity),
|
||||||
SUM(IF(aw.`type`, s.quantity, 0)),
|
SUM(IF(aw.`type`, s.quantity, 0)),
|
||||||
SUM(IF(
|
SUM(IF(
|
||||||
aw.`type` = 'external',
|
aw.`type` = 'external',
|
||||||
(b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) * s.quantity,
|
(icc.cost) * s.quantity,
|
||||||
0
|
0
|
||||||
)
|
)
|
||||||
),
|
),
|
||||||
SUM(IF(
|
SUM(IF(
|
||||||
aw.`type` = 'fault',
|
aw.`type` = 'fault',
|
||||||
(b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) * s.quantity,
|
(icc.cost) * s.quantity,
|
||||||
0
|
0
|
||||||
)
|
)
|
||||||
),
|
),
|
||||||
SUM(IF(
|
SUM(IF(
|
||||||
aw.`type` = 'container',
|
aw.`type` = 'container',
|
||||||
(b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) * s.quantity,
|
(icc.cost) * s.quantity,
|
||||||
0
|
0
|
||||||
)
|
)
|
||||||
),
|
),
|
||||||
SUM(IF(
|
SUM(IF(
|
||||||
aw.`type` = 'break',
|
aw.`type` = 'break',
|
||||||
(b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) * s.quantity,
|
(icc.cost) * s.quantity,
|
||||||
0
|
0
|
||||||
)
|
)
|
||||||
),
|
),
|
||||||
SUM(IF(
|
SUM(IF(
|
||||||
aw.`type` = 'other',
|
aw.`type` = 'other',
|
||||||
(b.buyingValue + b.freightValue + b.comissionValue + b.packageValue) * s.quantity,
|
(icc.cost) * s.quantity,
|
||||||
0
|
0
|
||||||
)
|
)
|
||||||
)
|
)
|
||||||
|
@ -73,11 +142,12 @@ BEGIN
|
||||||
JOIN vn.address a FORCE INDEX (PRIMARY) ON a.id = t.addressFk
|
JOIN vn.address a FORCE INDEX (PRIMARY) ON a.id = t.addressFk
|
||||||
LEFT JOIN vn.addressWaste aw ON aw.addressFk = a.id
|
LEFT JOIN vn.addressWaste aw ON aw.addressFk = a.id
|
||||||
JOIN vn.warehouse w ON w.id = t.warehouseFk
|
JOIN vn.warehouse w ON w.id = t.warehouseFk
|
||||||
JOIN cache.last_buy lb ON lb.item_id = i.id
|
JOIN tItemCalcCost icc ON icc.itemFk = i.id
|
||||||
AND lb.warehouse_id = w.id
|
AND icc.warehouseFk = w.id
|
||||||
JOIN vn.buy b ON b.id = lb.buy_id
|
|
||||||
WHERE t.shipped BETWEEN vDateFrom AND util.dayEnd(vDateTo)
|
WHERE t.shipped BETWEEN vDateFrom AND util.dayEnd(vDateTo)
|
||||||
AND w.isManaged
|
AND w.isManaged
|
||||||
GROUP BY YEARWEEK(t.shipped, 6) DIV 100, WEEK(t.shipped, 6), i.id;
|
GROUP BY YEARWEEK(t.shipped, 6) DIV 100, WEEK(t.shipped, 6), i.id;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE tItemCalcCost;
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
Loading…
Reference in New Issue
sempre gastem el curddate de util, pel tema local y fixtures