Skip to content

Commit

Permalink
feat(db): add student class
Browse files Browse the repository at this point in the history
- merge all migration files in one file

Closes #87
Closes #88
Closes #89
Closes #91
  • Loading branch information
michaelcoll committed Jun 11, 2023
1 parent 6f46854 commit b3728e6
Show file tree
Hide file tree
Showing 11 changed files with 534 additions and 142 deletions.
140 changes: 140 additions & 0 deletions db/migrations/v1_init.sql
Original file line number Diff line number Diff line change
Expand Up @@ -41,4 +41,144 @@ CREATE TABLE quiz_question_answer

FOREIGN KEY (question_sha1) REFERENCES quiz_question (sha1),
FOREIGN KEY (answer_sha1) REFERENCES quiz_answer (sha1)
);

CREATE TABLE role
(
id INTEGER PRIMARY KEY,
name TEXT NOT NULL
);

INSERT INTO role (id, name)
VALUES (1, 'Admin');
INSERT INTO role (id, name)
VALUES (2, 'Teacher');
INSERT INTO role (id, name)
VALUES (3, 'Student');

CREATE TABLE student_class
(
uuid TEXT PRIMARY KEY,
name TEXT NOT NULL
);

CREATE TABLE user
(
id TEXT PRIMARY KEY,
email TEXT NOT NULL,
firstname TEXT NOT NULL,
lastname TEXT NOT NULL,
active INTEGER NOT NULL DEFAULT 1,
role_id INTEGER NOT NULL,
class_uuid TEXT,

FOREIGN KEY (role_id) REFERENCES role (id),
FOREIGN KEY (class_uuid) REFERENCES student_class (uuid) ON DELETE SET NULL
);

CREATE TABLE session
(
uuid TEXT PRIMARY KEY,
quiz_sha1 TEXT NOT NULL,
user_id TEXT NOT NULL,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,

UNIQUE (quiz_sha1, user_id),
FOREIGN KEY (quiz_sha1) REFERENCES quiz (sha1),
FOREIGN KEY (user_id) REFERENCES user (id)
);

CREATE TABLE session_answer
(
session_uuid TEXT NOT NULL,
user_id TEXT NOT NULL,
question_sha1 TEXT NOT NULL,
answer_sha1 TEXT NOT NULL,
checked INTEGER NOT NULL,

PRIMARY KEY (session_uuid, question_sha1, answer_sha1),
FOREIGN KEY (session_uuid) REFERENCES session (uuid),
FOREIGN KEY (user_id) REFERENCES user (id),
FOREIGN KEY (question_sha1) REFERENCES quiz_question (sha1),
FOREIGN KEY (answer_sha1) REFERENCES quiz_answer (sha1)
);

CREATE VIEW quiz_answer_count_view
AS
SELECT q.sha1 AS quiz_sha1,
COUNT(qa.valid) AS checked_answers
FROM quiz q
JOIN quiz_question_quiz qqq ON q.sha1 = qqq.quiz_sha1
JOIN quiz_question_answer qqa ON qqq.question_sha1 = qqa.question_sha1
JOIN quiz_answer qa ON qa.sha1 = qqa.answer_sha1
GROUP BY q.sha1;

CREATE VIEW session_response_view
AS
SELECT qqq.quiz_sha1,
qqq.question_sha1,
qqa.answer_sha1,
s.uuid AS session_uuid,
s.user_id,
sa.checked,
CASE
WHEN checked IS NOT NULL
THEN CASE
WHEN qa.valid == sa.checked
THEN 1
ELSE 0
END
END AS result
FROM quiz_question_quiz qqq
JOIN quiz_question_answer qqa ON qqq.question_sha1 = qqa.question_sha1
JOIN quiz_answer qa ON qa.sha1 = qqa.answer_sha1
LEFT JOIN session s ON qqq.quiz_sha1 = s.quiz_sha1
LEFT JOIN session_answer sa ON qa.sha1 = sa.answer_sha1 AND sa.question_sha1 = qqq.question_sha1 AND
sa.answer_sha1 = qqa.answer_sha1;

CREATE VIEW session_view
AS
SELECT s.uuid AS uuid,
q.sha1 AS quiz_sha1,
q.name AS quiz_name,
q.active AS quiz_active,
u.id AS user_id,
CAST(u.firstname || ' ' || u.lastname AS TEXT) AS user_name,
CAST(MAX(q.duration - (STRFTIME('%s', 'now') - STRFTIME('%s', s.created_at)), 0) AS INTEGER) AS remaining_sec,
checked_answers,
SUM(srv.result) AS results
FROM session s
JOIN quiz q ON q.sha1 = s.quiz_sha1
JOIN user u ON u.id = s.user_id
JOIN quiz_answer_count_view qacv ON s.quiz_sha1 = qacv.quiz_sha1
JOIN session_response_view srv ON s.uuid = srv.session_uuid;

