From 126ee75c7e36fdb01f6685832d1f3ddb75e62f85 Mon Sep 17 00:00:00 2001 From: Diego Giovane Pasqualin <dpasqualin@c3sl.ufpr.br> Date: Thu, 31 Oct 2013 11:08:16 -0200 Subject: [PATCH] Add availability and net usage queries for gesac The availability for now are just a copy from telecentros-br Signed-off-by: Diego Giovane Pasqualin <dpasqualin@c3sl.ufpr.br> --- web/queries/gesac/avail/current.sql | 11 ++++++++ web/queries/gesac/avail/hist.sql | 17 +++++++++++++ web/queries/gesac/avail/sub_cities.sql | 13 ++++++++++ web/queries/gesac/avail/sub_regions.sql | 11 ++++++++ web/queries/gesac/avail/sub_states.sql | 12 +++++++++ web/queries/gesac/avail/sub_telecenters.sql | 14 +++++++++++ web/queries/gesac/net_usage/sub_cities.sql | 25 +++++++++++++++++++ web/queries/gesac/net_usage/sub_regions.sql | 21 ++++++++++++++++ web/queries/gesac/net_usage/sub_states.sql | 23 +++++++++++++++++ .../gesac/net_usage/sub_telecenters.sql | 15 +++++++++++ web/queries/gesac/net_usage/telecenter.sql | 13 ++++++++++ 11 files changed, 175 insertions(+) create mode 100644 web/queries/gesac/avail/current.sql create mode 100644 web/queries/gesac/avail/hist.sql create mode 100644 web/queries/gesac/avail/sub_cities.sql create mode 100644 web/queries/gesac/avail/sub_regions.sql create mode 100644 web/queries/gesac/avail/sub_states.sql create mode 100644 web/queries/gesac/avail/sub_telecenters.sql create mode 100644 web/queries/gesac/net_usage/sub_cities.sql create mode 100644 web/queries/gesac/net_usage/sub_regions.sql create mode 100644 web/queries/gesac/net_usage/sub_states.sql create mode 100644 web/queries/gesac/net_usage/sub_telecenters.sql create mode 100644 web/queries/gesac/net_usage/telecenter.sql diff --git a/web/queries/gesac/avail/current.sql b/web/queries/gesac/avail/current.sql new file mode 100644 index 0000000..450ab79 --- /dev/null +++ b/web/queries/gesac/avail/current.sql @@ -0,0 +1,11 @@ +SELECT + SUM(is_green) AS green, + SUM(is_yellow) AS yellow, + SUM(is_red) AS red +FROM + aggr_availability +WHERE + base_date = (SELECT max(base_date) FROM aggr_availability) AND + ($1::text IS NULL OR region = $1::text) AND + ($2::text IS NULL OR state = $2::text) AND + ($3::text IS NULL OR city = $3::text); \ No newline at end of file diff --git a/web/queries/gesac/avail/hist.sql b/web/queries/gesac/avail/hist.sql new file mode 100644 index 0000000..373d24b --- /dev/null +++ b/web/queries/gesac/avail/hist.sql @@ -0,0 +1,17 @@ +SELECT + get_month_name(extract(month from base_date)::integer)::text AS month, + SUM(is_green) AS green, + SUM(is_yellow) AS yellow, + SUM(is_red) AS red +FROM + aggr_availability +WHERE + base_date = (SELECT max(base_date) FROM aggr_availability) AND + ($1::text IS NULL OR region = $1::text) AND + ($2::text IS NULL OR state = $2::text) AND + ($3::text IS NULL OR city = $3::text) +GROUP BY + base_date +ORDER BY + base_date DESC +LIMIT 6; \ No newline at end of file diff --git a/web/queries/gesac/avail/sub_cities.sql b/web/queries/gesac/avail/sub_cities.sql new file mode 100644 index 0000000..c88677d --- /dev/null +++ b/web/queries/gesac/avail/sub_cities.sql @@ -0,0 +1,13 @@ +SELECT + city AS cat, + SUM(is_green) AS green, + SUM(is_yellow) AS yellow, + SUM(is_red) AS red +FROM + aggr_availability +WHERE + base_date = (SELECT max(base_date) FROM aggr_availability) AND + ($1::text IS NULL OR region = $1::text) AND + ($2::text IS NULL OR state = $2::text) +GROUP BY + city; diff --git a/web/queries/gesac/avail/sub_regions.sql b/web/queries/gesac/avail/sub_regions.sql new file mode 100644 index 0000000..05ee84f --- /dev/null +++ b/web/queries/gesac/avail/sub_regions.sql @@ -0,0 +1,11 @@ +SELECT + region AS cat, + SUM(is_green) AS green, + SUM(is_yellow) AS yellow, + SUM(is_red) AS red +FROM + aggr_availability +WHERE + base_date = (SELECT max(base_date) FROM aggr_availability) +GROUP BY + region; diff --git a/web/queries/gesac/avail/sub_states.sql b/web/queries/gesac/avail/sub_states.sql new file mode 100644 index 0000000..2bdb215 --- /dev/null +++ b/web/queries/gesac/avail/sub_states.sql @@ -0,0 +1,12 @@ +SELECT + state AS cat, + SUM(is_green) AS green, + SUM(is_yellow) AS yellow, + SUM(is_red) AS red +FROM + aggr_availability +WHERE + base_date = (SELECT max(base_date) FROM aggr_availability) AND + ($1::text IS NULL OR region = $1::text) +GROUP BY + state; diff --git a/web/queries/gesac/avail/sub_telecenters.sql b/web/queries/gesac/avail/sub_telecenters.sql new file mode 100644 index 0000000..a4d2c74 --- /dev/null +++ b/web/queries/gesac/avail/sub_telecenters.sql @@ -0,0 +1,14 @@ +SELECT + tc_name AS cat, + SUM(is_green) AS green, + SUM(is_yellow) AS yellow, + SUM(is_red) AS red +FROM + aggr_availability +WHERE + base_date = (SELECT max(base_date) FROM aggr_availability) AND + ($1::text IS NULL OR region = $1::text) AND + ($2::text IS NULL OR state = $2::text) AND + ($3::text IS NULL OR city = $3::text) +GROUP BY + tc_name; diff --git a/web/queries/gesac/net_usage/sub_cities.sql b/web/queries/gesac/net_usage/sub_cities.sql new file mode 100644 index 0000000..f3e98d9 --- /dev/null +++ b/web/queries/gesac/net_usage/sub_cities.sql @@ -0,0 +1,25 @@ +SELECT + city AS cat + , AVG(bytes_five_min_to_kbits_sec(down)) AS down + , AVG(bytes_five_min_to_kbits_sec(up)) AS up +FROM + (SELECT + city + , id_city + , MAX(down_kbits) AS down + , MAX(up_kbits) AS up + FROM + fact_net_usage_convention + WHERE + state = $1::text + GROUP BY + city + , id_city + , id_point + ) AS f +GROUP BY + city + , id_city +ORDER BY + city +; diff --git a/web/queries/gesac/net_usage/sub_regions.sql b/web/queries/gesac/net_usage/sub_regions.sql new file mode 100644 index 0000000..6c34206 --- /dev/null +++ b/web/queries/gesac/net_usage/sub_regions.sql @@ -0,0 +1,21 @@ +-- Compute the peak for every telecenter and than the average for each region +SELECT + f.region AS cat + , AVG(bytes_five_min_to_kbits_sec(f.down)) AS down + , AVG(bytes_five_min_to_kbits_sec(f.up)) AS up +FROM + (SELECT + region + , MAX(down_kbits) AS down + , MAX(up_kbits) AS up + FROM + fact_net_usage_convention + GROUP BY + region + , id_point + ) AS f +GROUP BY + f.region +ORDER BY + f.region +; diff --git a/web/queries/gesac/net_usage/sub_states.sql b/web/queries/gesac/net_usage/sub_states.sql new file mode 100644 index 0000000..55190aa --- /dev/null +++ b/web/queries/gesac/net_usage/sub_states.sql @@ -0,0 +1,23 @@ +-- Compute the peak for every telecenter and than the average for each state +SELECT + state AS cat + , AVG(bytes_five_min_to_kbits_sec(down)) AS down + , AVG(bytes_five_min_to_kbits_sec(up)) AS up +FROM + (SELECT + state + , MAX(down_kbits) AS down + , MAX(up_kbits) AS up + FROM + fact_net_usage_convention + WHERE + region = $1::text + GROUP BY + state + , id_point + ) AS f +GROUP BY + state +ORDER BY + state +; diff --git a/web/queries/gesac/net_usage/sub_telecenters.sql b/web/queries/gesac/net_usage/sub_telecenters.sql new file mode 100644 index 0000000..6716206 --- /dev/null +++ b/web/queries/gesac/net_usage/sub_telecenters.sql @@ -0,0 +1,15 @@ +SELECT + establishment AS cat + , id_point + , MAX(bytes_five_min_to_kbits_sec(down_kbits)) AS down + , MAX(bytes_five_min_to_kbits_sec(up_kbits)) AS up +FROM + fact_net_usage_convention +WHERE + city = $1::text +GROUP BY + id_point + , establishment +ORDER BY + establishment +; diff --git a/web/queries/gesac/net_usage/telecenter.sql b/web/queries/gesac/net_usage/telecenter.sql new file mode 100644 index 0000000..54c8919 --- /dev/null +++ b/web/queries/gesac/net_usage/telecenter.sql @@ -0,0 +1,13 @@ +SELECT + establishment AS cat + , bytes_five_min_to_kbits_sec(down_kbits) AS down + , bytes_five_min_to_kbits_sec(up_kbits) AS up + , collect_date + collect_time AS timestamp +FROM + fact_net_usage_convention +WHERE + id_point = $1::integer +ORDER BY + collect_date + , collect_time +; -- GitLab