From: Michael Tremer Date: Sat, 6 Dec 2025 17:10:30 +0000 (+0000) Subject: db: Create some experimental VIEWs for PowerDNS X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=63dbef2156bf5bf1c285538e2d7896ec50680c10;p=dbl.git db: Create some experimental VIEWs for PowerDNS Signed-off-by: Michael Tremer --- diff --git a/src/database.sql b/src/database.sql index c9db7d3..3bb7585 100644 --- a/src/database.sql +++ b/src/database.sql @@ -2,7 +2,7 @@ -- PostgreSQL database dump -- -\restrict 4VzOIUheVtRwzS2rft5XdaUcuWX8KbD2he89e8drg1IaUXy4XXk30HlrSNZUryq +\restrict lKLDtx9usnrI5oagNTAJGCh4DQFB5EhlTwRbiSmcjtxczaiSLvMMmoCJDe8NM1A -- Dumped from database version 17.6 (Debian 17.6-0+deb13u1) -- Dumped by pg_dump version 17.6 (Debian 17.6-0+deb13u1) @@ -19,6 +19,32 @@ SET xmloption = content; SET client_min_messages = warning; SET row_security = off; +-- +-- Name: cryptokeys; Type: VIEW; Schema: public; Owner: - +-- + +CREATE VIEW public.cryptokeys AS + SELECT NULL::integer AS id, + NULL::integer AS domain_id, + NULL::integer AS flags, + NULL::boolean AS active, + NULL::boolean AS published, + NULL::text AS content + WHERE false; + + +-- +-- Name: domainmetadata; Type: VIEW; Schema: public; Owner: - +-- + +CREATE VIEW public.domainmetadata AS + SELECT NULL::integer AS id, + NULL::integer AS domain_id, + NULL::text AS kind, + NULL::text AS content + WHERE false; + + SET default_tablespace = ''; SET default_table_access_method = heap; @@ -40,6 +66,23 @@ CREATE TABLE public.lists ( ); +-- +-- Name: domains; Type: VIEW; Schema: public; Owner: - +-- + +CREATE VIEW public.domains AS + SELECT id, + (slug || '.dnsbl.ipfire.org'::text) AS name, + ''::text AS master, + 0 AS last_check, + 'MASTER'::text AS type, + 0 AS notified_serial, + ''::text AS account, + ''::text AS options, + ''::text AS catalog + FROM public.lists; + + -- -- Name: lists_id_seq; Type: SEQUENCE; Schema: public; Owner: - -- @@ -74,6 +117,69 @@ CREATE TABLE public.source_domains ( ); +-- +-- Name: sources; Type: TABLE; Schema: public; Owner: - +-- + +CREATE TABLE public.sources ( + id integer NOT NULL, + name text NOT NULL, + url text NOT NULL, + created_at timestamp with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, + created_by text NOT NULL, + deleted_at timestamp with time zone, + deleted_by text, + license text NOT NULL, + list_id integer, + last_modified_at timestamp with time zone, + etag text +); + + +-- +-- Name: records; Type: VIEW; Schema: public; Owner: - +-- + +CREATE VIEW public.records AS + WITH records AS ( + SELECT lists.id AS domain_id, + (lists.slug || '.dnsbl.ipfire.org'::text) AS name, + 'SOA'::text AS type, + concat((lists.slug || '.dnsbl.ipfire.org. hostmaster.ipfire.org. '::text), (EXTRACT(epoch FROM COALESCE(lists.updated_at, CURRENT_TIMESTAMP)))::integer, ' 3600 600 3600000 60') AS content, + 60 AS ttl, + 0 AS prio, + false AS disabled, + ''::text AS ordername, + true AS auth + FROM public.lists + UNION ALL + SELECT lists.id AS domain_id, + (((source_domains.name || '.'::text) || lists.slug) || '.dnsbl.ipfire.org'::text) AS name, + 'CNAME'::text AS type, + '.'::text AS content, + 60 AS ttl, + 0 AS prio, + false AS disabled, + ''::text AS ordername, + true AS auth + FROM ((public.source_domains + LEFT JOIN public.sources ON ((source_domains.source_id = sources.id))) + LEFT JOIN public.lists ON ((sources.list_id = lists.id))) + WHERE (source_domains.removed_at IS NULL) + ) + SELECT row_number() OVER (ORDER BY name) AS id, + domain_id, + name, + type, + content, + ttl, + prio, + disabled, + ordername, + auth + FROM records; + + -- -- Name: source_domains_id_seq; Type: SEQUENCE; Schema: public; Owner: - -- @@ -94,23 +200,6 @@ CREATE SEQUENCE public.source_domains_id_seq ALTER SEQUENCE public.source_domains_id_seq OWNED BY public.source_domains.id; --- --- Name: sources; Type: TABLE; Schema: public; Owner: - --- - -CREATE TABLE public.sources ( - id integer NOT NULL, - name text NOT NULL, - url text NOT NULL, - created_at timestamp with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, - created_by text NOT NULL, - deleted_at timestamp with time zone, - deleted_by text, - license text NOT NULL, - list_id integer -); - - -- -- Name: sources_id_seq; Type: SEQUENCE; Schema: public; Owner: - -- @@ -217,5 +306,5 @@ ALTER TABLE ONLY public.sources -- PostgreSQL database dump complete -- -\unrestrict 4VzOIUheVtRwzS2rft5XdaUcuWX8KbD2he89e8drg1IaUXy4XXk30HlrSNZUryq +\unrestrict lKLDtx9usnrI5oagNTAJGCh4DQFB5EhlTwRbiSmcjtxczaiSLvMMmoCJDe8NM1A