--- Datetimes are stored as 'ISO 8601' text format.
--- For example: '2025-01-07T10:41:05.697884837+00:00'.
-
--- 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, -- In form of 'YYYY-MM-DD'.
- [servings] INTEGER, -- If NULL use [recipe].[servings].
-
- UNIQUE([user_id], [recipe_id], [date]),
-
- FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE,
- FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE
-);
-
-CREATE INDEX [RecipeScheduled_user_id_index] ON [RecipeScheduled]([user_id]);
-CREATE INDEX [RecipeScheduled_date_index] ON [RecipeScheduled]([date]);
-
-CREATE TABLE [ShoppingEntry] (
- [id] INTEGER PRIMARY KEY,
- [user_id] INTEGER NOT NULL,
- -- The linked 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,
- [recipe_scheduled_id] INTEGER, -- Can be null when manually added.
-
- [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,
- FOREIGN KEY([recipe_scheduled_id]) REFERENCES [RecipeScheduled]([id]) ON DELETE SET NULL
-);
-
-CREATE INDEX [ShoppingEntry_user_id_index] ON [ShoppingEntry]([user_id]);
-
--- 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');
+-- Datetimes are stored as 'ISO 8601' text format.\r
+-- For example: '2025-01-07T10:41:05.697884837+00:00'.\r
+\r
+-- Version 1 is the initial structure.\r
+CREATE TABLE [Version] (\r
+ [id] INTEGER PRIMARY KEY,\r
+ [version] INTEGER NOT NULL UNIQUE,\r
+ [datetime] TEXT\r
+) STRICT;\r
+\r
+CREATE TABLE [User] (\r
+ [id] INTEGER PRIMARY KEY,\r
+\r
+ [email] TEXT NOT NULL,\r
+ [name] TEXT NOT NULL DEFAULT '',\r
+ [creation_datetime] TEXT NOT NULL,\r
+\r
+ [default_servings] INTEGER DEFAULT 4,\r
+ [lang] TEXT NOT NULL DEFAULT 'en',\r
+\r
+ [password] TEXT NOT NULL, -- argon2(password_plain, salt).\r
+\r
+ [validation_token_datetime] TEXT NOT NULL, -- Updated when the validation email is sent.\r
+ [validation_token] TEXT, -- If not null then the user has not validated his account yet.\r
+\r
+ [password_reset_token] TEXT, -- If not null then the user can reset its password.\r
+ -- The time when the reset token has been created.\r
+ -- Password can only be reset during a certain duration after this time.\r
+ [password_reset_datetime] TEXT,\r
+\r
+ [is_admin] INTEGER NOT NULL DEFAULT FALSE\r
+) STRICT;\r
+\r
+CREATE INDEX [validation_token_index] ON [User]([validation_token]);\r
+CREATE UNIQUE INDEX [User_email_index] ON [User]([email]);\r
+\r
+CREATE TABLE [UserLoginToken] (\r
+ [id] INTEGER PRIMARY KEY,\r
+ [user_id] INTEGER NOT NULL,\r
+ [last_login_datetime] TEXT,\r
+\r
+ -- 24 alphanumeric character token.\r
+ -- Can be stored in a cookie to be able to authenticate without a password.\r
+ [token] TEXT NOT NULL,\r
+\r
+ [ip] TEXT, -- Can be ipv4 or ipv6\r
+ [user_agent] TEXT,\r
+\r
+ FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE\r
+) STRICT;\r
+\r
+CREATE INDEX [UserLoginToken_token_index] ON [UserLoginToken]([token]);\r
+\r
+CREATE TABLE [Recipe] (\r
+ [id] INTEGER PRIMARY KEY,\r
+ [user_id] INTEGER, -- Can be null if a user is deleted.\r
+ [title] TEXT NOT NULL,\r
+ -- https://en.wikipedia.org/wiki/List_of_ISO_639_language_codes\r
+ [lang] TEXT NOT NULL DEFAULT 'en',\r
+ [estimated_time] INTEGER, -- in [s].\r
+ [description] TEXT NOT NULL DEFAULT '',\r
+ -- 0: Unknown, 1: Easy, 2: Medium, 4: Hard.\r
+ [difficulty] INTEGER NOT NULL DEFAULT 0,\r
+ [servings] INTEGER DEFAULT 4,\r
+ [is_published] INTEGER NOT NULL DEFAULT FALSE,\r
+ [creation_datetime] TEXT NOT NULL,\r
+\r
+ FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE SET NULL\r
+) STRICT;\r
+\r
+CREATE TRIGGER [Recipe_trigger_update_difficulty]\r
+BEFORE UPDATE OF [difficulty]\r
+ON [Recipe]\r
+BEGIN\r
+ SELECT\r
+ CASE\r
+ WHEN NEW.[difficulty] < 0 OR NEW.[difficulty] > 3 THEN\r
+ RAISE (ABORT, 'Invalid [difficulty] value')\r
+ END;\r
+END;\r
+\r
+CREATE TRIGGER [Recipe_trigger_insert_difficulty]\r
+BEFORE INSERT\r
+ON [Recipe]\r
+BEGIN\r
+ SELECT\r
+ CASE\r
+ WHEN NEW.[difficulty] < 0 OR NEW.[difficulty] > 3 THEN\r
+ RAISE (ABORT, 'Invalid [difficulty] value')\r
+ END;\r
+END;\r
+\r
+CREATE TABLE [Image] (\r
+ [Id] INTEGER PRIMARY KEY,\r
+ [recipe_id] INTEGER NOT NULL,\r
+ [name] TEXT NOT NULL DEFAULT '',\r
+ [description] TEXT NOT NULL DEFAULT '',\r
+ [image] BLOB NOT NULL,\r
+\r
+ FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE\r
+) STRICT;\r
+\r
+CREATE TABLE [RecipeTag] (\r
+ [id] INTEGER PRIMARY KEY,\r
+\r
+ [recipe_id] INTEGER NOT NULL,\r
+ [tag_id] INTEGER NOT NULL,\r
+\r
+ UNIQUE([recipe_id], [tag_id]),\r
+\r
+ FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE,\r
+ FOREIGN KEY([tag_id]) REFERENCES [Tag]([id]) ON DELETE CASCADE\r
+) STRICT;\r
+\r
+CREATE TABLE [Tag] (\r
+ [id] INTEGER PRIMARY KEY,\r
+ [name] TEXT NOT NULL\r
+ -- https://en.wikipedia.org/wiki/List_of_ISO_639_language_codes\r
+) STRICT;\r
+\r
+CREATE UNIQUE INDEX [Tag_name_lang_index] ON [Tag]([name]);\r
+\r
+CREATE TABLE [Group] (\r
+ [id] INTEGER PRIMARY KEY,\r
+\r
+ [order] INTEGER NOT NULL DEFAULT 0,\r
+ [recipe_id] INTEGER NOT NULL,\r
+\r
+ [name] TEXT NOT NULL DEFAULT '',\r
+ [comment] TEXT NOT NULL DEFAULT '',\r
+\r
+ FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE\r
+) STRICT;\r
+\r
+CREATE INDEX [Group_order_index] ON [Group]([order]);\r
+\r
+CREATE TABLE [Step] (\r
+ [id] INTEGER PRIMARY KEY,\r
+\r
+ [order] INTEGER NOT NULL DEFAULT 0,\r
+ [group_id] INTEGER NOT NULL,\r
+\r
+ [action] TEXT NOT NULL DEFAULT '',\r
+\r
+ FOREIGN KEY(group_id) REFERENCES [Group](id) ON DELETE CASCADE\r
+) STRICT;\r
+\r
+CREATE INDEX [Step_order_index] ON [Group]([order]);\r
+\r
+CREATE TABLE [Ingredient] (\r
+ [id] INTEGER PRIMARY KEY,\r
+\r
+ [order] INTEGER NOT NULL DEFAULT 0,\r
+ [step_id] INTEGER NOT NULL,\r
+\r
+ [name] TEXT NOT NULL DEFAULT '',\r
+ [quantity_value] REAL,\r
+ [quantity_unit] TEXT NOT NULL DEFAULT '',\r
+\r
+ [comment] TEXT NOT NULL DEFAULT '',\r
+\r
+ FOREIGN KEY([step_id]) REFERENCES [Step]([id]) ON DELETE CASCADE\r
+) STRICT;\r
+\r
+CREATE INDEX [Ingredient_order_index] ON [Ingredient]([order]);\r
+\r
+CREATE TABLE [RecipeScheduled] (\r
+ [id] INTEGER PRIMARY KEY,\r
+ [user_id] INTEGER NOT NULL,\r
+ [recipe_id] INTEGER NOT NULL,\r
+ [date] TEXT NOT NULL, -- In form of 'YYYY-MM-DD'.\r
+ [servings] INTEGER, -- If NULL use [recipe].[servings].\r
+\r
+ UNIQUE([user_id], [recipe_id], [date]),\r
+\r
+ FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE,\r
+ FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE\r
+);\r
+\r
+CREATE INDEX [RecipeScheduled_user_id_index] ON [RecipeScheduled]([user_id]);\r
+CREATE INDEX [RecipeScheduled_date_index] ON [RecipeScheduled]([date]);\r
+\r
+CREATE TABLE [ShoppingEntry] (\r
+ [id] INTEGER PRIMARY KEY,\r
+ [user_id] INTEGER NOT NULL,\r
+ -- The linked ingredient can be deleted or a custom entry can be manually added.\r
+ -- In both cases [name], [quantity_value], [quantity_unit] and [Servings] are used to display\r
+ -- the entry instead of [Ingredient] data.\r
+ [ingredient_id] INTEGER,\r
+ [recipe_scheduled_id] INTEGER, -- Can be null when manually added.\r
+\r
+ [is_checked] INTEGER NOT NULL DEFAULT FALSE,\r
+\r
+ -- The following four fields contain data only if [recipe_scheduled_id] is NULL.\r
+ [name] TEXT NOT NULL DEFAULT '',\r
+ [quantity_value] REAL,\r
+ [quantity_unit] TEXT NOT NULL DEFAULT '',\r
+ [servings] INTEGER,\r
+\r
+ FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE,\r
+ FOREIGN KEY([ingredient_id]) REFERENCES [Ingredient]([id]) ON DELETE SET NULL,\r
+ FOREIGN KEY([recipe_scheduled_id]) REFERENCES [RecipeScheduled]([id]) ON DELETE SET NULL\r
+);\r
+\r
+CREATE INDEX [ShoppingEntry_user_id_index] ON [ShoppingEntry]([user_id]);\r
+\r
+-- When an ingredient is deleted, its values are copied to any shopping entry\r
+-- that referenced it.\r
+CREATE TRIGGER [Ingredient_trigger_delete]\r
+BEFORE DELETE\r
+ON [Ingredient]\r
+BEGIN\r
+ UPDATE [ShoppingEntry]\r
+ SET\r
+ [name] = OLD.[name],\r
+ [quantity_value] = OLD.[quantity_value],\r
+ [quantity_unit] = OLD.[quantity_unit],\r
+ [servings] = (\r
+ SELECT [servings]\r
+ FROM [Recipe]\r
+ INNER JOIN [Group] ON [Group].[recipe_id] = [Recipe].[id]\r
+ INNER JOIN [Step] ON [Step].[group_id] = [Group].[id]\r
+ WHERE [Step].[id] = OLD.[step_id]\r
+ )\r
+ WHERE [ingredient_id] = OLD.[id];\r
+END;\r
+\r
+CREATE TABLE [Settings] (\r
+ [name] TEXT NOT NULL PRIMARY KEY,\r
+\r
+ -- Value can by anything that can be read from a text by\r
+ -- implementing the trait 'std::str::FromStr'.\r
+ [value] TEXT NOT NULL\r
+) STRICT;\r
+\r
+INSERT INTO [Settings] ([name], [value]) VALUES ('new_user_registration_enabled', 'true');\r