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)
3
-- Check that the provided name is sane for use in URLs.
4
CREATE OR REPLACE FUNCTION valid_url_name(name text) RETURNS boolean AS
7
RETURN name ~ E'^[a-z0-9][a-z0-9_\+\.\-]*$';
11
-- Just like valid_url_name, except that @ is permitted (so we can use a
12
-- reasonable subset of email addresses as usernames).
13
CREATE OR REPLACE FUNCTION valid_login_name(name text) RETURNS boolean AS
16
RETURN name ~ E'^[a-z0-9][a-z0-9@_\+\.\-]*$';
18
$$ LANGUAGE 'plpgsql';
20
CREATE SEQUENCE login_unixid_seq MINVALUE 1000 MAXVALUE 29999 START WITH 5000;
23
loginid SERIAL PRIMARY KEY NOT NULL,
24
login VARCHAR UNIQUE NOT NULL CHECK (valid_login_name(login)),
26
state VARCHAR NOT NULL CHECK (state in ('no_agreement', 'pending',
27
'enabled', 'disabled'))
28
DEFAULT 'no_agreement',
29
admin BOOLEAN NOT NULL DEFAULT false,
30
unixid INT UNIQUE DEFAULT nextval('login_unixid_seq') NOT NULL,
31
nick VARCHAR NOT NULL,
37
fullname VARCHAR NOT NULL,
38
studentid VARCHAR, -- may be null
45
CREATE TABLE subject (
46
subjectid SERIAL PRIMARY KEY NOT NULL,
47
subj_code VARCHAR UNIQUE NOT NULL,
48
subj_name VARCHAR NOT NULL,
49
subj_short_name VARCHAR UNIQUE NOT NULL CHECK (valid_url_name(subj_short_name))
52
CREATE TABLE semester (
53
semesterid SERIAL PRIMARY KEY NOT NULL,
54
year TEXT NOT NULL CHECK (valid_url_name(year)),
55
url_name TEXT NOT NULL CHECK (valid_url_name(url_name)),
57
display_name TEXT NOT NULL,
58
state TEXT NOT NULL CHECK (state IN ('disabled', 'past',
59
'current', 'future')) DEFAULT 'current',
60
UNIQUE (year, url_name),
64
CREATE TABLE offering (
65
offeringid SERIAL PRIMARY KEY NOT NULL,
66
subject INT4 REFERENCES subject (subjectid) NOT NULL,
67
semesterid INTEGER REFERENCES semester (semesterid) NOT NULL,
70
show_worksheet_marks BOOLEAN NOT NULL DEFAULT false,
71
worksheet_cutoff TIMESTAMP,
72
groups_student_permissions VARCHAR NOT NULL DEFAULT 'none',
73
CHECK (groups_student_permissions in ('none', 'invite', 'create')),
74
UNIQUE (subject, semesterid)
77
-- Projects and groups
78
-- -------------------
80
CREATE TABLE project_set (
81
projectsetid SERIAL PRIMARY KEY NOT NULL,
82
offeringid INTEGER REFERENCES offering (offeringid) NOT NULL,
83
max_students_per_group INTEGER
86
CREATE TABLE project (
87
projectid SERIAL PRIMARY KEY NOT NULL,
88
short_name TEXT NOT NULL CHECK (valid_url_name(short_name)),
92
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
93
deadline TIMESTAMP NOT NULL
96
CREATE OR REPLACE FUNCTION check_project_namespacing_insertupdate()
101
IF TG_OP = ''UPDATE'' THEN
102
IF NEW.projectsetid = OLD.projectsetid AND NEW.short_name = OLD.short_name THEN
106
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
107
PERFORM 1 FROM project, project_set
108
WHERE project_set.offeringid = oid AND
109
project.projectsetid = project_set.projectsetid AND
110
project.short_name = NEW.short_name;
112
RAISE EXCEPTION ''a project named % already exists in offering ID %'', NEW.short_name, oid;
116
' LANGUAGE 'plpgsql';
118
CREATE TRIGGER check_project_namespacing
119
BEFORE INSERT OR UPDATE ON project
120
FOR EACH ROW EXECUTE PROCEDURE check_project_namespacing_insertupdate();
122
CREATE TABLE project_group (
123
groupnm VARCHAR NOT NULL CHECK (valid_url_name(groupnm)),
124
groupid SERIAL PRIMARY KEY NOT NULL,
125
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
127
createdby INT4 REFERENCES login (loginid) NOT NULL,
128
epoch TIMESTAMP NOT NULL,
129
UNIQUE (projectsetid, groupnm)
132
CREATE OR REPLACE FUNCTION check_group_namespacing_insertupdate()
137
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
138
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;
140
RAISE EXCEPTION ''a project group named % already exists in offering ID %'', NEW.groupnm, oid;
144
' LANGUAGE 'plpgsql';
146
CREATE TRIGGER check_group_namespacing
147
BEFORE INSERT OR UPDATE ON project_group
148
FOR EACH ROW EXECUTE PROCEDURE check_group_namespacing_insertupdate();
150
CREATE TABLE group_invitation (
151
loginid INT4 REFERENCES login (loginid) NOT NULL,
152
groupid INT4 REFERENCES project_group (groupid) NOT NULL,
153
inviter INT4 REFERENCES login (loginid) NOT NULL,
154
invited TIMESTAMP NOT NULL,
156
UNIQUE (loginid,groupid)
159
CREATE TABLE group_member (
160
loginid INT4 REFERENCES login (loginid),
161
groupid INT4 REFERENCES project_group (groupid),
162
PRIMARY KEY (loginid,groupid)
25
165
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');
166
loginid INT4 REFERENCES login (loginid),
167
offeringid INT4 REFERENCES offering (offeringid),
168
role TEXT NOT NULL CHECK (role IN ('student', 'tutor',
169
'lecturer')) DEFAULT 'student',
171
special_result VARCHAR,
173
special_supp_result VARCHAR,
175
active BOOL NOT NULL DEFAULT true,
176
PRIMARY KEY (loginid,offeringid)
179
CREATE TABLE assessed (
180
assessedid SERIAL PRIMARY KEY NOT NULL,
181
loginid INT4 REFERENCES login (loginid),
182
groupid INT4 REFERENCES project_group (groupid),
183
projectid INT4 REFERENCES project (projectid) NOT NULL,
184
-- exactly one of loginid and groupid must be non-null
185
CHECK ((loginid IS NOT NULL AND groupid IS NULL)
186
OR (loginid IS NULL AND groupid IS NOT NULL))
189
-- We must use conditional constraints here -- NULL != NULL.
190
CREATE UNIQUE INDEX assessed_loginid_key ON assessed(loginid, projectid) WHERE loginid IS NOT NULL;
191
CREATE UNIQUE INDEX assessed_groupid_key ON assessed(groupid, projectid) WHERE groupid IS NOT NULL;
193
CREATE TABLE project_extension (
194
extensionid SERIAL PRIMARY KEY,
195
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
197
approver INT4 REFERENCES login (loginid) NOT NULL,
201
CREATE TABLE project_submission (
202
submissionid SERIAL PRIMARY KEY,
203
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
204
path VARCHAR NOT NULL,
205
revision INT4 NOT NULL,
206
date_submitted TIMESTAMP NOT NULL,
207
submitter INT4 REFERENCES login (loginid) NOT NULL
210
CREATE TABLE project_mark (
211
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
213
marker INT4 REFERENCES login (loginid) NOT NULL,
222
CREATE TABLE exercise (
223
identifier TEXT PRIMARY KEY CHECK (valid_url_name(identifier)),
226
description_xhtml_cache TEXT,
233
CREATE TABLE worksheet (
234
worksheetid SERIAL PRIMARY KEY,
235
offeringid INT4 REFERENCES offering (offeringid) NOT NULL,
236
identifier TEXT NOT NULL CHECK (valid_url_name(identifier)),
239
data_xhtml_cache TEXT,
240
assessable BOOLEAN NOT NULL,
241
published BOOLEAN NOT NULL DEFAULT true,
242
seq_no INT4 NOT NULL,
243
format TEXT NOT NUll,
244
UNIQUE (offeringid, identifier)
247
CREATE TABLE worksheet_exercise (
248
ws_ex_id SERIAL PRIMARY KEY,
249
worksheetid INT4 REFERENCES worksheet (worksheetid) NOT NULL,
250
exerciseid TEXT REFERENCES exercise (identifier) NOT NULL,
251
seq_no INT4 NOT NULL,
252
active BOOLEAN NOT NULL DEFAULT true,
253
optional BOOLEAN NOT NULL,
254
UNIQUE (worksheetid, exerciseid)
257
CREATE TABLE exercise_attempt (
258
loginid INT4 REFERENCES login (loginid) NOT NULL,
259
ws_ex_id INT4 REFERENCES worksheet_exercise (ws_ex_id) NOT NULL,
260
date TIMESTAMP NOT NULL,
261
attempt TEXT NOT NULL,
262
complete BOOLEAN NOT NULL,
263
active BOOLEAN NOT NULL DEFAULT true,
264
PRIMARY KEY (loginid, ws_ex_id, date)
267
CREATE TABLE exercise_save (
268
loginid INT4 REFERENCES login (loginid) NOT NULL,
269
ws_ex_id INT4 REFERENCES worksheet_exercise (ws_ex_id) NOT NULL,
270
date TIMESTAMP NOT NULL,
272
PRIMARY KEY (loginid, ws_ex_id)
275
CREATE TABLE test_suite (
276
suiteid SERIAL PRIMARY KEY,
277
exerciseid TEXT REFERENCES exercise (identifier) NOT NULL,
284
CREATE TABLE test_case (
285
testid SERIAL PRIMARY KEY,
286
suiteid INT4 REFERENCES test_suite (suiteid) NOT NULL,
293
CREATE TABLE suite_variable (
294
varid SERIAL PRIMARY KEY,
295
suiteid INT4 REFERENCES test_suite (suiteid) NOT NULL,
298
var_type TEXT NOT NULL,
302
CREATE TABLE test_case_part (
303
partid SERIAL PRIMARY KEY,
304
testid INT4 REFERENCES test_case (testid) NOT NULL,
305
part_type TEXT NOT NULL,