CREATE TRIGGER verify_remaining_time_create
BEFORE INSERT
ON session_answer
BEGIN
SELECT CASE
WHEN (SELECT remaining_sec FROM session_view sv WHERE sv.uuid = new.session_uuid) = 0 THEN
RAISE(ABORT, 'session is over')
END;
END;

CREATE TRIGGER verify_remaining_time_update
BEFORE UPDATE
ON session_answer
BEGIN
SELECT CASE
WHEN (SELECT remaining_sec FROM session_view sv WHERE sv.uuid = new.session_uuid) = 0 THEN
RAISE(ABORT, 'session is over')
END;
END;

CREATE TABLE quiz_class_visibility
(
class_uuid TEXT NOT NULL,
quiz_sha1 TEXT NOT NULL,

PRIMARY KEY (class_uuid, quiz_sha1),
FOREIGN KEY (class_uuid) REFERENCES student_class (uuid) ON DELETE CASCADE,
FOREIGN KEY (quiz_sha1) REFERENCES quiz (sha1)
);
24 changes: 0 additions & 24 deletions db/migrations/v2_auth.sql

This file was deleted.

96 changes: 0 additions & 96 deletions db/migrations/v3_session.sql

This file was deleted.

34 changes: 34 additions & 0 deletions db/queries/quiz.sql
Original file line number Diff line number Diff line change
Expand Up @@ -49,6 +49,30 @@ FROM quiz q
JOIN quiz_answer qa ON qa.sha1 = qqa.answer_sha1
WHERE q.sha1 = ?;

-- name: FindQuizFullBySha1RestrictedToClass :many
SELECT q.sha1 AS quiz_sha1,
q.filename AS quiz_filename,
q.name AS quiz_name,
q.version AS quiz_version,
q.created_at AS quiz_created_at,
q.duration AS quiz_duration,
q.active AS quiz_active,
qq.sha1 AS question_sha1,
qq.content AS question_content,
qa.sha1 AS answer_sha1,
qa.content AS answer_content,
qa.valid AS answer_valid
FROM quiz q
JOIN quiz_question_quiz qqq ON q.sha1 = qqq.quiz_sha1
JOIN quiz_question qq ON qq.sha1 = qqq.question_sha1
JOIN quiz_question_answer qqa ON qq.sha1 = qqa.question_sha1
JOIN quiz_answer qa ON qa.sha1 = qqa.answer_sha1
JOIN quiz_class_visibility qcv ON q.sha1 = qcv.quiz_sha1
JOIN student_class sc ON sc.uuid = qcv.class_uuid
JOIN user u ON sc.uuid = u.class_uuid
WHERE q.sha1 = ?
AND u.id = ?;

-- name: FindQuizByFilenameAndLatestVersion :one
SELECT *
FROM quiz
Expand All @@ -62,6 +86,16 @@ FROM quiz
WHERE active = 1
LIMIT ? OFFSET ?;

-- name: FindAllActiveQuizRestrictedToClass :many
SELECT *
FROM quiz q
JOIN quiz_class_visibility qcv ON q.sha1 = qcv.quiz_sha1
JOIN student_class sc ON sc.uuid = qcv.class_uuid
JOIN user u ON sc.uuid = u.class_uuid
WHERE q.active = 1
AND u.id = ?
LIMIT ? OFFSET ?;

-- name: CountAllActiveQuiz :one
SELECT COUNT(1)
FROM quiz
Expand Down
28 changes: 28 additions & 0 deletions db/queries/student_class.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
-- name: CreateOrReplaceClass :exec
REPLACE INTO student_class (uuid, name)
VALUES (?, ?);

-- name: FindAllClasses :many
SELECT *
FROM student_class
LIMIT ? OFFSET ?;

-- name: DeleteClassById :exec
DELETE
FROM student_class
WHERE uuid = ?;

-- name: AssignUserToClass :exec
UPDATE user
SET class_uuid = ?
WHERE id = ?;

-- name: CreateQuizClassVisibility :exec
REPLACE INTO quiz_class_visibility (class_uuid, quiz_sha1)
VALUES (?, ?);

-- name: DeleteQuizClassVisibility :exec
DELETE
FROM quiz_class_visibility
WHERE class_uuid = ?
AND quiz_sha1 = ?;

0 comments on commit b3728e6

Please sign in to comment.