MT#58709 address update_sound_set_handle_parents() sp deadlocks

* update_sound_set_handle_parents() procedure is redesigned
  to avoid "insert into select from" statements as they cause
  gap locks when run concurrently and access the same index
  rows.

*** WAITING FOR THIS LOCK TO BE GRANTED:
RECORD LOCKS space id 6594 page no 6 n bits 56 index parent_id_idx
of table `provisioning`.`voip_sound_sets` trx id 400852
lock mode S locks rec but not gap waiting

  the "insert into select from" statements are reworked:
   the "select from/with recursive" parts are now declared cursors
   and the data is inserted inside the opened cursor loop (if any).
   this way the selects are not causing exclusive gap locks.

(cherry picked from commit 4017d3519c)

Change-Id: I35ec28a33ecca42de898e67a2709eda4364e5f95
mr11.3
Kirill Solomko 1 year ago committed by Sipwise Jenkins Builder
parent 7c874d027a
commit f7652553e2

@ -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 ;

@ -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 ;

@ -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` (

@ -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` (

File diff suppressed because one or more lines are too long

@ -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 */ ;

Loading…
Cancel
Save