From ee28c73769659ea06ffe2fa3822e3181f66a100c Mon Sep 17 00:00:00 2001 From: Kirill Solomko Date: Wed, 24 Jan 2024 13:34:27 +0100 Subject: [PATCH] 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. Change-Id: I35ec28a33ecca42de898e67a2709eda4364e5f95 (cherry picked from commit 4017d3519cc9f49db153ae09de66d96a782a8b32) (cherry picked from commit 9c0fd6e4a1889ddbcbb3a90521dd3e2d3bfe73a5) --- db_scripts/diff/15795.down | 190 ++++++++++++++++++++++++++ db_scripts/diff/15795.up | 265 +++++++++++++++++++++++++++++++++++++ 2 files changed, 455 insertions(+) create mode 100644 db_scripts/diff/15795.down create mode 100644 db_scripts/diff/15795.up 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 ; +