diff --git a/database/local-database.udb b/database/local-database.udb deleted file mode 100644 index 2e74ee6a95df4f729ee7b6f9af7da72c2015a89b..0000000000000000000000000000000000000000 --- a/database/local-database.udb +++ /dev/null @@ -1,7 +0,0 @@ -database - name pianos - host localhost - port 5432 - user pianos - password pianos -import pianos4-te.udb diff --git a/database/migrations/4.2.2.sql b/database/migrations/4.2.2.sql deleted file mode 100644 index ab3f4959d2b3e3686f6b6a448ec115e748e0e378..0000000000000000000000000000000000000000 --- a/database/migrations/4.2.2.sql +++ /dev/null @@ -1,97 +0,0 @@ -CREATE VIEW resultvex2 AS ( - SELECT result.assignment, - result.type AS typeid, - resulttype.name AS type, - result.step AS stepid, - resultstep.name AS step, - result.updatedon, - obs_concl.value AS conclusion, - obs_mark_value.value AS mark_value, - obs_mark_degradation.value AS mark_degradation, - obs_mark_details.value AS mark_details, - obs_decision.value AS decision, - obs_decision_ex.value AS decision_ex, - obs_comparison_need_better_known.value AS comparison_need_better_known, - obs_comparison_l3details.value AS comparison_l3details, - obs_comparison_qualquant.value AS comparison_qualquant - FROM resulttype,resultstep,result - LEFT OUTER JOIN observation AS obs_concl ON obs_concl.assignment = result.assignment - AND obs_concl.restype = result.type - AND obs_concl.resstep = result.step - AND obs_concl.type = (SELECT id FROM observationtype WHERE name = 'conclusion') - LEFT OUTER JOIN observation AS obs_mark_value ON obs_mark_value.assignment = result.assignment - AND obs_mark_value.restype = result.type - AND obs_mark_value.resstep = result.step - AND obs_mark_value.type = (SELECT id FROM observationtype WHERE name = 'mark-value') - LEFT OUTER JOIN observation AS obs_mark_degradation ON obs_mark_degradation.assignment = result.assignment - AND obs_mark_degradation.restype = result.type - AND obs_mark_degradation.resstep = result.step - AND obs_mark_degradation.type = (SELECT id FROM observationtype WHERE name = 'mark-degradation') - LEFT OUTER JOIN observation AS obs_mark_details ON obs_mark_details.assignment = result.assignment - AND obs_mark_details.restype = result.type - AND obs_mark_details.resstep = result.step - AND obs_mark_details.type = (SELECT id FROM observationtype WHERE name = 'mark-details') - LEFT OUTER JOIN observation AS obs_decision ON obs_decision.assignment = result.assignment - AND obs_decision.restype = result.type - AND obs_decision.resstep = result.step - AND obs_decision.type = (SELECT id FROM observationtype WHERE name = 'comparison-decision') - LEFT OUTER JOIN observation AS obs_decision_ex ON obs_decision_ex.assignment = result.assignment - AND obs_decision_ex.restype = result.type - AND obs_decision_ex.resstep = result.step - AND obs_decision_ex.type = (SELECT id FROM observationtype WHERE name = 'comparison-decision-ex') - LEFT OUTER JOIN observation AS obs_comparison_need_better_known ON obs_comparison_need_better_known.assignment = result.assignment - AND obs_comparison_need_better_known.restype = result.type - AND obs_comparison_need_better_known.resstep = result.step - AND obs_comparison_need_better_known.type = (SELECT id FROM observationtype WHERE name = 'comparison-need-better-known') - LEFT OUTER JOIN observation AS obs_comparison_l3details ON obs_comparison_l3details.assignment = result.assignment - AND obs_comparison_l3details.restype = result.type - AND obs_comparison_l3details.resstep = result.step - AND obs_comparison_l3details.type = (SELECT id FROM observationtype WHERE name = 'comparison-l3details') - LEFT OUTER JOIN observation AS obs_comparison_qualquant ON obs_comparison_qualquant.assignment = result.assignment - AND obs_comparison_qualquant.restype = result.type - AND obs_comparison_qualquant.resstep = result.step - AND obs_comparison_qualquant.type = (SELECT id FROM observationtype WHERE name = 'comparison-qualquant') - WHERE result.type = resulttype.id - AND result.step = resultstep.id -); - -CREATE TABLE messagetype ( - id serial UNIQUE NOT NULL, - name text UNIQUE NOT NULL, - PRIMARY KEY (id) -) WITHOUT OIDs; -INSERT INTO messagetype(name) VALUES (E'home'); - -CREATE TABLE messagevisibility ( - id serial UNIQUE NOT NULL, - name text UNIQUE NOT NULL, - PRIMARY KEY (id) -) WITHOUT OIDs; -INSERT INTO messagevisibility(name) VALUES (E'hidden'); -INSERT INTO messagevisibility(name) VALUES (E'tutors'); -INSERT INTO messagevisibility(name) VALUES (E'users'); -INSERT INTO messagevisibility(name) VALUES (E'all'); - -CREATE TABLE message ( - FOREIGN KEY (id) REFERENCES object(id), - id int UNIQUE NOT NULL, - FOREIGN KEY (type) REFERENCES messagetype(id), - type int NOT NULL, - FOREIGN KEY (visibility) REFERENCES messagevisibility(id), - visibility int NOT NULL, - FOREIGN KEY (parent) REFERENCES message(id), - parent int, - title text NOT NULL, - value text NOT NULL, - PRIMARY KEY (id) -) WITHOUT OIDs; -CREATE TRIGGER message_object_Inherit_Trigger - BEFORE INSERT ON message - FOR EACH ROW - EXECUTE PROCEDURE Generic_object_Inherit_Trigger_Hook(); - -CREATE VIEW messagev AS ( - SELECT message.id,messagetype.id AS typeid,messagetype.name AS type,message.visibility AS visibilityid,messagevisibility.name AS visibility,message.title,message.value,message.parent,object.createdon,object.creator AS creatorid,person.name AS creator FROM message,messagevisibility,messagetype,object,person WHERE person.id=object.creator AND object.id=message.id AND message.visibility=messagevisibility.id AND message.type=messagetype.id -); - -INSERT INTO observationtype(name) VALUES ('mark-gp'); diff --git a/database/pianos4-core.udb b/database/pianos4-core.udb deleted file mode 100644 index 66575f0fee007882fc1186a4179b5245379c71d8..0000000000000000000000000000000000000000 --- a/database/pianos4-core.udb +++ /dev/null @@ -1,91 +0,0 @@ -# -*- coding: utf-8 -*- - -# PiAnoS (Picture Annotation System), A fingerprint examiner training tool -# Copyright (C) 2011-2012 University of Lausanne, Switzerland -# https://ips-labs.unil.ch/pianos - -# This program is free software: you can redistribute it and/or modify -# it under the terms of the GNU Affero General Public License as -# published by the Free Software Foundation, either version 3 of the -# License, or (at your option) any later version. - -# This program is distributed in the hope that it will be useful, -# but WITHOUT ANY WARRANTY; without even the implied warranty of -# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the -# GNU Affero General Public License for more details. - -# You should have received a copy of the GNU Affero General Public License -# along with this program. If not, see http://www.gnu.org/licenses/. - -# ============================================================================ -# PiAnoS 4 - Core classes -# ---------------------------------------------------------------------------- -# ============================================================================ - - -# The base class of all top-level objects in the database. Manages -# ownership, security through ACLs and timestamped creation. -entity object autoid - createdon date now nn - updatedon date now nn - creator dfk person nn idx - store plpgsql "IF NEW.creator IS NULL THEN SELECT INTO NEW.creator safe_current_setting('unil.user'); END IF;" - -# Security is managed on a per-trustee basis. Both users (person) -# and groups (pgroup) are trustees -entity trustee inherits object - isgroup boolean false nn - -entity security - object fk object nn pk idx - trustee fk trustee nn pk idx - -# "User" being a reserved word, and me hating quoting column names in SQL queries, -# users are stored in the 'person' table. -entity person inherits trustee - username text nn ne uq - name text nn ne - password text nn ne - active boolean nn true - email text - language fk nn - last_login date - suitability_approach int nn - must_change_pwd boolean nn false - @data - admin Administrator d2abaa37a7c3db1137d385e1d8c15fd2 true "" "(SELECT id FROM language WHERE short = 'en_US')" NULL 2 false - jdoe "John Doe" 268a19d89a1e2e213dc2bf767c4bf089 true "" "(SELECT id FROM language WHERE short = 'en_US')" NULL 2 false - @fts - name A - username B - email - -entity language autoid - short text uq nn - name text nn - country text nn - @data - en_US "English" "United States" -# fr_CH "Français" "Suisse" -# de_CH "Deutsch" "Schweitz" -# it_CH "Italiano" "Svizzera" - -entity pgroup inherits trustee - name text nn - store plpgsql "UPDATE trustee SET isgroup = true WHERE id = NEW.id;" after insert - tutors boolean nn false - @data - "Administrators" true - "Default users" false - @fts - name - -# m-n associative table between users and groups -entity membership - person fk person nn pk idx - pgroup fk pgroup nn pk idx - @data - "(SELECT id FROM person WHERE username = 'admin')" "(SELECT id FROM pgroup WHERE name = 'Administrators')" - "(SELECT id FROM person WHERE username = 'jdoe')" "(SELECT id FROM pgroup WHERE name = 'Default users')" - - diff --git a/database/pianos4-functions.sql b/database/pianos4-functions.sql deleted file mode 100644 index c196c7359a4f8ab1c55909421156d395f56ec7c1..0000000000000000000000000000000000000000 --- a/database/pianos4-functions.sql +++ /dev/null @@ -1,95 +0,0 @@ - -CREATE OR REPLACE FUNCTION checkACL(int,int) RETURNS boolean AS $$ - DECLARE - pObjectID ALIAS FOR $1; - pTrusteeID ALIAS FOR $2; - groupid int; - BEGIN - -- Check for explicit access of the trustee to the object - IF (SELECT count(*) FROM Security WHERE Object = pObjectID AND Trustee = pTrusteeID) > 0 THEN - RETURN true; - END IF; - - -- If the trustee is a user - IF (SELECT IsGroup FROM Trustee WHERE ID = pTrusteeID) IS false THEN - - -- Iterate over all its person groups and recursively call checkACL - FOR groupid IN (SELECT pgroup FROM membership WHERE Person = pTrusteeID) LOOP - IF (SELECT checkACL(pObjectID, groupid)) IS true THEN - RETURN true; - END IF; - END LOOP; - - -- Tutors always have access to all the data - IF (SELECT bool_or(pgroup.tutors) FROM membership,pgroup WHERE membership.Person = pTrusteeID AND membership.pgroup = pgroup.ID) IS true THEN - RETURN true; - END IF; - - END IF; - - RETURN false; - END; -$$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION checkACL(int) RETURNS boolean AS $$ - DECLARE - userid int; - res boolean; - BEGIN - SELECT INTO userid current_setting('unil.user')::integer; - SELECT INTO res checkACL($1,userid); - RETURN res; - END; -$$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION applyACL(int, int[], int[]) RETURNS void AS $$ - DECLARE - pObjectID ALIAS FOR $1; - pGroupACL ALIAS FOR $2; - pUserACL ALIAS FOR $3; - BEGIN - - IF pGroupACL IS NOT NULL THEN - - DELETE FROM Security WHERE Object = pObjectID AND Trustee IN (SELECT ID FROM pgroup); - - IF array_lower(pGroupACL,1) IS NOT NULL THEN - FOR i IN array_lower(pGroupACL,1)..array_upper(pGroupACL,1) LOOP - IF (SELECT Tutor FROM pgroup WHERE ID = pGroupACL[i]) IS false THEN - INSERT INTO Security(Object,Trustee) VALUES - (pObjectID, pGroupACL[i]); - END IF; - END LOOP; - END IF; - END IF; - - IF pUserACL IS NOT NULL THEN - - DELETE FROM Security WHERE Object = pObjectID AND Trustee IN (SELECT ID FROM Person); - - IF array_lower(pUserACL,1) IS NOT NULL THEN - FOR i IN array_lower(pUserACL,1)..array_upper(pUserACL,1) LOOP - INSERT INTO Security(Object,Trustee) VALUES - (pObjectID, pUserACL[i]); - END LOOP; - END IF; - END IF; - - END; -$$ LANGUAGE plpgsql; - - -CREATE OR REPLACE FUNCTION assertACL(pObjectID int) RETURNS void AS $$ - BEGIN - IF (NOT checkACL(pObjectID)) THEN - RAISE EXCEPTION 'Access denied (ID=%)', pObjectID; - END IF; - END; -$$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION assertACL(pObjectID int,pTrusteeID int) RETURNS void AS $$ - BEGIN - IF (NOT checkACL(pObjectID,pTrusteeID)) THEN - RAISE EXCEPTION 'Access denied (ID=%)', pObjectID; - END IF; - END; -$$ LANGUAGE plpgsql; diff --git a/database/pianos4-install.py b/database/pianos4-install.py deleted file mode 100644 index 2e9b51928275af1a973f5f367072f5fe5e35a555..0000000000000000000000000000000000000000 --- a/database/pianos4-install.py +++ /dev/null @@ -1,94 +0,0 @@ -#!/usr/bin/python -# -*- coding: utf-8 -*- - -# PiAnoS (Picture Annotation System), A fingerprint examiner training tool -# Copyright (C) 2011-2012 University of Lausanne, Switzerland -# https://ips-labs.unil.ch/pianos - -# This program is free software: you can redistribute it and/or modify -# it under the terms of the GNU Affero General Public License as -# published by the Free Software Foundation, either version 3 of the -# License, or (at your option) any later version. - -# This program is distributed in the hope that it will be useful, -# but WITHOUT ANY WARRANTY; without even the implied warranty of -# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the -# GNU Affero General Public License for more details. - -# You should have received a copy of the GNU Affero General Public License -# along with this program. If not, see http://www.gnu.org/licenses/. - - -import udb -import pg -import os -import PIL.Image -import cStringIO as StringIO -import sys - -def microdb_main(db): - print " Initializing PiAnoS 4" - print " Registering administrator" - db.query("SELECT set_config('unil.user', (SELECT person.id FROM person,membership,pgroup WHERE person.id = membership.person AND membership.pgroup = pgroup.id AND pgroup.tutors IS true ORDER BY person.id ASC LIMIT 1)::text, false);") - - if sys.platform != 'win32': - print " Setting locales to *.UTF-8" - db.query("UPDATE language SET short = short || '.UTF-8' WHERE short NOT ILIKE '%utf%';") - - is_lab_edition = db.query("SELECT count(*) FROM pg_tables WHERE tablename = 'assignment'")[0]['count'] == 0 - - if is_lab_edition: - init_le(db) - else: - init_te(db) - - - -def init_te(db): - - print " Initializing PiAnoS 4 - Teaching Edition" - - if db.query("SELECT count(*) FROM image;")[0]['count'] == 0 and db.query("SELECT count(*) FROM pgroup WHERE name = 'Default users'")[0]['count'] > 0: - - print " Creating initial PiAnoS 4 dataset" - - images = [ - ('../debug_prints/print.jpg','PRINT'), - ('../debug_prints/trace.jpg','MARK') - ] - - ids = {} - - for image in images: - - filename = os.path.join(os.path.split(__file__)[0],image[0]) - surface = PIL.Image.open(filename) - - handle = file(filename,'rb') - buffer = handle.read() - handle.close() - - res = db.query("INSERT INTO image(type,name,mimetype,resolution,width,height,data) VALUES ((SELECT ImageType.ID FROM ImageType WHERE Short = E'"+pg.escape_string(image[1])+"'),E'"+pg.escape_string(os.path.split(image[0])[1])+"','image/jpeg',"+str(surface.info['dpi'][0])+","+str(surface.size[0])+","+str(surface.size[1])+",E'"+pg.escape_bytea(buffer)+"') RETURNING id;") - imgid = int(res[0]['id']) - - print " Inserted image " + image[0] + " as ID " + str(imgid) - - ids[image[1]] = imgid - - defgroupID = db.query("SELECT id FROM pgroup WHERE name = 'Default users'")[0]['id'] - - folderID = db.query("INSERT INTO folder(name) VALUES ('Default folder') RETURNING id;")[0]['id'] - db.query("INSERT INTO security(object,trustee) VALUES ("+str(folderID)+","+str(defgroupID)+");") - print " Created default folder as ID",folderID - - exID = db.query("INSERT INTO exercise(name,description,folder,mark,print) VALUES ('Default exercise','You may write a brief description of the exercise here',"+str(folderID)+","+str(ids['MARK'])+","+str(ids['PRINT'])+") RETURNING id;")[0]['id'] - print " Created default exercise as ID",exID - -def init_le(db): - - print " Initializing PiAnoS 4 - Lab Edition" - print "" - - return 0 - - diff --git a/database/pianos4-le.udb b/database/pianos4-le.udb deleted file mode 100644 index 3006fbb35c1b4ddef98ef3f9fbe3853872e0ad86..0000000000000000000000000000000000000000 --- a/database/pianos4-le.udb +++ /dev/null @@ -1,59 +0,0 @@ -# -*- coding: utf-8 -*- - -# PiAnoS (Picture Annotation System), A fingerprint examiner training tool -# Copyright (C) 2011-2013 University of Lausanne, Switzerland -# https://ips-labs.unil.ch/pianos - -# This program is free software: you can redistribute it and/or modify -# it under the terms of the GNU Affero General Public License as -# published by the Free Software Foundation, either version 3 of the -# License, or (at your option) any later version. - -# This program is distributed in the hope that it will be useful, -# but WITHOUT ANY WARRANTY; without even the implied warranty of -# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the -# GNU Affero General Public License for more details. - -# You should have received a copy of the GNU Affero General Public License -# along with this program. If not, see http://www.gnu.org/licenses/. - -# ============================ -# PiAnoS 4 - Lab Edition -# ============================ - -entity image autoid explicit id - name text nn - -entity prop autoid explicit id - name text nn - geo_x "double precision" - geo_y "double precision" - -entity scene inherits prop - -entity trace autoid - support fk prop nn - tnum text - -entity mark inherits image - trace fk trace nn - -entity individual autoid - name text nn - -entity finger autoid - hand int nn - num int nn - owner fk individual nn - -entity print inherits image - finger fk finger nn - -entity profile autoid - image fk image nn - -entity comparison autoid - op1 fk profile nn - op2 fk profile nn - - \ No newline at end of file diff --git a/database/pianos4-te-functions.sql b/database/pianos4-te-functions.sql deleted file mode 100644 index ebdc836b053908bfacbd10c92f7f9523efe78845..0000000000000000000000000000000000000000 --- a/database/pianos4-te-functions.sql +++ /dev/null @@ -1,100 +0,0 @@ - -CREATE OR REPLACE FUNCTION checkImageReadACL(imageid int, trusteeid int) RETURNS boolean AS $$ - SELECT bool_or(checkACL(markfolder.id, $2)) - OR bool_or(checkACL(printfolder.id, $2)) - OR checkACL(image.ID, $2) - FROM image - LEFT OUTER JOIN exercise AS markexercise ON markexercise.mark = image.id - LEFT OUTER JOIN folder AS markfolder ON markfolder.id = markexercise.folder - LEFT OUTER JOIN exercise AS printexercise ON printexercise.print = image.id - LEFT OUTER JOIN folder AS printfolder ON printfolder.id = printexercise.folder - WHERE image.id = $1 - GROUP BY image.id; -$$ LANGUAGE SQL; -CREATE OR REPLACE FUNCTION checkImageReadACL(imageid int) RETURNS boolean AS $$ - SELECT bool_or(checkACL(markfolder.id)) - OR bool_or(checkACL(printfolder.id)) - OR checkACL(image.ID) - FROM image - LEFT OUTER JOIN exercise AS markexercise ON markexercise.mark = image.id - LEFT OUTER JOIN folder AS markfolder ON markfolder.id = markexercise.folder - LEFT OUTER JOIN exercise AS printexercise ON printexercise.print = image.id - LEFT OUTER JOIN folder AS printfolder ON printfolder.id = printexercise.folder - WHERE image.id = $1 - GROUP BY image.id; -$$ LANGUAGE SQL; - -CREATE OR REPLACE FUNCTION checkAssignmentConstraints(pAID int) RETURNS void AS $$ - DECLARE - i int; - vid int; - BEGIN - SELECT INTO vid id FROM resulttype WHERE short = 'VALIDATED'; - -- At each step (i.e. ANALYSIS, COMPARISON, EVALUATION), a VALIDATED result - -- (besides not being allowed to be overwritten) may not be anterior to any - -- CURRENT or AUTOSAVE result - that is, you can't save after you have submitted. - -- In other words, the latest result saved must be either VALIDATED or no VALIDATED - -- result must be present at all. - FOR i IN (SELECT id FROM resultstep ORDER BY id ASC) LOOP - IF (((SELECT type FROM result WHERE assignment = pAID AND step = i ORDER BY updatedon DESC LIMIT 1) <> vid) AND ((SELECT count(*) FROM result WHERE assignment = pAID AND step = i AND type = vid) > 0)) THEN - RAISE EXCEPTION 'Assignment (ID=%) integrity error: cannot save to the CURRENT or AUTOSAVE result after the step (ID=%) has been VALIDATED', pAID, i; - END IF; - END LOOP; - -- One cannot save anything without the previous step being validated. - FOR i IN (SELECT id FROM resultstep ORDER BY id DESC) LOOP - IF ((i > 1) AND ((SELECT count(*) FROM result WHERE assignment = pAID AND step = i) > 0)) THEN - IF ((SELECT count(*) FROM result WHERE assignment = pAID AND step = i-1 AND type = vid) = 0) THEN - RAISE EXCEPTION 'Assignment (ID=%) integrity error: cannot save a result without the previous step being validated', pAID; - END IF; - END IF; - END LOOP; - RETURN; - END; -$$ LANGUAGE plpgsql; - --- Assignment progress is measured by the number of VALIDATED results and, if any, the number --- of intermediate results (i.e. CURRENT/AUTOSAVE) --- 0: exercise started (assignment created) but no results at all --- 1: analysis started (i.e. in analysis, CURRENT or AUTOSAVE result present, no VALIDATED) --- 2: analysis finished (i.e. in analysis, a VALIDATED result) --- 3: comparison started --- 4: comparison finished --- 5: evaluation started --- 6: evaluation finished --- Note that due to the fact that the web application saves 2 times upon validation, steps --- 2 and 3, as well as steps 4 and 5, are the same: we'll never see steps 2 or step 4, because --- the results are immediately copied into the next result, bumping the step by one. --- Note that this is done only to help the user: how frustrating it would be if you had to start --- all over again when submitting a result, and having to start the next step from scratch. -CREATE OR REPLACE FUNCTION getAssignmentStatus(pAID int) RETURNS int AS $$ - DECLARE - i int; - vid int; - BEGIN - IF (SELECT count(*) FROM assignment WHERE id = pAID) <> 1 THEN - RAISE EXCEPTION 'No such assignment (ID=%)', pAID; - END IF; - SELECT INTO vid id FROM resulttype WHERE short = 'VALIDATED'; - FOR i IN (SELECT id FROM resultstep ORDER BY id DESC) LOOP - IF (SELECT count(*) FROM result WHERE assignment = pAID AND step = i AND type = vid) > 0 THEN - RETURN 2*i; - ELSIF (SELECT count(*) FROM result WHERE assignment = pAID AND step = i) > 0 THEN - RETURN 2*i-1; - END IF; - END LOOP; - RETURN 0; - END; -$$ LANGUAGE plpgsql; - - -CREATE OR REPLACE FUNCTION getAnnotationType(pTextType text) RETURNS int AS $$ - DECLARE - res int; - BEGIN - SELECT INTO res id FROM annotationtype WHERE name = pTextType; - IF res IS NULL THEN - INSERT INTO annotationtype(name) VALUES (pTextType) RETURNING id INTO res; - END IF; - RETURN res; - END; -$$ LANGUAGE plpgsql; diff --git a/database/pianos4-te.udb b/database/pianos4-te.udb deleted file mode 100644 index 1fd60f85ecc55cf11009aece60abcb757473e376..0000000000000000000000000000000000000000 --- a/database/pianos4-te.udb +++ /dev/null @@ -1,249 +0,0 @@ -# -*- coding: utf-8 -*- - -# PiAnoS (Picture Annotation System), A fingerprint examiner training tool -# Copyright (C) 2011-2013 University of Lausanne, Switzerland -# https://ips-labs.unil.ch/pianos - -# This program is free software: you can redistribute it and/or modify -# it under the terms of the GNU Affero General Public License as -# published by the Free Software Foundation, either version 3 of the -# License, or (at your option) any later version. - -# This program is distributed in the hope that it will be useful, -# but WITHOUT ANY WARRANTY; without even the implied warranty of -# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the -# GNU Affero General Public License for more details. - -# You should have received a copy of the GNU Affero General Public License -# along with this program. If not, see http://www.gnu.org/licenses/. - -# ============================ -# PiAnoS 4 - Teaching Edition -# ============================ - -scripts - pianos4-te-functions.sql - - - -# Images -# ====== - -entity image inherits object - type fk imagetype nn - name text nn - mimetype text nn - info text - resolution int nn - width int nn - height int nn - data bytea nn - thumb fk image - checksum text - @fts - name - info - -entity imagetype autoid - short text uq nn - name text nn - @data - MARK "Mark" - PRINT "Print" - THUMBNAIL "Thumbnail" - -view imagev - sql "SELECT image.id,imagetype.id AS typeid,imagetype.short AS type,image.name,mimetype,info,resolution,width,height,thumb FROM image,imagetype WHERE image.type = imagetype.id" - depends image imagetype - - - -# Exercise definition -# =================== - -# Folders store exercises. At the app level, the folders' ACLs define the -# access rights of users to exercises -entity folder inherits object - name text nn - personalof fk person - childof int - @fts - name - -entity exercise inherits object - name text nn - description text - folder fk nn - mark fk image nn - print fk image nn - hidden_information text - @fts - name - description C - - - -# Assignments and results -# ======================= - -# The assignment is the object that is created when a user takes an exercise. -# The user is accessible through the object's creator. -entity assignment inherits object - exercise fk exercise nn idx - ispreview boolean nn false - -# Root object for all results: contains the creation time, last update time and the -# raw data (JSON object) -entity result - assignment fk assignment pk nn idx - type fk resulttype nn pk - store plpgsql "IF OLD.type = (SELECT id FROM resulttype WHERE short = 'VALIDATED') THEN RAISE EXCEPTION 'Cannot update VALIDATED result'; END IF;" before update - step fk resultstep nn pk - updatedon date now nn - store plpgsql "PERFORM checkAssignmentConstraints(NEW.assignment);" after "insert or update" - data text nn - -entity resulttype autoid - short text uq nn - name text nn - @data - CURRENT "Current" - AUTOSAVE "Autosave" - VALIDATED "Submission" - -entity resultstep autoid - short text uq nn - name text nn - @data - ANALYSIS "Analysis" - COMPARISON "Comparison" - EVALUATION "Evaluation" - -view resultv - sql "SELECT result.assignment, person.name AS \"user\", result.type AS typeid, resulttype.name AS type, result.step AS stepid, resultstep.name AS step, result.updatedon FROM result,resulttype,resultstep,object,person WHERE result.type = resulttype.id AND result.step = resultstep.id AND result.assignment = object.id AND object.creator = person.id" - depends result resulttype resultstep object person - -entity observation - result fk result nn pk - cfknames assignment restype resstep - type fk observationtype nn pk - value text nn - -entity observationtype autoid - name text uq - @data - conclusion - mark-needed-ridges - mark-value - mark-degradation - mark-details - mark-suitability-approach - mark-gp - comparison-decision - comparison-decision-ex - comparison-need-better-known - comparison-l3details - comparison-qualquant - -view observationv - sql "SELECT observation.*,observationtype.name FROM observation,observationtype WHERE observation.type = observationtype.id" - depends observation observationtype - -view resultvex - sqlfile views/resultvex.sql - depends result resulttype resultstep observation observationtype - -view resultvex2 - sqlfile views/resultvex2.sql - depends result resulttype resultstep observation observationtype - -entity annotation - id int nn pk - result fk result nn pk - cfknames assignment restype resstep - type fk annotationtype nn - image fk imagetype nn - createdon date nn - updatedon date nn - pairing int - subtype text - value int - groups int nn - -entity annotationtype autoid - name text uq nn - known boolean nn false - @data - "minutia" true - "ridge" true - "area" true - "comment" true - -entity minutia - annotation fk annotation nn pk - cfknames id assignment restype resstep - x "double precision" nn - y "double precision" nn - theta "double precision" nn - type fk minutiatype nn - -entity minutiatype autoid - name text uq nn - @data - "bifurcation" - "ridge_ending" - "unknown" - "unknown2" - "difference" - "center" - -entity resulthistory autoid - assignment fk assignment nn idx - type fk resulttype nn - store plpgsql "RAISE EXCEPTION 'Updating the result history is not allowed';" before update - step fk resultstep nn - createdon date now nn - data text nn - - -# Search views -# ========================== - -view ftsv - sqlfile views/ftsv.sql - depends person pgroup image folder exercise membership - - - -# Messaging subsystem -# ========================== - -entity message inherits object - type fk messagetype nn - visibility fk messagevisibility nn - parent fk message - title text nn - value text nn - -entity messagetype autoid - name text uq nn - @data - home - -entity messagevisibility autoid - name text uq nn - @data - hidden - tutors - users - all - -view messagev - sql "SELECT message.id,messagetype.id AS typeid,messagetype.name AS type,message.visibility AS visibilityid,messagevisibility.name AS visibility,message.title,message.value,message.parent,object.createdon,object.creator AS creatorid,person.name AS creator FROM message,messagevisibility,messagetype,object,person WHERE person.id=object.creator AND object.id=message.id AND message.visibility=messagevisibility.id AND message.type=messagetype.id" - depends message - - -# Plugins -# (comment out to disable) -# =================== -# import pianos4-nij.udb diff --git a/database/pianos4.udb b/database/pianos4.udb deleted file mode 100644 index aef6294183d83c0667ace1fec681318d6da660a4..0000000000000000000000000000000000000000 --- a/database/pianos4.udb +++ /dev/null @@ -1,63 +0,0 @@ -# -*- coding: utf-8 -*- - -# PiAnoS (Picture Annotation System), A fingerprint examiner training tool -# Copyright (C) 2011-2012 University of Lausanne, Switzerland -# https://ips-labs.unil.ch/pianos - -# This program is free software: you can redistribute it and/or modify -# it under the terms of the GNU Affero General Public License as -# published by the Free Software Foundation, either version 3 of the -# License, or (at your option) any later version. - -# This program is distributed in the hope that it will be useful, -# but WITHOUT ANY WARRANTY; without even the implied warranty of -# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the -# GNU Affero General Public License for more details. - -# You should have received a copy of the GNU Affero General Public License -# along with this program. If not, see http://www.gnu.org/licenses/. - -# ============================================================================ -# PiAnoS 4 -# ---------------------------------------------------------------------------- -# This is the master microDB script to create the database. It defines -# the base settings and then: -# - imports pianos4-core.udb to load common classes -# - imports local-database.udb, a site-dependent file (i.e. your working copy) -# - load either pianos4-le.udb or pianos4-te.udb. This is in fact done -# by the local-database.udb script. -# -# Since PiAnoS comes in different flavours (Teaching Edition (te) and Lab -# Edition (le)), you are left to import the correct version of the classes -# using your local-database.udb file. -# Remember that your local-database.udb file must also contain the -# 'database' block (db name, host, port, user, pwd) -# ============================================================================ - - - -# Import a few basic but very helpful SQL functions (aggregates, etc.) -template template.sql builtin - -# Post-schema installation script (loads demo images and creates an exercise) -scripts - pianos4-functions.sql - pianos4-install.py - - - -# Import core classes (object, trustees-users-groups) -# =================================================== -import pianos4-core.udb - -# Import the local database script (do not put the target file under version control) -# Note: as said above, this file must also -# import pianos4-te.udb -# or -# import pianos4-le.udb -# depending on the edition you wish to run -# NOTE: it is named 'local-database.udb' because it initially -# only contained the 'database' section, but now it must -# also reference the edition-dependent .udb script. -# =========================================================== -import local-database.udb diff --git a/database/views/ftsv.sql b/database/views/ftsv.sql deleted file mode 100644 index 2d228e36a2b9353f56934284db487f0bfcf17679..0000000000000000000000000000000000000000 --- a/database/views/ftsv.sql +++ /dev/null @@ -1,27 +0,0 @@ -SELECT 'person' AS type, person.id, person.name, CASE person.active WHEN true THEN 'Active' WHEN false THEN 'Inactive' END || ', In group(s): '||array_to_string(array_agg(pgroup.name), ',') AS desc, person.fts -FROM person,membership,pgroup -WHERE person.id = membership.person - AND membership.pgroup = pgroup.id -GROUP BY person.id, person.name, person.fts, person.active - -UNION - -SELECT 'pgroup' AS type, pgroup.id, pgroup.name, '' AS desc, pgroup.fts -FROM pgroup - -UNION - -SELECT 'image' AS type, image.id, image.name, image.info AS desc, image.fts -FROM image - -UNION - -SELECT 'folder' AS type, folder.id, folder.name, count(exercise.id)::text || ' exercise(s)' AS desc, folder.fts -FROM folder LEFT OUTER JOIN exercise ON exercise.folder = folder.id -GROUP BY folder.id, folder.name, folder.fts - -UNION - -SELECT 'exercise' AS type, exercise.id, exercise.name, exercise.description AS desc, exercise.fts -FROM exercise - diff --git a/database/views/resultvex.sql b/database/views/resultvex.sql deleted file mode 100644 index 28a7545e2b634f2ba66fa073385f140fb6bd354e..0000000000000000000000000000000000000000 --- a/database/views/resultvex.sql +++ /dev/null @@ -1,29 +0,0 @@ -SELECT result.assignment, - result.type AS typeid, - resulttype.name AS type, - result.step AS stepid, - resultstep.name AS step, - result.updatedon, - obs_concl.value AS conclusion, - obs_mark.value AS mark_value, - obs_decision.value AS decision, - obs_decision_ex.value AS decision_ex -FROM resulttype,resultstep,result - LEFT OUTER JOIN observation AS obs_concl ON obs_concl.assignment = result.assignment - AND obs_concl.restype = result.type - AND obs_concl.resstep = result.step - AND obs_concl.type = (SELECT id FROM observationtype WHERE name = 'conclusion') - LEFT OUTER JOIN observation AS obs_mark ON obs_mark.assignment = result.assignment - AND obs_mark.restype = result.type - AND obs_mark.resstep = result.step - AND obs_mark.type = (SELECT id FROM observationtype WHERE name = 'mark-value') - LEFT OUTER JOIN observation AS obs_decision ON obs_decision.assignment = result.assignment - AND obs_decision.restype = result.type - AND obs_decision.resstep = result.step - AND obs_decision.type = (SELECT id FROM observationtype WHERE name = 'comparison-decision') - LEFT OUTER JOIN observation AS obs_decision_ex ON obs_decision_ex.assignment = result.assignment - AND obs_decision_ex.restype = result.type - AND obs_decision_ex.resstep = result.step - AND obs_decision_ex.type = (SELECT id FROM observationtype WHERE name = 'comparison-decision-ex') -WHERE result.type = resulttype.id - AND result.step = resultstep.id diff --git a/database/views/resultvex2.sql b/database/views/resultvex2.sql deleted file mode 100644 index b8994c0c83aa9bab13b4599eae80c33270fb3082..0000000000000000000000000000000000000000 --- a/database/views/resultvex2.sql +++ /dev/null @@ -1,54 +0,0 @@ -SELECT result.assignment, - result.type AS typeid, - resulttype.name AS type, - result.step AS stepid, - resultstep.name AS step, - result.updatedon, - obs_concl.value AS conclusion, - obs_mark_value.value AS mark_value, - obs_mark_degradation.value AS mark_degradation, - obs_mark_details.value AS mark_details, - obs_decision.value AS decision, - obs_decision_ex.value AS decision_ex, - obs_comparison_need_better_known.value AS comparison_need_better_known, - obs_comparison_l3details.value AS comparison_l3details, - obs_comparison_qualquant.value AS comparison_qualquant -FROM resulttype,resultstep,result - LEFT OUTER JOIN observation AS obs_concl ON obs_concl.assignment = result.assignment - AND obs_concl.restype = result.type - AND obs_concl.resstep = result.step - AND obs_concl.type = (SELECT id FROM observationtype WHERE name = 'conclusion') - LEFT OUTER JOIN observation AS obs_mark_value ON obs_mark_value.assignment = result.assignment - AND obs_mark_value.restype = result.type - AND obs_mark_value.resstep = result.step - AND obs_mark_value.type = (SELECT id FROM observationtype WHERE name = 'mark-value') - LEFT OUTER JOIN observation AS obs_mark_degradation ON obs_mark_degradation.assignment = result.assignment - AND obs_mark_degradation.restype = result.type - AND obs_mark_degradation.resstep = result.step - AND obs_mark_degradation.type = (SELECT id FROM observationtype WHERE name = 'mark-degradation') - LEFT OUTER JOIN observation AS obs_mark_details ON obs_mark_details.assignment = result.assignment - AND obs_mark_details.restype = result.type - AND obs_mark_details.resstep = result.step - AND obs_mark_details.type = (SELECT id FROM observationtype WHERE name = 'mark-details') - LEFT OUTER JOIN observation AS obs_decision ON obs_decision.assignment = result.assignment - AND obs_decision.restype = result.type - AND obs_decision.resstep = result.step - AND obs_decision.type = (SELECT id FROM observationtype WHERE name = 'comparison-decision') - LEFT OUTER JOIN observation AS obs_decision_ex ON obs_decision_ex.assignment = result.assignment - AND obs_decision_ex.restype = result.type - AND obs_decision_ex.resstep = result.step - AND obs_decision_ex.type = (SELECT id FROM observationtype WHERE name = 'comparison-decision-ex') - LEFT OUTER JOIN observation AS obs_comparison_need_better_known ON obs_comparison_need_better_known.assignment = result.assignment - AND obs_comparison_need_better_known.restype = result.type - AND obs_comparison_need_better_known.resstep = result.step - AND obs_comparison_need_better_known.type = (SELECT id FROM observationtype WHERE name = 'comparison-need-better-known') - LEFT OUTER JOIN observation AS obs_comparison_l3details ON obs_comparison_l3details.assignment = result.assignment - AND obs_comparison_l3details.restype = result.type - AND obs_comparison_l3details.resstep = result.step - AND obs_comparison_l3details.type = (SELECT id FROM observationtype WHERE name = 'comparison-l3details') - LEFT OUTER JOIN observation AS obs_comparison_qualquant ON obs_comparison_qualquant.assignment = result.assignment - AND obs_comparison_qualquant.restype = result.type - AND obs_comparison_qualquant.resstep = result.step - AND obs_comparison_qualquant.type = (SELECT id FROM observationtype WHERE name = 'comparison-qualquant') -WHERE result.type = resulttype.id - AND result.step = resultstep.id