diff --git a/ddbb scripts/create_ddbb.sql b/ddbb scripts/create_ddbb.sql
index 731830981603ea2f7690df265d1f39d1ccc50661..8ffb16fe628b6c982df52212a00fe3d62c906473 100644
--- a/ddbb scripts/create_ddbb.sql	
+++ b/ddbb scripts/create_ddbb.sql	
@@ -89,4 +89,4 @@ CREATE TABLE `plan_detail` (
   `noise_global` int(11) DEFAULT NULL,
   PRIMARY KEY (`plan_id`,`time_slot`),
   CONSTRAINT `plan_detail_ibfk_1` FOREIGN KEY (`plan_id`) REFERENCES `plan` (`plan_id`)
-) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
\ No newline at end of file
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
diff --git a/ddbb scripts/recommender_bayesian.sql b/ddbb scripts/recommender_bayesian.sql
deleted file mode 100644
index 92d7f26520457c0a839d45e9d5bf5624028e69f5..0000000000000000000000000000000000000000
--- a/ddbb scripts/recommender_bayesian.sql	
+++ /dev/null
@@ -1,103 +0,0 @@
--- 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/ddbb scripts/recommender_bayesian_action_id.sql b/ddbb scripts/recommender_bayesian_action_id.sql
deleted file mode 100644
index 1c36b09046648059488a7e523bb38c938c5c5e41..0000000000000000000000000000000000000000
--- a/ddbb scripts/recommender_bayesian_action_id.sql	
+++ /dev/null
@@ -1,101 +0,0 @@
--- 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_kpis_kpi_id.sql b/ddbb scripts/recommender_kpis_kpi_id.sql
index 21ce4c792a456b86d6e94e1f6b087bf98547c06a..5a2ce3562a5f3d7fb8c750520b030c33304ba436 100644
--- a/ddbb scripts/recommender_kpis_kpi_id.sql	
+++ b/ddbb scripts/recommender_kpis_kpi_id.sql	
@@ -1,8 +1,4 @@
--- 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)
+CREATE DEFINER=`root`@`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 (
@@ -14,4 +10,5 @@ SELECT kpi.id, kpi_name, count(*) as Count, kpi.popularity as Popularity, count(
 		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
+END
+
diff --git a/recommender_kpis_kpi_id.sql b/recommender_kpis_kpi_id.sql
deleted file mode 100644
index 95b2406c5e73f9dad0cd27b11210bbf6c81176b8..0000000000000000000000000000000000000000
--- a/recommender_kpis_kpi_id.sql
+++ /dev/null
@@ -1,13 +0,0 @@
-CREATE DEFINER=`root`@`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
diff --git a/recommender_plans.sql b/recommender_plans.sql
deleted file mode 100644
index 05f2fd144d66bfc33bab093502964977a0424d6b..0000000000000000000000000000000000000000
--- a/recommender_plans.sql
+++ /dev/null
@@ -1,100 +0,0 @@
--- Created on: 16/01/2023
--- @author: Andoni Aranguren Ubierna
--- Adaptations: 02/2023 @author: Sergio Campos
-
-drop procedure `recommender_popularity_detailed`;
-DELIMITER $$
-CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_popularity_detailed`(IN kpi INT, IN action INT)
-BEGIN
-        IF ((kpi is null) and (action is NULL))  THEN
-                SELECT t_p_list.plan_id,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_p_list.plan_id) as plan_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_id) as kpi_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_name) as kpi_name_list,
-            		GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-            		GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-            		GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-                -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                p.popularity as popularity, p.category as category
-                FROM action p
-        -- This lines are so we can get the list of kpis vvvvvvvvvv
-                        INNER JOIN chosen_action t_list ON t_list.action_id = p.action_id
-                        INNER JOIN kpi_action_plan_detail t_p_list ON t_list.plan_id = t_p_list.plan_id
-                        INNER JOIN action a ON a.action_id = t_p_list.action_id
-        -- This lines are so we can get the list of kpis ^^^^^^^^^^
-        	GROUP BY p.action_id
-                ORDER BY popularity DESC
-                LIMIT 100;
-
-	ELSEIF (not(kpi is null))  THEN
-                SELECT t_p_list.plan_id,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_p_list.plan_id) as plan_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_id) as kpi_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_name) as kpi_name_list,
-                        GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-                        GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-                        GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-                -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                p.popularity as popularity, p.category as category
-                FROM action p
-        -- This lines are so we can get the list of kpis vvvvvvvvvv
-                        INNER JOIN chosen_action t_list ON t_list.action_id = p.action_id
-                        INNER JOIN kpi_action_plan_detail t_p_list ON t_list.plan_id = t_p_list.plan_id
-                        INNER JOIN action a ON a.action_id = t_p_list.action_id
-        -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                WHERE t_p_list.kpi_id = kpi
-		GROUP BY p.action_id
-                ORDER BY popularity DESC
-                LIMIT 100;
-		
-        ELSEIF (not(action is NULL))  THEN
-                SELECT t_p_list.plan_id, 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_p_list.plan_id) as plan_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_id) as kpi_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_name) as kpi_name_list,
-                        GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-                        GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-                        GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-                -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                p.popularity as popularity, p.category as category
-                FROM action p
-        -- This lines are so we can get the list of kpis vvvvvvvvvv
-                        INNER JOIN chosen_action t_list ON t_list.action_id = p.action_id
-                        INNER JOIN kpi_action_plan_detail t_p_list ON t_list.plan_id = t_p_list.plan_id
-                        INNER JOIN action a ON a.action_id = t_p_list.action_id
-        -- This lines are so we can get the list of kpis ^^^^^^^^^^
-		WHERE t_list.action_id = action
-                GROUP BY p.action_id
-                ORDER BY popularity DESC
-                LIMIT 100;
-
-	ELSE 
-                SELECT t_p_list.plan_id, 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_p_list.plan_id) as plan_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_id) as kpi_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_name) as kpi_name_list,
-                        GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-                        GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-                        GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-                -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                p.popularity as popularity, p.category as category
-                FROM action p
-        -- This lines are so we can get the list of kpis vvvvvvvvvv
-                        INNER JOIN chosen_action t_list ON t_list.action_id = p.action_id
-                        INNER JOIN kpi_action_plan_detail t_p_list ON t_list.plan_id = t_p_list.plan_id
-                        INNER JOIN action a ON a.action_id = t_p_list.action_id
-		WHERE t_list.action_id = action AND t_p_list.kpi_id = kpi
-		GROUP BY p.action_id
-                ORDER BY popularity DESC
-                LIMIT 100;
-
-
-
-         END IF;
-END$$
-DELIMITER ;
-
diff --git a/recommender_popularity.sql b/recommender_popularity.sql
deleted file mode 100644
index d66e20ae4775254ea6664dce6c7cb487d62cf994..0000000000000000000000000000000000000000
--- a/recommender_popularity.sql
+++ /dev/null
@@ -1,46 +0,0 @@
-drop procedure recommender_popularity;
-DELIMITER $$
-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.id) as kpi_id_list,
-			GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list,
-            GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-            GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-            GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-		-- This lines are so we can get the list of kpis ^^^^^^^^^^
-		p.popularity as popularity, p.category as category
-		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.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.id) as kpi_id_list,
-			GROUP_CONCAT(distinct t_list.kpi_name) as kpi_name_list,
-            GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-            GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-            GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-		-- This lines are so we can get the list of kpis ^^^^^^^^^^
-		p.popularity as popularity, p.category as category
-		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.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 ;
-
diff --git a/recommender_popularity_detailed.sql b/recommender_popularity_detailed.sql
deleted file mode 100644
index 05f2fd144d66bfc33bab093502964977a0424d6b..0000000000000000000000000000000000000000
--- a/recommender_popularity_detailed.sql
+++ /dev/null
@@ -1,100 +0,0 @@
--- Created on: 16/01/2023
--- @author: Andoni Aranguren Ubierna
--- Adaptations: 02/2023 @author: Sergio Campos
-
-drop procedure `recommender_popularity_detailed`;
-DELIMITER $$
-CREATE DEFINER=`root`@`localhost` PROCEDURE `recommender_popularity_detailed`(IN kpi INT, IN action INT)
-BEGIN
-        IF ((kpi is null) and (action is NULL))  THEN
-                SELECT t_p_list.plan_id,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_p_list.plan_id) as plan_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_id) as kpi_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_name) as kpi_name_list,
-            		GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-            		GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-            		GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-                -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                p.popularity as popularity, p.category as category
-                FROM action p
-        -- This lines are so we can get the list of kpis vvvvvvvvvv
-                        INNER JOIN chosen_action t_list ON t_list.action_id = p.action_id
-                        INNER JOIN kpi_action_plan_detail t_p_list ON t_list.plan_id = t_p_list.plan_id
-                        INNER JOIN action a ON a.action_id = t_p_list.action_id
-        -- This lines are so we can get the list of kpis ^^^^^^^^^^
-        	GROUP BY p.action_id
-                ORDER BY popularity DESC
-                LIMIT 100;
-
-	ELSEIF (not(kpi is null))  THEN
-                SELECT t_p_list.plan_id,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_p_list.plan_id) as plan_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_id) as kpi_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_name) as kpi_name_list,
-                        GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-                        GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-                        GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-                -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                p.popularity as popularity, p.category as category
-                FROM action p
-        -- This lines are so we can get the list of kpis vvvvvvvvvv
-                        INNER JOIN chosen_action t_list ON t_list.action_id = p.action_id
-                        INNER JOIN kpi_action_plan_detail t_p_list ON t_list.plan_id = t_p_list.plan_id
-                        INNER JOIN action a ON a.action_id = t_p_list.action_id
-        -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                WHERE t_p_list.kpi_id = kpi
-		GROUP BY p.action_id
-                ORDER BY popularity DESC
-                LIMIT 100;
-		
-        ELSEIF (not(action is NULL))  THEN
-                SELECT t_p_list.plan_id, 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_p_list.plan_id) as plan_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_id) as kpi_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_name) as kpi_name_list,
-                        GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-                        GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-                        GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-                -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                p.popularity as popularity, p.category as category
-                FROM action p
-        -- This lines are so we can get the list of kpis vvvvvvvvvv
-                        INNER JOIN chosen_action t_list ON t_list.action_id = p.action_id
-                        INNER JOIN kpi_action_plan_detail t_p_list ON t_list.plan_id = t_p_list.plan_id
-                        INNER JOIN action a ON a.action_id = t_p_list.action_id
-        -- This lines are so we can get the list of kpis ^^^^^^^^^^
-		WHERE t_list.action_id = action
-                GROUP BY p.action_id
-                ORDER BY popularity DESC
-                LIMIT 100;
-
-	ELSE 
-                SELECT t_p_list.plan_id, 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_p_list.plan_id) as plan_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_id) as kpi_id_list,
-                        GROUP_CONCAT(distinct t_p_list.kpi_name) as kpi_name_list,
-                        GROUP_CONCAT(t_p_list.absolute) as kpi_absolute_list,
-                        GROUP_CONCAT(t_p_list.relative) as kpi_relative_list,
-                        GROUP_CONCAT(t_p_list.geographical) as kpi_geographical_list,
-                -- This lines are so we can get the list of kpis ^^^^^^^^^^
-                p.popularity as popularity, p.category as category
-                FROM action p
-        -- This lines are so we can get the list of kpis vvvvvvvvvv
-                        INNER JOIN chosen_action t_list ON t_list.action_id = p.action_id
-                        INNER JOIN kpi_action_plan_detail t_p_list ON t_list.plan_id = t_p_list.plan_id
-                        INNER JOIN action a ON a.action_id = t_p_list.action_id
-		WHERE t_list.action_id = action AND t_p_list.kpi_id = kpi
-		GROUP BY p.action_id
-                ORDER BY popularity DESC
-                LIMIT 100;
-
-
-
-         END IF;
-END$$
-DELIMITER ;
-
diff --git a/recommender_preferences.sql b/recommender_preferences.sql
deleted file mode 100644
index 90536b36d816f536bb2c9ee1e4ab6793679b4e3f..0000000000000000000000000000000000000000
--- a/recommender_preferences.sql
+++ /dev/null
@@ -1,63 +0,0 @@
--- Created on: 16/01/2023
--- @author: Andoni Aranguren Ubierna
--- Adaptations: 02/2023 @author: Sergio Campos
-
-drop procedure recommender_preferences;
-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.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.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.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.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 ;
-