CREATE TABLE assessment ( name VARCHAR PRIMARY KEY, bonus_weight DOUBLE NOT NULL, outof DOUBLE NOT NULL ); CREATE TABLE category ( category VARCHAR PRIMARY KEY, sort_order SMALLINT ); CREATE TABLE criterion ( criterion VARCHAR PRIMARY KEY, category VARCHAR NOT NULL, description VARCHAR NOT NULL, sort_order SMALLINT, weight REAL, min SMALLINT, max SMALLINT, special BOOLEAN, CONSTRAINT fk_criterion_category FOREIGN KEY(category) REFERENCES category( category) ); CREATE TABLE submission ( student VARCHAR PRIMARY KEY ); CREATE TABLE result ( student VARCHAR NOT NULL, criterion VARCHAR NOT NULL, result REAL NOT NULL, comment VARCHAR, CONSTRAINT pk_result PRIMARY KEY(student, criterion), CONSTRAINT fk_result_student FOREIGN KEY(student) REFERENCES submission( student), CONSTRAINT fk_result_criterion FOREIGN KEY(criterion) REFERENCES criterion( criterion) ); CREATE VIEW weighted_mark AS SELECT student, Sum(weighted) * (SELECT outof FROM assessment) AS MARK FROM (SELECT student, result, weight, max, ( result / max * ( weight / (SELECT Sum(weight) FROM criterion WHERE NOT special) ) ) AS WEIGHTED FROM result INNER JOIN criterion ON result.criterion = criterion.criterion WHERE NOT special) GROUP BY student; -- UNION is a hack to ensure we always get something even if there are no special criterion CREATE VIEW weighted_special AS SELECT student, Sum(special) * (SELECT bonus_weight FROM assessment) AS special FROM ( SELECT student, result AS SPECIAL FROM result INNER JOIN criterion ON criterion.criterion = result.criterion WHERE special UNION ALL SELECT DISTINCT student, 0 FROM result ) GROUP BY student; # version to use when bonus contributes only to this assessment (maximum mark can not be exceeded) CREATE VIEW mark AS SELECT weighted_mark.student, Round(Casewhen(mark + special <= (SELECT outof FROM assessment), mark + special, ( SELECT outof FROM assessment)), 5) AS MARK FROM weighted_mark INNER JOIN weighted_special ON weighted_mark.student = weighted_special.student; # version to use when bonus contributes to other assessment (maximum mark CAN be exceeded) CREATE VIEW mark AS SELECT weighted_mark.student, Round(mark + special, 2) AS MARK FROM weighted_mark INNER JOIN weighted_special ON weighted_mark.student = weighted_special.student; CREATE VIEW marking_schedule AS SELECT criterion.category, description, weight, max AS OUTOF FROM criterion INNER JOIN category ON category.category = criterion.category ORDER BY category.sort_order, criterion.sort_order; CREATE TABLE PUBLIC.STUDENTS( STUDENTID VARCHAR primary key, NAME VARCHAR, USERCODE VARCHAR, email VARCHAR, SEND_FEEDBACK BOOLEAN ) CREATE VIEW allmarks("Student", "Weighted Mark", "Marking Complete") AS SELECT submission.student, COALESCE(Cast(Round(mark, 2) AS VARCHAR), '') AS mark, COALESCE(Cast(complete AS VARCHAR), '') AS complete FROM submission LEFT JOIN mark ON submission.student = mark.student LEFT JOIN (SELECT student, Count(criterion) = (SELECT Count(criterion) FROM criterion) AS complete FROM result GROUP BY student) c ON submission.student = c.student; -- use this if you want to produce useful category totals (and you don't care about weighting for individual criterion) UPDATE criterion SET weight = Cast(max AS DOUBLE) / (SELECT Count(*) FROM criterion); -- view for showing relative weightings as percentages of total mark create view weighted_schedule as select cat.category, criterion, description, weight, special, round(weight / total_weight * 100, 2) as relative_weight, round(weight / total_weight * max, 2) as out_of from criterion crit, (select sum(weight) as total_weight from criterion where not special) inner join category cat on crit.category = cat.category order by cat.sort_order, crit.sort_order create view weighted_categories as select category,round(sum(relative_weight),1) as weight FROM WEIGHTED_SCHEDULE where not special group by category --recorded by studentid create view report as select a.name as assessment, a.outof, s.studentid, s.name, s.usercode, cat.category, cat.sort_order as cat_order, cr.description as criterion, cr.max as max, cr.sort_order as cr_order, r.result,r.comment, round(m.mark,3) as mark from assessment a join category cat inner join criterion cr on cat.category = cr.category inner join result r on r.criterion=cr.criterion inner join students s on cast(r.student as integer)=cast(s.studentid as integer) inner join mark m on cast(m.student as integer)=cast(s.studentid as integer) order by studentid, cat_order,cr_order --recorded by usercode create view report as select a.name as assessment, a.outof, s.studentid, s.name, s.usercode, cat.category, cat.sort_order as cat_order, cr.description as criterion, cr.max as max, cr.sort_order as cr_order, r.result,r.comment, round(m.mark,3) as mark from assessment a join category cat inner join criterion cr on cat.category = cr.category inner join result r on r.criterion=cr.criterion inner join students s on r.student =s.usercode inner join mark m on r.student = m.student order by studentid, cat_order,cr_order