-- 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', -- 0: Monday, 1: Tuesday, 2: Wednesday, 3: Thursday, 4: Friday, 5: Saturday, 6: Sunday. [first_day_of_the_week] INTEGER DEFAULT 0, [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, CHECK ( length([email]) <= 255 AND length([name]) <= 255 AND length([lang]) = 2 AND length([password]) <= 255 AND [first_day_of_the_week] >= 0 AND [first_day_of_the_week] <= 6 AND ([is_admin] = TRUE OR [is_admin] = FALSE) ) ) STRICT; CREATE INDEX [User_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, CHECK ( length([ip]) <= 255 AND length([user_agent]) <= 255 ), 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 (Set 1). [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_public] INTEGER NOT NULL DEFAULT FALSE, [creation_datetime] TEXT NOT NULL, CHECK ( length([title]) <= 255 AND length([lang]) = 2 AND length([description]) <= 65535 AND [difficulty] >= 0 AND [difficulty] <= 3 AND [servings] > 0 AND [servings] <= 255 AND ([is_public] = TRUE OR [is_public] = FALSE) ), FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE SET NULL ) STRICT; CREATE VIRTUAL TABLE [RecipeTitle] USING FTS5( [title], CONTENT = [Recipe], CONTENT_ROWID = [id], PREFIX = 2, PREFIX = 3, PREFIX = 4, PREFIX = 5, PREFIX = 6, PREFIX = 7, ); CREATE TRIGGER [Recipe_trigger_insert] AFTER INSERT ON [Recipe] BEGIN INSERT INTO [RecipeTitle]([rowid], [title]) VALUES (NEW.[id], NEW.[title]); END; CREATE TRIGGER [Recipe_trigger_delete] AFTER DELETE ON [Recipe] BEGIN INSERT INTO [RecipeTitle]([RecipeTitle], [rowid], [title]) VALUES ('delete', OLD.[id], OLD.[title]); END; CREATE TRIGGER [Recipe_trigger_update] AFTER UPDATE ON [Recipe] BEGIN INSERT INTO [RecipeTitle]([RecipeTitle], [rowid], [title]) VALUES ('delete', OLD.[id], OLD.[title]); INSERT INTO [RecipeTitle]([rowid], [title]) VALUES (NEW.[id], NEW.[title]); 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, CHECK ( length([name]) <= 255 AND length([description]) <= 255 ), FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE ) STRICT; CREATE TABLE [Tag] ( [id] INTEGER PRIMARY KEY, [name] TEXT NOT NULL, -- Not needed, the lang is defined by the recipes linked to it -- (more than one language can be associaded to a tag). -- [lang] TEXT NOT NULL DEFAULT 'en', CHECK ( length([name]) <= 31 ) ) STRICT; CREATE UNIQUE INDEX [Tag_name_index] ON [Tag]([name]); 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 INDEX [RecipeTag_tag_id_index] ON [RecipeTag]([tag_id]); -- Delete all tags without references. CREATE TRIGGER [RecipeTag_trigger_delete] AFTER DELETE ON [RecipeTag] BEGIN DELETE FROM [Tag] WHERE [id] = OLD.[tag_id] AND (SELECT COUNT(*) = 0 FROM [RecipeTag] WHERE [tag_id] = OLD.[tag_id]); END; 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 '', CHECK ( length([name]) <= 255 AND length([comment]) <= 65535 ), 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 '', CHECK ( length([action]) <= 255 ), FOREIGN KEY(group_id) REFERENCES [Group](id) ON DELETE CASCADE ) STRICT; CREATE INDEX [Step_order_index] ON [Step]([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 '', CHECK ( length([name]) <= 255 AND length([comment]) <= 65535 ), 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 ) STRICT; 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], [quantity_unit] and [Servings] are used to display -- the entry instead of [Ingredient] data. [ingredient_id] INTEGER, -- Can be null when manually added (entry is not linked to a recipe). [recipe_scheduled_id] INTEGER, [is_checked] INTEGER NOT NULL DEFAULT FALSE, -- The following four fields contain data only if [recipe_scheduled_id] is NULL. [name] TEXT NOT NULL DEFAULT '', [quantity_value] REAL, [quantity_unit] TEXT NOT NULL DEFAULT '', [servings] INTEGER, CHECK ( length([name]) <= 255 AND ([is_checked] = TRUE OR [is_checked] = FALSE) ), 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 ) STRICT; 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] = COALESCE(( 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] LIMIT 1 -- In case a step is owned by more than one recipe (should never happen). ), 4) WHERE [ingredient_id] = OLD.[id]; END; CREATE TABLE [Settings] ( [name] TEXT NOT NULL PRIMARY KEY, -- Value can be 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');