use std::path::Path; use std::str::FromStr; use sqlx::sqlite::{SqliteConnectOptions, SqlitePool, SqlitePoolOptions}; use sqlx::{Error, Result}; #[cfg(any(not(feature = "publisher"), feature = "tester"))] use sqlx::Row; use crate::adventurer::Adventurer; use crate::tale::{Story, Tale}; #[cfg(feature = "publisher")] use crate::converter::Converter; #[cfg(feature = "publisher")] use crate::tavern::Tavern; #[cfg(any(not(feature = "publisher"), feature = "tester"))] use crate::tale::Lore; #[cfg(any(not(feature = "publisher"), feature = "tester"))] use crate::adventurer::Legend; /// Represents the database connection pool. pub struct Database { pool: SqlitePool } impl Database { /// Opens a connection to the SQLite database pool and creates the necessary /// tables. /// /// db_path is an absolute path to the resource file. /// Example: /// ```text /// open("/var/website/tavern.db"); /// ``` pub async fn open

(db_path: P) -> Result where P: AsRef { let db_str = db_path.as_ref().to_str().ok_or_else(|| { Error::Configuration("Invalid UTF-8 in database \ path" .into()) })?; let url: String = format!("sqlite://{db_str}"); // Set up connection options with foreign keys enabled. #[cfg(feature = "publisher")] let connect_options = SqliteConnectOptions::from_str(&url)?.read_only(false) .foreign_keys(true) .create_if_missing(true); #[cfg(not(feature = "publisher"))] let connect_options = SqliteConnectOptions::from_str(&url)?.read_only(true) .foreign_keys(true) .create_if_missing(false); let pool = SqlitePoolOptions::new().connect_with(connect_options) .await?; let database = Database { pool }; #[cfg(feature = "publisher")] database.create_tables().await?; Ok(database) } /// Creates the 'tales', 'adventurers', 'tags', 'tale_tags', and 'tavern' /// tables if they don't exist. #[cfg(feature = "publisher")] async fn create_tables(&self) -> Result<()> { sqlx::query!( "CREATE TABLE IF NOT EXISTS adventurers ( handle TEXT PRIMARY KEY, name TEXT NOT NULL, profile TEXT NOT NULL, image TEXT NOT NULL, blurb TEXT NOT NULL )" ).execute(&self.pool) .await?; sqlx::query!( "CREATE TABLE IF NOT EXISTS tales ( slug TEXT PRIMARY KEY, title TEXT NOT NULL, author TEXT NOT NULL, summary TEXT NOT NULL, publish_date TEXT NOT NULL, content TEXT NOT NULL )" ).execute(&self.pool) .await?; sqlx::query!( "CREATE TABLE IF NOT EXISTS tags ( id INTEGER PRIMARY KEY, name TEXT NOT NULL UNIQUE )" ).execute(&self.pool) .await?; sqlx::query!( "CREATE TABLE IF NOT EXISTS tale_tags ( tale_slug TEXT, tag_id INTEGER, FOREIGN KEY(tale_slug) REFERENCES tales(slug), FOREIGN KEY(tag_id) REFERENCES tags(id), UNIQUE(tale_slug, tag_id) )" ).execute(&self.pool) .await?; sqlx::query!( "CREATE TABLE IF NOT EXISTS tavern ( key TEXT PRIMARY KEY, value TEXT NOT NULL )" ).execute(&self.pool) .await?; Ok(()) } /// Inserts a single tale into the database. #[cfg(feature = "publisher")] pub async fn insert_tale(&self, tale: &Tale) -> Result<()> { // Convert the tales content from Markdown to HTML. let html_content: std::borrow::Cow<'_, str> = match &tale.story { Story::Html(story) => { std::borrow::Cow::Borrowed(story) } Story::File(path) => { let markdown = std::fs::read_to_string(path)?; std::borrow::Cow::Owned(Converter::markdown_to_html(&markdown)) } }; // Start a transaction. let mut tx = self.pool.begin().await?; // Store the tale. // Pull the HTML content out first so that the str will last long enough. // This get's around the macro lifetime issue. let html_str = html_content.as_ref(); sqlx::query!( "INSERT OR REPLACE INTO tales ( slug, title, author, summary, publish_date, content ) VALUES (?1, ?2, ?3, ?4, ?5, ?6)", tale.lore.slug, tale.lore.title, tale.lore.author, tale.lore.summary, tale.lore.publish_date, html_str ).execute(&mut *tx) // Pass mutable reference to the transaction .await?; // Store the tags. // For each tag ... for tag_name in &tale.lore.tags { // Insert a new tag, ignore if it already exists. sqlx::query!("INSERT OR IGNORE INTO tags (name) VALUES (?1)", tag_name).execute(&mut *tx) // Pass mutable reference to the transaction .await?; // Get the tag_id for the newly inserted or existing tag. let id: i64 = sqlx::query!("SELECT id FROM tags WHERE name = ?1", tag_name).fetch_one(&mut *tx) // Pass mutable reference to the transaction .await? .id .unwrap_or(0); // Use unwrap_or to handle the Option // Insert the tale_tag relationship. sqlx::query!( "INSERT OR IGNORE INTO tale_tags (tale_slug, tag_id) VALUES (?1, ?2)", tale.lore.slug, id ).execute(&mut *tx) // Pass mutable reference to the transaction .await?; } // Commit the transaction. tx.commit().await?; Ok(()) } /// Inserts a single adventurer into the database. #[cfg(feature = "publisher")] pub async fn insert_adventurer(&self, adventurer: &Adventurer) -> Result<()> { // Start a transaction. let mut tx = self.pool.begin().await?; sqlx::query!( "INSERT OR REPLACE INTO adventurers ( handle, name, profile, image, blurb ) VALUES (?1, ?2, ?3, ?4, ?5)", adventurer.handle, adventurer.name, adventurer.legend.profile, adventurer.legend.image, adventurer.legend.blurb ).execute(&mut *tx) .await?; // Commit the transaction. tx.commit().await?; Ok(()) } /// Inserts the site-wide settings like title and description. #[cfg(feature = "publisher")] pub async fn insert_tavern_settings(&self, title: &str, description: &str) -> Result<()> { // Start a transaction. let mut tx = self.pool.begin().await?; // Insert or replace the title. sqlx::query!("INSERT OR REPLACE INTO tavern (key, value) VALUES \ ('title', ?1)", title).execute(&mut *tx) // Pass mutable reference to the transaction .await?; // Insert or replace the description. sqlx::query!("INSERT OR REPLACE INTO tavern (key, value) VALUES \ ('description', ?1)", description).execute(&mut *tx) // Pass mutable reference to the transaction .await?; // Commit the transaction. tx.commit().await?; Ok(()) } /// Inserts a Tavern into the database. #[cfg(feature = "publisher")] pub async fn insert_tavern(&self, tavern: &Tavern) -> Result<()> { self.insert_tavern_settings(&tavern.title, &tavern.description).await?; for tale in &tavern.tales { self.insert_tale(tale).await?; } for author in &tavern.authors { self.insert_adventurer(author).await?; } Ok(()) } #[cfg(any(not(feature = "publisher"), feature = "tester"))] pub async fn get_all_tags(&self) -> Result> { let mut tx = self.pool.begin().await?; let rows = sqlx::query!( "SELECT name FROM tags ORDER BY name ASC" ) .fetch_all(&mut *tx) .await?; tx.commit().await?; let tags = rows .into_iter() .filter_map(|row| Some(row.name)) .collect(); Ok(tags) } #[cfg(any(not(feature = "publisher"), feature = "tester"))] pub async fn get_tales_summary(&self, categories: &[String]) -> Result> { let mut tales = Vec::new(); // Start a read-only transaction. let mut tx = self.pool.begin().await?; // Dynamically build the query. let mut query = String::from( "SELECT t.title, t.slug, t.summary, t.author, t.publish_date, GROUP_CONCAT(tg.name, ',') AS tags FROM tales AS t LEFT JOIN tale_tags AS tt ON t.slug = tt.tale_slug LEFT JOIN tags AS tg ON tt.tag_id = tg.id" ); if !categories.is_empty() { query.push_str(" WHERE tg.name IN ("); let placeholders: Vec<_> = (0..categories.len()).map(|_| "?").collect(); query.push_str(&placeholders.join(", ")); query.push(')'); } query.push_str(" GROUP BY t.slug ORDER BY t.publish_date DESC"); let mut q = sqlx::query(&query); for cat in categories { q = q.bind(cat); } let rows = q.fetch_all(&mut *tx).await?; for row in rows { let tags_str: Option = row.try_get("tags")?; let tags = tags_str.map(|s| s.split(',').map(String::from).collect()) .unwrap_or_default(); let date_str: String = row.try_get("publish_date")?; let publish_date = chrono::NaiveDateTime::parse_from_str(&date_str, "%Y-%m-%d %H:%M:%S") .map_err(|e| sqlx::Error::Decode(e.into()))?; tales.push(Lore { title: row.try_get("title")?, slug: row.try_get("slug")?, summary: row.try_get("summary")?, author: row.try_get("author")?, publish_date, tags }); } tx.commit().await?; // Explicit commit, even for read transactions. Ok(tales) } #[cfg(any(not(feature = "publisher"), feature = "tester"))] pub async fn get_tale_by_slug(&self, slug: &str) -> Result> { let mut tx = self.pool.begin().await?; let tale_row = sqlx::query( "SELECT t.title, t.slug, t.summary, t.author, t.publish_date, t.content, GROUP_CONCAT(tg.name, ',') AS tags FROM tales AS t LEFT JOIN tale_tags AS tt ON t.slug = tt.tale_slug LEFT JOIN tags AS tg ON tt.tag_id = tg.id WHERE t.slug = ?1 GROUP BY t.slug" ).bind(slug) .fetch_optional(&mut *tx) // Use transaction here .await?; tx.commit().await?; if let Some(row) = tale_row { let tags_str: Option = row.try_get("tags")?; let tags = tags_str.map(|s| s.split(',').map(String::from).collect()) .unwrap_or_default(); let date_str: String = row.try_get("publish_date")?; let publish_date = chrono::NaiveDateTime::parse_from_str(&date_str, "%Y-%m-%d %H:%M:%S") .map_err(|e| Error::Decode(e.into()))?; let lore = Lore { title: row.try_get("title")?, slug: row.try_get("slug")?, summary: row.try_get("summary")?, author: row.try_get("author")?, publish_date, tags }; Ok(Some(Tale { lore, story: Story::Html(row.try_get("content")?) })) } else { Ok(None) } } #[cfg(any(not(feature = "publisher"), feature = "tester"))] pub async fn get_adventurer(&self, handle: &str) -> Result> { let mut tx = self.pool.begin().await?; let legend = sqlx::query_as!( Legend, "SELECT profile AS profile, image AS image, blurb AS blurb FROM adventurers WHERE handle = ?1", handle ) .fetch_optional(&mut *tx) .await?; let hero = sqlx::query!( "SELECT name, handle AS 'handle!' FROM adventurers WHERE handle = ?1", handle ) .fetch_optional(&mut *tx) .await?; tx.commit().await?; let adventurer = match (hero, legend) { (Some(h), Some(l)) => { Some(Adventurer { name: h.name, handle: h.handle, legend: l, }) } _ => { None } }; Ok(adventurer) } }