salix/db/routines/vn/procedures/clean.sql

227 lines
6.8 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`clean`()
BEGIN
/**
* 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 vCompanyBlk INT;
DELETE FROM workerActivity WHERE created < v2Years;
DELETE FROM ticketParking WHERE created < v2Months;
DELETE FROM routesMonitor WHERE dated < 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 itemShelvingSale
WHERE itemShelvingFk IN (
SELECT id
FROM itemShelving
WHERE created < util.VN_CURDATE()
AND visible = 0
);
DELETE FROM itemShelving WHERE created < util.VN_CURDATE() AND visible = 0;
DELETE FROM ticketDown WHERE created < util.yesterday();
DELETE IGNORE FROM expedition WHERE created < v26Months;
DELETE cs
FROM sms s
JOIN clientSms cs ON cs.smsFk = s.id
WHERE s.created < v18Months;
DELETE FROM sms WHERE created < v18Months;
DELETE FROM saleTracking WHERE created < v1Years;
DELETE FROM productionError WHERE dated < 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 < 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
LEFT JOIN ticketService ts ON ts.ticketFk = tw.ticketFk
WHERE s.id IS NULL
AND tr.id IS NULL
AND ts.id IS NULL;
DELETE FROM claim WHERE ticketCreated < v4Years;
-- Robert ubicacion anterior de travelLog comentario para debug
DELETE FROM zoneEvent WHERE `type` = 'day' AND dated < v3Months;
DELETE b FROM buy b
JOIN entryConfig e ON e.defaultEntry = b.entryFk
WHERE b.created < v2Months;
DELETE FROM stockBought WHERE dated < v2Months;
DELETE FROM printQueue WHERE statusCode = 'printed' AND created < v2Months;
-- Equipos duplicados
DELETE w.*
FROM workerTeam w
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;
DELETE sc
FROM saleComponent sc
JOIN sale s ON s.id= sc.saleFk
JOIN ticket t ON t.id= s.ticketFk
WHERE t.shipped < v18Months;
DELETE c
FROM claim c
JOIN claimState cs ON cs.id = c.claimStateFk
WHERE cs.description = 'Anulado'
AND c.created < v2Months;
DELETE FROM roadmapStop 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 travel t
LEFT JOIN entry e ON e.travelFk = t.id
JOIN travelThermograph th ON th.travelFk = t.id
WHERE t.shipped < v3Months
AND e.travelFk IS NULL;
SELECT dt.id INTO vTrashId
FROM dmsType dt
WHERE dt.code = 'trash';
UPDATE tThermographToDelete th
JOIN dms d ON d.id = th.dmsFk
SET d.dmsTypeFk = vTrashId;
DELETE th
FROM tThermographToDelete tmp
JOIN travelThermograph th ON th.id = tmp.id;
DELETE t
FROM travel t
LEFT JOIN entry e ON e.travelFk = t.id
WHERE t.shipped < v3Months AND e.travelFk IS NULL;
UPDATE dms d
JOIN dmsType dt ON dt.id = d.dmsTypeFk
SET d.dmsTypeFk = vTrashId
WHERE created < util.VN_CURDATE() - INTERVAL dt.monthToDelete MONTH;
-- borrar entradas sin compras
CREATE OR REPLACE TEMPORARY TABLE tEntryToDelete
SELECT e.*
FROM entry e
LEFT JOIN buy b ON b.entryFk = e.id
JOIN entryConfig ec ON e.id <> ec.defaultEntry
WHERE e.dated < v3Months
AND b.entryFK IS NULL;
DELETE e
FROM entry e
JOIN tEntryToDelete tmp ON tmp.id = e.id
WHERE NOT e.isBooked;
-- borrar de route registros menores a 4 años
CREATE OR REPLACE TEMPORARY TABLE tRouteToDelete
SELECT *
FROM route r
WHERE created < v4Years;
UPDATE tRouteToDelete tmp
JOIN dms d ON d.id = tmp.gestdocFk
SET d.dmsTypeFk = vTrashId;
DELETE r
FROM tRouteToDelete tmp
JOIN route r ON r.id = tmp.id;
-- borrar registros de dua y awb menores a 2 años
CREATE OR REPLACE TEMPORARY TABLE tDuaToDelete
SELECT *
FROM dua
WHERE operated < v2Years;
UPDATE tDuaToDelete tm
JOIN dms d ON d.id = tm.gestdocFk
SET d.dmsTypeFk = vTrashId;
DELETE d
FROM tDuaToDelete tmp
JOIN dua d ON d.id = tmp.id;
DELETE a
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 collection WHERE created < v2Months;
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 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
LEFT JOIN ticketWeekly tw ON tw.ticketFk = t.id
WHERE t.shipped BETWEEN '2000-01-01' AND '2000-12-31'
AND t.isDeleted
AND tw.ticketFk IS NULL
GROUP BY t.id
) sub ON sub.ids = tl.id
WHERE tl.creationDate <= v2Months;
DELETE t
FROM ticket t
JOIN tTicketDelete tmp ON tmp.ticketFk = t.id;
DELETE sl
FROM saleLabel sl
JOIN sale s ON s.id = sl.saleFk
JOIN ticket t ON t.id = s.ticketFk
WHERE t.shipped < v2Months;
-- 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 ;