You can not select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
339 lines
8.3 KiB
339 lines
8.3 KiB
-- Suppression des tables
|
|
DROP TABLE IF EXISTS Commentary;
|
|
DROP TABLE IF EXISTS Favorite;
|
|
DROP TABLE IF EXISTS DailyQuote;
|
|
DROP TABLE IF EXISTS Quote;
|
|
DROP TABLE IF EXISTS Caracter;
|
|
DROP TABLE IF EXISTS Source;
|
|
DROP TABLE IF EXISTS Record_quiz;
|
|
DROP TABLE IF EXISTS Quiz_Question;
|
|
DROP TABLE IF EXISTS Quiz;
|
|
DROP TABLE IF EXISTS Question;
|
|
DROP TABLE IF EXISTS Admin;
|
|
DROP TABLE IF EXISTS Users;
|
|
DROP TABLE IF EXISTS Image;
|
|
|
|
-- Création des tables
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Image(
|
|
id_img NUMERIC PRIMARY KEY,
|
|
imgPath varchar(300) NOT NULL UNIQUE
|
|
);
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Users(
|
|
id_user SERIAL PRIMARY KEY,
|
|
username varchar(50) NOT NULL,
|
|
email varchar(50) NOT NULL,
|
|
password varchar(100) NOT NULL,
|
|
img NUMERIC NOT NULL,
|
|
creation date NOT NULL,
|
|
CONSTRAINT unique_col UNIQUE (email),
|
|
CONSTRAINT fk_img FOREIGN KEY(img) REFERENCES Image(id_img)
|
|
);
|
|
|
|
Create OR REPLACE Function IfUserIsAdmin() RETURNS trigger AS $$
|
|
DECLARE
|
|
|
|
BEGIN
|
|
Delete From Admin
|
|
where users = OLD.id_user;
|
|
|
|
RETURN OLD;
|
|
END;
|
|
$$ LANGUAGE plpgsql ;
|
|
|
|
|
|
Create Trigger IfUserIsAdmin BEFORE DELETE on Users
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION IfUserIsAdmin();
|
|
|
|
|
|
Create OR REPLACE Function DeleteUserFavorite() RETURNS trigger AS $$
|
|
DECLARE
|
|
|
|
BEGIN
|
|
Delete From Favorite
|
|
where users = OLD.id_user;
|
|
|
|
RETURN OLD;
|
|
END;
|
|
$$ LANGUAGE plpgsql ;
|
|
|
|
|
|
Create Trigger DeleteUserFavorite BEFORE DELETE on Users
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION DeleteUserFavorite();
|
|
|
|
Create OR REPLACE Function DeleteUserCommentary() RETURNS trigger AS $$
|
|
DECLARE
|
|
|
|
BEGIN
|
|
Delete From Commentary
|
|
where users = OLD.id_user;
|
|
|
|
RETURN OLD;
|
|
END;
|
|
$$ LANGUAGE plpgsql ;
|
|
|
|
|
|
Create Trigger DeleteUserCommentary BEFORE DELETE on Users
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION DeleteUserCommentary();
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Admin(
|
|
users SERIAL PRIMARY KEY,
|
|
CONSTRAINT fk_user FOREIGN KEY(users) REFERENCES Users(id_user)
|
|
);
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Question(
|
|
id_question SERIAL PRIMARY KEY,
|
|
texte text NOT NULL UNIQUE,
|
|
answerA varchar(30) NOT NULL,
|
|
answerB varchar(30) NOT NULL,
|
|
answerC varchar(30) NOT NULL,
|
|
answerD varchar(30) NOT NULL,
|
|
cAnswer varchar(30) NOT NULL,
|
|
CONSTRAINT check_cAnswer CHECK (cAnswer = answerA OR cAnswer = answerB OR cAnswer = answerC OR cAnswer = answerD)
|
|
);
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Quiz(
|
|
id_quiz SERIAL PRIMARY KEY,
|
|
title varchar(40) NOT NULL,
|
|
img NUMERIC NOT NULL,
|
|
nb_quest numeric Default 0,
|
|
CONSTRAINT fk_img FOREIGN KEY(img) REFERENCES Image(id_img)
|
|
);
|
|
|
|
Create OR REPLACE Function DeleteQuiz() RETURNS trigger AS $$
|
|
DECLARE
|
|
|
|
BEGIN
|
|
Delete From Quiz_Question
|
|
where quiz=OLD.id_quiz;
|
|
|
|
Delete From Record_quiz
|
|
where quiz=OLD.id_quiz;
|
|
END;
|
|
$$ LANGUAGE plpgsql ;
|
|
|
|
Create Trigger DeleteQuiz BEFORE DELETE on Quiz
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION DeleteQuiz();
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Quiz_Question(
|
|
quiz SERIAL NOT NULL,
|
|
question SERIAL NOT NULL,
|
|
PRIMARY KEY (quiz, question),
|
|
CONSTRAINT fk_quiz FOREIGN KEY(quiz) REFERENCES Quiz(id_quiz),
|
|
CONSTRAINT fk_question FOREIGN KEY(question) REFERENCES Question(id_question)
|
|
);
|
|
|
|
Create OR REPLACE Function NombreQuestionQuiz() RETURNS trigger AS $$
|
|
DECLARE
|
|
nb numeric;
|
|
BEGIN
|
|
|
|
IF TG_OP='DELETE' Then
|
|
SELECT count(quiz) INTO nb
|
|
FROM Quiz_Question
|
|
WHERE quiz = OLD.quiz;
|
|
Else
|
|
SELECT count(quiz) INTO nb
|
|
FROM Quiz_Question
|
|
WHERE quiz = NEW.quiz;
|
|
End IF;
|
|
|
|
|
|
Update Quiz
|
|
set nb_quest=nb
|
|
where id_quiz=NEW.quiz;
|
|
|
|
Return OLD;
|
|
END;
|
|
$$ LANGUAGE plpgsql ;
|
|
|
|
Create Trigger NombreQuestionQuiz AFTER INSERT or UPDATE or DELETE on Quiz_Question
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION NombreQuestionQuiz();
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Record_quiz(
|
|
users SERIAL NOT NULL,
|
|
quiz SERIAL NOT NULL,
|
|
nbPoint numeric DEFAULT 0,
|
|
timeQ numeric DEFAULT 0,
|
|
PRIMARY KEY (users, quiz),
|
|
CONSTRAINT fk_user FOREIGN KEY(users) REFERENCES Users(id_user),
|
|
CONSTRAINT fk_quiz FOREIGN KEY(quiz) REFERENCES Quiz(id_quiz),
|
|
CONSTRAINT err_nbPoint CHECK(nbPoint >= 0),
|
|
CONSTRAINT err_timeQ CHECK(timeQ >= 0)
|
|
);
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Source(
|
|
id_source SERIAL PRIMARY KEY,
|
|
title varchar(100) NOT NULL,
|
|
dateS numeric(4) NOT NULL
|
|
);
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Caracter(
|
|
id_caracter SERIAL PRIMARY KEY,
|
|
caracter varchar(100) NOT NULL,
|
|
id_img NUMERIC NOT NULL
|
|
);
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Quote(
|
|
id_quote SERIAL PRIMARY KEY,
|
|
content text NOT NULL,
|
|
likes numeric DEFAULT '0',
|
|
langue char(2) NOT NULL,
|
|
isValide boolean NOT NULL DEFAULT 'false',
|
|
reason varchar(100) NOT NULL,
|
|
id_caracter SERIAL NOT NULL,
|
|
id_source SERIAL NOT NULL,
|
|
id_user_verif SERIAL NOT NULL,
|
|
CONSTRAINT fk_caracter FOREIGN KEY(id_caracter) REFERENCES Caracter(id_caracter),
|
|
CONSTRAINT fk_source FOREIGN KEY(id_source) REFERENCES Source(id_source),
|
|
CONSTRAINT fk_userverif FOREIGN KEY(id_user_verif) REFERENCES Users(id_user),
|
|
CONSTRAINT err_nbLike CHECK (likes >= 0),
|
|
CONSTRAINT err_language CHECK (langue = 'fr' OR langue = 'en')
|
|
);
|
|
|
|
Create OR REPLACE Function DeleteQuoteBEFORE() RETURNS trigger AS $$
|
|
DECLARE
|
|
|
|
BEGIN
|
|
Delete From Favorite
|
|
where quote=OLD.id_quote;
|
|
|
|
|
|
Delete From Commentary
|
|
where quote=OLD.id_quote;
|
|
|
|
|
|
If OLD.id_quote in (Select citation_id From DailyQuote) Then
|
|
Update DailyQuote
|
|
set citation_id = (Select id_quote
|
|
From Quote
|
|
Where id_quote!=OLD.id_quote
|
|
ORDER BY RAND()
|
|
LIMIT 1)
|
|
Where citation_id=OLD.id_quote;
|
|
END IF;
|
|
|
|
Return OLD;
|
|
END;
|
|
$$ LANGUAGE plpgsql ;
|
|
|
|
Create Trigger DeleteQuoteBEFORE BEFORE DELETE on Quote
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION DeleteQuoteBEFORE();
|
|
|
|
|
|
Create OR REPLACE Function DeleteQuoteAFTER() RETURNS trigger AS $$
|
|
DECLARE
|
|
nb numeric;
|
|
BEGIN
|
|
Select count(id_caracter) into nb
|
|
from Quote
|
|
where id_caracter=OLD.id_caracter;
|
|
|
|
IF nb <= 1 Then
|
|
Delete from Caracter
|
|
where id_caracter=OLD.id_caracter;
|
|
END IF;
|
|
|
|
|
|
Select count(id_source) into nb
|
|
from Quote
|
|
where id_source=OLD.id_source;
|
|
|
|
IF nb <= 1 Then
|
|
Delete from Source
|
|
where id_source=OLD.id_source;
|
|
END IF;
|
|
|
|
Return OLD;
|
|
END;
|
|
$$ LANGUAGE plpgsql ;
|
|
|
|
Create Trigger DeleteQuoteAFTER AFTER DELETE on Quote
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION DeleteQuoteAFTER();
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE DailyQuote(
|
|
citation_id INT PRIMARY KEY,
|
|
FOREIGN KEY (citation_id) REFERENCES Quote(id_quote) ON DELETE CASCADE
|
|
);
|
|
|
|
Create OR REPLACE Function UniqueDailyQuote() RETURNS trigger AS $$
|
|
DECLARE
|
|
nb numeric;
|
|
BEGIN
|
|
Select count(*) into nb
|
|
from DailyQuote;
|
|
|
|
IF nb = 0 Then
|
|
INSERT INTO DailyQuote (citation_id)
|
|
VALUES( (Select id_quote
|
|
From Quote
|
|
Where id_quote!=OLD.id_quote
|
|
ORDER BY RAND()
|
|
LIMIT 1 ) );
|
|
|
|
ELSIF nb>1 then
|
|
|
|
DELETE From DailyQuote
|
|
where citation_id!=NEW.citation_id;
|
|
END IF;
|
|
RETURN OLD;
|
|
END;
|
|
$$ LANGUAGE plpgsql ;
|
|
|
|
Create Trigger UniqueDailyQuote AFTER INSERT or DELETE on DailyQuote
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION UniqueDailyQuote();
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
|
|
CREATE TABLE Favorite(
|
|
users SERIAL NOT NULL,
|
|
quote SERIAL NOT NULL,
|
|
PRIMARY KEY (users, quote),
|
|
CONSTRAINT fk_quote FOREIGN KEY(quote) REFERENCES Quote(id_quote),
|
|
CONSTRAINT fk_user FOREIGN KEY(users) REFERENCES Users(id_user)
|
|
);
|
|
|
|
-------------------------------------------------------------------------
|
|
|
|
CREATE TABLE Commentary(
|
|
id_comment SERIAL PRIMARY KEY,
|
|
quote SERIAL NOT NULL,
|
|
users SERIAL NOT NULL,
|
|
dateC date NOT NULL,
|
|
comment text NOT NULL,
|
|
CONSTRAINT fk_quote FOREIGN KEY(quote) REFERENCES Quote(id_quote),
|
|
CONSTRAINT fk_user FOREIGN KEY(users) REFERENCES Users(id_user)
|
|
);
|
|
|
|
-------------------------------------------------------------------------
|
|
|