7152-devToTest_2414 #2228

Merged
alexm merged 636 commits from 7152-devToTest_2414 into test 2024-03-28 08:26:34 +00:00
5 changed files with 131 additions and 191 deletions
Showing only changes of commit fefc193ec0 - Show all commits

View File

@ -3,7 +3,7 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `cache`.`clean`()
BEGIN
DECLARE vDateShort DATETIME;
SET vDateShort = TIMESTAMPADD(MONTH, -1, util.VN_CURDATE());
SET vDateShort = util.VN_CURDATE() - INTERVAL 1 MONTH;
DELETE FROM cache.departure_limit WHERE Fecha < vDateShort;
END$$

View File

@ -1,48 +1,42 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`clean`()
BEGIN
DECLARE vDateShort DATETIME;
DECLARE vOneYearAgo DATE;
DECLARE vFourYearsAgo DATE;
DECLARE vFiveYearsAgo DATE;
DECLARE v18Month DATE;
DECLARE v26Month DATE;
DECLARE v3Month DATE;
/**
* Purges outdated data to optimize performance.
* Exercise caution when executing.
*/
DECLARE v2Months DATE DEFAULT util.VN_CURDATE() - INTERVAL 2 MONTH;
DECLARE v3Months DATE DEFAULT util.VN_CURDATE() - INTERVAL 3 MONTH;
DECLARE v18Months DATE DEFAULT util.VN_CURDATE() - INTERVAL 18 MONTH;
DECLARE v26Months DATE DEFAULT util.VN_CURDATE() - INTERVAL 26 MONTH;
DECLARE v1Years DATE DEFAULT util.VN_CURDATE() - INTERVAL 1 YEAR;
DECLARE v2Years DATE DEFAULT util.VN_CURDATE() - INTERVAL 2 YEAR;
DECLARE v4Years DATE DEFAULT util.VN_CURDATE() - INTERVAL 4 YEAR;
DECLARE v5Years DATE DEFAULT util.VN_CURDATE() - INTERVAL 5 YEAR;
DECLARE vTrashId VARCHAR(15);
DECLARE v2Years DATE;
DECLARE v5Years DATE;
SET vDateShort = util.VN_CURDATE() - INTERVAL 2 MONTH;
SET vOneYearAgo = util.VN_CURDATE() - INTERVAL 1 YEAR;
SET vFourYearsAgo = util.VN_CURDATE() - INTERVAL 4 YEAR;
SET vFiveYearsAgo = util.VN_CURDATE() - INTERVAL 5 YEAR;
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;
DECLARE vCompanyBlk INT;
DELETE FROM workerActivity WHERE created < v2Years;
DELETE FROM ticketParking WHERE created < vDateShort;
DELETE FROM routesMonitor WHERE dated < vDateShort;
DELETE FROM workerTimeControlLog WHERE created < vDateShort;
DELETE FROM `message` WHERE sendDate < vDateShort;
DELETE FROM messageInbox WHERE sendDate < vDateShort;
DELETE FROM messageInbox WHERE sendDate < vDateShort;
DELETE FROM workerTimeControl WHERE timed < vFourYearsAgo;
DELETE FROM ticketParking WHERE created < v2Months;
DELETE FROM routesMonitor WHERE dated < v2Months;
DELETE FROM workerTimeControlLog WHERE created < v2Months;
DELETE FROM `message` WHERE sendDate < v2Months;
DELETE FROM messageInbox WHERE sendDate < v2Months;
DELETE FROM messageInbox WHERE sendDate < v2Months;
DELETE FROM workerTimeControl WHERE timed < v4Years;
DELETE FROM itemShelving WHERE created < util.VN_CURDATE() AND visible = 0;
DELETE FROM ticketDown WHERE created < TIMESTAMPADD(DAY,-1,util.VN_CURDATE());
DELETE FROM entryLog WHERE creationDate < vDateShort;
DELETE IGNORE FROM expedition WHERE created < v26Month;
DELETE FROM sms WHERE created < v18Month;
DELETE FROM saleTracking WHERE created < vOneYearAgo;
DELETE FROM ticketTracking WHERE created < v18Month;
DELETE FROM ticketDown WHERE created < util.yesterday();
DELETE FROM entryLog WHERE creationDate < v2Months;
DELETE IGNORE FROM expedition WHERE created < v26Months;
DELETE FROM sms WHERE created < v18Months;
DELETE FROM saleTracking WHERE created < v1Years;
DELETE FROM ticketTracking WHERE created < v18Months;
DELETE tobs FROM ticketObservation tobs
JOIN ticket t ON tobs.ticketFk = t.id
WHERE t.shipped < v5Years;
DELETE sc.* FROM saleCloned sc JOIN sale s ON s.id = sc.saleClonedFk JOIN ticket t ON t.id = s.ticketFk WHERE t.shipped < vOneYearAgo;
DELETE FROM sharingCart where ended < vDateShort;
DELETE FROM sharingClient where ended < vDateShort;
DELETE sc.* FROM saleCloned sc JOIN sale s ON s.id = sc.saleClonedFk JOIN ticket t ON t.id = s.ticketFk WHERE t.shipped < v1Years;
DELETE FROM sharingCart where ended < v2Months;
DELETE FROM sharingClient where ended < v2Months;
DELETE tw.* FROM ticketWeekly tw
LEFT JOIN sale s ON s.ticketFk = tw.ticketFk
LEFT JOIN ticketRequest tr ON tr.ticketFk = tw.ticketFk
@ -50,73 +44,73 @@ BEGIN
WHERE s.id IS NULL
AND tr.id IS NULL
AND ts.id IS NULL;
DELETE FROM claim WHERE ticketCreated < vFourYearsAgo;
DELETE FROM message WHERE sendDate < vDateShort;
-- Robert ubicacion anterior de trevelLog comentario para debug
DELETE FROM zoneEvent WHERE `type` = 'day' AND dated < v3Month;
DELETE FROM claim WHERE ticketCreated < v4Years;
-- Robert ubicacion anterior de travelLog comentario para debug
DELETE FROM zoneEvent WHERE `type` = 'day' AND dated < v3Months;
DELETE bm
FROM buyMark bm
JOIN buy b ON b.id = bm.id
JOIN entry e ON e.id = b.entryFk
JOIN travel t ON t.id = e.travelFk
WHERE t.landed <= vDateShort;
DELETE b FROM vn.buy b
JOIN vn.entryConfig e ON e.defaultEntry = b.entryFk
WHERE b.created < vDateShort;
DELETE FROM vn.itemShelvingLog WHERE created < vDateShort;
DELETE FROM vn.stockBuyed WHERE creationDate < vDateShort;
DELETE FROM vn.itemCleanLog WHERE created < util.VN_NOW() - INTERVAL 1 YEAR;
DELETE FROM printQueue WHERE statusCode = 'printed' AND created < vDateShort;
DELETE FROM ticketLog WHERE creationDate <= vFiveYearsAgo;
WHERE t.landed <= v2Months;
DELETE b FROM buy b
JOIN entryConfig e ON e.defaultEntry = b.entryFk
WHERE b.created < v2Months;
DELETE FROM itemShelvingLog WHERE created < v2Months;
DELETE FROM stockBuyed WHERE creationDate < v2Months;
DELETE FROM itemCleanLog WHERE created < util.VN_NOW() - INTERVAL 1 YEAR;
DELETE FROM printQueue WHERE statusCode = 'printed' AND created < v2Months;
DELETE FROM ticketLog WHERE creationDate <= v5Years;
-- Equipos duplicados
DELETE w.*
FROM workerTeam w
JOIN (SELECT id, team, workerFk, COUNT(*) - 1 as duplicated
JOIN (
SELECT id, team, workerFk, COUNT(*) - 1 duplicated
FROM workerTeam
GROUP BY team,workerFk
HAVING duplicated
) d ON d.team = w.team AND d.workerFk = w.workerFk AND d.id != w.id;
) d ON d.team = w.team
AND d.workerFk = w.workerFk
AND d.id <> w.id;
DELETE sc
FROM saleComponent sc
JOIN sale s ON s.id= sc.saleFk
JOIN ticket t ON t.id= s.ticketFk
WHERE t.shipped < v18Month;
WHERE t.shipped < v18Months;
DELETE c
FROM vn.claim c
JOIN vn.claimState cs ON cs.id = c.claimStateFk
WHERE cs.description = "Anulado" AND
c.created < vDateShort;
DELETE
FROM vn.expeditionTruck
WHERE eta < v3Month;
FROM claim c
JOIN claimState cs ON cs.id = c.claimStateFk
WHERE cs.description = "Anulado"
AND c.created < v2Months;
DELETE FROM XDiario WHERE FECHA < v3Month OR FECHA IS NULL;
-- borrar travels sin entradas
DROP TEMPORARY TABLE IF EXISTS tmp.thermographToDelete;
CREATE TEMPORARY TABLE tmp.thermographToDelete
DELETE FROM expeditionTruck WHERE eta < v3Months;
DELETE FROM XDiario WHERE FECHA < v3Months OR FECHA IS NULL;
-- Borrar travels sin entradas
CREATE OR REPLACE TEMPORARY TABLE tThermographToDelete
SELECT th.id,th.dmsFk
FROM vn.travel t
LEFT JOIN vn.entry e ON e.travelFk = t.id
JOIN vn.travelThermograph th ON th.travelFk = t.id
FROM travel t
LEFT JOIN entry e ON e.travelFk = t.id
JOIN travelThermograph th ON th.travelFk = t.id
WHERE t.shipped < TIMESTAMPADD(MONTH, -3, util.VN_CURDATE()) AND e.travelFk IS NULL;
SELECT dt.id INTO vTrashId
FROM vn.dmsType dt
FROM dmsType dt
WHERE dt.code = 'trash';
UPDATE tmp.thermographToDelete th
JOIN vn.dms d ON d.id = th.dmsFk
UPDATE tThermographToDelete th
JOIN dms d ON d.id = th.dmsFk
SET d.dmsTypeFk = vTrashId;
DELETE th
FROM tmp.thermographToDelete tmp
JOIN vn.travelThermograph th ON th.id = tmp.id;
FROM tThermographToDelete tmp
JOIN travelThermograph th ON th.id = tmp.id;
DELETE t
FROM vn.travel t
LEFT JOIN vn.entry e ON e.travelFk = t.id
FROM travel t
LEFT JOIN entry e ON e.travelFk = t.id
WHERE t.shipped < TIMESTAMPADD(MONTH, -3, util.VN_CURDATE()) AND e.travelFk IS NULL;
UPDATE dms d
@ -125,69 +119,98 @@ BEGIN
WHERE created < TIMESTAMPADD(MONTH, -dt.monthToDelete, util.VN_CURDATE());
-- borrar entradas sin compras
DROP TEMPORARY TABLE IF EXISTS tmp.entryToDelete;
CREATE TEMPORARY TABLE tmp.entryToDelete
CREATE OR REPLACE TEMPORARY TABLE tEntryToDelete
SELECT e.*
FROM vn.entry e
LEFT JOIN vn.buy b ON b.entryFk = e.id
JOIN vn.entryConfig ec ON e.id != ec.defaultEntry
FROM entry e
LEFT JOIN buy b ON b.entryFk = e.id
JOIN entryConfig ec ON e.id <> ec.defaultEntry
WHERE e.dated < TIMESTAMPADD(MONTH, -3, util.VN_CURDATE()) AND b.entryFK IS NULL;
DELETE e
FROM vn.entry e
JOIN tmp.entryToDelete tmp ON tmp.id = e.id;
FROM entry e
JOIN tEntryToDelete tmp ON tmp.id = e.id;
-- borrar de route registros menores a 4 años
DROP TEMPORARY TABLE IF EXISTS tmp.routeToDelete;
CREATE TEMPORARY TABLE tmp.routeToDelete
CREATE OR REPLACE TEMPORARY TABLE tRouteToDelete
SELECT *
FROM vn.route r
FROM route r
WHERE created < TIMESTAMPADD(YEAR,-4,util.VN_CURDATE());
UPDATE tmp.routeToDelete tmp
JOIN vn.dms d ON d.id = tmp.gestdocFk
UPDATE tRouteToDelete tmp
JOIN dms d ON d.id = tmp.gestdocFk
SET d.dmsTypeFk = vTrashId;
DELETE r
FROM tmp.routeToDelete tmp
JOIN vn.route r ON r.id = tmp.id;
FROM tRouteToDelete tmp
JOIN route r ON r.id = tmp.id;
-- borrar registros de dua y awb menores a 2 años
DROP TEMPORARY TABLE IF EXISTS tmp.duaToDelete;
CREATE TEMPORARY TABLE tmp.duaToDelete
CREATE OR REPLACE TEMPORARY TABLE tDuaToDelete
SELECT *
FROM vn.dua
FROM dua
WHERE operated < TIMESTAMPADD(YEAR,-2,CURDATE());
UPDATE tmp.duaToDelete tm
JOIN vn.dms d ON d.id = tm.gestdocFk
UPDATE tDuaToDelete tm
JOIN dms d ON d.id = tm.gestdocFk
SET d.dmsTypeFk = vTrashId;
DELETE d
FROM tmp.duaToDelete tmp
JOIN vn.dua d ON d.id = tmp.id;
FROM tDuaToDelete tmp
JOIN dua d ON d.id = tmp.id;
DELETE a
FROM vn.awb a
LEFT JOIN vn.travel t ON t.awbFk = a.id
FROM awb a
LEFT JOIN 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;
DELETE FROM collection WHERE created < v2Months;
DELETE FROM travelLog WHERE creationDate < v3Months;
DROP TEMPORARY TABLE IF EXISTS tmp.thermographToDelete;
DROP TEMPORARY TABLE IF EXISTS tmp.entryToDelete;
DROP TEMPORARY TABLE IF EXISTS tmp.duaToDelete;
DELETE FROM travelLog WHERE creationDate < v3Month;
CALL shelving_clean;
CALL shelving_clean();
DELETE FROM chat WHERE dated < v5Years;
DELETE tt FROM ticketTracking tt
JOIN ticket t ON tt.ticketFk = t.id
WHERE t.shipped <= v2Months;
DELETE tt FROM ticketTracking tt JOIN vn.ticket t ON tt.ticketFk = t.id
WHERE t.shipped <= vDateShort;
-- Clean vn2008
DELETE FROM mail WHERE creationDate < v2Months;
DELETE FROM split WHERE dated < v18Months;
DELETE FROM remittance WHERE dated < v18Months;
CREATE OR REPLACE TEMPORARY TABLE tTicketDelete
SELECT DISTINCT tl.originFk ticketFk
FROM ticketLog tl
JOIN (
SELECT MAX(tl.id)ids
FROM ticket t
JOIN ticketLog tl ON tl.originFk = t.id
WHERE t.shipped BETWEEN '2000-01-01' AND '2000-12-31'
AND t.isDeleted
GROUP BY t.id
) sub ON sub.ids = tl.id
WHERE tl.creationDate <= util.VN_CURDATE() - INTERVAL 60 DAY;
DELETE t
FROM ticket t
JOIN tTicketDelete tmp ON tmp.ticketFk = t.id;
-- Tickets Nulos PAK 11/10/2016
SELECT id INTO vCompanyBlk FROM company WHERE code = 'BLK';
UPDATE ticket
SET companyFk = vCompanyBlk
WHERE clientFk = (SELECT id FROM client WHERE name = 'AUTOCONSUMO')
AND companyFk <> vCompanyBlk;
DROP TEMPORARY TABLE tTicketDelete,
tThermographToDelete,
tEntryToDelete,
tDuaToDelete,
tRouteToDelete;
-- Other schemas
DELETE FROM hedera.`order` WHERE date_send < v18Months;
DELETE FROM pbx.cdr WHERE call_date < v18Months;
END$$
DELIMITER ;

