Skip to content
Snippets Groups Projects
Commit a7680708 authored by Rafael De Lima Prado's avatar Rafael De Lima Prado
Browse files

database: Update table aggr_availability columns

parent 9d688401
Branches
No related tags found
No related merge requests found
CREATE TABLE aggr_availability ( CREATE TABLE aggr_availability (
sch_id INTEGER NOT NULL REFERENCES dim_school, base_date DATE NOT NULL,
cit_id INTEGER NOT NULL REFERENCES dim_city, macaddr MACADDR NOT NULL,
dat_id DATE NOT NULL REFERENCES dim_date,
mac_count BIGINT NOT NULL DEFAULT 0,
mac_count_red BIGINT NOT NULL DEFAULT 0,
mac_count_yellow BIGINT NOT NULL DEFAULT 0,
mac_count_green BIGINT NOT NULL DEFAULT 0,
project project_enum DEFAULT 'proinfo' NOT NULL, project project_enum DEFAULT 'proinfo' NOT NULL,
UNIQUE (sch_id, cit_id, dat_id, project) sch_inep VARCHAR (12) NOT NULL,
sch_name VARCHAR (150) NOT NULL,
city VARCHAR (100) NOT NULL,
state VARCHAR (2) NOT NULL,
region VARCHAR (12) NOT NULL,
is_green SMALLINT DEFAULT 0 NOT NULL,
is_yellow SMALLINT DEFAULT 0 NOT NULL,
is_red SMALLINT DEFAULT 0 NOT NULL
); );
CREATE INDEX aggr_availability_base_date_idx ON aggr_availability USING btree (base_date);
...@@ -10,21 +10,23 @@ BEGIN ...@@ -10,21 +10,23 @@ BEGIN
start_ts = CLOCK_TIMESTAMP(); start_ts = CLOCK_TIMESTAMP();
total_rows := 0; total_rows := 0;
-- remove the index - later we create it again
DROP INDEX IF EXISTS aggr_availability_base_date_idx;
-- remove old data -- remove old data
TRUNCATE TABLE aggr_availability; TRUNCATE TABLE aggr_availability;
-- iterate over past months -- iterate over past months
FOR date_it IN SELECT (date_trunc('month', generate_series( FOR i IN 0..5 LOOP
current_date - interval '4 months', date_it := CURRENT_DATE - (i * interval '1 month');
current_date,
interval '1 month')) - interval '1 day')::date UNION select current_date LOOP
INSERT INTO aggr_availability INSERT INTO aggr_availability
SELECT SELECT
date_it, date_it,
f.macaddr, f.macaddr,
t.id_point, f.project,
t.name, s.inep,
s.name,
c.name, c.name,
c.state, c.state,
c.region, c.region,
...@@ -34,27 +36,24 @@ BEGIN ...@@ -34,27 +36,24 @@ BEGIN
FROM FROM
(SELECT (SELECT
max(dat_id) as max_dat_id, max(dat_id) as max_dat_id,
f.id_tc, f.sch_id,
f.id_city, f.cit_id,
f.macaddr, f.macaddr,
f.project
FROM FROM
fact_communicate f fact_contact f
WHERE WHERE
dat_id <= date_it dat_id <= date_it
GROUP BY GROUP BY
f.id_city, f.id_tc, f.macaddr) as f f.cit_id, f.sch_id, f.macaddr, f.project) as f
INNER JOIN
telecenter t
ON
f.id_tc = t.id
INNER JOIN INNER JOIN
point_pt dim_school s
ON ON
t.id_point = pt.id f.sch_id = s.id
INNER JOIN INNER JOIN
city c dim_city c
ON ON
pt.id_city = c.id; f.cit_id = c.id;
-- how many rows were inserted? -- how many rows were inserted?
GET DIAGNOSTICS cur_rows := ROW_COUNT; GET DIAGNOSTICS cur_rows := ROW_COUNT;
...@@ -62,6 +61,9 @@ BEGIN ...@@ -62,6 +61,9 @@ BEGIN
END LOOP; END LOOP;
-- creating index to speed-up per-date queries, and it speeds up a lot..
CREATE INDEX aggr_availability_base_date_idx ON aggr_availability(base_date);
-- logging -- logging
INSERT INTO control (name, start_time, end_time, total) INSERT INTO control (name, start_time, end_time, total)
VALUES ('loading aggr_availability', start_ts, CLOCK_TIMESTAMP(), total_rows); VALUES ('loading aggr_availability', start_ts, CLOCK_TIMESTAMP(), total_rows);
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment