Add subject and name to posts table text index
This commit is contained in:
parent
c297bae697
commit
2fcd1d0582
|
@ -0,0 +1,6 @@
|
||||||
|
#--header "Authorization: Bearer eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJyb2xlIjoiY2hhbl9hcmNoaXZlciJ9.rGIKZokTDKTuQLIv8138bUby5PELfDipYYIDpJzH02c" \
|
||||||
|
time curl \
|
||||||
|
-v \
|
||||||
|
-H "Content-Type: application/json" \
|
||||||
|
-d '{ "max_time": "2023-10-26", "max_row_read": 1001 }' \
|
||||||
|
-X POST http://localhost:3000/rpc/fetch_catalog
|
|
@ -588,6 +588,20 @@ grouped AS (
|
||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
|
||||||
|
SELECT * FROM posts WHERE body_search_index @@ websearch_to_tsquery('english', 'TRUE CHRISTIAN');
|
||||||
|
SELECT to_tsvector('english', body) FROM posts WHERE board_post_id = 476524;
|
||||||
|
SELECT (setweight(to_tsvector('english', COALESCE(subject, '')), 'A') ||
|
||||||
|
setweight(to_tsvector('english', COALESCE(name, '')), 'B') ||
|
||||||
|
setweight(to_tsvector('english', COALESCE(body, '')), 'C')) FROM posts WHERE board_post_id = 476524;
|
||||||
|
SELECT * FROM posts WHERE board_post_id = 476524;
|
||||||
|
|
||||||
|
UPDATE posts SET subject = NULL WHERE board_post_id = 476524;
|
||||||
|
|
||||||
|
UPDATE posts
|
||||||
|
SET body_search_index = (
|
||||||
|
setweight(to_tsvector('english', COALESCE(subject, '')), 'A') ||
|
||||||
|
setweight(to_tsvector('english', COALESCE(name, '')), 'B') ||
|
||||||
|
setweight(to_tsvector('english', COALESCE(body, '')), 'C')
|
||||||
|
)
|
||||||
|
WHERE board_post_id = 476524;
|
||||||
|
|
||||||
|
|
|
@ -192,6 +192,7 @@ $$ LANGUAGE sql;
|
||||||
|
|
||||||
SELECT * FROM fetch_catalog(NOW() - INTERVAL '1y', 1001);
|
SELECT * FROM fetch_catalog(NOW() - INTERVAL '1y', 1001);
|
||||||
|
|
||||||
|
SELECT * FROM fetch_catalog(NOW(), 2000);
|
||||||
|
|
||||||
-- CREATE INDEX idx_posts_thread_board ON posts (thread_id, board_post_id);
|
-- CREATE INDEX idx_posts_thread_board ON posts (thread_id, board_post_id);
|
||||||
ANALYZE posts;
|
ANALYZE posts;
|
||||||
|
|
|
@ -66,6 +66,9 @@ CREATE TABLE IF NOT EXISTS posts
|
||||||
, board_post_id bigint NOT NULL
|
, board_post_id bigint NOT NULL
|
||||||
, creation_time timestamp with time zone NOT NULL
|
, creation_time timestamp with time zone NOT NULL
|
||||||
, body text
|
, body text
|
||||||
|
, subject text
|
||||||
|
, name text
|
||||||
|
, email text
|
||||||
, body_search_index tsvector
|
, body_search_index tsvector
|
||||||
, thread_id bigint NOT NULL
|
, thread_id bigint NOT NULL
|
||||||
, CONSTRAINT unique_thread_board_id_constraint UNIQUE (thread_id, board_post_id)
|
, CONSTRAINT unique_thread_board_id_constraint UNIQUE (thread_id, board_post_id)
|
||||||
|
@ -80,7 +83,12 @@ CREATE INDEX posts_thread_id_creation_time_idx ON posts (creation_time, thread_i
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION update_post_body_search_index() RETURNS trigger AS $$
|
CREATE OR REPLACE FUNCTION update_post_body_search_index() RETURNS trigger AS $$
|
||||||
BEGIN
|
BEGIN
|
||||||
NEW.body_search_index := to_tsvector('english', NEW.body);
|
NEW.body_search_index :=
|
||||||
|
(
|
||||||
|
setweight(to_tsvector('english', COALESCE(NEW.subject, '')), 'A') ||
|
||||||
|
setweight(to_tsvector('english', COALESCE(NEW.name, '')), 'B') ||
|
||||||
|
setweight(to_tsvector('english', COALESCE(NEW.body, '')), 'C')
|
||||||
|
);
|
||||||
RETURN NEW;
|
RETURN NEW;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$ LANGUAGE plpgsql;
|
||||||
|
@ -157,8 +165,8 @@ to_insert AS (
|
||||||
WHERE s.post_id IS NULL
|
WHERE s.post_id IS NULL
|
||||||
),
|
),
|
||||||
inserted AS (
|
inserted AS (
|
||||||
INSERT INTO posts (board_post_id, creation_time, body, thread_id)
|
INSERT INTO posts (board_post_id, creation_time, body, subject, name, email, thread_id)
|
||||||
SELECT board_post_id, creation_time, body, thread_id
|
SELECT board_post_id, creation_time, body, subject, name, email, thread_id
|
||||||
FROM to_insert
|
FROM to_insert
|
||||||
RETURNING post_id, board_post_id, thread_id
|
RETURNING post_id, board_post_id, thread_id
|
||||||
)
|
)
|
||||||
|
@ -204,6 +212,7 @@ RETURNS TABLE (
|
||||||
board_post_id bigint,
|
board_post_id bigint,
|
||||||
creation_time timestamptz,
|
creation_time timestamptz,
|
||||||
body text,
|
body text,
|
||||||
|
subject text,
|
||||||
thread_id bigint,
|
thread_id bigint,
|
||||||
board_thread_id bigint,
|
board_thread_id bigint,
|
||||||
pathpart text,
|
pathpart text,
|
||||||
|
@ -222,6 +231,7 @@ RETURNS TABLE (
|
||||||
posts.board_post_id,
|
posts.board_post_id,
|
||||||
posts.creation_time,
|
posts.creation_time,
|
||||||
posts.body,
|
posts.body,
|
||||||
|
posts.subject,
|
||||||
posts.thread_id
|
posts.thread_id
|
||||||
FROM top
|
FROM top
|
||||||
JOIN posts ON top.thread_id = posts.thread_id
|
JOIN posts ON top.thread_id = posts.thread_id
|
||||||
|
|
|
@ -199,6 +199,8 @@ apiPostToArchivePost thread post =
|
||||||
, Posts.board_post_id = JSONPosts.no post
|
, Posts.board_post_id = JSONPosts.no post
|
||||||
, Posts.creation_time = posixSecondsToUTCTime (realToFrac $ JSONPosts.time post)
|
, Posts.creation_time = posixSecondsToUTCTime (realToFrac $ JSONPosts.time post)
|
||||||
, Posts.body = JSONPosts.com post
|
, Posts.body = JSONPosts.com post
|
||||||
|
, Posts.name = JSONPosts.name post
|
||||||
|
, Posts.subject = JSONPosts.sub post
|
||||||
, Posts.thread_id = Threads.thread_id thread
|
, Posts.thread_id = Threads.thread_id thread
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
|
@ -52,11 +52,6 @@ instance FromJSON Catalog
|
||||||
parseJSONCatalog :: FilePath -> IO (Either String [Catalog])
|
parseJSONCatalog :: FilePath -> IO (Either String [Catalog])
|
||||||
parseJSONCatalog path = B.readFile path >>= return . eitherDecode
|
parseJSONCatalog path = B.readFile path >>= return . eitherDecode
|
||||||
|
|
||||||
{-
|
|
||||||
parsePosts :: FilePath -> IO (Either String Post.PostWrapper)
|
|
||||||
parsePosts path = B.readFile path >>= return . eitherDecode
|
|
||||||
-}
|
|
||||||
|
|
||||||
|
|
||||||
parsePosts :: FilePath -> IO (Either String Post.PostWrapper)
|
parsePosts :: FilePath -> IO (Either String Post.PostWrapper)
|
||||||
parsePosts path = do
|
parsePosts path = do
|
||||||
|
|
|
@ -13,6 +13,7 @@ data Post = Post
|
||||||
{ no :: Int64
|
{ no :: Int64
|
||||||
, com :: Maybe Text
|
, com :: Maybe Text
|
||||||
, name :: Maybe Text
|
, name :: Maybe Text
|
||||||
|
, sub :: Maybe Text
|
||||||
, time :: Int
|
, time :: Int
|
||||||
, omitted_posts :: Maybe Int
|
, omitted_posts :: Maybe Int
|
||||||
, omitted_images :: Maybe Int
|
, omitted_images :: Maybe Int
|
||||||
|
|
|
@ -15,5 +15,7 @@ data Post = Post
|
||||||
, board_post_id :: Int64
|
, board_post_id :: Int64
|
||||||
, creation_time :: UTCTime
|
, creation_time :: UTCTime
|
||||||
, body :: Maybe Text
|
, body :: Maybe Text
|
||||||
|
, name :: Maybe Text
|
||||||
|
, subject :: Maybe Text
|
||||||
, thread_id :: Int
|
, thread_id :: Int
|
||||||
} deriving (Show, Generic, FromJSON, ToJSON)
|
} deriving (Show, Generic, FromJSON, ToJSON)
|
||||||
|
|
Loading…
Reference in New Issue