diff --git a/sql.d/update/create_schema.sql b/sql.d/update/create_schema.sql index 2966fa795..37935cdea 100644 --- a/sql.d/update/create_schema.sql +++ b/sql.d/update/create_schema.sql @@ -265,11 +265,13 @@ CREATE TABLE maintainers ( num_packages_untrusted integer NOT NULL DEFAULT 0, num_packages_noscheme integer NOT NULL DEFAULT 0, num_packages_rolling integer NOT NULL DEFAULT 0, + num_packages_vulnerable integer NOT NULL DEFAULT 0, num_projects integer NOT NULL DEFAULT 0, num_projects_newest integer NOT NULL DEFAULT 0, num_projects_outdated integer NOT NULL DEFAULT 0, num_projects_problematic integer NOT NULL DEFAULT 0, + num_projects_vulnerable integer NOT NULL DEFAULT 0, -- XXX: replaces *_per_repo -- packages, projects, projects_newest, projects_outdated, projects_problematic @@ -360,6 +362,7 @@ CREATE TABLE repositories ( num_packages_untrusted integer NOT NULL DEFAULT 0, num_packages_noscheme integer NOT NULL DEFAULT 0, num_packages_rolling integer NOT NULL DEFAULT 0, + num_packages_vulnerable integer NOT NULL DEFAULT 0, num_metapackages integer NOT NULL DEFAULT 0, num_metapackages_unique integer NOT NULL DEFAULT 0, @@ -367,6 +370,7 @@ CREATE TABLE repositories ( num_metapackages_outdated integer NOT NULL DEFAULT 0, num_metapackages_comparable integer NOT NULL DEFAULT 0, num_metapackages_problematic integer NOT NULL DEFAULT 0, + num_metapackages_vulnerable integer NOT NULL DEFAULT 0, num_problems integer NOT NULL DEFAULT 0, num_maintainers integer NOT NULL DEFAULT 0, diff --git a/sql.d/update/update_maintainers.sql b/sql.d/update/update_maintainers.sql index 0c6b75a9d..c1df3acd8 100644 --- a/sql.d/update/update_maintainers.sql +++ b/sql.d/update/update_maintainers.sql @@ -35,11 +35,13 @@ WITH old AS ( count(*) FILTER (WHERE versionclass = 8) AS num_packages_untrusted, count(*) FILTER (WHERE versionclass = 9) AS num_packages_noscheme, count(*) FILTER (WHERE versionclass = 10) AS num_packages_rolling, + count(*) FILTER (WHERE (flags & (1 << 16))::boolean) AS num_packages_vulnerable, count(DISTINCT effname) AS num_projects, count(DISTINCT effname) FILTER(WHERE versionclass = 1 OR versionclass = 4 OR versionclass = 5) AS num_projects_newest, count(DISTINCT effname) FILTER(WHERE versionclass = 2) AS num_projects_outdated, - count(DISTINCT effname) FILTER(WHERE versionclass = 3 OR versionclass = 7 OR versionclass = 8) AS num_projects_problematic + count(DISTINCT effname) FILTER(WHERE versionclass = 3 OR versionclass = 7 OR versionclass = 8) AS num_projects_problematic, + count(DISTINCT effname) FILTER(WHERE (flags & (1 << 16))::boolean) AS num_projects_vulnerable FROM old_packages GROUP BY maintainer_name ), new AS ( @@ -57,11 +59,13 @@ WITH old AS ( count(*) FILTER (WHERE versionclass = 8) AS num_packages_untrusted, count(*) FILTER (WHERE versionclass = 9) AS num_packages_noscheme, count(*) FILTER (WHERE versionclass = 10) AS num_packages_rolling, + count(*) FILTER (WHERE (flags & (1 << 16))::boolean) AS num_packages_vulnerable, count(DISTINCT effname) AS num_projects, count(DISTINCT effname) FILTER(WHERE versionclass = 1 OR versionclass = 4 OR versionclass = 5) AS num_projects_newest, count(DISTINCT effname) FILTER(WHERE versionclass = 2) AS num_projects_outdated, - count(DISTINCT effname) FILTER(WHERE versionclass = 3 OR versionclass = 7 OR versionclass = 8) AS num_projects_problematic + count(DISTINCT effname) FILTER(WHERE versionclass = 3 OR versionclass = 7 OR versionclass = 8) AS num_projects_problematic, + count(DISTINCT effname) FILTER(WHERE (flags & (1 << 16))::boolean) AS num_projects_vulnerable FROM incoming_packages GROUP BY maintainer_name ) @@ -78,11 +82,13 @@ SET num_packages_untrusted = maintainers.num_packages_untrusted + coalesce(new.num_packages_untrusted, 0) - coalesce(old.num_packages_untrusted, 0), num_packages_noscheme = maintainers.num_packages_noscheme + coalesce(new.num_packages_noscheme, 0) - coalesce(old.num_packages_noscheme, 0), num_packages_rolling = maintainers.num_packages_rolling + coalesce(new.num_packages_rolling, 0) - coalesce(old.num_packages_rolling, 0), + num_packages_vulnerable = maintainers.num_packages_vulnerable + coalesce(new.num_packages_vulnerable, 0) - coalesce(old.num_packages_vulnerable, 0), num_projects = maintainers.num_projects + coalesce(new.num_projects, 0) - coalesce(old.num_projects, 0), num_projects_newest = maintainers.num_projects_newest + coalesce(new.num_projects_newest, 0) - coalesce(old.num_projects_newest, 0), num_projects_outdated = maintainers.num_projects_outdated + coalesce(new.num_projects_outdated, 0) - coalesce(old.num_projects_outdated, 0), num_projects_problematic = maintainers.num_projects_problematic + coalesce(new.num_projects_problematic, 0) - coalesce(old.num_projects_problematic, 0), + num_projects_vulnerable = maintainers.num_projects_vulnerable + coalesce(new.num_projects_vulnerable, 0) - coalesce(old.num_projects_vulnerable, 0), orphaned_at = CASE WHEN maintainers.num_packages + coalesce(new.num_packages, 0) - coalesce(old.num_packages, 0) = 0 THEN now() ELSE NULL END FROM old FULL OUTER JOIN new USING(maintainer_name) @@ -97,7 +103,8 @@ WITH old AS ( count(DISTINCT effname) AS num_projects, count(DISTINCT effname) FILTER (WHERE versionclass = 1 OR versionclass = 4 OR versionclass = 5) AS num_projects_newest, count(DISTINCT effname) FILTER (WHERE versionclass = 2) AS num_projects_outdated, - count(DISTINCT effname) FILTER (WHERE versionclass = 3 OR versionclass = 7 OR versionclass = 8) AS num_projects_problematic + count(DISTINCT effname) FILTER (WHERE versionclass = 3 OR versionclass = 7 OR versionclass = 8) AS num_projects_problematic, + count(DISTINCT effname) FILTER (WHERE (flags & (1 << 16))::boolean) AS num_projects_vulnerable FROM old_packages GROUP BY maintainer_name, repo ), new AS ( @@ -108,7 +115,8 @@ WITH old AS ( count(DISTINCT effname) AS num_projects, count(DISTINCT effname) FILTER (WHERE versionclass = 1 OR versionclass = 4 OR versionclass = 5) AS num_projects_newest, count(DISTINCT effname) FILTER (WHERE versionclass = 2) AS num_projects_outdated, - count(DISTINCT effname) FILTER (WHERE versionclass = 3 OR versionclass = 7 OR versionclass = 8) AS num_projects_problematic + count(DISTINCT effname) FILTER (WHERE versionclass = 3 OR versionclass = 7 OR versionclass = 8) AS num_projects_problematic, + count(DISTINCT effname) FILTER (WHERE (flags & (1 << 16))::boolean) AS num_projects_vulnerable FROM incoming_packages GROUP BY maintainer_name, repo ), delta AS ( @@ -119,14 +127,16 @@ WITH old AS ( coalesce(new.num_projects, 0) - coalesce(old.num_projects, 0) AS num_projects, coalesce(new.num_projects_newest, 0) - coalesce(old.num_projects_newest, 0) AS num_projects_newest, coalesce(new.num_projects_outdated, 0) - coalesce(old.num_projects_outdated, 0) AS num_projects_outdated, - coalesce(new.num_projects_problematic, 0) - coalesce(old.num_projects_problematic, 0) AS num_projects_problematic + coalesce(new.num_projects_problematic, 0) - coalesce(old.num_projects_problematic, 0) AS num_projects_problematic, + coalesce(new.num_projects_vulnerable, 0) - coalesce(old.num_projects_vulnerable, 0) AS num_projects_vulnerable FROM old FULL OUTER JOIN new USING(maintainer_name, repo) WHERE coalesce(new.num_packages, 0) - coalesce(old.num_packages, 0) != 0 OR coalesce(new.num_projects, 0) - coalesce(old.num_projects, 0) != 0 OR coalesce(new.num_projects_newest, 0) - coalesce(old.num_projects_newest, 0) != 0 OR coalesce(new.num_projects_outdated, 0) - coalesce(old.num_projects_outdated, 0) != 0 OR - coalesce(new.num_projects_problematic, 0) - coalesce(old.num_projects_problematic, 0) != 0 + coalesce(new.num_projects_problematic, 0) - coalesce(old.num_projects_problematic, 0) != 0 OR + coalesce(new.num_projects_vulnerable, 0) - coalesce(old.num_projects_vulnerable, 0) != 0 ), old_state AS ( SELECT maintainer AS maintainer_name, @@ -135,7 +145,8 @@ WITH old AS ( ((jsonb_each_text(counts_per_repo)).value::jsonb->>1)::integer AS num_projects, ((jsonb_each_text(counts_per_repo)).value::jsonb->>2)::integer AS num_projects_newest, ((jsonb_each_text(counts_per_repo)).value::jsonb->>3)::integer AS num_projects_outdated, - ((jsonb_each_text(counts_per_repo)).value::jsonb->>4)::integer AS num_projects_problematic + ((jsonb_each_text(counts_per_repo)).value::jsonb->>4)::integer AS num_projects_problematic, + ((jsonb_each_text(counts_per_repo)).value::jsonb->>5)::integer AS num_projects_vulnerable FROM maintainers WHERE maintainer IN (SELECT maintainer_name FROM delta) ), new_state AS ( @@ -146,7 +157,8 @@ WITH old AS ( coalesce(old_state.num_projects, 0) + coalesce(delta.num_projects, 0) AS num_projects, coalesce(old_state.num_projects_newest, 0) + coalesce(delta.num_projects_newest, 0) AS num_projects_newest, coalesce(old_state.num_projects_outdated, 0) + coalesce(delta.num_projects_outdated, 0) AS num_projects_outdated, - coalesce(old_state.num_projects_problematic, 0) + coalesce(delta.num_projects_problematic, 0) AS num_projects_problematic + coalesce(old_state.num_projects_problematic, 0) + coalesce(delta.num_projects_problematic, 0) AS num_projects_problematic, + coalesce(old_state.num_projects_vulnerable, 0) + coalesce(delta.num_projects_vulnerable, 0) AS num_projects_vulnerable FROM old_state FULL OUTER JOIN delta USING(maintainer_name, repo) ) UPDATE maintainers @@ -162,7 +174,8 @@ FROM ( num_projects, num_projects_newest, num_projects_outdated, - num_projects_problematic + num_projects_problematic, + num_projects_vulnerable ) ) FILTER(WHERE num_packages > 0) AS counts_per_repo, count(DISTINCT repo) FILTER(WHERE num_packages > 0) AS num_repos diff --git a/sql.d/update/update_repositories.sql b/sql.d/update/update_repositories.sql index e1b682b1e..1efc1d1a2 100644 --- a/sql.d/update/update_repositories.sql +++ b/sql.d/update/update_repositories.sql @@ -37,6 +37,7 @@ WITH old_countable_projects AS ( sum(num_packages_untrusted) AS num_packages_untrusted, sum(num_packages_noscheme) AS num_packages_noscheme, sum(num_packages_rolling) AS num_packages_rolling, + sum(num_packages_vulnerable) AS num_packages_vulnerable, count(*) AS num_metapackages, count(*) FILTER (WHERE is_unique) AS num_metapackages_unique, @@ -54,7 +55,10 @@ WITH old_countable_projects AS ( num_packages_ignored > 0 OR num_packages_incorrect > 0 OR num_packages_untrusted > 0 - ) AS num_metapackages_problematic + ) AS num_metapackages_problematic, + count(*) FILTER (WHERE + num_packages_vulnerable > 0 + ) AS num_metapackages_vulnerable FROM ( SELECT repo, @@ -69,7 +73,8 @@ WITH old_countable_projects AS ( count(*) FILTER (WHERE versionclass = 7) AS num_packages_incorrect, count(*) FILTER (WHERE versionclass = 8) AS num_packages_untrusted, count(*) FILTER (WHERE versionclass = 9) AS num_packages_noscheme, - count(*) FILTER (WHERE versionclass = 10) AS num_packages_rolling + count(*) FILTER (WHERE versionclass = 10) AS num_packages_rolling, + count(*) FILTER (WHERE (flags & (1 << 16))::boolean) AS num_packages_vulnerable FROM old_packages GROUP BY repo, effname ) AS tmp INNER JOIN old_countable_projects USING(effname) @@ -95,6 +100,7 @@ WITH old_countable_projects AS ( sum(num_packages_untrusted) AS num_packages_untrusted, sum(num_packages_noscheme) AS num_packages_noscheme, sum(num_packages_rolling) AS num_packages_rolling, + sum(num_packages_vulnerable) AS num_packages_vulnerable, count(*) AS num_metapackages, count(*) FILTER (WHERE is_unique) AS num_metapackages_unique, @@ -112,7 +118,10 @@ WITH old_countable_projects AS ( num_packages_ignored > 0 OR num_packages_incorrect > 0 OR num_packages_untrusted > 0 - ) AS num_metapackages_problematic + ) AS num_metapackages_problematic, + count(*) FILTER (WHERE + num_packages_vulnerable > 0 + ) AS num_metapackages_vulnerable FROM ( SELECT repo, @@ -127,7 +136,8 @@ WITH old_countable_projects AS ( count(*) FILTER (WHERE versionclass = 7) AS num_packages_incorrect, count(*) FILTER (WHERE versionclass = 8) AS num_packages_untrusted, count(*) FILTER (WHERE versionclass = 9) AS num_packages_noscheme, - count(*) FILTER (WHERE versionclass = 10) AS num_packages_rolling + count(*) FILTER (WHERE versionclass = 10) AS num_packages_rolling, + count(*) FILTER (WHERE (flags & (1 << 16))::boolean) AS num_packages_vulnerable FROM incoming_packages GROUP BY repo, effname ) AS tmp INNER JOIN new_countable_projects USING(effname) @@ -147,13 +157,15 @@ WITH old_countable_projects AS ( coalesce(new.num_packages_untrusted, 0) - coalesce(old.num_packages_untrusted, 0) AS num_packages_untrusted, coalesce(new.num_packages_noscheme, 0) - coalesce(old.num_packages_noscheme, 0) AS num_packages_noscheme, coalesce(new.num_packages_rolling, 0) - coalesce(old.num_packages_rolling, 0) AS num_packages_rolling, + coalesce(new.num_packages_vulnerable, 0) - coalesce(old.num_packages_vulnerable, 0) AS num_packages_vulnerable, coalesce(new.num_metapackages, 0) - coalesce(old.num_metapackages, 0) AS num_metapackages, coalesce(new.num_metapackages_unique, 0) - coalesce(old.num_metapackages_unique, 0) AS num_metapackages_unique, coalesce(new.num_metapackages_newest, 0) - coalesce(old.num_metapackages_newest, 0) AS num_metapackages_newest, coalesce(new.num_metapackages_outdated, 0) - coalesce(old.num_metapackages_outdated, 0) AS num_metapackages_outdated, coalesce(new.num_metapackages_comparable, 0) - coalesce(old.num_metapackages_comparable, 0) AS num_metapackages_comparable, - coalesce(new.num_metapackages_problematic, 0) - coalesce(old.num_metapackages_problematic, 0) AS num_metapackages_problematic + coalesce(new.num_metapackages_problematic, 0) - coalesce(old.num_metapackages_problematic, 0) AS num_metapackages_problematic, + coalesce(new.num_metapackages_vulnerable, 0) - coalesce(old.num_metapackages_vulnerable, 0) AS num_metapackages_vulnerable FROM old FULL OUTER JOIN new USING(repo) ) UPDATE repositories @@ -169,13 +181,15 @@ SET num_packages_untrusted = repositories.num_packages_untrusted + delta.num_packages_untrusted, num_packages_noscheme = repositories.num_packages_noscheme + delta.num_packages_noscheme, num_packages_rolling = repositories.num_packages_rolling + delta.num_packages_rolling, + num_packages_vulnerable = repositories.num_packages_vulnerable + delta.num_packages_vulnerable, num_metapackages = repositories.num_metapackages + delta.num_metapackages, num_metapackages_unique = repositories.num_metapackages_unique + delta.num_metapackages_unique, num_metapackages_newest = repositories.num_metapackages_newest + delta.num_metapackages_newest, num_metapackages_outdated = repositories.num_metapackages_outdated + delta.num_metapackages_outdated, num_metapackages_comparable = repositories.num_metapackages_comparable + delta.num_metapackages_comparable, - num_metapackages_problematic = repositories.num_metapackages_problematic + delta.num_metapackages_problematic + num_metapackages_problematic = repositories.num_metapackages_problematic + delta.num_metapackages_problematic, + num_metapackages_vulnerable = repositories.num_metapackages_vulnerable + delta.num_metapackages_vulnerable FROM delta WHERE repositories.name = delta.repo;