Add some CHECK constraints for data validation.
This commit is contained in:
parent
c13bc47d75
commit
d2733ccf01
1 changed files with 48 additions and 37 deletions
|
|
@ -30,23 +30,19 @@ CREATE TABLE [User] (
|
||||||
-- Password can only be reset during a certain duration after this time.
|
-- Password can only be reset during a certain duration after this time.
|
||||||
[password_reset_datetime] TEXT,
|
[password_reset_datetime] TEXT,
|
||||||
|
|
||||||
[is_admin] INTEGER NOT NULL DEFAULT FALSE
|
[is_admin] INTEGER NOT NULL DEFAULT FALSE,
|
||||||
|
|
||||||
|
CHECK (
|
||||||
|
length([email]) <= 255 AND
|
||||||
|
length([name]) <= 255 AND
|
||||||
|
length([password]) <= 255 AND
|
||||||
|
[first_day_of_the_week] >= 0 AND [first_day_of_the_week] <= 6
|
||||||
|
)
|
||||||
) STRICT;
|
) STRICT;
|
||||||
|
|
||||||
CREATE INDEX [validation_token_index] ON [User]([validation_token]);
|
CREATE INDEX [validation_token_index] ON [User]([validation_token]);
|
||||||
CREATE UNIQUE INDEX [User_email_index] ON [User]([email]);
|
CREATE UNIQUE INDEX [User_email_index] ON [User]([email]);
|
||||||
|
|
||||||
CREATE TRIGGER [User_trigger_update_first_day_of_the_week]
|
|
||||||
BEFORE UPDATE OF [first_day_of_the_week]
|
|
||||||
ON [User]
|
|
||||||
BEGIN
|
|
||||||
SELECT
|
|
||||||
CASE
|
|
||||||
WHEN NEW.[first_day_of_the_week] < 0 OR NEW.[first_day_of_the_week] > 6 THEN
|
|
||||||
RAISE (ABORT, 'Invalid [first_day_of_the_week] value')
|
|
||||||
END;
|
|
||||||
END;
|
|
||||||
|
|
||||||
CREATE TABLE [UserLoginToken] (
|
CREATE TABLE [UserLoginToken] (
|
||||||
[id] INTEGER PRIMARY KEY,
|
[id] INTEGER PRIMARY KEY,
|
||||||
[user_id] INTEGER NOT NULL,
|
[user_id] INTEGER NOT NULL,
|
||||||
|
|
@ -56,9 +52,14 @@ CREATE TABLE [UserLoginToken] (
|
||||||
-- Can be stored in a cookie to be able to authenticate without a password.
|
-- Can be stored in a cookie to be able to authenticate without a password.
|
||||||
[token] TEXT NOT NULL,
|
[token] TEXT NOT NULL,
|
||||||
|
|
||||||
[ip] TEXT, -- Can be ipv4 or ipv6
|
[ip] TEXT, -- Can be ipv4 or ipv6.
|
||||||
[user_agent] TEXT,
|
[user_agent] TEXT,
|
||||||
|
|
||||||
|
CHECK (
|
||||||
|
length([ip]) <= 255 AND
|
||||||
|
length([user_agent]) <= 255
|
||||||
|
),
|
||||||
|
|
||||||
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE
|
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE
|
||||||
) STRICT;
|
) STRICT;
|
||||||
|
|
||||||
|
|
@ -78,31 +79,15 @@ CREATE TABLE [Recipe] (
|
||||||
[is_public] INTEGER NOT NULL DEFAULT FALSE,
|
[is_public] INTEGER NOT NULL DEFAULT FALSE,
|
||||||
[creation_datetime] TEXT NOT NULL,
|
[creation_datetime] TEXT NOT NULL,
|
||||||
|
|
||||||
|
CHECK (
|
||||||
|
length([title]) <= 255 AND
|
||||||
|
length([description]) <= 65535 AND
|
||||||
|
[difficulty] >= 0 AND [difficulty] <= 3
|
||||||
|
),
|
||||||
|
|
||||||
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE SET NULL
|
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE SET NULL
|
||||||
) STRICT;
|
) 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] (
|
CREATE TABLE [Image] (
|
||||||
[Id] INTEGER PRIMARY KEY,
|
[Id] INTEGER PRIMARY KEY,
|
||||||
[recipe_id] INTEGER NOT NULL,
|
[recipe_id] INTEGER NOT NULL,
|
||||||
|
|
@ -110,6 +95,11 @@ CREATE TABLE [Image] (
|
||||||
[description] TEXT NOT NULL DEFAULT '',
|
[description] TEXT NOT NULL DEFAULT '',
|
||||||
[image] BLOB NOT NULL,
|
[image] BLOB NOT NULL,
|
||||||
|
|
||||||
|
CHECK (
|
||||||
|
length([name]) <= 255 AND
|
||||||
|
length([description]) <= 255
|
||||||
|
),
|
||||||
|
|
||||||
FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE
|
FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE
|
||||||
) STRICT;
|
) STRICT;
|
||||||
|
|
||||||
|
|
@ -127,8 +117,11 @@ CREATE TABLE [RecipeTag] (
|
||||||
|
|
||||||
CREATE TABLE [Tag] (
|
CREATE TABLE [Tag] (
|
||||||
[id] INTEGER PRIMARY KEY,
|
[id] INTEGER PRIMARY KEY,
|
||||||
[name] TEXT NOT NULL
|
[name] TEXT NOT NULL,
|
||||||
-- https://en.wikipedia.org/wiki/List_of_ISO_639_language_codes
|
|
||||||
|
CHECK (
|
||||||
|
length([name]) <= 31
|
||||||
|
)
|
||||||
) STRICT;
|
) STRICT;
|
||||||
|
|
||||||
CREATE UNIQUE INDEX [Tag_name_lang_index] ON [Tag]([name]);
|
CREATE UNIQUE INDEX [Tag_name_lang_index] ON [Tag]([name]);
|
||||||
|
|
@ -142,6 +135,11 @@ CREATE TABLE [Group] (
|
||||||
[name] TEXT NOT NULL DEFAULT '',
|
[name] TEXT NOT NULL DEFAULT '',
|
||||||
[comment] 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
|
FOREIGN KEY([recipe_id]) REFERENCES [Recipe]([id]) ON DELETE CASCADE
|
||||||
) STRICT;
|
) STRICT;
|
||||||
|
|
||||||
|
|
@ -155,6 +153,10 @@ CREATE TABLE [Step] (
|
||||||
|
|
||||||
[action] TEXT NOT NULL DEFAULT '',
|
[action] TEXT NOT NULL DEFAULT '',
|
||||||
|
|
||||||
|
CHECK (
|
||||||
|
length([action]) <= 255
|
||||||
|
),
|
||||||
|
|
||||||
FOREIGN KEY(group_id) REFERENCES [Group](id) ON DELETE CASCADE
|
FOREIGN KEY(group_id) REFERENCES [Group](id) ON DELETE CASCADE
|
||||||
) STRICT;
|
) STRICT;
|
||||||
|
|
||||||
|
|
@ -172,6 +174,11 @@ CREATE TABLE [Ingredient] (
|
||||||
|
|
||||||
[comment] 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
|
FOREIGN KEY([step_id]) REFERENCES [Step]([id]) ON DELETE CASCADE
|
||||||
) STRICT;
|
) STRICT;
|
||||||
|
|
||||||
|
|
@ -210,6 +217,10 @@ CREATE TABLE [ShoppingEntry] (
|
||||||
[quantity_unit] TEXT NOT NULL DEFAULT '',
|
[quantity_unit] TEXT NOT NULL DEFAULT '',
|
||||||
[servings] INTEGER,
|
[servings] INTEGER,
|
||||||
|
|
||||||
|
CHECK (
|
||||||
|
length([name]) <= 255
|
||||||
|
),
|
||||||
|
|
||||||
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE,
|
FOREIGN KEY([user_id]) REFERENCES [User]([id]) ON DELETE CASCADE,
|
||||||
FOREIGN KEY([ingredient_id]) REFERENCES [Ingredient]([id]) ON DELETE SET NULL,
|
FOREIGN KEY([ingredient_id]) REFERENCES [Ingredient]([id]) ON DELETE SET NULL,
|
||||||
FOREIGN KEY([recipe_scheduled_id]) REFERENCES [RecipeScheduled]([id]) ON DELETE SET NULL
|
FOREIGN KEY([recipe_scheduled_id]) REFERENCES [RecipeScheduled]([id]) ON DELETE SET NULL
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue