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
admin BOOLEAN NOT NULL DEFAULT false,
12
unixid INT UNIQUE DEFAULT nextval('login_unixid_seq') NOT NULL,
13
nick VARCHAR NOT NULL,
19
fullname VARCHAR NOT NULL,
20
studentid VARCHAR, -- may be null
25
CREATE TABLE subject (
26
subjectid SERIAL PRIMARY KEY NOT NULL,
27
subj_code VARCHAR UNIQUE NOT NULL,
28
subj_name VARCHAR NOT NULL,
29
subj_short_name VARCHAR UNIQUE NOT NULL
32
CREATE TABLE semester (
33
semesterid SERIAL PRIMARY KEY NOT NULL,
34
year CHAR(4) NOT NULL,
35
semester CHAR(1) NOT NULL,
36
state TEXT NOT NULL CHECK (state IN ('disabled', 'past',
37
'current', 'future')) DEFAULT 'current',
38
UNIQUE (year, semester)
41
CREATE TABLE offering (
42
offeringid SERIAL PRIMARY KEY NOT NULL,
43
subject INT4 REFERENCES subject (subjectid) NOT NULL,
44
semesterid INTEGER REFERENCES semester (semesterid) NOT NULL,
47
groups_student_permissions VARCHAR NOT NULL DEFAULT 'none',
48
CHECK (groups_student_permissions in ('none', 'invite', 'create')),
49
UNIQUE (subject, semesterid)
53
CREATE TABLE project_set (
54
projectsetid SERIAL PRIMARY KEY NOT NULL,
55
offeringid INTEGER REFERENCES offering (offeringid) NOT NULL,
56
max_students_per_group INTEGER
59
CREATE TABLE project (
60
projectid SERIAL PRIMARY KEY NOT NULL,
61
short_name TEXT NOT NULL,
65
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
66
deadline TIMESTAMP NOT NULL
69
CREATE OR REPLACE FUNCTION check_project_namespacing_insertupdate()
74
IF TG_OP = ''UPDATE'' THEN
75
IF NEW.projectsetid = OLD.projectsetid AND NEW.short_name = OLD.short_name THEN
79
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
80
PERFORM 1 FROM project, project_set
81
WHERE project_set.offeringid = oid AND
82
project.projectsetid = project_set.projectsetid AND
83
project.short_name = NEW.short_name;
85
RAISE EXCEPTION ''a project named % already exists in offering ID %'', NEW.short_name, oid;
91
CREATE TRIGGER check_project_namespacing
92
BEFORE INSERT OR UPDATE ON project
93
FOR EACH ROW EXECUTE PROCEDURE check_project_namespacing_insertupdate();
95
CREATE TABLE project_group (
96
groupnm VARCHAR NOT NULL,
97
groupid SERIAL PRIMARY KEY NOT NULL,
98
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
100
createdby INT4 REFERENCES login (loginid) NOT NULL,
101
epoch TIMESTAMP NOT NULL,
102
UNIQUE (projectsetid, groupnm)
105
CREATE OR REPLACE FUNCTION check_group_namespacing_insertupdate()
110
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
111
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;
113
RAISE EXCEPTION ''a project group named % already exists in offering ID %'', NEW.groupnm, oid;
117
' LANGUAGE 'plpgsql';
119
CREATE TRIGGER check_group_namespacing
120
BEFORE INSERT OR UPDATE ON project_group
121
FOR EACH ROW EXECUTE PROCEDURE check_group_namespacing_insertupdate();
123
CREATE TABLE group_invitation (
124
loginid INT4 REFERENCES login (loginid) NOT NULL,
125
groupid INT4 REFERENCES project_group (groupid) NOT NULL,
126
inviter INT4 REFERENCES login (loginid) NOT NULL,
127
invited TIMESTAMP NOT NULL,
129
UNIQUE (loginid,groupid)
132
CREATE TABLE group_member (
133
loginid INT4 REFERENCES login (loginid),
134
groupid INT4 REFERENCES project_group (groupid),
135
PRIMARY KEY (loginid,groupid)
1
-- We need a users database to do authorization, manage groups, &c
6
DROP TABLE group_members;
11
login varchar(80) PRIMARY KEY, -- login id
16
groupid varchar(18) PRIMARY KEY, -- group name Y^4-S^9-G^3
17
nick varchar(80), -- group nickname
18
subject varchar(9), -- subject code
19
year varchar(4) -- when
22
CREATE TABLE group_members (
23
login varchar(80) REFERENCES users (login),
24
groupid varchar(18) REFERENCES groups (groupid)
138
27
CREATE TABLE enrolment (
139
loginid INT4 REFERENCES login (loginid),
140
offeringid INT4 REFERENCES offering (offeringid),
141
role TEXT NOT NULL CHECK (role IN ('student', 'tutor',
142
'lecturer')) DEFAULT 'student',
144
special_result VARCHAR,
146
special_supp_result VARCHAR,
148
active BOOL NOT NULL DEFAULT true,
149
PRIMARY KEY (loginid,offeringid)
152
CREATE TABLE assessed (
153
assessedid SERIAL PRIMARY KEY NOT NULL,
154
loginid INT4 REFERENCES login (loginid),
155
groupid INT4 REFERENCES project_group (groupid),
156
projectid INT4 REFERENCES project (projectid) NOT NULL,
157
-- exactly one of loginid and groupid must be non-null
158
CHECK ((loginid IS NOT NULL AND groupid IS NULL)
159
OR (loginid IS NULL AND groupid IS NOT NULL))
162
CREATE TABLE project_extension (
163
extensionid SERIAL PRIMARY KEY,
164
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
165
deadline TIMESTAMP NOT NULL,
166
approver INT4 REFERENCES login (loginid) NOT NULL,
170
CREATE TABLE project_submission (
171
submissionid SERIAL PRIMARY KEY,
172
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
173
path VARCHAR NOT NULL,
174
revision INT4 NOT NULL,
175
date_submitted TIMESTAMP NOT NULL,
176
submitter INT4 REFERENCES login (loginid) NOT NULL
179
CREATE TABLE project_mark (
180
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
182
marker INT4 REFERENCES login (loginid) NOT NULL,
189
CREATE TABLE exercise (
190
identifier TEXT PRIMARY KEY,
199
CREATE TABLE worksheet (
200
worksheetid SERIAL PRIMARY KEY,
201
offeringid INT4 REFERENCES offering (offeringid) NOT NULL,
202
identifier TEXT NOT NULL,
205
assessable BOOLEAN NOT NULL,
206
seq_no INT4 NOT NULL,
207
format TEXT NOT NUll,
208
UNIQUE (offeringid, identifier)
211
CREATE TABLE worksheet_exercise (
212
ws_ex_id SERIAL PRIMARY KEY,
213
worksheetid INT4 REFERENCES worksheet (worksheetid) NOT NULL,
214
exerciseid TEXT REFERENCES exercise (identifier) NOT NULL,
215
seq_no INT4 NOT NULL,
216
active BOOLEAN NOT NULL DEFAULT true,
217
optional BOOLEAN NOT NULL,
218
UNIQUE (worksheetid, exerciseid)
221
CREATE TABLE exercise_attempt (
222
loginid INT4 REFERENCES login (loginid) NOT NULL,
223
ws_ex_id INT4 REFERENCES worksheet_exercise (ws_ex_id) NOT NULL,
224
date TIMESTAMP NOT NULL,
225
attempt TEXT NOT NULL,
226
complete BOOLEAN NOT NULL,
227
active BOOLEAN NOT NULL DEFAULT true,
228
PRIMARY KEY (loginid, ws_ex_id, date)
231
CREATE TABLE exercise_save (
232
loginid INT4 REFERENCES login (loginid) NOT NULL,
233
ws_ex_id INT4 REFERENCES worksheet_exercise (ws_ex_id) NOT NULL,
234
date TIMESTAMP NOT NULL,
236
PRIMARY KEY (loginid, ws_ex_id)
239
CREATE TABLE test_suite (
240
suiteid SERIAL PRIMARY KEY,
241
exerciseid TEXT REFERENCES exercise (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_variable (
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_part (
267
partid SERIAL PRIMARY KEY,
268
testid INT4 REFERENCES test_case (testid) NOT NULL,
269
part_type TEXT NOT NULL,
28
login varchar(80) REFERENCES users (login),
34
login varchar(80) REFERENCES users (login),
38
INSERT INTO users (login,nick) values ('conway', 'Tom');
39
INSERT INTO roles (login,role) values ('conway', 'student');
40
INSERT INTO users (login,nick) values ('apeel', 'Andrew');
41
INSERT INTO roles (login,role) values ('apeel', 'student');
42
INSERT INTO users (login,nick) values ('mgiuca', 'Matt');
43
INSERT INTO roles (login,role) values ('mgiuca', 'tutor');
44
INSERT INTO users (login,nick) values ('sb', 'Steven');
45
INSERT INTO roles (login,role) values ('sb', 'lecturer');
46
INSERT INTO users (login,nick) values ('mpp', 'Mike');
47
INSERT INTO roles (login,role) values ('mpp', 'student');
48
INSERT INTO users (login,nick) values ('ivo', 'Ivo');
49
INSERT INTO roles (login,role) values ('ivo', 'admin');
51
INSERT INTO groups (groupid, nick, subject, year) values ('2007-INFO10001-321', 'Purple Alert', 'INFO10001', '2008');
52
INSERT INTO groups (groupid, nick, subject, year) values ('2007-INFO10001-322', 'Blind Illuminati', 'INFO10001', '2008');
54
INSERT INTO group_members (login,groupid) values ('conway', '2007-INFO10001-321');
55
INSERT INTO group_members (login,groupid) values ('apeel', '2007-INFO10001-321');
56
INSERT INTO group_members (login,groupid) values ('mgiuca', '2007-INFO10001-321');
57
INSERT INTO group_members (login,groupid) values ('sb', '2007-INFO10001-321');
58
INSERT INTO group_members (login,groupid) values ('mpp', '2007-INFO10001-322');
59
INSERT INTO group_members (login,groupid) values ('ivo', '2007-INFO10001-322');
61
INSERT INTO enrolment (login,subject,year) values ('conway' , 'INFO10001', '2008');
62
INSERT INTO enrolment (login,subject,year) values ('apeel' , 'INFO10001', '2008');
63
INSERT INTO enrolment (login,subject,year) values ('mgiuca' , 'INFO10001', '2008');
64
INSERT INTO enrolment (login,subject,year) values ('sb' , 'INFO10001', '2008');
65
INSERT INTO enrolment (login,subject,year) values ('mpp' , 'INFO10001', '2008');
66
INSERT INTO enrolment (login,subject,year) values ('ivo' , 'INFO10001', '2008');