From 060c4d1a988afda61fba8845fa3c813bb8aa4d32 Mon Sep 17 00:00:00 2001
From: bayusamudra5502 <bayusamudra.55.02.com@gmail.com>
Date: Fri, 28 Apr 2023 09:21:52 +0700
Subject: [PATCH] feat: adding schema

---
 .../staging/20230312161230-add-course.sql     | 33 +++++++++++++
 .../staging/20230312161234-add-materials.sql  | 30 ++++++++++++
 .../staging/20230312161407-add-quiz.sql       | 43 +++++++++++++++++
 .../staging/20230312172631-add-quiz-take.sql  | 32 +++++++++++++
 .../staging/20230314061153-extend-course.sql  | 26 ++++++++++
 .../staging/20230314062152-course-flavor.sql  | 43 +++++++++++++++++
 .../staging/20230314062806-course-example.sql | 36 ++++++++++++++
 .../staging/20230314101130-normal-user.sql    | 13 +++++
 ...230316185603-add-contraint-unique-abbr.sql | 14 ++++++
 ...230329064016-delete-course-contributor.sql | 43 +++++++++++++++++
 .../20230401130532-update-material.sql        |  8 ++++
 .../staging/20230401130806-update-quiz.sql    | 47 +++++++++++++++++++
 12 files changed, 368 insertions(+)
 create mode 100644 migrations/staging/20230312161230-add-course.sql
 create mode 100644 migrations/staging/20230312161234-add-materials.sql
 create mode 100644 migrations/staging/20230312161407-add-quiz.sql
 create mode 100644 migrations/staging/20230312172631-add-quiz-take.sql
 create mode 100644 migrations/staging/20230314061153-extend-course.sql
 create mode 100644 migrations/staging/20230314062152-course-flavor.sql
 create mode 100644 migrations/staging/20230314062806-course-example.sql
 create mode 100644 migrations/staging/20230314101130-normal-user.sql
 create mode 100644 migrations/staging/20230316185603-add-contraint-unique-abbr.sql
 create mode 100644 migrations/staging/20230329064016-delete-course-contributor.sql
 create mode 100644 migrations/staging/20230401130532-update-material.sql
 create mode 100644 migrations/staging/20230401130806-update-quiz.sql

