diff --git a/ddbb scripts/recommender_bayesian_action_id.sql b/ddbb scripts/recommender_bayesian_action_id.sql new file mode 100644 index 0000000000000000000000000000000000000000..1c36b09046648059488a7e523bb38c938c5c5e41 --- /dev/null +++ b/ddbb scripts/recommender_bayesian_action_id.sql @@ -0,0 +1,101 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +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.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.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.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 \ No newline at end of file diff --git a/ddbb scripts/recommender_geographic_action_id.sql b/ddbb scripts/recommender_geographic_action_id.sql new file mode 100644 index 0000000000000000000000000000000000000000..d24019b7f48fdc8456f97fc990651890ed519008 --- /dev/null +++ b/ddbb scripts/recommender_geographic_action_id.sql @@ -0,0 +1,48 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +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.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.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.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.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 \ No newline at end of file diff --git a/ddbb scripts/recommender_kpis_action_id.sql b/ddbb scripts/recommender_kpis_action_id.sql new file mode 100644 index 0000000000000000000000000000000000000000..a4248368da008a0c99d130a72c19213a51d94c94 --- /dev/null +++ b/ddbb scripts/recommender_kpis_action_id.sql @@ -0,0 +1,16 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +CREATE DEFINER=`admin`@`localhost` PROCEDURE `recommender_kpis_action_id`(IN action_id INT) +BEGIN + SELECT 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.id = distinct_kpis.kpi_id + GROUP BY kpi.id + ORDER BY Probability DESC; +END \ No newline at end of file diff --git a/ddbb scripts/recommender_kpis_kpi_id.sql b/ddbb scripts/recommender_kpis_kpi_id.sql new file mode 100644 index 0000000000000000000000000000000000000000..21ce4c792a456b86d6e94e1f6b087bf98547c06a --- /dev/null +++ b/ddbb scripts/recommender_kpis_kpi_id.sql @@ -0,0 +1,17 @@ +-- Created on: 16/01/2023 +-- @author: Andoni Aranguren Ubierna +-- Adaptations: 02/2023 @author: Sergio Campos + +CREATE DEFINER=`admin`@`localhost` PROCEDURE `recommender_kpis_kpi_id`(IN kpi_id INT) +BEGIN +SELECT 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.id = distinct_kpis.kpi_id + GROUP BY kpi.id + ORDER BY Probability DESC; +END \ No newline at end of file diff --git a/ddbb scripts/recommender_popularity.sql b/ddbb scripts/recommender_popularity.sql index de0129142e1182248f06174b51f0675b3adf278a..66c678fdb4260cba03b0e3fa7f3b156fe61645ca 100644 --- a/ddbb scripts/recommender_popularity.sql +++ b/ddbb scripts/recommender_popularity.sql @@ -2,20 +2,19 @@ -- @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.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 + INNER JOIN kpi t_list ON t_list.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 @@ -23,7 +22,7 @@ BEGIN 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.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 @@ -31,58 +30,11 @@ BEGIN 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 + INNER JOIN kpi t_list ON t_list.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 +END \ No newline at end of file diff --git a/ddbb scripts/recommender_preferences.sql b/ddbb scripts/recommender_preferences.sql index 26f7ff02c8da513c06af1581da9d54cae6254d33..2db5758913e793f3b24a5d45335c3c0fef41ede5 100644 --- a/ddbb scripts/recommender_preferences.sql +++ b/ddbb scripts/recommender_preferences.sql @@ -2,7 +2,6 @@ -- @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, @@ -11,11 +10,11 @@ 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.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 + FROM chosen_action c_action INNER JOIN (SELECT r.plan_id, r.time_slot, @@ -26,7 +25,7 @@ BEGIN 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 + INNER JOIN kpi t_list ON t_list.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 @@ -34,11 +33,11 @@ BEGIN 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.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 + FROM chosen_action c_action INNER JOIN (SELECT r.plan_id, r.time_slot, @@ -50,12 +49,11 @@ BEGIN 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 + INNER JOIN kpi t_list ON t_list.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 ; +END \ No newline at end of file