UPDATE: Added database functionality for search bar, still need to integrate with webapp
This commit is contained in:
@@ -18,7 +18,7 @@ def search_results(query: str):
|
||||
# 3 categories
|
||||
categories = db.fetchall("""
|
||||
SELECT bm25(category_fts), rank, f.category_id, f.category_name
|
||||
FROM categorys AS c
|
||||
FROM categories AS c
|
||||
INNER JOIN category_fts AS f ON c.category_id = f.category_id
|
||||
WHERE category_fts MATCH ?
|
||||
LIMIT 3;
|
||||
@@ -38,7 +38,7 @@ def search_results(query: str):
|
||||
SELECT bm25(stream_fts), rank, f.user_id, f.title, f.num_viewers, f.category_id
|
||||
FROM streams s
|
||||
INNER JOIN stream_fts f ON s.user_id = f.user_id
|
||||
WHERE user_fts MATCH ?
|
||||
WHERE stream_fts MATCH ?
|
||||
LIMIT 3;
|
||||
""", (query,))
|
||||
|
||||
@@ -54,7 +54,7 @@ def search_categories(query: str):
|
||||
|
||||
categories = db.fetchall("""
|
||||
SELECT bm25(category_fts), rank, f.category_id, f.category_name
|
||||
FROM categorys AS c
|
||||
FROM categories AS c
|
||||
INNER JOIN category_fts AS f ON c.category_id = f.category_id
|
||||
WHERE category_fts MATCH ?;
|
||||
""", (query,))
|
||||
@@ -91,7 +91,7 @@ def search_streams(query: str):
|
||||
SELECT bm25(stream_fts), rank, f.user_id, f.title, f.num_viewers, f.category_id
|
||||
FROM streams s
|
||||
INNER JOIN stream_fts f ON s.user_id = f.user_id
|
||||
WHERE user_fts MATCH ?;
|
||||
WHERE stream_fts MATCH ?;
|
||||
""", (query,))
|
||||
|
||||
db.close_connection()
|
||||
|
||||
Binary file not shown.
114
web_server/database/text_search.sql
Normal file
114
web_server/database/text_search.sql
Normal file
@@ -0,0 +1,114 @@
|
||||
/* Full text search queries for categories */
|
||||
DROP TABLE IF EXISTS category_fts;
|
||||
CREATE VIRTUAL TABLE category_fts
|
||||
USING fts5 (category_id, category_name);
|
||||
|
||||
INSERT INTO category_fts (category_id, category_name)
|
||||
SELECT category_id, category_name
|
||||
FROM categories;
|
||||
|
||||
-- Triggers that inserts new titles into category_fts
|
||||
DROP TRIGGER IF EXISTS insert_category_fts;
|
||||
CREATE TRIGGER insert_category_fts
|
||||
AFTER INSERT ON categories
|
||||
BEGIN
|
||||
INSERT INTO category_fts(category_id, category_name)
|
||||
VALUES (NEW.category_id, NEW.category_name);
|
||||
END;
|
||||
|
||||
DROP TRIGGER IF EXISTS update_category_fts;
|
||||
CREATE TRIGGER update_category_fts
|
||||
AFTER UPDATE ON categories
|
||||
BEGIN
|
||||
UPDATE category_fts
|
||||
SET
|
||||
category_id = NEW.category_id,
|
||||
category_name = NEW.category_name
|
||||
WHERE category_id = NEW.category_id;
|
||||
END;
|
||||
|
||||
DROP TRIGGER IF EXISTS delete_category_fts;
|
||||
CREATE TRIGGER delete_category_fts
|
||||
AFTER DELETE ON categories
|
||||
BEGIN
|
||||
DELETE FROM category_fts
|
||||
WHERE category_id = OLD.category_id;
|
||||
END;
|
||||
|
||||
/* Full text search queries for users */
|
||||
DROP TABLE IF EXISTS user_fts;
|
||||
CREATE VIRTUAL TABLE user_fts
|
||||
USING fts5 (user_id, username, is_live);
|
||||
|
||||
INSERT INTO user_fts (user_id, username, is_live)
|
||||
SELECT user_id, username, is_live
|
||||
FROM users;
|
||||
|
||||
-- Triggers that inserts new titles into user_fts
|
||||
DROP TRIGGER IF EXISTS insert_user_fts;
|
||||
CREATE TRIGGER insert_user_fts
|
||||
AFTER INSERT ON users
|
||||
BEGIN
|
||||
INSERT INTO user_fts(user_id, username, is_live)
|
||||
VALUES (NEW.user_id, NEW.username, NEW.is_live);
|
||||
END;
|
||||
|
||||
DROP TRIGGER IF EXISTS update_user_fts;
|
||||
CREATE TRIGGER update_user_fts
|
||||
AFTER UPDATE ON users
|
||||
BEGIN
|
||||
UPDATE user_fts
|
||||
SET
|
||||
user_id = NEW.user_id,
|
||||
username = NEW.username,
|
||||
is_live = NEW.is_live
|
||||
WHERE user_id = NEW.user_id;
|
||||
END;
|
||||
|
||||
DROP TRIGGER IF EXISTS delete_user_fts;
|
||||
CREATE TRIGGER delete_user_fts
|
||||
AFTER DELETE ON users
|
||||
BEGIN
|
||||
DELETE FROM user_fts
|
||||
WHERE user_id = OLD.user_id;
|
||||
END;
|
||||
|
||||
|
||||
/* Full text search queries for users */
|
||||
DROP TABLE IF EXISTS stream_fts;
|
||||
CREATE VIRTUAL TABLE stream_fts
|
||||
USING fts5 (user_id, title, num_viewers, category_id);
|
||||
|
||||
INSERT INTO stream_fts (user_id, title, num_viewers, category_id)
|
||||
SELECT user_id, title, num_viewers, category_id
|
||||
FROM streams;
|
||||
|
||||
-- Triggers that inserts new titles into stream_fts
|
||||
DROP TRIGGER IF EXISTS insert_stream_fts;
|
||||
CREATE TRIGGER insert_stream_fts
|
||||
AFTER INSERT ON streams
|
||||
BEGIN
|
||||
INSERT INTO stream_fts(user_id, title, num_viewers, category_id)
|
||||
VALUES (NEW.user_id, NEW.title, NEW.num_viewers, NEW.category_id);
|
||||
END;
|
||||
|
||||
DROP TRIGGER IF EXISTS update_stream_fts;
|
||||
CREATE TRIGGER update_stream_fts
|
||||
AFTER UPDATE ON streams
|
||||
BEGIN
|
||||
UPDATE stream_fts
|
||||
SET
|
||||
user_id = NEW.user_id,
|
||||
title = NEW.title,
|
||||
num_viewers = NEW.num_viewers,
|
||||
category_id = NEW.category_id
|
||||
WHERE user_id = NEW.user_id;
|
||||
END;
|
||||
|
||||
DROP TRIGGER IF EXISTS delete_stream_fts;
|
||||
CREATE TRIGGER delete_stream_fts
|
||||
AFTER DELETE ON streams
|
||||
BEGIN
|
||||
DELETE FROM stream_fts
|
||||
WHERE user_id = OLD.user_id;
|
||||
END;
|
||||
Reference in New Issue
Block a user