-- ============================================ -- Vocab Courses - Vollständige SQL-Installation -- ============================================ -- Führe diese Queries direkt auf dem Server aus -- Reihenfolge beachten! -- ============================================ -- 1. Kurs-Tabellen erstellen -- ============================================ -- Kurs-Tabelle CREATE TABLE IF NOT EXISTS community.vocab_course ( id SERIAL PRIMARY KEY, owner_user_id INTEGER NOT NULL, title TEXT NOT NULL, description TEXT, language_id INTEGER NOT NULL, difficulty_level INTEGER DEFAULT 1, is_public BOOLEAN DEFAULT false, share_code TEXT, created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(), updated_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(), CONSTRAINT vocab_course_owner_fk FOREIGN KEY (owner_user_id) REFERENCES community."user"(id) ON DELETE CASCADE, CONSTRAINT vocab_course_language_fk FOREIGN KEY (language_id) REFERENCES community.vocab_language(id) ON DELETE CASCADE, CONSTRAINT vocab_course_share_code_uniq UNIQUE (share_code) ); -- Lektionen innerhalb eines Kurses CREATE TABLE IF NOT EXISTS community.vocab_course_lesson ( id SERIAL PRIMARY KEY, course_id INTEGER NOT NULL, chapter_id INTEGER, lesson_number INTEGER NOT NULL, title TEXT NOT NULL, description TEXT, week_number INTEGER, day_number INTEGER, lesson_type TEXT DEFAULT 'vocab', audio_url TEXT, cultural_notes TEXT, target_minutes INTEGER, target_score_percent INTEGER DEFAULT 80, requires_review BOOLEAN DEFAULT false, created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(), CONSTRAINT vocab_course_lesson_course_fk FOREIGN KEY (course_id) REFERENCES community.vocab_course(id) ON DELETE CASCADE, CONSTRAINT vocab_course_lesson_chapter_fk FOREIGN KEY (chapter_id) REFERENCES community.vocab_chapter(id) ON DELETE CASCADE, CONSTRAINT vocab_course_lesson_unique UNIQUE (course_id, lesson_number) ); -- Einschreibungen in Kurse CREATE TABLE IF NOT EXISTS community.vocab_course_enrollment ( id SERIAL PRIMARY KEY, user_id INTEGER NOT NULL, course_id INTEGER NOT NULL, enrolled_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(), CONSTRAINT vocab_course_enrollment_user_fk FOREIGN KEY (user_id) REFERENCES community."user"(id) ON DELETE CASCADE, CONSTRAINT vocab_course_enrollment_course_fk FOREIGN KEY (course_id) REFERENCES community.vocab_course(id) ON DELETE CASCADE, CONSTRAINT vocab_course_enrollment_unique UNIQUE (user_id, course_id) ); -- Fortschritt pro User und Lektion CREATE TABLE IF NOT EXISTS community.vocab_course_progress ( id SERIAL PRIMARY KEY, user_id INTEGER NOT NULL, course_id INTEGER NOT NULL, lesson_id INTEGER NOT NULL, completed BOOLEAN DEFAULT false, score INTEGER DEFAULT 0, last_accessed_at TIMESTAMP WITHOUT TIME ZONE, completed_at TIMESTAMP WITHOUT TIME ZONE, CONSTRAINT vocab_course_progress_user_fk FOREIGN KEY (user_id) REFERENCES community."user"(id) ON DELETE CASCADE, CONSTRAINT vocab_course_progress_course_fk FOREIGN KEY (course_id) REFERENCES community.vocab_course(id) ON DELETE CASCADE, CONSTRAINT vocab_course_progress_lesson_fk FOREIGN KEY (lesson_id) REFERENCES community.vocab_course_lesson(id) ON DELETE CASCADE, CONSTRAINT vocab_course_progress_unique UNIQUE (user_id, lesson_id) ); -- ============================================ -- 2. Grammatik-Übungstabellen erstellen -- ============================================ -- Grammatik-Übungstypen CREATE TABLE IF NOT EXISTS community.vocab_grammar_exercise_type ( id SERIAL PRIMARY KEY, name TEXT NOT NULL UNIQUE, description TEXT, created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW() ); -- Grammatik-Übungen CREATE TABLE IF NOT EXISTS community.vocab_grammar_exercise ( id SERIAL PRIMARY KEY, lesson_id INTEGER NOT NULL, exercise_type_id INTEGER NOT NULL, exercise_number INTEGER NOT NULL, title TEXT NOT NULL, instruction TEXT, question_data JSONB NOT NULL, answer_data JSONB NOT NULL, explanation TEXT, created_by_user_id INTEGER NOT NULL, created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(), CONSTRAINT vocab_grammar_exercise_lesson_fk FOREIGN KEY (lesson_id) REFERENCES community.vocab_course_lesson(id) ON DELETE CASCADE, CONSTRAINT vocab_grammar_exercise_type_fk FOREIGN KEY (exercise_type_id) REFERENCES community.vocab_grammar_exercise_type(id) ON DELETE CASCADE, CONSTRAINT vocab_grammar_exercise_creator_fk FOREIGN KEY (created_by_user_id) REFERENCES community."user"(id) ON DELETE CASCADE, CONSTRAINT vocab_grammar_exercise_unique UNIQUE (lesson_id, exercise_number) ); -- Fortschritt für Grammatik-Übungen CREATE TABLE IF NOT EXISTS community.vocab_grammar_exercise_progress ( id SERIAL PRIMARY KEY, user_id INTEGER NOT NULL, exercise_id INTEGER NOT NULL, attempts INTEGER DEFAULT 0, correct_attempts INTEGER DEFAULT 0, last_attempt_at TIMESTAMP WITHOUT TIME ZONE, completed BOOLEAN DEFAULT false, completed_at TIMESTAMP WITHOUT TIME ZONE, CONSTRAINT vocab_grammar_exercise_progress_user_fk FOREIGN KEY (user_id) REFERENCES community."user"(id) ON DELETE CASCADE, CONSTRAINT vocab_grammar_exercise_progress_exercise_fk FOREIGN KEY (exercise_id) REFERENCES community.vocab_grammar_exercise(id) ON DELETE CASCADE, CONSTRAINT vocab_grammar_exercise_progress_unique UNIQUE (user_id, exercise_id) ); -- ============================================ -- 3. Indizes erstellen -- ============================================ -- Kurs-Indizes CREATE INDEX IF NOT EXISTS vocab_course_owner_idx ON community.vocab_course(owner_user_id); CREATE INDEX IF NOT EXISTS vocab_course_language_idx ON community.vocab_course(language_id); CREATE INDEX IF NOT EXISTS vocab_course_public_idx ON community.vocab_course(is_public); -- Lektion-Indizes CREATE INDEX IF NOT EXISTS vocab_course_lesson_course_idx ON community.vocab_course_lesson(course_id); CREATE INDEX IF NOT EXISTS vocab_course_lesson_chapter_idx ON community.vocab_course_lesson(chapter_id); CREATE INDEX IF NOT EXISTS vocab_course_lesson_week_idx ON community.vocab_course_lesson(course_id, week_number); CREATE INDEX IF NOT EXISTS vocab_course_lesson_type_idx ON community.vocab_course_lesson(lesson_type); -- Einschreibungs-Indizes CREATE INDEX IF NOT EXISTS vocab_course_enrollment_user_idx ON community.vocab_course_enrollment(user_id); CREATE INDEX IF NOT EXISTS vocab_course_enrollment_course_idx ON community.vocab_course_enrollment(course_id); -- Fortschritts-Indizes CREATE INDEX IF NOT EXISTS vocab_course_progress_user_idx ON community.vocab_course_progress(user_id); CREATE INDEX IF NOT EXISTS vocab_course_progress_course_idx ON community.vocab_course_progress(course_id); CREATE INDEX IF NOT EXISTS vocab_course_progress_lesson_idx ON community.vocab_course_progress(lesson_id); -- Grammatik-Übungs-Indizes CREATE INDEX IF NOT EXISTS vocab_grammar_exercise_lesson_idx ON community.vocab_grammar_exercise(lesson_id); CREATE INDEX IF NOT EXISTS vocab_grammar_exercise_type_idx ON community.vocab_grammar_exercise(exercise_type_id); CREATE INDEX IF NOT EXISTS vocab_grammar_exercise_progress_user_idx ON community.vocab_grammar_exercise_progress(user_id); CREATE INDEX IF NOT EXISTS vocab_grammar_exercise_progress_exercise_idx ON community.vocab_grammar_exercise_progress(exercise_id); -- ============================================ -- 4. Standard-Daten einfügen -- ============================================ -- Standard-Übungstypen für Grammatik INSERT INTO community.vocab_grammar_exercise_type (name, description) VALUES ('gap_fill', 'Lückentext-Übung'), ('multiple_choice', 'Multiple-Choice-Fragen'), ('sentence_building', 'Satzbau-Übung'), ('transformation', 'Satzumformung'), ('conjugation', 'Konjugations-Übung'), ('declension', 'Deklinations-Übung') ON CONFLICT (name) DO NOTHING; -- ============================================ -- 5. Kommentare hinzufügen (optional) -- ============================================ COMMENT ON COLUMN community.vocab_course_lesson.lesson_type IS 'Type: vocab, grammar, conversation, culture, review'; COMMENT ON COLUMN community.vocab_course_lesson.target_minutes IS 'Zielzeit in Minuten für diese Lektion'; COMMENT ON COLUMN community.vocab_course_lesson.target_score_percent IS 'Mindestpunktzahl in Prozent zum Abschluss (z.B. 80)'; COMMENT ON COLUMN community.vocab_course_lesson.requires_review IS 'Muss diese Lektion wiederholt werden, wenn Ziel nicht erreicht?'; -- ============================================ -- Fertig! -- ============================================ -- Alle Tabellen, Indizes und Standard-Daten wurden erstellt. -- Du kannst jetzt Kurse erstellen und verwenden.