Add Vocab Trainer feature with routing, database schema, and translations
- Introduced Vocab Trainer functionality, including new routes for managing languages and chapters. - Implemented database schema for vocab-related tables to ensure data integrity. - Updated navigation and UI components to include Vocab Trainer in the social network menu. - Added translations for Vocab Trainer in both German and English locales, enhancing user accessibility.
This commit is contained in:
@@ -18,6 +18,7 @@ import taxiRouter from './routers/taxiRouter.js';
|
||||
import taxiMapRouter from './routers/taxiMapRouter.js';
|
||||
import taxiHighscoreRouter from './routers/taxiHighscoreRouter.js';
|
||||
import termineRouter from './routers/termineRouter.js';
|
||||
import vocabRouter from './routers/vocabRouter.js';
|
||||
import cors from 'cors';
|
||||
import './jobs/sessionCleanup.js';
|
||||
|
||||
@@ -69,6 +70,7 @@ app.use('/api/taxi/highscores', taxiHighscoreRouter);
|
||||
app.use('/images', express.static(path.join(__dirname, '../frontend/public/images')));
|
||||
app.use('/api/contact', contactRouter);
|
||||
app.use('/api/socialnetwork', socialnetworkRouter);
|
||||
app.use('/api/vocab', vocabRouter);
|
||||
app.use('/api/forum', forumRouter);
|
||||
app.use('/api/falukant', falukantRouter);
|
||||
app.use('/api/friendships', friendshipRouter);
|
||||
|
||||
@@ -4,6 +4,7 @@ import UserRight from '../models/community/user_right.js';
|
||||
import UserRightType from '../models/type/user_right.js';
|
||||
import UserParamType from '../models/type/user_param.js';
|
||||
import FalukantUser from '../models/falukant/data/user.js';
|
||||
import VocabService from '../services/vocabService.js';
|
||||
|
||||
const menuStructure = {
|
||||
home: {
|
||||
@@ -49,6 +50,11 @@ const menuStructure = {
|
||||
visible: ["all"],
|
||||
path: "/socialnetwork/gallery"
|
||||
},
|
||||
vocabtrainer: {
|
||||
visible: ["all"],
|
||||
path: "/socialnetwork/vocab",
|
||||
children: {}
|
||||
},
|
||||
blockedUsers: {
|
||||
visible: ["all"],
|
||||
path: "/socialnetwork/blocked"
|
||||
@@ -296,6 +302,7 @@ const menuStructure = {
|
||||
class NavigationController {
|
||||
constructor() {
|
||||
this.menu = this.menu.bind(this);
|
||||
this.vocabService = new VocabService();
|
||||
}
|
||||
|
||||
calculateAge(birthDate) {
|
||||
@@ -365,6 +372,24 @@ class NavigationController {
|
||||
const age = this.calculateAge(birthDate);
|
||||
const rights = userRights.map(ur => ur.rightType?.title).filter(Boolean);
|
||||
const filteredMenu = await this.filterMenu(menuStructure, rights, age, user.id);
|
||||
|
||||
// Dynamisches Submenü: Treffpunkt → Vokabeltrainer → (Neue Sprache + abonnierte/angelegte)
|
||||
// Wichtig: "Neue Sprache" soll IMMER sichtbar sein – auch wenn die DB-Abfrage (noch) fehlschlägt.
|
||||
if (filteredMenu?.socialnetwork?.children?.vocabtrainer) {
|
||||
const children = {
|
||||
newLanguage: { path: '/socialnetwork/vocab/new' },
|
||||
};
|
||||
try {
|
||||
const langs = await this.vocabService.listLanguagesForMenu(user.id);
|
||||
for (const l of langs) {
|
||||
children[`lang_${l.id}`] = { path: `/socialnetwork/vocab/${l.id}`, label: l.name };
|
||||
}
|
||||
} catch (e) {
|
||||
console.warn('[menu] Konnte Vokabeltrainer-Sprachen nicht laden:', e?.message || e);
|
||||
}
|
||||
filteredMenu.socialnetwork.children.vocabtrainer.children = children;
|
||||
}
|
||||
|
||||
res.status(200).json(filteredMenu);
|
||||
} catch (error) {
|
||||
console.error('Error fetching menu:', error);
|
||||
|
||||
45
backend/controllers/vocabController.js
Normal file
45
backend/controllers/vocabController.js
Normal file
@@ -0,0 +1,45 @@
|
||||
import VocabService from '../services/vocabService.js';
|
||||
|
||||
function extractHashedUserId(req) {
|
||||
return req.headers?.userid;
|
||||
}
|
||||
|
||||
class VocabController {
|
||||
constructor() {
|
||||
this.service = new VocabService();
|
||||
|
||||
this.listLanguages = this._wrapWithUser((userId) => this.service.listLanguages(userId));
|
||||
this.createLanguage = this._wrapWithUser((userId, req) => this.service.createLanguage(userId, req.body), { successStatus: 201 });
|
||||
this.subscribe = this._wrapWithUser((userId, req) => this.service.subscribeByShareCode(userId, req.body), { successStatus: 201 });
|
||||
this.getLanguage = this._wrapWithUser((userId, req) => this.service.getLanguage(userId, req.params.languageId));
|
||||
|
||||
this.listChapters = this._wrapWithUser((userId, req) => this.service.listChapters(userId, req.params.languageId));
|
||||
this.createChapter = this._wrapWithUser((userId, req) => this.service.createChapter(userId, req.params.languageId, req.body), { successStatus: 201 });
|
||||
this.listLanguageVocabs = this._wrapWithUser((userId, req) => this.service.listLanguageVocabs(userId, req.params.languageId));
|
||||
|
||||
this.getChapter = this._wrapWithUser((userId, req) => this.service.getChapter(userId, req.params.chapterId));
|
||||
this.listChapterVocabs = this._wrapWithUser((userId, req) => this.service.listChapterVocabs(userId, req.params.chapterId));
|
||||
this.addVocabToChapter = this._wrapWithUser((userId, req) => this.service.addVocabToChapter(userId, req.params.chapterId, req.body), { successStatus: 201 });
|
||||
}
|
||||
|
||||
_wrapWithUser(fn, { successStatus = 200 } = {}) {
|
||||
return async (req, res) => {
|
||||
try {
|
||||
const hashedUserId = extractHashedUserId(req);
|
||||
if (!hashedUserId) {
|
||||
return res.status(400).json({ error: 'Missing user identifier' });
|
||||
}
|
||||
const result = await fn(hashedUserId, req, res);
|
||||
res.status(successStatus).json(result);
|
||||
} catch (error) {
|
||||
console.error('Controller error:', error);
|
||||
const status = error.status && typeof error.status === 'number' ? error.status : 500;
|
||||
res.status(status).json({ error: error.message || 'Internal error' });
|
||||
}
|
||||
};
|
||||
}
|
||||
}
|
||||
|
||||
export default VocabController;
|
||||
|
||||
|
||||
@@ -0,0 +1,61 @@
|
||||
/* eslint-disable */
|
||||
'use strict';
|
||||
|
||||
module.exports = {
|
||||
async up(queryInterface) {
|
||||
// Sprache / Set, das geteilt werden kann
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_language (
|
||||
id SERIAL PRIMARY KEY,
|
||||
owner_user_id INTEGER NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
share_code TEXT NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_language_owner_fk
|
||||
FOREIGN KEY (owner_user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_language_share_code_uniq UNIQUE (share_code)
|
||||
);
|
||||
`);
|
||||
|
||||
// Abos (Freunde)
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_language_subscription (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_id INTEGER NOT NULL,
|
||||
language_id INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_language_subscription_user_fk
|
||||
FOREIGN KEY (user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_language_subscription_language_fk
|
||||
FOREIGN KEY (language_id)
|
||||
REFERENCES community.vocab_language(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_language_subscription_uniq UNIQUE (user_id, language_id)
|
||||
);
|
||||
`);
|
||||
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE INDEX IF NOT EXISTS vocab_language_owner_idx
|
||||
ON community.vocab_language(owner_user_id);
|
||||
`);
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE INDEX IF NOT EXISTS vocab_language_subscription_user_idx
|
||||
ON community.vocab_language_subscription(user_id);
|
||||
`);
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE INDEX IF NOT EXISTS vocab_language_subscription_language_idx
|
||||
ON community.vocab_language_subscription(language_id);
|
||||
`);
|
||||
},
|
||||
|
||||
async down(queryInterface) {
|
||||
await queryInterface.sequelize.query(`DROP TABLE IF EXISTS community.vocab_language_subscription;`);
|
||||
await queryInterface.sequelize.query(`DROP TABLE IF EXISTS community.vocab_language;`);
|
||||
}
|
||||
};
|
||||
|
||||
|
||||
@@ -0,0 +1,106 @@
|
||||
/* eslint-disable */
|
||||
'use strict';
|
||||
|
||||
module.exports = {
|
||||
async up(queryInterface) {
|
||||
// Kapitel innerhalb einer Sprache
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_chapter (
|
||||
id SERIAL PRIMARY KEY,
|
||||
language_id INTEGER NOT NULL,
|
||||
title TEXT NOT NULL,
|
||||
created_by_user_id INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_chapter_language_fk
|
||||
FOREIGN KEY (language_id)
|
||||
REFERENCES community.vocab_language(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chapter_creator_fk
|
||||
FOREIGN KEY (created_by_user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE
|
||||
);
|
||||
`);
|
||||
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE INDEX IF NOT EXISTS vocab_chapter_language_idx
|
||||
ON community.vocab_chapter(language_id);
|
||||
`);
|
||||
|
||||
// Lexeme/Wörter (wir deduplizieren pro Sprache über normalized)
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_lexeme (
|
||||
id SERIAL PRIMARY KEY,
|
||||
language_id INTEGER NOT NULL,
|
||||
text TEXT NOT NULL,
|
||||
normalized TEXT NOT NULL,
|
||||
created_by_user_id INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_lexeme_language_fk
|
||||
FOREIGN KEY (language_id)
|
||||
REFERENCES community.vocab_language(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_lexeme_creator_fk
|
||||
FOREIGN KEY (created_by_user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_lexeme_unique_per_language UNIQUE (language_id, normalized)
|
||||
);
|
||||
`);
|
||||
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE INDEX IF NOT EXISTS vocab_lexeme_language_idx
|
||||
ON community.vocab_lexeme(language_id);
|
||||
`);
|
||||
|
||||
// n:m Zuordnung pro Kapitel: Lernwort ↔ Referenzwort (Mehrdeutigkeiten möglich)
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_chapter_lexeme (
|
||||
id SERIAL PRIMARY KEY,
|
||||
chapter_id INTEGER NOT NULL,
|
||||
learning_lexeme_id INTEGER NOT NULL,
|
||||
reference_lexeme_id INTEGER NOT NULL,
|
||||
created_by_user_id INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_chlex_chapter_fk
|
||||
FOREIGN KEY (chapter_id)
|
||||
REFERENCES community.vocab_chapter(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chlex_learning_fk
|
||||
FOREIGN KEY (learning_lexeme_id)
|
||||
REFERENCES community.vocab_lexeme(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chlex_reference_fk
|
||||
FOREIGN KEY (reference_lexeme_id)
|
||||
REFERENCES community.vocab_lexeme(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chlex_creator_fk
|
||||
FOREIGN KEY (created_by_user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chlex_unique UNIQUE (chapter_id, learning_lexeme_id, reference_lexeme_id)
|
||||
);
|
||||
`);
|
||||
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE INDEX IF NOT EXISTS vocab_chlex_chapter_idx
|
||||
ON community.vocab_chapter_lexeme(chapter_id);
|
||||
`);
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE INDEX IF NOT EXISTS vocab_chlex_learning_idx
|
||||
ON community.vocab_chapter_lexeme(learning_lexeme_id);
|
||||
`);
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE INDEX IF NOT EXISTS vocab_chlex_reference_idx
|
||||
ON community.vocab_chapter_lexeme(reference_lexeme_id);
|
||||
`);
|
||||
},
|
||||
|
||||
async down(queryInterface) {
|
||||
await queryInterface.sequelize.query(`DROP TABLE IF EXISTS community.vocab_chapter_lexeme;`);
|
||||
await queryInterface.sequelize.query(`DROP TABLE IF EXISTS community.vocab_lexeme;`);
|
||||
await queryInterface.sequelize.query(`DROP TABLE IF EXISTS community.vocab_chapter;`);
|
||||
}
|
||||
};
|
||||
|
||||
|
||||
26
backend/routers/vocabRouter.js
Normal file
26
backend/routers/vocabRouter.js
Normal file
@@ -0,0 +1,26 @@
|
||||
import express from 'express';
|
||||
import { authenticate } from '../middleware/authMiddleware.js';
|
||||
import VocabController from '../controllers/vocabController.js';
|
||||
|
||||
const router = express.Router();
|
||||
const vocabController = new VocabController();
|
||||
|
||||
router.use(authenticate);
|
||||
|
||||
router.get('/languages', vocabController.listLanguages);
|
||||
router.post('/languages', vocabController.createLanguage);
|
||||
router.post('/subscribe', vocabController.subscribe);
|
||||
router.get('/languages/:languageId', vocabController.getLanguage);
|
||||
|
||||
// Kapitel
|
||||
router.get('/languages/:languageId/chapters', vocabController.listChapters);
|
||||
router.post('/languages/:languageId/chapters', vocabController.createChapter);
|
||||
router.get('/languages/:languageId/vocabs', vocabController.listLanguageVocabs);
|
||||
|
||||
router.get('/chapters/:chapterId', vocabController.getChapter);
|
||||
router.get('/chapters/:chapterId/vocabs', vocabController.listChapterVocabs);
|
||||
router.post('/chapters/:chapterId/vocabs', vocabController.addVocabToChapter);
|
||||
|
||||
export default router;
|
||||
|
||||
|
||||
485
backend/services/vocabService.js
Normal file
485
backend/services/vocabService.js
Normal file
@@ -0,0 +1,485 @@
|
||||
import crypto from 'crypto';
|
||||
import User from '../models/community/user.js';
|
||||
import { sequelize } from '../utils/sequelize.js';
|
||||
import { notifyUser } from '../utils/socket.js';
|
||||
|
||||
export default class VocabService {
|
||||
async _getUserByHashedId(hashedUserId) {
|
||||
const user = await User.findOne({ where: { hashedId: hashedUserId } });
|
||||
if (!user) {
|
||||
const err = new Error('User not found');
|
||||
err.status = 404;
|
||||
throw err;
|
||||
}
|
||||
return user;
|
||||
}
|
||||
|
||||
_normalizeLexeme(text) {
|
||||
return String(text || '')
|
||||
.trim()
|
||||
.toLowerCase()
|
||||
.replace(/\s+/g, ' ');
|
||||
}
|
||||
|
||||
async _getLanguageAccess(userId, languageId) {
|
||||
const id = Number.parseInt(languageId, 10);
|
||||
if (!Number.isFinite(id)) {
|
||||
const err = new Error('Invalid language id');
|
||||
err.status = 400;
|
||||
throw err;
|
||||
}
|
||||
|
||||
const [row] = await sequelize.query(
|
||||
`
|
||||
SELECT
|
||||
l.id,
|
||||
(l.owner_user_id = :userId) AS "isOwner"
|
||||
FROM community.vocab_language l
|
||||
WHERE l.id = :languageId
|
||||
AND (
|
||||
l.owner_user_id = :userId
|
||||
OR EXISTS (
|
||||
SELECT 1
|
||||
FROM community.vocab_language_subscription s
|
||||
WHERE s.user_id = :userId AND s.language_id = l.id
|
||||
)
|
||||
)
|
||||
LIMIT 1
|
||||
`,
|
||||
{
|
||||
replacements: { userId, languageId: id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
if (!row) {
|
||||
const err = new Error('Language not found or no access');
|
||||
err.status = 404;
|
||||
throw err;
|
||||
}
|
||||
|
||||
return row;
|
||||
}
|
||||
|
||||
async _getChapterAccess(userId, chapterId) {
|
||||
const id = Number.parseInt(chapterId, 10);
|
||||
if (!Number.isFinite(id)) {
|
||||
const err = new Error('Invalid chapter id');
|
||||
err.status = 400;
|
||||
throw err;
|
||||
}
|
||||
|
||||
const [row] = await sequelize.query(
|
||||
`
|
||||
SELECT
|
||||
c.id,
|
||||
c.language_id AS "languageId",
|
||||
c.title,
|
||||
(l.owner_user_id = :userId) AS "isOwner"
|
||||
FROM community.vocab_chapter c
|
||||
JOIN community.vocab_language l ON l.id = c.language_id
|
||||
WHERE c.id = :chapterId
|
||||
AND (
|
||||
l.owner_user_id = :userId
|
||||
OR EXISTS (
|
||||
SELECT 1
|
||||
FROM community.vocab_language_subscription s
|
||||
WHERE s.user_id = :userId AND s.language_id = l.id
|
||||
)
|
||||
)
|
||||
LIMIT 1
|
||||
`,
|
||||
{
|
||||
replacements: { userId, chapterId: id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
if (!row) {
|
||||
const err = new Error('Chapter not found or no access');
|
||||
err.status = 404;
|
||||
throw err;
|
||||
}
|
||||
|
||||
return row;
|
||||
}
|
||||
|
||||
async listLanguages(hashedUserId) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
|
||||
const rows = await sequelize.query(
|
||||
`
|
||||
SELECT
|
||||
l.id,
|
||||
l.name,
|
||||
l.share_code AS "shareCode",
|
||||
TRUE AS "isOwner"
|
||||
FROM community.vocab_language l
|
||||
WHERE l.owner_user_id = :userId
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
l.id,
|
||||
l.name,
|
||||
NULL::text AS "shareCode",
|
||||
FALSE AS "isOwner"
|
||||
FROM community.vocab_language_subscription s
|
||||
JOIN community.vocab_language l ON l.id = s.language_id
|
||||
WHERE s.user_id = :userId
|
||||
|
||||
ORDER BY name ASC
|
||||
`,
|
||||
{
|
||||
replacements: { userId: user.id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
return { languages: rows };
|
||||
}
|
||||
|
||||
async listLanguagesForMenu(userId) {
|
||||
// userId ist die numerische community.user.id
|
||||
const rows = await sequelize.query(
|
||||
`
|
||||
SELECT l.id, l.name
|
||||
FROM community.vocab_language l
|
||||
WHERE l.owner_user_id = :userId
|
||||
UNION
|
||||
SELECT l.id, l.name
|
||||
FROM community.vocab_language_subscription s
|
||||
JOIN community.vocab_language l ON l.id = s.language_id
|
||||
WHERE s.user_id = :userId
|
||||
ORDER BY name ASC
|
||||
`,
|
||||
{
|
||||
replacements: { userId },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
return rows;
|
||||
}
|
||||
|
||||
async createLanguage(hashedUserId, { name }) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const cleanName = typeof name === 'string' ? name.trim() : '';
|
||||
if (!cleanName || cleanName.length < 2 || cleanName.length > 60) {
|
||||
const err = new Error('Invalid language name');
|
||||
err.status = 400;
|
||||
throw err;
|
||||
}
|
||||
|
||||
// 16 hex chars => ausreichend kurz, gut teilbar
|
||||
const shareCode = crypto.randomBytes(8).toString('hex');
|
||||
|
||||
const [created] = await sequelize.query(
|
||||
`
|
||||
INSERT INTO community.vocab_language (owner_user_id, name, share_code)
|
||||
VALUES (:ownerUserId, :name, :shareCode)
|
||||
RETURNING id, name, share_code AS "shareCode"
|
||||
`,
|
||||
{
|
||||
replacements: { ownerUserId: user.id, name: cleanName, shareCode },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
// Menü dynamisch nachladen (bei allen offenen Tabs/Clients)
|
||||
try {
|
||||
notifyUser(user.hashedId, 'reloadmenu', {});
|
||||
} catch (_) {}
|
||||
|
||||
return created;
|
||||
}
|
||||
|
||||
async subscribeByShareCode(hashedUserId, { shareCode }) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const code = typeof shareCode === 'string' ? shareCode.trim() : '';
|
||||
if (!code || code.length < 6 || code.length > 128) {
|
||||
const err = new Error('Invalid share code');
|
||||
err.status = 400;
|
||||
throw err;
|
||||
}
|
||||
|
||||
const [lang] = await sequelize.query(
|
||||
`
|
||||
SELECT id, owner_user_id AS "ownerUserId", name
|
||||
FROM community.vocab_language
|
||||
WHERE share_code = :shareCode
|
||||
LIMIT 1
|
||||
`,
|
||||
{
|
||||
replacements: { shareCode: code },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
if (!lang) {
|
||||
const err = new Error('Language not found');
|
||||
err.status = 404;
|
||||
throw err;
|
||||
}
|
||||
|
||||
// Owner braucht kein Abo
|
||||
if (lang.ownerUserId === user.id) {
|
||||
return { subscribed: false, message: 'Already owner', languageId: lang.id };
|
||||
}
|
||||
|
||||
await sequelize.query(
|
||||
`
|
||||
INSERT INTO community.vocab_language_subscription (user_id, language_id)
|
||||
VALUES (:userId, :languageId)
|
||||
ON CONFLICT (user_id, language_id) DO NOTHING
|
||||
`,
|
||||
{
|
||||
replacements: { userId: user.id, languageId: lang.id },
|
||||
type: sequelize.QueryTypes.INSERT,
|
||||
}
|
||||
);
|
||||
|
||||
try {
|
||||
notifyUser(user.hashedId, 'reloadmenu', {});
|
||||
} catch (_) {}
|
||||
|
||||
return { subscribed: true, languageId: lang.id, name: lang.name };
|
||||
}
|
||||
|
||||
async getLanguage(hashedUserId, languageId) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const id = Number.parseInt(languageId, 10);
|
||||
if (!Number.isFinite(id)) {
|
||||
const err = new Error('Invalid language id');
|
||||
err.status = 400;
|
||||
throw err;
|
||||
}
|
||||
|
||||
const [row] = await sequelize.query(
|
||||
`
|
||||
SELECT
|
||||
l.id,
|
||||
l.name,
|
||||
CASE WHEN l.owner_user_id = :userId THEN l.share_code ELSE NULL END AS "shareCode",
|
||||
(l.owner_user_id = :userId) AS "isOwner"
|
||||
FROM community.vocab_language l
|
||||
WHERE l.id = :languageId
|
||||
AND (
|
||||
l.owner_user_id = :userId
|
||||
OR EXISTS (
|
||||
SELECT 1
|
||||
FROM community.vocab_language_subscription s
|
||||
WHERE s.user_id = :userId AND s.language_id = l.id
|
||||
)
|
||||
)
|
||||
LIMIT 1
|
||||
`,
|
||||
{
|
||||
replacements: { userId: user.id, languageId: id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
if (!row) {
|
||||
const err = new Error('Language not found or no access');
|
||||
err.status = 404;
|
||||
throw err;
|
||||
}
|
||||
|
||||
return row;
|
||||
}
|
||||
|
||||
async listChapters(hashedUserId, languageId) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const access = await this._getLanguageAccess(user.id, languageId);
|
||||
|
||||
const rows = await sequelize.query(
|
||||
`
|
||||
SELECT
|
||||
c.id,
|
||||
c.title,
|
||||
c.created_at AS "createdAt",
|
||||
(
|
||||
SELECT COUNT(*)
|
||||
FROM community.vocab_chapter_lexeme cl
|
||||
WHERE cl.chapter_id = c.id
|
||||
)::int AS "vocabCount"
|
||||
FROM community.vocab_chapter c
|
||||
WHERE c.language_id = :languageId
|
||||
ORDER BY c.title ASC
|
||||
`,
|
||||
{
|
||||
replacements: { languageId: access.id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
return { chapters: rows, isOwner: access.isOwner };
|
||||
}
|
||||
|
||||
async createChapter(hashedUserId, languageId, { title }) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const access = await this._getLanguageAccess(user.id, languageId);
|
||||
if (!access.isOwner) {
|
||||
const err = new Error('Only owner can create chapters');
|
||||
err.status = 403;
|
||||
throw err;
|
||||
}
|
||||
|
||||
const cleanTitle = typeof title === 'string' ? title.trim() : '';
|
||||
if (!cleanTitle || cleanTitle.length < 2 || cleanTitle.length > 80) {
|
||||
const err = new Error('Invalid chapter title');
|
||||
err.status = 400;
|
||||
throw err;
|
||||
}
|
||||
|
||||
const [created] = await sequelize.query(
|
||||
`
|
||||
INSERT INTO community.vocab_chapter (language_id, title, created_by_user_id)
|
||||
VALUES (:languageId, :title, :userId)
|
||||
RETURNING id, title, created_at AS "createdAt"
|
||||
`,
|
||||
{
|
||||
replacements: { languageId: access.id, title: cleanTitle, userId: user.id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
return created;
|
||||
}
|
||||
|
||||
async getChapter(hashedUserId, chapterId) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const ch = await this._getChapterAccess(user.id, chapterId);
|
||||
return { id: ch.id, languageId: ch.languageId, title: ch.title, isOwner: ch.isOwner };
|
||||
}
|
||||
|
||||
async listChapterVocabs(hashedUserId, chapterId) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const ch = await this._getChapterAccess(user.id, chapterId);
|
||||
|
||||
const rows = await sequelize.query(
|
||||
`
|
||||
SELECT
|
||||
cl.id,
|
||||
l1.text AS "learning",
|
||||
l2.text AS "reference",
|
||||
cl.created_at AS "createdAt"
|
||||
FROM community.vocab_chapter_lexeme cl
|
||||
JOIN community.vocab_lexeme l1 ON l1.id = cl.learning_lexeme_id
|
||||
JOIN community.vocab_lexeme l2 ON l2.id = cl.reference_lexeme_id
|
||||
WHERE cl.chapter_id = :chapterId
|
||||
ORDER BY l1.text ASC, l2.text ASC
|
||||
`,
|
||||
{
|
||||
replacements: { chapterId: ch.id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
return { chapter: { id: ch.id, title: ch.title, languageId: ch.languageId, isOwner: ch.isOwner }, vocabs: rows };
|
||||
}
|
||||
|
||||
async listLanguageVocabs(hashedUserId, languageId) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const access = await this._getLanguageAccess(user.id, languageId);
|
||||
|
||||
const rows = await sequelize.query(
|
||||
`
|
||||
SELECT
|
||||
cl.id,
|
||||
c.id AS "chapterId",
|
||||
c.title AS "chapterTitle",
|
||||
l1.text AS "learning",
|
||||
l2.text AS "reference",
|
||||
cl.created_at AS "createdAt"
|
||||
FROM community.vocab_chapter_lexeme cl
|
||||
JOIN community.vocab_chapter c ON c.id = cl.chapter_id
|
||||
JOIN community.vocab_lexeme l1 ON l1.id = cl.learning_lexeme_id
|
||||
JOIN community.vocab_lexeme l2 ON l2.id = cl.reference_lexeme_id
|
||||
WHERE c.language_id = :languageId
|
||||
ORDER BY c.title ASC, l1.text ASC, l2.text ASC
|
||||
`,
|
||||
{
|
||||
replacements: { languageId: access.id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
}
|
||||
);
|
||||
|
||||
return { languageId: access.id, isOwner: access.isOwner, vocabs: rows };
|
||||
}
|
||||
|
||||
async addVocabToChapter(hashedUserId, chapterId, { learning, reference }) {
|
||||
const user = await this._getUserByHashedId(hashedUserId);
|
||||
const ch = await this._getChapterAccess(user.id, chapterId);
|
||||
if (!ch.isOwner) {
|
||||
const err = new Error('Only owner can add vocab');
|
||||
err.status = 403;
|
||||
throw err;
|
||||
}
|
||||
|
||||
const learningText = typeof learning === 'string' ? learning.trim() : '';
|
||||
const referenceText = typeof reference === 'string' ? reference.trim() : '';
|
||||
if (!learningText || !referenceText) {
|
||||
const err = new Error('Invalid vocab');
|
||||
err.status = 400;
|
||||
throw err;
|
||||
}
|
||||
|
||||
const learningNorm = this._normalizeLexeme(learningText);
|
||||
const referenceNorm = this._normalizeLexeme(referenceText);
|
||||
|
||||
// Transaktion: Lexeme upserten + Zuordnung setzen
|
||||
return await sequelize.transaction(async (t) => {
|
||||
const [learningLex] = await sequelize.query(
|
||||
`
|
||||
INSERT INTO community.vocab_lexeme (language_id, text, normalized, created_by_user_id)
|
||||
VALUES (:languageId, :text, :normalized, :userId)
|
||||
ON CONFLICT (language_id, normalized) DO UPDATE SET text = EXCLUDED.text
|
||||
RETURNING id
|
||||
`,
|
||||
{
|
||||
replacements: { languageId: ch.languageId, text: learningText, normalized: learningNorm, userId: user.id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
transaction: t,
|
||||
}
|
||||
);
|
||||
|
||||
const [referenceLex] = await sequelize.query(
|
||||
`
|
||||
INSERT INTO community.vocab_lexeme (language_id, text, normalized, created_by_user_id)
|
||||
VALUES (:languageId, :text, :normalized, :userId)
|
||||
ON CONFLICT (language_id, normalized) DO UPDATE SET text = EXCLUDED.text
|
||||
RETURNING id
|
||||
`,
|
||||
{
|
||||
replacements: { languageId: ch.languageId, text: referenceText, normalized: referenceNorm, userId: user.id },
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
transaction: t,
|
||||
}
|
||||
);
|
||||
|
||||
const [mapping] = await sequelize.query(
|
||||
`
|
||||
INSERT INTO community.vocab_chapter_lexeme (chapter_id, learning_lexeme_id, reference_lexeme_id, created_by_user_id)
|
||||
VALUES (:chapterId, :learningId, :referenceId, :userId)
|
||||
ON CONFLICT (chapter_id, learning_lexeme_id, reference_lexeme_id) DO NOTHING
|
||||
RETURNING id
|
||||
`,
|
||||
{
|
||||
replacements: {
|
||||
chapterId: ch.id,
|
||||
learningId: learningLex.id,
|
||||
referenceId: referenceLex.id,
|
||||
userId: user.id,
|
||||
},
|
||||
type: sequelize.QueryTypes.SELECT,
|
||||
transaction: t,
|
||||
}
|
||||
);
|
||||
|
||||
return { created: Boolean(mapping?.id) };
|
||||
});
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
@@ -33,6 +33,123 @@ const syncDatabase = async () => {
|
||||
console.log("Initializing database schemas...");
|
||||
await initializeDatabase();
|
||||
|
||||
// Vokabeltrainer: Tabellen sicherstellen (auch ohne manuell ausgeführte Migrations)
|
||||
// Hintergrund: In Produktion sind Schema-Updates deaktiviert, und Migrations werden nicht automatisch ausgeführt.
|
||||
// Damit API/Menu nicht mit "relation does not exist" (42P01) scheitert, legen wir die Tabellen idempotent an.
|
||||
console.log("Ensuring Vocab-Trainer tables exist...");
|
||||
try {
|
||||
await sequelize.query(`
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_language (
|
||||
id SERIAL PRIMARY KEY,
|
||||
owner_user_id INTEGER NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
share_code TEXT NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_language_owner_fk
|
||||
FOREIGN KEY (owner_user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_language_share_code_uniq UNIQUE (share_code)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_language_subscription (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_id INTEGER NOT NULL,
|
||||
language_id INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_language_subscription_user_fk
|
||||
FOREIGN KEY (user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_language_subscription_language_fk
|
||||
FOREIGN KEY (language_id)
|
||||
REFERENCES community.vocab_language(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_language_subscription_uniq UNIQUE (user_id, language_id)
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS vocab_language_owner_idx
|
||||
ON community.vocab_language(owner_user_id);
|
||||
CREATE INDEX IF NOT EXISTS vocab_language_subscription_user_idx
|
||||
ON community.vocab_language_subscription(user_id);
|
||||
CREATE INDEX IF NOT EXISTS vocab_language_subscription_language_idx
|
||||
ON community.vocab_language_subscription(language_id);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_chapter (
|
||||
id SERIAL PRIMARY KEY,
|
||||
language_id INTEGER NOT NULL,
|
||||
title TEXT NOT NULL,
|
||||
created_by_user_id INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_chapter_language_fk
|
||||
FOREIGN KEY (language_id)
|
||||
REFERENCES community.vocab_language(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chapter_creator_fk
|
||||
FOREIGN KEY (created_by_user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS vocab_chapter_language_idx
|
||||
ON community.vocab_chapter(language_id);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_lexeme (
|
||||
id SERIAL PRIMARY KEY,
|
||||
language_id INTEGER NOT NULL,
|
||||
text TEXT NOT NULL,
|
||||
normalized TEXT NOT NULL,
|
||||
created_by_user_id INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_lexeme_language_fk
|
||||
FOREIGN KEY (language_id)
|
||||
REFERENCES community.vocab_language(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_lexeme_creator_fk
|
||||
FOREIGN KEY (created_by_user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_lexeme_unique_per_language UNIQUE (language_id, normalized)
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS vocab_lexeme_language_idx
|
||||
ON community.vocab_lexeme(language_id);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS community.vocab_chapter_lexeme (
|
||||
id SERIAL PRIMARY KEY,
|
||||
chapter_id INTEGER NOT NULL,
|
||||
learning_lexeme_id INTEGER NOT NULL,
|
||||
reference_lexeme_id INTEGER NOT NULL,
|
||||
created_by_user_id INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT vocab_chlex_chapter_fk
|
||||
FOREIGN KEY (chapter_id)
|
||||
REFERENCES community.vocab_chapter(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chlex_learning_fk
|
||||
FOREIGN KEY (learning_lexeme_id)
|
||||
REFERENCES community.vocab_lexeme(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chlex_reference_fk
|
||||
FOREIGN KEY (reference_lexeme_id)
|
||||
REFERENCES community.vocab_lexeme(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chlex_creator_fk
|
||||
FOREIGN KEY (created_by_user_id)
|
||||
REFERENCES community."user"(id)
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT vocab_chlex_unique UNIQUE (chapter_id, learning_lexeme_id, reference_lexeme_id)
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS vocab_chlex_chapter_idx
|
||||
ON community.vocab_chapter_lexeme(chapter_id);
|
||||
CREATE INDEX IF NOT EXISTS vocab_chlex_learning_idx
|
||||
ON community.vocab_chapter_lexeme(learning_lexeme_id);
|
||||
CREATE INDEX IF NOT EXISTS vocab_chlex_reference_idx
|
||||
ON community.vocab_chapter_lexeme(reference_lexeme_id);
|
||||
`);
|
||||
console.log("✅ Vocab-Trainer Tabellen sind vorhanden.");
|
||||
} catch (e) {
|
||||
console.warn('⚠️ Konnte Vocab-Trainer Tabellen nicht sicherstellen:', e?.message || e);
|
||||
}
|
||||
|
||||
// Vorab: Stelle kritische Spalten sicher, damit Index-Erstellung nicht fehlschlägt
|
||||
console.log("Pre-ensure Taxi columns (traffic_light) ...");
|
||||
try {
|
||||
|
||||
Reference in New Issue
Block a user