diff --git a/db_scripts/diff/15795.down b/db_scripts/diff/15795.down new file mode 100644 index 00000000..626a9fad --- /dev/null +++ b/db_scripts/diff/15795.down @@ -0,0 +1,190 @@ +USE provisioning; + + +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); + + IF u_handle_id IS NOT NULL THEN + 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; + + 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, + CAST(0 as unsigned) AS affected + 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 + 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(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain, + IF(v.id = u_sound_set_id OR v.parent_id = u_sound_set_id OR affected = 1, 1, 0) + 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 + WHERE set_id = u_sound_set_id OR affected = 1; + ELSE + 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 + ); + + 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, + CAST(0 as unsigned) AS affected + 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) + ) + 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(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain, + IF(v.id = u_sound_set_id OR v.parent_id = u_sound_set_id OR affected = 1, 1, 0) + 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 + WHERE set_id = u_sound_set_id OR affected = 1; + END IF; + ELSE + IF u_handle_id IS NOT NULL THEN + DELETE FROM voip_sound_set_handle_parents WHERE handle_id = u_handle_id; + + 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 + 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(LENGTH(cte.parent_chain) > 1, ':', ''), 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; + ELSE + DELETE FROM voip_sound_set_handle_parents; + + 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 + 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(LENGTH(cte.parent_chain) > 1, ':', ''), 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 IF; + +END ;; +DELIMITER ; + diff --git a/db_scripts/diff/15795.up b/db_scripts/diff/15795.up new file mode 100644 index 00000000..b0072b44 --- /dev/null +++ b/db_scripts/diff/15795.up @@ -0,0 +1,265 @@ +USE provisioning; + + +DELIMITER ;; +CREATE OR REPLACE PROCEDURE update_sound_set_handle_parents(IN u_sound_set_id INT, IN u_handle_id INT) +BEGIN + /* declare */ + DECLARE done INT DEFAULT FALSE; + + + DECLARE x_set_id INT DEFAULT 0; + DECLARE x_handle_id INT DEFAULT 0; + DECLARE x_parent_set_id INT DEFAULT NULL; + DECLARE x_parent_chain VARCHAR(255) DEFAULT ''; + + + /* u_sound_set_id and u_handle_id */ + DECLARE x_sound_set_handle CURSOR FOR + 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, + CAST(0 as unsigned) AS affected + 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 + 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(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain, + IF(v.id = u_sound_set_id OR v.parent_id = u_sound_set_id OR affected = 1, 1, 0) + 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 parent_set_id, + parent_chain + FROM cte + WHERE set_id = u_sound_set_id OR affected = 1; + + + /* u_sound_set_id */ + DECLARE x_sound_set CURSOR FOR + 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, + CAST(0 as unsigned) AS affected + 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) + ) + 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(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain, + IF(v.id = u_sound_set_id OR v.parent_id = u_sound_set_id OR affected = 1, 1, 0) + 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 parent_set_id, + parent_chain + FROM cte + WHERE set_id = u_sound_set_id OR affected = 1; + + + + /* u_handle_id */ + DECLARE x_handle CURSOR FOR + 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 + 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(LENGTH(cte.parent_chain) > 1, ':', ''), 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 parent_set_id, + parent_chain + FROM cte; + + + /* none */ + DECLARE x CURSOR FOR + 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 + 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(LENGTH(cte.parent_chain) > 1, ':', ''), 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 parent_set_id, + parent_chain + FROM cte; + + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + + + /* code */ + 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); + + IF u_handle_id IS NOT NULL THEN + 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; + + OPEN x_sound_set_handle; + iter: LOOP + FETCH x_sound_set_handle INTO x_set_id, x_handle_id, x_parent_set_id, x_parent_chain; + IF done THEN + LEAVE iter; + END IF; + INSERT INTO voip_sound_set_handle_parents + (set_id, handle_id, parent_set_id, parent_chain) + VALUES + (x_set_id, x_handle_id, x_parent_set_id, x_parent_chain); + END LOOP; + CLOSE x_sound_set_handle; + ELSE + 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 + ); + + OPEN x_sound_set; + iter: LOOP + FETCH x_sound_set INTO x_set_id, x_handle_id, x_parent_set_id, x_parent_chain; + IF done THEN + LEAVE iter; + END IF; + INSERT INTO voip_sound_set_handle_parents + (set_id, handle_id, parent_set_id, parent_chain) + VALUES + (x_set_id, x_handle_id, x_parent_set_id, x_parent_chain); + END LOOP; + CLOSE x_sound_set; + END IF; + ELSE + IF u_handle_id IS NOT NULL THEN + DELETE FROM voip_sound_set_handle_parents WHERE handle_id = u_handle_id; + + OPEN x_handle; + iter: LOOP + FETCH x_handle INTO x_set_id, x_handle_id, x_parent_set_id, x_parent_chain; + IF done THEN + LEAVE iter; + END IF; + INSERT INTO voip_sound_set_handle_parents + (set_id, handle_id, parent_set_id, parent_chain) + VALUES + (x_set_id, x_handle_id, x_parent_set_id, x_parent_chain); + END LOOP; + CLOSE x_handle; + ELSE + DELETE FROM voip_sound_set_handle_parents; + + OPEN x; + iter: LOOP + FETCH x INTO x_set_id, x_handle_id, x_parent_set_id, x_parent_chain; + IF done THEN + LEAVE iter; + END IF; + INSERT INTO voip_sound_set_handle_parents + (set_id, handle_id, parent_set_id, parent_chain) + VALUES + (x_set_id, x_handle_id, x_parent_set_id, x_parent_chain); + END LOOP; + CLOSE x; + END IF; + END IF; + +END ;; +DELIMITER ; + diff --git a/schema/kamailio.sql b/schema/kamailio.sql index 8d485fb7..792b7c47 100644 --- a/schema/kamailio.sql +++ b/schema/kamailio.sql @@ -790,7 +790,7 @@ CREATE TABLE `subscriber` ( KEY `uuid_idx` (`uuid`) ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci; /*!40101 SET character_set_client = @saved_cs_client */; -INSERT INTO `subscriber` VALUES (1,'no_such_number','voip.sipwise.local','5c83b8a56cdaf703a441375173c4bdd6','be82b94cb3ba2e0d0d2bd353cd59bf14','56e994cfc891e49bce455d0673b12448','9bcb88b6-541a-43da-8fdc-816f5557ff93','',NOW()); +INSERT INTO `subscriber` VALUES (1,'no_such_number','voip.sipwise.local','3cef5290e9aa18bbbff0d1e4af3d63b9','f2d7cff002695b2df8bde1522807d628','0b1cd18cb06a6ec429d04104cc1041d5','9bcb88b6-541a-43da-8fdc-816f5557ff93','',NOW()); /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `trusted` ( diff --git a/schema/ngcp.sql b/schema/ngcp.sql index 89247e0f..0ebe09da 100644 --- a/schema/ngcp.sql +++ b/schema/ngcp.sql @@ -30014,7 +30014,7 @@ CREATE TABLE `db_schema` ( `applied_at` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(), PRIMARY KEY (`id`), UNIQUE KEY `rev_idx` (`revision`,`node`) -) ENGINE=InnoDB AUTO_INCREMENT=833 DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci; +) ENGINE=InnoDB AUTO_INCREMENT=834 DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci; /*!40101 SET character_set_client = @saved_cs_client */; INSERT INTO `db_schema` VALUES (1,10,'spce',NOW()); INSERT INTO `db_schema` VALUES (2,20,'spce',NOW()); @@ -30848,6 +30848,7 @@ INSERT INTO `db_schema` VALUES (829,15766,'spce',NOW()); INSERT INTO `db_schema` VALUES (830,15767,'spce',NOW()); INSERT INTO `db_schema` VALUES (831,15775,'spce',NOW()); INSERT INTO `db_schema` VALUES (832,15790,'spce',NOW()); +INSERT INTO `db_schema` VALUES (833,15795,'spce',NOW()); /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `timezone` ( diff --git a/schema/provisioning.json b/schema/provisioning.json index 8ad0d58b..c6b03592 100644 --- a/schema/provisioning.json +++ b/schema/provisioning.json @@ -12933,7 +12933,7 @@ "key_col" : "ip_is_ipv6" }, "update_sound_set_handle_parents" : { - "ROUTINE_DEFINITION" : "BEGIN\n IF u_sound_set_id IS NOT NULL THEN\n DELETE p FROM voip_sound_set_handle_parents p\n WHERE set_id = u_sound_set_id\n AND NOT EXISTS (SELECT id\n FROM voip_sound_sets\n WHERE id = u_sound_set_id);\n\n IF u_handle_id IS NOT NULL THEN\n DELETE p FROM voip_sound_set_handle_parents p\n WHERE set_id IN (\n WITH RECURSIVE cte as (\n SELECT s.id\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id\n FROM voip_sound_sets s\n JOIN cte ON cte.id = s.parent_id\n )\n SELECT id\n FROM cte\n )\n AND handle_id = u_handle_id;\n\n INSERT INTO voip_sound_set_handle_parents(set_id, handle_id, parent_set_id, parent_chain)\n WITH RECURSIVE cte as (\n SELECT v.id AS set_id, v.handle_id,\n v.id AS data_set_id,\n CAST('' AS CHAR(4096)) AS parent_chain,\n CAST(0 as unsigned) AS affected\n FROM (SELECT s.*, h.id as handle_id\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n WHERE v.id = (\n WITH RECURSIVE cte as (\n SELECT s.id, s.parent_id, CAST(0 as unsigned) as iter\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id, s.parent_id, iter+1 as iter\n FROM voip_sound_sets s\n JOIN cte ON cte.parent_id = s.id\n )\n SELECT id\n FROM cte\n WHERE iter = (SELECT max(iter) from cte)\n )\n AND v.handle_id = u_handle_id\n UNION\n SELECT v.id AS set_id, v.handle_id,\n IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,\n CONCAT(v.parent_id, IF(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain,\n IF(v.id = u_sound_set_id OR v.parent_id = u_sound_set_id OR affected = 1, 1, 0)\n FROM (SELECT s.*, h.id as handle_id, h.name as handle_name\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id\n )\n SELECT set_id, handle_id,\n IF(data_set_id = set_id, NULL, data_set_id) as data_set_id,\n parent_chain\n FROM cte\n WHERE set_id = u_sound_set_id OR affected = 1;\n ELSE\n DELETE p FROM voip_sound_set_handle_parents p\n WHERE set_id IN (\n WITH RECURSIVE cte as (\n SELECT s.id\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id\n FROM voip_sound_sets s\n JOIN cte ON cte.id = s.parent_id\n )\n SELECT id\n FROM cte\n );\n\n INSERT INTO voip_sound_set_handle_parents(set_id, handle_id, parent_set_id, parent_chain)\n WITH RECURSIVE cte as (\n SELECT v.id AS set_id, v.handle_id,\n v.id AS data_set_id,\n CAST('' AS CHAR(4096)) AS parent_chain,\n CAST(0 as unsigned) AS affected\n FROM (SELECT s.*, h.id as handle_id\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n WHERE v.id = (\n WITH RECURSIVE cte as (\n SELECT s.id, s.parent_id, CAST(0 as unsigned) as iter\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id, s.parent_id, iter+1 as iter\n FROM voip_sound_sets s\n JOIN cte ON cte.parent_id = s.id\n )\n SELECT id\n FROM cte\n WHERE iter = (SELECT max(iter) from cte)\n )\n UNION\n SELECT v.id AS set_id, v.handle_id,\n IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,\n CONCAT(v.parent_id, IF(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain,\n IF(v.id = u_sound_set_id OR v.parent_id = u_sound_set_id OR affected = 1, 1, 0)\n FROM (SELECT s.*, h.id as handle_id, h.name as handle_name\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id\n )\n SELECT set_id, handle_id,\n IF(data_set_id = set_id, NULL, data_set_id) as data_set_id,\n parent_chain\n FROM cte\n WHERE set_id = u_sound_set_id OR affected = 1;\n END IF;\n ELSE\n IF u_handle_id IS NOT NULL THEN\n DELETE FROM voip_sound_set_handle_parents WHERE handle_id = u_handle_id;\n\n INSERT INTO voip_sound_set_handle_parents(set_id, handle_id, parent_set_id, parent_chain)\n WITH RECURSIVE cte as (\n SELECT v.id AS set_id, v.handle_id,\n v.id AS data_set_id,\n CAST('' AS CHAR(4096)) AS parent_chain\n FROM (SELECT s.*, h.id as handle_id\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n WHERE v.parent_id IS NULL\n AND v.handle_id = u_handle_id\n UNION\n SELECT v.id AS set_id, v.handle_id,\n IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,\n CONCAT(v.parent_id, IF(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain\n FROM (SELECT s.*, h.id as handle_id, h.name as handle_name\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id\n )\n SELECT set_id, handle_id,\n IF(data_set_id = set_id, NULL, data_set_id) as data_set_id,\n parent_chain\n FROM cte;\n ELSE\n DELETE FROM voip_sound_set_handle_parents;\n\n INSERT INTO voip_sound_set_handle_parents(set_id, handle_id, parent_set_id, parent_chain)\n WITH RECURSIVE cte as (\n SELECT v.id AS set_id, v.handle_id,\n v.id AS data_set_id,\n CAST('' AS CHAR(4096)) AS parent_chain\n FROM (SELECT s.*, h.id as handle_id\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n WHERE v.parent_id IS NULL\n UNION\n SELECT v.id AS set_id, v.handle_id,\n IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,\n CONCAT(v.parent_id, IF(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain\n FROM (SELECT s.*, h.id as handle_id, h.name as handle_name\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id\n )\n SELECT set_id, handle_id,\n IF(data_set_id = set_id, NULL, data_set_id) as data_set_id,\n parent_chain\n FROM cte;\n END IF;\n END IF;\n\nEND", + "ROUTINE_DEFINITION" : "BEGIN\n \n DECLARE done INT DEFAULT FALSE;\n\n\n DECLARE x_set_id INT DEFAULT 0;\n DECLARE x_handle_id INT DEFAULT 0;\n DECLARE x_parent_set_id INT DEFAULT NULL;\n DECLARE x_parent_chain VARCHAR(255) DEFAULT '';\n\n\n \n DECLARE x_sound_set_handle CURSOR FOR\n WITH RECURSIVE cte as (\n SELECT v.id AS set_id, v.handle_id,\n v.id AS data_set_id,\n CAST('' AS CHAR(4096)) AS parent_chain,\n CAST(0 as unsigned) AS affected\n FROM (SELECT s.*, h.id as handle_id\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n WHERE v.id = (\n WITH RECURSIVE cte as (\n SELECT s.id, s.parent_id, CAST(0 as unsigned) as iter\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id, s.parent_id, iter+1 as iter\n FROM voip_sound_sets s\n JOIN cte ON cte.parent_id = s.id\n )\n SELECT id\n FROM cte\n WHERE iter = (SELECT max(iter) from cte)\n )\n AND v.handle_id = u_handle_id\n UNION\n SELECT v.id AS set_id, v.handle_id,\n IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,\n CONCAT(v.parent_id, IF(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain,\n IF(v.id = u_sound_set_id OR v.parent_id = u_sound_set_id OR affected = 1, 1, 0)\n FROM (SELECT s.*, h.id as handle_id, h.name as handle_name\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id\n )\n SELECT set_id, handle_id,\n IF(data_set_id = set_id, NULL, data_set_id) as parent_set_id,\n parent_chain\n FROM cte\n WHERE set_id = u_sound_set_id OR affected = 1;\n\n\n \n DECLARE x_sound_set CURSOR FOR\n WITH RECURSIVE cte as (\n SELECT v.id AS set_id, v.handle_id,\n v.id AS data_set_id,\n CAST('' AS CHAR(4096)) AS parent_chain,\n CAST(0 as unsigned) AS affected\n FROM (SELECT s.*, h.id as handle_id\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n WHERE v.id = (\n WITH RECURSIVE cte as (\n SELECT s.id, s.parent_id, CAST(0 as unsigned) as iter\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id, s.parent_id, iter+1 as iter\n FROM voip_sound_sets s\n JOIN cte ON cte.parent_id = s.id\n )\n SELECT id\n FROM cte\n WHERE iter = (SELECT max(iter) from cte)\n )\n UNION\n SELECT v.id AS set_id, v.handle_id,\n IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,\n CONCAT(v.parent_id, IF(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain,\n IF(v.id = u_sound_set_id OR v.parent_id = u_sound_set_id OR affected = 1, 1, 0)\n FROM (SELECT s.*, h.id as handle_id, h.name as handle_name\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id\n )\n SELECT set_id, handle_id,\n IF(data_set_id = set_id, NULL, data_set_id) as parent_set_id,\n parent_chain\n FROM cte\n WHERE set_id = u_sound_set_id OR affected = 1;\n\n\n\n \n DECLARE x_handle CURSOR FOR\n WITH RECURSIVE cte as (\n SELECT v.id AS set_id, v.handle_id,\n v.id AS data_set_id,\n CAST('' AS CHAR(4096)) AS parent_chain\n FROM (SELECT s.*, h.id as handle_id\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n WHERE v.parent_id IS NULL\n AND v.handle_id = u_handle_id\n UNION\n SELECT v.id AS set_id, v.handle_id,\n IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,\n CONCAT(v.parent_id, IF(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain\n FROM (SELECT s.*, h.id as handle_id, h.name as handle_name\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id\n )\n SELECT set_id, handle_id,\n IF(data_set_id = set_id, NULL, data_set_id) as parent_set_id,\n parent_chain\n FROM cte;\n\n\n \n DECLARE x CURSOR FOR\n WITH RECURSIVE cte as (\n SELECT v.id AS set_id, v.handle_id,\n v.id AS data_set_id,\n CAST('' AS CHAR(4096)) AS parent_chain\n FROM (SELECT s.*, h.id as handle_id\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n WHERE v.parent_id IS NULL\n UNION\n SELECT v.id AS set_id, v.handle_id,\n IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,\n CONCAT(v.parent_id, IF(LENGTH(cte.parent_chain) > 1, ':', ''), cte.parent_chain) as parent_chain\n FROM (SELECT s.*, h.id as handle_id, h.name as handle_name\n FROM (voip_sound_sets s, voip_sound_handles h)\n ) AS v\n LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id\n JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id\n )\n SELECT set_id, handle_id,\n IF(data_set_id = set_id, NULL, data_set_id) as parent_set_id,\n parent_chain\n FROM cte;\n\n\n DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE;\n\n\n \n IF u_sound_set_id IS NOT NULL THEN\n DELETE p FROM voip_sound_set_handle_parents p\n WHERE set_id = u_sound_set_id\n AND NOT EXISTS (SELECT id\n FROM voip_sound_sets\n WHERE id = u_sound_set_id);\n\n IF u_handle_id IS NOT NULL THEN\n DELETE p FROM voip_sound_set_handle_parents p\n WHERE set_id IN (\n WITH RECURSIVE cte as (\n SELECT s.id\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id\n FROM voip_sound_sets s\n JOIN cte ON cte.id = s.parent_id\n )\n SELECT id\n FROM cte\n )\n AND handle_id = u_handle_id;\n\n OPEN x_sound_set_handle;\n iter: LOOP\n FETCH x_sound_set_handle INTO x_set_id, x_handle_id, x_parent_set_id, x_parent_chain;\n IF done THEN\n LEAVE iter;\n END IF;\n INSERT INTO voip_sound_set_handle_parents\n (set_id, handle_id, parent_set_id, parent_chain)\n VALUES\n (x_set_id, x_handle_id, x_parent_set_id, x_parent_chain);\n END LOOP;\n CLOSE x_sound_set_handle;\n ELSE\n DELETE p FROM voip_sound_set_handle_parents p\n WHERE set_id IN (\n WITH RECURSIVE cte as (\n SELECT s.id\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id\n FROM voip_sound_sets s\n JOIN cte ON cte.id = s.parent_id\n )\n SELECT id\n FROM cte\n );\n\n OPEN x_sound_set;\n iter: LOOP\n FETCH x_sound_set INTO x_set_id, x_handle_id, x_parent_set_id, x_parent_chain;\n IF done THEN\n LEAVE iter;\n END IF;\n INSERT INTO voip_sound_set_handle_parents\n (set_id, handle_id, parent_set_id, parent_chain)\n VALUES\n (x_set_id, x_handle_id, x_parent_set_id, x_parent_chain);\n END LOOP;\n CLOSE x_sound_set;\n END IF;\n ELSE\n IF u_handle_id IS NOT NULL THEN\n DELETE FROM voip_sound_set_handle_parents WHERE handle_id = u_handle_id;\n\n OPEN x_handle;\n iter: LOOP\n FETCH x_handle INTO x_set_id, x_handle_id, x_parent_set_id, x_parent_chain;\n IF done THEN\n LEAVE iter;\n END IF;\n INSERT INTO voip_sound_set_handle_parents\n (set_id, handle_id, parent_set_id, parent_chain)\n VALUES\n (x_set_id, x_handle_id, x_parent_set_id, x_parent_chain);\n END LOOP;\n CLOSE x_handle;\n ELSE\n DELETE FROM voip_sound_set_handle_parents;\n\n OPEN x;\n iter: LOOP\n FETCH x INTO x_set_id, x_handle_id, x_parent_set_id, x_parent_chain;\n IF done THEN\n LEAVE iter;\n END IF;\n INSERT INTO voip_sound_set_handle_parents\n (set_id, handle_id, parent_set_id, parent_chain)\n VALUES\n (x_set_id, x_handle_id, x_parent_set_id, x_parent_chain);\n END LOOP;\n CLOSE x;\n END IF;\n END IF;\n\nEND", "ROUTINE_TYPE" : "PROCEDURE", "key_col" : "update_sound_set_handle_parents" } diff --git a/schema/provisioning.sql b/schema/provisioning.sql index e08b8131..1a1d7fd6 100644 --- a/schema/provisioning.sql +++ b/schema/provisioning.sql @@ -5706,7 +5706,7 @@ CREATE TABLE `voip_subscribers` ( CONSTRAINT `voip_subscribers_ibfk_1` FOREIGN KEY (`domain_id`) REFERENCES `voip_domains` (`id`) ) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci; /*!40101 SET character_set_client = @saved_cs_client */; -INSERT INTO `voip_subscribers` VALUES (3,'no_such_number',2,'9bcb88b6-541a-43da-8fdc-816f5557ff93','5c83b8a56cdaf703a441375173c4bdd6',0,NULL,NULL,NULL,0,0,'none',NULL,NULL,NULL,NULL,NOW(),NOW()); +INSERT INTO `voip_subscribers` VALUES (3,'no_such_number',2,'9bcb88b6-541a-43da-8fdc-816f5557ff93','3cef5290e9aa18bbbff0d1e4af3d63b9',0,NULL,NULL,NULL,0,0,'none',NULL,NULL,NULL,NULL,NOW(),NOW()); /*!50003 SET @saved_cs_client = @@character_set_client */ ; /*!50003 SET @saved_cs_results = @@character_set_results */ ; /*!50003 SET @saved_col_connection = @@collation_connection */ ;