diff --git a/backend/migrations/20260112000000-add-indexes-for-director-proposals-rollback.sql b/backend/migrations/20260112000000-add-indexes-for-director-proposals-rollback.sql new file mode 100644 index 0000000..d801157 --- /dev/null +++ b/backend/migrations/20260112000000-add-indexes-for-director-proposals-rollback.sql @@ -0,0 +1,13 @@ +-- Rollback: Remove indexes for director proposals and character queries +-- Created: 2026-01-12 + +DROP INDEX IF EXISTS falukant_data.idx_character_region_user_created; +DROP INDEX IF EXISTS falukant_data.idx_character_region_user; +DROP INDEX IF EXISTS falukant_data.idx_character_user_id; +DROP INDEX IF EXISTS falukant_data.idx_director_proposal_employer_character; +DROP INDEX IF EXISTS falukant_data.idx_director_character_id; +DROP INDEX IF EXISTS falukant_data.idx_director_employer_user_id; +DROP INDEX IF EXISTS falukant_data.idx_knowledge_character_id; +DROP INDEX IF EXISTS falukant_data.idx_relationship_character1_id; +DROP INDEX IF EXISTS falukant_data.idx_child_relation_father_id; +DROP INDEX IF EXISTS falukant_data.idx_child_relation_mother_id; diff --git a/backend/migrations/20260112000000-add-indexes-for-director-proposals.sql b/backend/migrations/20260112000000-add-indexes-for-director-proposals.sql new file mode 100644 index 0000000..2d4fe61 --- /dev/null +++ b/backend/migrations/20260112000000-add-indexes-for-director-proposals.sql @@ -0,0 +1,43 @@ +-- Migration: Add indexes for director proposals and character queries +-- Created: 2026-01-12 + +-- Index für schnelle Suche nach NPCs in einer Region (mit Altersbeschränkung) +CREATE INDEX IF NOT EXISTS idx_character_region_user_created +ON falukant_data.character (region_id, user_id, created_at) +WHERE user_id IS NULL; + +-- Index für schnelle Suche nach NPCs ohne Altersbeschränkung +CREATE INDEX IF NOT EXISTS idx_character_region_user +ON falukant_data.character (region_id, user_id) +WHERE user_id IS NULL; + +-- Index für Character-Suche nach user_id (wichtig für getFamily, getDirectorForBranch) +CREATE INDEX IF NOT EXISTS idx_character_user_id +ON falukant_data.character (user_id); + +-- Index für Director-Proposals +CREATE INDEX IF NOT EXISTS idx_director_proposal_employer_character +ON falukant_data.director_proposal (employer_user_id, director_character_id); + +-- Index für aktive Direktoren +CREATE INDEX IF NOT EXISTS idx_director_character_id +ON falukant_data.director (director_character_id); + +-- Index für Director-Suche nach employer_user_id +CREATE INDEX IF NOT EXISTS idx_director_employer_user_id +ON falukant_data.director (employer_user_id); + +-- Index für Knowledge-Berechnung +CREATE INDEX IF NOT EXISTS idx_knowledge_character_id +ON falukant_data.knowledge (character_id); + +-- Index für Relationships (getFamily) +CREATE INDEX IF NOT EXISTS idx_relationship_character1_id +ON falukant_data.relationship (character1_id); + +-- Index für ChildRelations (getFamily) +CREATE INDEX IF NOT EXISTS idx_child_relation_father_id +ON falukant_data.child_relation (father_id); + +CREATE INDEX IF NOT EXISTS idx_child_relation_mother_id +ON falukant_data.child_relation (mother_id); diff --git a/backend/services/falukantService.js b/backend/services/falukantService.js index 1b16a18..bad5a8e 100644 --- a/backend/services/falukantService.js +++ b/backend/services/falukantService.js @@ -2463,154 +2463,84 @@ class FalukantService extends BaseService { const threeWeeksAgo = new Date(Date.now() - 21 * 24 * 60 * 60 * 1000); const proposalCount = Math.floor(Math.random() * 3) + 3; - // Hole bereits existierende Proposals, um diese Charaktere auszuschließen - const existingProposals = await DirectorProposal.findAll({ - where: { employerUserId: falukantUserId }, - attributes: ['directorCharacterId'], - raw: true - }); - const proposalCharacterIds = existingProposals.map(p => p.directorCharacterId); + // OPTIMIERUNG: Verwende eine einzige SQL-Query mit CTEs statt mehrerer separater Queries + // Dies ist viel schneller, da PostgreSQL die Query optimieren kann + // Die Knowledge-Berechnung wird direkt in SQL gemacht (AVG) + const sqlQuery = ` + WITH excluded_characters AS ( + SELECT DISTINCT director_character_id AS id + FROM falukant_data.director_proposal + WHERE employer_user_id = :falukantUserId + UNION + SELECT DISTINCT director_character_id AS id + FROM falukant_data.director + ), + older_characters AS ( + SELECT + c.id, + c.title_of_nobility, + t.level, + COALESCE(AVG(k.knowledge), 0) AS avg_knowledge + FROM falukant_data.character c + LEFT JOIN falukant_type.title_of_nobility t ON t.id = c.title_of_nobility + LEFT JOIN falukant_data.knowledge k ON k.character_id = c.id + WHERE c.region_id = :regionId + AND c.user_id IS NULL + AND c.created_at < :threeWeeksAgo + AND c.id NOT IN (SELECT id FROM excluded_characters) + GROUP BY c.id, c.title_of_nobility, t.level + ORDER BY RANDOM() + LIMIT :proposalCount + ), + all_characters AS ( + SELECT + c.id, + c.title_of_nobility, + t.level, + COALESCE(AVG(k.knowledge), 0) AS avg_knowledge + FROM falukant_data.character c + LEFT JOIN falukant_type.title_of_nobility t ON t.id = c.title_of_nobility + LEFT JOIN falukant_data.knowledge k ON k.character_id = c.id + WHERE c.region_id = :regionId + AND c.user_id IS NULL + AND c.id NOT IN (SELECT id FROM excluded_characters) + AND c.id NOT IN (SELECT id FROM older_characters) + GROUP BY c.id, c.title_of_nobility, t.level + ORDER BY RANDOM() + LIMIT GREATEST(0, :proposalCount - (SELECT COUNT(*) FROM older_characters)) + ) + SELECT * FROM older_characters + UNION ALL + SELECT * FROM all_characters + LIMIT :proposalCount + `; - // Hole alle Charaktere, die bereits als Direktor arbeiten (egal für welchen User) - const existingDirectors = await Director.findAll({ - attributes: ['directorCharacterId'], - raw: true - }); - const directorCharacterIds = existingDirectors.map(d => d.directorCharacterId); - - // Kombiniere beide Listen - const excludedCharacterIds = [...new Set([...proposalCharacterIds, ...directorCharacterIds])]; - - console.log(`[generateProposals] Excluding ${excludedCharacterIds.length} characters (${proposalCharacterIds.length} proposals + ${directorCharacterIds.length} active directors)`); - console.log(`[generateProposals] Region ID: ${regionId}, Proposal count needed: ${proposalCount}`); - - // Versuche zuerst Charaktere, die mindestens 3 Wochen alt sind - let whereClause = { - regionId, - userId: null, // Nur NPCs - }; - - if (excludedCharacterIds.length > 0) { - whereClause.id = { [Op.notIn]: excludedCharacterIds }; - } - whereClause.createdAt = { [Op.lt]: threeWeeksAgo }; - - // Erstelle Query-Objekt für Logging - const queryOptions = { - where: whereClause, - include: [ - { - model: TitleOfNobility, - as: 'nobleTitle', - attributes: ['level'], - }, - ], - order: sequelize.literal('RANDOM()'), - limit: proposalCount, - }; - - // Logge die SQL-Query - try { - const query = FalukantCharacter.findAll(queryOptions); - const sqlQuery = query.toSQL ? query.toSQL() : query; - console.log(`[generateProposals] SQL Query (older than 3 weeks):`, JSON.stringify(sqlQuery, null, 2)); - } catch (e) { - // Fallback: Logge die Query-Optionen direkt - console.log(`[generateProposals] Query Options (older than 3 weeks):`, JSON.stringify(queryOptions, null, 2)); - } - console.log(`[generateProposals] WHERE clause:`, JSON.stringify(whereClause, null, 2)); - console.log(`[generateProposals] Excluded character IDs:`, excludedCharacterIds); - - let directorCharacters = await FalukantCharacter.findAll(queryOptions); - - // Fallback: Wenn nicht genug ältere Charaktere gefunden werden, verwende auch neuere - if (directorCharacters.length < proposalCount) { - console.log(`[generateProposals] Only found ${directorCharacters.length} characters older than 3 weeks, trying all NPCs...`); - - const fallbackWhereClause = { + const results = await sequelize.query(sqlQuery, { + replacements: { + falukantUserId, regionId, - userId: null, // Nur NPCs - }; - - if (excludedCharacterIds.length > 0) { - fallbackWhereClause.id = { [Op.notIn]: excludedCharacterIds }; - } - - const fallbackQueryOptions = { - where: fallbackWhereClause, - include: [ - { - model: TitleOfNobility, - as: 'nobleTitle', - attributes: ['level'], - }, - ], - order: sequelize.literal('RANDOM()'), - limit: proposalCount, - }; - - // Logge die Fallback-SQL-Query - try { - const fallbackQuery = FalukantCharacter.findAll(fallbackQueryOptions); - const fallbackSqlQuery = fallbackQuery.toSQL ? fallbackQuery.toSQL() : fallbackQuery; - console.log(`[generateProposals] SQL Query (all NPCs):`, JSON.stringify(fallbackSqlQuery, null, 2)); - } catch (e) { - console.log(`[generateProposals] Fallback Query Options:`, JSON.stringify(fallbackQueryOptions, null, 2)); - } - console.log(`[generateProposals] Fallback WHERE clause:`, JSON.stringify(fallbackWhereClause, null, 2)); - - const fallbackCharacters = await FalukantCharacter.findAll(fallbackQueryOptions); - - // Kombiniere beide Listen und entferne Duplikate - const allCharacterIds = new Set(directorCharacters.map(c => c.id)); - fallbackCharacters.forEach(c => { - if (!allCharacterIds.has(c.id)) { - directorCharacters.push(c); - allCharacterIds.add(c.id); - } - }); - - // Limitiere auf proposalCount - directorCharacters = directorCharacters.slice(0, proposalCount); - } + threeWeeksAgo, + proposalCount + }, + type: sequelize.QueryTypes.SELECT + }); - if (directorCharacters.length === 0) { - console.error(`[generateProposals] No NPCs found in region ${regionId} at all`); + if (results.length === 0) { + console.error(`[generateProposals] No NPCs found in region ${regionId}`); throw new Error('No directors available for the region'); } - console.log(`[generateProposals] Found ${directorCharacters.length} available NPCs`); - - // Batch-Berechnung der Knowledge-Werte - const characterIds = directorCharacters.map(c => c.id); - const allKnowledges = await Knowledge.findAll({ - where: { characterId: { [Op.in]: characterIds } }, - attributes: ['characterId', 'knowledge'], - raw: true - }); - - // Gruppiere Knowledge nach characterId und berechne Durchschnitt - const knowledgeMap = new Map(); - characterIds.forEach(id => knowledgeMap.set(id, [])); - allKnowledges.forEach(k => { - const list = knowledgeMap.get(k.characterId) || []; - list.push(k.knowledge); - knowledgeMap.set(k.characterId, list); - }); + console.log(`[generateProposals] Found ${results.length} available NPCs`); // Erstelle alle Proposals in einem Batch - const proposalsToCreate = directorCharacters.map(character => { - const knowledges = knowledgeMap.get(character.id) || []; - const avgKnowledge = knowledges.length > 0 - ? knowledges.reduce((sum, k) => sum + k, 0) / knowledges.length - : 0; - + const proposalsToCreate = results.map(row => { + const avgKnowledge = parseFloat(row.avg_knowledge) || 0; const proposedIncome = Math.round( - character.nobleTitle.level * Math.pow(1.231, avgKnowledge / 1.5) + row.level * Math.pow(1.231, avgKnowledge / 1.5) ); return { - directorCharacterId: character.id, + directorCharacterId: row.id, employerUserId: falukantUserId, proposedIncome, }; @@ -2878,9 +2808,17 @@ class FalukantService extends BaseService { return { id: director.id, + character: { + name: `${director.character.definedFirstName.name} ${director.character.definedLastName.name}`, + title: director.character.nobleTitle.labelTr, + age: Math.floor((Date.now() - new Date(director.character.birthdate)) / (24 * 60 * 60 * 1000)), + gender: director.character.gender, + nobleTitle: director.character.nobleTitle, + definedFirstName: director.character.definedFirstName, + definedLastName: director.character.definedLastName, + knowledges: director.character.knowledges, + }, satisfaction: director.satisfaction, - character: director.character, - age: calcAge(director.character.birthdate), income: director.income, region: director.character.region.name, wishedIncome,