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

database: Add operating system queries

Signed-off-by: Eduardo L. Buratti's avatarEduardo L. Buratti <elb09@c3sl.ufpr.br>
parent 9025eca0
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 1.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 (category text) ON COMMIT DROP;
INSERT INTO temp_os_categories (category) VALUES
('Debian'),
('Linux Educacional 1.0'),
('Linux Educacional 2.0'),
('Linux Educacional 3.0'),
('Linux Educacional 4.0'),
('Linux Educacional 5.0'),
('Outros'),
('Ubuntu'),
('Windows 7'),
('Windows MultiPoint Server');
RETURN QUERY SELECT
os, sum(c)::bigint
FROM (
(SELECT 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
) AS s
GROUP BY s.os
ORDER BY count(s.os)
)
UNION ALL
(SELECT category AS os, 0::bigint AS c
FROM temp_os_categories)
) uni
GROUP BY os;
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,(os_brazil).total;
$$
LANGUAGE SQL;
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