View File

@ -1,79 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`clean`(IN `v_full` TINYINT(1))
proc: BEGIN
DECLARE vDate DATETIME;
DECLARE vDate18 DATETIME;
DECLARE vDate26 DATETIME;
DECLARE vDate8 DATE;
DECLARE vDate6 DATE;
DECLARE vDate3 DATE;
DECLARE vDate2000 DATE;
DECLARE vRangeDeleteTicket INT;
DECLARE vStrtable VARCHAR(15) DEFAULT NULL;
SET vDate = util.VN_CURDATE() - INTERVAL 2 MONTH;
SET vDate18 = util.VN_CURDATE() - INTERVAL 18 MONTH;
SET vDate26 = util.VN_CURDATE() - INTERVAL 26 MONTH;
SET vDate3 = util.VN_CURDATE() - INTERVAL 3 MONTH;
SET vDate8 = util.VN_CURDATE() - INTERVAL 8 DAY;
SET vDate6 = util.VN_CURDATE() - INTERVAL 6 DAY;
SET vDate2000 = util.VN_CURDATE() + INTERVAL (2000 - YEAR(util.VN_CURDATE())) YEAR;
SET vRangeDeleteTicket = 60;
DELETE FROM cdr WHERE calldate < vDate18;
DELETE FROM mail WHERE DATE_ODBC < vDate;
DELETE FROM Movimientos_mark WHERE odbc_date < vDate;
DELETE FROM Splits WHERE Fecha < vDate18;
DELETE tobs
FROM movement_label tobs
JOIN Movimientos m ON tobs.Id_Movimiento = m.Id_Movimiento
JOIN Tickets t ON m.Id_Ticket = t.Id_Ticket WHERE t.Fecha < vDate;
DELETE FROM Remesas WHERE `Fecha Remesa` < vDate18;
DELETE tt.*
FROM Tickets_turno tt
LEFT JOIN Movimientos m USING(Id_Ticket)
WHERE m.Id_Article IS NULL;
DELETE FROM cl_main WHERE Fecha < vDate18;
DELETE FROM hedera.`order` WHERE date_send < vDate18;
DELETE FROM vn.message WHERE sendDate < vDate;
DELETE FROM cache.departure_limit WHERE Fecha < util.VN_CURDATE() - INTERVAL 1 MONTH;
DELETE cm
FROM Compres_mark cm
JOIN Compres c ON c.Id_Compra = cm.Id_Compra
JOIN Entradas e ON e.Id_Entrada = c.Id_Entrada
JOIN travel t ON t.id = e.travel_id
WHERE t.landing <= vDate;
IF v_full THEN
CREATE OR REPLACE TEMPORARY TABLE tTicketDelete
SELECT DISTINCT tl.originFk ticketFk
FROM vn.ticketLog tl
JOIN (SELECT MAX(tl.id)ids
FROM vn.ticket t
JOIN vn.ticketLog tl ON tl.originFk = t.id
WHERE t.shipped BETWEEN '2000-01-01' AND '2000-12-31'
AND t.isDeleted
GROUP BY t.id
)sub ON sub.ids = tl.id
WHERE tl.creationDate <= util.VN_CURDATE() - INTERVAL 60 DAY;
DELETE t
FROM vn.ticket t
JOIN tTicketDelete tmp ON tmp.ticketFk = t.id;
DROP TEMPORARY TABLE tTicketDelete;
END IF;
-- Tickets Nulos PAK 11/10/2016
UPDATE Tickets
SET empresa_id = 965
WHERE Id_Cliente = 31
AND empresa_id != 965;
END$$
DELIMITER ;

View File

@ -1,6 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`clean_launcher`()
BEGIN
CALL clean(TRUE);
END$$
DELIMITER ;

View File

@ -0,0 +1,2 @@
DELETE IGNORE FROM bs.nightTask
WHERE `procedure` = 'clean_launcher';