forked from amfoss/root
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
add migration to create initial tables for member, streaks and attend…
…ance
- Loading branch information
1 parent
2be3d7e
commit 82e7f3a
Showing
4 changed files
with
90 additions
and
7 deletions.
There are no files selected for viewing
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,66 @@ | ||
-- Creates member, attendance, attendance_summary and streaks tables | ||
|
||
-- Custom type for sex | ||
CREATE TYPE sex_type AS ENUM ('M', 'F', 'Other'); | ||
|
||
CREATE TABLE Member ( | ||
member_id SERIAL PRIMARY KEY, | ||
roll_no VARCHAR(16) NOT NULL UNIQUE, | ||
name VARCHAR(255) NOT NULL, | ||
email VARCHAR(255) NOT NULL UNIQUE, | ||
sex sex_type NOT NULL, | ||
year INT NOT NULL, | ||
hostel VARCHAR(255) NOT NULL, | ||
mac_address VARCHAR(255) NOT NULL UNIQUE, | ||
discord_id VARCHAR(255) NOT NULL UNIQUE, | ||
group_id INT NOT NULL, | ||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, | ||
CHECK (year BETWEEN 1 and 4) | ||
); | ||
|
||
CREATE TABLE Attendance ( | ||
attendance_id SERIAL PRIMARY KEY, | ||
member_id INT REFERENCES Member(member_id) ON DELETE CASCADE, | ||
date DATE NOT NULL, | ||
is_present BOOLEAN NOT NULL DEFAULT FALSE, | ||
time_in TIME, | ||
time_out TIME, | ||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, | ||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, | ||
CHECK ( | ||
(is_present = TRUE AND time_in IS NOT NULL AND time_out is NOT NULL) OR | ||
(is_present = FALSE AND time_in IS NULL AND time_out IS NULL) | ||
), | ||
CHECK (is_present = FALSE OR date <= CURRENT_DATE), | ||
CHECK (time_out IS NULL OR time_out > time_in), | ||
UNIQUE (member_id, date) | ||
); | ||
|
||
CREATE OR REPLACE FUNCTION update_timestamp() | ||
RETURNS TRIGGER AS | ||
$$ | ||
BEGIN | ||
NEW.updated_at = CURRENT_TIMESTAMP; | ||
RETURN NEW; | ||
END; | ||
$$ LANGUAGE plpgsql; | ||
|
||
CREATE TRIGGER update_attendance_timestamp | ||
BEFORE UPDATE ON Attendance | ||
FOR EACH ROW | ||
EXECUTE FUNCTION update_timestamp(); | ||
|
||
CREATE TABLE AttendanceSummary ( | ||
member_id INT REFERENCES Member(member_id) ON DELETE CASCADE, | ||
year INT NOT NULL, | ||
month INT NOT NULL, | ||
days_attended INT NOT NULL DEFAULT 0, | ||
primary key (member_id, year, month) | ||
); | ||
|
||
CREATE TABLE StatusUpdateStreaks ( | ||
member_id INT REFERENCES Member(member_id) ON DELETE CASCADE, | ||
current_streak int NOT NULL DEFAULT 0, | ||
max_streak INT NOT NULL, | ||
PRIMARY KEY (member_id) | ||
); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters