From 61e8909ba96b75cbdeca5044def10972fdef0733 Mon Sep 17 00:00:00 2001 From: "Daniel J. Summers" Date: Tue, 31 Jan 2023 20:24:59 -0500 Subject: [PATCH] Finish legacy migration - Change search to use full-text search --- src/JobsJobsJobs/Citizens/Data.fs | 25 +++++++++------ src/JobsJobsJobs/Citizens/Views.fs | 38 ++++++++++++----------- src/JobsJobsJobs/Common/Data.fs | 49 ++++++++++++++++++++++++++++++ src/JobsJobsJobs/Home/Views.fs | 4 +-- src/JobsJobsJobs/Profiles/Data.fs | 13 +------- 5 files changed, 87 insertions(+), 42 deletions(-) diff --git a/src/JobsJobsJobs/Citizens/Data.fs b/src/JobsJobsJobs/Citizens/Data.fs index 05c2931..74aa8b2 100644 --- a/src/JobsJobsJobs/Citizens/Data.fs +++ b/src/JobsJobsJobs/Citizens/Data.fs @@ -223,34 +223,39 @@ let current () = backgroundTask { } let migrateLegacy currentId legacyId = backgroundTask { - let curId = CitizenId.toString currentId - let legId = CitizenId.toString legacyId + let oldId = CitizenId.toString legacyId let connProps = dataSource () use conn = Sql.createConnection connProps use! txn = conn.BeginTransactionAsync () try // Add legacy data to current user - let! _ = + let! profiles = conn |> Sql.existingConnection - |> Sql.query $"INSERT INTO {Table.Profile} SELECT @id, data FROM {Table.Profile} WHERE id = @oldId" - |> Sql.parameters [ "@id", Sql.string curId; "@oldId", Sql.string legId ] - |> Sql.executeNonQueryAsync + |> Sql.query $"SELECT * FROM {Table.Profile} WHERE id = @oldId" + |> Sql.parameters [ "@oldId", Sql.string oldId ] + |> Sql.executeAsync toDocument + match List.tryHead profiles with + | Some profile -> + do! saveDocument + Table.Profile (CitizenId.toString currentId) (Sql.existingConnection conn) + (mkDoc { profile with Id = currentId; IsLegacy = false }) + | None -> () let! listings = conn |> Sql.existingConnection |> Sql.query $"SELECT * FROM {Table.Listing} WHERE data ->> 'citizenId' = @oldId" - |> Sql.parameters [ "@oldId", Sql.string legId ] + |> Sql.parameters [ "@oldId", Sql.string oldId ] |> Sql.executeAsync toDocument for listing in listings do - let newListing = { listing with Id = ListingId.create (); CitizenId = currentId } + let newListing = { listing with Id = ListingId.create (); CitizenId = currentId; IsLegacy = false } do! saveDocument Table.Listing (ListingId.toString newListing.Id) (Sql.existingConnection conn) (mkDoc newListing) let! successes = conn |> Sql.existingConnection |> Sql.query $"SELECT * FROM {Table.Success} WHERE data ->> 'citizenId' = @oldId" - |> Sql.parameters [ "@oldId", Sql.string legId ] + |> Sql.parameters [ "@oldId", Sql.string oldId ] |> Sql.executeAsync toDocument for success in successes do let newSuccess = { success with Id = SuccessId.create (); CitizenId = currentId } @@ -264,7 +269,7 @@ let migrateLegacy currentId legacyId = backgroundTask { DELETE FROM {Table.Success} WHERE data ->> 'citizenId' = @oldId; DELETE FROM {Table.Listing} WHERE data ->> 'citizenId' = @oldId; DELETE FROM {Table.Citizen} WHERE id = @oldId" - |> Sql.parameters [ "@oldId", Sql.string legId ] + |> Sql.parameters [ "@oldId", Sql.string oldId ] |> Sql.executeNonQueryAsync do! txn.CommitAsync () return Ok "" diff --git a/src/JobsJobsJobs/Citizens/Views.fs b/src/JobsJobsJobs/Citizens/Views.fs index 78df5a6..2bdebdd 100644 --- a/src/JobsJobsJobs/Citizens/Views.fs +++ b/src/JobsJobsJobs/Citizens/Views.fs @@ -418,27 +418,29 @@ let legacy (current : Citizen list) (legacy : Citizen list) csrf = ] ] else p [] [ txt "There are no current accounts to which legacy accounts can be migrated" ] - ] - table [ _class "table table-sm table-hover" ] [ - thead [] [ - tr [] [ - th [ _scope "col" ] [ txt "Select" ] - th [ _scope "col" ] [ txt "NAS Profile" ] + div [ _class "col-12 col-lg-6 offset-xxl-2"] [ + table [ _class "table table-sm table-hover" ] [ + thead [] [ + tr [] [ + th [ _scope "col" ] [ txt "Select" ] + th [ _scope "col" ] [ txt "NAS Profile" ] + ] + ] + legacy |> List.map (fun it -> + let theId = CitizenId.toString it.Id + tr [] [ + td [] [ + if canProcess then + input [ _type "radio"; _id $"legacy_{theId}"; _name "LegacyId"; _value theId ] + else txt " " + ] + td [] [ label [ _for $"legacy_{theId}" ] [ str it.Email ] ] + ]) + |> tbody [] ] ] - legacy |> List.map (fun it -> - let theId = CitizenId.toString it.Id - tr [] [ - td [] [ - if canProcess then - input [ _type "radio"; _id $"legacy_{theId}"; _name "LegacyId"; _value theId ] - else txt " " - ] - td [] [ label [ _for $"legacy_{theId}" ] [ str it.Email ] ] - ]) - |> tbody [] ] - submitButton "save" "Migrate Account" + submitButton "content-save-outline" "Migrate Account" ] |> List.singleton |> pageWithTitle "Migrate Legacy Account" diff --git a/src/JobsJobsJobs/Common/Data.fs b/src/JobsJobsJobs/Common/Data.fs index b67b1e6..aaa2145 100644 --- a/src/JobsJobsJobs/Common/Data.fs +++ b/src/JobsJobsJobs/Common/Data.fs @@ -56,6 +56,7 @@ module DataConnection = $"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)" @@ -66,12 +67,59 @@ module DataConnection = $"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, [ [] ])) () } + + /// Create functions and triggers required to + let createTriggers () = backgroundTask { + let! functions = + dataSource () + |> Sql.query + "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") + 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 $$ + BEGIN + RETURN REPLACE(REPLACE(REPLACE(REPLACE(jsonb_path_query_array(target, path)::text, + '["', ''), '", "', ' '), '"]', ''), '[]', ''); + END; + $$ LANGUAGE plpgsql;""" + |> Sql.executeNonQueryAsync + () + if not (functions |> List.contains "set_text_search") then + let! _ = + dataSource () + |> Sql.query $" + CREATE FUNCTION jjj.set_text_search() RETURNS trigger AS $$ + BEGIN + NEW.text_search := to_tsvector('english', + COALESCE(NEW.data ->> 'region', '') || ' ' + || COALESCE(NEW.data ->> 'biography', '') || ' ' + || COALESCE(NEW.data ->> 'experience', '') || ' ' + || jjj.indexable_array_string(NEW.data, '$.skills[*].description') || ' ' + || jjj.indexable_array_string(NEW.data, '$.history[*].employer') || ' ' + || jjj.indexable_array_string(NEW.data, '$.history[*].position') || ' ' + || jjj.indexable_array_string(NEW.data, '$.history[*].description')); + RETURN NEW; + 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 + () + } /// Set up the data connection from the given configuration let setUp (cfg : IConfiguration) = backgroundTask { @@ -79,6 +127,7 @@ module DataConnection = let _ = builder.UseNodaTime () theDataSource <- Some (builder.Build ()) do! createTables () + do! createTriggers () } diff --git a/src/JobsJobsJobs/Home/Views.fs b/src/JobsJobsJobs/Home/Views.fs index ee90b5d..1ccdf7f 100644 --- a/src/JobsJobsJobs/Home/Views.fs +++ b/src/JobsJobsJobs/Home/Views.fs @@ -860,8 +860,8 @@ module Help = strong [] [ txt "Seeking Remote Work?" ]; txt " will select profiles based whether the citizen has " txt "selected remote work in their profile. "; strong [] [ txt "Text Search" ]; txt " will search " txt "several aspects of the employment profile for matches; it is case-insensitive and will match " - txt "partial words (ex. searching for “ing” will match “working”, " - txt "“BEING”, or “singsong”)." + txt "using English stemming rules (ex. searching for “force” will match words like " + txt "“force”, “forced”, or “forcing”)." ] p [] [ txt "If more than one field has a value selected, profiles must match all of those selections to be " diff --git a/src/JobsJobsJobs/Profiles/Data.fs b/src/JobsJobsJobs/Profiles/Data.fs index ec10167..ac58848 100644 --- a/src/JobsJobsJobs/Profiles/Data.fs +++ b/src/JobsJobsJobs/Profiles/Data.fs @@ -64,18 +64,7 @@ let search (search : ProfileSearchForm) isPublic = backgroundTask { if search.RemoteWork <> "" then "p.data ->> 'isRemote' = @remote", [ "@remote", jsonBool (search.RemoteWork = "yes") ] if search.Text <> "" then - "( p.data ->> 'region' ILIKE @text - OR p.data ->> 'biography' ILIKE @text - OR p.data ->> 'experience' ILIKE @text - OR EXISTS ( - SELECT 1 FROM jsonb_array_elements(p.data['skills']) x(elt) - WHERE x ->> 'description' ILIKE @text) - OR EXISTS ( - SELECT 1 FROM jsonb_array_elements(p.data['history']) x(elt) - WHERE x ->> 'employer' ILIKE @text - OR x ->> 'position' ILIKE @text - OR x ->> 'description' ILIKE @text))", - [ "@text", like search.Text ] + "p.text_search @@ plainto_tsquery(@text_search)", [ "@text_search", Sql.string search.Text ] ] let vizSql = if isPublic then