4
DROP TABLE group_members;
9
login varchar(80) PRIMARY KEY, -- login id
14
groupid varchar(18) PRIMARY KEY, -- group name Y^4-S^9-G^3
15
nick varchar(80), -- group nickname
16
subject varchar(9), -- subject code
17
year varchar(4) -- when
20
CREATE TABLE group_members (
21
login varchar(80) REFERENCES users (login),
22
groupid varchar(18) REFERENCES groups (groupid)
2
CREATE SEQUENCE login_unixid_seq MINVALUE 1000 MAXVALUE 29999 START WITH 5000;
5
loginid SERIAL PRIMARY KEY NOT NULL,
6
login VARCHAR UNIQUE NOT NULL,
8
state VARCHAR NOT NULL CHECK (state in ('no_agreement', 'pending',
9
'enabled', 'disabled'))
10
DEFAULT 'no_agreement',
11
rolenm VARCHAR NOT NULL CHECK (rolenm in ('anyone', 'student',
13
'lecturer', 'admin')),
14
unixid INT UNIQUE DEFAULT nextval('login_unixid_seq') NOT NULL,
15
nick VARCHAR NOT NULL,
21
fullname VARCHAR NOT NULL,
22
studentid VARCHAR, -- may be null
29
CREATE TABLE subject (
30
subjectid SERIAL PRIMARY KEY NOT NULL,
31
subj_code VARCHAR UNIQUE NOT NULL,
32
subj_name VARCHAR NOT NULL,
33
subj_short_name VARCHAR UNIQUE NOT NULL,
37
CREATE TABLE semester (
38
semesterid SERIAL PRIMARY KEY NOT NULL,
39
year CHAR(4) NOT NULL,
40
semester CHAR(1) NOT NULL,
42
UNIQUE (year, semester)
45
CREATE OR REPLACE FUNCTION deactivate_semester_enrolments_update()
48
IF OLD.active = true AND NEW.active = false THEN
49
UPDATE enrolment SET active=false WHERE offeringid IN (
50
SELECT offeringid FROM offering WHERE offering.semesterid = NEW.semesterid);
56
CREATE TRIGGER deactivate_semester_enrolments
57
AFTER UPDATE ON semester
58
FOR EACH ROW EXECUTE PROCEDURE deactivate_semester_enrolments_update();
60
CREATE TABLE offering (
61
offeringid SERIAL PRIMARY KEY NOT NULL,
62
subject INT4 REFERENCES subject (subjectid) NOT NULL,
63
semesterid INTEGER REFERENCES semester (semesterid) NOT NULL,
64
groups_student_permissions VARCHAR NOT NULL DEFAULT 'none',
65
CHECK (groups_student_permissions in ('none', 'invite', 'create')),
66
UNIQUE (subject, semesterid)
69
-- Projects and groups
70
-- -------------------
72
CREATE TABLE project_set (
73
projectsetid SERIAL PRIMARY KEY NOT NULL,
74
offeringid INTEGER REFERENCES offering (offeringid) NOT NULL,
75
max_students_per_group INTEGER NOT NULL DEFAULT 4
78
CREATE TABLE project (
79
projectid SERIAL PRIMARY KEY NOT NULL,
82
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
86
CREATE TABLE project_group (
87
groupnm VARCHAR NOT NULL,
88
groupid SERIAL PRIMARY KEY NOT NULL,
89
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
91
createdby INT4 REFERENCES login (loginid) NOT NULL,
92
epoch TIMESTAMP NOT NULL,
93
UNIQUE (projectsetid, groupnm)
96
CREATE OR REPLACE FUNCTION check_group_namespacing_insertupdate()
101
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
102
PERFORM 1 FROM project_group, project_set WHERE project_set.offeringid = oid AND project_group.projectsetid = project_set.projectsetid AND project_group.groupnm = NEW.groupnm;
104
RAISE EXCEPTION ''a project group named % already exists in offering ID %'', NEW.groupnm, oid;
108
' LANGUAGE 'plpgsql';
110
CREATE TRIGGER check_group_namespacing
111
BEFORE INSERT OR UPDATE ON project_group
112
FOR EACH ROW EXECUTE PROCEDURE check_group_namespacing_insertupdate();
114
CREATE TABLE group_invitation (
115
loginid INT4 REFERENCES login (loginid) NOT NULL,
116
groupid INT4 REFERENCES project_group (groupid) NOT NULL,
117
inviter INT4 REFERENCES login (loginid) NOT NULL,
118
invited TIMESTAMP NOT NULL,
120
UNIQUE (loginid,groupid)
123
CREATE TABLE group_member (
124
loginid INT4 REFERENCES login (loginid),
125
groupid INT4 REFERENCES project_group (groupid),
126
PRIMARY KEY (loginid,groupid)
25
129
CREATE TABLE enrolment (
26
login varchar(80) REFERENCES users (login),
32
login varchar(80) REFERENCES users (login),
36
INSERT INTO users (login,nick) values ('conway', 'Tom');
37
INSERT INTO roles (login,role) values ('conway', 'student');
38
INSERT INTO users (login,nick) values ('apeel', 'Andrew');
39
INSERT INTO roles (login,role) values ('apeel', 'student');
40
INSERT INTO users (login,nick) values ('mgiuca', 'Matt');
41
INSERT INTO roles (login,role) values ('mgiuca', 'tutor');
42
INSERT INTO users (login,nick) values ('sb', 'Steven');
43
INSERT INTO roles (login,role) values ('sb', 'lecturer');
44
INSERT INTO users (login,nick) values ('mpp', 'Mike');
45
INSERT INTO roles (login,role) values ('mpp', 'student');
46
INSERT INTO users (login,nick) values ('ivo', 'Ivo');
47
INSERT INTO roles (login,role) values ('ivo', 'admin');
49
INSERT INTO groups (groupid, nick, subject, year) values ('2007-INFO10001-321', 'Purple Alert', 'INFO10001', '2008');
50
INSERT INTO groups (groupid, nick, subject, year) values ('2007-INFO10001-322', 'Blind Illuminati', 'INFO10001', '2008');
52
INSERT INTO group_members (login,groupid) values ('conway', '2007-INFO10001-321');
53
INSERT INTO group_members (login,groupid) values ('apeel', '2007-INFO10001-321');
54
INSERT INTO group_members (login,groupid) values ('mgiuca', '2007-INFO10001-321');
55
INSERT INTO group_members (login,groupid) values ('sb', '2007-INFO10001-321');
56
INSERT INTO group_members (login,groupid) values ('mpp', '2007-INFO10001-322');
57
INSERT INTO group_members (login,groupid) values ('ivo', '2007-INFO10001-322');
59
INSERT INTO enrolment (login,subject,year) values ('conway' , 'INFO10001', '2008');
60
INSERT INTO enrolment (login,subject,year) values ('apeel' , 'INFO10001', '2008');
61
INSERT INTO enrolment (login,subject,year) values ('mgiuca' , 'INFO10001', '2008');
62
INSERT INTO enrolment (login,subject,year) values ('sb' , 'INFO10001', '2008');
63
INSERT INTO enrolment (login,subject,year) values ('mpp' , 'INFO10001', '2008');
64
INSERT INTO enrolment (login,subject,year) values ('ivo' , 'INFO10001', '2008');
130
loginid INT4 REFERENCES login (loginid),
131
offeringid INT4 REFERENCES offering (offeringid),
133
special_result VARCHAR,
135
special_supp_result VARCHAR,
137
active BOOL NOT NULL DEFAULT true,
138
PRIMARY KEY (loginid,offeringid)
141
CREATE OR REPLACE FUNCTION confirm_active_semester_insertupdate()
146
SELECT semester.active INTO active FROM offering, semester WHERE offeringid=NEW.offeringid AND semester.semesterid = offering.semesterid;
147
IF NOT active AND NEW.active = true THEN
148
RAISE EXCEPTION ''cannot have active enrolment for % in offering %, as the semester is inactive'', NEW.loginid, NEW.offeringid;
152
' LANGUAGE 'plpgsql';
154
CREATE TRIGGER confirm_active_semester
155
BEFORE INSERT OR UPDATE ON enrolment
156
FOR EACH ROW EXECUTE PROCEDURE confirm_active_semester_insertupdate();
158
CREATE TABLE assessed (
159
assessedid SERIAL PRIMARY KEY NOT NULL,
160
loginid INT4 REFERENCES login (loginid),
161
groupid INT4 REFERENCES project_group (groupid),
162
projectid INT4 REFERENCES project (projectid) NOT NULL,
163
-- exactly one of loginid and groupid must be non-null
164
CHECK ((loginid IS NOT NULL AND groupid IS NULL)
165
OR (loginid IS NULL AND groupid IS NOT NULL))
168
CREATE TABLE project_extension (
169
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
170
deadline TIMESTAMP NOT NULL,
171
approver INT4 REFERENCES login (loginid) NOT NULL,
175
CREATE TABLE project_submission (
176
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
177
path VARCHAR NOT NULL,
178
revision INT4 NOT NULL
181
CREATE TABLE project_mark (
182
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
184
marker INT4 REFERENCES login (loginid) NOT NULL,
193
CREATE TABLE problem (
194
identifier TEXT PRIMARY KEY,
203
CREATE TABLE worksheet (
204
worksheetid SERIAL PRIMARY KEY,
205
offeringid INT4 REFERENCES offering (offeringid) NOT NULL,
206
identifier VARCHAR NOT NULL,
209
UNIQUE (offeringid, identifier)
212
CREATE TABLE worksheet_problem (
213
worksheetid INT4 REFERENCES worksheet (worksheetid) NOT NULL,
214
problemid TEXT REFERENCES problem (identifier) NOT NULL,
216
PRIMARY KEY (worksheetid, problemid)
219
CREATE TABLE problem_attempt (
220
problemid TEXT REFERENCES problem (identifier) NOT NULL,
221
loginid INT4 REFERENCES login (loginid) NOT NULL,
222
worksheetid INT4 REFERENCES worksheet (worksheetid) NOT NULL,
223
date TIMESTAMP NOT NULL,
224
attempt VARCHAR NOT NULL,
225
complete BOOLEAN NOT NULL,
226
active BOOLEAN NOT NULL DEFAULT true,
227
PRIMARY KEY (problemid,loginid,worksheetid,date)
230
CREATE TABLE problem_save (
231
problemid TEXT REFERENCES problem (identifier) NOT NULL,
232
loginid INT4 REFERENCES login (loginid) NOT NULL,
233
worksheetid INT4 REFERENCES worksheet (worksheetid) NOT NULL,
234
date TIMESTAMP NOT NULL,
236
PRIMARY KEY (problemid,loginid, worksheetid)
239
CREATE TABLE test_suite (
240
suiteid SERIAL PRIMARY KEY,
241
problemid TEXT REFERENCES problem (identifier) NOT NULL,
248
CREATE TABLE test_case (
249
testid SERIAL PRIMARY KEY,
250
suiteid INT4 REFERENCES test_suite (suiteid) NOT NULL,
257
CREATE TABLE suite_variables (
258
varid SERIAL PRIMARY KEY,
259
suiteid INT4 REFERENCES test_suite (suiteid) NOT NULL,
262
var_type TEXT NOT NULL,
266
CREATE TABLE test_case_parts (
267
partid SERIAL PRIMARY KEY,
268
testid INT4 REFERENCES test_case (testid) NOT NULL,
269
part_type TEXT NOT NULL,