From b1d825d35e63e3827eb9f70926c954f8828e84c5 Mon Sep 17 00:00:00 2001 From: "Campos Cordobes, Sergio" <sergio.campos@tecnalia.com> Date: Tue, 14 Feb 2023 11:02:40 +0100 Subject: [PATCH] Update recommender_bayesian.sql, recommender_geographic.sql, recommender_popularity.sql, recommender_preferences.sql, recommender_tags.sql --- recommender_bayesian.sql | 103 ++++++++++++++++++++++++++++++++++++ recommender_geographic.sql | 50 +++++++++++++++++ recommender_popularity.sql | 88 ++++++++++++++++++++++++++++++ recommender_preferences.sql | 61 +++++++++++++++++++++ recommender_tags.sql | 36 +++++++++++++ 5 files changed, 338 insertions(+) create mode 100644 recommender_bayesian.sql create mode 100644 recommender_geographic.sql create mode 100644 recommender_popularity.sql create mode 100644 recommender_preferences.sql create mode 100644 recommender_tags.sql diff --git a/recommender_bayesian.sql b/recommender_bayesian.sql new file mode 100644 index 0000000..92d7f26 --- /dev/null +++ b/recommender_bayesian.sql @@ -0,0 +1,103 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +DELIMITER $$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_bayesian_action_id`( + IN action_id_array VARCHAR(255), + IN kpi INT) +BEGIN + -- Temporary table so we can parse an set of ids + DROP TEMPORARY TABLE IF EXISTS temp_table; + CREATE TEMPORARY TABLE temp_table(action_id INT); + + INSERT INTO temp_table(action_id) + SELECT action_id + FROM action p + WHERE FIND_IN_SET(p.action_id, action_id_array); + + -- Amount of actions in input set. Important to check if P(B/A) checks all input actions + SET @values_in_temp = (SELECT COUNT(*) FROM temp_table); + + -- P(B|A) + DROP TEMPORARY TABLE IF EXISTS probabilidad_b_sub_a; + CREATE TEMPORARY TABLE probabilidad_b_sub_a(action_id INT, probability_b_a FLOAT); + + INSERT INTO probabilidad_b_sub_a(action_id, probability_b_a) + SELECT distinct_t.action_id, COUNT(distinct_t.action_id) as probability_b_a FROM CHOSEN_action distinct_t + INNER JOIN (SELECT t.plan_id, t.time_slot, COUNT(t.action_id) as contador, t.action_id FROM CHOSEN_action t + WHERE action_id IN (SELECT * FROM temp_table) + GROUP BY t.plan_id, t.time_slot) as t + ON distinct_t.plan_id = t.plan_id + WHERE t.contador = @values_in_temp AND NOT FIND_IN_SET(distinct_t.action_id, action_id_array) + GROUP BY distinct_t.action_id + ORDER BY probability_b_a DESC; + + SET @total_rutas_b = (SELECT COUNT(*) FROM probabilidad_b_sub_a); + -- At this actionnt probability is just a count so probability = count / total + UPDATE probabilidad_b_sub_a SET probability_b_a = probability_b_a / @total_rutas_b; + + -- P(A) + SET @action_total = (SELECT Count(*) FROM CHOSEN_action); + + DROP TEMPORARY TABLE IF EXISTS probability_a; + CREATE TEMPORARY TABLE probability_a(action_id INT, probability_A Float); + + INSERT INTO probability_a(action_id, probability_A) + SELECT p.action_id, p.popularity/@action_total FROM probabilidad_b_sub_a p_b_a + INNER JOIN action p WHERE p.action_id = p_b_a.action_id; + + -- P(B) + SET @counter_b = (SELECT COUNT(r.plan_id) as Count FROM plan_detail r + INNER JOIN (SELECT t.plan_id, t.time_slot, COUNT(t.action_id) as contador, t.action_id FROM CHOSEN_action t + WHERE action_id IN (SELECT * FROM temp_table) + GROUP BY t.plan_id, t.time_slot) as t + ON r.plan_id = t.plan_id + WHERE t.contador = @values_in_temp); + + SET @probability_b = IF(@counter_b is null, 0, @counter_b/(SELECT Count(*) FROM plan_detail)); + + -- P(A/B) + IF kpi is null THEN + SELECT + p_a.action_id, action.action_name, action.lat, action.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 ^^^^^^^^^^ + probability_a*probability_b_a/@probability_b as bayesian_probability, + probability_a, probability_b_a, @probability_b as probability_b + FROM probability_a p_a + INNER JOIN probabilidad_b_sub_a p_b_a ON p_b_a.action_id = p_a.action_id + LEFT OUTER JOIN action action ON action.action_id = p_a.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_a.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_a.action_id + ORDER BY bayesian_probability DESC + LIMIT 100; + ELSE + SELECT + p_a.action_id, action.action_name, action.lat, action.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 ^^^^^^^^^^ + probability_a*probability_b_a/@probability_b as bayesian_probability, + probability_a, probability_b_a, @probability_b as probability_b + FROM probability_a p_a + INNER JOIN probabilidad_b_sub_a p_b_a ON p_b_a.action_id = p_a.action_id + LEFT OUTER JOIN action action ON action.action_id = p_a.action_id + INNER JOIN kpi_action t ON t.action_id = action.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_a.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_a.action_id + ORDER BY bayesian_probability DESC + LIMIT 100; + END IF; +END$$ +DELIMITER ; diff --git a/recommender_geographic.sql b/recommender_geographic.sql new file mode 100644 index 0000000..1693786 --- /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 0000000..de01291 --- /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 0000000..26f7ff0 --- /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 0000000..4da3b64 --- /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 ; -- GitLab