From: Michael Tremer Date: Mon, 5 Jan 2026 14:51:54 +0000 (+0000) Subject: lists: Export domains with a global, unique ID for each domain X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=42a14f468c41a64c4ebdabaf49021c9f92e6626d;p=dbl.git lists: Export domains with a global, unique ID for each domain Signed-off-by: Michael Tremer --- diff --git a/src/database.sql b/src/database.sql index f1d3294..da8a6b7 100644 --- a/src/database.sql +++ b/src/database.sql @@ -2,7 +2,7 @@ -- PostgreSQL database dump -- -\restrict rL7JZX9lefDYCij1ck1YZ9zBYKQONa1UgbdrSppmH7VGwDI2usPtcuRDMxQJwsl +\restrict PmCqBzadGBjf7X81pOnYPHbo4fs9Y3SWPwRhwMTKuXKIZtccpmryrLaLv9R92bW -- Dumped from database version 17.6 (Debian 17.6-0+deb13u1) -- Dumped by pg_dump version 17.6 (Debian 17.6-0+deb13u1) @@ -69,6 +69,35 @@ CREATE TABLE public.checker_domains ( ); +-- +-- Name: domain_unique_ids; Type: TABLE; Schema: public; Owner: - +-- + +CREATE TABLE public.domain_unique_ids ( + id bigint NOT NULL, + name text NOT NULL +); + + +-- +-- Name: domain_unique_ids_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + +CREATE SEQUENCE public.domain_unique_ids_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +-- +-- Name: domain_unique_ids_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: - +-- + +ALTER SEQUENCE public.domain_unique_ids_id_seq OWNED BY public.domain_unique_ids.id; + + -- -- Name: domains; Type: TABLE; Schema: public; Owner: - -- @@ -312,6 +341,13 @@ ALTER SEQUENCE public.sources_id_seq OWNED BY public.sources.id; ALTER TABLE ONLY public.api_keys ALTER COLUMN id SET DEFAULT nextval('public.api_keys_id_seq'::regclass); +-- +-- Name: domain_unique_ids id; Type: DEFAULT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public.domain_unique_ids ALTER COLUMN id SET DEFAULT nextval('public.domain_unique_ids_id_seq'::regclass); + + -- -- Name: domains id; Type: DEFAULT; Schema: public; Owner: - -- @@ -370,6 +406,14 @@ ALTER TABLE ONLY public.checker_domains ADD CONSTRAINT checker_domains_pkey PRIMARY KEY (name); +-- +-- Name: domain_unique_ids domain_unique_ids_pkey; Type: CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public.domain_unique_ids + ADD CONSTRAINT domain_unique_ids_pkey PRIMARY KEY (id); + + -- -- Name: domains domains_pkey; Type: CONSTRAINT; Schema: public; Owner: - -- @@ -433,6 +477,13 @@ ALTER TABLE ONLY public.sources CREATE INDEX api_keys_prefix ON public.api_keys USING btree (prefix) WHERE (deleted_at IS NULL); +-- +-- Name: domain_unique_ids_unique; Type: INDEX; Schema: public; Owner: - +-- + +CREATE UNIQUE INDEX domain_unique_ids_unique ON public.domain_unique_ids USING btree (name); + + -- -- Name: domains_list_id; Type: INDEX; Schema: public; Owner: - -- @@ -585,5 +636,5 @@ ALTER TABLE ONLY public.sources -- PostgreSQL database dump complete -- -\unrestrict rL7JZX9lefDYCij1ck1YZ9zBYKQONa1UgbdrSppmH7VGwDI2usPtcuRDMxQJwsl +\unrestrict PmCqBzadGBjf7X81pOnYPHbo4fs9Y3SWPwRhwMTKuXKIZtccpmryrLaLv9R92bW diff --git a/src/dnsbl/domains.py b/src/dnsbl/domains.py index 0b939ad..94e9812 100644 --- a/src/dnsbl/domains.py +++ b/src/dnsbl/domains.py @@ -104,3 +104,16 @@ 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 DomainUniqueID(sqlmodel.SQLModel, table=True): + __tablename__ = "domain_unique_ids" + + def __str__(self): + return self.name + + # ID + id: int = sqlmodel.Field(primary_key=True) + + # Name + name: str diff --git a/src/dnsbl/lists.py b/src/dnsbl/lists.py index e4c4f27..3f81c4c 100644 --- a/src/dnsbl/lists.py +++ b/src/dnsbl/lists.py @@ -256,10 +256,16 @@ class List(sqlmodel.SQLModel, database.BackendMixin, table=True): sqlmodel .select( blocked_domains.c.name, + domains.DomainUniqueID.id.label("unique_id"), ) .distinct( blocked_domains.c.name, ) + .join( + domains.DomainUniqueID, + domains.DomainUniqueID.name == blocked_domains.c.name, + isouter=True, + ) .where( ~sqlmodel.exists( sqlmodel @@ -275,7 +281,48 @@ class List(sqlmodel.SQLModel, database.BackendMixin, table=True): .cte("listed_domains") ) - return listed_domains + # Create and assign a unique ID to each domain + new_domains_with_unique_ids = ( + sqlalchemy.dialects.postgresql + .insert( + domains.DomainUniqueID, + ) + .from_select( + ["name"], + sqlmodel.select( + listed_domains.c.name, + ) + .where( + listed_domains.c.unique_id == None, + ), + ) + .on_conflict_do_nothing( + index_elements=["name"], + ) + .returning( + domains.DomainUniqueID.name, + domains.DomainUniqueID.id, + ) + .cte("new_domains_with_unique_ids") + ) + + all_domains = ( + sqlmodel + .select( + listed_domains.c.name, + sqlmodel.func.coalesce( + listed_domains.c.unique_id, + new_domains_with_unique_ids.c.id, + ).label("unique_id"), + ) + .join( + new_domains_with_unique_ids, + new_domains_with_unique_ids.c.name == listed_domains.c.name, + isouter=True, + ) + ) + + return all_domains @property def domains(self): @@ -285,7 +332,14 @@ class List(sqlmodel.SQLModel, database.BackendMixin, table=True): stmt = ( sqlmodel .select( - self.__domains.c.name, + domains.DomainUniqueID, + ) + .select_from( + self.__domains, + ) + .join( + domains.DomainUniqueID, + domains.DomainUniqueID.name == self.__domains.c.name, ) )