Commit 40ae2800 authored by Erik Alexandre Pucci's avatar Erik Alexandre Pucci

database: Data marts load halfway through

Add region fields to auxiliate load of upper tables.
Signed-off-by: default avatarErik Alexandre Pucci <eap08@c3sl.ufpr.br>
parent 2480a89e
......@@ -36,6 +36,7 @@ create table dm_avail_state (
/* Data mart table of availability per city */
create table dm_avail_city (
project project_enum default 'proinfo' not null,
region text not null,
state text not null,
city text not null,
total integer not null,
......@@ -47,6 +48,7 @@ create table dm_avail_city (
/* Data mart table of availability per school */
create table dm_avail_school (
project project_enum default 'proinfo' not null,
region text not null,
state text not null,
city text not null,
inep text not null,
......@@ -60,6 +62,7 @@ create table dm_avail_school (
/* Data mart table with availability per machine */
create table dm_avail_machine (
project project_enum default 'proinfo' not null,
region text not null,
state text not null,
city text not null,
inep text not null,
......@@ -91,6 +94,7 @@ create table dm_avail_state_history (
create table dm_avail_city_history (
project project_enum default 'proinfo' not null,
contact_date date not null,
region text not null,
state text not null,
city text not null,
total integer not null,
......@@ -144,6 +148,7 @@ create table dm_alert_state (
/* Data mart table with alerts per city */
create table dm_alert_city (
project project_enum default 'proinfo' not null,
region text not null,
state text not null,
city text not null,
memory_amount integer not null,
......@@ -153,6 +158,7 @@ create table dm_alert_city (
/* Data mart table with alerts per school */
create table dm_alert_school (
project project_enum default 'proinfo' not null,
region text not null,
state text not null,
city text not null,
inep text not null,
......@@ -164,6 +170,7 @@ create table dm_alert_school (
/* Data mart table with machines alerts */
create table dm_alert_machine (
project project_enum default 'proinfo' not null,
region text not null,
state text not null,
city text not null,
inep text not null,
......@@ -198,6 +205,7 @@ create table dm_alert_state_history (
create table dm_alert_city_history (
project project_enum default 'proinfo' not null,
contact_date date not null,
region text not null,
state text not null,
city text not null,
memory_amount integer not null,
......
......@@ -30,13 +30,13 @@ begin
/* ---------------------------------------------------------------------- */
/* Update availability data marts */
raise log 'Inserting new machines inventories and contacts into '
'"dm_avail_machine"...';
insert into dm_avail_machine (project, state, city, inep, school, machine,
color, first_contact, total_contacts, month_contacts, days_last_contact)
select project, state, city, inep, school, machine, case when
last_contact < current_date - 30 then 'red'::class_enum when
last_contact < current_date - 10 then 'yellow'::class_enum else
raise log 'Inserting machine availability data into "dm_avail_machine"...';
insert into dm_avail_machine (project, region, state, city, inep, school,
machine, color, first_contact, total_contacts, month_contacts,
days_last_contact)
select distinct project, region, state, city, inep, school, machine,
case when last_contact < current_date - 30 then 'red'::class_enum
when last_contact < current_date - 10 then 'yellow'::class_enum else
'green'::class_enum end, first_contact, total_contacts,
month_contacts, days_last_contact from fact_inventory i, dim_school
s, dim_machine m, (select machine_id, min(contact_date) as
......@@ -51,6 +51,133 @@ begin
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
raise log 'Inserting school availability data into "dm_avail_school"...';
insert into dm_avail_school (project, region, state, city, inep, school,
total, green, yellow, red)
select distinct s.project, region, state, city, s.inep, school, total,
green, yellow, red from dm_avail_machine m, (select project, inep,
count(*) as total, sum(case when color = 'green'::class_enum then 1
else 0 end) as green, sum(case when color = 'yellow'::class_enum
then 1 else 0 end) as yellow, sum(case when color =
'red'::class_enum then 1 else 0 end) as red from dm_avail_machine
group by project, inep) s where m.project = s.project and m.inep =
s.inep;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
raise log 'Inserting city availability data into "dm_avail_city"...';
insert into dm_avail_city (project, region, state, city, total, green,
yellow, red)
select distinct t.project, region, state, t.city, t.total, t.green,
t.yellow, t.red from dm_avail_school s, (select project, city,
sum(green) + sum(yellow) + sum(red) as total, sum(green) as green,
sum(yellow) as yellow, sum(red) as red from dm_avail_school group by
project, city) t where s.project = t.project and s.city = t.city;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
raise log 'Inserting state availability data into "dm_avail_state"...';
insert into dm_avail_state (project, region, state, total, green, yellow,
red)
select distinct s.project, region, s.state, s.total, s.green, s.yellow,
s.red from dm_avail_city c, (select project, state, sum(green) +
sum(yellow) + sum(red) as total, sum(green) as green, sum(yellow) as
yellow, sum(red) as red from dm_avail_city group by project, state)
s where c.project = s.project and c.state = s.state;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
/* ---------------------------------------------------------------------- */
/* Update inventory data mart */
raise log 'Inserting machine inventory data into "dm_invent_machine"...';
insert into dm_invent_machine (project, contact_date, state, city, inep,
school, machine, os_distro, processor, memory_size, hd_size)
select distinct project, contact_date, state, city, inep, school,
machine, o.detail, p.description, memory_size, h.detail::integer
from fact_inventory i, dim_component o, dim_component p,
dim_component h, dim_machine m, dim_school s, (select machine_id,
max(contact_date) as last_contact from fact_inventory group by
machine_id) t where i.machine_id = t.machine_id and contact_date =
last_contact and i.os_id = o.id and i.processor_id = p.id and
i.hd_id = h.id and i.machine_id = m.id and m.school_id = s.id;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
/* ---------------------------------------------------------------------- */
/* Update auditory data mart */
raise log 'Inserting auditory data into "dm_audit_zm_school"...';
insert into dm_audit_zm_school (project, state, city, inep, school)
with tmp_project as (
select distinct project from dim_machine
) select project, state, city, inep, school from dim_school, tmp_project
except select project, state, city, inep, school from dm_avail_machine;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
/* ---------------------------------------------------------------------- */
/* Update alert data marts */
raise log 'Inserting machine alert data into "dm_alert_machine"...';
insert into dm_alert_machine (project, region, state, city, inep, school,
machine, old_date, new_date, os_distro, processor, old_memory_size,
new_memory_size, old_hd_size, new_hd_size, memory_alert, hd_alert)
select distinct project, region, state, city, inep, school, machine,
i.contact_date, j.contact_date, o.detail, p.description,
i.memory_size, j.memory_size, h.detail::integer, z.detail::integer,
memory_alert, hd_alert from fact_alert, fact_inventory i,
fact_inventory j, dim_component o, dim_component p, dim_component h,
dim_component z, dim_machine m, dim_school s where old_inventory =
i.id and inventory = j.id and i.os_id = o.id and i.processor_id =
p.id and i.hd_id = h.id and i.hd_id = z.id and j.machine_id = m.id
and m.school_id = s.id and (memory_alert or hd_alert);
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
raise log 'Inserting school alert data into "dm_alert_school"...';
insert into dm_alert_school (project, region, state, city, inep, school,
memory_amount, hd_amount)
select distinct s.project, region, state, city, s.inep, school,
memory_amount, hd_amount from dm_alert_machine m, (select project,
inep, 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 dm_alert_machine group by project, inep) s where
m.project = s.project and m.inep = s.inep;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
raise log 'Inserting city alert data into "dm_alert_city"...';
insert into dm_alert_city (project, region, state, city, memory_amount,
hd_amount)
select distinct s.project, region, state, t.city, t.memory_amount,
t.hd_amount from dm_alert_school s, (select project, city,
sum(memory_amount) as memory_amount, sum(hd_amount) as hd_amount
from dm_alert_school group by project, city) t where s.project =
t.project and s.city = t.city;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
raise log 'Inserting state alert data into "dm_alert_state"...';
insert into dm_alert_state (project, region, state, memory_amount,
hd_amount)
select distinct s.project, region, s.state, s.memory_amount, s.hd_amount
from dm_alert_city c, (select project, state, sum(memory_amount) as
memory_amount, sum(hd_amount) as hd_amount from dm_alert_city group
by project, state) s where c.project = s.project and c.state =
s.state;
get diagnostics tmp = ROW_COUNT;
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
/* ---------------------------------------------------------------------- */
/* Update control table */
......@@ -63,42 +190,3 @@ begin
clock_timestamp(), current_timestamp, count_total;
end;
$$ language plpgsql;
/* -------------------------------------------------------------------------- */
/* Last load availability tables */
/* Data mart table of availability per state */
create table dm_avail_state (
project project_enum default 'proinfo' not null,
region text not null,
state text not null,
total integer not null,
green integer not null,
yellow integer not null,
red integer not null
);
/* Data mart table of availability per city */
create table dm_avail_city (
project project_enum default 'proinfo' not null,
state text not null,
city text not null,
total integer not null,
green integer not null,
yellow integer not null,
red integer not null
);
/* Data mart table of availability per school */
create table dm_avail_school (
project project_enum default 'proinfo' not null,
state text not null,
city text not null,
inep text not null,
school text not null,
total integer not null,
green integer not null,
yellow integer not null,
red integer not null
);
......@@ -149,10 +149,6 @@ begin
/* Get minimum date from which the load must take effect in fact_alert */
select min(contact_date) into min_date from sa_inventory;
select max(contact_date) into tmp from fact_inventory;
if tmp < min_date then
min_date := tmp;
end;
/* Insert new data into fact_inventory using the temporary tables */
raise log 'Inserting new machines inventories and contacts into '
......@@ -200,6 +196,9 @@ begin
count_total := count_total + tmp;
raise log 'Done - % rows inserted', tmp;
/* Get insertion date to control insertions in fact_net_usage */
select min(contact_date) into min_date from sa_net_usage;
raise log 'Updating existing rows with new network usage data in '
'"fact_net_usage"...';
update fact_net_usage f set load_date = load_date_id, down_bytes = sdb,
......
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