use std::path::Path; use rusqlite::{Connection, ToSql}; use chrono::{DateTime, Utc}; use crate::error::{Error, Result}; use crate::models::{Entry, Meta}; pub enum DBVersion { Timetrap, Version(u16), } pub trait Database { /// This is used to create tables and insert rows fn execute(&mut self, query: &str, params: &[&dyn ToSql]) -> Result<()>; /// And this is used to retrieve data fn entry_query(&self, query: &str, params: &[&dyn ToSql]) -> Result>; fn meta_query(&self, query: &str, params: &[&dyn ToSql]) -> Result>; // ---------- // Migrations // ---------- /// Create a database in the new database format. Actually the same format /// just it has an entry in the meta table that indicates the database /// version. fn init(&mut self) -> Result<()> { self.init_old()?; self.execute("INSERT INTO meta (key, value) VALUES ('database_version', 1)", &[])?; Ok(()) } /// Creates the tables for the old database format fn init_old(&mut self) -> Result<()> { self.execute("CREATE TABLE `entries` ( `id` integer NOT NULL PRIMARY KEY AUTOINCREMENT,\ `note` varchar(255), `start` timestamp, `end` timestamp, `sheet` varchar(255) ) ", &[])?; self.execute("CREATE TABLE `meta` ( `id` integer NOT NULL PRIMARY KEY AUTOINCREMENT, `key` varchar(255), `value` varchar(255) ) ", &[])?; self.execute("INSERT INTO meta (key, value) VALUES ('current_sheet', 'default')", &[])?; Ok(()) } // ------------- // Entry queries // ------------- fn entries_by_sheet(&self, sheet: &str, start: Option>, end: Option>) -> Result> { match (start, end) { (Some(start), Some(end)) => { self.entry_query( "select * from entries where sheet=?1 and start >= ?2 and start <= ?3 order by start asc", &[&sheet, &start, &end] ) } (Some(start), None) => { self.entry_query( "select * from entries where sheet=?1 and start >= ?2 order by start asc", &[&sheet, &start] ) } (None, Some(end)) => { self.entry_query( "select * from entries where sheet=?1 and start <= ?2 order by start asc", &[&sheet, &end] ) } (None, None) => { self.entry_query( "select * from entries where sheet=?1 order by start asc", &[&sheet] ) } } } fn entries_all_visible(&self, start: Option>, end: Option>) -> Result> { match (start, end) { (Some(start), Some(end)) => { self.entry_query( "select * from entries where sheet not like '!_%' escape \"!\" and start >= ?1 and start <= ?2 order by sheet asc, start asc", &[&start, &end] ) } (Some(start), None) => { self.entry_query( "select * from entries where sheet not like '!_%' escape \"!\" and start >= ?1 order by sheet asc, start asc", &[&start] ) } (None, Some(end)) => { self.entry_query( "select * from entries where sheet not like '!_%' escape \"!\" and start <= ?1 order by sheet asc, start asc", &[&end] ) } (None, None) => { self.entry_query( "select * from entries where sheet not like '!_%' escape \"!\" order by sheet asc, start asc", &[] ) } } } fn entries_full(&self, start: Option>, end: Option>) -> Result> { match (start, end) { (Some(start), Some(end)) => { self.entry_query( "select * from entries where start >= ?1 and start <= ?2 order by sheet asc, start asc", &[&start, &end] ) } (Some(start), None) => { self.entry_query( "select * from entries where start >= ?1 order by sheet asc, start asc", &[&start] ) } (None, Some(end)) => { self.entry_query( "select * from entries where start <= ?1 order by sheet asc, start asc", &[&end] ) } (None, None) => { self.entry_query( "select * from entries order by sheet asc, start asc", &[] ) } } } fn entry_insert(&mut self, start: DateTime, end: Option>, note: Option, sheet: &str) -> Result<()> { self.execute("insert into entries (start, end, note, sheet) values (?1, ?2, ?3, ?4)", &[ &start, &end, ¬e, &sheet, ]) } fn entry_update(&mut self, id: u64, start: DateTime, end: Option>, note: Option, sheet: &str) -> Result<()> { self.execute("update entries set start=?2, end=?3, note=?4, sheet=?5 where id=?1", &[ &id, &start, &end, ¬e, &sheet ]) } fn entry_by_id(&self, id: u64) -> Result> { Ok(self.entry_query("select * from entries where id=?1", &[&id])?.into_iter().next()) } fn running_entry(&self, sheet: &str) -> Result> { Ok(self.entry_query("select * from entries where end is null and sheet=?1", &[&sheet])?.into_iter().next()) } fn last_checkout_of_sheet(&self, sheet: &str) -> Result> { Ok(self.entry_query("select * from entries where end is not null and sheet=?1 order by end desc limit 1", &[&sheet])?.into_iter().next()) } fn delete_entry_by_id(&mut self, id: u64) -> Result<()> { Ok(self.execute("delete from entries where id=?1", &[&id])?) } fn delete_entries_in_sheet(&mut self, sheet: &str) -> Result<()> { self.execute("delete from entries where sheet=?1", &[&sheet])?; if let Some(last) = self.last_sheet()? { if last == sheet { self.unset_last_sheet()?; } } Ok(()) } // Meta queries fn current_sheet(&self) -> Result> { let results = self.meta_query("select * from meta where key='current_sheet'", &[])?; Ok(results.into_iter().next().map(|m| m.value)) } fn last_sheet(&self) -> Result> { let results = self.meta_query("select * from meta where key='last_sheet'", &[])?; Ok(results.into_iter().next().map(|m| m.value)) } fn set_current_sheet(&mut self, sheet: &str) -> Result<()> { self.execute("DELETE FROM meta WHERE key='current_sheet'", &[])?; self.execute("INSERT INTO meta (key, value) VALUES ('current_sheet', ?1)", &[&sheet])?; Ok(()) } fn set_last_sheet(&mut self, sheet: &str) -> Result<()> { self.execute("DELETE FROM meta WHERE key='last_sheet'", &[])?; self.execute("INSERT INTO meta (key, value) VALUES ('last_sheet', ?1)", &[&sheet])?; Ok(()) } fn unset_last_sheet(&mut self) -> Result<()> { Ok(self.execute("delete from meta where key='last_sheet'", &[])?) } fn version(&self) -> Result { let results = self.meta_query("select * from meta where key='database_version'", &[])?; if let Some(v) = results.into_iter().next().map(|m| m.value) { Ok(DBVersion::Version(v.parse().map_err(|_| { Error::CorruptedData(format!( "Found value '{}' for key 'database_version' in meta table, which is not a valid integer", v )) })?)) } else { Ok(DBVersion::Timetrap) } } } pub struct SqliteDatabase { connection: Connection, } impl SqliteDatabase { pub fn from_memory() -> Result { Ok(SqliteDatabase { connection: Connection::open_in_memory()?, }) } pub fn from_path>(path: P) -> Result { Ok(SqliteDatabase { connection: Connection::open(path)?, }) } pub fn from_path_or_create>(path: P) -> Result { if path.as_ref().is_file() { Self::from_path(path) } else { let mut db = Self::from_path(path)?; db.init()?; Ok(db) } } } impl Database for SqliteDatabase { fn execute(&mut self, query: &str, params: &[&dyn ToSql]) -> Result<()> { self.connection.execute(query, params)?; Ok(()) } fn entry_query(&self, query: &str, params: &[&dyn ToSql]) -> Result> { let mut stmt = self.connection.prepare(query)?; let entries = stmt.query_and_then(params, |row| { let id: u64 = row.get("id")?; let note = row.get("note")?; let sheet = row.get("sheet")?; let start = row.get("start").map_err(|_| { Error::InvalidTimeInDatabase { id: id.to_string(), col: "start".into(), } })?; let end = row.get("end").map_err(|_| { Error::InvalidTimeInDatabase { id: id.to_string(), col: "start".into(), } })?; Ok(Entry { id, note, start, end, sheet, }) })?.collect(); entries } fn meta_query(&self, query: &str, params: &[&dyn ToSql]) -> Result> { let mut stmt = self.connection.prepare(query)?; let results = stmt.query_map(params, |row| Ok(Meta { id: row.get("id")?, key: row.get("key")?, value: row.get("value")?, }))?.filter_map(|r| r.ok()).collect(); Ok(results) } } #[cfg(test)] mod tests { use chrono::TimeZone; use super::*; #[test] fn test_entries_by_sheet() { let mut db = SqliteDatabase::from_memory().unwrap(); db.init().unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), None, None, "OOO".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), None, None, "OOO".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), None, None, "OOO".into()).unwrap(); let start = Utc.ymd(2021, 7, 7).and_hms(1, 30, 0); let end = Utc.ymd(2021, 7, 7).and_hms(2, 30, 0); // filter by start and end assert_eq!( db.entries_by_sheet("XXX", Some(start), Some(end)).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), ] ); // filter only by start assert_eq!( db.entries_by_sheet("XXX", Some(start), None).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), ] ); // filter only by end assert_eq!( db.entries_by_sheet("XXX", None, Some(end)).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), ] ); // no filter assert_eq!( db.entries_by_sheet("XXX", None, None).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), ] ); } #[test] fn test_entries_all() { let mut db = SqliteDatabase::from_memory().unwrap(); db.init().unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), None, None, "_OO".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), None, None, "_OO".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), None, None, "_OO".into()).unwrap(); let start = Utc.ymd(2021, 7, 7).and_hms(1, 30, 0); let end = Utc.ymd(2021, 7, 7).and_hms(2, 30, 0); // filter by start and end assert_eq!( db.entries_all_visible(Some(start), Some(end)).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), ] ); // filter only by start assert_eq!( db.entries_all_visible(Some(start), None).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), ] ); // filter only by end assert_eq!( db.entries_all_visible(None, Some(end)).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), ] ); // no filter assert_eq!( db.entries_all_visible(None, None).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), ] ); } #[test] fn test_entries_full() { let mut db = SqliteDatabase::from_memory().unwrap(); db.init().unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), None, None, "_OO".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), None, None, "_OO".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), None, None, "XXX".into()).unwrap(); db.entry_insert(Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), None, None, "_OO".into()).unwrap(); let start = Utc.ymd(2021, 7, 7).and_hms(1, 30, 0); let end = Utc.ymd(2021, 7, 7).and_hms(2, 30, 0); // filter by start and end assert_eq!( db.entries_full(Some(start), Some(end)).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), ] ); // filter only by start assert_eq!( db.entries_full(Some(start), None).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), ] ); // filter only by end assert_eq!( db.entries_full(None, Some(end)).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), ] ); // no filter assert_eq!( db.entries_full(None, None).unwrap().into_iter().map(|e| e.start).collect::>(), vec![ Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), Utc.ymd(2021, 7, 7).and_hms(1, 0, 0), Utc.ymd(2021, 7, 7).and_hms(2, 0, 0), Utc.ymd(2021, 7, 7).and_hms(3, 0, 0), ] ); } }