]> git.ipfire.org Git - pbs.git/commitdiff
packages: Implement fulltext search
authorMichael Tremer <michael.tremer@ipfire.org>
Wed, 22 Jun 2022 15:11:30 +0000 (15:11 +0000)
committerMichael Tremer <michael.tremer@ipfire.org>
Wed, 22 Jun 2022 15:11:30 +0000 (15:11 +0000)
Signed-off-by: Michael Tremer <michael.tremer@ipfire.org>
src/buildservice/packages.py
src/database.sql

index d265e4db1ea67cd40e0b846c5881913f1cef717c..53acdc77d52fed29d5416b27a76b396523056dde 100644 (file)
@@ -123,22 +123,42 @@ class Packages(base.Object):
 
                print(pkg)
 
+               # Refresh the search index
+               self.refresh_search_index()
+
                return pkg
 
-       def search(self, pattern, limit=None):
+       def search(self, q, limit=None):
                """
                        Searches for packages that do match the query.
 
                        This function does not work for UUIDs or filenames.
                """
-               pattern = "%%%s%%" % pattern
-
-               packages = self._get_packages("SELECT * FROM packages \
-                       WHERE type = %s AND (name LIKE %s OR summary LIKE %s OR description LIKE %s)",
-                       "source", pattern, pattern, pattern)
+               packages = self._get_packages("""
+                       SELECT
+                               packages.*
+                       FROM
+                               package_search_index search_index
+                       LEFT JOIN
+                               packages ON search_index.package_id = packages.id
+                       WHERE
+                               packages.deleted IS FALSE
+                       AND
+                               search_index.document @@ websearch_to_tsquery('english', %s)
+                       ORDER BY
+                               ts_rank(search_index.document, websearch_to_tsquery('english', %s)) DESC
+                       LIMIT %s""",
+                       q, q, limit,
+               )
 
                return list(packages)
 
+       def refresh_search_index(self):
+               """
+                       Updates the search index for packages
+               """
+               self.db.execute("REFRESH MATERIALIZED VIEW package_search_index")
+
        def search_by_filename(self, filename, limit=None):
                query = "SELECT filelists.* FROM filelists \
                        JOIN packages ON filelists.pkg_id = packages.id \
index 103aef5973c4ed3424bdb2c0d2cf4d8c06f864eb..9248b03097eccd78ef68cc4c6c753f20447b2945 100644 (file)
@@ -908,7 +908,9 @@ CREATE TABLE public.packages (
     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
+    suggests text[] DEFAULT ARRAY[]::text[] NOT NULL,
+    created_at timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
+    deleted boolean DEFAULT false NOT NULL
 );
 
 
@@ -938,6 +940,40 @@ ALTER TABLE public.package_estimated_build_times OWNER TO pakfire;
 COMMENT ON VIEW public.package_estimated_build_times IS 'Should add this later: AND jobs.time_finished >= (CURRENT_TIMESTAMP - ''180 days''::interval)';
 
 
+--
+-- Name: package_search_index_generator; Type: VIEW; Schema: public; Owner: pakfire
+--
+
+CREATE VIEW public.package_search_index_generator AS
+ WITH p AS (
+         SELECT DISTINCT ON (packages.name) packages.id,
+            packages.name,
+            packages.summary,
+            packages.description
+           FROM public.packages
+          WHERE ((packages.deleted IS FALSE) AND (packages.arch = 'src'::text))
+          ORDER BY packages.name, packages.created_at DESC
+        )
+ SELECT p.id AS package_id,
+    ((setweight(to_tsvector('simple'::regconfig, p.name), 'A'::"char") || setweight(to_tsvector('english'::regconfig, p.summary), 'B'::"char")) || setweight(to_tsvector('english'::regconfig, p.description), 'C'::"char")) AS document
+   FROM p;
+
+
+ALTER TABLE public.package_search_index_generator OWNER TO pakfire;
+
+--
+-- Name: package_search_index; Type: MATERIALIZED VIEW; Schema: public; Owner: pakfire
+--
+
+CREATE MATERIALIZED VIEW public.package_search_index AS
+ SELECT package_search_index_generator.package_id,
+    package_search_index_generator.document
+   FROM public.package_search_index_generator
+  WITH NO DATA;
+
+
+ALTER TABLE public.package_search_index OWNER TO pakfire;
+
 --
 -- Name: packages_id_seq; Type: SEQUENCE; Schema: public; Owner: pakfire
 --
@@ -2248,6 +2284,20 @@ CREATE INDEX mirrors_checks_sort ON public.mirrors_checks USING btree (mirror_id
 ALTER TABLE public.mirrors_checks CLUSTER ON mirrors_checks_sort;
 
 
+--
+-- Name: package_search_index_unique; Type: INDEX; Schema: public; Owner: pakfire
+--
+
+CREATE UNIQUE INDEX package_search_index_unique ON public.package_search_index USING btree (package_id);
+
+
+--
+-- Name: packages_src_created_at; Type: INDEX; Schema: public; Owner: pakfire
+--
+
+CREATE INDEX packages_src_created_at ON public.packages USING btree (created_at DESC) WHERE ((deleted IS FALSE) AND (arch = 'src'::text));
+
+
 --
 -- Name: repositories_builds_repo_id; Type: INDEX; Schema: public; Owner: pakfire
 --