Add extra queries, again

Signed-off-by: Lucas Fernandes de Oliveira's avatarLucas Fernandes de Oliveira <lfoliveira@inf.ufpr.br>
parent 896bdceb
-- Creates a time series for each project
-- Creates a time series for each project (dayly)
COPY(
WITH dayly_fnu AS (
......@@ -70,7 +70,7 @@ WITH dayly_fnu AS (
SELECT
'2014-01-01'::date + s.a AS "collect_date"
FROM
generate_series(0, 1460) AS s(a)
generate_series(0, 1825) AS s(a)
) AS a
), renamed AS (
SELECT
......
-- Export fnu by city, year, proj - renamed
COPY(
WITH fnu_year_point AS (
SELECT
id_point
, id_city
, EXTRACT (YEAR FROM collect_date) AS "year"
, SUM(down_bytes) AS "down_bytes_total"
, SUM(up_bytes) AS "up_bytes_total"
, AVG(down_bytes) AS "down_bytes_avg"
, AVG(up_bytes) AS "up_bytes_avg"
, MAX(down_bytes) AS "down_bytes_max"
, MAX(up_bytes) AS "up_bytes_max"
FROM
fact_net_usage
WHERE
collect_date >= '${DATE_FILTER_INIT}'::date
AND collect_date < '${DATE_FILTER_END}'::date
GROUP BY
id_point
, id_city
, year
), fnu_year_point_proj AS (
SELECT
f.id_point
, f.id_city
, f.year
, f.down_bytes_total
, f.up_bytes_total
, f.down_bytes_avg
, f.up_bytes_max
, f.down_bytes_max
, f.up_bytes_avg
, p.is_gesac
, p.is_telecenter
, p.is_digital_city
FROM
fnu_year_point f
INNER JOIN point p ON p.id = f.id_point
), fnu_year_proj_city AS (
SELECT
year
, id_city
, SUM(CASE WHEN is_gesac THEN down_bytes_total ELSE NULL END) AS "dbt_gesac"
, SUM(CASE WHEN is_telecenter THEN down_bytes_total ELSE NULL END) AS "dbt_telecenter"
, SUM(CASE WHEN is_digital_city THEN down_bytes_total ELSE NULL END) AS "dbt_dc"
, SUM(CASE WHEN is_gesac THEN up_bytes_total ELSE NULL END) AS "ubt_gesac"
, SUM(CASE WHEN is_telecenter THEN up_bytes_total ELSE NULL END) AS "ubt_telecenter"
, SUM(CASE WHEN is_digital_city THEN up_bytes_total ELSE NULL END) AS "ubt_dc"
, AVG(CASE WHEN is_gesac THEN down_bytes_avg ELSE NULL END) AS "dba_gesac"
, AVG(CASE WHEN is_telecenter THEN down_bytes_avg ELSE NULL END) AS "dba_telecenter"
, AVG(CASE WHEN is_digital_city THEN down_bytes_avg ELSE NULL END) AS "dba_dc"
, AVG(CASE WHEN is_gesac THEN up_bytes_avg ELSE NULL END) AS "uba_gesac"
, AVG(CASE WHEN is_telecenter THEN up_bytes_avg ELSE NULL END) AS "uba_telecenter"
, AVG(CASE WHEN is_digital_city THEN up_bytes_avg ELSE NULL END) AS "uba_dc"
, MAX(CASE WHEN is_gesac THEN down_bytes_max ELSE NULL END) AS "dbm_gesac"
, MAX(CASE WHEN is_telecenter THEN down_bytes_max ELSE NULL END) AS "dbm_telecenter"
, MAX(CASE WHEN is_digital_city THEN down_bytes_max ELSE NULL END) AS "dbm_dc"
, MAX(CASE WHEN is_gesac THEN up_bytes_max ELSE NULL END) AS "ubm_gesac"
, MAX(CASE WHEN is_telecenter THEN up_bytes_max ELSE NULL END) AS "ubm_telecenter"
, MAX(CASE WHEN is_digital_city THEN up_bytes_max ELSE NULL END) AS "ubm_dc"
FROM
fnu_year_point_proj
GROUP BY
year
, id_city
), renamed AS (
SELECT
year AS "year"
, id_city AS "id_city"
, dbt_gesac AS "Total-GESAC-download"
, dbt_telecenter AS "Total-TLBR-download"
, dbt_dc AS "Total-C.Digital-download"
, ubt_gesac AS "Total-GESAC-upload"
, ubt_telecenter AS "Total-TLBR-upload"
, ubt_dc AS "Total-C.Digital-upload"
, dba_gesac AS "Média-GESAC-download"
, dba_telecenter AS "Média-TLBR-download"
, dba_dc AS "Média-C.Digital-download"
, uba_gesac AS "Média-GESAC-upload"
, uba_telecenter AS "Média-TLBR-upload"
, uba_dc AS "Média-C.Digital-upload"
, dbm_gesac AS "Pico-GESAC-download"
, dbm_telecenter AS "Pico-TLBR-download"
, dbm_dc AS "Pico-C.Digital-download"
, ubm_gesac AS "Pico-GESAC-upload"
, ubm_telecenter AS "Pico-TLBR-upload"
, ubm_dc AS "Pico-C.Digital-upload"
FROM
fnu_year_proj_city
)
SELECT * FROM renamed ORDER BY "year", "id_city"
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Creates a time series for each project (monthly)
COPY(
WITH monthly_fnu AS (
SELECT
id_point
, EXTRACT (MONTH FROM collect_date) AS "month"
, EXTRACT (YEAR FROM collect_date) AS "year"
, SUM(down_bytes) AS "down_bytes_total"
, SUM(up_bytes) AS "up_bytes_total"
, AVG(down_bytes) AS "down_bytes_avg"
, AVG(up_bytes) AS "up_bytes_avg"
, MAX(down_bytes) AS "down_bytes_max"
, MAX(up_bytes) AS "up_bytes_max"
FROM
fact_net_usage
WHERE
collect_date >= '${DATE_FILTER_INIT}'::date
AND collect_date < '${DATE_FILTER_END}'::date
GROUP BY
id_point
, year
, month
), mh_fnu_join_point AS (
SELECT
f.id_point
, f.year
, f.month
, f.down_bytes_total
, f.up_bytes_total
, f.down_bytes_avg
, f.up_bytes_max
, f.down_bytes_max
, f.up_bytes_avg
, p.is_gesac
, p.is_telecenter
, p.is_digital_city
FROM
monthly_fnu f
INNER JOIN point p ON p.id = f.id_point
), mh_by_project AS (
SELECT
month
, year
, SUM(CASE WHEN is_gesac THEN down_bytes_total ELSE NULL END) AS "dbt_gesac"
, SUM(CASE WHEN is_telecenter THEN down_bytes_total ELSE NULL END) AS "dbt_telecenter"
, SUM(CASE WHEN is_digital_city THEN down_bytes_total ELSE NULL END) AS "dbt_dc"
, SUM(CASE WHEN is_gesac THEN up_bytes_total ELSE NULL END) AS "ubt_gesac"
, SUM(CASE WHEN is_telecenter THEN up_bytes_total ELSE NULL END) AS "ubt_telecenter"
, SUM(CASE WHEN is_digital_city THEN up_bytes_total ELSE NULL END) AS "ubt_dc"
, AVG(CASE WHEN is_gesac THEN down_bytes_avg ELSE NULL END) AS "dba_gesac"
, AVG(CASE WHEN is_telecenter THEN down_bytes_avg ELSE NULL END) AS "dba_telecenter"
, AVG(CASE WHEN is_digital_city THEN down_bytes_avg ELSE NULL END) AS "dba_dc"
, AVG(CASE WHEN is_gesac THEN up_bytes_avg ELSE NULL END) AS "uba_gesac"
, AVG(CASE WHEN is_telecenter THEN up_bytes_avg ELSE NULL END) AS "uba_telecenter"
, AVG(CASE WHEN is_digital_city THEN up_bytes_avg ELSE NULL END) AS "uba_dc"
, MAX(CASE WHEN is_gesac THEN down_bytes_max ELSE NULL END) AS "dbm_gesac"
, MAX(CASE WHEN is_telecenter THEN down_bytes_max ELSE NULL END) AS "dbm_telecenter"
, MAX(CASE WHEN is_digital_city THEN down_bytes_max ELSE NULL END) AS "dbm_dc"
, MAX(CASE WHEN is_gesac THEN up_bytes_max ELSE NULL END) AS "ubm_gesac"
, MAX(CASE WHEN is_telecenter THEN up_bytes_max ELSE NULL END) AS "ubm_telecenter"
, MAX(CASE WHEN is_digital_city THEN up_bytes_max ELSE NULL END) AS "ubm_dc"
FROM
mh_fnu_join_point
GROUP BY
month,
year
), series AS (
SELECT
EXTRACT (MONTH FROM collect_date) AS "month"
, EXTRACT (YEAR FROM collect_date) AS "year"
FROM
(
SELECT
'2014-01-02'::date + s.a AS "collect_date"
FROM
generate_series(0, 1825, 30) AS s(a)
) AS a
), renamed AS (
SELECT
s.year AS "Ano"
, s.month AS "Mês"
, d.dbt_gesac AS "Total-GESAC-download"
, d.dbt_telecenter AS "Total-TLBR-download"
, d.dbt_dc AS "Total-C.Digital-download"
, d.ubt_gesac AS "Total-GESAC-upload"
, d.ubt_telecenter AS "Total-TLBR-upload"
, d.ubt_dc AS "Total-C.Digital-upload"
, d.dba_gesac AS "Média-GESAC-download"
, d.dba_telecenter AS "Média-TLBR-download"
, d.dba_dc AS "Média-C.Digital-download"
, d.uba_gesac AS "Média-GESAC-upload"
, d.uba_telecenter AS "Média-TLBR-upload"
, d.uba_dc AS "Média-C.Digital-upload"
, d.dbm_gesac AS "Pico-GESAC-download"
, d.dbm_telecenter AS "Pico-TLBR-download"
, d.dbm_dc AS "Pico-C.Digital-download"
, d.ubm_gesac AS "Pico-GESAC-upload"
, d.ubm_telecenter AS "Pico-TLBR-upload"
, d.ubm_dc AS "Pico-C.Digital-upload"
FROM
series s
LEFT OUTER JOIN mh_by_project d ON s.month = d.month AND s.year = d.year
)
SELECT * FROM renamed ORDER BY "Ano", "Mês"
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Creates a time series for each project
-- Creates a time series for each project (weekly)
COPY(
WITH weekly_fnu AS (
......@@ -10,6 +10,8 @@ WITH weekly_fnu AS (
, SUM(up_bytes) AS "up_bytes_total"
, AVG(down_bytes) AS "down_bytes_avg"
, AVG(up_bytes) AS "up_bytes_avg"
, MAX(down_bytes) AS "down_bytes_max"
, MAX(up_bytes) AS "up_bytes_max"
FROM
fact_net_usage
WHERE
......@@ -28,6 +30,8 @@ WITH weekly_fnu AS (
, f.up_bytes_total
, f.down_bytes_avg
, f.up_bytes_avg
, f.down_bytes_max
, f.up_bytes_max
, p.is_gesac
, p.is_telecenter
, p.is_digital_city
......@@ -50,30 +54,54 @@ WITH weekly_fnu AS (
, AVG(CASE WHEN is_gesac THEN up_bytes_avg ELSE NULL END) AS "uba_gesac"
, AVG(CASE WHEN is_telecenter THEN up_bytes_avg ELSE NULL END) AS "uba_telecenter"
, AVG(CASE WHEN is_digital_city THEN up_bytes_avg ELSE NULL END) AS "uba_dc"
, MAX(CASE WHEN is_gesac THEN down_bytes_max ELSE NULL END) AS "dbm_gesac"
, MAX(CASE WHEN is_telecenter THEN down_bytes_max ELSE NULL END) AS "dbm_telecenter"
, MAX(CASE WHEN is_digital_city THEN down_bytes_max ELSE NULL END) AS "dbm_dc"
, MAX(CASE WHEN is_gesac THEN up_bytes_max ELSE NULL END) AS "ubm_gesac"
, MAX(CASE WHEN is_telecenter THEN up_bytes_max ELSE NULL END) AS "ubm_telecenter"
, MAX(CASE WHEN is_digital_city THEN up_bytes_max ELSE NULL END) AS "ubm_dc"
FROM
wk_fnu_join_point
GROUP BY
week,
year
), series AS (
SELECT
EXTRACT (WEEK FROM collect_date) AS "week"
, EXTRACT (YEAR FROM collect_date) AS "year"
FROM
(
SELECT
'2014-01-02'::date + s.a AS "collect_date"
FROM
generate_series(0, 1825, 7) AS s(a)
) AS a
), renamed AS (
SELECT
year AS "Ano"
, week AS "Semana"
, dbt_gesac AS "Total-GESAC-download"
, dbt_telecenter AS "Total-TLBR-download"
, dbt_dc AS "Total-C.Digital-download"
, ubt_gesac AS "Total-GESAC-upload"
, ubt_telecenter AS "Total-TLBR-upload"
, ubt_dc AS "Total-C.Digital-upload"
, dba_gesac AS "Média-GESAC-download"
, dba_telecenter AS "Média-TLBR-download"
, dba_dc AS "Média-C.Digital-download"
, uba_gesac AS "Média-GESAC-upload"
, uba_telecenter AS "Média-TLBR-upload"
, uba_dc AS "Média-C.Digital-upload"
s.year AS "Ano"
, s.week AS "Semana"
, d.dbt_gesac AS "Total-GESAC-download"
, d.dbt_telecenter AS "Total-TLBR-download"
, d.dbt_dc AS "Total-C.Digital-download"
, d.ubt_gesac AS "Total-GESAC-upload"
, d.ubt_telecenter AS "Total-TLBR-upload"
, d.ubt_dc AS "Total-C.Digital-upload"
, d.dba_gesac AS "Média-GESAC-download"
, d.dba_telecenter AS "Média-TLBR-download"
, d.dba_dc AS "Média-C.Digital-download"
, d.uba_gesac AS "Média-GESAC-upload"
, d.uba_telecenter AS "Média-TLBR-upload"
, d.uba_dc AS "Média-C.Digital-upload"
, d.dbm_gesac AS "Pico-GESAC-download"
, d.dbm_telecenter AS "Pico-TLBR-download"
, d.dbm_dc AS "Pico-C.Digital-download"
, d.ubm_gesac AS "Pico-GESAC-upload"
, d.ubm_telecenter AS "Pico-TLBR-upload"
, d.ubm_dc AS "Pico-C.Digital-upload"
FROM
wk_by_project
series s
LEFT OUTER JOIN wk_by_project d ON s.week = d.week AND s.year = d.year
)
SELECT * FROM renamed
SELECT * FROM renamed ORDER BY "Ano", "Semana"
) TO STDOUT WITH CSV HEADER DELIMITER ';';
......@@ -18,7 +18,7 @@ QUERY_OPTS=(
[TIME_FILTER_INIT]="08:00:00"
[TIME_FILTER_END]="18:00:00"
[DATE_FILTER_INIT]="2014-01-01"
[DATE_FILTER_END]="2018-01-01"
[DATE_FILTER_END]="2019-01-01"
)
REPORTS=(
......@@ -36,6 +36,8 @@ REPORTS=(
#[fnu_by_year_city.sql]="fnu_by_year_city.csv"
#[weekly_fnu_by_proj.sql]="weekly_fnu_by_proj.csv"
#[dayly_fnu_by_proj.sql]="dayly_fnu_by_proj.csv"
#[monthly_fnu_by_proj.sql]="monthly_fnu_by_proj.csv"
#[fnu_by_year_city_proj.sql]="fnu_by_year_city_proj.csv"
)
POSTGRES_USER="db_user"
POSTGRES_HOST="db_host"
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment