From 2883ce74c7460a7c1f92c444ce1c74c615578b8a Mon Sep 17 00:00:00 2001 From: Guillaume Subiron Date: Tue, 5 Jun 2012 14:35:23 +0200 Subject: [PATCH] Added constraints in DB --- main.py | 1 + schema.sql | 88 ++++++++++++++++++++++++++++++------------------------ 2 files changed, 50 insertions(+), 39 deletions(-) diff --git a/main.py b/main.py index 3937dfb..7cd53f3 100755 --- a/main.py +++ b/main.py @@ -33,6 +33,7 @@ def connect_db(): @app.before_request def before_request(): g.db = connect_db() + g.db.execute("PRAGMA foreign_keys = ON") @app.teardown_request def teardown_request(exception): diff --git a/schema.sql b/schema.sql index 824c4df..757b695 100644 --- a/schema.sql +++ b/schema.sql @@ -6,76 +6,86 @@ drop table if exists user_group; drop table if exists groups; drop table if exists users; +PRAGMA foreign_keys = ON; + create table users ( - id INTEGER primary key autoincrement, - email TEXT unique not null, - password TEXT not null, - name TEXT unique not null, + id INTEGER PRIMARY KEY AUTOINCREMENT, + email TEXT UNIQUE NOT NULL, + password TEXT NOT NULL, + name TEXT UNIQUE NOT NULL, organization TEXT, - is_admin INTEGER default 0 not null, - key TEXT + is_admin BOOLEAN DEFAULT 0 NOT NULL, + key TEXT, + CHECK (is_admin IN (0, 1)) ); create table groups ( - id INTEGER primary key autoincrement, - name TEXT unique not null, - system INTEGER default 0 not null + id INTEGER PRIMARY KEY AUTOINCREMENT, + name TEXT UNIQUE NOT NULL, + system BOOLEAN DEFAULT 0 NOT NULL, + CHECK (system IN (0, 1)) ); create table user_group ( id_user INTEGER, id_group INTEGER, - FOREIGN KEY(id_user) REFERENCES users(id), - FOREIGN KEY(id_group) REFERENCES groups(id), + FOREIGN KEY(id_user) REFERENCES users (id) ON DELETE CASCADE, + FOREIGN KEY(id_group) REFERENCES groups (id) ON DELETE CASCADE, PRIMARY KEY(id_user, id_group) ); create table votes ( - id INTEGER primary key autoincrement, - title TEXT not null, + id INTEGER PRIMARY KEY AUTOINCREMENT, + title TEXT NOT NULL, description TEXT, category TEXT, - date_begin INTEGER default CURRENT_TIMESTAMP not null, - date_end INTEGER not null, - is_transparent INTEGER default 1 not null, - is_public INTEGER default 1 not null, - is_multiplechoice INTEGER default 1 not null, - is_weighted INTEGER default 0 not null, - is_open INTEGER default 0 not null, - is_terminated INTEGER default 0 not null, - id_author INTEGER, -- :COMMENT:maethor:120528: not null ? - id_group INTEGER default 1 not null, - FOREIGN KEY(id_author) REFERENCES users(id) - FOREIGN KEY(id_group) REFERENCES groups(id) + date_begin INTEGER DEFAULT CURRENT_TIMESTAMP NOT NULL, + date_end INTEGER NOT NULL, + is_transparent BOOLEAN DEFAULT 1 NOT NULL, + is_public BOOLEAN DEFAULT 1 NOT NULL, + is_multiplechoice BOOLEAN DEFAULT 1 NOT NULL, + is_weighted BOOLEAN DEFAULT 0 NOT NULL, + is_open BOOLEAN DEFAULT 0 NOT NULL, + is_terminated BOOLEAN DEFAULT 0 NOT NULL, + id_author INTEGER DEFAULT 1 NOT NULL, -- :COMMENT:maethor:120528: not null ? + id_group INTEGER DEFAULT 1 NOT NULL, + FOREIGN KEY(id_author) REFERENCES users (id) ON DELETE SET DEFAULT, + FOREIGN KEY(id_group) REFERENCES groups (id), + CHECK (is_transparent IN (0, 1)), + CHECK (is_public IN (0, 1)), + CHECK (is_weighted IN (0, 1)), + CHECK (is_open IN (0, 1)), + CHECK (is_terminated IN (0, 1)) ); create table attachments ( - id INTEGER primary key autoincrement, - url TEXT not null, - id_vote INTEGER not null, - FOREIGN KEY(id_vote) REFERENCES vote(id) + id INTEGER PRIMARY KEY AUTOINCREMENT, + url TEXT NOT NULL, + id_vote INTEGER NOT NULL, + FOREIGN KEY(id_vote) REFERENCES votes (id) ON DELETE CASCADE ); create table choices ( - id INTEGER primary key autoincrement, - name TEXT not null, - id_vote INTEGER not null, - FOREIGN KEY(id_vote) REFERENCES vote(id) + id INTEGER PRIMARY KEY AUTOINCREMENT, + name TEXT NOT NULL, + id_vote INTEGER NOT NULL, + FOREIGN KEY(id_vote) REFERENCES votes (id) ON DELETE CASCADE ); create table user_choice ( id_user INTEGER, id_choice INTEGER, weight INTEGER, - FOREIGN KEY(id_user) REFERENCES users(id), - FOREIGN KEY(id_choice) REFERENCES choices(id), + FOREIGN KEY(id_user) REFERENCES users (id) ON DELETE CASCADE, + FOREIGN KEY(id_choice) REFERENCES choices (id) ON DELETE CASCADE, PRIMARY KEY(id_user, id_choice) ); -- Test data -insert into users (email, password, name, organization, is_admin, key) values ("admin@admin.fr", "d033e22ae348aeb5660fc2140aec35850c4da997", "Toto (admin) Tata", "World corp", 1, "test"); -- mdp = admin -insert into groups (id, name, system) values (1, "Tous", 1); -insert into groups (name) values ("CA"); -insert into groups (name) values ("Membres"); +INSERT INTO users (id, email, password, name, organization, is_admin, key) VALUES (1, "admin@admin.fr", "d033e22ae348aeb5660fc2140aec35850c4da997", "Toto (admin) Tata", "World corp", 1, "test"); -- mdp = admin +INSERT INTO groups (id, name, system) VALUES (1, "Tous", 1); +INSERT INTO groups (name) VALUES ("CA"); +INSERT INTO groups (name) VALUES ("Membres"); +INSERT INTO user_group (id_user, id_group) VALUES(1, 1); -- 2.20.1