Commit 82e3dcca authored by Robert Czechowski's avatar Robert Czechowski
Browse files

Add slight modificated sqlite db connector that is more similar to the postgres db connector

parent 1ea5514a
......@@ -11,10 +11,12 @@ license = "LGPL-3.0"
#maintenance = { status = "active-developed" }
[features]
default = ["rusqlite"]
complete = ["rusqlite", "postgres", "webbrowser"]
server = ["rusqlite", "postgres"]
desktop = ["rusqlite", "webbrowser"]
rusqlite_old = ["rusqlite"]
rusqlite_new = ["rusqlite"]
default = ["rusqlite_old"]
complete = ["rusqlite_old", "postgres", "webbrowser"]
server = ["rusqlite_old", "postgres"]
desktop = ["rusqlite_old", "webbrowser"]
watch = ["handlebars-iron/watch"]
strict = [] # Treat warnings as a build error
debug = []
......
CREATE TABLE contest (
id INTEGER PRIMARY KEY,
location TEXT NOT NULL,
filename TEXT NOT NULL,
name TEXT NOT NULL,
duration INTEGER NOT NULL,
public INTEGER NOT NULL,
start_date TEXT,
end_date TEXT
)
CREATE TABLE grade (
taskgroup INTEGER,
session INTEGER,
grade INTEGER,
validated INTEGER,
PRIMARY KEY (taskgroup, session)
)
CREATE TABLE usergroup (
id INTEGER PRIMARY KEY,
name TEXT,
groupcode TEXT,
tag TEXT,
admin INTEGER
)
CREATE TABLE participation (
contest INTEGER,
session INTEGER,
start_date TEXT,
PRIMARY KEY (contest, session)
)
CREATE TABLE session (
id INTEGER PRIMARY KEY,
session_token TEXT,
csrf_token TEXT,
last_login TEXT,
last_activity TEXT,
permanent_login INTEGER,
username TEXT,
password TEXT,
salt TEXT,
logincode TEXT,
email TEXT,
email_unconfirmed TEXT,
email_confirmationcode TEXT,
firstname TEXT,
lastname TEXT,
street TEXT,
zip TEXT,
city TEXT,
nation TEXT,
grade INTEGER,
is_teacher INTEGER,
managed_by INTEGER,
oauth_foreign_id TEXT,
oauth_provider TEXT
)
CREATE TABLE submission (
id INTEGER PRIMARY KEY,
session INTEGER NOT NULL,
task INTEGER NOT NULL,
grade INTEGER NOT NULL,
validated INTEGER NOT NULL,
needs_validation INTEGER NOT NULL,
nonvalidated_grade INTEGER NOT NULL,
subtask_identifier TEXT,
value TEXT,
date TEXT
)
CREATE TABLE task (
id INTEGER PRIMARY KEY,
taskgroup INTEGER,
location TEXT,
stars INTEGER
)
CREATE TABLE taskgroup (
id INTEGER PRIMARY KEY,
contest INTEGER NOT NULL,
name TEXT NOT NULL
)
#![cfg(feature = "rusqlite")]
#![cfg(feature = "rusqlite_old")]
extern crate rusqlite;
......
#![cfg(feature = "rusqlite_new")]
extern crate rusqlite;
use rusqlite::Connection;
use time;
use time::Duration;
use db_conn::{MedalConnection, MedalObject};
use db_objects::*;
use helpers;
trait Queryable {
fn query_map_one<T, F>(&self, sql: &str, params: &[&dyn rusqlite::types::ToSql], f: F)
-> rusqlite::Result<Option<T>>
where F: FnOnce(&rusqlite::Row) -> T;
fn query_map_many<T, F>(&self, sql: &str, params: &[&dyn rusqlite::types::ToSql], f: F) -> rusqlite::Result<Vec<T>>
where F: FnMut(&rusqlite::Row) -> T;
fn exists(&self, sql: &str, params: &[&dyn rusqlite::types::ToSql]) -> bool;
fn get_last_id(&self) -> Option<i32>;
}
impl Queryable for Connection {
fn query_map_one<T, F>(&self, sql: &str, params: &[&dyn rusqlite::types::ToSql], f: F)
-> rusqlite::Result<Option<T>>
where F: FnOnce(&rusqlite::Row) -> T {
let mut stmt = self.prepare(sql)?;
let mut rows = stmt.query(params)?;
match rows.next() {
None => Ok(None),
Some(Err(e)) => Err(e),
Some(Ok(row)) => Ok(Some(f(&row))),
}
}
fn query_map_many<T, F>(&self, sql: &str, params: &[&dyn rusqlite::types::ToSql], f: F) -> rusqlite::Result<Vec<T>>
where F: FnMut(&rusqlite::Row) -> T {
let mut stmt = self.prepare(sql)?;
let rows = stmt.query_map(params, f)?;
Ok(rows.map(|x| x.unwrap()).collect())
}
fn exists(&self, sql: &str, params: &[&dyn rusqlite::types::ToSql]) -> bool {
let mut stmt = self.prepare(sql).unwrap();
stmt.exists(params).unwrap()
}
fn get_last_id(&self) -> Option<i32> { self.query_row("SELECT last_insert_rowid()", &[], |row| row.get(0)).ok() }
}
impl MedalConnection for Connection {
fn dbtype(&self) -> &'static str { "sqlite_v2" }
fn migration_already_applied(&self, name: &str) -> bool {
let create_string = "CREATE TABLE IF NOT EXISTS migrations (name TEXT PRIMARY KEY);";
self.execute(create_string, &[]).unwrap();
let query = "SELECT name FROM migrations WHERE name = ?1";
self.exists(query, &[&name])
}
fn apply_migration(&mut self, name: &str, contents: &str) {
print!("Applying migration `{}` … ", name);
let tx = self.transaction().unwrap();
tx.execute_batch(&contents).unwrap();
tx.execute("INSERT INTO migrations (name) VALUES (?1)", &[&name]).unwrap();
tx.commit().unwrap();
println!("OK.");
}
// fn get_session<T: ToSql>(&self, key: T, keyname: &str) -> Option<SessionUser> {
fn get_session(&self, key: &str) -> Option<SessionUser> {
let query = "SELECT id, csrf_token, last_login, last_activity, permanent_login, username, password, logincode,
email, email_unconfirmed, email_confirmationcode, firstname, lastname, street, zip, city,
nation, grade, is_teacher, managed_by, oauth_provider, oauth_foreign_id, salt
FROM session
WHERE session_token = ?1";
let session = self.query_map_one(query, &[&key], |row| SessionUser { id: row.get(0),
session_token: Some(key.to_string()),
csrf_token: row.get(1),
last_login: row.get(2),
last_activity: row.get(3),
permanent_login: row.get(4),
username: row.get(5),
password: row.get(6),
salt: row.get(22),
logincode: row.get(7),
email: row.get(8),
email_unconfirmed: row.get(9),
email_confirmationcode: row.get(10),
firstname: row.get(11),
lastname: row.get(12),
street: row.get(13),
zip: row.get(14),
city: row.get(15),
nation: row.get(16),
grade: row.get(17),
is_teacher: row.get(18),
managed_by: row.get(19),
oauth_provider: row.get(20),
oauth_foreign_id: row.get(21) })
.ok()??;
let duration = if session.permanent_login { Duration::days(90) } else { Duration::minutes(90) };
let now = time::get_time();
if let Some(last_activity) = session.last_activity {
if now - last_activity < duration {
let query = "UPDATE session
SET last_activity = ?1
WHERE id = ?2";
self.execute(query, &[&now, &session.id]).unwrap();
return Some(session);
} else {
// Session timed out
// Should remove session token from session
return None;
}
}
// last_activity undefined
// TODO: What should happen here?
None
}
fn save_session(&self, session: SessionUser) {
self.execute("UPDATE session SET
username = ?1,
password = ?2,
salt = ?3,
logincode = ?4,
firstname = ?5,
lastname = ?6,
street = ?7,
zip = ?8,
city = ?9,
grade = ?10,
is_teacher = ?11
WHERE id = ?12",
&[&session.username,
&session.password,
&session.salt,
&session.logincode,
&session.firstname,
&session.lastname,
&session.street,
&session.zip,
&session.city,
&session.grade,
&session.is_teacher,
&session.id])
.unwrap();
}
fn new_session(&self, session_token: &str) -> SessionUser {
let csrf_token = helpers::make_csrf_token();
let now = time::get_time();
let query = "INSERT INTO session (session_token, csrf_token, last_activity, permanent_login, grade,
is_teacher)
VALUES (?1, ?2, ?3, 0, 0, 0)";
self.execute(query, &[&session_token, &csrf_token, &now]).unwrap();
let id = self.get_last_id().expect("Expected to get last row id");
SessionUser::minimal(id, session_token.to_owned(), csrf_token)
}
fn get_session_or_new(&self, key: &str) -> SessionUser {
let query = "UPDATE session
SET session_token = ?1
WHERE session_token = ?2";
self.get_session(&key).ensure_alive().unwrap_or_else(|| {
// TODO: Factor this out in own function
// TODO: Should a new session key be generated every time?
self.execute(query, &[&Option::<String>::None, &key]).unwrap();
self.new_session(&key)
})
}
fn get_user_by_id(&self, user_id: i32) -> Option<SessionUser> {
let query = "SELECT session_token, csrf_token, last_login, last_activity, permanent_login, username, password,
logincode, email, email_unconfirmed, email_confirmationcode, firstname, lastname, street,
zip, city, nation, grade, is_teacher, managed_by, oauth_provider, oauth_foreign_id, salt
FROM session
WHERE id = ?1";
self.query_map_one(query, &[&user_id], |row| SessionUser { id: user_id,
session_token: row.get(0),
csrf_token: row.get(1),
last_login: row.get(2),
last_activity: row.get(3),
permanent_login: row.get(4),
username: row.get(5),
password: row.get(6),
salt: row.get(22),
logincode: row.get(7),
email: row.get(8),
email_unconfirmed: row.get(9),
email_confirmationcode: row.get(10),
firstname: row.get(11),
lastname: row.get(12),
street: row.get(13),
zip: row.get(14),
city: row.get(15),
nation: row.get(16),
grade: row.get(17),
is_teacher: row.get(18),
managed_by: row.get(19),
oauth_provider: row.get(20),
oauth_foreign_id: row.get(21) })
.ok()?
}
fn get_user_and_group_by_id(&self, user_id: i32) -> Option<(SessionUser, Option<Group>)> {
let session = self.get_user_by_id(user_id)?;
let group_id = match session.managed_by {
Some(id) => id,
None => return Some((session, None)),
};
let query = "SELECT name, groupcode, tag, admin
FROM usergroup
WHERE id = ?1";
let res = self.query_map_one(query, &[&group_id], |row| Group { id: Some(group_id),
name: row.get(0),
groupcode: row.get(1),
tag: row.get(2),
admin: row.get(3),
members: Vec::new() })
.ok()?;
match res {
Some(group) => Some((session, Some(group))),
_ => Some((session, None)),
}
}
//TODO: use session
fn login(&self, _session: Option<&str>, username: &str, password: &str) -> Result<String, ()> {
let query = "SELECT id, password, salt
FROM session
WHERE username = ?1";
self.query_map_one(query, &[&username], |row| {
let (id, password_hash, salt): (i32, Option<String>, Option<String>) =
(row.get(0), row.get(1), row.get(2));
//password_hash ist das, was in der Datenbank steht
if helpers::verify_password(&password,
&salt.expect("salt from database empty"),
&password_hash.expect("password from database empty"))
{
// TODO: fail more pleasantly
// Login okay, update session now!
let session_token = helpers::make_session_token();
let csrf_token = helpers::make_session_token();
let now = time::get_time();
let query = "UPDATE session
SET session_token = ?1, csrf_token = ?2, last_login = ?3, last_activity = ?3
WHERE id = ?4";
self.execute(query, &[&session_token, &csrf_token, &now, &id]).unwrap();
Ok(session_token)
} else {
Err(())
}
})
.map_err(|_| ())?
.ok_or(())?
}
//TODO: use session
fn login_with_code(&self, _session: Option<&str>, logincode: &str) -> Result<String, ()> {
let query = "SELECT id FROM session WHERE logincode = ?1";
self.query_map_one(query, &[&logincode], |row| {
// Login okay, update session now!
let id: i32 = row.get(0);
let session_token = helpers::make_session_token();
let csrf_token = helpers::make_csrf_token();
let now = time::get_time();
let query = "UPDATE session
SET session_token = ?1, csrf_token = ?2, last_login = ?3, last_activity = ?3
WHERE id = ?4";
self.execute(query, &[&session_token, &csrf_token, &now, &id]).unwrap();
session_token
})
.map_err(|_| ())?
.ok_or(())
}
//TODO: use session
fn login_foreign(&self, _session: Option<&str>, foreign_id: &str, is_teacher: bool, firstname: &str,
lastname: &str)
-> Result<String, ()>
{
let session_token = helpers::make_session_token();
let csrf_token = helpers::make_csrf_token();
let now = time::get_time();
let query = "SELECT id
FROM session
WHERE oauth_foreign_id = ?1";
match self.query_map_one(query, &[&foreign_id], |row| -> i32 { row.get(0) }) {
Ok(Some(id)) => {
let query = "UPDATE session
SET session_token = ?1, csrf_token = ?2, last_login = ?3, last_activity = ?3
WHERE id = ?4";
self.execute(query, &[&session_token, &csrf_token, &now, &id]).unwrap();
Ok(session_token)
}
// Add!
_ => {
let query = "INSERT INTO session (session_token, csrf_token, last_login, last_activity,
permanent_login, grade, is_teacher, oauth_foreign_id,
firstname, lastname)
VALUES (?1, ?2, ?3, ?3, ?4, ?5, ?6, ?7, ?8, ?9)";
self.execute(query,
&[&session_token,
&csrf_token,
&now,
&false,
&0,
&is_teacher,
&foreign_id,
&firstname,
&lastname])
.unwrap();
Ok(session_token)
}
}
}
//TODO: use session
fn create_user_with_groupcode(&self, _session: Option<&str>, groupcode: &str) -> Result<String, ()> {
let query = "SELECT id
FROM usergroup
WHERE groupcode = ?1";
let group_id =
self.query_map_one(query, &[&groupcode], |row| -> i32 { row.get(0) }).map_err(|_| ())?.ok_or(())?;
// Login okay, create session!
let session_token = helpers::make_session_token();
let csrf_token = helpers::make_csrf_token();
let login_code = helpers::make_login_code(); // TODO: check for collisions
let now = time::get_time();
let query = "INSERT INTO session (session_token, csrf_token, last_login, last_activity, permanent_login,
logincode, grade, is_teacher, managed_by)
VALUES (?1, ?2, ?3, ?3, ?4, ?5, ?6, ?7, ?8)";
self.execute(query, &[&session_token, &csrf_token, &now, &false, &login_code, &0, &false, &group_id]).unwrap();
Ok(session_token)
}
fn create_group_with_users(&self, mut group: Group) {
// Generate group ID:
group.save(self);
for user in group.members {
let csrf_token = helpers::make_csrf_token();
let login_code = helpers::make_login_code(); // TODO: check for collisions
let query = "INSERT INTO session (firstname, lastname, csrf_token, permanent_login, logincode, grade,
is_teacher, managed_by)
VALUES (?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8)";
self.execute(query,
&[&user.firstname,
&user.lastname,
&csrf_token,
&false,
&login_code,
&user.grade,
&false,
&group.id])
.unwrap();
}
}
fn logout(&self, session: &str) {
let query = "UPDATE session
SET session_token = NULL
WHERE session_token = ?1";
self.execute(query, &[&session]).unwrap();
}
fn load_submission(&self, session: &SessionUser, task: i32, subtask: Option<&str>) -> Option<Submission> {
match subtask {
None => {
let query = "SELECT id, grade, validated, nonvalidated_grade, value, date, needs_validation
FROM submission
WHERE task = ?1
AND session = ?2
ORDER BY id DESC
LIMIT 1";
self.query_map_one(query, &[&task, &session.id], |row| Submission { id: Some(row.get(0)),
task: task,
session_user: session.id,
grade: row.get(1),
validated: row.get(2),
nonvalidated_grade: row.get(3),
subtask_identifier: None,
value: row.get(4),
date: row.get(5),
needs_validation: row.get(6) })
.ok()?
}
Some(subtask_id) => {
let query = "SELECT id, grade, validated, nonvalidated_grade, value, date, needs_validation
FROM submission
WHERE task = ?1
AND session = ?2
AND subtask_identifier = ?3
ORDER BY id DESC
LIMIT 1";
self.query_map_one(query, &[&task, &session.id, &subtask_id], |row| {
Submission { id: Some(row.get(0)),
task: task,
session_user: session.id,
grade: row.get(1),
validated: row.get(2),
nonvalidated_grade: row.get(3),
subtask_identifier: Some(subtask_id.to_string()),
value: row.get(4),
date: row.get(5),
needs_validation: row.get(6) }
})
.ok()?
}
}
}
fn submit_submission(&self, mut submission: Submission) {
submission.save(self);
let mut grade = self.get_grade_by_submission(submission.id.unwrap());
if grade.grade.is_none() || submission.grade > grade.grade.unwrap() {
grade.grade = Some(submission.grade);
grade.validated = false;
grade.save(self);
}
}
fn get_grade_by_submission(&self, submission_id: i32) -> Grade {
let query = "SELECT grade.taskgroup, grade.session, grade.grade, grade.validated
FROM grade
JOIN task ON grade.taskgroup = task.taskgroup
JOIN submission ON task.id = submission.task
AND grade.session = submission.session
WHERE submission.id = ?1";
self.query_map_one(query, &[&submission_id], |row| {
Grade {
taskgroup: row.get(0),
user: row.get(1),
grade: row.get(2),
validated: row.get(3),
}
}).unwrap_or(None).unwrap_or_else(|| {
let query = "SELECT task.taskgroup, submission.session
FROM submission
JOIN task ON task.id = submission.task
WHERE submission.id = ?1";
self.query_map_one(query, &[&submission_id], |row| {
Grade {
taskgroup: row.get(0),
user: row.get(1),