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 \
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
);
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
--
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
--