Files
luna-recipes/features/DATA-MODEL.md
2026-02-18 09:56:01 +00:00

12 KiB

🗄️ Luna Recipes — Datenmodell

1. Entity-Relationship Übersicht

┌──────────┐     ┌──────────────┐     ┌──────────┐
│ Category │────<│    Recipe     │>────│   Tag    │
└──────────┘     └──────┬───────┘     └──────────┘
                        │
              ┌─────────┼──────────┐
              │         │          │
        ┌─────┴──┐ ┌────┴───┐ ┌───┴────┐
        │Ingredi-│ │  Step  │ │  Note  │
        │  ent   │ │        │ │        │
        └────┬───┘ └────────┘ └────────┘
             │
        ┌────┴────────┐
        │ShoppingItem │
        └─────────────┘

2. Entitäten im Detail

Recipe (Rezept)

Feld Typ Beschreibung
id TEXT (ULID) Primärschlüssel
title TEXT Rezeptname
slug TEXT URL-freundlicher Name (unique)
description TEXT Kurzbeschreibung
image_path TEXT Pfad zum Hauptbild
category_id TEXT FK → Category
servings INTEGER Anzahl Portionen
prep_time_min INTEGER Vorbereitungszeit in Minuten
cook_time_min INTEGER Koch-/Backzeit in Minuten
total_time_min INTEGER Gesamtzeit (computed oder manuell)
difficulty TEXT 'easy', 'medium', 'hard'
source_url TEXT Originalquelle (Pinterest-Link etc.)
is_favorite INTEGER 0/1 Boolean
is_draft INTEGER 0/1 Entwurf
created_at TEXT ISO 8601 Timestamp
updated_at TEXT ISO 8601 Timestamp
created_by TEXT 'user' oder 'bot'

Category (Kategorie)

Feld Typ Beschreibung
id TEXT (ULID) Primärschlüssel
name TEXT Anzeigename
slug TEXT URL-freundlich (unique)
icon TEXT Emoji oder Icon-Name
sort_order INTEGER Sortierung
is_default INTEGER Vom System vorgegeben

Standard-Kategorien: Backen, Torten, Frühstück, Mittag, Abend, Snacks, Desserts

Tag

Feld Typ Beschreibung
id TEXT (ULID) Primärschlüssel
name TEXT Tag-Name (unique, lowercase)

RecipeTag (n:m Verknüpfung)

Feld Typ Beschreibung
recipe_id TEXT FK → Recipe
tag_id TEXT FK → Tag

Ingredient (Zutat)

Feld Typ Beschreibung
id TEXT (ULID) Primärschlüssel
recipe_id TEXT FK → Recipe
amount REAL Menge (nullable für "eine Prise")
unit TEXT Einheit (g, ml, EL, TL, Stück, ...)
name TEXT Zutatname
group_name TEXT Optionale Gruppe ("Für den Teig", "Für die Creme")
sort_order INTEGER Reihenfolge

Step (Zubereitungsschritt)

Feld Typ Beschreibung
id TEXT (ULID) Primärschlüssel
recipe_id TEXT FK → Recipe
step_number INTEGER Schrittnummer
instruction TEXT Anweisung
image_path TEXT Optionales Bild zum Schritt
timer_minutes INTEGER Timer in Minuten (nullable)
timer_label TEXT Timer-Beschreibung ("Im Ofen backen")

Note (Notiz)

Feld Typ Beschreibung
id TEXT (ULID) Primärschlüssel
recipe_id TEXT FK → Recipe
content TEXT Markdown-Text
created_at TEXT ISO 8601
updated_at TEXT ISO 8601

ShoppingItem (Einkaufslisteneintrag)

Feld Typ Beschreibung
id TEXT (ULID) Primärschlüssel
ingredient_id TEXT FK → Ingredient (nullable)
recipe_id TEXT FK → Recipe (nullable, für Gruppierung)
name TEXT Anzeigename
amount REAL Menge
unit TEXT Einheit
is_checked INTEGER 0/1 abgehakt
is_custom INTEGER 0/1 manuell hinzugefügt
sort_order INTEGER Sortierung
created_at TEXT ISO 8601

3. SQLite Schema

-- Pragmas
PRAGMA journal_mode = WAL;
PRAGMA foreign_keys = ON;

-- ============================================================
-- Kategorien
-- ============================================================
CREATE TABLE categories (
    id          TEXT PRIMARY KEY,
    name        TEXT NOT NULL,
    slug        TEXT NOT NULL UNIQUE,
    icon        TEXT DEFAULT '🍽️',
    sort_order  INTEGER DEFAULT 0,
    is_default  INTEGER DEFAULT 0
);

