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:
parent
7cb508eb8a
commit
c1a59dc4a6
|
@ -2,27 +2,83 @@ BEGIN TRANSACTION;
|
||||||
|
|
||||||
DROP FUNCTION IF EXISTS search_posts;
|
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)
|
CREATE OR REPLACE FUNCTION search_posts(search_text text)
|
||||||
RETURNS TABLE (
|
RETURNS SETOF catalog_grid_result AS $$
|
||||||
post posts,
|
WITH
|
||||||
pathpart text,
|
query AS (
|
||||||
board_thread_id bigint,
|
|
||||||
relevance double precision
|
|
||||||
) AS $$
|
|
||||||
WITH query AS (
|
|
||||||
SELECT websearch_to_tsquery('english', search_text) AS query
|
SELECT websearch_to_tsquery('english', search_text) AS query
|
||||||
)
|
),
|
||||||
SELECT p::posts AS post, pathpart, board_thread_id,
|
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)
|
ts_rank(p.body_search_index, query.query)
|
||||||
/ (1 + EXTRACT(EPOCH FROM AGE(p.creation_time)) / (3600 * 24)) AS relevance
|
/ (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
|
FROM posts p
|
||||||
WHERE p.body_search_index @@ query.query
|
JOIN threads ON threads.thread_id = p.thread_id
|
||||||
ORDER BY relevance
|
JOIN boards ON boards.board_id = threads.board_id
|
||||||
DESC
|
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;
|
$$ LANGUAGE sql STABLE;
|
||||||
|
|
||||||
GRANT EXECUTE ON FUNCTION search_posts TO chan_archive_anon;
|
GRANT EXECUTE ON FUNCTION search_posts TO chan_archive_anon;
|
||||||
GRANT EXECUTE ON FUNCTION search_posts TO chan_archiver;
|
GRANT EXECUTE ON FUNCTION search_posts TO chan_archiver;
|
||||||
REVOKE EXECUTE ON FUNCTION search_posts FROM PUBLIC;
|
REVOKE EXECUTE ON FUNCTION search_posts FROM PUBLIC;
|
||||||
|
|
||||||
ROLLBACK;
|
COMMIT;
|
||||||
|
|
|
@ -16,6 +16,7 @@ DROP TABLE IF EXISTS boards CASCADE;
|
||||||
DROP TABLE IF EXISTS threads CASCADE;
|
DROP TABLE IF EXISTS threads CASCADE;
|
||||||
DROP TABLE IF EXISTS posts CASCADE;
|
DROP TABLE IF EXISTS posts CASCADE;
|
||||||
DROP TABLE IF EXISTS attachments 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 update_post_body_search_index;
|
||||||
DROP FUNCTION IF EXISTS fetch_top_threads;
|
DROP FUNCTION IF EXISTS fetch_top_threads;
|
||||||
DROP FUNCTION IF EXISTS fetch_catalog;
|
DROP FUNCTION IF EXISTS fetch_catalog;
|
||||||
|
@ -218,8 +219,8 @@ AS $$
|
||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION fetch_catalog(max_time timestamptz, max_row_read int DEFAULT 10000)
|
CREATE TYPE catalog_grid_result AS
|
||||||
RETURNS TABLE (
|
(
|
||||||
-- post_count bigint,
|
-- post_count bigint,
|
||||||
estimated_post_count bigint,
|
estimated_post_count bigint,
|
||||||
post_id bigint,
|
post_id bigint,
|
||||||
|
@ -239,7 +240,11 @@ RETURNS TABLE (
|
||||||
file_name text,
|
file_name text,
|
||||||
file_extension text,
|
file_extension text,
|
||||||
file_thumb_extension text
|
file_thumb_extension text
|
||||||
) AS $$
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION fetch_catalog(max_time timestamptz, max_row_read int DEFAULT 10000)
|
||||||
|
RETURNS SETOF catalog_grid_result AS $$
|
||||||
WITH
|
WITH
|
||||||
top AS
|
top AS
|
||||||
(
|
(
|
||||||
|
@ -292,7 +297,7 @@ RETURNS TABLE (
|
||||||
JOIN threads ON op_posts.thread_id = threads.thread_id
|
JOIN threads ON op_posts.thread_id = threads.thread_id
|
||||||
JOIN boards ON threads.board_id = boards.board_id
|
JOIN boards ON threads.board_id = boards.board_id
|
||||||
JOIN sites ON sites.site_id = boards.site_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;
|
ORDER BY bump_time DESC;
|
||||||
$$ LANGUAGE sql;
|
$$ LANGUAGE sql;
|
||||||
|
|
||||||
|
|
|
@ -1,9 +1,10 @@
|
||||||
BEGIN TRANSACTION;
|
BEGIN TRANSACTION;
|
||||||
|
|
||||||
|
DROP TYPE IF EXISTS catalog_grid_result CASCADE;
|
||||||
DROP FUNCTION IF EXISTS fetch_catalog;
|
DROP FUNCTION IF EXISTS fetch_catalog;
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION fetch_catalog(max_time timestamptz, max_row_read int DEFAULT 10000)
|
CREATE TYPE catalog_grid_result AS
|
||||||
RETURNS TABLE (
|
(
|
||||||
-- post_count bigint,
|
-- post_count bigint,
|
||||||
estimated_post_count bigint,
|
estimated_post_count bigint,
|
||||||
post_id bigint,
|
post_id bigint,
|
||||||
|
@ -23,7 +24,11 @@ RETURNS TABLE (
|
||||||
file_name text,
|
file_name text,
|
||||||
file_extension text,
|
file_extension text,
|
||||||
file_thumb_extension text
|
file_thumb_extension text
|
||||||
) AS $$
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION fetch_catalog(max_time timestamptz, max_row_read int DEFAULT 10000)
|
||||||
|
RETURNS SETOF catalog_grid_result AS $$
|
||||||
WITH
|
WITH
|
||||||
top AS
|
top AS
|
||||||
(
|
(
|
||||||
|
@ -76,7 +81,7 @@ RETURNS TABLE (
|
||||||
JOIN threads ON op_posts.thread_id = threads.thread_id
|
JOIN threads ON op_posts.thread_id = threads.thread_id
|
||||||
JOIN boards ON threads.board_id = boards.board_id
|
JOIN boards ON threads.board_id = boards.board_id
|
||||||
JOIN sites ON sites.site_id = boards.site_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;
|
ORDER BY bump_time DESC;
|
||||||
$$ LANGUAGE sql;
|
$$ LANGUAGE sql;
|
||||||
|
|
||||||
|
|
Loading…
Reference in New Issue