Add some extra queries

Signed-off-by: Lucas Fernandes de Oliveira's avatarLucas Fernandes de Oliveira <lfoliveira@inf.ufpr.br>
parent a5f0ed1e
-- Export city as csv
COPY(
SELECT * FROM city
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Export fact net usage as csv
COPY(
SELECT * FROM fact_net_usage
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Query that count the number of contacts in a interval and
-- divides by the total of contacts
COPY(
WITH filtered_fnu AS (
SELECT
id_city
, EXTRACT(HOUR FROM collect_time) AS "hour"
, COUNT(1) AS "contacts"
FROM
fact_net_usage
WHERE
collect_time >= '${TIME_FILTER_INIT}'::time
AND collect_time < '${TIME_FILTER_END}'::time
AND collect_date >= '${DATE_FILTER_INIT}'::date
AND collect_date < '${DATE_FILTER_END}'::date
AND EXTRACT(DOW FROM collect_date) != 0
AND EXTRACT(DOW FROM collect_date) != 6
GROUP BY
id_city
, hour
), total_by_city AS (
SELECT
id_city
, SUM(contacts) AS "total_contacts"
FROM
filtered_fnu
GROUP BY
id_city
), percentage_by_city AS (
SELECT
f.id_city
, f.hour
, (f.contacts/t.total_contacts) AS "percent_contacts"
FROM
filtered_fnu f
INNER JOIN total_by_city t ON f.id_city = t.id_city
), horizontal_percentage_by_city AS (
SELECT
id_city
, CASE
WHEN hour = 8 THEN percent_contacts
ELSE 0
END AS percent_contacts_8
, CASE
WHEN hour = 9 THEN percent_contacts
ELSE 0
END AS percent_contacts_9
, CASE
WHEN hour = 10 THEN percent_contacts
ELSE 0
END AS percent_contacts_10
, CASE
WHEN hour = 11 THEN percent_contacts
ELSE 0
END AS percent_contacts_11
, CASE
WHEN hour = 12 THEN percent_contacts
ELSE 0
END AS percent_contacts_12
, CASE
WHEN hour = 13 THEN percent_contacts
ELSE 0
END AS percent_contacts_13
, CASE
WHEN hour = 14 THEN percent_contacts
ELSE 0
END AS percent_contacts_14
, CASE
WHEN hour = 15 THEN percent_contacts
ELSE 0
END AS percent_contacts_15
, CASE
WHEN hour = 16 THEN percent_contacts
ELSE 0
END AS percent_contacts_16
, CASE
WHEN hour = 17 THEN percent_contacts
ELSE 0
END AS percent_contacts_17
FROM
percentage_by_city
), sumarize_horizontal_percentage_by_city AS (
SELECT
id_city AS "COD IBGE 7"
, SUM(percent_contacts_8) AS "Porcentagem de contatos (8)"
, SUM(percent_contacts_9) AS "Porcentagem de contatos (9)"
, SUM(percent_contacts_10) AS "Porcentagem de contatos (10)"
, SUM(percent_contacts_11) AS "Porcentagem de contatos (11)"
, SUM(percent_contacts_12) AS "Porcentagem de contatos (12)"
, SUM(percent_contacts_13) AS "Porcentagem de contatos (13)"
, SUM(percent_contacts_14) AS "Porcentagem de contatos (14)"
, SUM(percent_contacts_15) AS "Porcentagem de contatos (15)"
, SUM(percent_contacts_16) AS "Porcentagem de contatos (16)"
, SUM(percent_contacts_17) AS "Porcentagem de contatos (17)"
FROM
horizontal_percentage_by_city
GROUP BY
id_city
)
SELECT * FROM sumarize_horizontal_percentage_by_city
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Export point as csv
COPY(
SELECT * FROM point
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Export point_geolocation to csv
COPY(
SELECT id_point, latitude, longitude FROM point_geolocation
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Query to calculate the "SIMMC index".
-- This index calculates the potential of net usage.
-- It takes, for each point, the MAX net_usage -- in the five minutes interval
-- (estimative of connection BANDWITH) and multiplies by the number of intervals
-- of five min. This represents the MAXIMUM net_usage possible for that point.
-- Then it takes the total of net usage of the point in the same intervals.
-- The total is divided by the maximum, so is a value between 0 and 1 that
-- measures how much the point use of its potential.
-- The index of a city is the mean of the index of each point in the city.
COPY(
WITH filtered_fnu AS (
SELECT
id_point
, id_city
, macaddr
, ip
, collect_date
, collect_time
, up_bytes
, down_bytes
, EXTRACT(TIMEZONE_HOUR FROM collect_time) AS "timezone"
, EXTRACT(HOUR FROM collect_time) AS "hour"
, EXTRACT(DAY FROM collect_date) AS "day"
, EXTRACT(MONTH FROM collect_date) AS "month"
, EXTRACT(YEAR FROM collect_date) AS "year"
FROM
fact_net_usage
WHERE
collect_time >= '${TIME_FILTER_INIT}'::time
AND collect_time < '${TIME_FILTER_END}'::time
AND collect_date >= '${DATE_FILTER_INIT}'::date
AND collect_date < '${DATE_FILTER_END}'::date
AND EXTRACT(DOW FROM collect_date) != 0
AND EXTRACT(DOW FROM collect_date) != 6
), ffnu_by_point_by_year AS (
SELECT
id_city
, id_point
, macaddr
, ip
, timezone
, hour
, day
, month
, year
, MAX(up_bytes) AS "max_up_bytes"
, MAX(down_bytes) AS "max_down_bytes"
, SUM(up_bytes) AS "sum_up_bytes"
, SUM(down_bytes) AS "sum_down_bytes"
FROM
filtered_fnu
GROUP BY
id_city
, id_point
, macaddr
, ip
, year
, month
, day
, hour
, timezone
), ffnu_with_index AS (
SELECT
id_city
, id_point
, macaddr
, ip
, hour
, timezone
, day
, month
, year
, CASE
WHEN max_down_bytes > 0 THEN
(
sum_down_bytes::double precision
/(max_down_bytes*12)
)
ELSE NULL
END AS "index_down_bytes"
, CASE
WHEN max_up_bytes> 0 THEN
(
sum_up_bytes::double precision
/(max_up_bytes*12)
)
ELSE NULL
END AS "index_up_bytes"
FROM
ffnu_by_point_by_year
), ffnu_index_by_city_year AS (
SELECT
id_city
, year
, AVG(index_down_bytes) AS "index_down_bytes"
, AVG(index_up_bytes) AS "index_up_bytes"
--, COUNT(1) AS "total_samples"
--, COUNT(CASE index_down_bytes IS NULL 1 ELSE NULL) AS "down_samples_removed"
--, COUNT(CASE index_up_bytes IS NULL 1 ELSE NULL) AS "up_samples_removed"
FROM
ffnu_with_index
GROUP BY
id_city
, year
), ffnu_with_index_by_city AS (
SELECT
id_city
, CASE
WHEN year = 2014 THEN index_down_bytes
ELSE 0
END AS index_down_bytes_2014
, CASE
WHEN year = 2015 THEN index_down_bytes
ELSE 0
END AS index_down_bytes_2015
, CASE
WHEN year = 2016 THEN index_down_bytes
ELSE 0
END AS index_down_bytes_2016
, CASE
WHEN year = 2017 THEN index_down_bytes
ELSE 0
END AS index_down_bytes_2017
, CASE
WHEN year = 2014 THEN index_up_bytes
ELSE 0
END AS index_up_bytes_2014
, CASE
WHEN year = 2015 THEN index_up_bytes
ELSE 0
END AS index_up_bytes_2015
, CASE
WHEN year = 2016 THEN index_up_bytes
ELSE 0
END AS index_up_bytes_2016
, CASE
WHEN year = 2017 THEN index_up_bytes
ELSE 0
END AS index_up_bytes_2017
FROM
ffnu_index_by_city_year
), ffnu_with_index_by_city_rename AS (
SELECT
id_city AS "COD IBGE 7"
, SUM(index_down_bytes_2014) AS "Índice SIMMC (download) (2014)"
, SUM(index_down_bytes_2015) AS "Índice SIMMC (download) (2015)"
, SUM(index_down_bytes_2016) AS "Índice SIMMC (download) (2016)"
, SUM(index_down_bytes_2017) AS "Índice SIMMC (download) (2017)"
, SUM(index_up_bytes_2014) AS "Índice SIMMC (upload) (2014)"
, SUM(index_up_bytes_2015) AS "Índice SIMMC (upload) (2015)"
, SUM(index_up_bytes_2016) AS "Índice SIMMC (upload) (2016)"
, SUM(index_up_bytes_2017) AS "Índice SIMMC (upload) (2017)"
FROM
ffnu_with_index_by_city
GROUP BY
id_city
)
SELECT * FROM ffnu_with_index_by_city_rename
--SELECT * FROM ffnu_with_index WHERE index_down_bytes > 1 OR index_up_bytes > 1
) TO STDOUT WITH CSV HEADER DELIMITER ';';
...@@ -15,6 +15,10 @@ QUERY_OPTS=( ...@@ -15,6 +15,10 @@ QUERY_OPTS=(
[REJECT_INIT_DATE]="2018-05-01" [REJECT_INIT_DATE]="2018-05-01"
[REJECT_END_DATE]="2018-08-01" [REJECT_END_DATE]="2018-08-01"
[ACTIVE_INTERVAL]="30" [ACTIVE_INTERVAL]="30"
[TIME_FILTER_INIT]="08:00:00"
[TIME_FILTER_END]="18:00:00"
[DATE_FILTER_INIT]="2014-01-01"
[DATE_FILTER_END]="2018-01-01"
) )
REPORTS=( REPORTS=(
...@@ -23,8 +27,13 @@ REPORTS=( ...@@ -23,8 +27,13 @@ REPORTS=(
#[dc_active.sql]="dc_active.csv" #[dc_active.sql]="dc_active.csv"
#[dc_pirate_lc.sql]="dc_pirate_lc.csv" #[dc_pirate_lc.sql]="dc_pirate_lc.csv"
#[gesac_avail_by_code.sql]="gesac_avail_by_code.csv" #[gesac_avail_by_code.sql]="gesac_avail_by_code.csv"
#[simmc_index.sql]="simmc_index.csv"
#[city.sql]="city.csv"
#[point.sql]="point.csv"
#[fnu.sql]="fnu.csv"
#[point_geolocation.sql]="point_geolocation.csv"
#[net_usage_percentage.sql]="net_usage_percentage.csv"
) )
REPORT="dc_pirate_net_usage.sql"
POSTGRES_USER="db_user" POSTGRES_USER="db_user"
POSTGRES_HOST="db_host" POSTGRES_HOST="db_host"
POSTGRES_PORT="5432" POSTGRES_PORT="5432"
......
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