-- 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);