use super::{Connection, DBError, Result}; use crate::data::model; use common::ron_api::Difficulty; impl Connection { /// Returns all the recipe titles where recipe is written in the given language. /// If a user_id is given, the language constraint is ignored for recipes owned by user_id. pub async fn get_all_published_recipe_titles( &self, lang: &str, user_id: Option, ) -> Result> { if let Some(user_id) = user_id { sqlx::query_as( r#" SELECT [id], [title] FROM [Recipe] WHERE [is_published] = true AND ([lang] = $1 OR [user_id] = $2) ORDER BY [title] "#, ) .bind(lang) .bind(user_id) } else { sqlx::query_as( r#" SELECT [id], [title] FROM [Recipe] WHERE [is_published] = true AND [lang] = $1 ORDER BY [title] "#, ) .bind(lang) } .fetch_all(&self.pool) .await .map_err(DBError::from) } pub async fn get_all_unpublished_recipe_titles( &self, owned_by: i64, ) -> Result> { sqlx::query_as( r#" SELECT [id], [title] FROM [Recipe] WHERE [is_published] = false AND [user_id] = $1 ORDER BY [title] "#, ) .bind(owned_by) .fetch_all(&self.pool) .await .map_err(DBError::from) } pub async fn can_edit_recipe(&self, user_id: i64, recipe_id: i64) -> Result { sqlx::query_scalar( r#"SELECT COUNT(*) = 1 FROM [Recipe] WHERE [id] = $1 AND [user_id] = $2"#, ) .bind(recipe_id) .bind(user_id) .fetch_one(&self.pool) .await .map_err(DBError::from) } pub async fn can_edit_recipe_group(&self, user_id: i64, group_id: i64) -> Result { sqlx::query_scalar( r#" SELECT COUNT(*) = 1 FROM [Recipe] INNER JOIN [Group] ON [Group].[recipe_id] = [Recipe].[id] WHERE [Group].[id] = $1 AND [user_id] = $2 "#, ) .bind(group_id) .bind(user_id) .fetch_one(&self.pool) .await .map_err(DBError::from) } pub async fn can_edit_recipe_step(&self, user_id: i64, step_id: i64) -> Result { sqlx::query_scalar( r#" SELECT COUNT(*) = 1 FROM [Recipe] INNER JOIN [Group] ON [Group].[recipe_id] = [Recipe].[id] INNER JOIN [Step] ON [Step].[group_id] = [Group].[id] WHERE [Step].[id] = $1 AND [user_id] = $2 "#, ) .bind(step_id) .bind(user_id) .fetch_one(&self.pool) .await .map_err(DBError::from) } pub async fn can_edit_recipe_ingredient( &self, user_id: i64, ingredient_id: i64, ) -> Result { sqlx::query_scalar( r#" SELECT COUNT(*) FROM [Recipe] INNER JOIN [Group] ON [Group].[recipe_id] = [Recipe].[id] INNER JOIN [Step] ON [Step].[group_id] = [Group].[id] INNER JOIN [Ingredient] ON [Ingredient].[step_id] = [Step].[id] WHERE [Ingredient].[id] = $1 AND [user_id] = $2 "#, ) .bind(ingredient_id) .bind(user_id) .fetch_one(&self.pool) .await .map_err(DBError::from) } pub async fn get_recipe(&self, id: i64, with_groups: bool) -> Result> { match sqlx::query_as::<_, model::Recipe>( r#" SELECT [id], [user_id], [title], [lang], [estimated_time], [description], [difficulty], [servings], [is_published] FROM [Recipe] WHERE [id] = $1 "#, ) .bind(id) .fetch_optional(&self.pool) .await? { Some(mut recipe) if with_groups => { recipe.groups = self.get_groups(id).await?; Ok(Some(recipe)) } recipe => Ok(recipe), } } pub async fn create_recipe(&self, user_id: i64) -> Result { let mut tx = self.tx().await?; // Search for an existing empty recipe and return its id instead of creating a new one. match sqlx::query_scalar::<_, i64>( r#" SELECT [Recipe].[id] FROM [Recipe] LEFT JOIN [Image] ON [Image].[recipe_id] = [Recipe].[id] LEFT JOIN [Group] ON [Group].[recipe_id] = [Recipe].[id] WHERE [Recipe].[user_id] = $1 AND [Recipe].[title] = '' AND [Recipe].[estimated_time] IS NULL AND [Recipe].[description] = '' AND [Image].[id] IS NULL AND [Group].[id] IS NULL "#, ) .bind(user_id) .fetch_optional(&mut *tx) .await? { Some(recipe_id) => Ok(recipe_id), None => { let lang: String = sqlx::query_scalar("SELECT [lang] FROM [User] WHERE [id] = $1") .bind(user_id) .fetch_one(&mut *tx) .await?; let db_result = sqlx::query( "INSERT INTO [Recipe] ([user_id], [lang], [title]) VALUES ($1, $2, '')", ) .bind(user_id) .bind(lang) .execute(&mut *tx) .await?; tx.commit().await?; Ok(db_result.last_insert_rowid()) } } } pub async fn set_recipe_title(&self, recipe_id: i64, title: &str) -> Result<()> { sqlx::query("UPDATE [Recipe] SET [title] = $2 WHERE [id] = $1") .bind(recipe_id) .bind(title) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_recipe_description(&self, recipe_id: i64, description: &str) -> Result<()> { sqlx::query("UPDATE [Recipe] SET [description] = $2 WHERE [id] = $1") .bind(recipe_id) .bind(description) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_recipe_servings(&self, recipe_id: i64, servings: Option) -> Result<()> { sqlx::query("UPDATE [Recipe] SET [servings] = $2 WHERE [id] = $1") .bind(recipe_id) .bind(servings) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_recipe_estimated_time( &self, recipe_id: i64, estimated_time: Option, ) -> Result<()> { sqlx::query("UPDATE [Recipe] SET [estimated_time] = $2 WHERE [id] = $1") .bind(recipe_id) .bind(estimated_time) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn get_all_tags(&self) -> Result> { sqlx::query_scalar( r#" SELECT [name] FROM [Tag] ORDER BY [name] "#, ) .fetch_all(&self.pool) .await .map_err(DBError::from) } pub async fn get_all_tags_by_lang(&self, lang: &str) -> Result> { sqlx::query_scalar( r#" SELECT DISTINCT [name] FROM [Tag] INNER JOIN [RecipeTag] ON [RecipeTag].[tag_id] = [Tag].[id] INNER JOIN [Recipe] ON [Recipe].[id] = [RecipeTag].[recipe_id] WHERE [Recipe].[lang] = $1 ORDER BY [name] "#, ) .bind(lang) .fetch_all(&self.pool) .await .map_err(DBError::from) } pub async fn get_recipes_tags(&self, recipe_id: i64) -> Result> { sqlx::query_scalar( r#" SELECT [name] FROM [Tag] INNER JOIN [RecipeTag] ON [RecipeTag].[tag_id] = [Tag].[id] INNER JOIN [Recipe] ON [Recipe].[id] = [RecipeTag].[recipe_id] WHERE [Recipe].[id] = $1 ORDER BY [name] "#, ) .bind(recipe_id) .fetch_all(&self.pool) .await .map_err(DBError::from) } pub async fn add_recipe_tags(&self, recipe_id: i64, tags: &[T]) -> Result<()> where T: AsRef, { let mut tx = self.tx().await?; for tag in tags { let tag = tag.as_ref().trim().to_lowercase(); let tag_id: i64 = if let Some(tag_id) = sqlx::query_scalar("SELECT [id] FROM [Tag] WHERE [name] = $1") .bind(&tag) .fetch_optional(&mut *tx) .await? { tag_id } else { let result = sqlx::query("INSERT INTO [Tag] ([name]) VALUES ($1)") .bind(&tag) .execute(&mut *tx) .await?; result.last_insert_rowid() }; sqlx::query( r#" INSERT INTO [RecipeTag] ([recipe_id], [tag_id]) VALUES ($1, $2) ON CONFLICT DO NOTHING "#, ) .bind(recipe_id) .bind(tag_id) .execute(&mut *tx) .await?; } tx.commit().await?; Ok(()) } pub async fn rm_recipe_tags(&self, recipe_id: i64, tags: &[T]) -> Result<()> where T: AsRef, { let mut tx = self.tx().await?; for tag in tags { if let Some(tag_id) = sqlx::query_scalar::<_, i64>( r#" DELETE FROM [RecipeTag] WHERE [id] IN ( SELECT [RecipeTag].[id] FROM [RecipeTag] INNER JOIN [Tag] ON [Tag].[id] = [tag_id] WHERE [recipe_id] = $1 AND [Tag].[name] = $2 ) RETURNING [RecipeTag].[tag_id] "#, ) .bind(recipe_id) .bind(tag.as_ref()) .fetch_optional(&mut *tx) .await? { sqlx::query( r#" DELETE FROM [Tag] WHERE [id] = $1 AND [id] NOT IN ( SELECT [tag_id] FROM [RecipeTag] WHERE [tag_id] = $1 ) "#, ) .bind(tag_id) .execute(&mut *tx) .await?; } } tx.commit().await?; Ok(()) } pub async fn set_recipe_difficulty( &self, recipe_id: i64, difficulty: Difficulty, ) -> Result<()> { sqlx::query("UPDATE [Recipe] SET [difficulty] = $2 WHERE [id] = $1") .bind(recipe_id) .bind(u32::from(difficulty)) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_recipe_language(&self, recipe_id: i64, lang: &str) -> Result<()> { sqlx::query("UPDATE [Recipe] SET [lang] = $2 WHERE [id] = $1") .bind(recipe_id) .bind(lang) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_recipe_is_published(&self, recipe_id: i64, is_published: bool) -> Result<()> { sqlx::query("UPDATE [Recipe] SET [is_published] = $2 WHERE [id] = $1") .bind(recipe_id) .bind(is_published) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn rm_recipe(&self, recipe_id: i64) -> Result<()> { sqlx::query("DELETE FROM [Recipe] WHERE [id] = $1") .bind(recipe_id) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn get_groups(&self, recipe_id: i64) -> Result> { let mut tx = self.tx().await?; let mut groups: Vec = sqlx::query_as( r#" SELECT [id], [name], [comment] FROM [Group] WHERE [recipe_id] = $1 ORDER BY [order] "#, ) .bind(recipe_id) .fetch_all(&mut *tx) .await?; for group in groups.iter_mut() { group.steps = sqlx::query_as( r#" SELECT [id], [action] FROM [Step] WHERE [group_id] = $1 ORDER BY [order] "#, ) .bind(group.id) .fetch_all(&mut *tx) .await?; for step in group.steps.iter_mut() { step.ingredients = sqlx::query_as( r#" SELECT [id], [name], [comment], [quantity_value], [quantity_unit] FROM [Ingredient] WHERE [step_id] = $1 ORDER BY [name] "#, ) .bind(step.id) .fetch_all(&mut *tx) .await?; } } Ok(groups) } pub async fn add_recipe_group(&self, recipe_id: i64) -> Result { let db_result = sqlx::query("INSERT INTO [Group] ([recipe_id]) VALUES ($1)") .bind(recipe_id) .execute(&self.pool) .await?; Ok(db_result.last_insert_rowid()) } pub async fn rm_recipe_group(&self, group_id: i64) -> Result<()> { sqlx::query("DELETE FROM [Group] WHERE [id] = $1") .bind(group_id) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_group_name(&self, group_id: i64, name: &str) -> Result<()> { sqlx::query("UPDATE [Group] SET [name] = $2 WHERE [id] = $1") .bind(group_id) .bind(name) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_group_comment(&self, group_id: i64, comment: &str) -> Result<()> { sqlx::query("UPDATE [Group] SET [comment] = $2 WHERE [id] = $1") .bind(group_id) .bind(comment) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn add_recipe_step(&self, group_id: i64) -> Result { let db_result = sqlx::query("INSERT INTO [Step] ([group_id]) VALUES ($1)") .bind(group_id) .execute(&self.pool) .await?; Ok(db_result.last_insert_rowid()) } pub async fn rm_recipe_step(&self, step_id: i64) -> Result<()> { sqlx::query("DELETE FROM [Step] WHERE [id] = $1") .bind(step_id) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_step_action(&self, step_id: i64, action: &str) -> Result<()> { sqlx::query("UPDATE [Step] SET [action] = $2 WHERE [id] = $1") .bind(step_id) .bind(action) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn add_recipe_ingredient(&self, step_id: i64) -> Result { let db_result = sqlx::query("INSERT INTO [Ingredient] ([step_id]) VALUES ($1)") .bind(step_id) .execute(&self.pool) .await?; Ok(db_result.last_insert_rowid()) } pub async fn rm_recipe_ingredient(&self, ingredient_id: i64) -> Result<()> { sqlx::query("DELETE FROM [Ingredient] WHERE [id] = $1") .bind(ingredient_id) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_ingredient_name(&self, ingredient_id: i64, name: &str) -> Result<()> { sqlx::query("UPDATE [Ingredient] SET [name] = $2 WHERE [id] = $1") .bind(ingredient_id) .bind(name) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_ingredient_comment(&self, ingredient_id: i64, comment: &str) -> Result<()> { sqlx::query("UPDATE [Ingredient] SET [comment] = $2 WHERE [id] = $1") .bind(ingredient_id) .bind(comment) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_ingredient_quantity( &self, ingredient_id: i64, quantity: Option, ) -> Result<()> { sqlx::query("UPDATE [Ingredient] SET [quantity_value] = $2 WHERE [id] = $1") .bind(ingredient_id) .bind(quantity) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } pub async fn set_ingredient_unit(&self, ingredient_id: i64, unit: &str) -> Result<()> { sqlx::query("UPDATE [Ingredient] SET [quantity_unit] = $2 WHERE [id] = $1") .bind(ingredient_id) .bind(unit) .execute(&self.pool) .await .map(|_| ()) .map_err(DBError::from) } } #[cfg(test)] mod tests { use super::*; #[tokio::test] async fn create_a_new_recipe_then_update_its_title() -> Result<()> { let connection = Connection::new_in_memory().await?; let user_id = create_a_user(&connection).await?; let recipe_id = connection.create_recipe(user_id).await?; connection.set_recipe_title(recipe_id, "Crêpe").await?; let recipe = connection.get_recipe(recipe_id, false).await?.unwrap(); assert_eq!(recipe.title, "Crêpe".to_string()); Ok(()) } #[tokio::test] async fn setters() -> Result<()> { let connection = Connection::new_in_memory().await?; let user_id = create_a_user(&connection).await?; let recipe_id = connection.create_recipe(user_id).await?; connection.set_recipe_title(recipe_id, "Ouiche").await?; connection .set_recipe_description(recipe_id, "C'est bon, mangez-en") .await?; connection .set_recipe_estimated_time(recipe_id, Some(420)) .await?; connection .set_recipe_difficulty(recipe_id, Difficulty::Medium) .await?; connection.set_recipe_language(recipe_id, "fr").await?; connection.set_recipe_is_published(recipe_id, true).await?; let recipe = connection.get_recipe(recipe_id, false).await?.unwrap(); assert_eq!(recipe.id, recipe_id); assert_eq!(recipe.title, "Ouiche"); assert_eq!(recipe.description, "C'est bon, mangez-en"); assert_eq!(recipe.estimated_time, Some(420)); assert_eq!(recipe.difficulty, Difficulty::Medium); assert_eq!(recipe.lang, "fr"); assert!(recipe.is_published); Ok(()) } async fn create_a_user(connection: &Connection) -> Result { let user_id = 1; connection.execute_sql( sqlx::query( r#" INSERT INTO [User] ([id], [email], [name], [creation_datetime], [password], [validation_token_datetime], [validation_token]) VALUES ($1, $2, $3, $4, $5, $6, $7) "# ) .bind(user_id) .bind("paul@atreides.com") .bind("paul") .bind("") .bind("$argon2id$v=19$m=4096,t=3,p=1$G4fjepS05MkRbTqEImUdYg$GGziE8uVQe1L1oFHk37lBno10g4VISnVqynSkLCH3Lc") .bind("2022-11-29 22:05:04.121407300+00:00") .bind(None::<&str>) // 'null'. ).await?; Ok(user_id) } #[tokio::test] async fn add_and_remove_tags() -> Result<()> { let connection = Connection::new_in_memory().await?; let user_id = create_a_user(&connection).await?; let recipe_id_1 = connection.create_recipe(user_id).await?; connection.set_recipe_title(recipe_id_1, "recipe 1").await?; let tags_1 = ["abc", "xyz"]; connection.add_recipe_tags(recipe_id_1, &tags_1).await?; // Adding the same tags should do nothing. connection.add_recipe_tags(recipe_id_1, &tags_1).await?; assert_eq!(connection.get_recipes_tags(recipe_id_1).await?, tags_1); let tags_2 = ["abc", "def", "xyz"]; let recipe_id_2 = connection.create_recipe(user_id).await?; connection.set_recipe_title(recipe_id_2, "recipe 2").await?; connection.add_recipe_tags(recipe_id_2, &tags_2).await?; assert_eq!(connection.get_recipes_tags(recipe_id_1).await?, tags_1); assert_eq!(connection.get_recipes_tags(recipe_id_2).await?, tags_2); assert_eq!(connection.get_all_tags().await?, ["abc", "def", "xyz"]); connection.rm_recipe_tags(recipe_id_2, &["abc"]).await?; assert_eq!(connection.get_all_tags().await?, ["abc", "def", "xyz"]); assert_eq!( connection.get_recipes_tags(recipe_id_1).await?, ["abc", "xyz"] ); assert_eq!( connection.get_recipes_tags(recipe_id_2).await?, ["def", "xyz"] ); connection.rm_recipe_tags(recipe_id_1, &["abc"]).await?; assert_eq!(connection.get_recipes_tags(recipe_id_1).await?, ["xyz"]); assert_eq!( connection.get_recipes_tags(recipe_id_2).await?, ["def", "xyz"] ); assert_eq!(connection.get_all_tags().await?, ["def", "xyz"]); assert_eq!(connection.get_all_tags_by_lang("en").await?, ["def", "xyz"]); connection.rm_recipe_tags(recipe_id_1, &tags_1).await?; connection.rm_recipe_tags(recipe_id_2, &tags_2).await?; assert!(connection.get_all_tags().await?.is_empty()); Ok(()) } }