From 6eee49d2d1aae3ad1b6a80e026f86e380ecf4f7f Mon Sep 17 00:00:00 2001 From: h7x4 Date: Fri, 23 May 2025 15:28:00 +0200 Subject: [PATCH] lib/search/word: order english queries by score --- lib/search/word_search/entry_id_query.dart | 216 ++++++++++++++------- migrations/0010_Views.sql | 9 + 2 files changed, 160 insertions(+), 65 deletions(-) diff --git a/lib/search/word_search/entry_id_query.dart b/lib/search/word_search/entry_id_query.dart index 3c1833e..a44d3a7 100644 --- a/lib/search/word_search/entry_id_query.dart +++ b/lib/search/word_search/entry_id_query.dart @@ -86,6 +86,135 @@ SearchMode _determineSearchMode(String word) { ] ); +Future> _queryKanji( + DatabaseExecutor connection, + String word, + int pageSize, + int? offset, +) { + final (query, args) = _kanjiReadingTemplate( + JMdictTableNames.kanjiElement, + word, + pageSize: pageSize, + ); + return connection.rawQuery(query, args).then((result) => result + .map((row) => ScoredEntryId( + row['entryId'] as int, + row['score'] as int, + )) + .toList()); +} + +Future _queryKanjiCount( + DatabaseExecutor connection, + String word, +) { + final (query, args) = _kanjiReadingTemplate( + JMdictTableNames.kanjiElement, + word, + countOnly: true, + ); + return connection.rawQuery(query, args).then((result) => result.first['count'] as int); +} + +Future> _queryKana( + DatabaseExecutor connection, + String word, + int pageSize, + int? offset, +) { + final (query, args) = _kanjiReadingTemplate( + JMdictTableNames.readingElement, + word, + pageSize: pageSize, + ); + return connection.rawQuery(query, args).then((result) => result + .map((row) => ScoredEntryId( + row['entryId'] as int, + row['score'] as int, + )) + .toList()); +} + +Future _queryKanaCount( + DatabaseExecutor connection, + String word, +) { + final (query, args) = _kanjiReadingTemplate( + JMdictTableNames.readingElement, + word, + countOnly: true, + ); + return connection.rawQuery(query, args).then((result) => result.first['count'] as int); +} + +Future> _queryEnglish( + DatabaseExecutor connection, + String word, + int pageSize, + int? offset, +) async { + final result = await connection.rawQuery( + ''' + SELECT + "${JMdictTableNames.sense}"."entryId", + MAX("JMdict_EntryScore"."score") + + (("${JMdictTableNames.senseGlossary}"."phrase" = ? AND "${JMdictTableNames.sense}"."orderNum" = 1) * 50) + + (("${JMdictTableNames.senseGlossary}"."phrase" = ? AND "${JMdictTableNames.sense}"."orderNum" = 2) * 30) + + (("${JMdictTableNames.senseGlossary}"."phrase" = ?) * 20) + as "score" + FROM "${JMdictTableNames.senseGlossary}" + JOIN "${JMdictTableNames.sense}" USING ("senseId") + JOIN "JMdict_EntryScore" USING ("entryId") + WHERE "${JMdictTableNames.senseGlossary}"."phrase" LIKE ? + GROUP BY "JMdict_EntryScore"."entryId" + ORDER BY + "score" DESC, + "${JMdictTableNames.sense}"."entryId" ASC + LIMIT ? + OFFSET ? + ''' + .trim(), + [ + word, + '%$word%', + '%$word%', + '%$word%', + pageSize, + offset, + ], + ); + + return result + .map((row) => ScoredEntryId( + row['entryId'] as int, + row['score'] as int, + )) + .toList(); +} + +Future _queryEnglishCount( + DatabaseExecutor connection, + String word, +) async { + final result = await connection.rawQuery( + ''' + + SELECT + COUNT(DISTINCT "${JMdictTableNames.sense}"."entryId") AS "count" + FROM "${JMdictTableNames.senseGlossary}" + JOIN "${JMdictTableNames.sense}" USING ("senseId") + WHERE "${JMdictTableNames.senseGlossary}"."phrase" LIKE ? + ''' + .trim(), + [ + '%$word%', + ], + ); + + return result.first['count'] as int; +} + Future> fetchEntryIds( DatabaseExecutor connection, String word, @@ -105,56 +234,30 @@ Future> fetchEntryIds( late final List entryIds; switch (searchMode) { case SearchMode.Kanji: - final (query, args) = _kanjiReadingTemplate( - JMdictTableNames.kanjiElement, + entryIds = await _queryKanji( + connection, word, - pageSize: pageSize, + pageSize, + offset, ); - entryIds = (await connection.rawQuery(query, args)) - .map((row) => ScoredEntryId( - row['entryId'] as int, - row['score'] as int, - )) - .toList(); break; case SearchMode.Kana: - final (query, args) = _kanjiReadingTemplate( - JMdictTableNames.readingElement, + entryIds = await _queryKana( + connection, word, - pageSize: pageSize, + pageSize, + offset, ); - entryIds = (await connection.rawQuery(query, args)) - .map((row) => ScoredEntryId( - row['entryId'] as int, - row['score'] as int, - )) - .toList(); break; case SearchMode.English: - entryIds = (await connection.rawQuery( - ''' - SELECT DISTINCT - "${JMdictTableNames.sense}"."entryId" - FROM "${JMdictTableNames.senseGlossary}" - JOIN "${JMdictTableNames.sense}" USING ("senseId") - WHERE "${JMdictTableNames.senseGlossary}"."phrase" LIKE ? - LIMIT ? - OFFSET ? - ''' - .trim(), - [ - '%$word%', - pageSize, - offset, - ], - )) - .map((row) => ScoredEntryId( - row['entryId'] as int, - 0, - )) - .toList(); + entryIds = await _queryEnglish( + connection, + word, + pageSize, + offset, + ); break; case SearchMode.MixedKana: @@ -187,41 +290,24 @@ Future fetchEntryIdCount( switch (searchMode) { case SearchMode.Kanji: - final (query, args) = _kanjiReadingTemplate( - JMdictTableNames.kanjiElement, + entryIdCount = await _queryKanjiCount( + connection, word, - pageSize: 1, - countOnly: true, ); - entryIdCount = (await connection.rawQuery(query, args)) - .firstOrNull?['count'] as int?; break; case SearchMode.Kana: - final (query, args) = _kanjiReadingTemplate( - JMdictTableNames.readingElement, + entryIdCount = await _queryKanaCount( + connection, word, - pageSize: 1, - countOnly: true, ); - entryIdCount = (await connection.rawQuery(query, args)) - .firstOrNull?['count'] as int?; break; case SearchMode.English: - entryIdCount = (await connection.rawQuery( - ''' - SELECT COUNT(DISTINCT "${JMdictTableNames.sense}"."entryId") AS "count" - FROM "${JMdictTableNames.senseGlossary}" - JOIN "${JMdictTableNames.sense}" USING ("senseId") - WHERE "${JMdictTableNames.senseGlossary}"."phrase" LIKE ? - ''' - .trim(), - [ - '%$word%', - ], - )) - .firstOrNull?['count'] as int?; + entryIdCount = await _queryEnglishCount( + connection, + word, + ); break; case SearchMode.MixedKana: diff --git a/migrations/0010_Views.sql b/migrations/0010_Views.sql index c9ca2f8..b0acf94 100644 --- a/migrations/0010_Views.sql +++ b/migrations/0010_Views.sql @@ -73,3 +73,12 @@ WHERE "JMdict_EntryScore"."common" = 1; CREATE VIEW "RADKFILE_Radicals" AS SELECT DISTINCT "radical" FROM "RADKFILE"; + +CREATE VIEW "JMdict_CombinedEntryScore" +AS +SELECT + "JMdict_EntryScore"."entryId", + MAX("JMdict_EntryScore"."score") AS "score", + MAX("JMdict_EntryScore"."common") AS "common" +FROM "JMdict_EntryScore" +GROUP BY "JMdict_EntryScore"."entryId";