Commit d22527d2 authored by Eduardo L. Buratti's avatar Eduardo L. Buratti

Merge branch 'db-elb09'

parents c85ee5e7 905f6588
-- search tables
CREATE TABLE search_school (
id SERIAL PRIMARY KEY,
sch_id INTEGER NOT NULL REFERENCES dim_school,
cit_id INTEGER NOT NULL REFERENCES dim_city,
ts_vector TSVECTOR,
contacted_once BOOLEAN NOT NULL DEFAULT false
);
-- should we create an index on dim_inventory.is_current? Bitmap would be the best type...
CREATE INDEX search_school_ts_vector ON search_school USING gin(ts_vector);
CREATE OR REPLACE FUNCTION populate_search_school() returns void as $$
DECLARE
start_ts TIMESTAMP;
total_rows INTEGER;
cur_rows INTEGER;
BEGIN
-- getting initial timestamp
start_ts = CLOCK_TIMESTAMP();
total_rows := 0;
-- remove old data
TRUNCATE TABLE search_school;
INSERT INTO search_school (sch_id, cit_id, ts_vector)
SELECT
sch.id,
cit.id,
setweight(to_tsvector('portuguese', COALESCE(sch.name, '')), 'A')
|| setweight(to_tsvector('portuguese', COALESCE(cit.name, '')), 'B')
FROM dim_school sch, dim_city cit
WHERE cit.id = sch.cit_id;
-- accumulate total rows affected
GET DIAGNOSTICS cur_rows := ROW_COUNT;
total_rows := total_rows + cur_rows;
UPDATE search_school SET contacted_once = true
FROM (SELECT DISTINCT(sch_id) FROM fact_contact) contact
WHERE search_school.sch_id = contact.sch_id;
GET DIAGNOSTICS cur_rows := ROW_COUNT;
total_rows := total_rows + cur_rows;
-- logging
INSERT INTO control (name, start_time, end_time, total)
VALUES ('populate search_school', start_ts, CLOCK_TIMESTAMP(), total_rows);
END;
$$ language plpgsql;
......@@ -20,6 +20,9 @@ BEGIN
PERFORM load_fact_net_usage();
PERFORM load_aggr_availability();
-- populate search tables
PERFORM populate_search_school();
-- dropping staging area tables
PERFORM sa_drop();
END;
......
DROP FUNCTION os_categorize(text);
CREATE OR REPLACE FUNCTION os_categorize(name text) RETURNS
text
AS $$
SELECT CASE $1
WHEN 'Debian GNU/Linux 4.0' THEN 'Debian'
WHEN 'Debian GNU/Linux 6.0' THEN 'Debian'
WHEN 'Kernel' THEN 'Outros'
WHEN 'Linux Educacional' THEN 'Linux Educacional 3.0'
WHEN 'Linux Educacional 2.0' THEN 'Linux Educacional 2.0'
WHEN 'Linux Educacional 3.0' THEN 'Linux Educacional 3.0'
WHEN 'Linux Educacional 4.0' THEN 'Linux Educacional 4.0'
WHEN 'Linux Educacional 5.0' THEN 'Linux Educacional 5.0'
WHEN 'openSUSE 12.2 "Mantis" - Kernel' THEN 'Outros'
WHEN 'Ubuntu 10.04.1 LTS' THEN 'Ubuntu'
WHEN 'Ubuntu 10.04.2 LTS' THEN 'Ubuntu'
WHEN 'Ubuntu 10.04.3 LTS' THEN 'Ubuntu'
WHEN 'Ubuntu 10.04.4 LTS' THEN 'Ubuntu'
WHEN 'Ubuntu 10.10' THEN 'Ubuntu'
WHEN 'Ubuntu 11.04' THEN 'Ubuntu'
WHEN 'Ubuntu 11.10' THEN 'Ubuntu'
WHEN 'Ubuntu 12.04.1 LTS' THEN 'Ubuntu'
WHEN 'Ubuntu 12.04.2 LTS' THEN 'Ubuntu'
WHEN 'Ubuntu 12.04 LTS' THEN 'Ubuntu'
WHEN 'Ubuntu 12.10' THEN 'Ubuntu'
WHEN 'Ubuntu 8.04.1' THEN 'Ubuntu'
WHEN 'Ubuntu 8.04.4 LTS' THEN 'Ubuntu'
WHEN 'Ubuntu 8.10' THEN 'Ubuntu'
WHEN 'Ubuntu 9.04' THEN 'Ubuntu'
WHEN 'Ubuntu 9.10' THEN 'Ubuntu'
WHEN 'Ubuntu maverick (development branch)' THEN 'Ubuntu'
WHEN 'Windows 7 Enterprise' THEN 'Windows 7'
WHEN 'Windows 7 Home Basic' THEN 'Windows 7'
WHEN 'Windows 7 Home Premium' THEN 'Windows 7'
WHEN 'Windows 7 Professional' THEN 'Windows 7'
WHEN 'Windows 7 Starter' THEN 'Windows 7'
WHEN 'Windows 7 Ultimate' THEN 'Windows 7'
WHEN 'Windows MultiPoint Server 2010' THEN 'Windows MultiPoint Server'
ELSE 'Outros'
END;
$$
LANGUAGE SQL;
DROP FUNCTION os_brazil(project_enum, date);
CREATE OR REPLACE FUNCTION os_brazil(proj project_enum, b_date DATE DEFAULT CURRENT_DATE) RETURNS
TABLE (os_distro text, total bigint)
AS $$
BEGIN
CREATE TEMP TABLE temp_os_categories (ord integer, category text) ON COMMIT DROP;
INSERT INTO temp_os_categories (ord, category) VALUES
(0, 'Linux Educacional 5.0'),
(1, 'Linux Educacional 4.0'),
(2, 'Linux Educacional 3.0'),
(3, 'Linux Educacional 2.0'),
(4, 'Windows 7'),
(5, 'Windows MultiPoint Server'),
(6, 'Ubuntu'),
(7, 'Debian'),
(8, 'Outros');
RETURN QUERY SELECT
os, sum(c)::bigint
FROM (
(SELECT tmp.ord AS ord, s.os AS os, count(s.os) AS c
FROM (
SELECT os_categorize(max(inv.os_distro)) AS os
FROM dim_inventory inv
WHERE inv.project = proj AND inv.load_date <= b_date
GROUP BY inv.sch_id, inv.macaddr
) s, temp_os_categories tmp
WHERE tmp.category = s.os
GROUP BY tmp.ord, s.os
)
UNION ALL
(SELECT ord, category AS os, 0::bigint AS c
FROM temp_os_categories)
) uni
GROUP BY ord, os
ORDER BY ord;
DROP TABLE IF EXISTS temp_os_categories;
END;
$$
LANGUAGE plpgsql;
DROP FUNCTION os_brazil_monthly_history(project_enum);
CREATE OR REPLACE FUNCTION os_brazil_monthly_history(proj project_enum) RETURNS
TABLE (dat date, os_distro text, count bigint)
AS $$
SELECT
gen_date,
(os_brazil).os_distro,
(os_brazil).total
FROM
(SELECT
gen_date,
os_brazil($1, gen_date)
FROM
(SELECT
(date_trunc('month', generate_series(
current_date - interval '4 months',
current_date,
'1 month')) - interval '1 day')::date AS gen_date
UNION SELECT current_date) dates
) a
ORDER BY
gen_date;
$$
LANGUAGE SQL;
CREATE OR REPLACE FUNCTION remove_accents(text) RETURNS text AS
$$
SELECT translate($1, 'áàâãäéèêëíìïóòôõöúùûüÁÀÂÃÄÉÈÊËÍÌÏÓÒÔÕÖÚÙÛÜçÇ',
'aaaaaeeeeiiiooooouuuuAAAAAEEEEIIIOOOOOUUUUcC');
$$
LANGUAGE SQL;
CREATE OR REPLACE FUNCTION search_school(query text) RETURNS
TABLE (id integer, name text, city text, region text, state text, city_raw text) AS $$
BEGIN
RETURN QUERY SELECT
sch.id,
INITCAP(ts_headline(sch.name, q)),
INITCAP(ts_headline(cit.name, q)),
cit.region::text,
cit.state::text,
cit.name::text
FROM search_school s, dim_school sch, dim_city cit,
to_tsquery(regexp_replace(remove_accents(query), E'[ \+]+', '|', 'g')) q
WHERE
s.contacted_once = true AND
sch.id = s.sch_id AND
cit.id = sch.cit_id AND
s.ts_vector @@ q
ORDER BY ts_rank(s.ts_vector, q) DESC;
END;
$$ language plpgsql;
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