v 3.1 (#42)
- Use PostgreSQL document library - Remove `isLegacy` property from profiles and listings - Update Docker image parameters (v 3.1 is deployed as a container) - Update dependencies
This commit was merged in pull request #42.
This commit is contained in:
@@ -29,80 +29,63 @@ module Table =
|
||||
let Success = "jjj.success"
|
||||
|
||||
|
||||
open BitBadger.Npgsql.FSharp.Documents
|
||||
open Npgsql.FSharp
|
||||
|
||||
/// Connection management for the document store
|
||||
[<AutoOpen>]
|
||||
module DataConnection =
|
||||
|
||||
open System.Text.Json
|
||||
open BitBadger.Npgsql.Documents
|
||||
open JobsJobsJobs
|
||||
open Microsoft.Extensions.Configuration
|
||||
open Npgsql
|
||||
|
||||
/// The data source for the document store
|
||||
let mutable private theDataSource : NpgsqlDataSource option = None
|
||||
|
||||
/// Get the data source as the start of a SQL statement
|
||||
let dataSource () =
|
||||
match theDataSource with
|
||||
| Some ds -> Sql.fromDataSource ds
|
||||
| None -> invalidOp "DataConnection.setUp() must be called before accessing the database"
|
||||
|
||||
/// Create tables
|
||||
let private createTables () = backgroundTask {
|
||||
let sql = [
|
||||
"CREATE SCHEMA IF NOT EXISTS jjj"
|
||||
// Tables
|
||||
$"CREATE TABLE IF NOT EXISTS {Table.Citizen} (id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL)"
|
||||
$"CREATE TABLE IF NOT EXISTS {Table.Continent} (id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL)"
|
||||
$"CREATE TABLE IF NOT EXISTS {Table.Listing} (id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL)"
|
||||
$"CREATE TABLE IF NOT EXISTS {Table.Profile} (id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL,
|
||||
text_search TSVECTOR NOT NULL,
|
||||
CONSTRAINT fk_profile_citizen FOREIGN KEY (id) REFERENCES {Table.Citizen} (id) ON DELETE CASCADE)"
|
||||
$"CREATE TABLE IF NOT EXISTS {Table.SecurityInfo} (id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL,
|
||||
CONSTRAINT fk_security_info_citizen FOREIGN KEY (id) REFERENCES {Table.Citizen} (id) ON DELETE CASCADE)"
|
||||
$"CREATE TABLE IF NOT EXISTS {Table.Success} (id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL)"
|
||||
// Key indexes
|
||||
$"CREATE UNIQUE INDEX IF NOT EXISTS uk_citizen_email ON {Table.Citizen} ((data -> 'email'))"
|
||||
$"CREATE INDEX IF NOT EXISTS idx_listing_citizen ON {Table.Listing} ((data -> 'citizenId'))"
|
||||
$"CREATE INDEX IF NOT EXISTS idx_listing_continent ON {Table.Listing} ((data -> 'continentId'))"
|
||||
$"CREATE INDEX IF NOT EXISTS idx_profile_continent ON {Table.Profile} ((data -> 'continentId'))"
|
||||
$"CREATE INDEX IF NOT EXISTS idx_success_citizen ON {Table.Success} ((data -> 'citizenId'))"
|
||||
// Profile text search index
|
||||
$"CREATE INDEX IF NOT EXISTS idx_profile_search ON {Table.Profile} USING GIN(text_search)"
|
||||
]
|
||||
let! _ =
|
||||
dataSource ()
|
||||
|> Sql.executeTransactionAsync (sql |> List.map (fun sql -> sql, [ [] ]))
|
||||
()
|
||||
do! Custom.nonQuery "CREATE SCHEMA IF NOT EXISTS jjj" []
|
||||
do! Definition.ensureTable Table.Citizen
|
||||
do! Definition.ensureTable Table.Continent
|
||||
do! Definition.ensureTable Table.Listing
|
||||
do! Definition.ensureTable Table.Success
|
||||
// Tables that use more than the default document configuration, key indexes, and text search index
|
||||
do! Custom.nonQuery
|
||||
$"CREATE TABLE IF NOT EXISTS {Table.Profile}
|
||||
(id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL, text_search TSVECTOR NOT NULL,
|
||||
CONSTRAINT fk_profile_citizen FOREIGN KEY (id) REFERENCES {Table.Citizen} (id) ON DELETE CASCADE);
|
||||
CREATE TABLE IF NOT EXISTS {Table.SecurityInfo} (id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL,
|
||||
CONSTRAINT fk_security_info_citizen
|
||||
FOREIGN KEY (id) REFERENCES {Table.Citizen} (id) ON DELETE CASCADE);
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS uk_citizen_email ON {Table.Citizen} ((data -> 'email'));
|
||||
CREATE INDEX IF NOT EXISTS idx_listing_citizen ON {Table.Listing} ((data -> 'citizenId'));
|
||||
CREATE INDEX IF NOT EXISTS idx_listing_continent ON {Table.Listing} ((data -> 'continentId'));
|
||||
CREATE INDEX IF NOT EXISTS idx_profile_continent ON {Table.Profile} ((data -> 'continentId'));
|
||||
CREATE INDEX IF NOT EXISTS idx_success_citizen ON {Table.Success} ((data -> 'citizenId'));
|
||||
CREATE INDEX IF NOT EXISTS idx_profile_search ON {Table.Profile} USING GIN(text_search)"
|
||||
[]
|
||||
}
|
||||
|
||||
/// Create functions and triggers required to
|
||||
let createTriggers () = backgroundTask {
|
||||
/// Create functions and triggers required to keep the search index current
|
||||
let private createTriggers () = backgroundTask {
|
||||
let! functions =
|
||||
dataSource ()
|
||||
|> Sql.query
|
||||
Custom.list
|
||||
"SELECT p.proname
|
||||
FROM pg_catalog.pg_proc p
|
||||
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace
|
||||
WHERE n.nspname = 'jjj'"
|
||||
|> Sql.executeAsync (fun row -> row.string "proname")
|
||||
[] (fun row -> row.string "proname")
|
||||
if not (functions |> List.contains "indexable_array_string") then
|
||||
let! _ =
|
||||
dataSource ()
|
||||
|> Sql.query """
|
||||
CREATE FUNCTION jjj.indexable_array_string(target jsonb, path jsonpath) RETURNS text AS $$
|
||||
do! Custom.nonQuery
|
||||
"""CREATE FUNCTION jjj.indexable_array_string(target jsonb, path jsonpath) RETURNS text AS $$
|
||||
BEGIN
|
||||
RETURN REPLACE(REPLACE(REPLACE(REPLACE(jsonb_path_query_array(target, path)::text,
|
||||
'["', ''), '", "', ' '), '"]', ''), '[]', '');
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;"""
|
||||
|> Sql.executeNonQueryAsync
|
||||
()
|
||||
$$ LANGUAGE plpgsql;""" []
|
||||
if not (functions |> List.contains "set_text_search") then
|
||||
let! _ =
|
||||
dataSource ()
|
||||
|> Sql.query $"
|
||||
CREATE FUNCTION jjj.set_text_search() RETURNS trigger AS $$
|
||||
do! Custom.nonQuery
|
||||
$"CREATE FUNCTION jjj.set_text_search() RETURNS trigger AS $$
|
||||
BEGIN
|
||||
NEW.text_search := to_tsvector('english',
|
||||
COALESCE(NEW.data ->> 'region', '') || ' '
|
||||
@@ -116,73 +99,33 @@ module DataConnection =
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
CREATE TRIGGER set_text_search BEFORE INSERT OR UPDATE ON {Table.Profile}
|
||||
FOR EACH ROW EXECUTE FUNCTION jjj.set_text_search();"
|
||||
|> Sql.executeNonQueryAsync
|
||||
()
|
||||
FOR EACH ROW EXECUTE FUNCTION jjj.set_text_search();" []
|
||||
}
|
||||
|
||||
/// Set up the data connection from the given configuration
|
||||
let setUp (cfg : IConfiguration) = backgroundTask {
|
||||
let builder = NpgsqlDataSourceBuilder (cfg.GetConnectionString "PostgreSQL")
|
||||
let _ = builder.UseNodaTime ()
|
||||
theDataSource <- Some (builder.Build ())
|
||||
Configuration.useDataSource (builder.Build ())
|
||||
Configuration.useSerializer
|
||||
{ new IDocumentSerializer with
|
||||
member _.Serialize<'T> (it : 'T) = JsonSerializer.Serialize (it, Json.options)
|
||||
member _.Deserialize<'T> (it : string) = JsonSerializer.Deserialize<'T> (it, Json.options)
|
||||
}
|
||||
do! createTables ()
|
||||
do! createTriggers ()
|
||||
}
|
||||
|
||||
|
||||
open System.Text.Json
|
||||
open System.Threading.Tasks
|
||||
open JobsJobsJobs
|
||||
|
||||
/// Map the data field to the requested document type
|
||||
let toDocumentFrom<'T> fieldName (row : RowReader) =
|
||||
JsonSerializer.Deserialize<'T> (row.string fieldName, Json.options)
|
||||
|
||||
/// Map the data field to the requested document type
|
||||
let toDocument<'T> (row : RowReader) = toDocumentFrom<'T> "data" row
|
||||
|
||||
/// Get a document
|
||||
let getDocument<'T> table docId sqlProps : Task<'T option> = backgroundTask {
|
||||
let! doc =
|
||||
Sql.query $"SELECT * FROM %s{table} where id = @id" sqlProps
|
||||
|> Sql.parameters [ "@id", Sql.string docId ]
|
||||
|> Sql.executeAsync toDocument
|
||||
return List.tryHead doc
|
||||
}
|
||||
|
||||
/// Serialize a document to JSON
|
||||
let mkDoc<'T> (doc : 'T) =
|
||||
JsonSerializer.Serialize<'T> (doc, Json.options)
|
||||
|
||||
/// Save a document
|
||||
let saveDocument table docId sqlProps doc = backgroundTask {
|
||||
let! _ =
|
||||
Sql.query
|
||||
$"INSERT INTO %s{table} (id, data) VALUES (@id, @data)
|
||||
ON CONFLICT (id) DO UPDATE SET data = EXCLUDED.data"
|
||||
sqlProps
|
||||
|> Sql.parameters
|
||||
[ "@id", Sql.string docId
|
||||
"@data", Sql.jsonb doc ]
|
||||
|> Sql.executeNonQueryAsync
|
||||
()
|
||||
}
|
||||
|
||||
/// Create a match-anywhere clause for a LIKE or ILIKE clause
|
||||
let like value =
|
||||
Sql.string $"%%%s{value}%%"
|
||||
|
||||
/// The JSON access operator ->> makes values text; this makes a parameter that will compare the properly
|
||||
let jsonBool value =
|
||||
Sql.string (if value then "true" else "false")
|
||||
|
||||
/// Get the SQL for a search WHERE clause
|
||||
let searchSql criteria =
|
||||
let sql = criteria |> List.map fst |> String.concat " AND "
|
||||
if sql = "" then "" else $"AND {sql}"
|
||||
|
||||
|
||||
/// Continent data access functions
|
||||
[<RequireQualifiedAccess>]
|
||||
module Continents =
|
||||
@@ -191,10 +134,8 @@ module Continents =
|
||||
|
||||
/// Retrieve all continents
|
||||
let all () =
|
||||
dataSource ()
|
||||
|> Sql.query $"SELECT * FROM {Table.Continent} ORDER BY data ->> 'name'"
|
||||
|> Sql.executeAsync toDocument<Continent>
|
||||
Custom.list $"{Query.selectFromTable Table.Continent} ORDER BY data ->> 'name'" [] fromData<Continent>
|
||||
|
||||
/// Retrieve a continent by its ID
|
||||
let findById continentId =
|
||||
dataSource () |> getDocument<Continent> Table.Continent (ContinentId.toString continentId)
|
||||
Find.byId<Continent> Table.Continent (ContinentId.toString continentId)
|
||||
|
||||
Reference in New Issue
Block a user