sql: Return the same rows in search as we do in fetch_catalog

- create a new catalog_grid result type that these functions share
This commit is contained in:
towards-a-new-leftypol 2024-03-01 19:25:47 -05:00
parent 7cb508eb8a
commit c1a59dc4a6
3 changed files with 127 additions and 61 deletions

View File

@ -2,27 +2,83 @@ BEGIN TRANSACTION;
DROP FUNCTION IF EXISTS search_posts;
-- CREATE TYPE catalog_grid_result AS
-- (
-- -- post_count bigint,
-- estimated_post_count bigint,
-- post_id bigint,
-- board_post_id bigint,
-- creation_time timestamptz,
-- bump_time timestamptz,
-- body text,
-- subject text,
-- thread_id bigint,
-- embed text,
-- board_thread_id bigint,
-- pathpart text,
-- site_name text,
-- file_mimetype text,
-- file_illegal boolean,
-- -- file_resolution dimension,
-- file_name text,
-- file_extension text,
-- file_thumb_extension text
-- );
CREATE OR REPLACE FUNCTION search_posts(search_text text)
RETURNS TABLE (
post posts,
pathpart text,
board_thread_id bigint,
relevance double precision
) AS $$
WITH query AS (
SELECT websearch_to_tsquery('english', search_text) AS query
)
SELECT p::posts AS post, pathpart, board_thread_id,
ts_rank(p.body_search_index, query.query)
/ (1 + EXTRACT(EPOCH FROM AGE(p.creation_time)) / (3600 * 24)) AS relevance
FROM posts p JOIN threads ON threads.thread_id = p.thread_id JOIN boards ON boards.board_id = threads.board_id, query
WHERE p.body_search_index @@ query.query
ORDER BY relevance
DESC
RETURNS SETOF catalog_grid_result AS $$
WITH
query AS (
SELECT websearch_to_tsquery('english', search_text) AS query
),
result_set AS (
SELECT
p.*,
threads.board_thread_id,
pathpart,
sites.name AS site_name,
attachments.mimetype as file_mimetype,
attachments.illegal as file_illegal,
-- attachments.resolution as file_resolution,
attachments.board_filename as file_name,
attachments.file_extension,
attachments.thumb_extension as file_thumb_extension,
ts_rank(p.body_search_index, query.query)
/ (1 + EXTRACT(EPOCH FROM AGE(p.creation_time)) / (3600 * 24)) AS relevance
FROM posts p
JOIN threads ON threads.thread_id = p.thread_id
JOIN boards ON boards.board_id = threads.board_id
JOIN sites ON sites.site_id = boards.site_id
LEFT OUTER JOIN attachments
ON attachments.post_id = p.post_id
AND attachments.attachment_idx = 1
, query
WHERE p.body_search_index @@ query.query
)
SELECT
0 AS estimated_post_count,
result_set.post_id,
result_set.board_post_id,
result_set.creation_time,
result_set.creation_time AS bump_time,
result_set.body,
result_set.subject,
result_set.thread_id,
result_set.embed,
result_set.board_thread_id,
result_set.pathpart,
result_set.site_name,
result_set.file_mimetype,
result_set.file_illegal,
result_set.file_name,
result_set.file_extension,
result_set.file_thumb_extension
FROM result_set
ORDER BY result_set.relevance DESC;
$$ LANGUAGE sql STABLE;
GRANT EXECUTE ON FUNCTION search_posts TO chan_archive_anon;
GRANT EXECUTE ON FUNCTION search_posts TO chan_archiver;
REVOKE EXECUTE ON FUNCTION search_posts FROM PUBLIC;
ROLLBACK;
COMMIT;

View File

