Add queries to extract telecenters

Signed-off-by: Lucas Fernandes de Oliveira's avatarLucas Fernandes de Oliveira <lfoliveira@inf.ufpr.br>
parent cd56f3c6
-- Query which generated the table contact_temp used in the
-- creation step of the simmctic database
-- for details check simmctic/database/create/data/001-load_data_telecenter.sql
-- and simmctic/database/create/data/contact_temp.csv
-- WARNING: Some telecenters were inserted without id_onid. Such telecenters
-- cannot be identifyed unically (without id_point) and are removed of this
-- query.
SELECT
t.id_onid
, ct.name AS "responsible_name"
, ct.rg AS "responsible_rg"
, ct.cpf AS "responsible_cpf"
, ct.post AS "responsible_post"
, ct.phone1 AS "responsible_phone_1"
, ct.phone2 AS "responsible_phone_2"
, ct.phone3 AS "responsible_phone_3"
FROM
point p
INNER JOIN telecenter t ON p.id = t.id_point
INNER JOIN contact ct ON p.id = ct.id_point
WHERE
t.id_onid IS NOT NULL
AND p.is_active
;
-- Download by point, year, proj
COPY(
WITH weekly_fnu 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
), wk_fnu_join_point AS (
SELECT
f.id_point
, f.year
, f.id_city
, f.down_bytes_total
, 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
FROM
weekly_fnu f
INNER JOIN point p ON p.id = f.id_point
)
SELECT * FROM wk_fnu_join_point ORDER BY year, id_city
) TO STDOUT WITH CSV HEADER DELIMITER ';';
......@@ -12,4 +12,7 @@ SELECT
, ip
FROM
fact_net_usage
WHERE
collect_date >= '${DATE_FILTER_INIT}'::date
AND collect_date < '${DATE_FILTER_END}'::date
) TO STDOUT WITH CSV HEADER DELIMITER ';';
-- Query which generated the table scholarship_temp used in the
-- creation step of the simmctic database
-- for details check simmctic/database/create/data/001-load_data_telecenter.sql
-- and simmctic/database/create/data/scholarship_temp.csv
-- WARNING: Some telecenters were inserted without id_onid. Such telecenters
-- cannot be identifyed unically (without id_point) and are removed of this
-- query.
SELECT
t.id_onid
, s.value
, s.situation
, s.note
FROM
point p
INNER JOIN telecenter t ON p.id = t.id_point
INNER JOIN scholarship s ON p.id = s.id_point
WHERE
t.id_onid IS NOT NULL
AND p.is_active
;
-- Query which generated the table telecenter_temp used in the
-- creation step of the simmctic database
-- for details check simmctic/database/create/data/001-load_data_telecenter.sql
-- and simmctic/database/create/data/telecenter_temp.csv
-- WARNING: Some telecenters were inserted without id_onid. Such telecenters
-- cannot be identifyed unically (without id_point) and are removed of this
-- query.
SELECT
p.is_gesac
, c.name AS "city"
, c.state AS "state"
, t.id_onid
, t.id_proponent
, t.proponent
, t.furniture_note
, t.computer_note
, t.connection_note
, fs.value AS "furniture_situation"
, cs.value AS "computer_situation"
, cns.value AS "connection_situation"
, a.establishment
, a.phone
, a.email
, a.street
, a.neighborhood
, a.complement
, a.reference
, a.zipcode
, a.has_alt_address
, b.name AS "beneficiary_name"
, b.corporate_name AS "corporate_name"
, b.cnpj AS "beneficiary_cnpj"
, b.phone AS "beneficiary_phone"
, b.email AS "beneficiary_email"
FROM
point p
INNER JOIN city c ON c.id = p.id_city
INNER JOIN telecenter t ON p.id = t.id_point
INNER JOIN beneficiary b ON p.id = b.id_point
LEFT OUTER JOIN address a ON p.id = a.id_point
LEFT OUTER JOIN furniture_situation fs ON t.id_furniture_situation = fs.id
LEFT OUTER JOIN computer_situation cs ON t.id_computer_situation = cs.id
LEFT OUTER JOIN connection_situation cns ON t.id_connection_situation = cns.id
WHERE
t.id_onid IS NOT NULL
AND p.is_active
;
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