304 lines
8.8 KiB
SQL
304 lines
8.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `util`.`json_cleanEquals`(vA JSON, vB JSON)
|
|
RETURNS JSON
|
|
DETERMINISTIC
|
|
BEGIN
|
|
/**
|
|
* Cleans @vA instance removing nulls and keys whose values are the same.
|
|
*
|
|
* @param vA JSON containing the old values
|
|
* @param vB JSON containing the new values
|
|
*/
|
|
DECLARE vKeys JSON;
|
|
DECLARE vPath VARCHAR(255);
|
|
DECLARE vValueA JSON;
|
|
DECLARE vValueB JSON;
|
|
DECLARE i INT DEFAULT 0;
|
|
DECLARE vCount INT;
|
|
|
|
IF vA IS NULL OR vB IS NULL THEN
|
|
RETURN vA;
|
|
END IF;
|
|
|
|
SET vKeys = JSON_KEYS(vB);
|
|
SET vCount = JSON_LENGTH(vKeys);
|
|
|
|
WHILE i < vCount DO
|
|
SET vPath = CONCAT('$.', JSON_VALUE(vKeys, CONCAT('$[',i,']')));
|
|
SET vValueA = JSON_EXTRACT(vA, vPath);
|
|
SET vValueB = JSON_EXTRACT(vB, vPath);
|
|
IF vValueA <=> vValueB THEN
|
|
SET vA = JSON_REMOVE(vA, vPath);
|
|
END IF;
|
|
SET i := i + 1;
|
|
END WHILE;
|
|
|
|
RETURN vA;
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
|
|
-- Aplicar a todas las tablas log
|
|
|
|
-- ticketLog
|
|
UPDATE vn.ticketLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.ticketLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.ticketLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.ticketLog;
|
|
|
|
-- entryLog
|
|
UPDATE vn.entryLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.entryLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.entryLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.entryLog;
|
|
|
|
-- itemLog
|
|
UPDATE vn.itemLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.itemLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.itemLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.itemLog;
|
|
|
|
-- routeLog
|
|
UPDATE vn.routeLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.routeLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.routeLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.routeLog;
|
|
|
|
-- travelLog
|
|
UPDATE vn.travelLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.travelLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.travelLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.travelLog;
|
|
|
|
-- zoneLog
|
|
UPDATE vn.zoneLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.zoneLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.zoneLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.zoneLog;
|
|
|
|
-- clientLog
|
|
UPDATE vn.clientLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.clientLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.clientLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.clientLog;
|
|
|
|
-- workerLog
|
|
UPDATE vn.workerLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.workerLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.workerLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.workerLog;
|
|
|
|
-- claimLog
|
|
UPDATE vn.claimLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.claimLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.claimLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.claimLog;
|
|
|
|
-- shelvingLog
|
|
UPDATE vn.shelvingLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.shelvingLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.shelvingLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.shelvingLog;
|
|
|
|
-- invoiceInLog
|
|
UPDATE vn.invoiceInLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.invoiceInLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.invoiceInLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.invoiceInLog;
|
|
|
|
-- userLog
|
|
UPDATE vn.userLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.userLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.userLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.userLog;
|
|
|
|
-- supplierLog
|
|
UPDATE vn.supplierLog
|
|
SET oldInstance = util.json_cleanEquals(@oldI := oldInstance, newInstance),
|
|
newInstance = util.json_cleanEquals(newInstance, @oldI)
|
|
WHERE `action` = 'update';
|
|
|
|
UPDATE vn.supplierLog
|
|
SET oldInstance = util.json_removeNulls(oldInstance)
|
|
WHERE `action` = 'delete'
|
|
AND oldInstance IS NOT NULL
|
|
AND NOT (oldInstance <=> util.json_removeNulls(oldInstance));
|
|
|
|
UPDATE vn.supplierLog
|
|
SET newInstance = util.json_removeNulls(newInstance)
|
|
WHERE `action` = 'insert'
|
|
AND newInstance IS NOT NULL
|
|
AND NOT (newInstance <=> util.json_removeNulls(newInstance));
|
|
|
|
OPTIMIZE TABLE vn.supplierLog;
|
|
|
|
DROP FUNCTION util.json_cleanEquals;
|