From 829957222518f355c69accaa2d08e2fd0619d9e3 Mon Sep 17 00:00:00 2001 From: h7x4 Date: Wed, 14 May 2025 17:12:31 +0200 Subject: [PATCH] migrations: add view for base/furigana queries --- lib/search/word_search.dart | 60 +++++++++++++++---------------------- migrations/0001_JMDict.sql | 35 ++++++++++++++++++++-- 2 files changed, 57 insertions(+), 38 deletions(-) diff --git a/lib/search/word_search.dart b/lib/search/word_search.dart index 32e9704..a6a6bd3 100644 --- a/lib/search/word_search.dart +++ b/lib/search/word_search.dart @@ -99,23 +99,19 @@ Future?> searchWordWithDbConnection( JMdict_SenseAntonym.senseId, JMdict_SenseAntonym.ambiguous, JMdict_SenseAntonym.xrefEntryId, - JMdict_KanjiElementDistinct.reading AS kanji, - JMdict_ReadingElementDistinct.reading AS reading + JMdict_BaseAndFurigana.base, + JMdict_BaseAndFurigana.furigana FROM JMdict_SenseAntonym - LEFT JOIN - (SELECT entryId, reading FROM JMdict_KanjiElement GROUP BY entryId HAVING MIN(orderNum)) - AS JMdict_KanjiElementDistinct - ON JMdict_SenseAntonym.xrefEntryId = JMdict_KanjiElementDistinct.entryId - LEFT JOIN - (SELECT entryId, reading FROM JMdict_ReadingElement GROUP BY entryId HAVING MIN(orderNum)) - AS JMdict_ReadingElementDistinct - ON JMdict_SenseAntonym.xrefEntryId = JMdict_ReadingElementDistinct.entryId - WHERE senseId IN (${senseIds.join(',')}) + JOIN "JMdict_BaseAndFurigana" + ON JMdict_SenseAntonym.xrefEntryId = JMdict_BaseAndFurigana.entryId + WHERE + senseId IN (${senseIds.join(',')}) + AND COALESCE("JMdict_BaseAndFurigana"."kanjiOrderNum", 1) + + "JMdict_BaseAndFurigana"."readingOrderNum" + = 2 ORDER BY JMdict_SenseAntonym.senseId, - JMdict_SenseAntonym.xrefEntryId, - JMdict_KanjiElementDistinct.reading, - JMdict_ReadingElementDistinct.reading + JMdict_SenseAntonym.xrefEntryId """); late final List> senseDialects; @@ -184,23 +180,19 @@ Future?> searchWordWithDbConnection( JMdict_SenseSeeAlso.senseId, JMdict_SenseSeeAlso.ambiguous, JMdict_SenseSeeAlso.xrefEntryId, - JMdict_KanjiElementDistinct.reading AS kanji, - JMdict_ReadingElementDistinct.reading AS reading + JMdict_BaseAndFurigana.base, + JMdict_BaseAndFurigana.furigana FROM JMdict_SenseSeeAlso - LEFT JOIN - (SELECT entryId, reading FROM JMdict_KanjiElement GROUP BY entryId HAVING MIN(orderNum)) - AS JMdict_KanjiElementDistinct - ON JMdict_SenseSeeAlso.xrefEntryId = JMdict_KanjiElementDistinct.entryId - LEFT JOIN - (SELECT entryId, reading FROM JMdict_ReadingElement GROUP BY entryId HAVING MIN(orderNum)) - AS JMdict_ReadingElementDistinct - ON JMdict_SenseSeeAlso.xrefEntryId = JMdict_ReadingElementDistinct.entryId - WHERE senseId IN (${senseIds.join(',')}) + JOIN "JMdict_BaseAndFurigana" + ON JMdict_SenseSeeAlso.xrefEntryId = JMdict_BaseAndFurigana.entryId + WHERE + senseId IN (${senseIds.join(',')}) + AND COALESCE("JMdict_BaseAndFurigana"."kanjiOrderNum", 1) + + "JMdict_BaseAndFurigana"."readingOrderNum" + = 2 ORDER BY JMdict_SenseSeeAlso.senseId, - JMdict_SenseSeeAlso.xrefEntryId, - JMdict_KanjiElementDistinct.reading, - JMdict_ReadingElementDistinct.reading + JMdict_SenseSeeAlso.xrefEntryId """); late final List> exampleSentences; @@ -531,20 +523,16 @@ List _regroup_senses({ seeAlso: seeAlsos .map((e) => WordSearchXrefEntry( entryId: e['xrefEntryId'] as int, - baseWord: (e['kanji'] ?? e['reading']) as String, - furigana: (e['kanji'] != null) ? - (e['reading'] as String) : - null, + baseWord: e['base'] as String, + furigana: e['furigana'] as String?, ambiguous: e['ambiguous'] == 1, )) .toList(), antonyms: antonyms .map((e) => WordSearchXrefEntry( entryId: e['xrefEntryId'] as int, - baseWord: (e['kanji'] ?? e['reading']) as String, - furigana: (e['kanji'] != null) ? - (e['reading'] as String) : - null, + baseWord: e['base'] as String, + furigana: e['furigana'] as String?, ambiguous: e['ambiguous'] == 1, )) .toList(), diff --git a/migrations/0001_JMDict.sql b/migrations/0001_JMDict.sql index 9dec0ff..b2b6218 100644 --- a/migrations/0001_JMDict.sql +++ b/migrations/0001_JMDict.sql @@ -47,9 +47,11 @@ CREATE TABLE "JMdict_KanjiElement" ( "spec" INTEGER CHECK ("spec" BETWEEN 1 AND 2), "gai" INTEGER CHECK ("gai" BETWEEN 1 AND 2), "nf" INTEGER CHECK ("nf" BETWEEN 1 AND 48), - PRIMARY KEY ("entryId", "reading") + PRIMARY KEY ("entryId", "reading"), + UNIQUE("entryId", "orderNum") ) WITHOUT ROWID; +CREATE INDEX "JMdict_KanjiElement_byEntryId_byOrderNum" ON "JMdict_KanjiElement"("entryId", "orderNum"); CREATE INDEX "JMdict_KanjiElement_byReading" ON "JMdict_KanjiElement"("reading"); CREATE TABLE "JMdict_KanjiElementInfo" ( @@ -73,9 +75,11 @@ CREATE TABLE "JMdict_ReadingElement" ( "spec" INTEGER CHECK ("spec" BETWEEN 1 AND 2), "gai" INTEGER CHECK ("gai" BETWEEN 1 AND 2), "nf" INTEGER CHECK ("nf" BETWEEN 1 AND 48), - PRIMARY KEY ("entryId", "reading") + PRIMARY KEY ("entryId", "reading"), + UNIQUE("entryId", "orderNum") ) WITHOUT ROWID; +CREATE INDEX "JMdict_ReadingElement_byEntryId_byOrderNum" ON "JMdict_ReadingElement"("entryId", "orderNum"); CREATE INDEX "JMdict_ReadingElement_byReading" ON "JMdict_ReadingElement"("reading"); CREATE TABLE "JMdict_ReadingElementRestriction" ( @@ -237,6 +241,8 @@ CREATE TABLE "JMdict_ExampleSentence" ( -- "type" TEXT NOT NULL DEFAULT "tat", ); +--- + CREATE VIEW "JMdict_EntryByKana"("kana", "entryId") AS SELECT @@ -244,9 +250,34 @@ SELECT "JMdict_ReadingElement"."entryId" AS "entryId" FROM "JMdict_ReadingElement"; + CREATE VIEW "JMdict_EntryByEnglish"("english", "entryId") AS SELECT "JMdict_SenseGlossary"."phrase" AS "english", "JMdict_Sense"."senseId" AS "entryId" FROM "JMdict_SenseGlossary" JOIN "JMdict_Sense" USING("senseId"); + +CREATE VIEW "JMdict_BaseAndFurigana"("entryId", "base", "furigana", "kanjiOrderNum", "readingOrderNum") +AS +SELECT + "JMdict_Entry"."entryId" AS "entryId", + CASE WHEN ( + "JMdict_KanjiElement"."reading" IS NOT NULL + AND NOT "JMdict_ReadingElement"."readingDoesNotMatchKanji" + ) + THEN "JMdict_KanjiElement"."reading" + ELSE "JMdict_ReadingElement"."reading" + END AS "base", + CASE WHEN ( + "JMdict_KanjiElement"."reading" IS NOT NULL + AND NOT "JMdict_ReadingElement"."readingDoesNotMatchKanji" + ) + THEN "JMdict_ReadingElement"."reading" + ELSE NULL + END AS "furigana", + "JMdict_KanjiElement"."orderNum" AS "kanjiOrderNum", + "JMdict_ReadingElement"."orderNum" AS "readingOrderNum" +FROM "JMdict_Entry" +LEFT JOIN "JMdict_KanjiElement" USING("entryId") +LEFT JOIN "JMdict_ReadingElement" USING("entryId");