MT#56693 fix voip_sound_set_handle_parents updates

* on update_sound_set_handle_parents() call delete
  orphaned entries from voip_sound_set_handle_parents
  do not have entries in the voip_sound_sets
* update_sound_set_handle_parents() improvements:
  - when u_sound_set_id is not null:
    = delete only child entries (before, also the parent entries
       were removed)
    = on insert, on duplicate update parent_set_id and parent_chain
      to effectively skip entries that already exist and only
      insert new entries

Change-Id: Id0881d9f79ddd05bc5be67d1f181ea809e43e180
mr11.4
Kirill Solomko 3 years ago
parent 722524ffea
commit 4fd9399a2b

@ -18,6 +18,12 @@ DELIMITER ;;
CREATE OR REPLACE PROCEDURE update_sound_set_handle_parents(IN u_sound_set_id INT, IN u_handle_id INT)
BEGIN
IF u_sound_set_id IS NOT NULL THEN
DELETE p FROM voip_sound_set_handle_parents p
WHERE set_id = u_sound_set_id
AND NOT EXISTS (SELECT id
FROM voip_sound_sets
WHERE id = u_sound_set_id);
DELETE p FROM voip_sound_set_handle_parents p
WHERE set_id IN (
WITH RECURSIVE cte as (
@ -31,63 +37,51 @@ BEGIN
)
SELECT id
FROM cte
)
AND (handle_id = u_handle_id OR 1=1);
DELETE p FROM voip_sound_set_handle_parents p
WHERE set_id IN (
WITH RECURSIVE cte as (
SELECT s.id, s.parent_id
FROM voip_sound_sets s
WHERE id = u_sound_set_id
UNION
SELECT s.id, s.parent_id
FROM voip_sound_sets s
JOIN cte ON cte.parent_id = s.id
)
SELECT id
FROM cte
)
)
AND (handle_id = u_handle_id OR 1=1);
INSERT INTO voip_sound_set_handle_parents(set_id, handle_id, parent_set_id, parent_chain)
WITH RECURSIVE cte as (
SELECT v.set_id, v.handle_id, v.data_set_id, v.parent_chain
FROM (
WITH RECURSIVE cte as (
SELECT v.id AS set_id, v.handle_id,
v.id AS data_set_id,
CAST('' AS CHAR(4096)) AS parent_chain
v.id AS data_set_id,
CAST('' AS CHAR(4096)) AS parent_chain
FROM (SELECT s.*, h.id as handle_id
FROM (voip_sound_sets s, voip_sound_handles h)
) AS v
LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id
WHERE v.id = (
WITH RECURSIVE cte as (
SELECT s.id, s.parent_id, CAST(0 as unsigned) as iter
FROM voip_sound_sets s
WHERE id = u_sound_set_id
UNION
SELECT s.id, s.parent_id, iter+1 as iter
FROM voip_sound_sets s
JOIN cte ON cte.parent_id = s.id
)
SELECT id
FROM cte
WHERE iter = (SELECT max(iter) from cte)
)
AND (v.handle_id = u_handle_id OR 1=1)
UNION
SELECT v.id AS set_id, v.handle_id,
IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,
CONCAT(v.parent_id, IF(cte.parent_chain, ':', ''), cte.parent_chain) as parent_chain
FROM (SELECT s.*, h.id as handle_id, h.name as handle_name
FROM (voip_sound_sets s, voip_sound_handles h)
) AS v
LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id
WHERE v.id = (
WITH RECURSIVE cte as (
SELECT s.id, s.parent_id, CAST(0 as unsigned) as iter
FROM voip_sound_sets s
WHERE id = u_sound_set_id
UNION
SELECT s.id, s.parent_id, iter+1 as iter
FROM voip_sound_sets s
JOIN cte ON cte.parent_id = s.id
)
SELECT id
FROM cte
WHERE iter = (SELECT max(iter) from cte)
JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id
)
AND (v.handle_id = u_handle_id OR 1=1)
UNION
SELECT v.id AS set_id, v.handle_id,
IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,
CONCAT(v.parent_id, IF(cte.parent_chain, ':', ''), cte.parent_chain) as parent_chain
FROM (SELECT s.*, h.id as handle_id, h.name as handle_name
FROM (voip_sound_sets s, voip_sound_handles h)
) AS v
LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id
JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id
)
SELECT set_id, handle_id,
IF(data_set_id = set_id, NULL, data_set_id) as data_set_id,
parent_chain
FROM cte;
SELECT set_id, handle_id,
IF(data_set_id = set_id, NULL, data_set_id) as data_set_id,
parent_chain
FROM cte
) as v
ON DUPLICATE KEY UPDATE parent_set_id=v.data_set_id, parent_chain=v.parent_chain;
ELSE
IF u_handle_id IS NOT NULL THEN
DELETE FROM voip_sound_set_handle_parents WHERE handle_id = u_handle_id;
@ -127,18 +121,16 @@ DELIMITER ;
delimiter ;;
CREATE OR REPLACE TRIGGER voip_sound_sets_create_trig AFTER INSERT ON voip_sound_sets
FOR each ROW BEGIN
FOR each ROW BEGIN
IF NEW.parent_id IS NOT NULL THEN
CALL update_sound_set_handle_parents(NEW.id, NULL);
END IF;
CALL update_sound_set_handle_parents(NEW.id, NULL);
END;;
delimiter ;
delimiter ;;
CREATE OR REPLACE TRIGGER voip_sound_sets_update_trig AFTER UPDATE ON voip_sound_sets
FOR each ROW BEGIN
FOR each ROW BEGIN
IF NOT (OLD.parent_id <=> NEW.parent_id) THEN
CALL update_sound_set_handle_parents(NEW.id, NULL);
@ -150,7 +142,7 @@ delimiter ;
delimiter ;;
CREATE OR REPLACE TRIGGER voip_sound_sets_delete_trig AFTER DELETE ON voip_sound_sets
FOR each ROW BEGIN
FOR each ROW BEGIN
DECLARE done INT DEFAULT 0;
DECLARE set_id INT DEFAULT 0;
@ -170,13 +162,15 @@ CREATE OR REPLACE TRIGGER voip_sound_sets_delete_trig AFTER DELETE ON voip_sound
END LOOP;
CLOSE x;
CALL update_sound_set_handle_parents(OLD.id, NULL);
END;;
delimiter ;
delimiter ;;
CREATE OR REPLACE TRIGGER voip_sound_files_create_trig AFTER UPDATE ON voip_sound_files
FOR each ROW BEGIN
FOR each ROW BEGIN
CALL update_sound_set_handle_parents(NEW.set_id, NEW.handle_id);
@ -185,7 +179,7 @@ delimiter ;
delimiter ;;
CREATE OR REPLACE TRIGGER voip_sound_files_update_trig AFTER UPDATE ON voip_sound_files
FOR each ROW BEGIN
FOR each ROW BEGIN
CALL update_sound_set_handle_parents(NEW.set_id, NEW.handle_id);
@ -194,7 +188,7 @@ delimiter ;
delimiter ;;
CREATE OR REPLACE TRIGGER voip_sound_files_delete_trig AFTER DELETE ON voip_sound_files
FOR each ROW BEGIN
FOR each ROW BEGIN
DECLARE done INT DEFAULT 0;
DECLARE set_id INT DEFAULT 0;

Loading…
Cancel
Save