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 CHAR(4) NOT NULL CHECK (valid_url_name(year)),
55
semester CHAR(1) NOT NULL CHECK (valid_url_name(semester)),
56
state TEXT NOT NULL CHECK (state IN ('disabled', 'past',
57
'current', 'future')) DEFAULT 'current',
58
UNIQUE (year, semester)
61
CREATE TABLE offering (
62
offeringid SERIAL PRIMARY KEY NOT NULL,
63
subject INT4 REFERENCES subject (subjectid) NOT NULL,
64
semesterid INTEGER REFERENCES semester (semesterid) NOT NULL,
67
show_worksheet_marks BOOLEAN NOT NULL DEFAULT false,
68
worksheet_cutoff TIMESTAMP,
69
groups_student_permissions VARCHAR NOT NULL DEFAULT 'none',
70
CHECK (groups_student_permissions in ('none', 'invite', 'create')),
71
UNIQUE (subject, semesterid)
74
-- Projects and groups
75
-- -------------------
77
CREATE TABLE project_set (
78
projectsetid SERIAL PRIMARY KEY NOT NULL,
79
offeringid INTEGER REFERENCES offering (offeringid) NOT NULL,
80
max_students_per_group INTEGER
83
CREATE TABLE project (
84
projectid SERIAL PRIMARY KEY NOT NULL,
85
short_name TEXT NOT NULL CHECK (valid_url_name(short_name)),
89
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
90
deadline TIMESTAMP NOT NULL
93
CREATE OR REPLACE FUNCTION check_project_namespacing_insertupdate()
98
IF TG_OP = ''UPDATE'' THEN
99
IF NEW.projectsetid = OLD.projectsetid AND NEW.short_name = OLD.short_name THEN
103
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
104
PERFORM 1 FROM project, project_set
105
WHERE project_set.offeringid = oid AND
106
project.projectsetid = project_set.projectsetid AND
107
project.short_name = NEW.short_name;
109
RAISE EXCEPTION ''a project named % already exists in offering ID %'', NEW.short_name, oid;
113
' LANGUAGE 'plpgsql';
115
CREATE TRIGGER check_project_namespacing
116
BEFORE INSERT OR UPDATE ON project
117
FOR EACH ROW EXECUTE PROCEDURE check_project_namespacing_insertupdate();
119
CREATE TABLE project_group (
120
groupnm VARCHAR NOT NULL CHECK (valid_url_name(groupnm)),
121
groupid SERIAL PRIMARY KEY NOT NULL,
122
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
124
createdby INT4 REFERENCES login (loginid) NOT NULL,
125
epoch TIMESTAMP NOT NULL,
126
UNIQUE (projectsetid, groupnm)
129
CREATE OR REPLACE FUNCTION check_group_namespacing_insertupdate()
134
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
135
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;
137
RAISE EXCEPTION ''a project group named % already exists in offering ID %'', NEW.groupnm, oid;
141
' LANGUAGE 'plpgsql';
143
CREATE TRIGGER check_group_namespacing
144
BEFORE INSERT OR UPDATE ON project_group
145
FOR EACH ROW EXECUTE PROCEDURE check_group_namespacing_insertupdate();
147
CREATE TABLE group_invitation (
148
loginid INT4 REFERENCES login (loginid) NOT NULL,
149
groupid INT4 REFERENCES project_group (groupid) NOT NULL,
150
inviter INT4 REFERENCES login (loginid) NOT NULL,
151
invited TIMESTAMP NOT NULL,
153
UNIQUE (loginid,groupid)
156
CREATE TABLE group_member (
157
loginid INT4 REFERENCES login (loginid),
158
groupid INT4 REFERENCES project_group (groupid),
159
PRIMARY KEY (loginid,groupid)
162
CREATE TABLE enrolment (
163
loginid INT4 REFERENCES login (loginid),
164
offeringid INT4 REFERENCES offering (offeringid),
165
role TEXT NOT NULL CHECK (role IN ('student', 'tutor',
166
'lecturer')) DEFAULT 'student',
168
special_result VARCHAR,
170
special_supp_result VARCHAR,
172
active BOOL NOT NULL DEFAULT true,
173
PRIMARY KEY (loginid,offeringid)
176
CREATE TABLE assessed (
177
assessedid SERIAL PRIMARY KEY NOT NULL,
178
loginid INT4 REFERENCES login (loginid),
179
groupid INT4 REFERENCES project_group (groupid),
180
projectid INT4 REFERENCES project (projectid) NOT NULL,
181
-- exactly one of loginid and groupid must be non-null
182
CHECK ((loginid IS NOT NULL AND groupid IS NULL)
183
OR (loginid IS NULL AND groupid IS NOT NULL))
186
-- We must use conditional constraints here -- NULL != NULL.
187
CREATE UNIQUE INDEX assessed_loginid_key ON assessed(loginid, projectid) WHERE loginid IS NOT NULL;
188
CREATE UNIQUE INDEX assessed_groupid_key ON assessed(groupid, projectid) WHERE groupid IS NOT NULL;
190
CREATE TABLE project_extension (
191
extensionid SERIAL PRIMARY KEY,
192
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
193
deadline TIMESTAMP NOT NULL,
194
approver INT4 REFERENCES login (loginid) NOT NULL,
198
CREATE TABLE project_submission (
199
submissionid SERIAL PRIMARY KEY,
200
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
201
path VARCHAR NOT NULL,
202
revision INT4 NOT NULL,
203
date_submitted TIMESTAMP NOT NULL,
204
submitter INT4 REFERENCES login (loginid) NOT NULL
207
CREATE TABLE project_mark (
208
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
210
marker INT4 REFERENCES login (loginid) NOT NULL,
219
CREATE TABLE exercise (
220
identifier TEXT PRIMARY KEY CHECK (valid_url_name(identifier)),
223
description_xhtml_cache TEXT,
230
CREATE TABLE worksheet (
231
worksheetid SERIAL PRIMARY KEY,
232
offeringid INT4 REFERENCES offering (offeringid) NOT NULL,
233
identifier TEXT NOT NULL CHECK (valid_url_name(identifier)),
236
data_xhtml_cache TEXT,
237
assessable BOOLEAN NOT NULL,
238
published BOOLEAN NOT NULL DEFAULT true,
239
seq_no INT4 NOT NULL,
240
format TEXT NOT NUll,
241
UNIQUE (offeringid, identifier)
244
CREATE TABLE worksheet_exercise (
245
ws_ex_id SERIAL PRIMARY KEY,
246
worksheetid INT4 REFERENCES worksheet (worksheetid) NOT NULL,
247
exerciseid TEXT REFERENCES exercise (identifier) NOT NULL,
248
seq_no INT4 NOT NULL,
249
active BOOLEAN NOT NULL DEFAULT true,
250
optional BOOLEAN NOT NULL,
251
UNIQUE (worksheetid, exerciseid)
254
CREATE TABLE exercise_attempt (
255
loginid INT4 REFERENCES login (loginid) NOT NULL,
256
ws_ex_id INT4 REFERENCES worksheet_exercise (ws_ex_id) NOT NULL,
257
date TIMESTAMP NOT NULL,
258
attempt TEXT NOT NULL,
259
complete BOOLEAN NOT NULL,
260
active BOOLEAN NOT NULL DEFAULT true,
261
PRIMARY KEY (loginid, ws_ex_id, date)
264
CREATE TABLE exercise_save (
265
loginid INT4 REFERENCES login (loginid) NOT NULL,
266
ws_ex_id INT4 REFERENCES worksheet_exercise (ws_ex_id) NOT NULL,
267
date TIMESTAMP NOT NULL,
269
PRIMARY KEY (loginid, ws_ex_id)
272
CREATE TABLE test_suite (
273
suiteid SERIAL PRIMARY KEY,
274
exerciseid TEXT REFERENCES exercise (identifier) NOT NULL,
281
CREATE TABLE test_case (
282
testid SERIAL PRIMARY KEY,
283
suiteid INT4 REFERENCES test_suite (suiteid) NOT NULL,
290
CREATE TABLE suite_variable (
291
varid SERIAL PRIMARY KEY,
292
suiteid INT4 REFERENCES test_suite (suiteid) NOT NULL,
295
var_type TEXT NOT NULL,
299
CREATE TABLE test_case_part (
300
partid SERIAL PRIMARY KEY,
301
testid INT4 REFERENCES test_case (testid) NOT NULL,
302
part_type TEXT NOT NULL,