@ -16,6 +16,7 @@ DROP TABLE IF EXISTS boards CASCADE;
DROP TABLE IF EXISTS threads CASCADE;
DROP TABLE IF EXISTS posts CASCADE;
DROP TABLE IF EXISTS attachments CASCADE;
DROP TYPE IF EXISTS catalog_grid_result CASCADE;
DROP FUNCTION IF EXISTS update_post_body_search_index;
DROP FUNCTION IF EXISTS fetch_top_threads;
DROP FUNCTION IF EXISTS fetch_catalog;
@ -218,28 +219,32 @@ AS $$
$$;
CREATE TYPE catalog_grid_result AS
(
-- post_count bigint,
estimated_post_count bigint,
post_id bigint,
board_post_id bigint,
creation_time timestamptz,
bump_time timestamptz,
body text,
subject text,
thread_id bigint,
embed text,
board_thread_id bigint,
pathpart text,
site_name text,
file_mimetype text,
file_illegal boolean,
-- file_resolution dimension,
file_name text,
file_extension text,
file_thumb_extension text
);
CREATE OR REPLACE FUNCTION fetch_catalog(max_time timestamptz, max_row_read int DEFAULT 10000)
RETURNS TABLE (
-- post_count bigint,
estimated_post_count bigint,
post_id bigint,
board_post_id bigint,
creation_time timestamptz,
bump_time timestamptz,
body text,
subject text,
thread_id bigint,
embed text,
board_thread_id bigint,
pathpart text,
site_name text,
file_mimetype text,
file_illegal boolean,
-- file_resolution dimension,
file_name text,
file_extension text,
file_thumb_extension text
) AS $$
RETURNS SETOF catalog_grid_result AS $$
WITH
top AS
(
@ -292,7 +297,7 @@ RETURNS TABLE (
JOIN threads ON op_posts.thread_id = threads.thread_id
JOIN boards ON threads.board_id = boards.board_id
JOIN sites ON sites.site_id = boards.site_id
LEFT OUTER JOIN attachments ON attachments.post_id = op_posts.post_id
LEFT OUTER JOIN attachments ON attachments.post_id = op_posts.post_id AND attachments.attachment_idx = 1
ORDER BY bump_time DESC;
$$ LANGUAGE sql;

View File

@ -1,29 +1,34 @@
BEGIN TRANSACTION;
DROP TYPE IF EXISTS catalog_grid_result CASCADE;
DROP FUNCTION IF EXISTS fetch_catalog;
CREATE TYPE catalog_grid_result AS
(
-- post_count bigint,
estimated_post_count bigint,
post_id bigint,
board_post_id bigint,
creation_time timestamptz,
bump_time timestamptz,
body text,
subject text,
thread_id bigint,
embed text,
board_thread_id bigint,
pathpart text,
site_name text,
file_mimetype text,
file_illegal boolean,
-- file_resolution dimension,
file_name text,
file_extension text,
file_thumb_extension text
);
CREATE OR REPLACE FUNCTION fetch_catalog(max_time timestamptz, max_row_read int DEFAULT 10000)
RETURNS TABLE (
-- post_count bigint,
estimated_post_count bigint,
post_id bigint,
board_post_id bigint,
creation_time timestamptz,
bump_time timestamptz,
body text,
subject text,
thread_id bigint,
embed text,
board_thread_id bigint,
pathpart text,
site_name text,
file_mimetype text,
file_illegal boolean,
-- file_resolution dimension,
file_name text,
file_extension text,
file_thumb_extension text
) AS $$
RETURNS SETOF catalog_grid_result AS $$
WITH
top AS
(
@ -76,7 +81,7 @@ RETURNS TABLE (
JOIN threads ON op_posts.thread_id = threads.thread_id
JOIN boards ON threads.board_id = boards.board_id
JOIN sites ON sites.site_id = boards.site_id
LEFT OUTER JOIN attachments ON attachments.post_id = op_posts.post_id
LEFT OUTER JOIN attachments ON attachments.post_id = op_posts.post_id AND attachments.attachment_idx = 1
ORDER BY bump_time DESC;
$$ LANGUAGE sql;