diff --git a/migrations/staging/20230312161230-add-course.sql b/migrations/staging/20230312161230-add-course.sql
new file mode 100644
index 0000000..0fda2ea
--- /dev/null
+++ b/migrations/staging/20230312161230-add-course.sql
@@ -0,0 +1,33 @@
+
+-- +migrate Up
+CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
+
+CREATE TABLE public."major" (
+  id        UUID DEFAULT uuid_generate_v4(),
+  name      varchar(250) NOT NULL,
+  PRIMARY KEY (id)
+);
+
+CREATE TABLE public."course" (
+  id          varchar(30) NOT NULL,
+  name        varchar(255) NOT NULL,
+  major_id    UUID NOT NULL,
+  description TEXT,
+  PRIMARY KEY (id),
+  FOREIGN KEY (major_id) REFERENCES public."major"(id)
+);
+
+CREATE TABLE public."course_contributor" (
+  course_id     varchar(30) NOT NULL,
+  email         varchar(100) NOT NULL,
+  PRIMARY KEY (course_id, email),
+  FOREIGN KEY (course_id) 
+    REFERENCES public."course"(id) 
+    ON UPDATE CASCADE ON DELETE CASCADE,
+  FOREIGN KEY (email) REFERENCES public."user"(email) ON DELETE CASCADE 
+);
+
+-- +migrate Down
+DROP TABLE public."course_contributor";
+DROP TABLE public."course";
+DROP TABLE public."major";
\ No newline at end of file
diff --git a/migrations/staging/20230312161234-add-materials.sql b/migrations/staging/20230312161234-add-materials.sql
new file mode 100644
index 0000000..b41922a
--- /dev/null
+++ b/migrations/staging/20230312161234-add-materials.sql
@@ -0,0 +1,30 @@
+-- +migrate Up
+CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
+
+CREATE TYPE MATERIAL_TYPE AS ENUM('video','handout','external');
+
+CREATE TABLE public."material" (
+  id                UUID DEFAULT uuid_generate_v4(),
+  course_id         varchar(30) NOT NULL,
+  creator_email     varchar(100) NOT NULL,
+  name              varchar(250) NOT NULL,
+  PRIMARY KEY(id),
+  FOREIGN KEY (course_id, creator_email) 
+    REFERENCES public."course_contributor"(course_id, email)
+    ON DELETE CASCADE ON UPDATE CASCADE
+);
+
+CREATE TABLE public."material_data" (
+  id                UUID DEFAULT uuid_generate_v4(),
+  "type"            MATERIAL_TYPE NOT NULL,
+  link              TEXT NOT NULL,
+  material_id       UUID NOT NULL,
+  PRIMARY KEY(id),
+  FOREIGN KEY(material_id) 
+    REFERENCES public."material"(id)
+);
+
+-- +migrate Down
+DROP TABLE public."material_data";
+DROP TABLE public."material";
+DROP TYPE MATERIAL_TYPE;
diff --git a/migrations/staging/20230312161407-add-quiz.sql b/migrations/staging/20230312161407-add-quiz.sql
new file mode 100644
index 0000000..3e60819
--- /dev/null
+++ b/migrations/staging/20230312161407-add-quiz.sql
@@ -0,0 +1,43 @@
+
+-- +migrate Up
+CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
+
+CREATE TYPE PROBLEM_TYPE AS ENUM('choice');
+
+CREATE TABLE public."quiz" (
+  id               UUID DEFAULT uuid_generate_v4(),
+  name             varchar(255) NOT NULL,
+  course_id        varchar(30)  NOT NULL,  
+  creator_email    varchar(100) NOT NULL,
+  PRIMARY KEY(id),
+  FOREIGN KEY (course_id, creator_email) 
+    REFERENCES public."course_contributor"(course_id, email)
+    ON DELETE CASCADE ON UPDATE CASCADE
+);
+
+CREATE TABLE public."quiz_problem" (
+  id        UUID DEFAULT uuid_generate_v4(),
+  statement TEXT NOT NULL,
+  "type"    PROBLEM_TYPE NOT NULL,
+  quiz_id   UUID NOT NULL,
+  PRIMARY KEY(id),
+  FOREIGN KEY(quiz_id)
+    REFERENCES public."quiz"(id)
+);
+
+CREATE TABLE public."quiz_choice_option" (
+  id              UUID DEFAULT uuid_generate_v4(),
+  quiz_problem_id UUID NOT NULL,
+  statement       TEXT NOT NULL,
+  is_answer       BOOLEAN DEFAULT false,
+  PRIMARY KEY(id, quiz_problem_id),
+  FOREIGN KEY (quiz_problem_id)
+    REFERENCES public."quiz_problem"(id)
+    ON DELETE CASCADE
+);
+
+-- +migrate Down
+DROP TABLE public."quiz_choice_option";
+DROP TABLE public."quiz_problem";
+DROP TABLE public."quiz";
+DROP TYPE PROBLEM_TYPE;
diff --git a/migrations/staging/20230312172631-add-quiz-take.sql b/migrations/staging/20230312172631-add-quiz-take.sql
new file mode 100644
index 0000000..3104bb9
--- /dev/null
+++ b/migrations/staging/20230312172631-add-quiz-take.sql
@@ -0,0 +1,32 @@
+
+-- +migrate Up
+CREATE TABLE public."quiz_take" (
+  id               UUID DEFAULT uuid_generate_v4(),
+  quiz_id          UUID NOT NULL,
+  email            varchar(100) NOT NULL,         
+  start_time       TIMESTAMP DEFAULT NOW(),
+  is_finished      BOOLEAN DEFAULT false,
+  score            INT DEFAULT 0,
+  PRIMARY KEY(id),
+  FOREIGN KEY (quiz_id)
+    REFERENCES public."quiz"(id),
+  FOREIGN KEY (email)
+    REFERENCES public."user"(email)
+    ON DELETE CASCADE ON UPDATE CASCADE
+);
+
+CREATE TABLE public."quiz_take_choice_answer" (
+  quiz_take_id       UUID NOT NULL,
+  answer_choice_id   UUID NOT NULL,
+  quiz_problem_id    UUID NOT NULL,
+  PRIMARY KEY (quiz_take_id, quiz_problem_id),
+  FOREIGN KEY (quiz_take_id)
+    REFERENCES public."quiz_take"(id)
+    ON DELETE CASCADE ON UPDATE CASCADE,
+  FOREIGN KEY (answer_choice_id, quiz_problem_id)
+    REFERENCES public."quiz_choice_option"(id, quiz_problem_id)
+);
+
+-- +migrate Down
+DROP TABLE public."quiz_take_choice_answer";
+DROP TABLE public."quiz_take";
\ No newline at end of file
diff --git a/migrations/staging/20230314061153-extend-course.sql b/migrations/staging/20230314061153-extend-course.sql
new file mode 100644
index 0000000..df60336
--- /dev/null
+++ b/migrations/staging/20230314061153-extend-course.sql
@@ -0,0 +1,26 @@
+
+-- +migrate Up
+
+CREATE TABLE public."faculty" (
+  id        UUID DEFAULT uuid_generate_v4(),
+  name      varchar(250) NOT NULL,
+  PRIMARY KEY (id)
+);
+
+ALTER TABLE public."major"
+  ADD COLUMN fac_id UUID NOT NULL,
+  ADD FOREIGN KEY (fac_id) REFERENCES public."faculty"(id);
+
+ALTER TABLE public."course"
+  ADD COLUMN email varchar(100) NOT NULL,
+  ADD FOREIGN KEY (email) REFERENCES public."user"(email);
+
+-- +migrate Down
+
+ALTER TABLE public."course"
+  DROP COLUMN email;
+
+ALTER TABLE public."major"
+  DROP COLUMN fac_id;
+
+DROP TABLE public."faculty";
\ No newline at end of file
diff --git a/migrations/staging/20230314062152-course-flavor.sql b/migrations/staging/20230314062152-course-flavor.sql
new file mode 100644
index 0000000..0b46742
--- /dev/null
+++ b/migrations/staging/20230314062152-course-flavor.sql
@@ -0,0 +1,43 @@
+
+-- +migrate Up
+ALTER TABLE public."faculty"
+  ADD COLUMN abbreviation VARCHAR(20) DEFAULT NULL;
+
+ALTER TABLE public."major"
+  ADD COLUMN abbreviation VARCHAR(20) DEFAULT NULL;
+
+ALTER TABLE public."course"
+  ADD COLUMN abbreviation VARCHAR(20) DEFAULT NULL,
+  ADD COLUMN lecturer VARCHAR(250) DEFAULT NULL;
+
+-- +migrate StatementBegin
+CREATE OR REPLACE FUNCTION assign_lecturer()
+RETURNS TRIGGER
+AS $assign$
+BEGIN
+  IF NEW.lecturer is NULL THEN
+    NEW.lecturer = (SELECT name FROM public."user" WHERE email = NEW.email);
+  END IF;
+  RETURN NEW;
+END;
+$assign$ LANGUAGE plpgsql;
+-- +migrate StatementEnd
+
+CREATE TRIGGER assign_lecturer
+BEFORE INSERT ON public."course"
+FOR EACH ROW EXECUTE PROCEDURE assign_lecturer();
+
+-- +migrate Down
+DROP TRIGGER IF EXISTS assign_lecturer ON public."course"
+
+DROP FUNCTION IF EXISTS assign_lecturer();
+
+ALTER TABLE public."course"
+  DROP COLUMN abbreviation,
+  DROP COLUMN lecturer;
+
+ALTER TABLE public."major"
+  DROP COLUMN abbreviation;
+
+ALTER TABLE public."faculty"
+  DROP COLUMN abbreviation;
\ No newline at end of file
diff --git a/migrations/staging/20230314062806-course-example.sql b/migrations/staging/20230314062806-course-example.sql
new file mode 100644
index 0000000..a5922b1
--- /dev/null
+++ b/migrations/staging/20230314062806-course-example.sql
@@ -0,0 +1,36 @@
+
+-- +migrate Up
+UPDATE public."user" SET
+  name = 'Dr. Yani Widyani, S.T, M.T.'
+  WHERE email = 'contributor@example.com';
+
+INSERT INTO public."faculty" ("name", "abbreviation")
+VALUES
+  ('Sekolah Teknik Elektro dan Informatika', 'STEI');
+
+INSERT INTO public."major" ("name", "fac_id", "abbreviation")
+VALUES
+  ('Teknik Informatika', (SELECT id FROM public."faculty" WHERE abbreviation='STEI'), 'IF');
+
+INSERT INTO public."course" ("id", "name", "major_id", "description", "email", "abbreviation")
+VALUES 
+  ('IF3250', 'Proyek Perangkat Lunak', (SELECT id FROM public."major" WHERE abbreviation='IF'), 'Kuliah ini memberikan gambaran kompleksitas dan pengalaman mengenai pengembangan perangkat lunak skala besar. Mahasiswa memanfaatkan/ menggunakan berbagai platform, framework, dan tools yang biasa dipakai untuk proyek berskala besar. Kuliah ini juga memberikan pengetahuan rekayasa perangkat lunak tingkat lanjut, mencakup Domain Specific Language (DSL), Domain-oriented Design/Analysis/Architecture, Large Scale Software development, dan Performance Engineering.', 'contributor@example.com', 'PPL'),
+  ('IF3270', 'Pembelajaran Mesin', (SELECT id FROM public."major" WHERE abbreviation='IF'), 'Kuliah ini membahas berbagai teknik pembelajaran oleh mesin serta pengenalan pola. Pendekatan yang diberikan mencakup supervised learning dan unsupervised learning.', 'contributor@example.com', 'ML');
+
+-- +migrate Down
+DELETE FROM public."course" WHERE id IN (
+  'IF3250',
+  'IF3270'
+);
+
+DELETE FROM public."major" WHERE abbreviation IN (
+  'IF'
+);
+
+DELETE FROM public."faculty" WHERE abbreviation IN (
+  'STEI'
+);
+
+UPDATE public."user" SET
+  name = 'contributor'
+  WHERE email = 'contributor@example.com';
\ No newline at end of file
diff --git a/migrations/staging/20230314101130-normal-user.sql b/migrations/staging/20230314101130-normal-user.sql
new file mode 100644
index 0000000..401d22e
--- /dev/null
+++ b/migrations/staging/20230314101130-normal-user.sql
@@ -0,0 +1,13 @@
+
+-- +migrate Up
+INSERT INTO public."user" ("email", "password", "name", "role", "is_activated")
+VALUES 
+  ('ucok@example.com', '$2a$10$J4POz3KQESxzA.d9S8rHRu3ZuJSRdcJkVQcx1SRdMNQqtD8gHfccy', 'Ucok', 'student', true),
+  ('udin@example.com', '$2a$10$J4POz3KQESxzA.d9S8rHRu3ZuJSRdcJkVQcx1SRdMNQqtD8gHfccy', 'Udin', 'student', false);
+
+-- +migrate Down
+
+DELETE FROM public."user" WHERE email IN (
+  'ucok@example.com',
+  'udin@example.com'
+);
diff --git a/migrations/staging/20230316185603-add-contraint-unique-abbr.sql b/migrations/staging/20230316185603-add-contraint-unique-abbr.sql
new file mode 100644
index 0000000..f1a4443
--- /dev/null
+++ b/migrations/staging/20230316185603-add-contraint-unique-abbr.sql
@@ -0,0 +1,14 @@
+
+-- +migrate Up
+ALTER TABLE public."course" ADD UNIQUE (abbreviation);
+
+ALTER TABLE public."major" ADD UNIQUE (abbreviation);
+
+ALTER TABLE public."faculty" ADD UNIQUE (abbreviation);
+-- +migrate Down
+
+ALTER TABLE public."course" DROP CONSTRAINT course_abbreviation_key;
+
+ALTER TABLE public."major" DROP CONSTRAINT major_abbreviation_key;
+
+ALTER TABLE public."faculty" DROP CONSTRAINT faculty_abbreviation_key;
\ No newline at end of file
diff --git a/migrations/staging/20230329064016-delete-course-contributor.sql b/migrations/staging/20230329064016-delete-course-contributor.sql
new file mode 100644
index 0000000..d3f391c
--- /dev/null
+++ b/migrations/staging/20230329064016-delete-course-contributor.sql
@@ -0,0 +1,43 @@
+
+-- +migrate Up
+ALTER TABLE material
+    DROP CONSTRAINT IF EXISTS  material_course_id_creator_email_fkey;
+ALTER TABLE quiz
+    DROP CONSTRAINT IF EXISTS quiz_course_id_creator_email_fkey;
+
+DROP TABLE IF EXISTS course_contributor;
+
+ALTER TABLE material
+    ADD FOREIGN KEY (creator_email) REFERENCES public."user"(email);
+
+ALTER TABLE quiz
+    ADD FOREIGN KEY (creator_email) REFERENCES public."user"(email);
+
+
+-- +migrate Down
+
+ALTER TABLE material
+    DROP CONSTRAINT IF EXISTS  material_creator_email_fkey;
+
+ALTER TABLE quiz
+    DROP CONSTRAINT IF EXISTS quiz_creator_email_fkey;
+
+CREATE TABLE public."course_contributor" (
+  course_id     varchar(30) NOT NULL,
+  email         varchar(100) NOT NULL,
+  PRIMARY KEY (course_id, email),
+  FOREIGN KEY (course_id)
+    REFERENCES public."course"(id)
+    ON UPDATE CASCADE ON DELETE CASCADE,
+  FOREIGN KEY (email) REFERENCES public."user"(email) ON DELETE CASCADE
+);
+
+ALTER TABLE material
+    ADD FOREIGN KEY (course_id, creator_email)
+    REFERENCES public."course_contributor"(course_id, email)
+    ON DELETE CASCADE ON UPDATE CASCADE;
+
+ALTER TABLE quiz
+    ADD   FOREIGN KEY (course_id, creator_email)
+    REFERENCES public."course_contributor"(course_id, email)
+    ON DELETE CASCADE ON UPDATE CASCADE;
diff --git a/migrations/staging/20230401130532-update-material.sql b/migrations/staging/20230401130532-update-material.sql
new file mode 100644
index 0000000..b739bd7
--- /dev/null
+++ b/migrations/staging/20230401130532-update-material.sql
@@ -0,0 +1,8 @@
+
+-- +migrate Up
+ALTER TABLE material
+  ADD COLUMN week INT;
+
+-- +migrate Down
+ALTER TABLE material
+  DROP COLUMN week;
\ No newline at end of file
diff --git a/migrations/staging/20230401130806-update-quiz.sql b/migrations/staging/20230401130806-update-quiz.sql
new file mode 100644
index 0000000..a2e0126
--- /dev/null
+++ b/migrations/staging/20230401130806-update-quiz.sql
@@ -0,0 +1,47 @@
+
+-- +migrate Up
+DROP TABLE quiz_take_choice_answer;
+DROP TABLE quiz_choice_option;
+DROP TABLE quiz_problem;
+
+ALTER TABLE quiz
+  ADD COLUMN quiz_path TEXT;
+
+-- +migrate Down
+
+ALTER TABLE quiz
+  DROP COLUMN quiz_path;
+
+CREATE TABLE public."quiz_problem" (
+  id        UUID DEFAULT uuid_generate_v4(),
+  statement TEXT NOT NULL,
+  "type"    PROBLEM_TYPE NOT NULL,
+  quiz_id   UUID NOT NULL,
+  PRIMARY KEY(id),
+  FOREIGN KEY(quiz_id)
+    REFERENCES public."quiz"(id)
+);
+
+CREATE TABLE public."quiz_choice_option" (
+  id              UUID DEFAULT uuid_generate_v4(),
+  quiz_problem_id UUID NOT NULL,
+  statement       TEXT NOT NULL,
+  is_answer       BOOLEAN DEFAULT false,
+  PRIMARY KEY(id, quiz_problem_id),
+  FOREIGN KEY (quiz_problem_id)
+    REFERENCES public."quiz_problem"(id)
+    ON DELETE CASCADE
+);
+
+
+CREATE TABLE public."quiz_take_choice_answer" (
+  quiz_take_id       UUID NOT NULL,
+  answer_choice_id   UUID NOT NULL,
+  quiz_problem_id    UUID NOT NULL,
+  PRIMARY KEY (quiz_take_id, quiz_problem_id),
+  FOREIGN KEY (quiz_take_id)
+    REFERENCES public."quiz_take"(id)
+    ON DELETE CASCADE ON UPDATE CASCADE,
+  FOREIGN KEY (answer_choice_id, quiz_problem_id)
+    REFERENCES public."quiz_choice_option"(id, quiz_problem_id)
+);
-- 
GitLab