From 985d8a71695f853d5ad38433ffbe4e6fd2a23f65 Mon Sep 17 00:00:00 2001 From: Runar Ingebrigtsen Date: Thu, 22 Jan 2026 19:18:02 +0100 Subject: [PATCH] use Sqlite FTS5 for search, assume correct language codes --- README.md | 2 + app/models/entry.rb | 32 ++++++ app/models/suggested_meaning.rb | 6 +- app/models/supported_language.rb | 6 ++ app/models/user.rb | 6 +- config/application.rb | 1 + db/migrate/20260122130000_add_entries_fts.rb | 57 +++++++++++ db/structure.sql | 101 +++++++++++++++++++ 8 files changed, 201 insertions(+), 10 deletions(-) create mode 100644 db/migrate/20260122130000_add_entries_fts.rb create mode 100644 db/structure.sql diff --git a/README.md b/README.md index d40c583..7b52fe2 100644 --- a/README.md +++ b/README.md @@ -15,6 +15,8 @@ We currently support the following languages: * Russian * German +Language codes are fixed because translations are stored in columns on `entries`. The `supported_languages` table controls labels, ordering, and whether a language is active. To add a language, you must add a new column to `entries` and add a corresponding row to `supported_languages`. + ### Entry An entry represents a translatable unit which may be: diff --git a/app/models/entry.rb b/app/models/entry.rb index 96f5a8c..7db4743 100644 --- a/app/models/entry.rb +++ b/app/models/entry.rb @@ -9,4 +9,36 @@ class Entry < ApplicationRecord enum :category, %i[word phrase proper_name title reference other] validates :category, presence: true + + scope :with_category, ->(cat) { cat.present? ? where(category: cat) : all } + + def self.search(query, language_code: nil) + return all if query.blank? + + prefix = valid_lang?(language_code) ? "#{language_code}:" : "" + fts_query = "#{prefix}\"#{query.to_s.gsub('"', '""')}\"" + + joins("JOIN entries_fts ON entries_fts.rowid = entries.id") + .where("entries_fts MATCH ?", fts_query) + end + + def self.starts_with(prefix, language_code:) + return none unless valid_lang?(language_code) + return all if prefix.blank? + + where("#{language_code} LIKE ?", "#{sanitize_sql_like(prefix)}%") + end + + def self.alphabetical_for(language_code) + return none unless valid_lang?(language_code) + + where.not(language_code => [ nil, "" ]) + .order(Arel.sql("#{language_code} ASC")) + end + + private + + def self.valid_lang?(code) + SupportedLanguage.valid_codes.include?(code.to_s) + end end diff --git a/app/models/suggested_meaning.rb b/app/models/suggested_meaning.rb index 5df0467..de128a1 100644 --- a/app/models/suggested_meaning.rb +++ b/app/models/suggested_meaning.rb @@ -7,11 +7,7 @@ class SuggestedMeaning < ApplicationRecord foreign_key: :language_code, primary_key: :code - enum status: { - pending: 0, - accepted: 1, - rejected: 2 - } + enum :status, %i[pending accepted rejected] validates :language_code, presence: true validates :alternative_translation, presence: true diff --git a/app/models/supported_language.rb b/app/models/supported_language.rb index ecb8b22..216e097 100644 --- a/app/models/supported_language.rb +++ b/app/models/supported_language.rb @@ -7,4 +7,10 @@ class SupportedLanguage < ApplicationRecord validates :code, presence: true, uniqueness: true validates :name, presence: true validates :native_name, presence: true + + def self.valid_codes + Rails.cache.fetch("supported_languages_codes", expires_in: 1.hour) do + pluck(:code).map(&:to_s) + end + end end diff --git a/app/models/user.rb b/app/models/user.rb index 3c4903f..a20f371 100644 --- a/app/models/user.rb +++ b/app/models/user.rb @@ -17,11 +17,7 @@ class User < ApplicationRecord has_many :entry_versions, dependent: :nullify has_many :comments, dependent: :nullify - enum role: { - contributor: 0, - reviewer: 1, - admin: 2 - } + enum :role, %i[contributor reviewer admin] validates :email, presence: true, uniqueness: true end diff --git a/config/application.rb b/config/application.rb index 51d39ca..b2f9895 100644 --- a/config/application.rb +++ b/config/application.rb @@ -23,5 +23,6 @@ module SanastoWiki # # config.time_zone = "Central Time (US & Canada)" # config.eager_load_paths << Rails.root.join("extras") + config.active_record.schema_format = :sql end end diff --git a/db/migrate/20260122130000_add_entries_fts.rb b/db/migrate/20260122130000_add_entries_fts.rb new file mode 100644 index 0000000..b5bd57d --- /dev/null +++ b/db/migrate/20260122130000_add_entries_fts.rb @@ -0,0 +1,57 @@ +class AddEntriesFts < ActiveRecord::Migration[8.1] + def up + execute <<~SQL + CREATE VIRTUAL TABLE IF NOT EXISTS entries_fts USING fts5( + fi, + en, + sv, + no, + ru, + de, + notes, + content='entries', + content_rowid='id' + ); + SQL + + execute <<~SQL + INSERT INTO entries_fts(entries_fts) VALUES('rebuild'); + SQL + + execute <<~SQL + CREATE TRIGGER IF NOT EXISTS entries_fts_after_insert + AFTER INSERT ON entries + BEGIN + INSERT INTO entries_fts(rowid, fi, en, sv, no, ru, de, notes) + VALUES (new.id, new.fi, new.en, new.sv, new.no, new.ru, new.de, new.notes); + END; + SQL + + execute <<~SQL + CREATE TRIGGER IF NOT EXISTS entries_fts_after_update + AFTER UPDATE ON entries + BEGIN + INSERT INTO entries_fts(entries_fts, rowid, fi, en, sv, no, ru, de, notes) + VALUES('delete', old.id, old.fi, old.en, old.sv, old.no, old.ru, old.de, old.notes); + INSERT INTO entries_fts(rowid, fi, en, sv, no, ru, de, notes) + VALUES (new.id, new.fi, new.en, new.sv, new.no, new.ru, new.de, new.notes); + END; + SQL + + execute <<~SQL + CREATE TRIGGER IF NOT EXISTS entries_fts_after_delete + AFTER DELETE ON entries + BEGIN + INSERT INTO entries_fts(entries_fts, rowid, fi, en, sv, no, ru, de, notes) + VALUES('delete', old.id, old.fi, old.en, old.sv, old.no, old.ru, old.de, old.notes); + END; + SQL + end + + def down + execute "DROP TRIGGER IF EXISTS entries_fts_after_insert" + execute "DROP TRIGGER IF EXISTS entries_fts_after_update" + execute "DROP TRIGGER IF EXISTS entries_fts_after_delete" + execute "DROP TABLE IF EXISTS entries_fts" + end +end diff --git a/db/structure.sql b/db/structure.sql new file mode 100644 index 0000000..cfb7fb5 --- /dev/null +++ b/db/structure.sql @@ -0,0 +1,101 @@ +CREATE TABLE IF NOT EXISTS "schema_migrations" ("version" varchar NOT NULL PRIMARY KEY); +CREATE TABLE IF NOT EXISTS "ar_internal_metadata" ("key" varchar NOT NULL PRIMARY KEY, "value" varchar, "created_at" datetime(6) NOT NULL, "updated_at" datetime(6) NOT NULL); +CREATE TABLE IF NOT EXISTS "entries" ("id" integer PRIMARY KEY AUTOINCREMENT NOT NULL, "category" integer DEFAULT 0 NOT NULL, "fi" varchar, "en" varchar, "sv" varchar, "no" varchar, "ru" varchar, "de" varchar, "notes" text, "verified" boolean DEFAULT FALSE NOT NULL, "created_by_id" integer, "updated_by_id" integer, "created_at" datetime(6) NOT NULL, "updated_at" datetime(6) NOT NULL, CONSTRAINT "fk_rails_367d1ab731" +FOREIGN KEY ("created_by_id") + REFERENCES "users" ("id") +, CONSTRAINT "fk_rails_6f84c41258" +FOREIGN KEY ("updated_by_id") + REFERENCES "users" ("id") +); +CREATE INDEX "index_entries_on_created_by_id" ON "entries" ("created_by_id") /*application='SanastoWiki'*/; +CREATE INDEX "index_entries_on_updated_by_id" ON "entries" ("updated_by_id") /*application='SanastoWiki'*/; +CREATE INDEX "index_entries_on_category" ON "entries" ("category") /*application='SanastoWiki'*/; +CREATE TABLE IF NOT EXISTS "comments" ("id" integer PRIMARY KEY AUTOINCREMENT NOT NULL, "user_id" integer NOT NULL, "commentable_type" varchar NOT NULL, "commentable_id" integer NOT NULL, "body" text NOT NULL, "created_at" datetime(6) NOT NULL, "updated_at" datetime(6) NOT NULL, CONSTRAINT "fk_rails_03de2dc08c" +FOREIGN KEY ("user_id") + REFERENCES "users" ("id") +); +CREATE INDEX "index_comments_on_user_id" ON "comments" ("user_id") /*application='SanastoWiki'*/; +CREATE INDEX "index_comments_on_commentable" ON "comments" ("commentable_type", "commentable_id") /*application='SanastoWiki'*/; +CREATE TABLE IF NOT EXISTS "entry_versions" ("id" integer PRIMARY KEY AUTOINCREMENT NOT NULL, "entry_id" integer NOT NULL, "user_id" integer NOT NULL, "changes_made" json NOT NULL, "change_type" varchar, "created_at" datetime(6) NOT NULL, CONSTRAINT "fk_rails_be24c8cfa1" +FOREIGN KEY ("entry_id") + REFERENCES "entries" ("id") +, CONSTRAINT "fk_rails_aaeb10db8b" +FOREIGN KEY ("user_id") + REFERENCES "users" ("id") +); +CREATE INDEX "index_entry_versions_on_entry_id" ON "entry_versions" ("entry_id") /*application='SanastoWiki'*/; +CREATE INDEX "index_entry_versions_on_user_id" ON "entry_versions" ("user_id") /*application='SanastoWiki'*/; +CREATE TABLE IF NOT EXISTS "supported_languages" ("id" integer PRIMARY KEY AUTOINCREMENT NOT NULL, "code" varchar NOT NULL, "name" varchar NOT NULL, "native_name" varchar NOT NULL, "sort_order" integer DEFAULT 0 NOT NULL, "active" boolean DEFAULT TRUE NOT NULL, "created_at" datetime(6) NOT NULL, "updated_at" datetime(6) NOT NULL); +CREATE UNIQUE INDEX "index_supported_languages_on_code" ON "supported_languages" ("code") /*application='SanastoWiki'*/; +CREATE TABLE IF NOT EXISTS "users" ("id" integer PRIMARY KEY AUTOINCREMENT NOT NULL, "email" varchar NOT NULL, "password_digest" varchar NOT NULL, "name" varchar, "role" integer DEFAULT 0 NOT NULL, "primary_language" varchar, "invitation_token" varchar, "invitation_sent_at" datetime(6), "invitation_accepted_at" datetime(6), "invited_by_id" integer, "created_at" datetime(6) NOT NULL, "updated_at" datetime(6) NOT NULL, CONSTRAINT "fk_rails_ae14a5013f" +FOREIGN KEY ("invited_by_id") + REFERENCES "users" ("id") +); +CREATE INDEX "index_users_on_invited_by_id" ON "users" ("invited_by_id") /*application='SanastoWiki'*/; +CREATE UNIQUE INDEX "index_users_on_email" ON "users" ("email") /*application='SanastoWiki'*/; +CREATE UNIQUE INDEX "index_users_on_invitation_token" ON "users" ("invitation_token") /*application='SanastoWiki'*/; +CREATE TABLE IF NOT EXISTS "suggested_meanings" ("id" integer PRIMARY KEY AUTOINCREMENT NOT NULL, "entry_id" integer NOT NULL, "language_code" varchar NOT NULL, "alternative_translation" varchar NOT NULL, "context" text, "reasoning" text, "source" varchar, "region" varchar, "status" integer DEFAULT 0 NOT NULL, "submitted_by_id" integer NOT NULL, "reviewed_by_id" integer, "reviewed_at" datetime(6), "created_at" datetime(6) NOT NULL, "updated_at" datetime(6) NOT NULL, CONSTRAINT "fk_rails_ef8b9af505" +FOREIGN KEY ("reviewed_by_id") + REFERENCES "users" ("id") +, CONSTRAINT "fk_rails_c971e5e710" +FOREIGN KEY ("submitted_by_id") + REFERENCES "users" ("id") +, CONSTRAINT "fk_rails_3b2160e218" +FOREIGN KEY ("entry_id") + REFERENCES "entries" ("id") +, CONSTRAINT "fk_rails_1050c43426" +FOREIGN KEY ("language_code") + REFERENCES "supported_languages" ("code") +); +CREATE INDEX "index_suggested_meanings_on_entry_id" ON "suggested_meanings" ("entry_id") /*application='SanastoWiki'*/; +CREATE INDEX "index_suggested_meanings_on_submitted_by_id" ON "suggested_meanings" ("submitted_by_id") /*application='SanastoWiki'*/; +CREATE INDEX "index_suggested_meanings_on_reviewed_by_id" ON "suggested_meanings" ("reviewed_by_id") /*application='SanastoWiki'*/; +CREATE INDEX "index_suggested_meanings_on_language_code" ON "suggested_meanings" ("language_code") /*application='SanastoWiki'*/; +CREATE INDEX "index_suggested_meanings_on_status" ON "suggested_meanings" ("status") /*application='SanastoWiki'*/; +CREATE VIRTUAL TABLE entries_fts USING fts5( + fi, + en, + sv, + no, + ru, + de, + notes, + content='entries', + content_rowid='id' +) +/* entries_fts(fi,en,sv,"no",ru,de,notes) */; +CREATE TABLE IF NOT EXISTS 'entries_fts_data'(id INTEGER PRIMARY KEY, block BLOB); +CREATE TABLE IF NOT EXISTS 'entries_fts_idx'(segid, term, pgno, PRIMARY KEY(segid, term)) WITHOUT ROWID; +CREATE TABLE IF NOT EXISTS 'entries_fts_docsize'(id INTEGER PRIMARY KEY, sz BLOB); +CREATE TABLE IF NOT EXISTS 'entries_fts_config'(k PRIMARY KEY, v) WITHOUT ROWID; +CREATE TRIGGER entries_fts_after_insert +AFTER INSERT ON entries +BEGIN + INSERT INTO entries_fts(rowid, fi, en, sv, no, ru, de, notes) + VALUES (new.id, new.fi, new.en, new.sv, new.no, new.ru, new.de, new.notes); +END; +CREATE TRIGGER entries_fts_after_update +AFTER UPDATE ON entries +BEGIN + INSERT INTO entries_fts(entries_fts, rowid, fi, en, sv, no, ru, de, notes) + VALUES('delete', old.id, old.fi, old.en, old.sv, old.no, old.ru, old.de, old.notes); + INSERT INTO entries_fts(rowid, fi, en, sv, no, ru, de, notes) + VALUES (new.id, new.fi, new.en, new.sv, new.no, new.ru, new.de, new.notes); +END; +CREATE TRIGGER entries_fts_after_delete +AFTER DELETE ON entries +BEGIN + INSERT INTO entries_fts(entries_fts, rowid, fi, en, sv, no, ru, de, notes) + VALUES('delete', old.id, old.fi, old.en, old.sv, old.no, old.ru, old.de, old.notes); +END; +INSERT INTO "schema_migrations" (version) VALUES +('20260122130000'), +('20260122124151'), +('20260122123837'), +('20260122123833'), +('20260122123831'), +('20260122123828'), +('20260122123822'), +('20260122123818'), +('0'); +