Files
jadb/migrations/0005_JMDict_search_index_tables.sql
2025-06-25 20:18:27 +02:00

208 lines
5.8 KiB
SQL

CREATE TABLE "JMdict_EntryScore" (
"type" CHAR(1) NOT NULL CHECK ("type" IN ('r', 'k')),
"entryId" INTEGER NOT NULL REFERENCES "JMdict_Entry"("entryId"),
"elementId" INTEGER NOT NULL,
"score" INTEGER NOT NULL DEFAULT 0,
"common" BOOLEAN NOT NULL DEFAULT FALSE,
PRIMARY KEY ("type", "elementId")
) WITHOUT ROWID;
CREATE INDEX "JMdict_EntryScore_byElementId_byScore" ON "JMdict_EntryScore"("elementId", "score");
CREATE INDEX "JMdict_EntryScore_byScore" ON "JMdict_EntryScore"("score");
CREATE INDEX "JMdict_EntryScore_byCommon" ON "JMdict_EntryScore"("common");
CREATE INDEX "JMdict_EntryScore_byType_byElementId_byScore" ON "JMdict_EntryScore"("type", "elementId", "score");
CREATE INDEX "JMdict_EntryScore_byType_byScore" ON "JMdict_EntryScore"("type", "score");
CREATE INDEX "JMdict_EntryScore_byType_byCommon" ON "JMdict_EntryScore"("type", "common");
-- NOTE: these views are deduplicated in order not to perform an unnecessary
-- UNION on every trigger
CREATE VIEW "JMdict_EntryScoreView_Reading" AS
SELECT
'r' AS "type",
"JMdict_ReadingElement"."entryId",
"JMdict_ReadingElement"."elementId",
(
"news" IS 1
OR "ichi" IS 1
OR "spec" IS 1
OR "gai" IS 1
)
AS "common",
((
"news" IS 1
OR "ichi" IS 1
OR "spec" IS 1
OR "gai" IS 1
) * 50)
+ (("news" IS 1) * 10)
+ (("news" IS 2) * 5)
+ (("ichi" IS 1) * 10)
+ (("ichi" IS 2) * 5)
+ (("spec" IS 1) * 10)
+ (("spec" IS 2) * 5)
+ (("gai" IS 1) * 10)
+ (("gai" IS 2) * 5)
+ (("orderNum" IS 1) * 20)
- (substr(COALESCE("JMdict_JLPTTag"."jlptLevel", 'N0'), 2) * -5)
AS "score"
FROM "JMdict_ReadingElement"
LEFT JOIN "JMdict_JLPTTag" USING ("entryId");
CREATE VIEW "JMdict_EntryScoreView_Kanji" AS
SELECT
'k' AS "type",
"JMdict_KanjiElement"."entryId",
"JMdict_KanjiElement"."elementId",
(
"news" IS 1
OR "ichi" IS 1
OR "spec" IS 1
OR "gai" IS 1
)
AS "common",
((
"news" IS 1
OR "ichi" IS 1
OR "spec" IS 1
OR "gai" IS 1
) * 50)
+ (("news" IS 1) * 10)
+ (("news" IS 2) * 5)
+ (("ichi" IS 1) * 10)
+ (("ichi" IS 2) * 5)
+ (("spec" IS 1) * 10)
+ (("spec" IS 2) * 5)
+ (("gai" IS 1) * 10)
+ (("gai" IS 2) * 5)
+ (("orderNum" IS 1) * 20)
- (substr(COALESCE("JMdict_JLPTTag"."jlptLevel", 'N0'), 2) * -5)
AS "score"
FROM "JMdict_KanjiElement"
LEFT JOIN "JMdict_JLPTTag" USING ("entryId");
CREATE VIEW "JMdict_EntryScoreView" AS
SELECT *
FROM "JMdict_EntryScoreView_Kanji"
UNION ALL
SELECT *
FROM "JMdict_EntryScoreView_Reading";
--- JMdict_ReadingElement triggers
CREATE TRIGGER "JMdict_EntryScore_Insert_JMdict_ReadingElement"
AFTER INSERT ON "JMdict_ReadingElement"
BEGIN
INSERT INTO "JMdict_EntryScore" (
"type",
"entryId",
"elementId",
"score",
"common"
)
SELECT "type", "entryId", "elementId", "score", "common"
FROM "JMdict_EntryScoreView_Reading"
WHERE "elementId" = NEW."elementId";
END;
CREATE TRIGGER "JMdict_EntryScore_Update_JMdict_ReadingElement"
AFTER UPDATE OF "news", "ichi", "spec", "gai", "nf", "orderNum"
ON "JMdict_ReadingElement"
BEGIN
UPDATE "JMdict_EntryScore"
SET
"score" = "JMdict_EntryScoreView_Reading"."score",
"common" = "JMdict_EntryScoreView_Reading"."common"
FROM "JMdict_EntryScoreView_Reading"
WHERE "elementId" = NEW."elementId";
END;
CREATE TRIGGER "JMdict_EntryScore_Delete_JMdict_ReadingElement"
AFTER DELETE ON "JMdict_ReadingElement"
BEGIN
DELETE FROM "JMdict_EntryScore"
WHERE "type" = 'r'
AND "elementId" = OLD."elementId";
END;
--- JMdict_KanjiElement triggers
CREATE TRIGGER "JMdict_EntryScore_Insert_JMdict_KanjiElement"
AFTER INSERT ON "JMdict_KanjiElement"
BEGIN
INSERT INTO "JMdict_EntryScore" (
"type",
"entryId",
"elementId",
"score",
"common"
)
SELECT "type", "entryId", "elementId", "score", "common"
FROM "JMdict_EntryScoreView_Kanji"
WHERE "elementId" = NEW."elementId";
END;
CREATE TRIGGER "JMdict_EntryScore_Update_JMdict_KanjiElement"
AFTER UPDATE OF "news", "ichi", "spec", "gai", "nf", "orderNum"
ON "JMdict_KanjiElement"
BEGIN
UPDATE "JMdict_EntryScore"
SET
"score" = "JMdict_EntryScoreView_Kanji"."score",
"common" = "JMdict_EntryScoreView_Kanji"."common"
FROM "JMdict_EntryScoreView_Kanji"
WHERE "elementId" = NEW."elementId";
END;
CREATE TRIGGER "JMdict_EntryScore_Delete_JMdict_KanjiElement"
AFTER DELETE ON "JMdict_KanjiElement"
BEGIN
DELETE FROM "JMdict_EntryScore"
WHERE "type" = 'k'
AND "elementId" = OLD."elementId";
END;
--- JMdict_JLPTTag triggers
CREATE TRIGGER "JMdict_EntryScore_Insert_JMdict_JLPTTag"
AFTER INSERT ON "JMdict_JLPTTag"
BEGIN
UPDATE "JMdict_EntryScore"
SET
"score" = "JMdict_EntryScoreView"."score",
"common" = "JMdict_EntryScoreView"."common"
FROM "JMdict_EntryScoreView"
WHERE "JMdict_EntryScoreView"."entryId" = NEW."entryId"
AND "JMdict_EntryScore"."entryId" = NEW."entryId"
AND "JMdict_EntryScoreView"."elementId" = "JMdict_EntryScore"."elementId";
END;
CREATE TRIGGER "JMdict_EntryScore_Update_JMdict_JLPTTag"
AFTER UPDATE OF "jlptLevel"
ON "JMdict_JLPTTag"
BEGIN
UPDATE "JMdict_EntryScore"
SET
"score" = "JMdict_EntryScoreView"."score",
"common" = "JMdict_EntryScoreView"."common"
FROM "JMdict_EntryScoreView"
WHERE "JMdict_EntryScoreView"."entryId" = NEW."entryId"
AND "JMdict_EntryScore"."entryId" = NEW."entryId"
AND "JMdict_EntryScoreView"."elementId" = "JMdict_EntryScore"."elementId";
END;
CREATE TRIGGER "JMdict_EntryScore_Delete_JMdict_JLPTTag"
AFTER DELETE ON "JMdict_JLPTTag"
BEGIN
UPDATE "JMdict_EntryScore"
SET
"score" = "JMdict_EntryScoreView"."score",
"common" = "JMdict_EntryScoreView"."common"
FROM "JMdict_EntryScoreView"
WHERE "JMdict_EntryScoreView"."entryId" = OLD."entryId"
AND "JMdict_EntryScore"."entryId" = OLD."entryId"
AND "JMdict_EntryScoreView"."elementId" = "JMdict_EntryScore"."elementId";
END;