From: Michael Tremer Date: Fri, 21 Jul 2023 09:54:07 +0000 (+0000) Subject: backend: Move temporary tables into CTEs X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=d4ecf08d9c38a71e1061a91098c35c12b96da7a5;p=pbs.git backend: Move temporary tables into CTEs It was a nice idea, but if we want to pool connections, we will only create the temporary tables on one connection with the others losing out. An alternative could have been to create all tables on all connections first, but I suppose that is going to create a lot of unnecessary overhead for short-lived connections. Signed-off-by: Michael Tremer --- diff --git a/src/buildservice/builds.py b/src/buildservice/builds.py index 8a692e77..bd22f117 100644 --- a/src/buildservice/builds.py +++ b/src/buildservice/builds.py @@ -28,27 +28,6 @@ class Builds(base.Object): for row in res: yield Build(self.backend, row.id, data=row) - def init(self): - self.db.execute(""" - CREATE TEMPORARY VIEW build_test_builds AS ( - SELECT - builds.id AS build_id, - test_builds.id AS test_build_id - FROM - builds - JOIN - build_groups ON builds.test_group_id = build_groups.id - JOIN - builds test_builds ON test_builds.build_group_id = build_groups.id - WHERE - builds.deleted_at IS NULL - AND - builds.test IS FALSE - AND - build_groups.deleted_at IS NULL - ) - """) - def __len__(self): res = self.db.get(""" SELECT @@ -1162,6 +1141,24 @@ class Build(base.DataObject): @lazy_property def test_build_for(self): return self.backend.builds._get_build(""" + WITH build_test_builds AS ( + SELECT + builds.id AS build_id, + test_builds.id AS test_build_id + FROM + builds + JOIN + build_groups ON builds.test_group_id = build_groups.id + JOIN + builds test_builds ON test_builds.build_group_id = build_groups.id + WHERE + builds.deleted_at IS NULL + AND + builds.test IS FALSE + AND + build_groups.deleted_at IS NULL + ) + SELECT builds.* FROM diff --git a/src/buildservice/events.py b/src/buildservice/events.py index e4438c0c..163a0b07 100644 --- a/src/buildservice/events.py +++ b/src/buildservice/events.py @@ -55,833 +55,831 @@ log = logging.getLogger("pbs.events") # points # -class Events(base.Object): - def init(self): - # Create events view - self.db.execute(""" - CREATE TEMPORARY VIEW events AS ( - -- Build creation times - SELECT - 'build-created'::text AS type, - builds.created_at AS t, - 4 AS priority, - builds.id AS build, - NULL::integer AS by_build, - NULL::integer AS build_comment, - NULL::integer AS build_group, - NULL::integer AS job, - NULL::text AS package_name, - NULL::integer AS mirror, - NULL::integer AS user, - builds.owner_id AS by_user, - NULL::integer AS builder, - NULL::integer AS repository, - NULL::integer AS release, - NULL::integer AS bug, - NULL::text AS error, - NULL::integer AS points - FROM - builds - - UNION ALL - - -- Build finish/failed times - SELECT - CASE - WHEN builds.failed IS TRUE - THEN 'build-failed'::text - ELSE 'build-finished'::text - END AS type, - builds.finished_at AS t, - CASE - WHEN builds.failed IS TRUE - THEN 8 - ELSE 4 - END AS priority, - builds.id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - NULL AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - builds - WHERE - builds.finished_at IS NOT NULL - - UNION ALL - - -- Deleted Builds - SELECT - 'build-deleted' AS type, - builds.deleted_at AS t, - 4 AS priority, - builds.id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - builds.deleted_by AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - builds - WHERE - builds.deleted_at IS NOT NULL - - UNION ALL - - -- Deprecated Builds - - SELECT - 'build-deprecated' AS type, - builds.deprecated_at AS t, - 4 AS priority, - builds.id AS build, - builds.deprecating_build_id AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - builds.deprecated_by AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - builds - WHERE - builds.deleted_at IS NULL - AND - builds.deprecated_at IS NOT NULL - - UNION ALL - - -- Build Comments - SELECT - 'build-comment' AS type, - build_comments.created_at AS t, - 5 AS priority, - build_comments.build_id AS build, - NULL AS by_build, - build_comments.id AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - build_comments.user_id AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - build_comments - WHERE - deleted IS FALSE - - UNION ALL - - -- Build Watchers added - SELECT - 'build-watcher-added' AS type, - build_watchers.added_at AS t, - 1 AS priority, - build_watchers.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - build_watchers.user_id AS user, - NULL AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - build_watchers - - UNION ALL - - -- Build Watchers removed - SELECT - 'build-watcher-removed' AS type, - build_watchers.deleted_at AS t, - 1 AS priority, - build_watchers.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - build_watchers.user_id AS user, - NULL AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - build_watchers - WHERE - deleted_at IS NOT NULL - - UNION ALL - - -- Bugs added to builds - SELECT - 'build-bug-added' AS type, - build_bugs.added_at AS t, - 4 AS priority, - build_bugs.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - build_bugs.added_by AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - build_bugs.bug_id AS bug, - NULL AS error, - NULL AS points - FROM - build_bugs - - UNION ALL - - -- Bugs removed from builds - - SELECT - 'build-bug-removed' AS type, - build_bugs.removed_at AS t, - 4 AS priority, - build_bugs.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - build_bugs.removed_by AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - build_bugs.bug_id AS bug, - NULL AS error, - NULL AS points - FROM - build_bugs - WHERE - removed_at IS NOT NULL - - UNION ALL - - -- Build added to repository - SELECT - 'repository-build-added' AS type, - repository_builds.added_at AS t, - 5 AS priority, - repository_builds.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - repository_builds.added_by AS by_user, - NULL AS builder, - repository_builds.repo_id AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - repository_builds - - UNION ALL - - -- Build removed from repository - SELECT - 'repository-build-removed' AS type, - repository_builds.removed_at AS t, - 5 AS priority, - repository_builds.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - repository_builds.removed_by AS by_user, - NULL AS builder, - repository_builds.repo_id AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - repository_builds - WHERE - removed_at IS NOT NULL - - UNION ALL - - -- Build Points - - SELECT - 'build-points' AS type, - build_points.created_at AS t, - 1 AS priority, - build_points.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - build_points.user_id AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - build_points.points AS points - FROM - build_points - - UNION ALL - - -- Test Builds - SELECT - CASE WHEN build_groups.failed IS TRUE THEN 'test-builds-failed' - ELSE 'test-builds-succeeded' END AS type, - build_groups.finished_at AS t, - 4 AS priority, - builds.id AS build, - NULL AS by_build, - NULL AS build_comment, - build_groups.id AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - NULL AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - builds - JOIN - build_groups ON builds.test_group_id = build_groups.id - WHERE - builds.deleted_at IS NULL - AND - build_groups.deleted_at IS NULL - AND - build_groups.finished_at IS NOT NULL - - UNION ALL - - -- Jobs Creations - SELECT - 'job-created' AS type, - jobs.created_at AS t, - 1 AS priority, - jobs.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - jobs.id AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - NULL AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - jobs - WHERE - jobs.deleted_at IS NULL - - UNION ALL - - -- Failed Jobs - SELECT - 'job-failed' AS type, - jobs.finished_at AS t, - 5 AS priority, - jobs.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - jobs.id AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - NULL AS by_user, - jobs.builder_id AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - jobs - WHERE - jobs.deleted_at IS NULL - AND - jobs.finished_at IS NOT NULL - AND - jobs.aborted IS FALSE - AND - jobs.failed IS TRUE - - UNION ALL - - -- Finished Jobs - SELECT - 'job-finished' AS type, - jobs.finished_at AS t, - 4 AS priority, - jobs.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - jobs.id AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - NULL AS by_user, - jobs.builder_id AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - jobs - WHERE - jobs.deleted_at IS NULL - AND - jobs.finished_at IS NOT NULL - AND - jobs.aborted IS FALSE - AND - jobs.failed IS FALSE - - UNION ALL - - -- Aborted Jobs - SELECT - 'job-aborted' AS type, - jobs.finished_at AS t, - 4 AS priority, - jobs.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - jobs.id AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - jobs.aborted_by AS by_user, - jobs.builder_id AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - jobs - WHERE - jobs.deleted_at IS NULL - AND - jobs.aborted IS TRUE - - UNION ALL - - -- Dispatched Jobs - SELECT - 'job-dispatched' AS type, - jobs.started_at AS t, - 1 AS priority, - jobs.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - jobs.id AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - NULL AS by_user, - jobs.builder_id AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - jobs - WHERE - jobs.deleted_at IS NULL - AND - jobs.started_at IS NOT NULL - - UNION ALL - - -- Retried jobs - SELECT - 'job-retry' AS type, - jobs.created_at AS t, - 4 AS priority, - jobs.build_id AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - jobs.id AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - NULL AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - jobs - JOIN - jobs superseeded_jobs ON superseeded_jobs.superseeded_by = jobs.id - WHERE - jobs.deleted_at IS NULL - - UNION ALL - - -- Builders Created - SELECT - 'builder-created' AS type, - builders.created_at AS t, - 5 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - builders.created_by AS by_user, - builders.id AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - builders - - UNION ALL - - -- Builders Deleted - SELECT - 'builder-deleted' AS type, - builders.deleted_at AS t, - 5 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - builders.deleted_by AS by_user, - builders.id AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - builders - WHERE - builders.deleted_at IS NOT NULL - - UNION ALL - - -- Releases Created - SELECT - 'release-created' AS type, - releases.created_at AS t, - 1 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - releases.created_by AS by_user, - NULL AS builder, - NULL AS repository, - releases.id AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - releases - - UNION ALL - - -- Releases Deleted - SELECT - 'release-deleted' AS type, - releases.deleted_at AS t, - 1 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - releases.deleted_by AS by_user, - NULL AS builder, - NULL AS repository, - releases.id AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - releases - WHERE - deleted_at IS NOT NULL - - UNION ALL - - -- Releases Published - SELECT - 'release-published' AS type, - releases.published_at AS t, - CASE WHEN releases.stable IS TRUE - THEN 5 ELSE 4 END AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - NULL AS mirror, - NULL AS user, - NULL AS by_user, - NULL AS builder, - NULL AS repository, - releases.id AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - releases - WHERE - published_at IS NOT NULL - AND - published_at <= CURRENT_TIMESTAMP - - UNION ALL - - -- Mirrors Created - SELECT - 'mirror-created' AS type, - mirrors.created_at AS t, - 5 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - mirrors.id AS mirror, - NULL AS user, - mirrors.created_by AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - mirrors - - UNION ALL - - -- Mirrors Deleted - SELECT - 'mirror-deleted' AS type, - mirrors.deleted_at AS t, - 5 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - mirrors.id AS mirror, - NULL AS user, - mirrors.deleted_by AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - mirrors - WHERE - deleted_at IS NOT NULL - - UNION ALL - - -- Mirror Status Changes - SELECT - CASE - WHEN mirror_status_changes.new_status IS TRUE - THEN 'mirror-online' - WHEN mirror_status_changes.new_status IS FALSE - THEN 'mirror-offline' - END AS type, - mirror_status_changes.checked_at AS t, - 4 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - NULL AS package_name, - mirror_status_changes.mirror_id AS mirror, - NULL AS user, - NULL AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - mirror_status_changes.error AS error, - NULL AS points - FROM ( - SELECT - mirror_checks.mirror_id AS mirror_id, - mirror_checks.checked_at AS checked_at, - mirror_checks.success AS new_status, - LAG(success) OVER ( - PARTITION BY mirror_id - ORDER BY checked_at ASC - ) AS old_status, - mirror_checks.error AS error - FROM - mirror_checks - ) mirror_status_changes - WHERE - mirror_status_changes.old_status <> mirror_status_changes.new_status - - UNION ALL - - -- Release Monitoring Created - SELECT - 'release-monitoring-created' AS type, - release_monitorings.created_at AS t, - 4 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - release_monitorings.name AS package_name, - NULL AS mirror, - NULL AS user, - release_monitorings.created_by AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - release_monitorings - - UNION ALL - - -- Release Monitoring Deleted - SELECT - 'release-monitoring-deleted' AS type, - release_monitorings.deleted_at AS t, - 4 AS priority, - NULL AS build, - NULL AS by_build, - NULL AS build_comment, - NULL AS build_group, - NULL AS job, - release_monitorings.name AS package_name, - NULL AS mirror, - NULL AS user, - release_monitorings.deleted_by AS by_user, - NULL AS builder, - NULL AS repository, - NULL AS release, - NULL AS bug, - NULL AS error, - NULL AS points - FROM - release_monitorings - WHERE - deleted_at IS NOT NULL - ) - """) +EVENTS_CTE = """ + WITH events AS ( + -- Build creation times + SELECT + 'build-created'::text AS type, + builds.created_at AS t, + 4 AS priority, + builds.id AS build, + NULL::integer AS by_build, + NULL::integer AS build_comment, + NULL::integer AS build_group, + NULL::integer AS job, + NULL::text AS package_name, + NULL::integer AS mirror, + NULL::integer AS user, + builds.owner_id AS by_user, + NULL::integer AS builder, + NULL::integer AS repository, + NULL::integer AS release, + NULL::integer AS bug, + NULL::text AS error, + NULL::integer AS points + FROM + builds + + UNION ALL + + -- Build finish/failed times + SELECT + CASE + WHEN builds.failed IS TRUE + THEN 'build-failed'::text + ELSE 'build-finished'::text + END AS type, + builds.finished_at AS t, + CASE + WHEN builds.failed IS TRUE + THEN 8 + ELSE 4 + END AS priority, + builds.id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + NULL AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + builds + WHERE + builds.finished_at IS NOT NULL + + UNION ALL + + -- Deleted Builds + SELECT + 'build-deleted' AS type, + builds.deleted_at AS t, + 4 AS priority, + builds.id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + builds.deleted_by AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + builds + WHERE + builds.deleted_at IS NOT NULL + + UNION ALL + + -- Deprecated Builds + + SELECT + 'build-deprecated' AS type, + builds.deprecated_at AS t, + 4 AS priority, + builds.id AS build, + builds.deprecating_build_id AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + builds.deprecated_by AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + builds + WHERE + builds.deleted_at IS NULL + AND + builds.deprecated_at IS NOT NULL + + UNION ALL + + -- Build Comments + SELECT + 'build-comment' AS type, + build_comments.created_at AS t, + 5 AS priority, + build_comments.build_id AS build, + NULL AS by_build, + build_comments.id AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + build_comments.user_id AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + build_comments + WHERE + deleted IS FALSE + + UNION ALL + + -- Build Watchers added + SELECT + 'build-watcher-added' AS type, + build_watchers.added_at AS t, + 1 AS priority, + build_watchers.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + build_watchers.user_id AS user, + NULL AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + build_watchers + + UNION ALL + + -- Build Watchers removed + SELECT + 'build-watcher-removed' AS type, + build_watchers.deleted_at AS t, + 1 AS priority, + build_watchers.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + build_watchers.user_id AS user, + NULL AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + build_watchers + WHERE + deleted_at IS NOT NULL + + UNION ALL + + -- Bugs added to builds + SELECT + 'build-bug-added' AS type, + build_bugs.added_at AS t, + 4 AS priority, + build_bugs.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + build_bugs.added_by AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + build_bugs.bug_id AS bug, + NULL AS error, + NULL AS points + FROM + build_bugs + + UNION ALL + + -- Bugs removed from builds + + SELECT + 'build-bug-removed' AS type, + build_bugs.removed_at AS t, + 4 AS priority, + build_bugs.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + build_bugs.removed_by AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + build_bugs.bug_id AS bug, + NULL AS error, + NULL AS points + FROM + build_bugs + WHERE + removed_at IS NOT NULL + + UNION ALL + + -- Build added to repository + SELECT + 'repository-build-added' AS type, + repository_builds.added_at AS t, + 5 AS priority, + repository_builds.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + repository_builds.added_by AS by_user, + NULL AS builder, + repository_builds.repo_id AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + repository_builds + + UNION ALL + + -- Build removed from repository + SELECT + 'repository-build-removed' AS type, + repository_builds.removed_at AS t, + 5 AS priority, + repository_builds.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + repository_builds.removed_by AS by_user, + NULL AS builder, + repository_builds.repo_id AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + repository_builds + WHERE + removed_at IS NOT NULL + + UNION ALL + + -- Build Points + + SELECT + 'build-points' AS type, + build_points.created_at AS t, + 1 AS priority, + build_points.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + build_points.user_id AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + build_points.points AS points + FROM + build_points + + UNION ALL + + -- Test Builds + SELECT + CASE WHEN build_groups.failed IS TRUE THEN 'test-builds-failed' + ELSE 'test-builds-succeeded' END AS type, + build_groups.finished_at AS t, + 4 AS priority, + builds.id AS build, + NULL AS by_build, + NULL AS build_comment, + build_groups.id AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + NULL AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + builds + JOIN + build_groups ON builds.test_group_id = build_groups.id + WHERE + builds.deleted_at IS NULL + AND + build_groups.deleted_at IS NULL + AND + build_groups.finished_at IS NOT NULL + + UNION ALL + + -- Jobs Creations + SELECT + 'job-created' AS type, + jobs.created_at AS t, + 1 AS priority, + jobs.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + jobs.id AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + NULL AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + jobs + WHERE + jobs.deleted_at IS NULL + + UNION ALL + + -- Failed Jobs + SELECT + 'job-failed' AS type, + jobs.finished_at AS t, + 5 AS priority, + jobs.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + jobs.id AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + NULL AS by_user, + jobs.builder_id AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + jobs + WHERE + jobs.deleted_at IS NULL + AND + jobs.finished_at IS NOT NULL + AND + jobs.aborted IS FALSE + AND + jobs.failed IS TRUE + + UNION ALL + + -- Finished Jobs + SELECT + 'job-finished' AS type, + jobs.finished_at AS t, + 4 AS priority, + jobs.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + jobs.id AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + NULL AS by_user, + jobs.builder_id AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + jobs + WHERE + jobs.deleted_at IS NULL + AND + jobs.finished_at IS NOT NULL + AND + jobs.aborted IS FALSE + AND + jobs.failed IS FALSE + + UNION ALL + + -- Aborted Jobs + SELECT + 'job-aborted' AS type, + jobs.finished_at AS t, + 4 AS priority, + jobs.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + jobs.id AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + jobs.aborted_by AS by_user, + jobs.builder_id AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + jobs + WHERE + jobs.deleted_at IS NULL + AND + jobs.aborted IS TRUE + + UNION ALL + + -- Dispatched Jobs + SELECT + 'job-dispatched' AS type, + jobs.started_at AS t, + 1 AS priority, + jobs.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + jobs.id AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + NULL AS by_user, + jobs.builder_id AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + jobs + WHERE + jobs.deleted_at IS NULL + AND + jobs.started_at IS NOT NULL + + UNION ALL + + -- Retried jobs + SELECT + 'job-retry' AS type, + jobs.created_at AS t, + 4 AS priority, + jobs.build_id AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + jobs.id AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + NULL AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + jobs + JOIN + jobs superseeded_jobs ON superseeded_jobs.superseeded_by = jobs.id + WHERE + jobs.deleted_at IS NULL + + UNION ALL + + -- Builders Created + SELECT + 'builder-created' AS type, + builders.created_at AS t, + 5 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + builders.created_by AS by_user, + builders.id AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + builders + + UNION ALL + + -- Builders Deleted + SELECT + 'builder-deleted' AS type, + builders.deleted_at AS t, + 5 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + builders.deleted_by AS by_user, + builders.id AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + builders + WHERE + builders.deleted_at IS NOT NULL + + UNION ALL + + -- Releases Created + SELECT + 'release-created' AS type, + releases.created_at AS t, + 1 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + releases.created_by AS by_user, + NULL AS builder, + NULL AS repository, + releases.id AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + releases + + UNION ALL + + -- Releases Deleted + SELECT + 'release-deleted' AS type, + releases.deleted_at AS t, + 1 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + releases.deleted_by AS by_user, + NULL AS builder, + NULL AS repository, + releases.id AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + releases + WHERE + deleted_at IS NOT NULL + + UNION ALL + + -- Releases Published + SELECT + 'release-published' AS type, + releases.published_at AS t, + CASE WHEN releases.stable IS TRUE + THEN 5 ELSE 4 END AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + NULL AS mirror, + NULL AS user, + NULL AS by_user, + NULL AS builder, + NULL AS repository, + releases.id AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + releases + WHERE + published_at IS NOT NULL + AND + published_at <= CURRENT_TIMESTAMP + + UNION ALL + + -- Mirrors Created + SELECT + 'mirror-created' AS type, + mirrors.created_at AS t, + 5 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + mirrors.id AS mirror, + NULL AS user, + mirrors.created_by AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + mirrors + + UNION ALL + + -- Mirrors Deleted + SELECT + 'mirror-deleted' AS type, + mirrors.deleted_at AS t, + 5 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + mirrors.id AS mirror, + NULL AS user, + mirrors.deleted_by AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + mirrors + WHERE + deleted_at IS NOT NULL + + UNION ALL + + -- Mirror Status Changes + SELECT + CASE + WHEN mirror_status_changes.new_status IS TRUE + THEN 'mirror-online' + WHEN mirror_status_changes.new_status IS FALSE + THEN 'mirror-offline' + END AS type, + mirror_status_changes.checked_at AS t, + 4 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + NULL AS package_name, + mirror_status_changes.mirror_id AS mirror, + NULL AS user, + NULL AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + mirror_status_changes.error AS error, + NULL AS points + FROM ( + SELECT + mirror_checks.mirror_id AS mirror_id, + mirror_checks.checked_at AS checked_at, + mirror_checks.success AS new_status, + LAG(success) OVER ( + PARTITION BY mirror_id + ORDER BY checked_at ASC + ) AS old_status, + mirror_checks.error AS error + FROM + mirror_checks + ) mirror_status_changes + WHERE + mirror_status_changes.old_status <> mirror_status_changes.new_status + + UNION ALL + + -- Release Monitoring Created + SELECT + 'release-monitoring-created' AS type, + release_monitorings.created_at AS t, + 4 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + release_monitorings.name AS package_name, + NULL AS mirror, + NULL AS user, + release_monitorings.created_by AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + release_monitorings + + UNION ALL + + -- Release Monitoring Deleted + SELECT + 'release-monitoring-deleted' AS type, + release_monitorings.deleted_at AS t, + 4 AS priority, + NULL AS build, + NULL AS by_build, + NULL AS build_comment, + NULL AS build_group, + NULL AS job, + release_monitorings.name AS package_name, + NULL AS mirror, + NULL AS user, + release_monitorings.deleted_by AS by_user, + NULL AS builder, + NULL AS repository, + NULL AS release, + NULL AS bug, + NULL AS error, + NULL AS points + FROM + release_monitorings + WHERE + deleted_at IS NOT NULL + ) +""" +class Events(base.Object): @lazy_property def map(self): return { @@ -990,7 +988,10 @@ class Events(base.Object): values.append(priority) # Fetch all events - events = self.db.query(""" + events = self.db.query( + """ + %s + -- Filter out everything we want SELECT * @@ -1006,7 +1007,7 @@ class Events(base.Object): %%s LIMIT %%s - """ % " AND ".join(conditions) or "TRUE", + """ % (EVENTS_CTE, " AND ".join(conditions) or "TRUE"), *values, offset, limit, ) diff --git a/src/buildservice/jobs.py b/src/buildservice/jobs.py index e8c56d4d..db0c1ebb 100644 --- a/src/buildservice/jobs.py +++ b/src/buildservice/jobs.py @@ -24,41 +24,36 @@ from .errors import * # Setup logging log = logging.getLogger("pbs.jobs") +JOB_QUEUE_CTE = """ + WITH job_queue AS ( + SELECT + jobs.*, + rank() OVER ( + ORDER BY (NOT builds.test), builds.priority DESC, jobs.created_at + ) AS _rank + FROM + jobs + LEFT JOIN + builds ON jobs.build_id = builds.id + WHERE + builds.deleted_at IS NULL + AND + jobs.deleted_at IS NULL + AND + jobs.started_at IS NULL + AND + jobs.finished_at IS NULL + AND + jobs.installcheck_succeeded IS TRUE + ORDER BY + _rank + ) +""" + class Jobs(base.Object): connections = {} def init(self): - self.db.execute(""" - CREATE TEMPORARY VIEW package_estimated_build_times AS - SELECT - packages.name, - jobs.arch, - AVG( - jobs.finished_at - jobs.started_at - ) AS build_time - FROM - jobs - LEFT JOIN - builds ON jobs.build_id = builds.id - LEFT JOIN - packages ON builds.pkg_id = packages.id - WHERE - jobs.deleted_at IS NULL - AND - jobs.started_at IS NOT NULL - AND - jobs.finished_at IS NOT NULL - AND - jobs.failed IS FALSE - AND - builds.test IS FALSE - AND - jobs.finished_at >= (CURRENT_TIMESTAMP - '180 days'::interval) - GROUP BY - packages.name, - jobs.arch - """) - # Setup queue self.queue = Queue(self.backend) @@ -148,32 +143,6 @@ class Queue(base.Object): # Locked when the queue is being processed lock = asyncio.Lock() - def init(self): - self.db.execute(""" - CREATE TEMPORARY VIEW job_queue AS - SELECT - jobs.*, - rank() OVER ( - ORDER BY (NOT builds.test), builds.priority DESC, jobs.created_at - ) AS _rank - FROM - jobs - LEFT JOIN - builds ON jobs.build_id = builds.id - WHERE - builds.deleted_at IS NULL - AND - jobs.deleted_at IS NULL - AND - jobs.started_at IS NULL - AND - jobs.finished_at IS NULL - AND - jobs.installcheck_succeeded IS TRUE - ORDER BY - _rank - """) - def __iter__(self): jobs = self.get_jobs() @@ -181,11 +150,13 @@ class Queue(base.Object): def __len__(self): res = self.db.get(""" + %s + SELECT COUNT(*) AS len FROM job_queue - """) + """ % JOB_QUEUE_CTE) if res: return res.len @@ -194,13 +165,15 @@ class Queue(base.Object): def get_jobs(self, limit=None): jobs = self.backend.jobs._get_jobs(""" + %s + SELECT * FROM job_queue LIMIT - %s - """, limit, + %%s + """ % JOB_QUEUE_CTE, limit, ) return list(jobs) @@ -210,14 +183,16 @@ class Queue(base.Object): Returns the next build job that matches the given architectures """ return self.backend.jobs._get_job(""" + %s + SELECT * FROM job_queue WHERE - job_queue.arch = ANY(%s) + job_queue.arch = ANY(%%s) LIMIT 1 - """, builder.supported_arches, + """ % JOB_QUEUE_CTE, builder.supported_arches, ) async def dispatch(self): @@ -408,6 +383,36 @@ class Job(base.DataObject): Returns the time we expect this job to run for """ res = self.db.get(""" + WITH package_estimated_build_times AS ( + SELECT + packages.name, + jobs.arch, + AVG( + jobs.finished_at - jobs.started_at + ) AS build_time + FROM + jobs + LEFT JOIN + builds ON jobs.build_id = builds.id + LEFT JOIN + packages ON builds.pkg_id = packages.id + WHERE + jobs.deleted_at IS NULL + AND + jobs.started_at IS NOT NULL + AND + jobs.finished_at IS NOT NULL + AND + jobs.failed IS FALSE + AND + builds.test IS FALSE + AND + jobs.finished_at >= (CURRENT_TIMESTAMP - '180 days'::interval) + GROUP BY + packages.name, + jobs.arch + ) + SELECT build_time FROM diff --git a/src/buildservice/packages.py b/src/buildservice/packages.py index 4f22dc56..397355b7 100644 --- a/src/buildservice/packages.py +++ b/src/buildservice/packages.py @@ -34,53 +34,6 @@ class Packages(base.Object): for row in res: yield Package(self.backend, row.id, data=row) - def init(self): - self.db.execute(""" - CREATE TEMPORARY VIEW package_search_index AS ( - -- Source packages - SELECT - packages.id AS package_id, - packages._search AS document - FROM - builds - LEFT JOIN - packages ON builds.pkg_id = packages.id - WHERE - builds.deleted_at IS NULL - AND - builds.test IS FALSE - AND - packages.deleted_at IS NULL - - UNION - - -- Binary Packages - SELECT - source_packages.id AS package_id, - packages._search AS document - FROM - builds - LEFT JOIN - jobs ON builds.id = jobs.build_id - LEFT JOIN - job_packages ON jobs.id = job_packages.job_id - LEFT JOIN - packages ON job_packages.pkg_id = packages.id - LEFT JOIN - packages source_packages ON builds.pkg_id = source_packages.id - WHERE - builds.deleted_at IS NULL - AND - builds.test IS FALSE - AND - jobs.deleted_at IS NULL - AND - packages.deleted_at IS NULL - AND - source_packages.deleted_at IS NULL - ) - """) - def get_list(self): """ Returns a list with all package names and the summary line @@ -233,7 +186,51 @@ class Packages(base.Object): This function does not work for UUIDs or filenames. """ packages = self._get_packages(""" - WITH search AS ( + WITH package_search_index AS ( + -- Source packages + SELECT + packages.id AS package_id, + packages._search AS document + FROM + builds + LEFT JOIN + packages ON builds.pkg_id = packages.id + WHERE + builds.deleted_at IS NULL + AND + builds.test IS FALSE + AND + packages.deleted_at IS NULL + + UNION + + -- Binary Packages + SELECT + source_packages.id AS package_id, + packages._search AS document + FROM + builds + LEFT JOIN + jobs ON builds.id = jobs.build_id + LEFT JOIN + job_packages ON jobs.id = job_packages.job_id + LEFT JOIN + packages ON job_packages.pkg_id = packages.id + LEFT JOIN + packages source_packages ON builds.pkg_id = source_packages.id + WHERE + builds.deleted_at IS NULL + AND + builds.test IS FALSE + AND + jobs.deleted_at IS NULL + AND + packages.deleted_at IS NULL + AND + source_packages.deleted_at IS NULL + ), + + search AS ( SELECT packages.id AS package_id FROM diff --git a/src/buildservice/users.py b/src/buildservice/users.py index c047da8f..c262ec83 100644 --- a/src/buildservice/users.py +++ b/src/buildservice/users.py @@ -59,88 +59,7 @@ class Users(base.Object): self.local = threading.local() self.db.execute(""" - CREATE TEMPORARY VIEW user_disk_usages AS ( - WITH objects AS ( - -- Uploads - SELECT - uploads.user_id, - uploads.size - FROM - uploads - WHERE - uploads.expires_at > CURRENT_TIMESTAMP - - UNION ALL - -- Source Packages - SELECT - builds.owner_id, - packages.size - FROM - builds - JOIN - packages ON builds.pkg_id = packages.id - WHERE - builds.deleted_at IS NULL - AND - builds.owner_id IS NOT NULL - AND - packages.deleted_at IS NULL - - UNION ALL - - -- Binary Packages - SELECT - builds.owner_id, - packages.size - FROM - builds - JOIN - jobs ON builds.id = jobs.build_id - JOIN - job_packages ON jobs.id = job_packages.job_id - JOIN - packages ON job_packages.pkg_id = packages.id - WHERE - builds.deleted_at IS NULL - AND - builds.owner_id IS NOT NULL - AND - builds.test IS FALSE - AND - jobs.deleted_at IS NULL - AND - packages.deleted_at IS NULL - - UNION ALL - - -- Build Logs - SELECT - builds.owner_id, - jobs.log_size - FROM - jobs - JOIN - builds ON builds.id = jobs.build_id - WHERE - builds.deleted_at IS NULL - AND - jobs.deleted_at IS NULL - AND - builds.owner_id IS NOT NULL - AND - jobs.log_size IS NOT NULL - ) - - -- Sum up all objects and group by user ID - SELECT - objects.user_id, - SUM(objects.size) AS disk_usage - FROM - objects - GROUP BY - objects.user_id - ) """) @property @@ -742,6 +661,89 @@ class User(base.DataObject): Returns the total disk usage of this user """ res = self.db.get(""" + WITH user_disk_usages AS ( + WITH objects AS ( + -- Uploads + SELECT + uploads.user_id, + uploads.size + FROM + uploads + WHERE + uploads.expires_at > CURRENT_TIMESTAMP + + UNION ALL + + -- Source Packages + SELECT + builds.owner_id, + packages.size + FROM + builds + JOIN + packages ON builds.pkg_id = packages.id + WHERE + builds.deleted_at IS NULL + AND + builds.owner_id IS NOT NULL + AND + packages.deleted_at IS NULL + + UNION ALL + + -- Binary Packages + SELECT + builds.owner_id, + packages.size + FROM + builds + JOIN + jobs ON builds.id = jobs.build_id + JOIN + job_packages ON jobs.id = job_packages.job_id + JOIN + packages ON job_packages.pkg_id = packages.id + WHERE + builds.deleted_at IS NULL + AND + builds.owner_id IS NOT NULL + AND + builds.test IS FALSE + AND + jobs.deleted_at IS NULL + AND + packages.deleted_at IS NULL + + UNION ALL + + -- Build Logs + SELECT + builds.owner_id, + jobs.log_size + FROM + jobs + JOIN + builds ON builds.id = jobs.build_id + WHERE + builds.deleted_at IS NULL + AND + jobs.deleted_at IS NULL + AND + builds.owner_id IS NOT NULL + AND + jobs.log_size IS NOT NULL + ) + + -- Sum up all objects and group by user ID + SELECT + objects.user_id, + SUM(objects.size) AS disk_usage + FROM + objects + GROUP BY + objects.user_id + ) + SELECT disk_usage FROM