DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `bs`.`waste_addSales`( vDateFrom DATE, vDateTo DATE ) BEGIN /** * Recalcula las mermas de un periodo. * * @param vDateFrom Fecha desde * @param vDateTo Fecha hasta */ DECLARE vDaysInYear INT; SET vDaysInYear = DATEDIFF(util.lastDayOfYear(util.VN_CURDATE()), util.firstDayOfYear(util.VN_CURDATE())); SET vDateFrom = COALESCE(vDateFrom, util.VN_CURDATE()); SET vDateTo = COALESCE(vDateTo, util.VN_CURDATE()); IF DATEDIFF(vDateTo, vDateFrom) > vDaysInYear THEN CALL util.throw('The period cannot be longer than one year'); END IF; -- 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); -- !! 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() 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 SELECT YEARWEEK(t.shipped, 6) DIV 100, WEEK(t.shipped, 6), it.workerFk, it.id, s.itemFk, SUM((icc.cost) * s.quantity), SUM(IF(aw.`type`, s.quantity, 0)), SUM(IF( aw.`type` = 'external', (icc.cost) * s.quantity, 0 ) ), SUM(IF( aw.`type` = 'fault', (icc.cost) * s.quantity, 0 ) ), SUM(IF( aw.`type` = 'container', (icc.cost) * s.quantity, 0 ) ), SUM(IF( aw.`type` = 'break', (icc.cost) * s.quantity, 0 ) ), SUM(IF( aw.`type` = 'other', (icc.cost) * s.quantity, 0 ) ) 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 JOIN vn.address a FORCE INDEX (PRIMARY) ON a.id = t.addressFk LEFT JOIN vn.addressWaste aw ON aw.addressFk = a.id JOIN vn.warehouse w ON w.id = t.warehouseFk JOIN tItemCalcCost icc ON icc.itemFk = i.id AND icc.warehouseFk = w.id WHERE t.shipped BETWEEN vDateFrom AND util.dayEnd(vDateTo) AND w.isManaged GROUP BY YEARWEEK(t.shipped, 6) DIV 100, WEEK(t.shipped, 6), i.id; DROP TEMPORARY TABLE tItemCalcCost; END$$ DELIMITER ;