57 lines
1.3 KiB
SQL
57 lines
1.3 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`zone_getFromGeo`(vGeoFk INT)
|
|
BEGIN
|
|
/**
|
|
* Returns all zones which have the passed geo included.
|
|
*
|
|
* @param vGeoFk The geo id
|
|
* @return tmp.zone(id) The list of zones
|
|
*/
|
|
DECLARE vChildFk INT DEFAULT vGeoFk;
|
|
DECLARE vParentFk INT;
|
|
DECLARE vLevel INT DEFAULT 1;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tNodes;
|
|
CREATE TEMPORARY TABLE tNodes
|
|
(PRIMARY KEY (id))
|
|
ENGINE = MEMORY
|
|
SELECT vGeoFk id, vLevel `level`;
|
|
|
|
myLoop: LOOP
|
|
SELECT parentFk INTO vParentFk
|
|
FROM zoneGeo
|
|
WHERE id = vChildFk;
|
|
|
|
SET vChildFk = vParentFk;
|
|
SET vLevel = vLevel + 1;
|
|
|
|
INSERT IGNORE INTO tNodes
|
|
SELECT vChildFk, vLevel
|
|
FROM DUAL
|
|
WHERE vChildFk IS NOT NULL;
|
|
|
|
IF ROW_COUNT() = 0 THEN
|
|
LEAVE myLoop;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.zone;
|
|
CREATE TEMPORARY TABLE tmp.zone
|
|
(INDEX (id))
|
|
ENGINE = MEMORY
|
|
SELECT id FROM (
|
|
SELECT zoneFk id, isIncluded
|
|
FROM (
|
|
SELECT i.zoneFk, i.isIncluded
|
|
FROM tNodes n
|
|
JOIN zoneIncluded i ON i.geoFk = n.id
|
|
ORDER BY zoneFk, n.`level`
|
|
LIMIT 10000000000000000000
|
|
) t
|
|
GROUP BY id HAVING isIncluded
|
|
) t;
|
|
|
|
DROP TEMPORARY TABLE tNodes;
|
|
END$$
|
|
DELIMITER ;
|