From: Michael Tremer Date: Wed, 7 Jan 2026 16:34:20 +0000 (+0000) Subject: domains: Realise the history as a view X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=84da458d7283c1c4dafde962a9e5668945d9c5f4;p=dbl.git domains: Realise the history as a view This avoids creating yet another complicated query and we can have a model so that accessing attributes becomes easier. Signed-off-by: Michael Tremer --- diff --git a/src/database.sql b/src/database.sql index c558ecb..28bd738 100644 --- a/src/database.sql +++ b/src/database.sql @@ -2,7 +2,7 @@ -- PostgreSQL database dump -- -\restrict UlXDtiDYC3J9Orwwxchpt98SVYW0RCcdlgObrOC1lbnACOlWKslD8MncEagFndp +\restrict HnyHE9wdHUeukhgNR1DDlycTFTTbv9pygL10rs3e3gZDrAeYEOJZ2ID4FIwBH1T -- Dumped from database version 17.6 (Debian 17.6-0+deb13u1) -- Dumped by pg_dump version 17.6 (Debian 17.6-0+deb13u1) @@ -89,6 +89,66 @@ CREATE TABLE public.domains ( ); +-- +-- Name: domain_events; Type: VIEW; Schema: public; Owner: - +-- + +CREATE VIEW public.domain_events AS + WITH events AS ( + SELECT domains.id, + domains.list_id, + domains.name, + domains.source_id, + domains.added_at AS "timestamp", + 'added'::text AS type, + domains.block, + domains.added_by AS by, + domains.report_add_id AS report_id, + CASE + WHEN domains.block THEN 1 + ELSE 0 + END AS _block, + CASE + WHEN (NOT domains.block) THEN 1 + ELSE 0 + END AS _allow + FROM public.domains + UNION ALL + SELECT domains.id, + domains.list_id, + domains.name, + domains.source_id, + domains.removed_at AS "timestamp", + 'removed'::text AS type, + domains.block, + domains.removed_by AS by, + domains.report_remove_id AS report_id, + CASE + WHEN domains.block THEN '-1'::integer + ELSE 0 + END AS _block, + CASE + WHEN (NOT domains.block) THEN '-1'::integer + ELSE 0 + END AS _allow + FROM public.domains + WHERE (domains.removed_at <> NULL::timestamp with time zone) + ) + SELECT id, + list_id, + name, + source_id, + "timestamp", + type, + block, + by, + report_id, + sum(_block) OVER (PARTITION BY name ORDER BY "timestamp") AS blocks, + sum(_allow) OVER (PARTITION BY name ORDER BY "timestamp") AS allows + FROM events + ORDER BY "timestamp"; + + -- -- Name: domains_id_seq; Type: SEQUENCE; Schema: public; Owner: - -- @@ -451,17 +511,17 @@ CREATE INDEX domains_list_id_added_at ON public.domains USING btree (added_at DE -- --- Name: domains_list_id_name; Type: INDEX; Schema: public; Owner: - +-- Name: domains_list_id_removed_at; Type: INDEX; Schema: public; Owner: - -- -CREATE INDEX domains_list_id_name ON public.domains USING btree (list_id, name); +CREATE INDEX domains_list_id_removed_at ON public.domains USING btree (removed_at DESC) WHERE (removed_at IS NOT NULL); -- --- Name: domains_list_id_removed_at; Type: INDEX; Schema: public; Owner: - +-- Name: domains_name; Type: INDEX; Schema: public; Owner: - -- -CREATE INDEX domains_list_id_removed_at ON public.domains USING btree (removed_at DESC) WHERE (removed_at IS NOT NULL); +CREATE INDEX domains_name ON public.domains USING btree (name); -- @@ -595,5 +655,5 @@ ALTER TABLE ONLY public.sources -- PostgreSQL database dump complete -- -\unrestrict UlXDtiDYC3J9Orwwxchpt98SVYW0RCcdlgObrOC1lbnACOlWKslD8MncEagFndp +\unrestrict HnyHE9wdHUeukhgNR1DDlycTFTTbv9pygL10rs3e3gZDrAeYEOJZ2ID4FIwBH1T diff --git a/src/dnsbl/api/lists.py b/src/dnsbl/api/lists.py index 8085ae5..95b3972 100644 --- a/src/dnsbl/api/lists.py +++ b/src/dnsbl/api/lists.py @@ -23,6 +23,7 @@ import fastapi import pydantic import typing +from .. import domains from .. import lists from .. import reports from .. import sources @@ -86,34 +87,9 @@ def get_list_reports( @router.get("/{list}/domains/{name}") def get_list_domains( name: str, list = fastapi.Depends(get_list_from_path), -): +) -> typing.List[domains.DomainEvent]: # Fetch the domain history - events = list.get_domain_history(name) - - # Return all events - for event in events: - e = { - "timestamp" : event.ts, - "type" : event.type, - "block" : event.block, - } - - # Append the person who has done thiy - if event.by: - e["by"] = event.by - - # Append the source - if event.source_id: - source = backend.sources.get_by_id(event.source_id) - - if source: - e["source"] = source.name - - # Append the report - if event.report: - e["report"] = event.report - - yield e + return list.get_domain_history(name) class CreateReport(pydantic.BaseModel): # Domain diff --git a/src/dnsbl/domains.py b/src/dnsbl/domains.py index 8976d7a..c1a0799 100644 --- a/src/dnsbl/domains.py +++ b/src/dnsbl/domains.py @@ -20,6 +20,7 @@ import datetime import logging +import pydantic import sqlmodel import uuid @@ -132,3 +133,72 @@ class Domain(sqlmodel.SQLModel, database.BackendMixin, table=True): # Log action log.info("%s (block = %s) has been removed from %s" % (self.name, self.block, self.list)) + + +class DomainEvent(sqlmodel.SQLModel, table=True): + """ + This is only a view because the query was becoming too complicated in SQLModel + """ + __tablename__ = "domain_events" + + def __hash__(self): + return hash((self.id, self.timestamp)) + + # ID + id: int = sqlmodel.Field(primary_key=True, foreign_key="domains.id", exclude=True) + + # Domain + domain: Domain = sqlmodel.Relationship() + + # List ID + list_id: int = sqlmodel.Field(foreign_key="lists.id", exclude=True) + + # List + list: "List" = sqlmodel.Relationship() + + # List Slug + @pydantic.computed_field + @property + def list_slug(self) -> str: + if self.list: + return self.list.slug + + # Name + name: str + + # Source ID + source_id: int | None = sqlmodel.Field(foreign_key="sources.id", exclude=True) + + # Source + source: "Source" = sqlmodel.Relationship() + + # Source Name + @pydantic.computed_field + @property + def source_name(self) -> str: + if self.source: + return self.source.name + + # Timestamp + timestamp: datetime.datetime + + # Type + type: str + + # Block? + block: bool + + # By + by: str | None + + # Report ID + report_id: uuid.UUID | None = sqlmodel.Field(foreign_key="reports.id") + + # Report + report: "Report" = sqlmodel.Relationship() + + # Blocks + blocks: int + + # Allows + allows: int diff --git a/src/dnsbl/lists.py b/src/dnsbl/lists.py index 1eef127..373ea87 100644 --- a/src/dnsbl/lists.py +++ b/src/dnsbl/lists.py @@ -740,63 +740,21 @@ class List(sqlmodel.SQLModel, database.BackendMixin, table=True): """ Fetches the history the given domain """ - events = ( - sqlmodel.union_all( - # Fetch all events where a domain has been added - sqlmodel - .select( - domains.Domain.name.label("name"), - domains.Domain.added_at.label("ts"), - sqlmodel.literal("added").label("type"), - domains.Domain.block.label("block"), - domains.Domain.added_by.label("by"), - domains.Domain.source_id.label("source_id"), - domains.Domain.report_add_id.label("report"), - sqlmodel.literal(1).label("delta"), - ). - where( - domains.Domain.list == self, - domains.Domain.name == name, - ), - - # Fetch all events where a domain has been removed - sqlmodel - .select( - domains.Domain.name.label("name"), - domains.Domain.removed_at.label("ts"), - sqlmodel.literal("removed").label("type"), - domains.Domain.block.label("block"), - domains.Domain.removed_by.label("by"), - domains.Domain.source_id.label("source_id"), - domains.Domain.report_remove_id.label("report"), - sqlmodel.literal(-1).label("delta"), - ) - .where( - domains.Domain.list == self, - domains.Domain.name == name, - domains.Domain.removed_at != None, - ) - ) - .cte("events") - ) - - # Order all events chronologically stmt = ( sqlmodel .select( - events.c.ts, - events.c.type, - events.c.block, - events.c.by, - events.c.source_id, - events.c.report, + domains.DomainEvent, + ) + .where( + domains.DomainEvent.list_id == self.id, + domains.DomainEvent.name == name, ) .order_by( - events.c.ts, + domains.DomainEvent.timestamp.desc(), ) ) - return self.backend.db.select(stmt) + return self.backend.db.fetch(stmt) class ListStats(sqlmodel.SQLModel, table=True):