diff --git a/recommender_geographic.sql b/recommender_geographic.sql new file mode 100644 index 0000000000000000000000000000000000000000..169378693599eb4229f8a583d08ecd9f9562c9c3 --- /dev/null +++ b/recommender_geographic.sql @@ -0,0 +1,50 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +DELIMITER $$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_geographic_action_id`(IN action_id_in INT, IN kpi INT) +BEGIN + SET @deg_to_km = 111.2; + IF kpi is null THEN + SELECT + p.action_id, p.action_name, p.lon, p.lat, + -- This lines are so we can get the list of kpis vvvvvvvvvv + GROUP_CONCAT(distinct t_list.kpi_id) as kpi_id_list, + GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list, + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + POW(@deg_to_km * (p.lat - p_t.lat), 2) + + POW(@deg_to_km * (p_t.lon - p.lon) * COS(p.lat / 57.3), 2) AS distance_squared + FROM action p + LEFT JOIN action p_t ON p_t.action_id = action_id_in + -- This lines are so we can get the list of kpis vvvvvvvvvv + INNER JOIN kpi_action t_p_list ON t_p_list.action_id = p.action_id + INNER JOIN kpi t_list ON t_list.kpi_id = t_p_list.kpi_id + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + WHERE p_t.action_id != p.action_id + GROUP BY p.action_id + ORDER BY distance_squared ASC + LIMIT 100; + ELSE + SELECT + p.action_id, p.action_name, p.lon, p.lat, + -- This lines are so we can get the list of kpis vvvvvvvvvv + GROUP_CONCAT(distinct t_list.kpi_id) as kpi_id_list, + GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list, + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + POW(@deg_to_km * (p.lat - p_t.lat), 2) + + POW(@deg_to_km * (p_t.lon - p.lon) * COS(p.lat / 57.3), 2) AS distance_squared + FROM action p + LEFT JOIN action p_t ON p_t.action_id = action_id_in + INNER JOIN kpi_action t ON t.action_id = p.action_id + -- This lines are so we can get the list of kpis vvvvvvvvvv + INNER JOIN kpi_action t_p_list ON t_p_list.action_id = p.action_id + INNER JOIN kpi t_list ON t_list.kpi_id = t_p_list.kpi_id + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + WHERE p_t.action_id != p.action_id AND t.kpi_id = kpi + GROUP BY p.action_id + ORDER BY distance_squared ASC + LIMIT 100; + END IF; +END$$ +DELIMITER ; diff --git a/recommender_popularity.sql b/recommender_popularity.sql new file mode 100644 index 0000000000000000000000000000000000000000..de0129142e1182248f06174b51f0675b3adf278a --- /dev/null +++ b/recommender_popularity.sql @@ -0,0 +1,88 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +recommender_kpis_action_idDELIMITER $$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_popularity`(IN kpi INT) +BEGIN + IF kpi is null THEN + SELECT p.action_id, p.action_name, p.lat, p.lon, + -- This lines are so we can get the list of kpis vvvvvvvvvv + GROUP_CONCAT(distinct t_list.kpi_id) as kpi_id_list, + GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list, + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + p.popularity as popularity + FROM action p + -- This lines are so we can get the list of kpis vvvvvvvvvv + INNER JOIN kpi_action t_p_list ON t_p_list.action_id = p.action_id + INNER JOIN kpi t_list ON t_list.kpi_id = t_p_list.kpi_id + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + GROUP BY p.action_id + ORDER BY popularity DESC + LIMIT 100; + ELSE + SELECT p.action_id, p.action_name, p.lat, p.lon, + -- This lines are so we can get the list of kpis vvvvvvvvvv + GROUP_CONCAT(distinct t_list.kpi_id) as kpi_id_list, + GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list, + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + p.popularity as popularity + FROM action p + INNER JOIN kpi_action t ON t.action_id = p.action_id + -- This lines are so we can get the list of kpis vvvvvvvvvv + INNER JOIN kpi_action t_p_list ON t_p_list.action_id = p.action_id + INNER JOIN kpi t_list ON t_list.kpi_id = t_p_list.kpi_id + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + WHERE t.kpi_id = kpi + GROUP BY p.action_id + ORDER BY popularity DESC + LIMIT 100; + END IF; +END$$ +DELIMITER ; +DELIMITER $$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_geographic_action_id`(IN action_id_in INT, IN kpi INT) +BEGIN + SET @deg_to_km = 111.2; + IF kpi is null THEN + SELECT + p.action_id, p.action_name, p.lon, p.lat, + -- This lines are so we can get the list of kpis vvvvvvvvvv + GROUP_CONCAT(distinct t_list.kpi_id) as kpi_id_list, + GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list, + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + POW(@deg_to_km * (p.lat - p_t.lat), 2) + + POW(@deg_to_km * (p_t.lon - p.lon) * COS(p.lat / 57.3), 2) AS distance_squared + FROM action p + LEFT JOIN action p_t ON p_t.action_id = action_id_in + -- This lines are so we can get the list of kpis vvvvvvvvvv + INNER JOIN kpi_action t_p_list ON t_p_list.action_id = p.action_id + INNER JOIN kpi t_list ON t_list.kpi_id = t_p_list.kpi_id + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + WHERE p_t.action_id != p.action_id + GROUP BY p.action_id + ORDER BY distance_squared ASC + LIMIT 100; + ELSE + SELECT + p.action_id, p.action_name, p.lon, p.lat, + -- This lines are so we can get the list of kpis vvvvvvvvvv + GROUP_CONCAT(distinct t_list.kpi_id) as kpi_id_list, + GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list, + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + POW(@deg_to_km * (p.lat - p_t.lat), 2) + + POW(@deg_to_km * (p_t.lon - p.lon) * COS(p.lat / 57.3), 2) AS distance_squared + FROM action p + LEFT JOIN action p_t ON p_t.action_id = action_id_in + INNER JOIN kpi_action t ON t.action_id = p.action_id + -- This lines are so we can get the list of kpis vvvvvvvvvv + INNER JOIN kpi_action t_p_list ON t_p_list.action_id = p.action_id + INNER JOIN kpi t_list ON t_list.kpi_id = t_p_list.kpi_id + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + WHERE p_t.action_id != p.action_id AND t.kpi_id = kpi + GROUP BY p.action_id + ORDER BY distance_squared ASC + LIMIT 100; + END IF; +END$$ +DELIMITER ; \ No newline at end of file diff --git a/recommender_preferences.sql b/recommender_preferences.sql new file mode 100644 index 0000000000000000000000000000000000000000..26f7ff02c8da513c06af1581da9d54cae6254d33 --- /dev/null +++ b/recommender_preferences.sql @@ -0,0 +1,61 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +DELIMITER $$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_preferences`( + IN emission_total FLOAT, + IN noise_total FLOAT, + IN kpi INT) +BEGIN + IF kpi IS NULL THEN + SELECT c_action.action_id, p.action_name, p.lat, p.lon, + -- This lines are so we can get the list of kpis vvvvvvvvvv + GROUP_CONCAT(distinct t_list.kpi_id) as kpi_id_list, + GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list, + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + COUNT(c_action.action_id) as Count + FROM CHOSEN_action c_action + INNER JOIN + (SELECT r.plan_id, + r.time_slot, + POWER(r.emission_total-emission_total,2) + POWER(r.noise_total-noise_total,2) as distance + FROM plan_detail r + ORDER BY distance ASC + LIMIT 5) as r ON c_action.plan_id = r.plan_id AND c_action.time_slot = r.time_slot + INNER JOIN action p ON c_action.action_id = p.action_id + -- This lines are so we can get the list of kpis vvvvvvvvvv + INNER JOIN kpi_action t_p_list ON t_p_list.action_id = p.action_id + INNER JOIN kpi t_list ON t_list.kpi_id = t_p_list.kpi_id + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + GROUP BY c_action.action_id + ORDER BY Count DESC + LIMIT 100; + ELSE + SELECT c_action.action_id, p.action_name, p.lat, p.lon, + -- This lines are so we can get the list of kpis vvvvvvvvvv + GROUP_CONCAT(distinct t_list.kpi_id) as kpi_id_list, + GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list, + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + COUNT(c_action.action_id) as Count + FROM CHOSEN_action c_action + INNER JOIN + (SELECT r.plan_id, + r.time_slot, + POWER(r.emission_total-emission_total,2) + POWER(r.noise_total-noise_total,2) as distance + FROM plan_detail r + ORDER BY distance ASC + LIMIT 5) as r ON c_action.plan_id = r.plan_id AND c_action.time_slot = r.time_slot + INNER JOIN action p ON c_action.action_id = p.action_id + INNER JOIN kpi_action t ON t.action_id = p.action_id + -- This lines are so we can get the list of kpis vvvvvvvvvv + INNER JOIN kpi_action t_p_list ON t_p_list.action_id = p.action_id + INNER JOIN kpi t_list ON t_list.kpi_id = t_p_list.kpi_id + -- This lines are so we can get the list of kpis ^^^^^^^^^^ + WHERE t.kpi_id = kpi + GROUP BY c_action.action_id + ORDER BY Count DESC + LIMIT 100; + END IF; +END$$ +DELIMITER ; diff --git a/recommender_tags.sql b/recommender_tags.sql new file mode 100644 index 0000000000000000000000000000000000000000..4da3b6425c4e758c4a3a090cb0b650a556d14e8f --- /dev/null +++ b/recommender_tags.sql @@ -0,0 +1,36 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +DELIMITER // +DELIMITER $$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_kpis_action_id`(IN action_id INT) +BEGIN + SELECT kpi.kpi_id, kpi_name, count(*) as Count, kpi.popularity as Popularity, count(*)/kpi.popularity as Probability FROM kpi kpi + INNER JOIN ( + SELECT DISTINCT t_p.action_id, t_p.kpi_id, c_p.plan_id, r.time_slot FROM kpi_action t_p + INNER JOIN CHOSEN_action c_p ON c_p.action_id = t_p.action_id + INNER JOIN plan_detail r ON r.plan_id = c_p.plan_id AND r.time_slot = c_p.time_slot + INNER JOIN CHOSEN_action target_p ON r.plan_id = target_p.plan_id AND r.time_slot = target_p.time_slot + WHERE target_p.action_id = action_id) as distinct_kpis ON kpi.kpi_id = distinct_kpis.kpi_id + GROUP BY kpi.kpi_id + ORDER BY Probability DESC; +END$$ +DELIMITER ; + + +DELIMITER $$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_kpis_kpi_id`(IN kpi_id INT) +BEGIN +SELECT kpi.kpi_id, kpi_name, count(*) as Count, kpi.popularity as Popularity, count(*)/kpi.popularity as Probability FROM kpi kpi + INNER JOIN ( + SELECT DISTINCT t_p.action_id, t_p.kpi_id, c_p.plan_id, r.time_slot FROM kpi_action t_p + INNER JOIN CHOSEN_action c_p ON c_p.action_id = t_p.action_id + INNER JOIN plan_detail r ON r.plan_id = c_p.plan_id AND r.time_slot = c_p.time_slot + INNER JOIN CHOSEN_action target_p ON r.plan_id = target_p.plan_id AND r.time_slot = target_p.time_slot + INNER JOIN kpi_action target_kpi_p ON target_kpi_p.kpi_id != t_p.kpi_id AND target_p.action_id = target_kpi_p.action_id + WHERE target_kpi_p.kpi_id = kpi_id) as distinct_kpis ON kpi.kpi_id = distinct_kpis.kpi_id + GROUP BY kpi.kpi_id + ORDER BY Probability DESC; +END$$ +DELIMITER ;