GitBucket
4.21.2
Toggle navigation
Snippets
Sign in
Files
Branches
1
Releases
Issues
2
Pull requests
Labels
Priorities
Milestones
Wiki
Forks
mark.george
/
marking
Browse code
Having no 'special' criterion caused issues. Fixed.
master
1 parent
59b522c
commit
3ed7c2a640e7e9770af5087d1f205ee814b2bc43
Mark
authored
on 27 Aug 2014
Patch
Showing
1 changed file
src/schema.sql
Ignore Space
Show notes
View
src/schema.sql
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 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; 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 VIEW feedback AS SELECT student, category.category, comment FROM criterion INNER JOIN result ON result.criterion = criterion.criterion INNER JOIN category ON criterion.category = category.category WHERE comment <> '' ORDER BY category.sort_order, criterion.sort_order; CREATE VIEW allmarks("Student", "Weighted Mark") AS SELECT submission.student, COALESCE(Cast(Round(mark, 2) AS VARCHAR), '') FROM submission LEFT JOIN mark ON submission.student = mark.student
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))) AS WEIGHTED FROM RESULT INNER JOIN CRITERION ON RESULT.CRITERION = CRITERION.CRITERION) GROUP BY STUDENT; CREATE VIEW WEIGHTED_SPECIAL AS SELECT STUDENT, COALESCE(SUM(RESULT) * (SELECT BONUS_WEIGHT FROM ASSESSMENT), 0) AS SPECIAL FROM RESULT INNER JOIN CRITERION ON CRITERION.CRITERION = RESULT.CRITERION WHERE SPECIAL CREATE VIEW MARK AS SELECT WEIGHTED_MARK.STUDENT, CASEWHEN(MARK + SPECIAL <= (SELECT OUTOF FROM ASSESSMENT), MARK + SPECIAL, (SELECT OUTOF FROM ASSESSMENT)) 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 VIEW FEEDBACK AS SELECT STUDENT, CATEGORY.CATEGORY, COMMENT FROM CRITERION INNER JOIN RESULT ON RESULT.CRITERION = CRITERION.CRITERION INNER JOIN CATEGORY ON CRITERION.CATEGORY = CATEGORY.CATEGORY WHERE COMMENT <> '' ORDER BY CATEGORY.SORT_ORDER,CRITERION.SORT_ORDER; CREATE VIEW ALLMARKS("Student", "Weighted Mark") AS SELECT SUBMISSION.STUDENT, COALESCE(CAST(ROUND(MARK, 2) AS VARCHAR), '') FROM SUBMISSION LEFT JOIN MARK ON SUBMISSION.STUDENT = MARK.STUDENT
Show line notes below