From 6938252127e347113202d54363313534489b3b4f Mon Sep 17 00:00:00 2001
From: Diego Giovane Pasqualin <dpasqualin@c3sl.ufpr.br>
Date: Wed, 30 Oct 2013 14:58:23 -0200
Subject: [PATCH] Net Usage queries return the total AVG of MAX down/up for
 each telecenter

Signed-off-by: Diego Giovane Pasqualin <dpasqualin@c3sl.ufpr.br>
---
 web/queries/tlbr/net_usage/sub_cities.sql     | 30 ++++++++++++-------
 web/queries/tlbr/net_usage/sub_regions.sql    | 22 ++++++++++----
 web/queries/tlbr/net_usage/sub_states.sql     | 27 +++++++++++------
 .../tlbr/net_usage/sub_telecenters.sql        |  6 ++--
 4 files changed, 57 insertions(+), 28 deletions(-)

diff --git a/web/queries/tlbr/net_usage/sub_cities.sql b/web/queries/tlbr/net_usage/sub_cities.sql
index a8acfcf..36c894e 100644
--- a/web/queries/tlbr/net_usage/sub_cities.sql
+++ b/web/queries/tlbr/net_usage/sub_cities.sql
@@ -1,15 +1,25 @@
 SELECT
-    state
-    , SUM(down_kbits) AS down_kbits
-    , SUM(up_kbits) AS up_kbits
-    , AVG(kbits_five_min_to_mbits_sec(down_kbits)) AS down_kbits
-    , AVG(kbits_five_min_to_mbits_sec(up_kbits)) AS up_kbits
+    city AS cat
+    , AVG(kbits_five_min_to_mbits_sec(down)) AS down
+    , AVG(kbits_five_min_to_mbits_sec(up)) AS up
 FROM
-    fact_net_usage_telecenter
-WHERE
-    region = $1::text
+    (SELECT
+        city
+        , id_city
+        , MAX(down_kbits) AS down
+        , MAX(up_kbits) AS up
+    FROM
+        fact_net_usage_telecenter
+    WHERE
+        state = $1::text
+    GROUP BY
+        city
+        , id_city
+        , id_point
+    ) AS f
 GROUP BY
-    state
+    city
+    , id_city
 ORDER BY
-    state
+    city
 ;
diff --git a/web/queries/tlbr/net_usage/sub_regions.sql b/web/queries/tlbr/net_usage/sub_regions.sql
index 5962e76..75f0fe8 100644
--- a/web/queries/tlbr/net_usage/sub_regions.sql
+++ b/web/queries/tlbr/net_usage/sub_regions.sql
@@ -1,11 +1,21 @@
+-- Compute the peak for every telecenter and than the average for each region
 SELECT
-    region AS cat
-    , AVG(kbits_five_min_to_mbits_sec(down_kbits)) AS down
-    , AVG(kbits_five_min_to_mbits_sec(up_kbits)) AS up
+    f.region AS cat
+    , AVG(kbits_five_min_to_mbits_sec(f.down)) AS down
+    , AVG(kbits_five_min_to_mbits_sec(f.up)) AS up
 FROM
-    fact_net_usage_telecenter
+    (SELECT
+        region
+        , MAX(down_kbits) AS down
+        , MAX(up_kbits) AS up
+    FROM
+        fact_net_usage_telecenter
+    GROUP BY
+        region
+        , id_point
+    ) AS f
 GROUP BY
-    region
+    f.region
 ORDER BY
-    region
+    f.region
 ;
diff --git a/web/queries/tlbr/net_usage/sub_states.sql b/web/queries/tlbr/net_usage/sub_states.sql
index 8d328e9..38fe36c 100644
--- a/web/queries/tlbr/net_usage/sub_states.sql
+++ b/web/queries/tlbr/net_usage/sub_states.sql
@@ -1,14 +1,23 @@
+-- Compute the peak for every telecenter and than the average for each state
 SELECT
-    city AS cat
-    , AVG(kbits_five_min_to_mbits_sec(down_kbits)) AS down
-    , AVG(kbits_five_min_to_mbits_sec(up_kbits)) AS up
+    state AS cat
+    , AVG(kbits_five_min_to_mbits_sec(down)) AS down
+    , AVG(kbits_five_min_to_mbits_sec(up)) AS up
 FROM
-    fact_net_usage_telecenter
-WHERE
-    region = $1::text
+    (SELECT
+        state
+        , MAX(down_kbits) AS down
+        , MAX(up_kbits) AS up
+    FROM
+        fact_net_usage_telecenter
+    WHERE
+        region = $1::text
+    GROUP BY
+        state
+        , id_point
+    ) AS f
 GROUP BY
-    city
-    , id_city
+    state
 ORDER BY
-    city
+    state
 ;
diff --git a/web/queries/tlbr/net_usage/sub_telecenters.sql b/web/queries/tlbr/net_usage/sub_telecenters.sql
index ce86f17..30ee01b 100644
--- a/web/queries/tlbr/net_usage/sub_telecenters.sql
+++ b/web/queries/tlbr/net_usage/sub_telecenters.sql
@@ -1,8 +1,8 @@
 SELECT
-    telecenter
+    telecenter AS cat
     , id_point
-    , AVG(kbits_five_min_to_mbits_sec(down_kbits)) AS down_kbits
-    , AVG(kbits_five_min_to_mbits_sec(up_kbits)) AS up_kbits
+    , MAX(kbits_five_min_to_mbits_sec(down_kbits)) AS down
+    , MAX(kbits_five_min_to_mbits_sec(up_kbits)) AS up
 FROM
     fact_net_usage_telecenter
 WHERE
-- 
GitLab