142 lines
4.2 KiB
SQL
142 lines
4.2 KiB
SQL
-- Version 1 is the initial structure.
|
|
CREATE TABLE [Version] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
[version] INTEGER NOT NULL UNIQUE,
|
|
[datetime] TEXT
|
|
) STRICT;
|
|
|
|
CREATE TABLE [User] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
[email] TEXT NOT NULL,
|
|
[name] TEXT NOT NULL DEFAULT '',
|
|
[default_servings] INTEGER DEFAULT 4,
|
|
|
|
[password] TEXT NOT NULL, -- argon2(password_plain, salt).
|
|
|
|
[validation_token_datetime] TEXT NOT NULL, -- Updated when the validation email is sent.
|
|
[validation_token] TEXT, -- If not null then the user has not validated his account yet.
|
|
|
|
[password_reset_token] TEXT, -- If not null then the user can reset its password.
|
|
-- The time when the reset token has been created.
|
|
-- Password can only be reset during a certain duration after this time.
|
|
[password_reset_datetime] TEXT,
|
|
|
|
[is_admin] INTEGER NOT NULL DEFAULT FALSE
|
|
) STRICT;
|
|
|
|
CREATE UNIQUE INDEX [User_email_index] ON [User]([email]);
|
|
|
|
CREATE TABLE [UserLoginToken] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
[user_id] INTEGER NOT NULL,
|
|
[last_login_datetime] TEXT,
|
|
|
|
-- 24 alphanumeric character token.
|
|
-- Can be stored in a cookie to be able to authenticate without a password.
|
|
[token] TEXT NOT NULL,
|
|
|
|
[ip] TEXT, -- Can be ipv4 or ipv6
|
|
[user_agent] TEXT,
|
|
|
|
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE
|
|
) STRICT;
|
|
|
|
CREATE INDEX [UserLoginToken_token_index] ON [UserLoginToken]([token]);
|
|
|
|
CREATE TABLE [Recipe] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
[user_id] INTEGER, -- Can be null if a user is deleted.
|
|
[title] TEXT NOT NULL,
|
|
-- https://en.wikipedia.org/wiki/List_of_ISO_639_language_codes
|
|
[lang] TEXT NOT NULL DEFAULT 'en',
|
|
[estimated_time] INTEGER, -- in [s].
|
|
[description] TEXT NOT NULL DEFAULT '',
|
|
[difficulty] INTEGER NOT NULL DEFAULT 0,
|
|
[servings] INTEGER DEFAULT 4,
|
|
[is_published] INTEGER NOT NULL DEFAULT FALSE,
|
|
|
|
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE SET NULL
|
|
) STRICT;
|
|
|
|
CREATE TABLE [Image] (
|
|
[Id] INTEGER PRIMARY KEY,
|
|
[recipe_id] INTEGER NOT NULL,
|
|
[name] TEXT NOT NULL DEFAULT '',
|
|
[description] TEXT NOT NULL DEFAULT '',
|
|
[image] BLOB NOT NULL,
|
|
|
|
FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE
|
|
) STRICT;
|
|
|
|
CREATE TABLE [RecipeTag] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
|
|
[recipe_id] INTEGER NOT NULL,
|
|
[tag_id] INTEGER NOT NULL,
|
|
|
|
UNIQUE([recipe_id], [tag_id]),
|
|
|
|
FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE,
|
|
FOREIGN KEY([tag_id]) REFERENCES [Tag]([id]) ON DELETE CASCADE
|
|
) STRICT;
|
|
|
|
CREATE TABLE [Tag] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
[name] TEXT NOT NULL,
|
|
-- https://en.wikipedia.org/wiki/List_of_ISO_639_language_codes
|
|
[lang] TEXT NOT NULL DEFAULT 'en'
|
|
) STRICT;
|
|
|
|
CREATE UNIQUE INDEX [Tag_name_lang_index] ON [Tag] ([name], [lang]);
|
|
|
|
CREATE TABLE [Group] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
|
|
[order] INTEGER NOT NULL DEFAULT 0,
|
|
[recipe_id] INTEGER NOT NULL,
|
|
|
|
[name] TEXT NOT NULL DEFAULT '',
|
|
[comment] TEXT NOT NULL DEFAULT '',
|
|
|
|
FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE
|
|
) STRICT;
|
|
|
|
CREATE INDEX [Group_order_index] ON [Group]([order]);
|
|
|
|
CREATE TABLE [Step] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
|
|
[order] INTEGER NOT NULL DEFAULT 0,
|
|
[group_id] INTEGER NOT NULL,
|
|
|
|
[action] TEXT NOT NULL DEFAULT '',
|
|
|
|
FOREIGN KEY(group_id) REFERENCES [Group](id) ON DELETE CASCADE
|
|
) STRICT;
|
|
|
|
CREATE INDEX [Step_order_index] ON [Group]([order]);
|
|
|
|
CREATE TABLE [Ingredient] (
|
|
[id] INTEGER PRIMARY KEY,
|
|
|
|
[step_id] INTEGER NOT NULL,
|
|
|
|
[name] TEXT NOT NULL DEFAULT '',
|
|
[comment] TEXT NOT NULL DEFAULT '',
|
|
[quantity_value] REAL,
|
|
[quantity_unit] TEXT NOT NULL DEFAULT '',
|
|
|
|
FOREIGN KEY([step_id]) REFERENCES [Step]([id]) ON DELETE CASCADE
|
|
) STRICT;
|
|
|
|
-- CREATE TABLE [IntermediateSubstance] (
|
|
-- [id] INTEGER PRIMARY KEY,
|
|
-- [name] TEXT NOT NULL DEFAULT '',
|
|
-- [quantity_value] REAL,
|
|
-- [quantity_unit] TEXT NOT NULL DEFAULT '',
|
|
-- [output_group_id] INTEGER NOT NULL,
|
|
-- [input_group_id] INTEGER NOT NULL,
|
|
|
|
-- FOREIGN KEY([output_group_id]) REFERENCES [group]([id]) ON DELETE CASCADE,
|
|
-- FOREIGN KEY([input_group_id]) REFERENCES [group]([id]) ON DELETE CASCADE
|
|
-- ) STRICT;
|