USE provisioning; CREATE OR REPLACE TABLE `voip_sound_set_handle_parents` ( `id` int(11) NOT NULL AUTO_INCREMENT, `set_id` int(11) NOT NULL, `handle_id` int(11) NOT NULL, `parent_set_id` int(11) DEFAULT NULL, `parent_chain` varchar(1024) DEFAULT NULL, PRIMARY KEY (`id`), UNIQUE KEY `set_handle_id_idx` (`set_id`, `handle_id`), KEY `handle_id_idx` (`handle_id`), KEY `parent_set_id_idx` (`parent_set_id`), CONSTRAINT `vshh_handle_id_ref` FOREIGN KEY (`handle_id`) REFERENCES `voip_sound_handles` (`id`) ON DELETE CASCADE ON UPDATE CASCADE ); 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 ( SELECT s.id FROM voip_sound_sets s WHERE id = u_sound_set_id UNION SELECT s.id FROM voip_sound_sets s JOIN cte ON cte.id = s.parent_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) 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 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 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 ) 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; ELSE DELETE FROM voip_sound_set_handle_parents; END IF; INSERT INTO voip_sound_set_handle_parents(set_id, handle_id, parent_set_id, parent_chain) 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 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.parent_id IS NULL 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; END IF; END ;; DELIMITER ; delimiter ;; CREATE OR REPLACE TRIGGER voip_sound_sets_create_trig AFTER INSERT ON voip_sound_sets FOR each ROW BEGIN 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 IF NOT (OLD.parent_id <=> NEW.parent_id) THEN CALL update_sound_set_handle_parents(NEW.id, NULL); END IF; END;; delimiter ; delimiter ;; CREATE OR REPLACE TRIGGER voip_sound_sets_delete_trig AFTER DELETE ON voip_sound_sets FOR each ROW BEGIN DECLARE done INT DEFAULT 0; DECLARE set_id INT DEFAULT 0; DECLARE x CURSOR FOR SELECT DISTINCT set_id FROM voip_sound_set_handle_parents WHERE parent_set_id = OLD.id; DECLARE continue handler FOR NOT FOUND SET done = true; OPEN x; iter: LOOP FETCH x INTO set_id; IF done THEN LEAVE iter; END IF; CALL update_sound_set_handle_parents(set_id, NULL); 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 CALL update_sound_set_handle_parents(NEW.set_id, NEW.handle_id); END;; delimiter ; delimiter ;; CREATE OR REPLACE TRIGGER voip_sound_files_update_trig AFTER UPDATE ON voip_sound_files FOR each ROW BEGIN CALL update_sound_set_handle_parents(NEW.set_id, NEW.handle_id); END;; delimiter ; delimiter ;; CREATE OR REPLACE TRIGGER voip_sound_files_delete_trig AFTER DELETE ON voip_sound_files FOR each ROW BEGIN DECLARE done INT DEFAULT 0; DECLARE set_id INT DEFAULT 0; DECLARE x CURSOR FOR SELECT DISTINCT set_id FROM voip_sound_set_handle_parents WHERE parent_set_id = OLD.set_id AND handle_id = OLD.handle_id; DECLARE continue handler FOR NOT FOUND SET done = true; OPEN x; iter: LOOP FETCH x INTO set_id; IF done THEN LEAVE iter; END IF; CALL update_sound_set_handle_parents(set_id, OLD.handle_id); END LOOP; CLOSE x; END;; delimiter ; CREATE OR REPLACE VIEW v_sound_set_files AS SELECT r.set_id, s.reseller_id, s.contract_id, s.name, s.description, r.handle_id, h.name as handle_name, IF(r.parent_set_id IS NOT NULL, vsf_p.id, vsf.id) as file_id, IF(r.parent_set_id IS NOT NULL, vsf_p.filename, vsf.filename) as filename, IF(r.parent_set_id IS NOT NULL, vsf_p.loopplay, vsf.loopplay) as loopplay, REPLACE(REPLACE(REPLACE( JSON_REMOVE(r.parent_chain, '$[0]'), '[', ''), ']', ''), ', ', ':' ) AS parent_chain, r.parent_set_id as data_set_id, IF(r.parent_set_id IS NOT NULL, vsf_p.data, vsf.data) as data FROM voip_sound_set_handle_parents r JOIN voip_sound_sets s ON s.id = r.set_id JOIN voip_sound_handles h ON h.id = r.handle_id LEFT JOIN voip_sound_files vsf ON vsf.set_id = r.set_id AND vsf.handle_id = r.handle_id LEFT JOIN voip_sound_files vsf_p ON vsf_p.set_id = r.parent_set_id AND vsf_p.handle_id = r.handle_id; CALL update_sound_set_handle_parents(NULL, NULL);