From: Michael Tremer Date: Tue, 6 Jun 2023 16:18:35 +0000 (+0000) Subject: users: Move disk usage view into the code X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=ce174af5b4ec7b8277ee3a2ba98b781f6f6d2b7c;p=pbs.git users: Move disk usage view into the code Signed-off-by: Michael Tremer --- diff --git a/src/buildservice/users.py b/src/buildservice/users.py index 1a6fc47d..ad800c91 100644 --- a/src/buildservice/users.py +++ b/src/buildservice/users.py @@ -58,6 +58,64 @@ class Users(base.Object): # Initialize thread-local storage 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 + LEFT JOIN + packages ON builds.pkg_id = packages.id + WHERE + builds.deleted_at IS NULL + AND + builds.owner_id IS NOT NULL + + UNION ALL + + -- Build Logs + SELECT + builds.owner_id, + jobs.log_size + FROM + jobs + LEFT 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 def ldap(self): if not hasattr(self.local, "ldap"): diff --git a/src/database.sql b/src/database.sql index a5e18b9d..4d3c26a1 100644 --- a/src/database.sql +++ b/src/database.sql @@ -256,6 +256,63 @@ CREATE TABLE public.repository_builds ( ); +-- +-- Name: packages; Type: TABLE; Schema: public; Owner: - +-- + +CREATE TABLE public.packages ( + id integer NOT NULL, + name text NOT NULL, + evr text NOT NULL, + arch text NOT NULL, + groups text NOT NULL, + packager text, + license text NOT NULL, + url text NOT NULL, + summary text NOT NULL, + description text NOT NULL, + size bigint NOT NULL, + supported_arches text, + uuid uuid NOT NULL, + commit_id integer, + build_id text, + build_host text NOT NULL, + build_time timestamp without time zone NOT NULL, + path text, + filesize bigint NOT NULL, + prerequires text[] DEFAULT ARRAY[]::text[] NOT NULL, + requires text[] DEFAULT ARRAY[]::text[] NOT NULL, + provides text[] DEFAULT ARRAY[]::text[] NOT NULL, + obsoletes text[] DEFAULT ARRAY[]::text[] NOT NULL, + conflicts text[] DEFAULT ARRAY[]::text[] NOT NULL, + recommends text[] DEFAULT ARRAY[]::text[] NOT NULL, + suggests text[] DEFAULT ARRAY[]::text[] NOT NULL, + created_at timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, + digest_type text NOT NULL, + digest bytea NOT NULL, + deleted_at timestamp without time zone, + deleted_by integer, + distro_id integer NOT NULL +); + + +-- +-- Name: uploads; Type: TABLE; Schema: public; Owner: - +-- + +CREATE TABLE public.uploads ( + id integer NOT NULL, + uuid uuid DEFAULT gen_random_uuid() NOT NULL, + user_id integer, + builder_id integer, + filename text NOT NULL, + path text NOT NULL, + size bigint NOT NULL, + created_at timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, + expires_at timestamp without time zone DEFAULT (CURRENT_TIMESTAMP + '24:00:00'::interval) NOT NULL +); + + -- -- Name: build_bugs_id_seq; Type: SEQUENCE; Schema: public; Owner: - -- @@ -627,46 +684,6 @@ CREATE TABLE public.package_files ( ); --- --- Name: packages; Type: TABLE; Schema: public; Owner: - --- - -CREATE TABLE public.packages ( - id integer NOT NULL, - name text NOT NULL, - evr text NOT NULL, - arch text NOT NULL, - groups text NOT NULL, - packager text, - license text NOT NULL, - url text NOT NULL, - summary text NOT NULL, - description text NOT NULL, - size bigint NOT NULL, - supported_arches text, - uuid uuid NOT NULL, - commit_id integer, - build_id text, - build_host text NOT NULL, - build_time timestamp without time zone NOT NULL, - path text, - filesize bigint NOT NULL, - prerequires text[] DEFAULT ARRAY[]::text[] NOT NULL, - requires text[] DEFAULT ARRAY[]::text[] NOT NULL, - provides text[] DEFAULT ARRAY[]::text[] NOT NULL, - obsoletes text[] DEFAULT ARRAY[]::text[] NOT NULL, - conflicts text[] DEFAULT ARRAY[]::text[] NOT NULL, - recommends text[] DEFAULT ARRAY[]::text[] NOT NULL, - suggests text[] DEFAULT ARRAY[]::text[] NOT NULL, - created_at timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, - digest_type text NOT NULL, - digest bytea NOT NULL, - deleted_at timestamp without time zone, - deleted_by integer, - distro_id integer NOT NULL -); - - -- -- Name: package_search_index_generator; Type: VIEW; Schema: public; Owner: - -- @@ -1018,23 +1035,6 @@ CREATE SEQUENCE public.sources_id_seq ALTER SEQUENCE public.sources_id_seq OWNED BY public.sources.id; --- --- Name: uploads; Type: TABLE; Schema: public; Owner: - --- - -CREATE TABLE public.uploads ( - id integer NOT NULL, - uuid uuid DEFAULT gen_random_uuid() NOT NULL, - user_id integer, - builder_id integer, - filename text NOT NULL, - path text NOT NULL, - size bigint NOT NULL, - created_at timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, - expires_at timestamp without time zone DEFAULT (CURRENT_TIMESTAMP + '24:00:00'::interval) NOT NULL -); - - -- -- Name: uploads_id_seq; Type: SEQUENCE; Schema: public; Owner: - -- @@ -1054,35 +1054,6 @@ CREATE SEQUENCE public.uploads_id_seq ALTER SEQUENCE public.uploads_id_seq OWNED BY public.uploads.id; --- --- Name: user_disk_usages; Type: VIEW; Schema: public; Owner: - --- - -CREATE VIEW public.user_disk_usages AS - WITH objects AS ( - SELECT uploads.user_id, - uploads.size - FROM public.uploads - WHERE (uploads.expires_at > CURRENT_TIMESTAMP) - UNION ALL - SELECT builds.owner_id, - packages.size - FROM (public.builds - LEFT JOIN public.packages ON ((builds.pkg_id = packages.id))) - WHERE ((builds.deleted_at IS NULL) AND (builds.owner_id IS NOT NULL)) - UNION ALL - SELECT builds.owner_id, - jobs.log_size - FROM (public.jobs - LEFT JOIN public.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)) - ) - SELECT objects.user_id, - sum(objects.size) AS disk_usage - FROM objects - GROUP BY objects.user_id; - - -- -- Name: user_push_subscriptions; Type: TABLE; Schema: public; Owner: - --