diff --git a/backend/sql/version_1.sql b/backend/sql/version_1.sql index c73ab94..2da0db8 100644 --- a/backend/sql/version_1.sql +++ b/backend/sql/version_1.sql @@ -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, diff --git a/backend/src/data/db/recipe.rs b/backend/src/data/db/recipe.rs index 4ec6259..347154c 100644 --- a/backend/src/data/db/recipe.rs +++ b/backend/src/data/db/recipe.rs @@ -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: . + pub async fn search_recipes( + &self, + lang: &str, + term: &str, + ) -> Result> { + sqlx::query_as( + r#" +SELECT [id], [recipe].[title], highlight([RecipeTitle], 0, '', '') [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 { 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 { + 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 yyy 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 yyy 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, + "AAA ZZZ".to_string() + ); + + assert_eq!(recipes[1].id, id1); + assert_eq!(recipes[1].title, "AAA yyy CCC".to_string()); + assert_eq!( + recipes[1].title_highlighted, + "AAA 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 ZZZ".to_string() + ); + } + + Ok(()) + } + #[tokio::test] async fn setters() -> Result<()> { let connection = Connection::new_in_memory().await?; diff --git a/backend/src/data/model.rs b/backend/src/data/model.rs index 01aae36..40fa406 100644 --- a/backend/src/data/model.rs +++ b/backend/src/data/model.rs @@ -51,6 +51,13 @@ pub struct Recipe { pub groups: Vec, } +#[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,