INSERT INTO categories (id, name, slug, icon, sort_order, is_default) VALUES
    ('cat_backen',     'Backen',     'backen',     '🧁', 1, 1),
    ('cat_torten',     'Torten',     'torten',     '🎂', 2, 1),
    ('cat_fruehstueck','Frühstück',  'fruehstueck','🥐', 3, 1),
    ('cat_mittag',     'Mittag',     'mittag',     '🍝', 4, 1),
    ('cat_abend',      'Abend',      'abend',      '🥘', 5, 1),
    ('cat_snacks',     'Snacks',     'snacks',     '🥨', 6, 1),
    ('cat_desserts',   'Desserts',   'desserts',   '🍮', 7, 1);

-- ============================================================
-- Tags
-- ============================================================
CREATE TABLE tags (
    id    TEXT PRIMARY KEY,
    name  TEXT NOT NULL UNIQUE
);

CREATE INDEX idx_tags_name ON tags(name);

-- ============================================================
-- Rezepte
-- ============================================================
CREATE TABLE recipes (
    id             TEXT PRIMARY KEY,
    title          TEXT NOT NULL,
    slug           TEXT NOT NULL UNIQUE,
    description    TEXT,
    image_path     TEXT,
    category_id    TEXT NOT NULL REFERENCES categories(id),
    servings       INTEGER DEFAULT 4,
    prep_time_min  INTEGER,
    cook_time_min  INTEGER,
    total_time_min INTEGER,
    difficulty     TEXT DEFAULT 'medium' CHECK(difficulty IN ('easy','medium','hard')),
    source_url     TEXT,
    is_favorite    INTEGER DEFAULT 0,
    is_draft       INTEGER DEFAULT 0,
    created_at     TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%SZ','now')),
    updated_at     TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%SZ','now')),
    created_by     TEXT DEFAULT 'user'
);

CREATE INDEX idx_recipes_category ON recipes(category_id);
CREATE INDEX idx_recipes_favorite ON recipes(is_favorite) WHERE is_favorite = 1;
CREATE INDEX idx_recipes_slug ON recipes(slug);

-- Volltextsuche
CREATE VIRTUAL TABLE recipes_fts USING fts5(
    title, description, content='recipes', content_rowid='rowid'
);

-- Trigger für FTS-Sync
CREATE TRIGGER recipes_ai AFTER INSERT ON recipes BEGIN
    INSERT INTO recipes_fts(rowid, title, description)
    VALUES (new.rowid, new.title, new.description);
END;

CREATE TRIGGER recipes_ad AFTER DELETE ON recipes BEGIN
    INSERT INTO recipes_fts(recipes_fts, rowid, title, description)
    VALUES ('delete', old.rowid, old.title, old.description);
END;

CREATE TRIGGER recipes_au AFTER UPDATE ON recipes BEGIN
    INSERT INTO recipes_fts(recipes_fts, rowid, title, description)
    VALUES ('delete', old.rowid, old.title, old.description);
    INSERT INTO recipes_fts(rowid, title, description)
    VALUES (new.rowid, new.title, new.description);
END;

-- Auto-Update updated_at
CREATE TRIGGER recipes_updated AFTER UPDATE ON recipes BEGIN
    UPDATE recipes SET updated_at = strftime('%Y-%m-%dT%H:%M:%SZ','now')
    WHERE id = new.id;
END;

-- ============================================================
-- Recipe-Tags (n:m)
-- ============================================================
CREATE TABLE recipe_tags (
    recipe_id  TEXT NOT NULL REFERENCES recipes(id) ON DELETE CASCADE,
    tag_id     TEXT NOT NULL REFERENCES tags(id) ON DELETE CASCADE,
    PRIMARY KEY (recipe_id, tag_id)
);

CREATE INDEX idx_recipe_tags_tag ON recipe_tags(tag_id);

-- ============================================================
-- Zutaten
-- ============================================================
CREATE TABLE ingredients (
    id          TEXT PRIMARY KEY,
    recipe_id   TEXT NOT NULL REFERENCES recipes(id) ON DELETE CASCADE,
    amount      REAL,
    unit        TEXT,
    name        TEXT NOT NULL,
    group_name  TEXT,
    sort_order  INTEGER DEFAULT 0
);

CREATE INDEX idx_ingredients_recipe ON ingredients(recipe_id);

-- Zutaten-Volltextsuche (für "Suche nach Zutat")
CREATE VIRTUAL TABLE ingredients_fts USING fts5(
    name, content='ingredients', content_rowid='rowid'
);

