2024-01-15 11:31:03 +00:00
|
|
|
DELIMITER $$
|
2025-02-20 07:48:49 +00:00
|
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `bs`.`waste_addSales`(
|
2024-09-16 11:33:53 +00:00
|
|
|
vDateFrom DATE,
|
|
|
|
vDateTo DATE
|
|
|
|
)
|
2024-01-15 11:31:03 +00:00
|
|
|
BEGIN
|
2024-09-17 10:35:08 +00:00
|
|
|
/**
|
|
|
|
* Recalcula las mermas de un periodo.
|
|
|
|
*
|
|
|
|
* @param vDateFrom Fecha desde
|
|
|
|
* @param vDateTo Fecha hasta
|
|
|
|
*/
|
2025-01-09 10:29:07 +00:00
|
|
|
DECLARE vDaysInYear INT;
|
2025-02-28 12:01:49 +00:00
|
|
|
SET vDaysInYear = DATEDIFF(util.lastDayOfYear(util.VN_CURDATE()), util.firstDayOfYear(util.VN_CURDATE()));
|
2025-01-09 10:29:07 +00:00
|
|
|
|
|
|
|
SET vDateFrom = COALESCE(vDateFrom, util.VN_CURDATE());
|
|
|
|
SET vDateTo = COALESCE(vDateTo, util.VN_CURDATE());
|
2024-09-16 11:33:53 +00:00
|
|
|
|
2025-01-09 10:29:07 +00:00
|
|
|
IF DATEDIFF(vDateTo, vDateFrom) > vDaysInYear THEN
|
|
|
|
CALL util.throw('The period cannot be longer than one year');
|
2024-09-16 11:33:53 +00:00
|
|
|
END IF;
|
2024-07-10 10:00:54 +00:00
|
|
|
|
2025-01-09 10:29:07 +00:00
|
|
|
-- Obtiene el primer día de la semana de esa fecha
|
|
|
|
SET vDateFrom = DATE_SUB(vDateFrom, INTERVAL ((WEEKDAY(vDateFrom) + 1) % 7) DAY);
|
|
|
|
|
|
|
|
-- Obtiene el último día de la semana de esa fecha
|
|
|
|
SET vDateTo = DATE_ADD(vDateTo, INTERVAL (6 - ((WEEKDAY(vDateTo) + 1) % 7)) DAY);
|
|
|
|
|
2025-02-28 11:07:25 +00:00
|
|
|
-- !! 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
|
2025-02-28 12:01:49 +00:00
|
|
|
WHERE tr.landed BETWEEN util.VN_CURDATE() - INTERVAL 1 WEEK AND util.VN_CURDATE()
|
2025-02-28 11:07:25 +00:00
|
|
|
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
|
2025-02-28 12:01:49 +00:00
|
|
|
WHERE tr.landed BETWEEN util.VN_CURDATE() - INTERVAL 1 YEAR AND util.VN_CURDATE()
|
2025-02-28 11:07:25 +00:00
|
|
|
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
|
2025-02-28 12:01:49 +00:00
|
|
|
WHERE tr.landed BETWEEN util.VN_CURDATE() - INTERVAL 1 YEAR AND util.VN_CURDATE()
|
2025-02-28 11:07:25 +00:00
|
|
|
)
|
|
|
|
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;
|
2024-07-09 09:56:32 +00:00
|
|
|
|
2024-01-15 11:31:03 +00:00
|
|
|
REPLACE bs.waste
|
2025-01-09 10:29:07 +00:00
|
|
|
SELECT YEARWEEK(t.shipped, 6) DIV 100,
|
2025-01-09 06:28:14 +00:00
|
|
|
WEEK(t.shipped, 6),
|
2024-05-10 08:01:46 +00:00
|
|
|
it.workerFk,
|
|
|
|
it.id,
|
|
|
|
s.itemFk,
|
2025-02-28 11:07:25 +00:00
|
|
|
SUM((icc.cost) * s.quantity),
|
2024-08-09 06:18:30 +00:00
|
|
|
SUM(IF(aw.`type`, s.quantity, 0)),
|
2024-09-16 10:32:52 +00:00
|
|
|
SUM(IF(
|
|
|
|
aw.`type` = 'external',
|
2025-02-28 11:07:25 +00:00
|
|
|
(icc.cost) * s.quantity,
|
2024-05-10 08:01:46 +00:00
|
|
|
0
|
|
|
|
)
|
2024-09-16 10:32:52 +00:00
|
|
|
),
|
|
|
|
SUM(IF(
|
|
|
|
aw.`type` = 'fault',
|
2025-02-28 11:07:25 +00:00
|
|
|
(icc.cost) * s.quantity,
|
2024-09-16 10:32:52 +00:00
|
|
|
0
|
|
|
|
)
|
|
|
|
),
|
|
|
|
SUM(IF(
|
|
|
|
aw.`type` = 'container',
|
2025-02-28 11:07:25 +00:00
|
|
|
(icc.cost) * s.quantity,
|
2024-09-16 10:32:52 +00:00
|
|
|
0
|
|
|
|
)
|
|
|
|
),
|
|
|
|
SUM(IF(
|
|
|
|
aw.`type` = 'break',
|
2025-02-28 11:07:25 +00:00
|
|
|
(icc.cost) * s.quantity,
|
2024-09-16 10:32:52 +00:00
|
|
|
0
|
|
|
|
)
|
|
|
|
),
|
|
|
|
SUM(IF(
|
|
|
|
aw.`type` = 'other',
|
2025-02-28 11:07:25 +00:00
|
|
|
(icc.cost) * s.quantity,
|
2024-08-09 11:53:28 +00:00
|
|
|
0
|
2024-05-10 08:01:46 +00:00
|
|
|
)
|
2024-08-09 06:18:30 +00:00
|
|
|
)
|
2024-05-10 08:01:46 +00:00
|
|
|
FROM vn.sale s
|
|
|
|
JOIN vn.item i ON i.id = s.itemFk
|
|
|
|
JOIN vn.itemType it ON it.id = i.typeFk
|
|
|
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
2024-07-09 09:56:32 +00:00
|
|
|
JOIN vn.address a FORCE INDEX (PRIMARY) ON a.id = t.addressFk
|
2024-07-09 09:40:24 +00:00
|
|
|
LEFT JOIN vn.addressWaste aw ON aw.addressFk = a.id
|
2024-05-10 08:01:46 +00:00
|
|
|
JOIN vn.warehouse w ON w.id = t.warehouseFk
|
2025-02-28 11:07:25 +00:00
|
|
|
JOIN tItemCalcCost icc ON icc.itemFk = i.id
|
|
|
|
AND icc.warehouseFk = w.id
|
2025-01-09 10:29:07 +00:00
|
|
|
WHERE t.shipped BETWEEN vDateFrom AND util.dayEnd(vDateTo)
|
2024-07-10 10:00:54 +00:00
|
|
|
AND w.isManaged
|
2025-01-09 10:29:07 +00:00
|
|
|
GROUP BY YEARWEEK(t.shipped, 6) DIV 100, WEEK(t.shipped, 6), i.id;
|
2025-02-28 11:07:25 +00:00
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tItemCalcCost;
|
2024-01-15 11:31:03 +00:00
|
|
|
END$$
|
|
|
|
DELIMITER ;
|