MT#56693 fix 15766.up improve parent_chain aggregation, schemes update

Change-Id: Ifbaa9ee385d7b39ddcee406f2dce323744571b3a
mr11.3
Sipwise Jenkins Builder 2 years ago committed by Marco Capetta
parent 861f5c9ad8
commit 3749c8babb

@ -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','8353ab8f32ac02c25b81aac4564cf2da','000ff269816884209a318b5ba99d683a','d6ad8fa82767629149db6e87f9899cc9','9bcb88b6-541a-43da-8fdc-816f5557ff93','',NOW());
INSERT INTO `subscriber` VALUES (1,'no_such_number','voip.sipwise.local','470f6aa25d0182cf8532377aed57ef87','b99ca7755b591ac102708dd549d62050','b3d09291886ade730d8ccd16610ccf74','9bcb88b6-541a-43da-8fdc-816f5557ff93','',NOW());
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `trusted` (

@ -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=829 DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci;
) ENGINE=InnoDB AUTO_INCREMENT=830 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());
@ -30844,6 +30844,7 @@ INSERT INTO `db_schema` VALUES (825,15756,'spce',NOW());
INSERT INTO `db_schema` VALUES (826,15757,'spce',NOW());
INSERT INTO `db_schema` VALUES (827,15758,'spce',NOW());
INSERT INTO `db_schema` VALUES (828,15759,'spce',NOW());
INSERT INTO `db_schema` VALUES (829,15766,'spce',NOW());
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `timezone` (

@ -6132,6 +6132,66 @@
"TABLE_NAME" : "voip_sound_handles",
"key_col" : "voip_sound_handles/name"
},
"voip_sound_set_handle_parents/handle_id" : {
"CHARACTER_SET_NAME" : null,
"COLLATION_NAME" : null,
"COLUMN_DEFAULT" : null,
"COLUMN_NAME" : "handle_id",
"COLUMN_TYPE" : "int(11)",
"EXTRA" : "",
"IS_NULLABLE" : "NO",
"ORDINAL_POSITION" : 3,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/handle_id"
},
"voip_sound_set_handle_parents/id" : {
"CHARACTER_SET_NAME" : null,
"COLLATION_NAME" : null,
"COLUMN_DEFAULT" : null,
"COLUMN_NAME" : "id",
"COLUMN_TYPE" : "int(11)",
"EXTRA" : "auto_increment",
"IS_NULLABLE" : "NO",
"ORDINAL_POSITION" : 1,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/id"
},
"voip_sound_set_handle_parents/parent_chain" : {
"CHARACTER_SET_NAME" : "utf8",
"COLLATION_NAME" : "utf8_general_ci",
"COLUMN_DEFAULT" : "NULL",
"COLUMN_NAME" : "parent_chain",
"COLUMN_TYPE" : "varchar(1024)",
"EXTRA" : "",
"IS_NULLABLE" : "YES",
"ORDINAL_POSITION" : 5,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/parent_chain"
},
"voip_sound_set_handle_parents/parent_set_id" : {
"CHARACTER_SET_NAME" : null,
"COLLATION_NAME" : null,
"COLUMN_DEFAULT" : "NULL",
"COLUMN_NAME" : "parent_set_id",
"COLUMN_TYPE" : "int(11)",
"EXTRA" : "",
"IS_NULLABLE" : "YES",
"ORDINAL_POSITION" : 4,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/parent_set_id"
},
"voip_sound_set_handle_parents/set_id" : {
"CHARACTER_SET_NAME" : null,
"COLLATION_NAME" : null,
"COLUMN_DEFAULT" : null,
"COLUMN_NAME" : "set_id",
"COLUMN_TYPE" : "int(11)",
"EXTRA" : "",
"IS_NULLABLE" : "NO",
"ORDINAL_POSITION" : 2,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/set_id"
},
"voip_sound_sets/contract_default" : {
"CHARACTER_SET_NAME" : null,
"COLLATION_NAME" : null,
@ -8452,6 +8512,16 @@
"UPDATE_RULE" : "CASCADE",
"key_col" : "voip_sound_handles/v_s_h_group_ref/group_id/voip_sound_groups/id"
},
"voip_sound_set_handle_parents/vshh_handle_id_ref/handle_id/voip_sound_handles/id" : {
"COLUMN_NAME" : "handle_id",
"CONSTRAINT_NAME" : "vshh_handle_id_ref",
"DELETE_RULE" : "CASCADE",
"REFERENCED_COLUMN_NAME" : "id",
"REFERENCED_TABLE_NAME" : "voip_sound_handles",
"TABLE_NAME" : "voip_sound_set_handle_parents",
"UPDATE_RULE" : "CASCADE",
"key_col" : "voip_sound_set_handle_parents/vshh_handle_id_ref/handle_id/voip_sound_handles/id"
},
"voip_sound_sets/vss_parent_id_ref/parent_id/voip_sound_sets/id" : {
"COLUMN_NAME" : "parent_id",
"CONSTRAINT_NAME" : "vss_parent_id_ref",
@ -12088,6 +12158,66 @@
"TABLE_NAME" : "voip_sound_handles",
"key_col" : "voip_sound_handles/v_s_h_group_ref/1"
},
"voip_sound_set_handle_parents/PRIMARY/1" : {
"COLLATION" : "A",
"COLUMN_NAME" : "id",
"INDEX_NAME" : "PRIMARY",
"INDEX_TYPE" : "BTREE",
"NON_UNIQUE" : 0,
"NULLABLE" : "",
"SEQ_IN_INDEX" : 1,
"SUB_PART" : null,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/PRIMARY/1"
},
"voip_sound_set_handle_parents/handle_id_idx/1" : {
"COLLATION" : "A",
"COLUMN_NAME" : "handle_id",
"INDEX_NAME" : "handle_id_idx",
"INDEX_TYPE" : "BTREE",
"NON_UNIQUE" : 1,
"NULLABLE" : "",
"SEQ_IN_INDEX" : 1,
"SUB_PART" : null,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/handle_id_idx/1"
},
"voip_sound_set_handle_parents/parent_set_id_idx/1" : {
"COLLATION" : "A",
"COLUMN_NAME" : "parent_set_id",
"INDEX_NAME" : "parent_set_id_idx",
"INDEX_TYPE" : "BTREE",
"NON_UNIQUE" : 1,
"NULLABLE" : "YES",
"SEQ_IN_INDEX" : 1,
"SUB_PART" : null,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/parent_set_id_idx/1"
},
"voip_sound_set_handle_parents/set_handle_id_idx/1" : {
"COLLATION" : "A",
"COLUMN_NAME" : "set_id",
"INDEX_NAME" : "set_handle_id_idx",
"INDEX_TYPE" : "BTREE",
"NON_UNIQUE" : 0,
"NULLABLE" : "",
"SEQ_IN_INDEX" : 1,
"SUB_PART" : null,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/set_handle_id_idx/1"
},
"voip_sound_set_handle_parents/set_handle_id_idx/2" : {
"COLLATION" : "A",
"COLUMN_NAME" : "handle_id",
"INDEX_NAME" : "set_handle_id_idx",
"INDEX_TYPE" : "BTREE",
"NON_UNIQUE" : 0,
"NULLABLE" : "",
"SEQ_IN_INDEX" : 2,
"SUB_PART" : null,
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents/set_handle_id_idx/2"
},
"voip_sound_sets/PRIMARY/1" : {
"COLLATION" : "A",
"COLUMN_NAME" : "id",
@ -12801,6 +12931,11 @@
"ROUTINE_DEFINITION" : "BEGIN\n\n RETURN IF(LOCATE(\".\",_ipnet) = 0,1,0);\n\nEND",
"ROUTINE_TYPE" : "FUNCTION",
"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 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 OR 1=1);\n\n DELETE p FROM voip_sound_set_handle_parents p\n WHERE set_id IN (\n WITH RECURSIVE cte as (\n SELECT s.id, s.parent_id\n FROM voip_sound_sets s\n WHERE id = u_sound_set_id\n UNION\n SELECT s.id, s.parent_id\n FROM voip_sound_sets s\n JOIN cte ON cte.parent_id = s.id\n )\n SELECT id\n FROM cte\n )\n AND (handle_id = u_handle_id OR 1=1);\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.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 OR 1=1)\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(cte.parent_chain, ':', ''), 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 IF u_handle_id IS NOT NULL THEN\n DELETE FROM voip_sound_set_handle_parents WHERE handle_id = u_handle_id;\n ELSE\n DELETE FROM voip_sound_set_handle_parents;\n END IF;\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 OR 1=1)\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(cte.parent_chain, ':', ''), 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\nEND",
"ROUTINE_TYPE" : "PROCEDURE",
"key_col" : "update_sound_set_handle_parents"
}
},
"tables" : {
@ -13378,6 +13513,13 @@
"TABLE_NAME" : "voip_sound_handles",
"key_col" : "voip_sound_handles"
},
"voip_sound_set_handle_parents" : {
"CREATE_OPTIONS" : "",
"ENGINE" : "InnoDB",
"TABLE_COLLATION" : "utf8_general_ci",
"TABLE_NAME" : "voip_sound_set_handle_parents",
"key_col" : "voip_sound_set_handle_parents"
},
"voip_sound_sets" : {
"CREATE_OPTIONS" : "",
"ENGINE" : "InnoDB",
@ -13493,7 +13635,7 @@
},
"views" : {
"v_sound_set_files" : {
"VIEW_DEFINITION" : "with recursive cte as (select `v`.`id` AS `set_id`,`v`.`reseller_id` AS `reseller_id`,`v`.`contract_id` AS `contract_id`,`v`.`name` AS `name`,`v`.`description` AS `description`,`v`.`handle_id` AS `handle_id`,`v`.`handle_name` AS `handle_name`,`v`.`id` AS `data_set_id`,json_array(`v`.`id`) AS `parent_chain` from ((select `s`.`id` AS `id`,`s`.`reseller_id` AS `reseller_id`,`s`.`contract_id` AS `contract_id`,`s`.`name` AS `name`,`s`.`description` AS `description`,`s`.`contract_default` AS `contract_default`,`s`.`parent_id` AS `parent_id`,`s`.`expose_to_customer` AS `expose_to_customer`,`h`.`id` AS `handle_id`,`h`.`name` AS `handle_name` from `provisioning`.`voip_sound_sets` `s` join `provisioning`.`voip_sound_handles` `h`) `v` left join `provisioning`.`voip_sound_files` `f` on(`f`.`handle_id` = `v`.`handle_id` and `f`.`set_id` = `v`.`id`)) where `v`.`parent_id` is null union all select `v`.`id` AS `set_id`,`v`.`reseller_id` AS `reseller_id`,`v`.`contract_id` AS `contract_id`,`v`.`name` AS `name`,`v`.`description` AS `description`,`v`.`handle_id` AS `handle_id`,`v`.`handle_name` AS `handle_name`,if(`v`.`use_parent` = 0,`v`.`id`,`cte`.`data_set_id`) AS `data_set_id`,json_array_insert(`cte`.`parent_chain`,'$[0]',`v`.`id`) AS `parent_chain` from ((select `t`.`id` AS `id`,`t`.`reseller_id` AS `reseller_id`,`t`.`contract_id` AS `contract_id`,`t`.`name` AS `name`,`t`.`description` AS `description`,`t`.`contract_default` AS `contract_default`,`t`.`parent_id` AS `parent_id`,`t`.`expose_to_customer` AS `expose_to_customer`,`t`.`handle_id` AS `handle_id`,`t`.`handle_name` AS `handle_name`,`f`.`filename` AS `filename`,`f`.`use_parent` AS `use_parent` from ((select `s`.`id` AS `id`,`s`.`reseller_id` AS `reseller_id`,`s`.`contract_id` AS `contract_id`,`s`.`name` AS `name`,`s`.`description` AS `description`,`s`.`contract_default` AS `contract_default`,`s`.`parent_id` AS `parent_id`,`s`.`expose_to_customer` AS `expose_to_customer`,`h`.`id` AS `handle_id`,`h`.`name` AS `handle_name` from `provisioning`.`voip_sound_sets` `s` join `provisioning`.`voip_sound_handles` `h`) `t` left join `provisioning`.`voip_sound_files` `f` on(`f`.`handle_id` = `t`.`handle_id` and `f`.`set_id` = `t`.`id`))) `v` join `cte` on(`cte`.`set_id` = `v`.`parent_id` and `cte`.`handle_id` = `v`.`handle_id`)))select `cte`.`set_id` AS `set_id`,`cte`.`reseller_id` AS `reseller_id`,`cte`.`contract_id` AS `contract_id`,`cte`.`name` AS `name`,`cte`.`description` AS `description`,`cte`.`handle_id` AS `handle_id`,`cte`.`handle_name` AS `handle_name`,`vsf`.`id` AS `file_id`,`vsf`.`filename` AS `filename`,`vsf`.`loopplay` AS `loopplay`,replace(replace(replace(json_remove(`cte`.`parent_chain`,'$[0]'),'[',''),']',''),', ',':') AS `parent_chain`,`cte`.`data_set_id` AS `data_set_id`,`vsf`.`data` AS `data` from (`cte` left join `provisioning`.`voip_sound_files` `vsf` on(`vsf`.`set_id` = `cte`.`data_set_id` and `vsf`.`handle_id` = `cte`.`handle_id`))",
"VIEW_DEFINITION" : "select `r`.`set_id` AS `set_id`,`s`.`reseller_id` AS `reseller_id`,`s`.`contract_id` AS `contract_id`,`s`.`name` AS `name`,`s`.`description` AS `description`,`r`.`handle_id` AS `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 ((((`provisioning`.`voip_sound_set_handle_parents` `r` join `provisioning`.`voip_sound_sets` `s` on(`s`.`id` = `r`.`set_id`)) join `provisioning`.`voip_sound_handles` `h` on(`h`.`id` = `r`.`handle_id`)) left join `provisioning`.`voip_sound_files` `vsf` on(`vsf`.`set_id` = `r`.`set_id` and `vsf`.`handle_id` = `r`.`handle_id`)) left join `provisioning`.`voip_sound_files` `vsf_p` on(`vsf_p`.`set_id` = `r`.`parent_set_id` and `vsf_p`.`handle_id` = `r`.`handle_id`))",
"key_col" : "v_sound_set_files"
},
"v_subscriber_cfs" : {

@ -5114,6 +5114,83 @@ CREATE TABLE `voip_sound_files` (
CONSTRAINT `set_id_ref` FOREIGN KEY (`set_id`) REFERENCES `voip_sound_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = utf8 */ ;
/*!50003 SET character_set_results = utf8 */ ;
/*!50003 SET collation_connection = utf8_general_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ;;
/*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 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 ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = utf8 */ ;
/*!50003 SET character_set_results = utf8 */ ;
/*!50003 SET collation_connection = utf8_general_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ;;
/*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 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 ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = utf8 */ ;
/*!50003 SET character_set_results = utf8 */ ;
/*!50003 SET collation_connection = utf8_general_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ;;
/*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 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 ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `voip_sound_groups` (
@ -5300,6 +5377,21 @@ INSERT INTO `voip_sound_handles` VALUES (151,'aa_timeout',2,1);
INSERT INTO `voip_sound_handles` VALUES (152,'aa_default',2,1);
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE 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
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `voip_sound_sets` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`reseller_id` int(11) unsigned NOT NULL DEFAULT 1,
@ -5318,6 +5410,86 @@ CREATE TABLE `voip_sound_sets` (
CONSTRAINT `vss_reseller_ref` FOREIGN KEY (`reseller_id`) REFERENCES `billing`.`resellers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = utf8 */ ;
/*!50003 SET character_set_results = utf8 */ ;
/*!50003 SET collation_connection = utf8_general_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ;;
/*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER voip_sound_sets_create_trig AFTER INSERT ON voip_sound_sets
FOR each ROW BEGIN
IF NEW.parent_id IS NOT NULL THEN
CALL update_sound_set_handle_parents(NEW.id, NULL);
END IF;
END */;;
DELIMITER ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = utf8 */ ;
/*!50003 SET character_set_results = utf8 */ ;
/*!50003 SET collation_connection = utf8_general_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ;;
/*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 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 ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = utf8 */ ;
/*!50003 SET character_set_results = utf8 */ ;
/*!50003 SET collation_connection = utf8_general_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ;;
/*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 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;
END */;;
DELIMITER ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `voip_speed_dial` (
@ -5534,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','8353ab8f32ac02c25b81aac4564cf2da',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','470f6aa25d0182cf8532377aed57ef87',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 */ ;
@ -6016,7 +6188,7 @@ CREATE TABLE `xmlqueue` (
/*!50001 SET collation_connection = utf8_general_ci */;
/*!50001 CREATE ALGORITHM=UNDEFINED */
/*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */
/*!50001 VIEW `v_sound_set_files` AS with recursive cte as (select `v`.`id` AS `set_id`,`v`.`reseller_id` AS `reseller_id`,`v`.`contract_id` AS `contract_id`,`v`.`name` AS `name`,`v`.`description` AS `description`,`v`.`handle_id` AS `handle_id`,`v`.`handle_name` AS `handle_name`,`v`.`id` AS `data_set_id`,json_array(`v`.`id`) AS `parent_chain` from ((select `s`.`id` AS `id`,`s`.`reseller_id` AS `reseller_id`,`s`.`contract_id` AS `contract_id`,`s`.`name` AS `name`,`s`.`description` AS `description`,`s`.`contract_default` AS `contract_default`,`s`.`parent_id` AS `parent_id`,`s`.`expose_to_customer` AS `expose_to_customer`,`h`.`id` AS `handle_id`,`h`.`name` AS `handle_name` from (`voip_sound_sets` `s` join `voip_sound_handles` `h`)) `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 all select `v`.`id` AS `set_id`,`v`.`reseller_id` AS `reseller_id`,`v`.`contract_id` AS `contract_id`,`v`.`name` AS `name`,`v`.`description` AS `description`,`v`.`handle_id` AS `handle_id`,`v`.`handle_name` AS `handle_name`,if(`v`.`use_parent` = 0,`v`.`id`,`cte`.`data_set_id`) AS `data_set_id`,json_array_insert(`cte`.`parent_chain`,'$[0]',`v`.`id`) AS `parent_chain` from ((select `t`.`id` AS `id`,`t`.`reseller_id` AS `reseller_id`,`t`.`contract_id` AS `contract_id`,`t`.`name` AS `name`,`t`.`description` AS `description`,`t`.`contract_default` AS `contract_default`,`t`.`parent_id` AS `parent_id`,`t`.`expose_to_customer` AS `expose_to_customer`,`t`.`handle_id` AS `handle_id`,`t`.`handle_name` AS `handle_name`,`f`.`filename` AS `filename`,`f`.`use_parent` AS `use_parent` from ((select `s`.`id` AS `id`,`s`.`reseller_id` AS `reseller_id`,`s`.`contract_id` AS `contract_id`,`s`.`name` AS `name`,`s`.`description` AS `description`,`s`.`contract_default` AS `contract_default`,`s`.`parent_id` AS `parent_id`,`s`.`expose_to_customer` AS `expose_to_customer`,`h`.`id` AS `handle_id`,`h`.`name` AS `handle_name` from (`voip_sound_sets` `s` join `voip_sound_handles` `h`)) `t` left join `voip_sound_files` `f` on(`f`.`handle_id` = `t`.`handle_id` and `f`.`set_id` = `t`.`id`))) `v` join `cte` on(`cte`.`set_id` = `v`.`parent_id` and `cte`.`handle_id` = `v`.`handle_id`)))select `cte`.`set_id` AS `set_id`,`cte`.`reseller_id` AS `reseller_id`,`cte`.`contract_id` AS `contract_id`,`cte`.`name` AS `name`,`cte`.`description` AS `description`,`cte`.`handle_id` AS `handle_id`,`cte`.`handle_name` AS `handle_name`,`vsf`.`id` AS `file_id`,`vsf`.`filename` AS `filename`,`vsf`.`loopplay` AS `loopplay`,replace(replace(replace(json_remove(`cte`.`parent_chain`,'$[0]'),'[',''),']',''),', ',':') AS `parent_chain`,`cte`.`data_set_id` AS `data_set_id`,`vsf`.`data` AS `data` from (`cte` left join `voip_sound_files` `vsf` on(`vsf`.`set_id` = `cte`.`data_set_id` and `vsf`.`handle_id` = `cte`.`handle_id`)) */;
/*!50001 VIEW `v_sound_set_files` AS select `r`.`set_id` AS `set_id`,`s`.`reseller_id` AS `reseller_id`,`s`.`contract_id` AS `contract_id`,`s`.`name` AS `name`,`s`.`description` AS `description`,`r`.`handle_id` AS `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`)) */;
/*!50001 SET character_set_client = @saved_cs_client */;
/*!50001 SET character_set_results = @saved_cs_results */;
/*!50001 SET collation_connection = @saved_col_connection */;

Loading…
Cancel
Save