mirror of https://github.com/sipwise/db-schema.git
* convert unique key set_handle_id_idx (set_id, handle_id)
to non-unique to avoid deadlocks because of forced gap locks
in INSERT and DELETE concurrent operations (when such occur)
* "update_sound_set_handle_parents" procedure:
- avoid IODKU and instead calculate entries to skip on the fly.
- WITH and WITHOUT u_handle_id is now split into 2 separate
IF blocks as otherwise "AND handle_id = u_handle_id OR 1:1"
caused full handles update even if u_handle_id was there
* fix a typo for "TRIGGER voip_sound_files_create_trig AFTER INSERT"
which wrongly had "AFTER UPDATE"
* fix warnings of 'Truncated DOUBLE' coming from using IF evaluation
variable as boolean, IF(LENGTH(cte.parent_chain) > 1 addresses
it.
Change-Id: Id6b6ab66de53c2ccd95f28d23e5e2b97ece89923
(cherry picked from commit 38051cfc67
)
mr11.3
parent
f99b131f7f
commit
f9b9d89d8f
@ -0,0 +1,121 @@
|
||||
USE provisioning;
|
||||
|
||||
ALTER TABLE `voip_sound_set_handle_parents`
|
||||
DROP KEY `set_handle_id_idx`,
|
||||
ADD UNIQUE KEY `set_handle_id_idx` (`set_id`, `handle_id`);
|
||||
|
||||
|
||||
DELIMITER ;;
|
||||
CREATE OR REPLACE PROCEDURE update_sound_set_handle_parents(IN u_sound_set_id INT, IN u_handle_id INT)
|
||||
BEGIN
|
||||
IF u_sound_set_id IS NOT NULL THEN
|
||||
DELETE p FROM voip_sound_set_handle_parents p
|
||||
WHERE set_id = u_sound_set_id
|
||||
AND NOT EXISTS (SELECT id
|
||||
FROM voip_sound_sets
|
||||
WHERE id = u_sound_set_id);
|
||||
|
||||
DELETE p FROM voip_sound_set_handle_parents p
|
||||
WHERE set_id IN (
|
||||
WITH RECURSIVE cte as (
|
||||
SELECT s.id
|
||||
FROM voip_sound_sets s
|
||||
WHERE id = u_sound_set_id
|
||||
UNION
|
||||
SELECT s.id
|
||||
FROM voip_sound_sets s
|
||||
JOIN cte ON cte.id = s.parent_id
|
||||
)
|
||||
SELECT id
|
||||
FROM cte
|
||||
)
|
||||
AND (handle_id = u_handle_id OR 1=1);
|
||||
|
||||
INSERT INTO voip_sound_set_handle_parents(set_id, handle_id, parent_set_id, parent_chain)
|
||||
SELECT v.set_id, v.handle_id, v.data_set_id, v.parent_chain
|
||||
FROM (
|
||||
WITH RECURSIVE cte as (
|
||||
SELECT v.id AS set_id, v.handle_id,
|
||||
v.id AS data_set_id,
|
||||
CAST('' AS CHAR(4096)) AS parent_chain
|
||||
FROM (SELECT s.*, h.id as handle_id
|
||||
FROM (voip_sound_sets s, voip_sound_handles h)
|
||||
) AS v
|
||||
LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id
|
||||
WHERE v.id = (
|
||||
WITH RECURSIVE cte as (
|
||||
SELECT s.id, s.parent_id, CAST(0 as unsigned) as iter
|
||||
FROM voip_sound_sets s
|
||||
WHERE id = u_sound_set_id
|
||||
UNION
|
||||
SELECT s.id, s.parent_id, iter+1 as iter
|
||||
FROM voip_sound_sets s
|
||||
JOIN cte ON cte.parent_id = s.id
|
||||
)
|
||||
SELECT id
|
||||
FROM cte
|
||||
WHERE iter = (SELECT max(iter) from cte)
|
||||
)
|
||||
AND (v.handle_id = u_handle_id OR 1=1)
|
||||
UNION
|
||||
SELECT v.id AS set_id, v.handle_id,
|
||||
IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,
|
||||
CONCAT(v.parent_id, IF(cte.parent_chain, ':', ''), cte.parent_chain) as parent_chain
|
||||
FROM (SELECT s.*, h.id as handle_id, h.name as handle_name
|
||||
FROM (voip_sound_sets s, voip_sound_handles h)
|
||||
) AS v
|
||||
LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id
|
||||
JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id
|
||||
)
|
||||
SELECT set_id, handle_id,
|
||||
IF(data_set_id = set_id, NULL, data_set_id) as data_set_id,
|
||||
parent_chain
|
||||
FROM cte
|
||||
) as v
|
||||
ON DUPLICATE KEY UPDATE parent_set_id=v.data_set_id, parent_chain=v.parent_chain;
|
||||
ELSE
|
||||
IF u_handle_id IS NOT NULL THEN
|
||||
DELETE FROM voip_sound_set_handle_parents WHERE handle_id = u_handle_id;
|
||||
ELSE
|
||||
DELETE FROM voip_sound_set_handle_parents;
|
||||
END IF;
|
||||
|
||||
INSERT INTO voip_sound_set_handle_parents(set_id, handle_id, parent_set_id, parent_chain)
|
||||
WITH RECURSIVE cte as (
|
||||
SELECT v.id AS set_id, v.handle_id,
|
||||
v.id AS data_set_id,
|
||||
CAST('' AS CHAR(4096)) AS parent_chain
|
||||
FROM (SELECT s.*, h.id as handle_id
|
||||
FROM (voip_sound_sets s, voip_sound_handles h)
|
||||
) AS v
|
||||
LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id
|
||||
WHERE v.parent_id IS NULL
|
||||
AND (v.handle_id = u_handle_id OR 1=1)
|
||||
UNION
|
||||
SELECT v.id AS set_id, v.handle_id,
|
||||
IF(f.use_parent = 0, v.id, cte.data_set_id) AS data_set_id,
|
||||
CONCAT(v.parent_id, IF(cte.parent_chain, ':', ''), cte.parent_chain) as parent_chain
|
||||
FROM (SELECT s.*, h.id as handle_id, h.name as handle_name
|
||||
FROM (voip_sound_sets s, voip_sound_handles h)
|
||||
) AS v
|
||||
LEFT JOIN voip_sound_files f ON f.handle_id = v.handle_id AND f.set_id = v.id
|
||||
JOIN cte ON cte.set_id = v.parent_id AND cte.handle_id = v.handle_id
|
||||
)
|
||||
SELECT set_id, handle_id,
|
||||
IF(data_set_id = set_id, NULL, data_set_id) as data_set_id,
|
||||
parent_chain
|
||||
FROM cte;
|
||||
END IF;
|
||||
|
||||
END ;;
|
||||
DELIMITER ;
|
||||
|
||||
|
||||
delimiter ;;
|
||||
CREATE OR REPLACE TRIGGER voip_sound_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 ;
|
@ -0,0 +1,203 @@
|
||||
USE provisioning;
|
||||
|
||||
ALTER TABLE `voip_sound_set_handle_parents`
|
||||
DROP KEY `set_handle_id_idx`,
|
||||
ADD KEY `set_handle_id_idx` (`set_id`, `handle_id`);
|
||||
|
||||
|
||||
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 ;
|
||||
|
||||
|
||||
delimiter ;;
|
||||
CREATE OR REPLACE TRIGGER voip_sound_files_create_trig AFTER INSERT ON voip_sound_files
|
||||
FOR each ROW BEGIN
|
||||
|
||||
CALL update_sound_set_handle_parents(NEW.set_id, NEW.handle_id);
|
||||
|
||||
END;;
|
||||
delimiter ;
|
Loading…
Reference in new issue