CREATE TRIGGER ingredients_ai AFTER INSERT ON ingredients BEGIN
    INSERT INTO ingredients_fts(rowid, name) VALUES (new.rowid, new.name);
END;

CREATE TRIGGER ingredients_ad AFTER DELETE ON ingredients BEGIN
    INSERT INTO ingredients_fts(ingredients_fts, rowid, name)
    VALUES ('delete', old.rowid, old.name);
END;

-- ============================================================
-- Zubereitungsschritte
-- ============================================================
CREATE TABLE steps (
    id             TEXT PRIMARY KEY,
    recipe_id      TEXT NOT NULL REFERENCES recipes(id) ON DELETE CASCADE,
    step_number    INTEGER NOT NULL,
    instruction    TEXT NOT NULL,
    image_path     TEXT,
    timer_minutes  INTEGER,
    timer_label    TEXT
);

CREATE INDEX idx_steps_recipe ON steps(recipe_id);

-- ============================================================
-- Notizen
-- ============================================================
CREATE TABLE notes (
    id          TEXT PRIMARY KEY,
    recipe_id   TEXT NOT NULL REFERENCES recipes(id) ON DELETE CASCADE,
    content     TEXT NOT NULL,
    created_at  TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%SZ','now')),
    updated_at  TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%SZ','now'))
);

CREATE INDEX idx_notes_recipe ON notes(recipe_id);

-- ============================================================
-- Einkaufsliste
-- ============================================================
CREATE TABLE shopping_items (
    id             TEXT PRIMARY KEY,
    ingredient_id  TEXT REFERENCES ingredients(id) ON DELETE SET NULL,
    recipe_id      TEXT REFERENCES recipes(id) ON DELETE SET NULL,
    name           TEXT NOT NULL,
    amount         REAL,
    unit           TEXT,
    is_checked     INTEGER DEFAULT 0,
    is_custom      INTEGER DEFAULT 0,
    sort_order     INTEGER DEFAULT 0,
    created_at     TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%SZ','now'))
);

CREATE INDEX idx_shopping_recipe ON shopping_items(recipe_id);
CREATE INDEX idx_shopping_checked ON shopping_items(is_checked);

4. Beispiel-Queries

-- Alle Rezepte einer Kategorie, neuste zuerst
SELECT r.*, c.name as category_name, c.icon as category_icon
FROM recipes r
JOIN categories c ON r.category_id = c.id
WHERE c.slug = 'torten' AND r.is_draft = 0
ORDER BY r.created_at DESC;

-- Volltextsuche
SELECT r.*
FROM recipes r
JOIN recipes_fts ON recipes_fts.rowid = r.rowid
WHERE recipes_fts MATCH 'schokolade'
ORDER BY rank;

-- Rezepte die eine bestimmte Zutat enthalten
SELECT DISTINCT r.*
FROM recipes r
JOIN ingredients i ON i.recipe_id = r.id
JOIN ingredients_fts ON ingredients_fts.rowid = i.rowid
WHERE ingredients_fts MATCH 'mascarpone';

-- Komplettansicht eines Rezepts
SELECT r.*, c.name as category_name
FROM recipes r
JOIN categories c ON r.category_id = c.id
WHERE r.slug = 'schwarzwaelder-kirschtorte';

-- Zutaten für Einkaufsliste generieren
INSERT INTO shopping_items (id, ingredient_id, recipe_id, name, amount, unit)
SELECT
    'shop_' || hex(randomblob(8)),
    i.id,
    i.recipe_id,
    i.name,
    i.amount,
    i.unit
FROM ingredients i
WHERE i.recipe_id = ?;

-- Einkaufsliste gruppiert nach Rezept
SELECT si.*, r.title as recipe_title
FROM shopping_items si
LEFT JOIN recipes r ON si.recipe_id = r.id
ORDER BY si.is_checked ASC, r.title, si.sort_order;

5. ID-Strategie

ULID (Universally Unique Lexicographically Sortable Identifier) statt Auto-Increment:

  • Sortierbar nach Erstellzeitpunkt
  • Generierbar auf Client und Server (offline-fähig)
  • Keine Kollisionen bei Bot-API + UI gleichzeitig
  • Format: 01ARZ3NDEKTSV4RRFFQ69G5FAV (26 Zeichen)

6. Bild-Speicherung

/data/images/
  recipes/
    {recipe_id}/
      hero.webp          ← Hauptbild (max 1200px breit)
      hero_thumb.webp     ← Thumbnail (400px)
      step_{n}.webp       ← Schrittbilder
  • Format: WebP (beste Kompression für Web)
  • Thumbnails automatisch beim Upload generiert
  • Bilder werden über statische Route ausgeliefert: /images/recipes/{id}/hero.webp