Add a script to perform queries using templates, and some queries

Signed-off-by: Lucas Fernandes de Oliveira's avatarLucas Fernandes de Oliveira <lfoliveira@inf.ufpr.br>
parent 9d10cf21
config.sh
*.swp
*.swo
*.tmp
*.in
*.out
*.csv
# Tools
## Sobre
O objetivo desse repositório é armazenar ferramentas/*scripts* que tenham sido
desenvolvidos para o SIMMC(TIC) para auxiliar em alguma tarefa e/ou para
a realização de alguma tarefa temporária.
Para evitar que o conhecimento seja perdido e/ou que uma tarefa temporária
seja necessária novamente, as ferramenta/*scripts* utilizado são armazenados
nesse repositório.
Além disso existe a possibilidade de funcionalidades temporárias poderem
ser adicionadas permanentemente no portal e se esse conhecimento já
estiver armazenado nesse repositório já será meio caminho andado.
## Organização
* **scripts**: Diretório que contém *scripts* utilizados para alguma tarefa
* query_reports: Transforma *templates* em queries validas e as executa.
De preferencia essas consultas devem ser escritas para gerar um arquivo
csv na saída padrão, mas nada impede que a consulta seja diferente.
* config.sh: Arquivo não versionado, mas utilizado como arquivo de
configuração para outros *scripts* em bash.
* config.sh.example: Arquivo que deve ser usando de exemplo para
criar o config.sh. NUNCA deve possuir informação sensível, apenas exemplos
* queries: Diretório qu contém consultas sql para os mais diferentes propósitos
-- Query to detect active points
COPY(
WITH dc_traffic AS (
SELECT
f.id_point
, p.id_city
, f.collect_date
FROM
fact_net_usage f
INNER JOIN point p ON p.id = f.id_point
WHERE
p.is_active
AND p.is_digital_city
GROUP BY
f.id_point
, p.id_city
, collect_date
), dc_last_contact AS (
SELECT
id_point
, id_city
, MAX(collect_date) AS last_contact
FROM
dc_traffic
GROUP BY
id_point
, id_city
), dc_points AS (
SELECT
c.city_code
, UPPER(e.access_point_type) AS access_point_type
, e.access_point_id
, e.id_point
FROM
entity e
INNER JOIN point p ON p.id = e.id_point
INNER JOIN city c ON c.id = p.id_city
WHERE
p.is_active
AND p.is_digital_city
), dc_access_point_type AS (
SELECT
e.city_code
, access_point_type
, e.access_point_id
, d.last_contact
FROM
dc_points e
LEFT OUTER JOIN dc_last_contact d ON e.id_point = d.id_point
), expanded_dc_apt AS (
SELECT
city_code
, access_point_type
, access_point_id
, last_contact
, CASE
WHEN
last_contact IS NOT NULL
AND last_contact > current_date - interval '${ACTIVE_INTERVAL}' day
THEN 1
ELSE 0
END AS "is_active"
, CASE
WHEN last_contact IS NULL THEN 1
ELSE 0
END AS "never_contacted"
FROM
dc_access_point_type
), aggr_dc_apt AS (
SELECT
city_code
, COUNT(1) AS "total_points"
, SUM(is_active) AS "active_points"
, SUM(never_contacted) AS "never_contacted_points"
FROM
expanded_dc_apt
GROUP BY
city_code
-- Inserted from dc_pirate_lc
), temporal_rejected_net_usage_net AS (
SELECT
SUM(down_bytes) AS down_bytes
, SUM (up_bytes) AS up_bytes
, MAX (collect_date) AS last_contact
, (ip & '255.255.255.0') AS net
, city_code
FROM
rejected_net_usage
WHERE
ip IS NOT NULL
AND city_code IS NOT NULL
GROUP BY
net
, city_code
), temporal_rejected_net_usage AS (
SELECT
SUM(down_bytes) AS down_bytes
, SUM (up_bytes) AS up_bytes
, MAX (last_contact) AS last_contact
, net
, city_code
FROM
temporal_rejected_net_usage_net
GROUP BY
city_code
, net
), expanded_rnu AS (
SELECT
city_code
, net
, last_contact
, CASE
WHEN
last_contact IS NOT NULL
AND last_contact > current_date - interval '${ACTIVE_INTERVAL}' day
THEN 1
ELSE 0
END AS "is_active"
FROM
temporal_rejected_net_usage
WHERE
down_bytes > 0
AND up_bytes > 0
), aggr_rnu AS (
SELECT
city_code
, SUM (1) AS "total_pirates"
, SUM (is_active) AS "active_pirates"
FROM
expanded_rnu
GROUP BY
city_code
-- End of dc_pirate_lc
), join_rnu_dc_apt AS (
SELECT
a.city_code
, CASE
WHEN r.total_pirates IS NULL THEN 0
ELSE r.total_pirates END AS "total_pirates"
, CASE
WHEN r.active_pirates IS NULL THEN 0
ELSE r.active_pirates END AS "active_pirates"
, a.total_points
, a.active_points
, a.never_contacted_points
FROM
aggr_dc_apt a
LEFT OUTER JOIN aggr_rnu r ON a.city_code = r.city_code
), stats_dc_apt AS (
SELECT
SUM(CASE
WHEN total_points = active_points
AND active_pirates > 0 THEN 1
ELSE 0 END) AS "active_cities_with_pirates"
, SUM(CASE
WHEN total_points = active_points
AND active_pirates = 0 THEN 1
ELSE 0 END) AS "active_cities_without_pirates"
, SUM(CASE
WHEN active_points = 0
AND total_points != never_contacted_points
AND active_pirates > 0 THEN 1
ELSE 0 END) AS "inactive_cities_with_pirates"
, SUM(CASE
WHEN active_points = 0
AND total_points != never_contacted_points
AND active_pirates = 0 THEN 1
ELSE 0 END) AS "inactive_cities_without_pirates"
, SUM(CASE
WHEN total_points = never_contacted_points
AND active_pirates > 0 THEN 1
ELSE 0 END) AS "never_active_cities_with_pirates"
, SUM(CASE
WHEN total_points = never_contacted_points
AND active_pirates = 0 THEN 1
ELSE 0 END) AS "never_active_cities_without_pirates"
, SUM(CASE
WHEN
total_points != active_points
AND total_points != 0
AND active_pirates > 0
THEN 1
ELSE 0 END) AS "partial_cities_with_pirates"
, SUM(CASE
WHEN
total_points != active_points
AND total_points != 0
AND active_pirates = 0
THEN 1
ELSE 0 END) AS "partial_cities_without_pirates"
FROM
join_rnu_dc_apt
)
--SELECT * FROM expanded_dc_apt ORDER BY city_code, access_point_type, access_point_id, last_contact
--SELECT * FROM join_rnu_dc_apt ORDER BY city_code
SELECT * FROM stats_dc_apt
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Query to detect pirate (unidentified) net usage
COPY (
WITH temporal_rejected_net_usage_net AS (
SELECT
SUM(down_bytes) AS down_bytes
, SUM (up_bytes) AS up_bytes
, (ip & '255.255.255.0') AS net
, city_code
FROM
rejected_net_usage
WHERE
collect_date >= '${REJECT_INIT_DATE}'::date
AND collect_date < '${REJECT_END_DATE}'::date
AND ip IS NOT NULL
AND city_code IS NOT NULL
GROUP BY
net
, city_code
), temporal_rejected_net_usage AS (
SELECT
SUM(down_bytes) AS down_bytes
, SUM (up_bytes) AS up_bytes
, COUNT(net)AS nets
, city_code
FROM
temporal_rejected_net_usage_net
GROUP BY
city_code
), points_by_city AS (
SELECT
c.id AS id_city
, c.city_code
, c.state
, c.name AS city_name
, COUNT(p.id) AS total_points
FROM
city c
INNER JOIN point p ON p.id_city = c.id
WHERE
p.is_active
AND p.is_digital_city
GROUP BY
c.id
, c.city_code
, c.state
, c.name
), located_rejected_net_usage AS (
SELECT
c.state
, c.city_name
, c.city_code
, c.id_city
, c.total_points
, nets
FROM
temporal_rejected_net_usage r
INNER JOIN points_by_city c ON c.city_code = r.city_code
WHERE
r.down_bytes > 0
AND r.up_bytes > 0
), temporal_fact_net_usage AS (
SELECT
id_city
, id_point
, SUM(up_bytes) AS sum_up_bytes
, SUM(down_bytes) AS sum_down_bytes
FROM
fact_net_usage
WHERE
collect_date >= '${REJECT_INIT_DATE}'::date
AND collect_date < '${REJECT_END_DATE}'::date
AND id_city IS NOT NULL
AND id_point IS NOT NULL
GROUP BY
id_city
, id_point
), active_city AS (
SELECT
p.id_city
, COUNT(CASE
WHEN f.id_point IS NOT NULL
AND f.sum_up_bytes > 0
AND f.sum_down_bytes > 0
THEN 1
ELSE NULL
END) AS active
, COUNT(1) AS total
FROM
point p
LEFT OUTER JOIN temporal_fact_net_usage f ON p.id = f.id_point
WHERE
p.is_active
AND p.is_digital_city
GROUP BY
p.id_city
), city_stats AS (
SELECT
r.state
, r.city_name
, r.city_code
, CASE
WHEN c.active IS NULL THEN 0
ELSE c.active
END AS "active_points"
, r.total_points
, CASE
WHEN c.active IS NULL THEN r.total_points
ELSE (c.total - c.active)
END AS "inactive_points"
, r.nets AS "pirate_nets"
FROM
located_rejected_net_usage r
LEFT OUTER JOIN active_city c ON c.id_city = r.id_city
)
SELECT * FROM city_stats ORDER BY state, city_name, city_code
--SELECT city_code FROM located_rejected_net_usage group by city_code order by city_code
--SELECT * FROM points_by_city where city_code= 'PMN'
--SELECT * FROM temporal_rejected_net_usage where city_code= 'PMN'
--SELECT city_code FROM temporal_rejected_net_usage where up_bytes > 0 and down_bytes > 0 group by city_code order by city_code
--SELECT SUM(up_bytes) AS up, SUM(down_bytes) AS down , city_code FROM temporal_rejected_net_usage where up_bytes > 0 and down_bytes > 0 group by city_code order by city_code
--SELECT SUM(up_bytes) AS up, SUM(down_bytes) AS down , city_code FROM temporal_rejected_net_usage group by city_code order by city_code
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Query to detect active pirates
COPY(
WITH temporal_rejected_net_usage_net AS (
SELECT
SUM(down_bytes) AS down_bytes
, SUM (up_bytes) AS up_bytes
, MAX (collect_date) AS last_contact
, (ip & '255.255.255.0') AS net
, city_code
FROM
rejected_net_usage
WHERE
ip IS NOT NULL
AND city_code IS NOT NULL
GROUP BY
net
, city_code
), temporal_rejected_net_usage AS (
SELECT
SUM(down_bytes) AS down_bytes
, SUM (up_bytes) AS up_bytes
, MAX (last_contact) AS last_contact
, net
, city_code
FROM
temporal_rejected_net_usage_net
GROUP BY
city_code
, net
), expanded_rnu AS (
SELECT
city_code
, net
, last_contact
, CASE
WHEN
last_contact IS NOT NULL
AND last_contact > current_date - interval '${ACTIVE_INTERVAL}' day
THEN 1
ELSE 0
END AS "is_active"
FROM
temporal_rejected_net_usage
WHERE
down_bytes > 0
AND up_bytes > 0
), aggr_rnu AS (
SELECT
city_code
, SUM (1) AS "total_pirates"
, SUM (is_active) AS "active_pirates"
FROM
expanded_rnu
GROUP BY
city_code
)
SELECT
*
FROM
expanded_rnu
ORDER BY
city_code
, net
, last_contact
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Query to detect pirate (unidentified) net usage
COPY (
WITH temporal_fact_net_usage AS (
SELECT
id_city
, id_point
, SUM(up_bytes) AS sum_up_bytes
, SUM(down_bytes) AS sum_down_bytes
FROM
fact_net_usage
WHERE
collect_date >= '${REJECT_INIT_DATE}'::date
AND collect_date < '${REJECT_END_DATE}'::date
AND id_city IS NOT NULL
AND id_point IS NOT NULL
GROUP BY
id_city
, id_point
), active_city AS (
SELECT
p.id_city
, COUNT(CASE
WHEN f.id_point IS NOT NULL
AND f.sum_up_bytes > 0
AND f.sum_down_bytes > 0
THEN 1
ELSE NULL
END) AS active
, COUNT(1) AS total
FROM
point p
LEFT OUTER JOIN temporal_fact_net_usage f ON p.id = f.id_point
WHERE
p.is_active
AND p.is_digital_city
GROUP BY
p.id_city
), city_stats2 AS (
SELECT
c.state
, c.name AS "city_name"
, c.city_code
, a.active AS "active_points"
, a.total AS "total_points"
, (a.total - a.active) AS "inactive_points"
FROM
active_city a
INNER JOIN city c on a.id_city = c.id
)
SELECT * FROM city_stats2 ORDER BY state, city_name, city_code
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Query to get the availability status of a GESAC point
COPY(
SELECT
c.cod_gesac
, CASE
WHEN a.is_green THEN 'Verde'
WHEN a.is_yellow THEN 'Amarelo'
WHEN a.is_red THEN 'Vermelho'
WHEN a.is_grey THEN 'Cinza'
ELSE '????'
END AS status
FROM
aggr_availability_point a
INNER JOIN convention c on c.id_point = a.id_point
WHERE
a.base_date = current_date - interval '1 day'
AND a.is_gesac = true
ORDER BY
cod_gesac
) TO STDOUT WITH CSV HEADER DELIMITER ';';
#! /bin/bash
# Use this file as an example to create the config.sh file
# WARNING!!!!!!!!!!!!!!!!!!!
# NEVER USE THIS FILE AS CONFIG.SH BECAUSE THIS IS A VERSIONABLE FILE
# ANY CHANGE TO THIS FILE WILL BE UPLOADED TO A REMOTE GIT REPOSITORY
# AND WILL BE PUBLIC.
# ANY SENTIVE INFORMATION IN THIS FILE, LIKE PASSWORDS, WILL BE AVAILABLE
# TO ANY ONE USE. SO NEVER PUT SENSITIVE INFORMATION ON IT, ONLY EXAMPLES.
declare -A QUERY_OPTS
declare -A REPORTS
QUERY_OPTS=(
[REJECT_INIT_DATE]="2018-05-01"
[REJECT_END_DATE]="2018-08-01"
[ACTIVE_INTERVAL]="30"
)
REPORTS=(
#[dc_pirate_exists.sql]="dc_pirate_exists.csv"
#[dc_turned_off.sql]="dc_turned_off.csv"
#[dc_active.sql]="dc_active.csv"
#[dc_pirate_lc.sql]="dc_pirate_lc.csv"
#[gesac_avail_by_code.sql]="gesac_avail_by_code.csv"
)
REPORT="dc_pirate_net_usage.sql"
POSTGRES_USER="db_user"
POSTGRES_HOST="db_host"
POSTGRES_PORT="5432"
POSTGRES_DB="db_name"
#! /bin/bash
source ${1:-config.sh}
SED_OPTS=""
for key in "${!QUERY_OPTS[@]}"; do
SED_OPTS="${SED_OPTS} -e s/\\\${${key}}/${QUERY_OPTS[${key}]}/g"
done
for REPORT in "${!REPORTS[@]}"; do
cat ../queries/${REPORT} | grep -v '\-\-' | sed $SED_OPTS > tmp.sql
psql -U ${POSTGRES_USER} -h ${POSTGRES_HOST} -p $POSTGRES_PORT -d ${POSTGRES_DB} -f tmp.sql > ${REPORTS[${REPORT}]}
done
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