Add full-text search for recipe titles
This commit is contained in:
parent
c24b0caeaf
commit
a3f61e3711
3 changed files with 122 additions and 2 deletions
|
|
@ -42,7 +42,7 @@ CREATE TABLE [User] (
|
|||
)
|
||||
) STRICT;
|
||||
|
||||
CREATE INDEX [validation_token_index] ON [User]([validation_token]);
|
||||
CREATE INDEX [User_validation_token_index] ON [User]([validation_token]);
|
||||
CREATE UNIQUE INDEX [User_email_index] ON [User]([email]);
|
||||
|
||||
CREATE TABLE [UserLoginToken] (
|
||||
|
|
@ -93,6 +93,29 @@ CREATE TABLE [Recipe] (
|
|||
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE SET NULL
|
||||
) STRICT;
|
||||
|
||||
CREATE VIRTUAL TABLE [RecipeTitle] USING FTS5(
|
||||
[title],
|
||||
CONTENT = [Recipe],
|
||||
CONTENT_ROWID = [id]
|
||||
);
|
||||
|
||||
CREATE TRIGGER [Recipe_trigger_insert] AFTER INSERT ON [Recipe] BEGIN
|
||||
INSERT INTO [RecipeTitle]([rowid], [title])
|
||||
VALUES (NEW.[id], NEW.[title]);
|
||||
END;
|
||||
|
||||
CREATE TRIGGER [Recipe_trigger_delete] AFTER DELETE ON [Recipe] BEGIN
|
||||
INSERT INTO [RecipeTitle]([RecipeTitle], [rowid], [title])
|
||||
VALUES ('delete', OLD.[id], OLD.[title]);
|
||||
END;
|
||||
|
||||
CREATE TRIGGER [Recipe_trigger_update] AFTER UPDATE ON [Recipe] BEGIN
|
||||
INSERT INTO [RecipeTitle]([RecipeTitle], [rowid], [title])
|
||||
VALUES ('delete', OLD.[id], OLD.[title]);
|
||||
|
||||
INSERT INTO [RecipeTitle]([rowid], [title]) VALUES (NEW.[id], NEW.[title]);
|
||||
END;
|
||||
|
||||
CREATE TABLE [Image] (
|
||||
[id] INTEGER PRIMARY KEY,
|
||||
[recipe_id] INTEGER NOT NULL,
|
||||
|
|
|
|||
|
|
@ -263,7 +263,8 @@ WHERE [id] = $1 AND ([user_id] = $2 OR (SELECT [is_admin] FROM [User] WHERE [id]
|
|||
r#"
|
||||
SELECT
|
||||
[id], [user_id], [title], [lang],
|
||||
[estimated_time], [description], [difficulty], [servings], [is_public]
|
||||
[estimated_time], [description], [difficulty], [servings],
|
||||
[is_public]
|
||||
FROM [Recipe] WHERE [id] = $1
|
||||
"#,
|
||||
)
|
||||
|
|
@ -280,6 +281,29 @@ FROM [Recipe] WHERE [id] = $1
|
|||
}
|
||||
}
|
||||
|
||||
/// Search for recipes matching the given term in the recipe title.
|
||||
/// The search term follows the syntax described here: <https://sqlite.org/fts5.html>.
|
||||
pub async fn search_recipes(
|
||||
&self,
|
||||
lang: &str,
|
||||
term: &str,
|
||||
) -> Result<Vec<model::RecipeSearchResult>> {
|
||||
sqlx::query_as(
|
||||
r#"
|
||||
SELECT [id], [recipe].[title], highlight([RecipeTitle], 0, '<em>', '</em>') [title_highlighted]
|
||||
FROM [RecipeTitle]
|
||||
INNER JOIN [Recipe] ON [Recipe].[id] = [RecipeTitle].[rowid]
|
||||
WHERE [Recipe].[lang] = $1 AND [RecipeTitle] MATCH $2
|
||||
ORDER BY RANK, [Recipe].[title]
|
||||
"#,
|
||||
)
|
||||
.bind(lang)
|
||||
.bind(term)
|
||||
.fetch_all(&self.pool)
|
||||
.await
|
||||
.map_err(DBError::from)
|
||||
}
|
||||
|
||||
pub async fn create_recipe(&self, user_id: i64) -> Result<i64> {
|
||||
let mut tx = self.tx().await?;
|
||||
|
||||
|
|
@ -970,6 +994,72 @@ mod tests {
|
|||
Ok(())
|
||||
}
|
||||
|
||||
#[tokio::test]
|
||||
async fn create_some_recipes_then_search_them_by_title() -> Result<()> {
|
||||
let connection = Connection::new_in_memory().await?;
|
||||
|
||||
let user_id = create_a_user(&connection).await?;
|
||||
|
||||
async fn add_recipe(connection: &Connection, user_id: i64, title: &str) -> Result<i64> {
|
||||
let recipe_id = connection.create_recipe(user_id).await?;
|
||||
connection.set_recipe_title(recipe_id, title).await?;
|
||||
Ok(recipe_id)
|
||||
}
|
||||
|
||||
let id1 = add_recipe(&connection, user_id, "AAA yyy CCC").await?;
|
||||
let id2 = add_recipe(&connection, user_id, "XXX yyy ZZZ").await?;
|
||||
let id3 = add_recipe(&connection, user_id, "AAA ZZZ").await?;
|
||||
|
||||
{
|
||||
let recipes = connection.search_recipes("en", "yyy").await?;
|
||||
|
||||
assert_eq!(recipes.len(), 2);
|
||||
|
||||
assert_eq!(recipes[0].id, id1);
|
||||
assert_eq!(recipes[0].title, "AAA yyy CCC".to_string());
|
||||
assert_eq!(
|
||||
recipes[0].title_highlighted,
|
||||
"AAA <em>yyy</em> CCC".to_string()
|
||||
);
|
||||
|
||||
assert_eq!(recipes[1].id, id2);
|
||||
assert_eq!(recipes[1].title, "XXX yyy ZZZ".to_string());
|
||||
assert_eq!(
|
||||
recipes[1].title_highlighted,
|
||||
"XXX <em>yyy</em> ZZZ".to_string()
|
||||
);
|
||||
}
|
||||
|
||||
{
|
||||
let recipes = connection.search_recipes("en", "aaa OR zzz").await?;
|
||||
|
||||
assert_eq!(recipes.len(), 3);
|
||||
|
||||
assert_eq!(recipes[0].id, id3);
|
||||
assert_eq!(recipes[0].title, "AAA ZZZ".to_string());
|
||||
assert_eq!(
|
||||
recipes[0].title_highlighted,
|
||||
"<em>AAA</em> <em>ZZZ</em>".to_string()
|
||||
);
|
||||
|
||||
assert_eq!(recipes[1].id, id1);
|
||||
assert_eq!(recipes[1].title, "AAA yyy CCC".to_string());
|
||||
assert_eq!(
|
||||
recipes[1].title_highlighted,
|
||||
"<em>AAA</em> yyy CCC".to_string()
|
||||
);
|
||||
|
||||
assert_eq!(recipes[2].id, id2);
|
||||
assert_eq!(recipes[2].title, "XXX yyy ZZZ".to_string());
|
||||
assert_eq!(
|
||||
recipes[2].title_highlighted,
|
||||
"XXX yyy <em>ZZZ</em>".to_string()
|
||||
);
|
||||
}
|
||||
|
||||
Ok(())
|
||||
}
|
||||
|
||||
#[tokio::test]
|
||||
async fn setters() -> Result<()> {
|
||||
let connection = Connection::new_in_memory().await?;
|
||||
|
|
|
|||
|
|
@ -51,6 +51,13 @@ pub struct Recipe {
|
|||
pub groups: Vec<Group>,
|
||||
}
|
||||
|
||||
#[derive(Debug, FromRow)]
|
||||
pub struct RecipeSearchResult {
|
||||
pub id: i64,
|
||||
pub title: String,
|
||||
pub title_highlighted: String,
|
||||
}
|
||||
|
||||
#[derive(Debug, FromRow)]
|
||||
pub struct Group {
|
||||
pub id: i64,
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue