3
CREATE OR REPLACE FUNCTION valid_url_name(name text) RETURNS boolean AS
6
RETURN name ~ E'^[a-z0-9][a-z0-9\+\.\-]*$';
10
CREATE OR REPLACE FUNCTION valid_login_name(name text) RETURNS boolean AS
13
RETURN name ~ E'^[a-z0-9][a-z0-9\+\.\-@_]*$';
15
$$ LANGUAGE 'plpgsql';
17
CREATE SEQUENCE login_unixid_seq MINVALUE 1000 MAXVALUE 29999 START WITH 5000;
20
loginid SERIAL PRIMARY KEY NOT NULL,
21
login VARCHAR UNIQUE NOT NULL CHECK (valid_login_name(login)),
23
state VARCHAR NOT NULL CHECK (state in ('no_agreement', 'pending',
24
'enabled', 'disabled'))
25
DEFAULT 'no_agreement',
26
admin BOOLEAN NOT NULL DEFAULT false,
27
unixid INT UNIQUE DEFAULT nextval('login_unixid_seq') NOT NULL,
28
nick VARCHAR NOT NULL,
34
fullname VARCHAR NOT NULL,
35
studentid VARCHAR, -- may be null
40
CREATE TABLE subject (
41
subjectid SERIAL PRIMARY KEY NOT NULL,
42
subj_code VARCHAR UNIQUE NOT NULL,
43
subj_name VARCHAR NOT NULL,
44
subj_short_name VARCHAR UNIQUE NOT NULL CHECK (valid_url_name(subj_short_name))
47
CREATE TABLE semester (
48
semesterid SERIAL PRIMARY KEY NOT NULL,
49
year CHAR(4) NOT NULL CHECK (valid_url_name(year)),
50
semester CHAR(1) NOT NULL CHECK (valid_url_name(semester)),
51
state TEXT NOT NULL CHECK (state IN ('disabled', 'past',
52
'current', 'future')) DEFAULT 'current',
53
UNIQUE (year, semester)
56
CREATE TABLE offering (
57
offeringid SERIAL PRIMARY KEY NOT NULL,
58
subject INT4 REFERENCES subject (subjectid) NOT NULL,
59
semesterid INTEGER REFERENCES semester (semesterid) NOT NULL,
62
groups_student_permissions VARCHAR NOT NULL DEFAULT 'none',
63
CHECK (groups_student_permissions in ('none', 'invite', 'create')),
64
UNIQUE (subject, semesterid)
68
CREATE TABLE project_set (
69
projectsetid SERIAL PRIMARY KEY NOT NULL,
70
offeringid INTEGER REFERENCES offering (offeringid) NOT NULL,
71
max_students_per_group INTEGER
74
CREATE TABLE project (
75
projectid SERIAL PRIMARY KEY NOT NULL,
76
short_name TEXT NOT NULL CHECK (valid_url_name(short_name)),
80
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
81
deadline TIMESTAMP NOT NULL
84
CREATE OR REPLACE FUNCTION check_project_namespacing_insertupdate()
89
IF TG_OP = ''UPDATE'' THEN
90
IF NEW.projectsetid = OLD.projectsetid AND NEW.short_name = OLD.short_name THEN
94
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
95
PERFORM 1 FROM project, project_set
96
WHERE project_set.offeringid = oid AND
97
project.projectsetid = project_set.projectsetid AND
98
project.short_name = NEW.short_name;
100
RAISE EXCEPTION ''a project named % already exists in offering ID %'', NEW.short_name, oid;
104
' LANGUAGE 'plpgsql';
106
CREATE TRIGGER check_project_namespacing
107
BEFORE INSERT OR UPDATE ON project
108
FOR EACH ROW EXECUTE PROCEDURE check_project_namespacing_insertupdate();
110
CREATE TABLE project_group (
111
groupnm VARCHAR NOT NULL CHECK (valid_url_name(groupnm)),
112
groupid SERIAL PRIMARY KEY NOT NULL,
113
projectsetid INTEGER REFERENCES project_set (projectsetid) NOT NULL,
115
createdby INT4 REFERENCES login (loginid) NOT NULL,
116
epoch TIMESTAMP NOT NULL,
117
UNIQUE (projectsetid, groupnm)
120
CREATE OR REPLACE FUNCTION check_group_namespacing_insertupdate()
125
SELECT offeringid INTO oid FROM project_set WHERE project_set.projectsetid = NEW.projectsetid;
126
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;
128
RAISE EXCEPTION ''a project group named % already exists in offering ID %'', NEW.groupnm, oid;
132
' LANGUAGE 'plpgsql';
134
CREATE TRIGGER check_group_namespacing
135
BEFORE INSERT OR UPDATE ON project_group
136
FOR EACH ROW EXECUTE PROCEDURE check_group_namespacing_insertupdate();
138
CREATE TABLE group_invitation (
139
loginid INT4 REFERENCES login (loginid) NOT NULL,
140
groupid INT4 REFERENCES project_group (groupid) NOT NULL,
141
inviter INT4 REFERENCES login (loginid) NOT NULL,
142
invited TIMESTAMP NOT NULL,
144
UNIQUE (loginid,groupid)
147
CREATE TABLE group_member (
148
loginid INT4 REFERENCES login (loginid),
149
groupid INT4 REFERENCES project_group (groupid),
150
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)
153
27
CREATE TABLE enrolment (
154
loginid INT4 REFERENCES login (loginid),
155
offeringid INT4 REFERENCES offering (offeringid),
156
role TEXT NOT NULL CHECK (role IN ('student', 'tutor',
157
'lecturer')) DEFAULT 'student',
159
special_result VARCHAR,
161
special_supp_result VARCHAR,
163
active BOOL NOT NULL DEFAULT true,
164
PRIMARY KEY (loginid,offeringid)
167
CREATE TABLE assessed (
168
assessedid SERIAL PRIMARY KEY NOT NULL,
169
loginid INT4 REFERENCES login (loginid),
170
groupid INT4 REFERENCES project_group (groupid),
171
projectid INT4 REFERENCES project (projectid) NOT NULL,
172
-- exactly one of loginid and groupid must be non-null
173
CHECK ((loginid IS NOT NULL AND groupid IS NULL)
174
OR (loginid IS NULL AND groupid IS NOT NULL))
177
CREATE TABLE project_extension (
178
extensionid SERIAL PRIMARY KEY,
179
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
180
deadline TIMESTAMP NOT NULL,
181
approver INT4 REFERENCES login (loginid) NOT NULL,
185
CREATE TABLE project_submission (
186
submissionid SERIAL PRIMARY KEY,
187
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
188
path VARCHAR NOT NULL,
189
revision INT4 NOT NULL,
190
date_submitted TIMESTAMP NOT NULL,
191
submitter INT4 REFERENCES login (loginid) NOT NULL
194
CREATE TABLE project_mark (
195
assessedid INT4 REFERENCES assessed (assessedid) NOT NULL,
197
marker INT4 REFERENCES login (loginid) NOT NULL,
204
CREATE TABLE exercise (
205
identifier TEXT PRIMARY KEY CHECK (valid_url_name(identifier)),
214
CREATE TABLE worksheet (
215
worksheetid SERIAL PRIMARY KEY,
216
offeringid INT4 REFERENCES offering (offeringid) NOT NULL,
217
identifier TEXT NOT NULL CHECK (valid_url_name(identifier)),
220
assessable BOOLEAN NOT NULL,
221
seq_no INT4 NOT NULL,
222
format TEXT NOT NUll,
223
UNIQUE (offeringid, identifier)
226
CREATE TABLE worksheet_exercise (
227
ws_ex_id SERIAL PRIMARY KEY,
228
worksheetid INT4 REFERENCES worksheet (worksheetid) NOT NULL,
229
exerciseid TEXT REFERENCES exercise (identifier) NOT NULL,
230
seq_no INT4 NOT NULL,
231
active BOOLEAN NOT NULL DEFAULT true,
232
optional BOOLEAN NOT NULL,
233
UNIQUE (worksheetid, exerciseid)
236
CREATE TABLE exercise_attempt (
237
loginid INT4 REFERENCES login (loginid) NOT NULL,
238
ws_ex_id INT4 REFERENCES worksheet_exercise (ws_ex_id) NOT NULL,
239
date TIMESTAMP NOT NULL,
240
attempt TEXT NOT NULL,
241
complete BOOLEAN NOT NULL,
242
active BOOLEAN NOT NULL DEFAULT true,
243
PRIMARY KEY (loginid, ws_ex_id, date)
246
CREATE TABLE exercise_save (
247
loginid INT4 REFERENCES login (loginid) NOT NULL,
248
ws_ex_id INT4 REFERENCES worksheet_exercise (ws_ex_id) NOT NULL,
249
date TIMESTAMP NOT NULL,
251
PRIMARY KEY (loginid, ws_ex_id)
254
CREATE TABLE test_suite (
255
suiteid SERIAL PRIMARY KEY,
256
exerciseid TEXT REFERENCES exercise (identifier) NOT NULL,
263
CREATE TABLE test_case (
264
testid SERIAL PRIMARY KEY,
265
suiteid INT4 REFERENCES test_suite (suiteid) NOT NULL,
272
CREATE TABLE suite_variable (
273
varid SERIAL PRIMARY KEY,
274
suiteid INT4 REFERENCES test_suite (suiteid) NOT NULL,
277
var_type TEXT NOT NULL,
281
CREATE TABLE test_case_part (
282
partid SERIAL PRIMARY KEY,
283
testid INT4 REFERENCES test_case (testid) NOT NULL,
284
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');