Commit b5f7720c authored by Rafael De Lima Prado's avatar Rafael De Lima Prado

Database: Fix project verification of inventory_city

Signed-off-by: 's avatarRafael De Lima Prado <rlp09@c3sl.ufpr.br>
parent d6c80b5d
#!/bin/bash
# Copyright (C) 2007-2013 Centro de Computacao Cientifica e Software Livre
# Departamento de Informatica - Universidade Federal do Parana - C3SL/UFPR
#
# This file is part of database
#
# database is free software; you can redistribute it and/or
# modify it under the terms of the GNU General Public License
# as published by the Free Software Foundation; either version 2
# of the License, or (at your option) any later version.
#
# This program is distributed in the hope that it will be useful,
# but WITHOUT ANY WARRANTY; without even the implied warranty of
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
# GNU General Public License for more details.
#
# You should have received a copy of the GNU General Public License
# along with this program; if not, write to the Free Software
# Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301,
# USA.
DB_NAME=$1
export DB_NAME=$1
DB_LINK_LOCATION=/usr/share/postgresql/8.4/contrib/dblink.sql
# checking parameters
......@@ -9,6 +28,10 @@ if [[ -z $DB_NAME ]]; then
exit 1
fi
# importing db_link functions
psql $DB_NAME -f $DB_LINK_LOCATION
# creating database tables and structure
for file in $(ls -B create/); do
psql $DB_NAME -f create/$file
......@@ -29,5 +52,5 @@ for file in $(ls -B query/); do
psql $DB_NAME -f query/$file
done
# importing db_link functions
psql $DB_NAMR -f $DB_LINK_LOCATION
# installing crontab
./cron.sh
......@@ -37,21 +37,22 @@ CREATE TABLE dim_inventory (
macaddr MACADDR NOT NULL,
load_date DATE NOT NULL DEFAULT CURRENT_DATE REFERENCES dim_date,
project project_enum DEFAULT 'proinfo' NOT NULL,
-- inventory info
disk1_model TEXT,
disk1_size INTEGER,
disk1_used INTEGER,
disk1_model TEXT NOT NULL,
disk1_size INTEGER NOT NULL,
disk1_used INTEGER NOT NULL,
disk2_model TEXT,
disk2_size INTEGER,
disk2_used INTEGER,
memory INTEGER,
processor TEXT,
os_type TEXT,
os_distro TEXT,
os_kernel TEXT,
memory INTEGER NOT NULL,
processor TEXT NOT NULL,
os_type TEXT NOT NULL,
os_distro TEXT NOT NULL,
os_kernel TEXT NOT NULL,
is_first BIT NOT NULL DEFAULT '0',
is_current BIT NOT NULL DEFAULT '1',
CHECK (macaddr <> '00:00:00:00:00:00')
......
......@@ -5,6 +5,7 @@ CREATE TABLE fact_contact (
cit_id INTEGER NOT NULL REFERENCES dim_city,
dat_id DATE NOT NULL REFERENCES dim_date,
macaddr MACADDR NOT NULL,
project project_enum DEFAULT 'proinfo' NOT NULL,
UNIQUE (sch_id, cit_id, dat_id, macaddr)
);
......
CREATE TABLE aggr_availability (
base_date DATE NOT NULL,
macaddr MACADDR NOT NULL,
project project_enum DEFAULT 'proinfo' NOT NULL,
sch_inep CHARACTER VARYING(12) NOT NULL,
sch_name CHARACTER VARYING(150) NOT NULL,
city CHARACTER VARYING(100) NOT NULL,
state CHARACTER VARYING(2) NOT NULL,
region CHARACTER VARYING(12) NOT NULL,
is_green SMALLINT NOT NULL DEFAULT 0,
is_yellow SMALLINT NOT NULL DEFAULT 0,
is_red SMALLINT NOT NULL DEFAULT 0
);
#!/bin/bash
# Copyright (C) 2004-2010 Centro de Computacao Cientifica e Software Livre
# Copyright (C) 2007-2013 Centro de Computacao Cientifica e Software Livre
# Departamento de Informatica - Universidade Federal do Parana - C3SL/UFPR
#
# This file is part of database
......@@ -19,7 +19,6 @@
# Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301,
# USA.
LOADFILE='/var/lib/postgresql/database/load/load.sh'
LOGFILE="/var/lib/postgresql/database/log/$(date +%d_%m_%y).log"
COMMAND="psql -d $DB_NAME -c 'SELECT load_dw();'"
echo "59 23 * * * $LOADFILE > $LOGFILE" | crontab -
echo "59 23 * * * $COMMAND" | crontab -
......@@ -49,7 +49,7 @@ BEGIN
i.disk2_size,
i.disk2_used,
i.extra_hds,
'1'::boolean as valid
'0'::boolean as valid
FROM
proinfo_inventory i
LEFT JOIN
......@@ -61,6 +61,9 @@ BEGIN
-- how many rows were inserted?
GET DIAGNOSTICS total_rows = ROW_COUNT;
-- creating primary key (and btree index)
ALTER TABLE sa_inventory ADD PRIMARY KEY ("id");
-- logging
INSERT INTO control (name, start_time, end_time, total)
VALUES ('create sa inventory', start_ts, CLOCK_TIMESTAMP(), total_rows);
......@@ -125,7 +128,7 @@ BEGIN
-- truncating OLTP table
--TRUNCATE TABLE proinfo_net_usage;
TRUNCATE TABLE proinfo_net_usage;
END;
$$ language plpgsql;
......@@ -147,15 +150,27 @@ CREATE OR REPLACE FUNCTION sa_sanitize_inventory() returns void as $$
DECLARE
start_ts TIMESTAMP;
total_rows INTEGER;
new_inv record;
BEGIN
-- getting initial timestamp
start_ts = CLOCK_TIMESTAMP();
-- updating the 'valid' column on invalid records
-- we create this table marking as rows as invalid.
-- when a computer sends more than one inventory per day, we get
-- only the last one. Validating the newers:
FOR new_inv IN
SELECT max(id) AS id FROM sa_inventory GROUP BY sch_id, macaddr, contact_date
LOOP
UPDATE sa_inventory set valid = '1' WHERE id = new_inv.id;
END LOOP;
-- Checking whether valid records have the required information
UPDATE sa_inventory
SET valid = '0'
WHERE
sch_id is NULL OR
valid = '1' AND
(sch_id is NULL OR
cit_id is NULL OR
contact_date is NULL OR
os_type is NULL OR
......@@ -168,7 +183,8 @@ BEGIN
disk1_used is NULL OR
NOT valid_macaddress(macaddr) OR
project < 0 OR project > 3 OR
inep is NULL;
inep is NULL);
-- log the invalid information into rejected table
INSERT INTO rejected_inventory
......
......@@ -9,118 +9,151 @@ SELECT CASE WHEN $1 = 0 THEN 'proinfo'::project_enum
END as project;
$$ LANGUAGE SQL;
CREATE OR REPLACE FUNCTION load_dim_inventory() returns void as $$
DECLARE
inv_row record;
date_row record;
start_ts TIMESTAMP;
total_rows INTEGER;
is_new BOOLEAN;
BEGIN
-- I think the better way to compare the current inventory and the new
-- one is to iterate over each record. Using one batch insert will
-- certainly perform way faster, but here we have more flexibility.
-- Also, we are inside one trasaction and it will be commited just once
-- at the end of the function.
FOR inv_row IN SELECT * FROM sa_inventory s LEFT JOIN (SELECT * FROM dim_inventory
WHERE is_current = '1') d ON s.sch_id = d.sch_id AND
s.macaddr::macaddr = d.macaddr AND NOT
(s.memory >= d.memory * 0.9 AND
s.memory <= d.memory * 1.1 AND
s.processor = d.processor AND
s.os_type = d.os_type AND
s.os_distro = d.os_distro AND
s.os_kernel = d.os_kernel AND
s.disk1_model = d.disk1_model AND
s.disk1_size >= d.disk1_size * 0.9 AND
s.disk1_size <= d.disk1_size * 1.1 AND
s.disk1_used = d.disk1_used AND
s.disk2_model = d.disk2_model AND
s.disk2_size >= d.disk2_size * 0.9 AND
s.disk2_size <= d.disk2_size * 1.1 AND
s.disk2_used = d.disk2_used)
WHERE valid = '1' LOOP
-- IF .... THEN
-- CONTINUE
-- END IF;
-- If we get here, we decided to update the record. First insert
-- the new inventory
INSERT INTO dim_inventory (sch_id, macaddr, load_date, project,
disk1_model, disk1_size, disk1_used, disk2_model,
disk2_size, disk2_used, memory, processor, os_type,
os_distro, os_kernel, is_current) VALUES
(inv_row.sch_id, inv_row.macaddr::macaddr,
inv_row.contact_date, to_project_enum(inv_row.project),
inv_row.disk1_model, inv_row.disk1_size,
inv_row.disk1_used, inv_row.disk2_model,
inv_row.disk2_size, inv_row.disk2_used,
inv_row.memory, inv_row.processor,
inv_row.os_type, inv_row.os_distro,
inv_row.os_kernel, '1');
-- Then update the 'is_current' flag of the last one.
UPDATE dim_inventory SET is_current = '0' WHERE
id = inv_row.id;
-- getting initial timestamp
start_ts = CLOCK_TIMESTAMP();
total_rows := 0;
-- since we removed multiple inventories on the same date on sa_sanitize,
-- looping one day at a time will ensure that we won't have more than one
-- inventory from the same computer.
FOR date_row IN SELECT DISTINCT contact_date FROM sa_inventory WHERE valid = '1' ORDER BY contact_date
LOOP
-- I think the better way to compare the current inventory and the new
-- one is to iterate over each record. Using one batch insert will
-- certainly perform way faster, but here we have more flexibility.
FOR inv_row IN
SELECT
s.sch_id as new_sch_id,
s.macaddr as new_macaddr,
s.contact_date as new_contact_date,
s.project as new_project,
s.disk1_model as new_disk1_model,
s.disk1_size as new_disk1_size,
s.disk1_used as new_disk1_used,
s.disk2_model as new_disk2_model,
s.disk2_size as new_disk2_size,
s.disk2_used as new_disk2_used,
s.memory as new_memory,
s.processor as new_processor,
s.os_type as new_os_type,
s.os_distro as new_os_distro,
s.os_kernel as new_os_kernel,
d.id as cur_id,
d.sch_id as cur_sch_id,
d.load_date as cur_load_date,
d.disk1_model as cur_disk1_model,
d.disk1_size as cur_disk1_size,
d.disk1_used as cur_disk1_used,
d.disk2_model as cur_disk2_model,
d.disk2_size as cur_disk2_size,
d.disk2_used as cur_disk2_used,
d.memory as cur_memory,
d.processor as cur_processor,
d.os_type as cur_os_type,
d.os_distro as cur_os_distro,
d.os_kernel as cur_os_kernel
FROM sa_inventory s LEFT JOIN
(SELECT * FROM dim_inventory WHERE is_current = '1') as d
ON s.sch_id = d.sch_id AND s.macaddr::macaddr = d.macaddr
WHERE s.contact_date = date_row.contact_date AND s.valid = '1'
LOOP
-- in which cases we shouldn't update the table
-- Note that since disk2_* can be null, the logic is a little
-- more complicated... The other columns are NOT NULL.
IF (inv_row.cur_id IS NOT NULL AND
inv_row.new_memory >= inv_row.cur_memory * 0.9 AND
inv_row.new_memory <= inv_row.cur_memory * 1.1 AND
inv_row.new_processor = inv_row.cur_processor AND
inv_row.new_os_type = inv_row.cur_os_type AND
inv_row.new_os_distro = inv_row.cur_os_distro AND
inv_row.new_os_kernel = inv_row.cur_os_kernel AND
inv_row.new_disk1_model = inv_row.cur_disk1_model AND
inv_row.new_disk1_size >= inv_row.cur_disk1_size * 0.9 AND
inv_row.new_disk1_size <= inv_row.cur_disk1_size * 1.1 AND
inv_row.new_disk1_used >= inv_row.cur_disk1_used * 0.9 AND
inv_row.new_disk1_used <= inv_row.cur_disk1_used * 1.1 AND
(
(inv_row.new_disk2_model IS NULL AND inv_row.cur_disk2_model IS NULL)
OR
inv_row.new_disk2_model = inv_row.cur_disk2_model
) AND
(
(inv_row.new_disk2_size IS NULL AND inv_row.cur_disk2_size IS NULL)
OR
(inv_row.new_disk2_size >= inv_row.cur_disk2_size * 0.9 AND
inv_row.new_disk2_size <= inv_row.cur_disk2_size * 1.1)
) AND
(
(inv_row.new_disk2_used IS NULL AND inv_row.cur_disk2_used IS NULL)
OR
(inv_row.new_disk2_used >= inv_row.cur_disk2_used * 0.9 AND
inv_row.new_disk2_used <= inv_row.cur_disk2_used * 1.1)
))
THEN
CONTINUE;
END IF;
-- if this inventory is older than the current, ignore it. Probably
-- the nicest way here would be to insert the historical data, but
-- that would complicate the loading function too much and slow all
-- things down.
IF (inv_row.new_contact_date <= inv_row.cur_load_date) THEN
CONTINUE;
END IF;
-- if cur_id is NULL then it's a new record. Marking it accordingly..
IF (inv_row.cur_id IS NULL) THEN
is_new := '1';
ELSE
is_new := '0';
END IF;
-- If we get here, we decided to update the record. First insert
-- the new inventory
INSERT INTO dim_inventory (sch_id, macaddr, load_date, project,
disk1_model, disk1_size, disk1_used, disk2_model,
disk2_size, disk2_used, memory, processor, os_type,
os_distro, os_kernel, is_first, is_current) VALUES
(inv_row.new_sch_id, inv_row.new_macaddr::macaddr,
inv_row.new_contact_date, to_project_enum(inv_row.new_project),
inv_row.new_disk1_model, inv_row.new_disk1_size,
inv_row.new_disk1_used, inv_row.new_disk2_model,
inv_row.new_disk2_size, inv_row.new_disk2_used,
inv_row.new_memory, inv_row.new_processor,
inv_row.new_os_type, inv_row.new_os_distro,
inv_row.new_os_kernel, (SELECT CASE WHEN is_new THEN B'1' ELSE B'0' END), '1');
-- only for logging purposes
total_rows := total_rows + 1;
-- Since we only insert newer inventories, we must update the
-- 'is_current' flag of the last inventory. Note that maybe we
-- don't have a previous inventory to update
IF (inv_row.cur_id IS NOT NULL) THEN
UPDATE dim_inventory SET is_current = '0' WHERE
id = inv_row.cur_id;
END IF;
END LOOP;
END LOOP;
-- logging
INSERT INTO control (name, start_time, end_time, total)
VALUES ('loading dim_inventory', start_ts, CLOCK_TIMESTAMP(), total_rows);
END;
$$ language plpgsql;
--CREATE OR REPLACE FUNCTION load_dim_inventory() returns void as $$
--BEGIN
-- creating a temporary table containing the inventories
-- we will need to insert/update - i.e. new inventories
-- EXCEPT current inventories
-- CREATE TEMP TABLE new_inventories ON COMMIT DROP AS
-- SELECT sch_id, macaddr FROM
-- (
-- -- new computer information
-- (SELECT
-- sch_id, macaddr, project, memory,
-- disk1_model, disk1_size,
-- disk2_model, disk2_size,
-- os_type, os_distro, os_kernel
-- FROM sa_inventory
-- )
-- EXCEPT
-- list of current inventory for each computer
-- (SELECT
-- sch_id, macaddr, project, memory,
-- disk1_model, disk1_size,
-- disk2_model, disk2_size,
-- os_type, os_distro, os_kernel
-- FROM dim_inventory
-- WHERE is_current = '1'
-- )
-- ) as A;
-- setting is_current to '0' on old records
-- UPDATE dim_inventory SET is_current = '0'
-- WHERE
-- is_current = '1' and (sch_id, macaddr) IN (SELECT * FROM new_inventories);
-- inserting new records
-- INSERT INTO dim_inventory
-- (sch_id, macaddr, load_date, project,
-- disk1_model, disk1_size, disk1_used,
-- disk2_model, disk2_size, disk2_used,
-- memory, processor,
-- os_type, os_distro, os_kernel, is_current)
-- SELECT
-- s.sch_id, s.macaddr, s.contact_date, s.project,
-- s.disk1_model, s.disk1_size, s.disk1_used,
-- s.disk2_model, s.disk2_size, s.disk2_used,
-- s.memory, s.processor,
-- s.os_type, s.os_distro, s.os_kernel, '1'
-- FROM new_inventories n INNER JOIN sa_inventory s
-- ON n.sch_id = s.sch_id and n.macaddr = s.macaddr;
-- when the transaction commits, the temporary table
-- 'new_inventories' will be removed
--END;
--$$ language plpgsql;
......@@ -15,10 +15,10 @@ BEGIN
INTO result from sa_inventory;
--
INSERT INTO fact_contact (sch_id, cit_id, dat_id, macaddr)
(SELECT sch_id, cit_id, contact_date, macaddr::macaddr FROM sa_inventory WHERE valid = '1')
INSERT INTO fact_contact (sch_id, cit_id, dat_id, macaddr, project)
(SELECT sch_id, cit_id, contact_date, macaddr::macaddr, to_project_enum(project) FROM sa_inventory WHERE valid = '1')
EXCEPT
(SELECT sch_id, cit_id, dat_id, macaddr FROM fact_contact WHERE dat_id >= result.min_date AND dat_id <= result.max_date);
(SELECT sch_id, cit_id, dat_id, macaddr, project FROM fact_contact WHERE dat_id >= result.min_date AND dat_id <= result.max_date);
-- how many rows were inserted?
GET DIAGNOSTICS total_rows = ROW_COUNT;
......
......@@ -18,7 +18,8 @@ BEGIN
INSERT INTO fact_net_usage (sch_id, cit_id, dat_id, macaddr,
collect_time, down_kbits, down_packages, up_kbits, up_packages)
(SELECT sch_id, cit_id, contact_date, macaddr, collect_time, down_kbits,
down_packages, up_kbits, up_packages FROM sa_net_usage)
down_packages, up_kbits, up_packages FROM sa_net_usage
WHERE valid = '1')
EXCEPT
(SELECT sch_id, cit_id, dat_id, macaddr, collect_time, down_kbits,
down_packages, up_kbits, up_packages FROM fact_net_usage WHERE
......
CREATE OR REPLACE FUNCTION load_aggr_availability() returns void as $$
DECLARE
date_it date;
i INTEGER;
start_ts TIMESTAMP;
total_rows INTEGER;
cur_rows INTEGER;
BEGIN
-- getting initial timestamp
start_ts = CLOCK_TIMESTAMP();
total_rows := 0;
-- remove the index - later we create it again
DROP INDEX IF EXISTS aggr_availability_base_date_idx;
-- remove old data
TRUNCATE TABLE aggr_availability;
-- iterate over past months
FOR i IN 0..5 LOOP
date_it := CURRENT_DATE - (i * interval '1 month');
INSERT INTO aggr_availability
SELECT
date_it,
f.macaddr,
f.project,
s.inep,
s.name,
c.name,
c.state,
c.region,
CASE WHEN date_it - max_dat_id <= 10 THEN 1 ELSE 0 END as is_green,
CASE WHEN date_it - max_dat_id > 10 AND date_it - max_dat_id <= 30 THEN 1 ELSE 0 END as is_yellow,
CASE WHEN date_it - max_dat_id > 30 THEN 1 ELSE 0 END as is_red
FROM
(SELECT
max(dat_id) as max_dat_id,
f.sch_id,
f.cit_id,
f.macaddr,
f.project
FROM
fact_contact f
WHERE
dat_id <= date_it
GROUP BY
f.cit_id, f.sch_id, f.macaddr, f.project) as f
INNER JOIN
dim_school s
ON
f.sch_id = s.id
INNER JOIN
dim_city c
ON
f.cit_id = c.id;
-- how many rows were inserted?
GET DIAGNOSTICS cur_rows := ROW_COUNT;
total_rows := total_rows + cur_rows;
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
INSERT INTO control (name, start_time, end_time, total)
VALUES ('loading aggr_availability', start_ts, CLOCK_TIMESTAMP(), total_rows);
END;
$$ language plpgsql;
......@@ -2,7 +2,7 @@
-- only function that should be called directly. Run it once a day.
CREATE OR REPLACE FUNCTION load_dw() returns void as $$
BEGIN
-- populating dim_date with next 10 years
PERFORM populate_dim_date(CAST(extract(year FROM CURRENT_DATE) AS INTEGER) + 10);
......@@ -17,7 +17,8 @@ BEGIN
-- ET'L' -> Load
PERFORM load_dim_inventory();
PERFORM load_fact_contact();
--SELECT load_fact_net_usage();
PERFORM load_fact_net_usage();
PERFORM load_aggr_availability();
-- dropping staging area tables
PERFORM sa_drop();
......
CREATE OR REPLACE FUNCTION alert_hd_and_mem_brazil(proj project_enum) RETURNS
TABLE ("hd" bigint, "memory" bigint) AS $$
BEGIN
RETURN QUERY SELECT
SUM(CASE WHEN i1.memory != i2.memory THEN 1 ELSE 0 END),
SUM(
CASE WHEN
i1.disk1_model != i2.disk1_model
OR
i1.disk1_size != i2.disk1_size
OR
(i1.disk2_model != i2.disk2_model AND (i1.disk2_model IS NOT NULL OR i2.disk2_model IS NOT NULL))
OR
(i1.disk2_size != i2.disk2_size AND (i1.disk2_size IS NOT NULL OR i2.disk2_size IS NOT NULL))
THEN 1
ELSE 0 END
)
FROM
dim_inventory i1
INNER JOIN
dim_inventory i2
ON
i1.sch_id = i2.sch_id AND i1.macaddr = i2.macaddr AND
i1.is_first = '1' AND i2.is_current = '1'
WHERE
i1.project = proj;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION alert_hd_and_mem_region(proj project_enum) RETURNS
TABLE ("region" varchar, "hd" bigint, "memory" bigint) AS $$
BEGIN
RETURN QUERY SELECT
c.region,
SUM(CASE WHEN i1.memory != i2.memory THEN 1 ELSE 0 END),
SUM(
CASE WHEN
i1.disk1_model != i2.disk1_model
OR
i1.disk1_size != i2.disk1_size
OR
(i1.disk2_model != i2.disk2_model AND (i1.disk2_model IS NOT NULL OR i2.disk2_model IS NOT NULL))
OR
(i1.disk2_size != i2.disk2_size AND (i1.disk2_size IS NOT NULL OR i2.disk2_size IS NOT NULL))
THEN 1
ELSE 0 END
)
FROM
dim_inventory i1
INNER JOIN
dim_inventory i2
ON
i1.sch_id = i2.sch_id AND i1.macaddr = i2.macaddr AND
i1.is_first = '1' AND i2.is_current = '1'
INNER JOIN
dim_school s
ON
i1.sch_id = s.id
INNER JOIN
dim_city c
ON
s.cit_id = c.id
WHERE
i1.project = proj
GROUP BY
c.region;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION alert_hd_and_mem_state(proj project_enum, region_in text) RETURNS
TABLE ("state" varchar, "hd" bigint, "memory" bigint) AS $$
BEGIN
RETURN QUERY SELECT
c.state,
SUM(CASE WHEN i1.memory != i2.memory THEN 1 ELSE 0 END),
SUM(
CASE WHEN
i1.disk1_model != i2.disk1_model
OR
i1.disk1_size != i2.disk1_size
OR
(i1.disk2_model != i2.disk2_model AND (i1.disk2_model IS NOT NULL OR i2.disk2_model IS NOT NULL))
OR
(i1.disk2_size != i2.disk2_size AND (i1.disk2_size IS NOT NULL OR i2.disk2_size IS NOT NULL))
THEN 1
ELSE 0 END
)
FROM
dim_inventory i1
INNER JOIN
dim_inventory i2
ON
i1.sch_id = i2.sch_id AND i1.macaddr = i2.macaddr AND
i1.is_first = '1' AND i2.is_current = '1'
INNER JOIN
dim_school s
ON
i1.sch_id = s.id
INNER JOIN
dim_city c
ON
s.cit_id = c.id
WHERE
i1.project = proj AND c.region = region_in
GROUP BY
c.region, c.state;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION alert_hd_and_mem_city(proj project_enum, state_in text) RETURNS
TABLE ("city" varchar, "hd" bigint, "memory" bigint) AS $$
BEGIN
RETURN QUERY SELECT
c.name,
SUM(CASE WHEN i1.memory != i2.memory THEN 1 ELSE 0 END),
SUM(
CASE WHEN
i1.disk1_model != i2.disk1_model
OR
i1.disk1_size != i2.disk1_size
OR
(i1.disk2_model != i2.disk2_model AND (i1.disk2_model IS NOT NULL OR i2.disk2_model IS NOT NULL))
OR
(i1.disk2_size != i2.disk2_size AND (i1.disk2_size IS NOT NULL OR i2.disk2_size IS NOT NULL))
THEN 1
ELSE 0 END
)
FROM
dim_inventory i1
INNER JOIN
dim_inventory i2
ON
i1.sch_id = i2.sch_id AND i1.macaddr = i2.macaddr AND
i1.is_first = '1' AND i2.is_current = '1'
INNER JOIN
dim_school s
ON
i1.sch_id = s.id
INNER JOIN
dim_city c
ON
s.cit_id = c.id
WHERE
i1.project = proj AND c.state = state_in
GROUP BY
c.name;
END;
$$ language plpgsql;
CREATE