Commit 08d9286b authored by Erik Alexandre Pucci's avatar Erik Alexandre Pucci

database: Revision 1

Signed-off-by: default avatarErik Alexandre Pucci <eap08@c3sl.ufpr.br>
parent 7234f69e
......@@ -60,9 +60,6 @@ comment on column dim_school.city is 'Longest city name has 32 characters';
comment on column dim_school.school is 'MEC database limit for school names is '
'100 characters';
comment on column dim_school.address is 'Longest address has 70 characters';
comment on column dim_school.fts_school is 'Full text search field for schools';
comment on column dim_school.nud_avail is 'It indicates if the school has '
'already sent some network usage data';
comment on table dim_component is 'Dimension table of software and hardware '
'components';
comment on column dim_component.description is 'HD model, OS type, processor '
......
......@@ -249,11 +249,11 @@ begin
insert into dm_alert_city_history (project, contact_date, region, state,
city, memory_amount, hd_amount)
with tmp_alert_machine_history as (
select project, region, state, city, month_last_day, t.machine_id,
last_alert_per_month from dim_machine m, dim_school s, (select
select project, region, state, city, month_last_day, --inventory,
last_alert_per_month, memory_alert, hd_alert from dim_machine m, dim_school s, (select
month_last_day, inventory, memory_alert, hd_alert, max(contact_date)
over(partition by month_last_day, machine_id) as
last_alert_per_month from fact_alert, fact_inventory (select
last_alert_per_month from fact_alert, fact_inventory, (select
distinct (date_trunc('month', contact_date) + interval '1 month - 1
day')::date as month_last_day from fact_inventory) t where inventory
= id and contact_date <= month_last_day) u where inventory = m.id
......@@ -261,7 +261,7 @@ begin
) select project, month_last_day, region, state, city,
sum(case when memory_alert then 1 else 0 end) as memory_amount,
sum(case when hd_alert then 1 else 0 end) as hd_amount from
tmp_avail_machine_history group by project, region, state, city,
tmp_alert_machine_history group by project, region, state, city,
month_last_day;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
......@@ -280,6 +280,38 @@ begin
/* ---------------------------------------------------------------------- */
/* Update network usage data marts */
raise log 'Updating existing rows with new network usage data per school '
'in "fact_net_usage_school"...';
update fact_net_usage_school f set load_date = load_date_id, down_kbits =
sdb, down_packages = sdp, up_kbits = sub, up_packages = sup
from (select t.id, t.collect_time, sum(down_kbits) as sdb,
sum(down_packages) as sdp, sum(up_kbits) as sub, sum(up_packages) as
sup from (select id, collect_time from tmp_net_usage n, dim_school s
where n.inep = s.inep
intersect select school_id, collect_time from fact_net_usage_school)
t, tmp_net_usage n, dim_school s where n.inep = s.inep and t.id =
s.id and t.collect_time = n.collect_time group by t.id,
t.collect_time) u
where school_id = u.id and f.collect_time = u.collect_time;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows updated', tmp;
raise log 'Inserting new network usage data per school into '
'"fact_net_usage_school"...';
insert into fact_net_usage_school (load_date, school_id, collect_time,
down_kbits, down_packages, up_kbits, up_packages)
select load_date_id, t.id, t.collect_time, sum(down_kbits),
sum(down_packages), sum(up_kbits), sum(up_packages) from (select id,
collect_time from tmp_net_usage n, dim_school s where n.inep =
s.inep
except select school_id, collect_time from fact_net_usage_school) t,
tmp_net_usage n, dim_school s where n.inep = s.inep and t.id = s.id
and t.collect_time = n.collect_time group by t.id, t.collect_time;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
raise log 'Inserting network usage data per day into '
'"dm_net_usage_daily"...';
insert into dm_net_usage_daily (state, city, inep, school, collect_time,
......
......@@ -86,8 +86,8 @@ begin
raise log 'Inserting new machine data into "dim_machine"...';
insert into dim_machine (load_date, school_id, machine, project)
select load_date_id, id, machine, project from tmp_inventory i,
dim_school s where i.inep = s.inep
select distinct on (id, machine) load_date_id, id, machine, project
from tmp_inventory i, dim_school s where i.inep = s.inep
except select load_date_id, school_id, machine, project from
dim_machine;
get diagnostics tmp = ROW_COUNT;
......@@ -217,38 +217,6 @@ begin
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
raise log 'Updating existing rows with new network usage data per school '
'in "fact_net_usage_school"...';
update fact_net_usage_school f set load_date = load_date_id, down_kbits =
sdb, down_packages = sdp, up_kbits = sub, up_packages = sup
from (select t.id, t.collect_time, sum(down_kbits) as sdb,
sum(down_packages) as sdp, sum(up_kbits) as sub, sum(up_packages) as
sup from (select id, collect_time from tmp_net_usage n, dim_school s
where n.inep = s.inep
intersect select school_id, collect_time from fact_net_usage_school)
t, tmp_net_usage n, dim_school s where n.inep = s.inep and t.id =
s.id and t.collect_time = n.collect_time group by t.id,
t.collect_time) u
where school_id = u.id and f.collect_time = u.collect_time;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows updated', tmp;
raise log 'Inserting new network usage data per school into '
'"fact_net_usage_school"...';
insert into fact_net_usage_school (load_date, school_id, collect_time,
down_kbits, down_packages, up_kbits, up_packages)
select load_date_id, t.id, t.collect_time, sum(down_kbits),
sum(down_packages), sum(up_kbits), sum(up_packages) from (select id,
collect_time from tmp_net_usage n, dim_school s where n.inep =
s.inep
except select school_id, collect_time from fact_net_usage_school) t,
tmp_net_usage n, dim_school s where n.inep = s.inep and t.id = s.id
and t.collect_time = n.collect_time group by t.id, t.collect_time;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
/* ---------------------------------------------------------------------- */
/* Update control table and clean staging area tables */
......
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