diff --git a/src/MyWebLog.Data/MyWebLog.Data.fsproj b/src/MyWebLog.Data/MyWebLog.Data.fsproj index 558c1cf..3014d6d 100644 --- a/src/MyWebLog.Data/MyWebLog.Data.fsproj +++ b/src/MyWebLog.Data/MyWebLog.Data.fsproj @@ -9,6 +9,8 @@ + + @@ -29,6 +31,9 @@ + + + diff --git a/src/MyWebLog.Data/PostgreSql/PostgreSqlCategoryData.fs b/src/MyWebLog.Data/PostgreSql/PostgreSqlCategoryData.fs new file mode 100644 index 0000000..8783c9d --- /dev/null +++ b/src/MyWebLog.Data/PostgreSql/PostgreSqlCategoryData.fs @@ -0,0 +1,185 @@ +namespace MyWebLog.Data.PostgreSql + +open MyWebLog +open MyWebLog.Data +open Npgsql +open Npgsql.FSharp + +type PostgreSqlCategoryData (conn : NpgsqlConnection) = + + /// Add parameters for category INSERT or UPDATE statements + let addCategoryParameters (cat : Category) = + Sql.parameters [ + webLogIdParam cat.WebLogId + "@id", Sql.string (CategoryId.toString cat.Id) + "@name", Sql.string cat.Name + "@slug", Sql.string cat.Slug + "@description", Sql.stringOrNone cat.Description + "@parentId", Sql.stringOrNone (cat.ParentId |> Option.map CategoryId.toString) + ] + + /// Add a category + let add cat = backgroundTask { + let! _ = + Sql.existingConnection conn + |> Sql.query """ + INSERT INTO category ( + id, web_log_id, name, slug, description, parent_id + ) VALUES ( + @id, @webLogId, @name, @slug, @description, @parentId + )""" + |> addCategoryParameters cat + |> Sql.executeNonQueryAsync + () + } + + /// Count all categories for the given web log + let countAll webLogId = + Sql.existingConnection conn + |> Sql.query "SELECT COUNT(id) AS the_count FROM category WHERE web_log_id = @webLogId" + |> Sql.parameters [ webLogIdParam webLogId ] + |> Sql.executeRowAsync Map.toCount + + /// Count all top-level categories for the given web log + let countTopLevel webLogId = + Sql.existingConnection conn + |> Sql.query "SELECT COUNT(id) FROM category WHERE web_log_id = @webLogId AND parent_id IS NULL" + |> Sql.parameters [ webLogIdParam webLogId ] + |> Sql.executeRowAsync Map.toCount + + /// Retrieve all categories for the given web log in a DotLiquid-friendly format + let findAllForView webLogId = backgroundTask { + let! cats = + Sql.existingConnection conn + |> Sql.query "SELECT * FROM category WHERE web_log_id = @webLogId ORDER BY LOWER(name)" + |> Sql.parameters [ webLogIdParam webLogId ] + |> Sql.executeAsync Map.toCategory + let ordered = Utils.orderByHierarchy cats None None [] + let counts = + ordered + // |> Seq.map (fun it -> backgroundTask { + // // Parent category post counts include posts in subcategories + // cmd.Parameters.Clear () + // addWebLogId cmd webLogId + // cmd.CommandText <- """ + // SELECT COUNT(DISTINCT p.id) + // FROM post p + // INNER JOIN post_category pc ON pc.post_id = p.id + // WHERE p.web_log_id = @webLogId + // AND p.status = 'Published' + // AND pc.category_id IN (""" + // ordered + // |> Seq.filter (fun cat -> cat.ParentNames |> Array.contains it.Name) + // |> Seq.map (fun cat -> cat.Id) + // |> Seq.append (Seq.singleton it.Id) + // |> Seq.iteri (fun idx item -> + // if idx > 0 then cmd.CommandText <- $"{cmd.CommandText}, " + // cmd.CommandText <- $"{cmd.CommandText}@catId{idx}" + // cmd.Parameters.AddWithValue ($"@catId{idx}", item) |> ignore) + // cmd.CommandText <- $"{cmd.CommandText})" + // let! postCount = count cmd + // return it.Id, postCount + // }) + // |> Task.WhenAll + return + ordered + |> Seq.map (fun cat -> + { cat with + PostCount = counts + |> Array.tryFind (fun c -> fst c = cat.Id) + |> Option.map snd + |> Option.defaultValue 0 + }) + |> Array.ofSeq + } + /// Find a category by its ID for the given web log + let findById catId webLogId = backgroundTask { + let! cat = + Sql.existingConnection conn + |> Sql.query "SELECT * FROM category WHERE id = @id AND web_log_id = @webLogId" + |> Sql.parameters [ "@id", Sql.string (CategoryId.toString catId); webLogIdParam webLogId ] + |> Sql.executeAsync Map.toCategory + return List.tryHead cat + } + + /// Find all categories for the given web log + let findByWebLog webLogId = + Sql.existingConnection conn + |> Sql.query "SELECT * FROM category WHERE web_log_id = @webLogId" + |> Sql.parameters [ webLogIdParam webLogId ] + |> Sql.executeAsync Map.toCategory + + + /// Delete a category + let delete catId webLogId = backgroundTask { + match! findById catId webLogId with + | Some cat -> + // Reassign any children to the category's parent category + let parentParam = "@parentId", Sql.string (CategoryId.toString catId) + let! children = + Sql.existingConnection conn + |> Sql.query "SELECT COUNT(id) AS the_count FROM category WHERE parent_id = @parentId" + |> Sql.parameters [ parentParam ] + |> Sql.executeRowAsync Map.toCount + if children > 0 then + let! _ = + Sql.existingConnection conn + |> Sql.query "UPDATE category SET parent_id = @newParentId WHERE parent_id = @parentId" + |> Sql.parameters + [ parentParam + "@newParentId", Sql.stringOrNone (cat.ParentId |> Option.map CategoryId.toString) ] + |> Sql.executeNonQueryAsync + () + // Delete the category off all posts where it is assigned + let catIdParam = "@id", Sql.string (CategoryId.toString catId) + let! _ = + Sql.existingConnection conn + |> Sql.query """ + DELETE FROM post_category + WHERE category_id = @id + AND post_id IN (SELECT id FROM post WHERE web_log_id = @webLogId)""" + |> Sql.parameters [ catIdParam; webLogIdParam webLogId ] + |> Sql.executeNonQueryAsync + // Delete the category itself + let! _ = + Sql.existingConnection conn + |> Sql.query "DELETE FROM category WHERE id = @id" + |> Sql.parameters [ catIdParam ] + |> Sql.executeNonQueryAsync + return if children = 0 then CategoryDeleted else ReassignedChildCategories + | None -> return CategoryNotFound + } + + /// Restore categories from a backup + let restore cats = backgroundTask { + for cat in cats do + do! add cat + } + + /// Update a category + let update cat = backgroundTask { + let! _ = + Sql.existingConnection conn + |> Sql.query """ + UPDATE category + SET name = @name, + slug = @slug, + description = @description, + parent_id = @parentId + WHERE id = @id + AND web_log_id = @webLogId""" + |> addCategoryParameters cat + |> Sql.executeNonQueryAsync + () + } + + interface ICategoryData with + member _.Add cat = add cat + member _.CountAll webLogId = countAll webLogId + member _.CountTopLevel webLogId = countTopLevel webLogId + member _.FindAllForView webLogId = findAllForView webLogId + member _.FindById catId webLogId = findById catId webLogId + member _.FindByWebLog webLogId = findByWebLog webLogId + member _.Delete catId webLogId = delete catId webLogId + member _.Restore cats = restore cats + member _.Update cat = update cat diff --git a/src/MyWebLog.Data/PostgreSql/PostgreSqlHelpers.fs b/src/MyWebLog.Data/PostgreSql/PostgreSqlHelpers.fs new file mode 100644 index 0000000..ed8ee91 --- /dev/null +++ b/src/MyWebLog.Data/PostgreSql/PostgreSqlHelpers.fs @@ -0,0 +1,27 @@ +/// Helper functions for the PostgreSQL data implementation +[] +module MyWebLog.Data.PostgreSql.PostgreSqlHelpers + +open MyWebLog +open Npgsql.FSharp + +/// Create a SQL parameter for the web log ID +let webLogIdParam webLogId = + "@webLogId", Sql.string (WebLogId.toString webLogId) + +/// Mapping functions for SQL queries +module Map = + + /// Create a category from the current row in the given data reader + let toCategory (row : RowReader) : Category = + { Id = row.string "id" |> CategoryId + WebLogId = row.string "web_log_id" |> WebLogId + Name = row.string "name" + Slug = row.string "slug" + Description = row.stringOrNone "description" + ParentId = row.stringOrNone "parent_id" |> Option.map CategoryId + } + + /// Get a count from a row + let toCount (row : RowReader) = + row.int "the_count" diff --git a/src/MyWebLog.Data/PostgreSqlData.fs b/src/MyWebLog.Data/PostgreSqlData.fs new file mode 100644 index 0000000..230966d --- /dev/null +++ b/src/MyWebLog.Data/PostgreSqlData.fs @@ -0,0 +1,263 @@ +namespace MyWebLog.Data + +open Microsoft.Extensions.Logging +open MyWebLog.Data.PostgreSql +open Npgsql +open Npgsql.FSharp + +/// Data implementation for PostgreSQL +type PostgreSqlData (conn : NpgsqlConnection, log : ILogger) = + + + interface IData with + + member _.Category = PostgreSqlCategoryData conn + + member _.StartUp () = backgroundTask { + + let! tables = + Sql.existingConnection conn + |> Sql.query "SELECT tablename FROM pg_tables WHERE schemaname = 'public'" + |> Sql.executeAsync (fun row -> row.string "tablename") + let needsTable table = not (List.contains table tables) + + seq { + // Theme tables + if needsTable "theme" then + """CREATE TABLE theme ( + id TEXT NOT NULL PRIMARY KEY, + name TEXT NOT NULL, + version TEXT NOT NULL)""" + if needsTable "theme_template" then + """CREATE TABLE theme_template ( + theme_id TEXT NOT NULL REFERENCES theme (id), + name TEXT NOT NULL, + template TEXT NOT NULL, + PRIMARY KEY (theme_id, name))""" + if needsTable "theme_asset" then + """CREATE TABLE theme_asset ( + theme_id TEXT NOT NULL REFERENCES theme (id), + path TEXT NOT NULL, + updated_on TIMESTAMPTZ NOT NULL, + data BYTEA NOT NULL, + PRIMARY KEY (theme_id, path))""" + + // Web log tables + if needsTable "web_log" then + """CREATE TABLE web_log ( + id TEXT NOT NULL PRIMARY KEY, + name TEXT NOT NULL, + slug TEXT NOT NULL, + subtitle TEXT, + default_page TEXT NOT NULL, + posts_per_page INTEGER NOT NULL, + theme_id TEXT NOT NULL REFERENCES theme (id), + url_base TEXT NOT NULL, + time_zone TEXT NOT NULL, + auto_htmx BOOLEAN NOT NULL DEFAULT FALSE, + uploads TEXT NOT NULL, + is_feed_enabled BOOLEAN NOT NULL DEFAULT FALSE, + feed_name TEXT NOT NULL, + items_in_feed INTEGER, + is_category_enabled BOOLEAN NOT NULL DEFAULT FALSE, + is_tag_enabled BOOLEAN NOT NULL DEFAULT FALSE, + copyright TEXT); + CREATE INDEX web_log_theme_idx ON web_log (theme_id)""" + if needsTable "web_log_feed" then + """CREATE TABLE web_log_feed ( + id TEXT NOT NULL PRIMARY KEY, + web_log_id TEXT NOT NULL REFERENCES web_log (id), + source TEXT NOT NULL, + path TEXT NOT NULL); + CREATE INDEX web_log_feed_web_log_idx ON web_log_feed (web_log_id)""" + if needsTable "web_log_feed_podcast" then + """CREATE TABLE web_log_feed_podcast ( + feed_id TEXT NOT NULL PRIMARY KEY REFERENCES web_log_feed (id), + title TEXT NOT NULL, + subtitle TEXT, + items_in_feed INTEGER NOT NULL, + summary TEXT NOT NULL, + displayed_author TEXT NOT NULL, + email TEXT NOT NULL, + image_url TEXT NOT NULL, + apple_category TEXT NOT NULL, + apple_subcategory TEXT, + explicit TEXT NOT NULL, + default_media_type TEXT, + media_base_url TEXT, + podcast_guid TEXT, + funding_url TEXT, + funding_text TEXT, + medium TEXT)""" + + // Category table + if needsTable "category" then + """CREATE TABLE category ( + id TEXT NOT NULL PRIMARY KEY, + web_log_id TEXT NOT NULL REFERENCES web_log (id), + name TEXT NOT NULL, + slug TEXT NOT NULL, + description TEXT, + parent_id TEXT); + CREATE INDEX category_web_log_idx ON category (web_log_id)""" + + // Web log user table + if needsTable "web_log_user" then + """CREATE TABLE web_log_user ( + id TEXT NOT NULL PRIMARY KEY, + web_log_id TEXT NOT NULL REFERENCES web_log (id), + email TEXT NOT NULL, + first_name TEXT NOT NULL, + last_name TEXT NOT NULL, + preferred_name TEXT NOT NULL, + password_hash TEXT NOT NULL, + salt TEXT NOT NULL, + url TEXT, + access_level TEXT NOT NULL, + created_on TIMESTAMPTZ NOT NULL, + last_seen_on TIMESTAMPTZ); + CREATE INDEX web_log_user_web_log_idx ON web_log_user (web_log_id); + CREATE INDEX web_log_user_email_idx ON web_log_user (web_log_id, email)""" + + // Page tables + if needsTable "page" then + """CREATE TABLE page ( + id TEXT NOT NULL PRIMARY KEY, + web_log_id TEXT NOT NULL REFERENCES web_log (id), + author_id TEXT NOT NULL REFERENCES web_log_user (id), + title TEXT NOT NULL, + permalink TEXT NOT NULL, + published_on TIMESTAMPTZ NOT NULL, + updated_on TIMESTAMPTZ NOT NULL, + is_in_page_list BOOLEAN NOT NULL DEFAULT FALSE, + template TEXT, + page_text TEXT NOT NULL); + CREATE INDEX page_web_log_idx ON page (web_log_id); + CREATE INDEX page_author_idx ON page (author_id); + CREATE INDEX page_permalink_idx ON page (web_log_id, permalink)""" + if needsTable "page_meta" then + """CREATE TABLE page_meta ( + page_id TEXT NOT NULL REFERENCES page (id), + name TEXT NOT NULL, + value TEXT NOT NULL, + PRIMARY KEY (page_id, name, value))""" + if needsTable "page_permalink" then + """CREATE TABLE page_permalink ( + page_id TEXT NOT NULL REFERENCES page (id), + permalink TEXT NOT NULL, + PRIMARY KEY (page_id, permalink))""" + if needsTable "page_revision" then + """CREATE TABLE page_revision ( + page_id TEXT NOT NULL REFERENCES page (id), + as_of TIMESTAMPTZ NOT NULL, + revision_text TEXT NOT NULL, + PRIMARY KEY (page_id, as_of))""" + + // Post tables + if needsTable "post" then + """CREATE TABLE post ( + id TEXT NOT NULL PRIMARY KEY, + web_log_id TEXT NOT NULL REFERENCES web_log (id), + author_id TEXT NOT NULL REFERENCES web_log_user (id), + status TEXT NOT NULL, + title TEXT NOT NULL, + permalink TEXT NOT NULL, + published_on TIMESTAMPTZ, + updated_on TIMESTAMPTZ NOT NULL, + template TEXT, + post_text TEXT NOT NULL); + CREATE INDEX post_web_log_idx ON post (web_log_id); + CREATE INDEX post_author_idx ON post (author_id); + CREATE INDEX post_status_idx ON post (web_log_id, status, updated_on); + CREATE INDEX post_permalink_idx ON post (web_log_id, permalink)""" + if needsTable "post_category" then + """CREATE TABLE post_category ( + post_id TEXT NOT NULL REFERENCES post (id), + category_id TEXT NOT NULL REFERENCES category (id), + PRIMARY KEY (post_id, category_id)); + CREATE INDEX post_category_category_idx ON post_category (category_id)""" + if needsTable "post_episode" then + """CREATE TABLE post_episode ( + post_id TEXT NOT NULL PRIMARY KEY REFERENCES post(id), + media TEXT NOT NULL, + length INTEGER NOT NULL, + duration TEXT, + media_type TEXT, + image_url TEXT, + subtitle TEXT, + explicit TEXT, + chapter_file TEXT, + chapter_type TEXT, + transcript_url TEXT, + transcript_type TEXT, + transcript_lang TEXT, + transcript_captions INTEGER, + season_number INTEGER, + season_description TEXT, + episode_number TEXT, + episode_description TEXT)""" + if needsTable "post_tag" then + """CREATE TABLE post_tag ( + post_id TEXT NOT NULL REFERENCES post (id), + tag TEXT NOT NULL, + PRIMARY KEY (post_id, tag))""" + if needsTable "post_meta" then + """CREATE TABLE post_meta ( + post_id TEXT NOT NULL REFERENCES post (id), + name TEXT NOT NULL, + value TEXT NOT NULL, + PRIMARY KEY (post_id, name, value))""" + if needsTable "post_permalink" then + """CREATE TABLE post_permalink ( + post_id TEXT NOT NULL REFERENCES post (id), + permalink TEXT NOT NULL, + PRIMARY KEY (post_id, permalink))""" + if needsTable "post_revision" then + """CREATE TABLE post_revision ( + post_id TEXT NOT NULL REFERENCES post (id), + as_of TIMESTAMPTZ NOT NULL, + revision_text TEXT NOT NULL, + PRIMARY KEY (post_id, as_of))""" + if needsTable "post_comment" then + """CREATE TABLE post_comment ( + id TEXT NOT NULL PRIMARY KEY, + post_id TEXT NOT NULL REFERENCES post(id), + in_reply_to_id TEXT, + name TEXT NOT NULL, + email TEXT NOT NULL, + url TEXT, + status TEXT NOT NULL, + posted_on TIMESTAMPTZ NOT NULL, + comment_text TEXT NOT NULL); + CREATE INDEX post_comment_post_idx ON post_comment (post_id)""" + + // Tag map table + if needsTable "tag_map" then + """CREATE TABLE tag_map ( + id TEXT NOT NULL PRIMARY KEY, + web_log_id TEXT NOT NULL REFERENCES web_log (id), + tag TEXT NOT NULL, + url_value TEXT NOT NULL); + CREATE INDEX tag_map_web_log_idx ON tag_map (web_log_id)""" + + // Uploaded file table + if needsTable "upload" then + """CREATE TABLE upload ( + id TEXT NOT NULL PRIMARY KEY, + web_log_id TEXT NOT NULL REFERENCES web_log (id), + path TEXT NOT NULL, + updated_on TIMESTAMPTZ NOT NULL, + data BYTEA NOT NULL); + CREATE INDEX upload_web_log_idx ON upload (web_log_id); + CREATE INDEX upload_path_idx ON upload (web_log_id, path)""" + } + |> Seq.iter (fun sql -> + let table = (sql.Split ' ')[2] + log.LogInformation $"Creating {(sql.Split ' ')[2]} table..." + Sql.existingConnection conn + |> Sql.query sql + |> Sql.executeNonQueryAsync + |> Async.AwaitTask + |> Async.RunSynchronously + |> ignore) + }