recipes/backend/sql/version_1.sql

222 lines
6.5 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 '',
[creation_datetime] TEXT NOT NULL,
[default_servings] INTEGER DEFAULT 4,
[lang] TEXT NOT NULL DEFAULT 'en',
[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 INDEX [validation_token_index] ON [User]([validation_token]);
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 '',
-- 0: Unknown, 1: Easy, 2: Medium, 4: Hard.
[difficulty] INTEGER NOT NULL DEFAULT 0,
[servings] INTEGER DEFAULT 4,
[is_published] INTEGER NOT NULL DEFAULT FALSE,
[creation_datetime] TEXT NOT NULL,
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE SET NULL
) STRICT;
CREATE TRIGGER [Recipe_trigger_update_difficulty]
BEFORE UPDATE OF [difficulty]
ON [Recipe]
BEGIN
SELECT
CASE
WHEN NEW.[difficulty] < 0 OR NEW.[difficulty] > 3 THEN
RAISE (ABORT, 'Invalid [difficulty] value')
END;
END;
CREATE TRIGGER [Recipe_trigger_insert_difficulty]
BEFORE INSERT
ON [Recipe]
BEGIN
SELECT
CASE
WHEN NEW.[difficulty] < 0 OR NEW.[difficulty] > 3 THEN
RAISE (ABORT, 'Invalid [difficulty] value')
END;
END;
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
) STRICT;
CREATE UNIQUE INDEX [Tag_name_lang_index] ON [Tag]([name]);
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,
[order] INTEGER NOT NULL DEFAULT 0,
[step_id] INTEGER NOT NULL,
[name] TEXT NOT NULL DEFAULT '',
[quantity_value] REAL,
[quantity_unit] TEXT NOT NULL DEFAULT '',
[comment] TEXT NOT NULL DEFAULT '',
FOREIGN KEY([step_id]) REFERENCES [Step]([id]) ON DELETE CASCADE
) STRICT;
CREATE INDEX [Ingredient_order_index] ON [Ingredient]([order]);
CREATE TABLE [RecipeScheduled] (
[id] INTEGER PRIMARY KEY,
[user_id] INTEGER NOT NULL,
[recipe_id] INTEGER NOT NULL,
[date] TEXT NOT NULL,
[servings] INTEGER, -- If NULL use [recipe].[servings].
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE,
FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE
);
CREATE TABLE [ShoppingEntry] (
[id] INTEGER PRIMARY KEY,
[user_id] INTEGER NOT NULL,
-- The linkded ingredient can be deleted or a custom entry can be manually added.
-- In both cases [name], [quantity_value] and [quantity_unit] are used to display
-- the entry instead of [Ingredient] data.
[ingredient_id] INTEGER,
[is_checked] INTEGER NOT NULL DEFAULT FALSE,
[name] TEXT NOT NULL DEFAULT '',
[quantity_value] REAL,
[quantity_unit] TEXT NOT NULL DEFAULT '',
[servings] INTEGER,
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE,
FOREIGN KEY([ingredient_id]) REFERENCES [Ingredient]([id]) ON DELETE SET NULL
);
-- When an ingredient is deleted, its values are copied to any shopping entry
-- that referenced it.
CREATE TRIGGER [Ingredient_trigger_delete]
BEFORE DELETE
ON [Ingredient]
BEGIN
UPDATE [ShoppingEntry]
SET
[name] = OLD.[name],
[quantity_value] = OLD.[quantity_value],
[quantity_unit] = OLD.[quantity_unit],
[servings] = (
SELECT [servings]
FROM [Recipe]
INNER JOIN [Group] ON [Group].[recipe_id] = [Recipe].[id]
INNER JOIN [Step] ON [Step].[group_id] = [Group].[id]
WHERE [Step].[id] = OLD.[step_id]
)
WHERE [ingredient_id] = OLD.[id];
END;
CREATE TABLE [Settings] (
[name] TEXT NOT NULL PRIMARY KEY,
-- Value can by anything that can be read from a text by
-- implementing the trait 'std::str::FromStr'.
[value] TEXT NOT NULL
) STRICT;
INSERT INTO [Settings] ([name], [value]) VALUES ('new_user_registration_enabled', 'true');