use crate::structs::*; use lazy_static::lazy_static; use regex::Regex; use slug::slugify; use sqlx::{ sqlite::{Sqlite, SqliteRow}, Done, Executor, Row, }; use std::collections::HashSet; type SqlResult = sqlx::Result; // ___ _ _ // | _ \_ _(_)_ ____ _| |_ ___ // | _/ '_| \ V / _` | _/ -_) // |_| |_| |_|\_/\__,_|\__\___| // // I'm putting a lot of faith in Rust's ability to inline stuff. I'm // sure this is okay. But really, this lets the API be clean and // coherent and easily readable, and hides away the gnarliness of some // of the SQL queries. pub(crate) async fn reset_database<'a, E>(executor: E) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { let initialize_sql = include_str!("sql/initialize_database.sql"); sqlx::query(initialize_sql).execute(executor).await.map(|_| ()) } pub(crate) async fn select_page_by_slug<'a, E>(executor: E, slug: &str) -> SqlResult where E: Executor<'a, Database = Sqlite>, { let select_one_page_by_slug_sql = concat!( "SELECT id, title, slug, note_id, creation_date, updated_date, ", "lastview_date, deleted_date FROM pages WHERE slug=?;" ); Ok(sqlx::query_as(&select_one_page_by_slug_sql) .bind(&slug) .fetch_one(executor) .await?) } pub(crate) async fn select_page_by_title<'a, E>(executor: E, title: &str) -> SqlResult where E: Executor<'a, Database = Sqlite>, { let select_one_page_by_title_sql = concat!( "SELECT id, title, slug, note_id, creation_date, updated_date, ", "lastview_date, deleted_date FROM pages WHERE title=?;" ); Ok(sqlx::query_as(&select_one_page_by_title_sql) .bind(&title) .fetch_one(executor) .await?) } pub(crate) async fn select_note_id_for_uuid<'a, E>(executor: E, uuid: &str) -> SqlResult where E: Executor<'a, Database = Sqlite>, { let select_note_id_for_uuid_sql = "SELECT id FROM notes WHERE uuid = ?;"; let id: JustId = sqlx::query_as(&select_note_id_for_uuid_sql) .bind(&uuid) .fetch_one(executor) .await?; Ok(ParentId(id.id)) } pub(crate) async fn make_room_for_new_note<'a, E>(executor: E, parent_id: ParentId, position: i64) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { let make_room_for_new_note_sql = concat!( "UPDATE note_relationships ", "SET position = position + 1 ", "WHERE position >= ? and parent_id = ?;" ); sqlx::query(make_room_for_new_note_sql) .bind(&position) .bind(&*parent_id) .execute(executor) .await .map(|_| ()) } pub(crate) async fn insert_note_to_note_relationship<'a, E>( executor: E, parent_id: ParentId, note_id: NoteId, position: i64, nature: &str, ) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { let insert_note_to_note_relationship_sql = concat!( "INSERT INTO note_relationships (parent_id, note_id, position, nature) ", "values (?, ?, ?, ?)" ); sqlx::query(insert_note_to_note_relationship_sql) .bind(&*parent_id) .bind(&*note_id) .bind(&position) .bind(&nature) .execute(executor) .await .map(|_| ()) } pub(crate) async fn select_note_collection_from_root<'a, E>(executor: E, root: i64) -> SqlResult> where E: Executor<'a, Database = Sqlite>, { let select_note_collection_from_root_sql = include_str!("sql/select_note_collection_from_root.sql"); Ok(sqlx::query_as(&select_note_collection_from_root_sql) .bind(&root) .fetch_all(executor) .await?) } pub(crate) async fn insert_one_new_note<'a, E>(executor: E, note: &NewNote) -> SqlResult where E: Executor<'a, Database = Sqlite>, { let insert_one_note_sql = concat!( "INSERT INTO notes ( ", " uuid, ", " content, ", " notetype, ", " creation_date, ", " updated_date, ", " lastview_date) ", "VALUES (?, ?, ?, ?, ?, ?);" ); Ok(NoteId( sqlx::query(insert_one_note_sql) .bind(¬e.uuid) .bind(¬e.content) .bind(¬e.notetype) .bind(¬e.creation_date) .bind(¬e.updated_date) .bind(¬e.lastview_date) .execute(executor) .await? .last_insert_rowid(), )) } // Given a possible slug, find the slug with the highest // uniquification number, and return that number, if any. pub(crate) fn find_maximal_slug(slugs: &[JustSlugs]) -> Option { lazy_static! { static ref RE_CAP_NUM: Regex = Regex::new(r"-(\d+)$").unwrap(); } if slugs.is_empty() { return None; } let mut slug_counters: Vec = slugs .iter() .filter_map(|slug| RE_CAP_NUM.captures(&slug.slug)) .map(|cap| cap.get(1).unwrap().as_str().parse::().unwrap()) .collect(); slug_counters.sort_unstable(); slug_counters.pop() } // Given an initial string and an existing collection of slugs, // generate a new slug that does not conflict with the current // collection. pub(crate) async fn generate_slug<'a, E>(executor: E, title: &str) -> SqlResult where E: Executor<'a, Database = Sqlite>, { lazy_static! { static ref RE_STRIP_NUM: Regex = Regex::new(r"-\d+$").unwrap(); } let initial_slug = slugify(title); let sample_slug = RE_STRIP_NUM.replace_all(&initial_slug, ""); let slug_finder_sql = "SELECT slug FROM pages WHERE slug LIKE '?%';"; let similar_slugs: Vec = sqlx::query_as(&slug_finder_sql) .bind(&*sample_slug) .fetch_all(executor) .await?; let maximal_slug = find_maximal_slug(&similar_slugs); match maximal_slug { None => Ok(initial_slug), Some(max_slug) => Ok(format!("{}-{}", initial_slug, max_slug + 1)), } } pub(crate) async fn insert_one_new_page<'a, E>(executor: E, page: &NewPage) -> SqlResult where E: Executor<'a, Database = Sqlite>, { let insert_one_page_sql = concat!( "INSERT INTO pages ( ", " slug, ", " title, ", " note_id, ", " creation_date, ", " updated_date, ", " lastview_date) ", "VALUES (?, ?, ?, ?, ?, ?);" ); Ok(PageId( sqlx::query(insert_one_page_sql) .bind(&page.slug) .bind(&page.title) .bind(&page.note_id) .bind(&page.creation_date) .bind(&page.updated_date) .bind(&page.lastview_date) .execute(executor) .await? .last_insert_rowid(), )) } pub(crate) async fn insert_note_to_page_relationships<'a, E>( executor: E, note_id: NoteId, references: &[PageId], ) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { if references.is_empty() { return Ok(()); } let insert_note_page_references_sql = "INSERT INTO page_relationships (note_id, page_id) VALUES ".to_string() + &["(?, ?)"].repeat(references.len()).join(", ") + &";".to_string(); let mut request = sqlx::query(&insert_note_page_references_sql); for reference in references { request = request.bind(*note_id).bind(**reference); } request.execute(executor).await.map(|_| ()) } // For a given collection of uuids, retrieve the internal ID used by // the database. pub(crate) async fn bulk_select_ids_for_note_uuids<'a, E>(executor: E, ids: &[&str]) -> SqlResult> where E: Executor<'a, Database = Sqlite>, { if ids.is_empty() { return Ok(vec![]); } let bulk_select_ids_for_note_uuids_sql = "SELECT uuid, id FROM notes WHERE uuid IN (".to_string() + &["?"].repeat(ids.len()).join(",") + &");".to_string(); let mut request = sqlx::query(&bulk_select_ids_for_note_uuids_sql); for id in ids.iter() { request = request.bind(id); } Ok(request .try_map(|row: SqliteRow| { let l = row.try_get::(0)?; let r = row.try_get::(1)?; Ok((l, r)) }) .fetch_all(executor) .await? .into_iter() .collect()) } // Used by move_note to identify the single note to note relationship // by the original parent and child pair. Used mostly to find the // position for recalculation, to create a new gap or close an old // one. pub(crate) async fn get_note_to_note_relationship<'a, E>( executor: E, parent_id: ParentId, note_id: NoteId, ) -> SqlResult where E: Executor<'a, Database = Sqlite>, { let get_note_to_note_relationship_sql = concat!( "SELECT parent_id, note_id, position, nature ", "FROM note_relationships ", "WHERE parent_id = ? and note_id = ? ", "LIMIT 1" ); sqlx::query_as(get_note_to_note_relationship_sql) .bind(&*parent_id) .bind(&*note_id) .fetch_one(executor) .await } pub(crate) async fn delete_note_to_note_relationship<'a, E>( executor: E, parent_id: ParentId, note_id: NoteId, ) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { let delete_note_to_note_relationship_sql = concat!( "DELETE FROM note_relationships ", "WHERE parent_id = ? and note_id = ? " ); let count = sqlx::query(delete_note_to_note_relationship_sql) .bind(&*parent_id) .bind(&*note_id) .execute(executor) .await? .rows_affected(); match count { 1 => Ok(()), _ => Err(sqlx::Error::RowNotFound), } } pub(crate) async fn delete_note_to_page_relationships<'a, E>(executor: E, note_id: NoteId) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { let delete_note_to_page_relationships_sql = "DELETE FROM page_relationships WHERE note_id = ?;"; let _ = sqlx::query(delete_note_to_page_relationships_sql) .bind(&*note_id) .execute(executor) .await?; Ok(()) } pub(crate) async fn delete_note<'a, E>(executor: E, note_id: NoteId) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { let delete_note_sql = "DELETE FROM notes WHERE note_id = ?"; let count = sqlx::query(delete_note_sql) .bind(&*note_id) .execute(executor) .await? .rows_affected(); match count { 1 => Ok(()), _ => Err(sqlx::Error::RowNotFound), } } pub(crate) async fn count_existing_note_relationships<'a, E>(executor: E, note_id: NoteId) -> SqlResult where E: Executor<'a, Database = Sqlite>, { let count_existing_note_relationships_sql = "SELECT COUNT(*) as count FROM page_relationships WHERE note_id = ?;"; let count: RowCount = sqlx::query_as(count_existing_note_relationships_sql) .bind(&*note_id) .fetch_one(executor) .await?; Ok(count.count) } pub(crate) async fn assert_max_child_position_for_note<'a, E>(executor: E, note_id: ParentId) -> SqlResult where E: Executor<'a, Database = Sqlite>, { let assert_max_child_position_for_note_sql = "SELECT MAX(position) AS count FROM note_relationships WHERE parent_id = ?;"; let count: RowCount = sqlx::query_as(assert_max_child_position_for_note_sql) .bind(&*note_id) .fetch_one(executor) .await?; Ok(count.count) } // After removing a note, recalculate the position of all notes under // the parent note, such that there order is now completely // sequential. pub(crate) async fn close_hole_for_deleted_note<'a, E>(executor: E, parent_id: ParentId, position: i64) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { let close_hole_for_deleted_note_sql = concat!( "UPDATE note_relationships ", "SET position = position - 1 ", "WHERE position > ? and parent_id = ?;" ); sqlx::query(close_hole_for_deleted_note_sql) .bind(&position) .bind(&*parent_id) .execute(executor) .await .map(|_| ()) } pub(crate) async fn find_all_page_references_for<'a, E>( executor: E, references: &[String], ) -> SqlResult> where E: Executor<'a, Database = Sqlite>, { if references.is_empty() { return Ok(vec![]); } let find_all_references_for_sql = "SELECT id, title FROM pages WHERE title IN (".to_string() + &["?"].repeat(references.len()).join(",") + &");".to_string(); let mut request = sqlx::query_as(&find_all_references_for_sql); for id in references.iter() { request = request.bind(id); } request.fetch_all(executor).await } pub(crate) async fn update_note_content<'a, E>(executor: E, note_id: NoteId, content: &str) -> SqlResult<()> where E: Executor<'a, Database = Sqlite>, { let update_note_content_sql = "UPDATE notes SET content = ? WHERE note_id = ?"; let count = sqlx::query(update_note_content_sql) .bind(content) .bind(&*note_id) .execute(executor) .await? .rows_affected(); match count { 1 => Ok(()), _ => Err(sqlx::Error::RowNotFound), } } pub(crate) fn create_unique_root_note() -> NewNote { NewNoteBuilder::default() .uuid(friendly_id::create()) .content("".to_string()) .notetype("root".to_string()) .build() .unwrap() } pub(crate) fn create_new_page_for(title: &str, slug: &str, note_id: NoteId) -> NewPage { NewPageBuilder::default() .slug(slug.to_string()) .title(title.to_string()) .note_id(*note_id) .build() .unwrap() } // Given the references supplied, and the references found in the datastore, // return a list of the references not found in the datastore. pub(crate) fn diff_references(references: &[String], found_references: &[PageTitles]) -> Vec { let all: HashSet = references.iter().cloned().collect(); let found: HashSet = found_references.iter().map(|r| r.title.clone()).collect(); all.difference(&found).cloned().collect() }