hanchu/data/schema.sql
2024-10-20 19:51:30 +07:00

168 lines
4.9 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- Enable foreign key support
PRAGMA foreign_keys = ON;
PRAGMA journal_mode = WAL;
PRAGMA cache_size = -2000;
PRAGMA mmap_size = 30000000000;
-- Words table
CREATE TABLE words (
id INTEGER PRIMARY KEY AUTOINCREMENT,
spelling TEXT NOT NULL,
ipa TEXT NOT NULL,
language_id INTEGER NOT NULL,
frequency INTEGER,
FOREIGN KEY (language_id) REFERENCES languages(id)
);
CREATE INDEX idx_words_spelling ON words(spelling);
CREATE INDEX idx_words_language_id ON words(language_id);
-- Languages table
CREATE TABLE languages (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL
);
-- Parts of Speech table
CREATE TABLE parts_of_speech (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL
);
-- Categories table (for noun and verb categories)
CREATE TABLE categories (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL,
part_of_speech_id INTEGER NOT NULL,
FOREIGN KEY (part_of_speech_id) REFERENCES parts_of_speech(id)
);
CREATE INDEX idx_categories_name ON categories(name);
CREATE INDEX idx_categories_part_of_speech_id ON categories(part_of_speech_id);
-- Word Categories junction table
CREATE TABLE word_categories (
word_id INTEGER NOT NULL,
category_id INTEGER NOT NULL,
PRIMARY KEY (word_id, category_id),
FOREIGN KEY (word_id) REFERENCES words(id),
FOREIGN KEY (category_id) REFERENCES categories(id)
);
CREATE INDEX idx_word_categories_category_id ON word_categories(category_id);
-- Example data insertion
INSERT INTO languages (name) VALUES ('en-us');
INSERT INTO languages (name) VALUES ('th');
INSERT INTO languages (name) VALUES ('zh-cn');
INSERT INTO languages (name) VALUES ('zh-hk');
INSERT INTO languages (name) VALUES ('ja-jp');
INSERT INTO parts_of_speech (name) VALUES ('noun'), ('verb'), ('adjective'), ('adverb'), ('pronoun'), ('adposition'), ('conjunction');
INSERT INTO categories (name, part_of_speech_id) VALUES
('countable', 1),
('uncountable', 1),
('animate', 1),
('inanimate', 1),
('spatial', 1),
('temporal', 1),
('transitive', 2),
('intransitive', 2),
('action', 2),
('mental', 2),
('auxiliar', 2),
('preposition', 6),
('postposition', 6),
('circumposition', 6);
-- Example word insertion
INSERT INTO words (spelling, ipa, language_id) VALUES ('book', 'bʊk', 1);
-- Categorize 'book' as a countable, inanimate noun
INSERT INTO word_categories (word_id, category_id)
SELECT
(SELECT id FROM words WHERE spelling = 'book'),
id
FROM categories
WHERE name IN ('countable', 'inanimate');
-- Example verb insertion
INSERT INTO words (spelling, ipa, language_id) VALUES ('think','θɪŋk', 1);
-- Categorize 'think' as an intransitive, mental verb
INSERT INTO word_categories (word_id, category_id)
SELECT
(SELECT id FROM words WHERE spelling = 'think'),
id
FROM categories
WHERE name IN ('intransitive', 'mental');
-- multi word stuff
CREATE TABLE idioms(
id INTEGER PRIMARY KEY AUTOINCREMENT,
text TEXT NOT NULL,
language_id INTEGER NOT NULL,
frequency INTEGER,
FOREIGN KEY (language_id) REFERENCES languages(id)
);
CREATE TABLE idioms_words(
idiom_id INTEGER NOT NULL,
word_id INTEGER NOT NULL,
PRIMARY KEY (idiom_id, word_id),
FOREIGN KEY (word_id) REFERENCES words(id),
FOREIGN KEY (idiom_id) REFERENCES idioms(id)
);
-- phrasal verbs, other sui generis stuff
CREATE TABLE expressions(
id INTEGER PRIMARY KEY AUTOINCREMENT,
text TEXT NOT NULL,
type TEXT NOT NULL, -- phrasal-verb, result-complement etc.
language_id INTEGER NOT NULL,
FOREIGN KEY (language_id) REFERENCES languages(id)
);
CREATE TABLE expression_words(
expression_id INTEGER NOT NULL,
word_id INTEGER NOT NULL,
PRIMARY KEY (expression_id, word_id),
FOREIGN KEY (expression_id) REFERENCES expressions(id),
FOREIGN KEY (word_id) REFERENCES words(id)
);
-- Progress
CREATE TABLE users(
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL,
creds TEXT NOT NULL
);
CREATE TABLE attempts(
id INTEGER PRIMARY KEY AUTOINCREMENT,
user_id INTEGER NOT NULL,
timestamp INTEGER NOT NULL,
resource_id INTEGER NOT NULL,
resources_type TEXT NOT NULL, -- name of the table, words, expressions, lessons etc.
good INTEGER NOT NULL, -- 0 or 1
FOREIGN KEY (user_id) REFERENCES users(id)
);
-- Index to query attempts on a specific resource
CREATE INDEX idx_attempts_resource ON attempts(resource_id, resources_type);
-- Index to query attempts for a specific user
CREATE INDEX idx_attempts_user ON attempts(user_id);
-- (Optional) Index to query attempts by user and resource (useful if you often query by both)
CREATE INDEX idx_attempts_user_resource ON attempts(user_id, resource_id, resources_type);
-- Lessons
CREATE TABLE lessons(
id INTEGER PRIMARY KEY AUTOINCREMENT,
text TEXT NOT NULL
);
CREATE TABLE lessons_resources(
resource_id INTEGER NOT NULL,
resources_type TEXT NOT NULL, -- name of the table, words, expressions etc.
lesson_id INTEGER NOT NULL,
FOREIGN KEY (lesson_id) REFERENCES lessons(id)
);