Add more extra queries

Signed-off-by: Lucas Fernandes de Oliveira's avatarLucas Fernandes de Oliveira <lfoliveira@inf.ufpr.br>
parent c3e25984
-- Creates a time series for each project
COPY(
WITH dayly_fnu AS (
SELECT
id_point
, EXTRACT (DAY FROM collect_date) AS "day"
, 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"
FROM
fact_net_usage
WHERE
collect_date >= '${DATE_FILTER_INIT}'::date
AND collect_date < '${DATE_FILTER_END}'::date
GROUP BY
id_point
, year
, month
, day
), dayly_fnu_join_point AS (
SELECT
f.id_point
, f.year
, f.month
, f.day
, f.down_bytes_total
, f.up_bytes_total
, f.down_bytes_avg
, f.up_bytes_avg
, p.is_gesac
, p.is_telecenter
, p.is_digital_city
FROM
dayly_fnu f
INNER JOIN point p ON p.id = f.id_point
), dayly_by_project AS (
SELECT
day
, 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"
FROM
dayly_fnu_join_point
GROUP BY
day,
month,
year
), series AS (
SELECT
EXTRACT (DAY FROM collect_date) AS "day"
, EXTRACT (MONTH FROM collect_date) AS "month"
, EXTRACT (YEAR FROM collect_date) AS "year"
FROM
(
SELECT
'2014-01-01'::date + s.a AS "collect_date"
FROM
generate_series(0, 1460) AS s(a)
) AS a
), renamed AS (
SELECT
s.year AS "Ano"
, s.month AS "Mês"
, s.day AS "Dia"
, 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"
FROM
series s
LEFT OUTER JOIN dayly_by_project d ON s.day = d.day AND s.month = d.month AND s.year = d.year
)
SELECT * FROM renamed ORDER BY "Ano", "Mês", "Dia"
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Export fact net usage as csv -- Export fact net usage as csv
COPY( COPY(
SELECT * FROM fact_net_usage SELECT
contact_date
, id_point
, id_city
, macaddr
, collect_date
, collect_time
, down_bytes
, up_bytes
, ip
FROM
fact_net_usage
) TO STDOUT WITH CSV HEADER DELIMITER ';'; ) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Export fnu by city,year - renamed
COPY(
WITH fnu_year_city AS (
SELECT
id_city
, EXTRACT (YEAR FROM collect_date) AS "year"
, SUM(down_bytes) AS "down_bytes_total"
, SUM(up_bytes) AS "up_bytes_total"
, 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_city
, year
), fnu_yc_with_city_info AS (
SELECT
f.id_city
, f.year
, f.down_bytes_total
, f.up_bytes_total
, f.down_bytes_max
, f.up_bytes_max
, c.name
, c.state
FROM
fnu_year_city f
INNER JOIN city c ON c.id = f.id_city
), renamed AS (
SELECT
id_city AS "COD IBGE 7"
, name AS "Cidade"
, state AS "Estado"
, down_bytes_total AS "Tráfego (download)"
, up_bytes_total AS "Tráfego (upload)"
, down_bytes_max AS "Pico (download)"
, up_bytes_max AS "Pico (upload)"
FROM
fnu_yc_with_city_info
)
SELECT * FROM renamed
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Creates a time series for each project
COPY(
WITH weekly_fnu AS (
SELECT
id_point
, EXTRACT (WEEK FROM collect_date) AS "week"
, 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"
FROM
fact_net_usage
WHERE
collect_date >= '${DATE_FILTER_INIT}'::date
AND collect_date < '${DATE_FILTER_END}'::date
GROUP BY
id_point
, year
, week
), wk_fnu_join_point AS (
SELECT
f.id_point
, f.year
, f.week
, f.down_bytes_total
, f.up_bytes_total
, f.down_bytes_avg
, f.up_bytes_avg
, p.is_gesac
, p.is_telecenter
, p.is_digital_city
FROM
weekly_fnu f
INNER JOIN point p ON p.id = f.id_point
), wk_by_project AS (
SELECT
week
, 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"
FROM
wk_fnu_join_point
GROUP BY
week,
year
), 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"
FROM
wk_by_project
)
SELECT * FROM renamed
) TO STDOUT WITH CSV HEADER DELIMITER ';';
...@@ -33,6 +33,9 @@ REPORTS=( ...@@ -33,6 +33,9 @@ REPORTS=(
#[fnu.sql]="fnu.csv" #[fnu.sql]="fnu.csv"
#[point_geolocation.sql]="point_geolocation.csv" #[point_geolocation.sql]="point_geolocation.csv"
#[net_usage_percentage.sql]="net_usage_percentage.csv" #[net_usage_percentage.sql]="net_usage_percentage.csv"
#[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"
) )
POSTGRES_USER="db_user" POSTGRES_USER="db_user"
POSTGRES_HOST="db_host" 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