From 6685a201143a320920bbe04db7f8d0d1bd32d415 Mon Sep 17 00:00:00 2001 From: alexm Date: Thu, 15 Feb 2024 10:04:15 +0100 Subject: [PATCH] build: refs #6859 myt pull db --- db/.pullinfo.json | 4 + .../bi/procedures/analisis_ventas_update.sql | 8 +- .../vn/functions/hasAnyNegativeBase.sql | 31 +-- .../vn/functions/hasAnyPositiveBase.sql | 30 ++ db/routines/vn/procedures/clean.sql | 8 +- .../vn/procedures/collection_assign.sql | 8 +- .../vn/procedures/duaInvoiceInBooking.sql | 78 +++--- db/routines/vn/procedures/getTaxBases.sql | 32 +++ db/routines/vn/procedures/inventoryMake.sql | 258 +++++++++--------- .../vn/procedures/inventoryMakeLauncher.sql | 9 +- .../vn/procedures/invoiceInTaxMakeByDua.sql | 39 +-- .../vn/procedures/invoiceInTax_getFromDua.sql | 33 ++- .../invoiceInTax_getFromEntries.sql | 17 +- .../vn/procedures/itemProposal_Add.sql | 2 +- .../itemShelving_selfConsumption.sql | 11 +- db/routines/vn/procedures/test.sql | 6 - .../vn/procedures/ticket_getMovable.sql | 59 ++-- .../vn/triggers/calendar_afterDelete.sql | 12 +- .../vn/triggers/calendar_beforeInsert.sql | 2 +- .../vn/triggers/calendar_beforeUpdate.sql | 12 +- ...reInser.sql => saleGroup_beforeInsert.sql} | 0 .../workerTimeControl_afterDelete.sql | 12 +- .../workerTimeControl_beforeInsert.sql | 12 +- .../workerTimeControl_beforeUpdate.sql | 12 +- db/routines/vn/views/awbVolume.sql | 2 +- .../vn/views/expeditionPallet_Print.sql | 2 +- .../vn/views/itemShelvingAvailable.sql | 2 +- db/routines/vn/views/ticketStateToday.sql | 11 +- .../vn/views/zoneEstimatedDelivery.sql | 67 +++-- .../vn2008/procedures/recobro_credito.sql | 2 +- db/routines/vn2008/views/v_xsubcuentas.sql | 28 +- 31 files changed, 464 insertions(+), 345 deletions(-) create mode 100644 db/.pullinfo.json create mode 100644 db/routines/vn/functions/hasAnyPositiveBase.sql create mode 100644 db/routines/vn/procedures/getTaxBases.sql delete mode 100644 db/routines/vn/procedures/test.sql rename db/routines/vn/triggers/{saleGroup_beforeInser.sql => saleGroup_beforeInsert.sql} (100%) diff --git a/db/.pullinfo.json b/db/.pullinfo.json new file mode 100644 index 0000000000..20a294f1f5 --- /dev/null +++ b/db/.pullinfo.json @@ -0,0 +1,4 @@ +{ + "lastPull": "2024-02-15T08:58:24.000Z", + "shaSums": {} +} \ No newline at end of file diff --git a/db/routines/bi/procedures/analisis_ventas_update.sql b/db/routines/bi/procedures/analisis_ventas_update.sql index 04f9b6483e..383d102b54 100644 --- a/db/routines/bi/procedures/analisis_ventas_update.sql +++ b/db/routines/bi/procedures/analisis_ventas_update.sql @@ -1,5 +1,5 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`analisis_ventas_update`() +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`analisis_ventas_update`() BEGIN DECLARE vLastMonth DATE; @@ -49,5 +49,5 @@ BEGIN LEFT JOIN vn2008.province p ON p.province_id = cs.province_id LEFT JOIN vn2008.warehouse w ON w.id = t.warehouse_id WHERE bt.fecha >= vLastMonth AND r.mercancia; -END$$ -DELIMITER ; +END$$ +DELIMITER ; diff --git a/db/routines/vn/functions/hasAnyNegativeBase.sql b/db/routines/vn/functions/hasAnyNegativeBase.sql index 3b96a3d223..97d1e7328c 100644 --- a/db/routines/vn/functions/hasAnyNegativeBase.sql +++ b/db/routines/vn/functions/hasAnyNegativeBase.sql @@ -4,32 +4,25 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`hasAnyNegativeBase`( DETERMINISTIC BEGIN -/* Calcula si existe alguna base imponible negativa -* Requiere la tabla temporal tmp.ticketToInvoice(id) +/** +* Calcula si existe alguna base imponible negativa +* Requiere la tabla temporal tmp.ticketToInvoice(id) para getTaxBases() * * returns BOOLEAN */ + DECLARE hasAnyNegativeBase BOOLEAN; - DROP TEMPORARY TABLE IF EXISTS tmp.ticket; - CREATE TEMPORARY TABLE tmp.ticket - (KEY (ticketFk)) - ENGINE = MEMORY - SELECT id ticketFk - FROM tmp.ticketToInvoice; + CALL getTaxBases(); - CALL ticket_getTax(NULL); + SELECT negative INTO hasAnyNegativeBase + FROM tmp.taxBases + LIMIT 1; - SELECT COUNT(*) INTO hasAnyNegativeBase - FROM( - SELECT SUM(taxableBase) as taxableBase - FROM tmp.ticketTax - GROUP BY pgcFk - HAVING taxableBase < 0 - ) t; - - DROP TEMPORARY TABLE tmp.ticketTax; - DROP TEMPORARY TABLE tmp.ticket; + DROP TEMPORARY TABLE + tmp.ticketTax, + tmp.ticket, + tmp.taxBases; RETURN hasAnyNegativeBase; diff --git a/db/routines/vn/functions/hasAnyPositiveBase.sql b/db/routines/vn/functions/hasAnyPositiveBase.sql new file mode 100644 index 0000000000..7222c3b2a2 --- /dev/null +++ b/db/routines/vn/functions/hasAnyPositiveBase.sql @@ -0,0 +1,30 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`hasAnyPositiveBase`() + RETURNS tinyint(1) + DETERMINISTIC +BEGIN + +/** +* Calcula si existe alguna base imponible positiva +* Requiere la tabla temporal tmp.ticketToInvoice(id) para getTaxBases() +* +* returns BOOLEAN +*/ + + DECLARE hasAnyPositiveBase BOOLEAN; + + CALL getTaxBases(); + + SELECT positive INTO hasAnyPositiveBase + FROM tmp.taxBases + LIMIT 1; + + DROP TEMPORARY TABLE + tmp.ticketTax, + tmp.ticket, + tmp.taxBases; + + RETURN hasAnyPositiveBase; + +END$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/clean.sql b/db/routines/vn/procedures/clean.sql index 1734bea982..57df1b7074 100644 --- a/db/routines/vn/procedures/clean.sql +++ b/db/routines/vn/procedures/clean.sql @@ -9,6 +9,7 @@ BEGIN DECLARE v26Month DATE; DECLARE v3Month DATE; DECLARE vTrashId VARCHAR(15); + DECLARE v2Years DATE; DECLARE v5Years DATE; SET vDateShort = util.VN_CURDATE() - INTERVAL 2 MONTH; @@ -18,6 +19,7 @@ BEGIN SET v18Month = util.VN_CURDATE() - INTERVAL 18 MONTH; SET v26Month = util.VN_CURDATE() - INTERVAL 26 MONTH; SET v3Month = util.VN_CURDATE() - INTERVAL 3 MONTH; + SET v2Years = util.VN_CURDATE() - INTERVAL 2 YEAR; SET v5Years = util.VN_CURDATE() - INTERVAL 5 YEAR; DELETE FROM ticketParking WHERE created < vDateShort; @@ -162,7 +164,11 @@ BEGIN FROM tmp.duaToDelete tmp JOIN vn.dua d ON d.id = tmp.id; - DELETE FROM vn.awb WHERE created < TIMESTAMPADD(YEAR,-2,util.VN_CURDATE()); + DELETE a + FROM vn.awb a + LEFT JOIN vn.travel t ON t.awbFk = a.id + WHERE a.created < v2Years + AND t.id IS NULL; -- Borra los registros de collection y ticketcollection DELETE FROM vn.collection WHERE created < vDateShort; diff --git a/db/routines/vn/procedures/collection_assign.sql b/db/routines/vn/procedures/collection_assign.sql index 0918bf1da2..6d31fbc8f7 100644 --- a/db/routines/vn/procedures/collection_assign.sql +++ b/db/routines/vn/procedures/collection_assign.sql @@ -1,8 +1,8 @@ -DELIMITER $$ +DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_assign`( vUserFk INT, OUT vCollectionFk INT -) +) proc:BEGIN /** * Comprueba si existen colecciones libres que se ajustan @@ -84,5 +84,5 @@ proc:BEGIN WHERE id = vCollectionFk; DO RELEASE_LOCK('collection_assign'); -END$$ -DELIMITER ; +END$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/duaInvoiceInBooking.sql b/db/routines/vn/procedures/duaInvoiceInBooking.sql index 9e794f0ede..dd5ab8fd27 100644 --- a/db/routines/vn/procedures/duaInvoiceInBooking.sql +++ b/db/routines/vn/procedures/duaInvoiceInBooking.sql @@ -1,70 +1,74 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`duaInvoiceInBooking`(vDuaFk INT) BEGIN - +/** + * Genera el asiento de un DUA y marca las entradas como confirmadas + * + * @param vDuaFk Id del dua a recalcular + */ DECLARE done BOOL DEFAULT FALSE; DECLARE vInvoiceFk INT; - DECLARE vASIEN BIGINT DEFAULT 0; - DECLARE vCounter INT DEFAULT 0; - + DECLARE vASIEN BIGINT DEFAULT 0; + DECLARE vCounter INT DEFAULT 0; + DECLARE rs CURSOR FOR - SELECT e.invoiceInFk + SELECT DISTINCT e.invoiceInFk FROM entry e JOIN duaEntry de ON de.entryFk = e.id - JOIN invoiceIn ii ON ii.id = e.invoiceInFk - WHERE de.duaFk = vDuaFk + JOIN invoiceIn ii ON ii.id = e.invoiceInFk + WHERE de.duaFk = vDuaFk AND de.customsValue AND ii.isBooked = FALSE; DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; OPEN rs; - + UPDATE invoiceIn ii JOIN entry e ON e.invoiceInFk = ii.id - JOIN duaEntry de ON de.entryFk = e.id - JOIN dua d ON d.id = de.duaFk + JOIN duaEntry de ON de.entryFk = e.id + JOIN dua d ON d.id = de.duaFk SET ii.isBooked = TRUE, ii.booked = IFNULL(ii.booked,d.booked), ii.operated = IFNULL(ii.operated,d.operated), - ii.issued = IFNULL(ii.issued,d.issued), - ii.bookEntried = IFNULL(ii.bookEntried,d.bookEntried), - e.isConfirmed = TRUE + ii.issued = IFNULL(ii.issued,d.issued), + ii.bookEntried = IFNULL(ii.bookEntried,d.bookEntried), + e.isConfirmed = TRUE WHERE d.id = vDuaFk; - - SELECT IFNULL(ASIEN,0) INTO vASIEN + + SELECT IFNULL(ASIEN,0) INTO vASIEN FROM dua WHERE id = vDuaFk; - + FETCH rs INTO vInvoiceFk; - + WHILE NOT done DO CALL invoiceIn_booking(vInvoiceFk); - - IF vCounter > 0 OR vASIEN > 0 THEN - + + IF vCounter > 0 OR vASIEN > 0 THEN + UPDATE vn2008.XDiario x - JOIN vn.ledgerConfig lc ON lc.lastBookEntry = x.ASIEN - SET x.ASIEN = vASIEN; - - ELSE - - SELECT lastBookEntry INTO vASIEN FROM vn.ledgerConfig; - + JOIN ledgerConfig lc ON lc.lastBookEntry = x.ASIEN + SET x.ASIEN = vASIEN; + + ELSE + + SELECT lastBookEntry INTO vASIEN FROM ledgerConfig; + END IF; - - SET vCounter = vCounter + 1; - + + SET vCounter = vCounter + 1; + FETCH rs INTO vInvoiceFk; END WHILE; - - CLOSE rs; - - UPDATE dua - SET ASIEN = vASIEN - WHERE id = vDuaFk; - + + CLOSE rs; + + UPDATE dua + SET ASIEN = vASIEN + WHERE id = vDuaFk; + END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/getTaxBases.sql b/db/routines/vn/procedures/getTaxBases.sql new file mode 100644 index 0000000000..54932aa4f1 --- /dev/null +++ b/db/routines/vn/procedures/getTaxBases.sql @@ -0,0 +1,32 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`getTaxBases`() +BEGIN +/** +* Calcula y devuelve en número de bases imponibles postivas y negativas +* Requiere la tabla temporal tmp.ticketToInvoice(id) +* +* returns tmp.taxBases +*/ + + CREATE OR REPLACE TEMPORARY TABLE tmp.ticket + (KEY (ticketFk)) + ENGINE = MEMORY + SELECT id ticketFk + FROM tmp.ticketToInvoice; + + CALL ticket_getTax(NULL); + + DROP TEMPORARY TABLE IF EXISTS tmp.taxBases; + CREATE TEMPORARY TABLE tmp.taxBases + ENGINE = MEMORY + SELECT + SUM(taxableBase > 0) as positive, + SUM(taxableBase < 0) as negative + FROM( + SELECT SUM(taxableBase) taxableBase + FROM tmp.ticketTax + GROUP BY pgcFk + ) t; + +END$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/inventoryMake.sql b/db/routines/vn/procedures/inventoryMake.sql index 0def763dcd..ed6a7fa436 100644 --- a/db/routines/vn/procedures/inventoryMake.sql +++ b/db/routines/vn/procedures/inventoryMake.sql @@ -1,182 +1,175 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`inventoryMake`(vDate DATE, vWh INT) -proc: BEGIN +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`inventoryMake`(vInventoryDate DATE) +BEGIN /** -* Recalcula los inventarios de todos los almacenes, si vWh = 0 +* Recalculate the inventories * -* @param vDate Fecha de los nuevos inventarios -* @param vWh almacen al cual hacer el inventario +* @param vInventoryDate date for the new inventory */ - DECLARE vDone BOOL; DECLARE vEntryFk INT; DECLARE vTravelFk INT; DECLARE vDateLastInventory DATE; - DECLARE vDateYesterday DATETIME DEFAULT vDate - INTERVAL 1 SECOND; + DECLARE vDateYesterday DATETIME DEFAULT vInventoryDate - INTERVAL 1 SECOND; DECLARE vWarehouseOutFkInventory INT; DECLARE vInventorySupplierFk INT; DECLARE vAgencyModeFkInventory INT; + DECLARE vMaxRecentInventories INT; + DECLARE vWarehouseFk INT; DECLARE cWarehouses CURSOR FOR SELECT id FROM warehouse - WHERE isInventory - AND vWh IN (0,id); + WHERE isInventory; + + DECLARE CONTINUE HANDLER FOR SQLEXCEPTION + BEGIN + ROLLBACK; + RESIGNAL; + END; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; + SELECT inventorySupplierFk INTO vInventorySupplierFk FROM entryConfig LIMIT 1; + SELECT inventoried INTO vDateLastInventory FROM config LIMIT 1; + SELECT maxRecentInventories, + warehouseOutFk, + agencyModeFk + INTO vMaxRecentInventories, + vWarehouseOutFkInventory, + vAgencyModeFkInventory + FROM inventoryConfig + LIMIT 1; + + IF vDateLastInventory IS NULL + OR vInventorySupplierFk IS NULL + OR vMaxRecentInventories IS NULL + OR vInventoryDate IS NULL + OR vWarehouseOutFkInventory IS NULL + OR vAgencyModeFkInventory IS NULL THEN + CALL util.throw('Some config parameters are not set'); + END IF; + + START TRANSACTION; + OPEN cWarehouses; + -- Environment variable to disable the triggers of the affected tables SET @isModeInventory := TRUE; l: LOOP - SET vDone = FALSE; - FETCH cWarehouses INTO vWh; + SET vEntryFk = NULL; + SET vTravelFk = NULL; + + FETCH cWarehouses INTO vWarehouseFk; IF vDone THEN LEAVE l; END IF; - SELECT w.id INTO vWarehouseOutFkInventory - FROM warehouse w - WHERE w.code = 'inv'; - - SELECT inventorySupplierFk INTO vInventorySupplierFk - FROM entryConfig; - - SELECT am.id INTO vAgencyModeFkInventory - FROM agencyMode am - where code = 'inv'; - - SELECT MAX(landed) INTO vDateLastInventory - FROM travel tr - JOIN entry e ON e.travelFk = tr.id - JOIN buy b ON b.entryFk = e.id - WHERE warehouseOutFk = vWarehouseOutFkInventory - AND landed < vDate - AND e.supplierFk = vInventorySupplierFk - AND warehouseInFk = vWh - AND NOT isRaid; - - IF vDateLastInventory IS NULL THEN - SELECT inventoried INTO vDateLastInventory FROM config; - END IF; - - -- Generamos travel, si no existe. - SET vTravelFK = 0; - + -- Generate travel, if it does not exist SELECT id INTO vTravelFk FROM travel WHERE warehouseOutFk = vWarehouseOutFkInventory - AND warehouseInFk = vWh - AND landed = vDate + AND warehouseInFk = vWarehouseFk + AND landed = vInventoryDate AND agencyModeFk = vAgencyModeFkInventory AND ref = 'inventario' LIMIT 1; - IF NOT vTravelFK THEN - - INSERT INTO travel SET - warehouseOutFk = vWarehouseOutFkInventory, - warehouseInFk = vWh, - shipped = vDate, - landed = vDate, - agencyModeFk = vAgencyModeFkInventory, - ref = 'inventario', - isDelivered = TRUE, - isReceived = TRUE; + IF vTravelFk IS NULL THEN + INSERT INTO travel + SET warehouseOutFk = vWarehouseOutFkInventory, + warehouseInFk = vWarehouseFk, + shipped = vInventoryDate, + landed = vInventoryDate, + agencyModeFk = vAgencyModeFkInventory, + ref = 'inventario', + isDelivered = TRUE, + isReceived = TRUE; SELECT LAST_INSERT_ID() INTO vTravelFk; - END IF; - -- Generamos entrada si no existe, o la vaciamos. - SET vEntryFk = 0; - + -- Generate an entry if it does not exist, or we empty it SELECT id INTO vEntryFk FROM entry WHERE supplierFk = vInventorySupplierFk AND travelFk = vTravelFk; - IF NOT vEntryFk THEN - - INSERT INTO entry SET - supplierFk = vInventorySupplierFk, - isConfirmed = TRUE, - isOrdered = TRUE, - travelFk = vTravelFk; + IF vEntryFk IS NULL THEN + INSERT INTO entry + SET supplierFk = vInventorySupplierFk, + isConfirmed = TRUE, + isOrdered = TRUE, + travelFk = vTravelFk; SELECT LAST_INSERT_ID() INTO vEntryFk; - ELSE - DELETE FROM buy WHERE entryFk = vEntryFk; - END IF; - -- Preparamos tabla auxilar - CREATE OR REPLACE TEMPORARY TABLE tmp.inventory ( - itemFk INT(11) NOT NULL PRIMARY KEY, - quantity int(11) DEFAULT '0', - buyingValue decimal(10,4) DEFAULT '0.0000', - freightValue decimal(10,3) DEFAULT '0.000', - packing int(11) DEFAULT '0', - `grouping` smallint(5) unsigned NOT NULL DEFAULT '1', - groupingMode tinyint(4) NOT NULL DEFAULT 0 , - comissionValue decimal(10,3) DEFAULT '0.000', - packageValue decimal(10,3) DEFAULT '0.000', - packageFk varchar(10) COLLATE utf8_unicode_ci DEFAULT '--', - price1 decimal(10,2) DEFAULT '0.00', - price2 decimal(10,2) DEFAULT '0.00', - price3 decimal(10,2) DEFAULT '0.00', - minPrice decimal(10,2) DEFAULT '0.00', - producer varchar(50) COLLATE utf8_unicode_ci DEFAULT NULL, - INDEX (itemFK)) ENGINE = MEMORY; + -- Prepare the auxiliary table + CREATE OR REPLACE TEMPORARY TABLE tInventory ( + itemFk INT(11) NOT NULL PRIMARY KEY, + quantity int(11) DEFAULT '0', + buyingValue decimal(10,4) DEFAULT '0.0000', + freightValue decimal(10,3) DEFAULT '0.000', + packing int(11) DEFAULT '0', + `grouping` smallint(5) unsigned NOT NULL DEFAULT '1', + groupingMode tinyint(4) NOT NULL DEFAULT 0 , + comissionValue decimal(10,3) DEFAULT '0.000', + packageValue decimal(10,3) DEFAULT '0.000', + packageFk varchar(10) COLLATE utf8_unicode_ci DEFAULT '--', + price1 decimal(10,2) DEFAULT '0.00', + price2 decimal(10,2) DEFAULT '0.00', + price3 decimal(10,2) DEFAULT '0.00', + minPrice decimal(10,2) DEFAULT '0.00', + producer varchar(50) COLLATE utf8_unicode_ci DEFAULT NULL, + INDEX (itemFK) + ) ENGINE = MEMORY; - -- Compras - INSERT INTO tmp.inventory(itemFk,quantity) + -- Buys + INSERT INTO tInventory(itemFk, quantity) SELECT b.itemFk, SUM(b.quantity) FROM buy b JOIN entry e ON e.id = b.entryFk JOIN travel tr ON tr.id = e.travelFk - WHERE tr.warehouseInFk = vWh - AND tr.landed BETWEEN vDateLastInventory - AND vDateYesterday + WHERE tr.warehouseInFk = vWarehouseFk + AND tr.landed BETWEEN vDateLastInventory AND vDateYesterday AND NOT isRaid GROUP BY b.itemFk; - SELECT vDateLastInventory , vDateYesterday; - -- Traslados - INSERT INTO tmp.inventory(itemFk, quantity) + -- Transfers + INSERT INTO tInventory(itemFk, quantity) SELECT itemFk, quantityOut - FROM ( + FROM ( SELECT b.itemFk,- SUM(b.quantity) quantityOut FROM buy b JOIN entry e ON e.id = b.entryFk JOIN travel tr ON tr.id = e.travelFk - WHERE tr.warehouseOutFk = vWh - AND tr.shipped BETWEEN vDateLastInventory - AND vDateYesterday + WHERE tr.warehouseOutFk = vWarehouseFk + AND tr.shipped BETWEEN vDateLastInventory AND vDateYesterday AND NOT isRaid GROUP BY b.itemFk ) sub ON DUPLICATE KEY UPDATE quantity = IFNULL(quantity, 0) + sub.quantityOut; - -- Ventas - INSERT INTO tmp.inventory(itemFk,quantity) + -- Sales + INSERT INTO tInventory(itemFk, quantity) SELECT itemFk, saleOut - FROM ( + FROM ( SELECT s.itemFk, - SUM(s.quantity) saleOut FROM sale s JOIN ticket t ON t.id = s.ticketFk - WHERE t.warehouseFk = vWh + WHERE t.warehouseFk = vWarehouseFk AND t.shipped BETWEEN vDateLastInventory AND vDateYesterday GROUP BY s.itemFk ) sub ON DUPLICATE KEY UPDATE quantity = IFNULL(quantity,0) + sub.saleOut; - -- Actualiza valores de la ultima compra - UPDATE tmp.inventory inv - JOIN cache.last_buy lb ON lb.item_id = inv.itemFk AND lb.warehouse_id = vWh + -- Update values of the last purchase + UPDATE tInventory inv + JOIN cache.last_buy lb ON lb.item_id = inv.itemFk AND lb.warehouse_id = vWarehouseFk JOIN buy b ON b.id = lb.buy_id JOIN item i ON i.id = b.itemFk LEFT JOIN producer p ON p.id = i.producerFk @@ -194,7 +187,7 @@ proc: BEGIN inv.minPrice = b.minPrice, inv.producer = p.name; - INSERT INTO buy( itemFk, + INSERT INTO buy(itemFk, quantity, buyingValue, freightValue, @@ -224,42 +217,53 @@ proc: BEGIN price3, minPrice, vEntryFk - FROM tmp.inventory; + FROM tInventory; - SELECT vWh, COUNT(*), util.VN_NOW() FROM tmp.inventory; - - -- Actualizamos el campo lastUsed de item - UPDATE item i - JOIN tmp.inventory i2 ON i2.itemFk = i.id - SET i.lastUsed = NOW() - WHERE i2.quantity; - - -- DROP TEMPORARY TABLE tmp.inventory; + -- Update the 'lastUsed' field of the item + UPDATE item i + JOIN tInventory i2 ON i2.itemFk = i.id + SET i.lastUsed = NOW() + WHERE i2.quantity; + + DROP TEMPORARY TABLE tInventory; END LOOP; - + CLOSE cWarehouses; - UPDATE config SET inventoried = vDate; - SET @isModeInventory := FALSE; + UPDATE config SET inventoried = vInventoryDate; - DROP TEMPORARY TABLE IF EXISTS tmp.entryToDelete; - CREATE TEMPORARY TABLE tmp.entryToDelete - (INDEX(entryId) USING BTREE) ENGINE = MEMORY - SELECT e.id as entryId, - t.id as travelId + SET @isModeInventory := FALSE; + + CREATE OR REPLACE TEMPORARY TABLE tEntryToDelete + (INDEX(entryId)) ENGINE = MEMORY + SELECT e.id entryId, + t.id travelId FROM travel t JOIN `entry` e ON e.travelFk = t.id + JOIN ( + SELECT t.shipped + FROM travel t + JOIN `entry` e ON e.travelFk = t.id + WHERE e.supplierFk = vInventorySupplierFk + AND t.shipped <= vInventoryDate + GROUP BY t.shipped + ORDER BY t.shipped DESC + OFFSET vMaxRecentInventories ROWS + ) sub WHERE e.supplierFk = vInventorySupplierFk - AND t.shipped <= util.VN_CURDATE() - INTERVAL 12 DAY - AND (DAY(t.shipped) <> 1 OR shipped < util.VN_CURDATE() - INTERVAL 12 DAY); + AND t.shipped IN (sub.shipped); - DELETE e + DELETE e FROM `entry` e - JOIN tmp.entryToDelete tmp ON tmp.entryId = e.id; + JOIN tEntryToDelete tmp ON tmp.entryId = e.id; DELETE IGNORE t FROM travel t - JOIN tmp.entryToDelete tmp ON tmp.travelId = t.id; + JOIN tEntryToDelete tmp ON tmp.travelId = t.id; + + DROP TEMPORARY TABLE IF EXISTS tEntryToDelete; + + COMMIT; END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/inventoryMakeLauncher.sql b/db/routines/vn/procedures/inventoryMakeLauncher.sql index 6f362f70e7..717e3c163d 100644 --- a/db/routines/vn/procedures/inventoryMakeLauncher.sql +++ b/db/routines/vn/procedures/inventoryMakeLauncher.sql @@ -2,10 +2,11 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`inventoryMakeLauncher`() BEGIN /** - * Recalcula los inventarios de todos los almacenes. + * Recalculate the inventories of all warehouses */ - - call vn.inventoryMake(TIMESTAMPADD(DAY, -10, util.VN_CURDATE()), 0); - + CALL inventoryMake( + util.VN_CURDATE() - + INTERVAL (SELECT daysInPastForInventory FROM inventoryConfig LIMIT 1) DAY + ); END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/invoiceInTaxMakeByDua.sql b/db/routines/vn/procedures/invoiceInTaxMakeByDua.sql index f415046698..2ff478d6b4 100644 --- a/db/routines/vn/procedures/invoiceInTaxMakeByDua.sql +++ b/db/routines/vn/procedures/invoiceInTaxMakeByDua.sql @@ -1,32 +1,35 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceInTaxMakeByDua`(vDuaFk INT) BEGIN - - DECLARE done BOOL DEFAULT FALSE; +/** + * Borra los valores de duaTax y sus vctos. y los vuelve a crear en base a la tabla duaEntry + * + * @param vDuaFk Id del dua a recalcular + */ + DECLARE vDone BOOL DEFAULT FALSE; DECLARE vInvoiceInFk INT; - DECLARE rs CURSOR FOR - SELECT invoiceInFk - FROM entry e - JOIN duaEntry de ON de.entryFk = e.id - WHERE de.duaFk = vDuaFk; + DECLARE vInvoices CURSOR FOR + SELECT DISTINCT invoiceInFk + FROM entry e + JOIN duaEntry de ON de.entryFk = e.id + WHERE de.duaFk = vDuaFk; - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; - OPEN rs; + OPEN vInvoices; + l: LOOP + SET vDone = FALSE; + FETCH vInvoices INTO vInvoiceInFk; - FETCH rs INTO vInvoiceInFk; - - WHILE NOT done DO + IF vDone THEN + LEAVE l; + END IF; CALL vn2008.recibidaIvaInsert(vInvoiceInFk); CALL invoiceInDueDay_recalc(vInvoiceInFk); - FETCH rs INTO vInvoiceInFk; - - END WHILE; - - CLOSE rs; - + END LOOP; + CLOSE vInvoices; END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/invoiceInTax_getFromDua.sql b/db/routines/vn/procedures/invoiceInTax_getFromDua.sql index c7574f72f4..bf2cbe61e0 100644 --- a/db/routines/vn/procedures/invoiceInTax_getFromDua.sql +++ b/db/routines/vn/procedures/invoiceInTax_getFromDua.sql @@ -1,32 +1,35 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceInTax_getFromDua`(vDuaFk INT) BEGIN - - DECLARE done BOOL DEFAULT FALSE; +/** + * Borra los valores de duaTax y sus vctos. y los vuelve a crear en base a la tabla duaEntry + * + * @param vDuaFk Id del dua a recalcular + */ + DECLARE vDone BOOL DEFAULT FALSE; DECLARE vInvoiceInFk INT; - DECLARE rs CURSOR FOR - SELECT invoiceInFk + DECLARE vInvoices CURSOR FOR + SELECT DISTINCT invoiceInFk FROM entry e JOIN duaEntry de ON de.entryFk = e.id WHERE de.duaFk = vDuaFk; - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; - OPEN rs; + OPEN vInvoices; + l: LOOP + SET vDone = FALSE; + FETCH vInvoices INTO vInvoiceInFk; - FETCH rs INTO vInvoiceInFk; - - WHILE NOT done DO + IF vDone THEN + LEAVE l; + END IF; CALL invoiceInTax_getFromEntries(vInvoiceInFk); CALL invoiceInDueDay_calculate(vInvoiceInFk); - - FETCH rs INTO vInvoiceInFk; - - END WHILE; - - CLOSE rs; + END LOOP; + CLOSE vInvoices; END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/invoiceInTax_getFromEntries.sql b/db/routines/vn/procedures/invoiceInTax_getFromEntries.sql index 14cc43e154..5a53b75436 100644 --- a/db/routines/vn/procedures/invoiceInTax_getFromEntries.sql +++ b/db/routines/vn/procedures/invoiceInTax_getFromEntries.sql @@ -1,13 +1,22 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceInTax_getFromEntries`(IN vId INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceInTax_getFromEntries`(IN vInvoiceInFk INT) BEGIN DECLARE vRate DOUBLE DEFAULT 1; DECLARE vDated DATE; DECLARE vExpenseFk VARCHAR(10); + DECLARE vIsBooked BOOLEAN DEFAULT FALSE; + SELECT isBooked INTO vIsBooked + FROM invoiceIn ii + WHERE id = vInvoiceInFk; + + IF vIsBooked THEN + CALL util.throw('A booked invoice cannot be modified'); + END IF; + SELECT MAX(rr.dated) INTO vDated FROM referenceRate rr - JOIN invoiceIn ii ON ii.id = vId + JOIN invoiceIn ii ON ii.id = vInvoiceInFk WHERE rr.dated <= ii.issued AND rr.currencyFk = ii.currencyFk ; @@ -24,7 +33,7 @@ BEGIN LIMIT 1; DELETE FROM invoiceInTax - WHERE invoiceInFk = vId; + WHERE invoiceInFk = vInvoiceInFk; INSERT INTO invoiceInTax(invoiceInFk, taxableBase, expenseFk, foreignValue, taxTypeSageFk, transactionTypeSageFk) SELECT ii.id, @@ -39,7 +48,7 @@ BEGIN JOIN buy b ON b.entryFk = e.id LEFT JOIN referenceRate rr ON rr.currencyFk = ii.currencyFk AND rr.dated = ii.issued - WHERE ii.id = vId + WHERE ii.id = vInvoiceInFk HAVING taxableBase IS NOT NULL; END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/itemProposal_Add.sql b/db/routines/vn/procedures/itemProposal_Add.sql index 5a01cb67ab..ac4dfa5d54 100644 --- a/db/routines/vn/procedures/itemProposal_Add.sql +++ b/db/routines/vn/procedures/itemProposal_Add.sql @@ -67,4 +67,4 @@ BEGIN COMMIT; END$$ -DELIMITER ; \ No newline at end of file +DELIMITER ; diff --git a/db/routines/vn/procedures/itemShelving_selfConsumption.sql b/db/routines/vn/procedures/itemShelving_selfConsumption.sql index aa6c341991..c974d99030 100644 --- a/db/routines/vn/procedures/itemShelving_selfConsumption.sql +++ b/db/routines/vn/procedures/itemShelving_selfConsumption.sql @@ -20,20 +20,23 @@ BEGIN DECLARE vCompanyFk INT; DECLARE vAgencyModeFk INT; DECLARE vItemShelvingFk INT; + DECLARE vAddressFk INT; SELECT c.id, pc.clientSelfConsumptionFk, - s.warehouseFk + s.warehouseFk, + pc.addressSelfConsumptionFk INTO vCompanyFk, vClientFk, - vWarehouseFk + vWarehouseFk, + vAddressFk FROM company c JOIN address a ON a.clientFk = c.clientFk JOIN warehouse w ON w.addressFk = a.id JOIN sector s ON s.warehouseFk = w.id JOIN parking p ON p.sectorFk = s.id JOIN shelving s2 ON s2.parkingFk = p.id - JOIN productionConfig pc ON TRUE + JOIN productionConfig pc WHERE s2.code = vShelvingFk; IF vClientFk IS NULL THEN @@ -65,7 +68,7 @@ BEGIN vClientFk, vWarehouseFk, CURDATE(), - NULL, + vAddressFk, vCompanyFk, NULL, vTicketFk diff --git a/db/routines/vn/procedures/test.sql b/db/routines/vn/procedures/test.sql deleted file mode 100644 index 69340291d6..0000000000 --- a/db/routines/vn/procedures/test.sql +++ /dev/null @@ -1,6 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`test`() -BEGIN -select 'procedimiento ejecutado con éxito'; -END$$ -DELIMITER ; diff --git a/db/routines/vn/procedures/ticket_getMovable.sql b/db/routines/vn/procedures/ticket_getMovable.sql index b69fa220ab..eee165538d 100644 --- a/db/routines/vn/procedures/ticket_getMovable.sql +++ b/db/routines/vn/procedures/ticket_getMovable.sql @@ -1,44 +1,55 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getMovable`(vTicketFk INT, vDatedNew DATETIME, vWarehouseFk INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getMovable`( + vTicketFk INT, + vNewShipped DATETIME, + vWarehouseFk INT +) BEGIN /** * Cálcula el stock movible para los artículos de un ticket - * vDatedNew debe ser menor que vDatedOld, en los otros casos se + * vNewShipped debe ser menor que vOldShipped, en los otros casos se * asume que siempre es posible * * @param vTicketFk -> Ticket - * @param vDatedNew -> Nueva fecha + * @param vNewShipped -> Nueva fecha * @return Sales con Movible -*/ - DECLARE vDatedOld DATETIME; - SET vDatedNew = DATE_ADD(vDatedNew, INTERVAL 1 DAY); +*/ + DECLARE vOldShipped DATETIME; - SELECT t.shipped INTO vDatedOld - FROM ticket t + SELECT t.shipped INTO vOldShipped + FROM ticket t WHERE t.id = vTicketFk; - CALL item_getStock(vWarehouseFk, vDatedNew, NULL); - CALL item_getMinacum(vWarehouseFk, vDatedNew, DATEDIFF(DATE_SUB(vDatedOld, INTERVAL 1 DAY), vDatedNew), NULL); - - SELECT s.id, - s.itemFk, - s.quantity, - s.concept, - s.price, + -- Añadimos un dia más para calcular el stock hasta vNewShipped inclusive + CALL item_getStock(vWarehouseFk, DATE_ADD(vNewShipped, INTERVAL 1 DAY), NULL); + CALL item_getMinacum( + vWarehouseFk, + vNewShipped, + DATEDIFF(DATE_SUB(vOldShipped, INTERVAL 1 DAY), vNewShipped), + NULL + ); + + SELECT s.id, + s.itemFk, + s.quantity, + s.concept, + s.price, s.reserved, - s.discount, - i.image, - i.subName, + s.discount, + i.image, + i.subName, il.stock + IFNULL(im.amount, 0) AS movable FROM ticket t JOIN sale s ON s.ticketFk = t.id - JOIN item i ON i.id = s.itemFk - LEFT JOIN tmp.itemMinacum im ON im.itemFk = s.itemFk AND im.warehouseFk = vWarehouseFk + JOIN item i ON i.id = s.itemFk + LEFT JOIN tmp.itemMinacum im ON im.itemFk = s.itemFk + AND im.warehouseFk = vWarehouseFk LEFT JOIN tmp.itemList il ON il.itemFk = s.itemFk WHERE t.id = vTicketFk; - DROP TEMPORARY TABLE IF EXISTS tmp.itemList; - DROP TEMPORARY TABLE IF EXISTS tmp.itemMinacum; - + DROP TEMPORARY TABLE IF EXISTS + tmp.itemList, + tmp.itemMinacum; + END$$ DELIMITER ; diff --git a/db/routines/vn/triggers/calendar_afterDelete.sql b/db/routines/vn/triggers/calendar_afterDelete.sql index acd2c55b73..5d0114ea8e 100644 --- a/db/routines/vn/triggers/calendar_afterDelete.sql +++ b/db/routines/vn/triggers/calendar_afterDelete.sql @@ -1,12 +1,12 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`calendar_afterDelete` - AFTER DELETE ON `calendar` - FOR EACH ROW +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`calendar_afterDelete` + AFTER DELETE ON `calendar` + FOR EACH ROW BEGIN INSERT INTO workerLog SET `action` = 'delete', `changedModel` = 'Calendar', `changedModelId` = OLD.id, `userFk` = account.myUser_getId(); -END$$ -DELIMITER ; \ No newline at end of file +END$$ +DELIMITER ; diff --git a/db/routines/vn/triggers/calendar_beforeInsert.sql b/db/routines/vn/triggers/calendar_beforeInsert.sql index 9e51e6d18a..3e265a099a 100644 --- a/db/routines/vn/triggers/calendar_beforeInsert.sql +++ b/db/routines/vn/triggers/calendar_beforeInsert.sql @@ -5,4 +5,4 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`calendar_beforeInsert BEGIN SET NEW.editorFk = account.myUser_getId(); END$$ -DELIMITER ; \ No newline at end of file +DELIMITER ; diff --git a/db/routines/vn/triggers/calendar_beforeUpdate.sql b/db/routines/vn/triggers/calendar_beforeUpdate.sql index bb1ba53c3d..f015dc29af 100644 --- a/db/routines/vn/triggers/calendar_beforeUpdate.sql +++ b/db/routines/vn/triggers/calendar_beforeUpdate.sql @@ -1,8 +1,8 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`calendar_beforeUpdate` - BEFORE UPDATE ON `calendar` - FOR EACH ROW +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`calendar_beforeUpdate` + BEFORE UPDATE ON `calendar` + FOR EACH ROW BEGIN SET NEW.editorFk = account.myUser_getId(); -END$$ -DELIMITER ; \ No newline at end of file +END$$ +DELIMITER ; diff --git a/db/routines/vn/triggers/saleGroup_beforeInser.sql b/db/routines/vn/triggers/saleGroup_beforeInsert.sql similarity index 100% rename from db/routines/vn/triggers/saleGroup_beforeInser.sql rename to db/routines/vn/triggers/saleGroup_beforeInsert.sql diff --git a/db/routines/vn/triggers/workerTimeControl_afterDelete.sql b/db/routines/vn/triggers/workerTimeControl_afterDelete.sql index 6f0f00dbfb..19653c913b 100644 --- a/db/routines/vn/triggers/workerTimeControl_afterDelete.sql +++ b/db/routines/vn/triggers/workerTimeControl_afterDelete.sql @@ -1,12 +1,12 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`workerTimeControl_afterDelete` - AFTER DELETE ON `workerTimeControl` - FOR EACH ROW +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`workerTimeControl_afterDelete` + AFTER DELETE ON `workerTimeControl` + FOR EACH ROW BEGIN INSERT INTO workerLog SET `action` = 'delete', `changedModel` = 'WorkerTimeControl', `changedModelId` = OLD.id, `userFk` = account.myUser_getId(); -END$$ -DELIMITER ; \ No newline at end of file +END$$ +DELIMITER ; diff --git a/db/routines/vn/triggers/workerTimeControl_beforeInsert.sql b/db/routines/vn/triggers/workerTimeControl_beforeInsert.sql index a899b879a8..ad7acb7849 100644 --- a/db/routines/vn/triggers/workerTimeControl_beforeInsert.sql +++ b/db/routines/vn/triggers/workerTimeControl_beforeInsert.sql @@ -1,8 +1,8 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`workerTimeControl_beforeInsert` - BEFORE INSERT ON `workerTimeControl` - FOR EACH ROW +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`workerTimeControl_beforeInsert` + BEFORE INSERT ON `workerTimeControl` + FOR EACH ROW BEGIN SET NEW.editorFk = account.myUser_getId(); -END$$ -DELIMITER ; \ No newline at end of file +END$$ +DELIMITER ; diff --git a/db/routines/vn/triggers/workerTimeControl_beforeUpdate.sql b/db/routines/vn/triggers/workerTimeControl_beforeUpdate.sql index 969e087115..bb391ad619 100644 --- a/db/routines/vn/triggers/workerTimeControl_beforeUpdate.sql +++ b/db/routines/vn/triggers/workerTimeControl_beforeUpdate.sql @@ -1,8 +1,8 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`workerTimeControl_beforeUpdate` - BEFORE UPDATE ON `workerTimeControl` - FOR EACH ROW +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`workerTimeControl_beforeUpdate` + BEFORE UPDATE ON `workerTimeControl` + FOR EACH ROW BEGIN SET NEW.editorFk = account.myUser_getId(); -END$$ -DELIMITER ; \ No newline at end of file +END$$ +DELIMITER ; diff --git a/db/routines/vn/views/awbVolume.sql b/db/routines/vn/views/awbVolume.sql index 2c77973ca6..df3b1ed1a6 100644 --- a/db/routines/vn/views/awbVolume.sql +++ b/db/routines/vn/views/awbVolume.sql @@ -28,4 +28,4 @@ FROM ( JOIN `vn`.`volumeConfig` `vc` ) WHERE `t`.`shipped` > makedate(year(`util`.`VN_CURDATE`()) - 1, 1) - AND t.awbFk \ No newline at end of file + AND `t`.`awbFk` <> 0 diff --git a/db/routines/vn/views/expeditionPallet_Print.sql b/db/routines/vn/views/expeditionPallet_Print.sql index 4e9e8cb0e7..07627e8177 100644 --- a/db/routines/vn/views/expeditionPallet_Print.sql +++ b/db/routines/vn/views/expeditionPallet_Print.sql @@ -9,7 +9,7 @@ AS SELECT `et2`.`description` AS `truck`, `et`.`id` <=> `rm`.`expeditionTruckFk` AS `isMatch`, `t`.`warehouseFk` AS `warehouseFk`, IF( - `r`.`created` > util.VN_CURDATE() + INTERVAL 1 DAY, + `r`.`created` > `util`.`VN_CURDATE`() + INTERVAL 1 DAY, ucase(dayname(`r`.`created`)), NULL ) AS `nombreDia` diff --git a/db/routines/vn/views/itemShelvingAvailable.sql b/db/routines/vn/views/itemShelvingAvailable.sql index ee4ef62b60..868d6a963b 100644 --- a/db/routines/vn/views/itemShelvingAvailable.sql +++ b/db/routines/vn/views/itemShelvingAvailable.sql @@ -1,7 +1,7 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `vn`.`itemShelvingAvailable` -AS SELECT `s`.`id` `saleFk`, +AS SELECT `s`.`id` AS `saleFk`, `tst`.`updated` AS `Modificado`, `s`.`ticketFk` AS `ticketFk`, 0 AS `isPicked`, diff --git a/db/routines/vn/views/ticketStateToday.sql b/db/routines/vn/views/ticketStateToday.sql index 2ee65b7c28..1f10aceb1f 100644 --- a/db/routines/vn/views/ticketStateToday.sql +++ b/db/routines/vn/views/ticketStateToday.sql @@ -1,8 +1,7 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `vn`.`ticketStateToday` -AS SELECT - `ts`.`ticketFk` AS `ticketFk`, +AS SELECT `ts`.`ticketFk` AS `ticketFk`, `ts`.`state` AS `state`, `ts`.`productionOrder` AS `productionOrder`, `ts`.`alertLevel` AS `alertLevel`, @@ -10,6 +9,8 @@ AS SELECT `ts`.`code` AS `code`, `ts`.`updated` AS `updated`, `ts`.`isPicked` AS `isPicked` -FROM `ticketState` `ts` - JOIN `ticket` `t` ON `t`.`id` = `ts`.`ticketFk` -WHERE `t`.`shipped` BETWEEN `util`.`VN_CURDATE`() AND `MIDNIGHT`(`util`.`VN_CURDATE`()); +FROM ( + `vn`.`ticketState` `ts` + JOIN `vn`.`ticket` `t` ON(`t`.`id` = `ts`.`ticketFk`) + ) +WHERE `t`.`shipped` BETWEEN `util`.`VN_CURDATE`() AND `MIDNIGHT`(`util`.`VN_CURDATE`()) diff --git a/db/routines/vn/views/zoneEstimatedDelivery.sql b/db/routines/vn/views/zoneEstimatedDelivery.sql index 621d1a8f00..081ccb0bd4 100644 --- a/db/routines/vn/views/zoneEstimatedDelivery.sql +++ b/db/routines/vn/views/zoneEstimatedDelivery.sql @@ -1,25 +1,48 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `vn`.`zoneEstimatedDelivery` - AS SELECT t.zoneFk, - zc.`hour` zoneClosureHour, - z.`hour` zoneHour, - sv.volume volume, - al.hasToRecalcPrice, - lhp.m3, - dl.minSpeed - FROM ticket t - JOIN ticketStateToday tst ON tst.ticketFk = t.id - JOIN state s ON s.id = tst.state - JOIN saleVolume sv ON sv.ticketFk = t.id - LEFT JOIN lastHourProduction lhp ON lhp.warehouseFk = t.warehouseFk - JOIN warehouse w ON w.id = t.warehouseFk - JOIN warehouseAlias wa ON wa.id = w.aliasFk - STRAIGHT_JOIN `zone` z ON z.id = t.zoneFk - LEFT JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk - AND zc.dated = util.VN_CURDATE() - LEFT JOIN cache.departure_limit dl ON dl.warehouse_id = t.warehouseFk - AND dl.fecha = util.VN_CURDATE() - JOIN alertLevel al ON al.id = s.alertLevel - WHERE w.hasProduction - AND DATE(t.shipped) = util.VN_CURDATE() +AS SELECT `t`.`zoneFk` AS `zoneFk`, + `zc`.`hour` AS `zoneClosureHour`, + `z`.`hour` AS `zoneHour`, + `sv`.`volume` AS `volume`, + `al`.`hasToRecalcPrice` AS `hasToRecalcPrice`, + `lhp`.`m3` AS `m3`, + `dl`.`minSpeed` AS `minSpeed` +FROM ( + ( + ( + ( + ( + ( + ( + ( + ( + ( + `vn`.`ticket` `t` + JOIN `vn`.`ticketStateToday` `tst` ON(`tst`.`ticketFk` = `t`.`id`) + ) + JOIN `vn`.`state` `s` ON(`s`.`id` = `tst`.`state`) + ) + JOIN `vn`.`saleVolume` `sv` ON(`sv`.`ticketFk` = `t`.`id`) + ) + LEFT JOIN `vn`.`lastHourProduction` `lhp` ON(`lhp`.`warehouseFk` = `t`.`warehouseFk`) + ) + JOIN `vn`.`warehouse` `w` ON(`w`.`id` = `t`.`warehouseFk`) + ) + JOIN `vn`.`warehouseAlias` `wa` ON(`wa`.`id` = `w`.`aliasFk`) + ) STRAIGHT_JOIN `vn`.`zone` `z` ON(`z`.`id` = `t`.`zoneFk`) + ) + LEFT JOIN `vn`.`zoneClosure` `zc` ON( + `zc`.`zoneFk` = `t`.`zoneFk` + AND `zc`.`dated` = `util`.`VN_CURDATE`() + ) + ) + LEFT JOIN `cache`.`departure_limit` `dl` ON( + `dl`.`warehouse_id` = `t`.`warehouseFk` + AND `dl`.`fecha` = `util`.`VN_CURDATE`() + ) + ) + JOIN `vn`.`alertLevel` `al` ON(`al`.`id` = `s`.`alertLevel`) + ) +WHERE `w`.`hasProduction` <> 0 + AND cast(`t`.`shipped` AS date) = `util`.`VN_CURDATE`() diff --git a/db/routines/vn2008/procedures/recobro_credito.sql b/db/routines/vn2008/procedures/recobro_credito.sql index ca5304b6cf..fbb5ea1aa8 100644 --- a/db/routines/vn2008/procedures/recobro_credito.sql +++ b/db/routines/vn2008/procedures/recobro_credito.sql @@ -52,4 +52,4 @@ BEGIN DROP TEMPORARY TABLE clientes_credit; COMMIT; END$$ -DELIMITER ; \ No newline at end of file +DELIMITER ; diff --git a/db/routines/vn2008/views/v_xsubcuentas.sql b/db/routines/vn2008/views/v_xsubcuentas.sql index a200e4ad92..7f2075a83a 100644 --- a/db/routines/vn2008/views/v_xsubcuentas.sql +++ b/db/routines/vn2008/views/v_xsubcuentas.sql @@ -17,7 +17,7 @@ AS SELECT `Clientes`.`Cuenta` AS `COD`, `province`.`name` AS `PROVINCIA`, `Clientes`.`codPostal` AS `CODPOSTAL`, `p`.`Codigo` AS `country_code`, - sub.`empresa_id` AS `empresa_id`, + `sub`.`empresa_id` AS `empresa_id`, substr( `Clientes`.`e-mail`, 1, @@ -49,9 +49,7 @@ FROM ( `Recibos`.`empresa_id` AS `empresa_id` FROM `vn2008`.`Recibos` WHERE `Recibos`.`Fechacobro` > `util`.`VN_CURDATE`() + INTERVAL -2 MONTH - ) sub ON( - `Clientes`.`id_cliente` = sub.`Id_Cliente` - ) + ) `sub` ON(`Clientes`.`id_cliente` = `sub`.`Id_Cliente`) ) LEFT JOIN `vn2008`.`Paises` `p` ON(`p`.`Id` = `Clientes`.`Id_Pais`) ) @@ -60,7 +58,7 @@ FROM ( ) ) GROUP BY `Clientes`.`id_cliente`, - sub.`empresa_id` + `sub`.`empresa_id` UNION ALL SELECT `Proveedores`.`cuenta` AS `Cuenta`, `Proveedores`.`Proveedor` AS `Proveedor`, @@ -78,7 +76,7 @@ SELECT `Proveedores`.`cuenta` AS `Cuenta`, `prov`.`name` AS `Provincia`, `Proveedores`.`codpos` AS `CP`, `p`.`Codigo` AS `country_code`, - sub.`empresa_id` AS `empresa_id`, + `sub`.`empresa_id` AS `empresa_id`, substr( `c`.`email`, 1, @@ -104,8 +102,8 @@ FROM ( WHERE `pago`.`fecha` > `util`.`VN_CURDATE`() + INTERVAL -3 MONTH GROUP BY `pago`.`id_proveedor`, `pago`.`empresa_id` - ) sub ON( - `Proveedores`.`Id_Proveedor` = sub.`proveedor_id` + ) `sub` ON( + `Proveedores`.`Id_Proveedor` = `sub`.`proveedor_id` ) ) LEFT JOIN `vn2008`.`Paises` `p` ON(`p`.`Id` = `Proveedores`.`pais_id`) @@ -117,8 +115,8 @@ FROM ( LEFT JOIN `vn`.`supplierContact` `c` ON(`c`.`supplierFk` = `Proveedores`.`Id_Proveedor`) ) WHERE `Proveedores`.`oficial` <> 0 -GROUP BY sub.`proveedor_id`, - sub.`empresa_id` +GROUP BY `sub`.`proveedor_id`, + `sub`.`empresa_id` UNION ALL SELECT `Gastos`.`Id_Gasto` COLLATE utf8mb3_unicode_ci AS `Id_Gasto`, `Gastos`.`Gasto` COLLATE utf8mb3_unicode_ci AS `Gasto`, @@ -160,7 +158,7 @@ SELECT lpad(right(`Proveedores`.`cuenta`, 5), 10, '47510000') AS `Cuenta`, `prov`.`name` AS `Provincia`, `Proveedores`.`codpos` AS `CP`, `p`.`Codigo` AS `country_code`, - sub.`empresa_id` AS `empresa_id`, + `sub`.`empresa_id` AS `empresa_id`, substr( `c`.`email`, 1, @@ -186,8 +184,8 @@ FROM ( WHERE `pago`.`fecha` > `util`.`VN_CURDATE`() + INTERVAL -3 MONTH GROUP BY `pago`.`id_proveedor`, `pago`.`empresa_id` - ) sub ON( - `Proveedores`.`Id_Proveedor` = sub.`proveedor_id` + ) `sub` ON( + `Proveedores`.`Id_Proveedor` = `sub`.`proveedor_id` ) ) LEFT JOIN `vn2008`.`Paises` `p` ON(`p`.`Id` = `Proveedores`.`pais_id`) @@ -203,5 +201,5 @@ WHERE ( OR `Proveedores`.`cuenta` LIKE '_____2____' ) AND `Proveedores`.`oficial` = 1 -GROUP BY sub.`proveedor_id`, - sub.`empresa_id` +GROUP BY `sub`.`proveedor_id`, + `sub`.`empresa_id`