salix/db/routines/util/procedures/log_cleanInstances.sql

56 lines
1.6 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `util`.`log_cleanInstances`(
vActionCode VARCHAR(45),
INOUT vOldInstance JSON,
INOUT vNewInstance JSON)
BEGIN
/**
* Cleans both instances removing nulls and keys whose values are the same.
*
* @param vActionCode The action code {insert | delete | update}
* @param vOldInstance JSON containing the old values
* @param vNewInstance JSON containing the new values
*/
DECLARE vKeys JSON;
DECLARE vPath VARCHAR(255);
DECLARE vOldValue JSON;
DECLARE vNewValue JSON;
DECLARE vOld JSON;
DECLARE vNew JSON;
DECLARE i INT DEFAULT 0;
DECLARE vCount INT;
CASE vActionCode
WHEN 'insert' THEN
SET vNewInstance = json_removeNulls(vNewInstance);
WHEN 'update' THEN
SET vOld = '{}';
SET vNew = '{}';
SET vKeys = JSON_KEYS(vNewInstance);
SET vCount = JSON_LENGTH(vKeys);
WHILE i < vCount DO
SET vPath = CONCAT('$.', JSON_VALUE(vKeys, CONCAT('$[',i,']')));
SET vOldValue = JSON_EXTRACT(vOldInstance, vPath);
SET vNewValue = JSON_EXTRACT(vNewInstance, vPath);
IF NOT (vOldValue <=> vNewValue) THEN
IF vOldValue IS NOT NULL AND vOldValue <> 'null' THEN
SET vOld = JSON_SET(vOld, vPath, JSON_COMPACT(vOldValue));
END IF;
IF vNewValue IS NOT NULL THEN
SET vNew = JSON_SET(vNew, vPath, JSON_COMPACT(vNewValue));
END IF;
END IF;
SET i := i + 1;
END WHILE;
SET vOldInstance = vOld;
SET vNewInstance = vNew;
WHEN 'delete' THEN
SET vOldInstance = json_removeNulls(vOldInstance);
ELSE BEGIN END;
END CASE;
SET vOldInstance = log_formatDate(vOldInstance);
SET vNewInstance = log_formatDate(vNewInstance);
END$$
DELIMITER ;