db_conn_postgres.rs 54.9 KB
Newer Older
1
2
3
4
5
6
7
8
9
10
11
12
13
/* * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * *
 *                                                                             *
 *        WARNING                                                              *
 *                                                                             *
 * This file is auto generated by ./generate_connectors.sh                     *
 *                                                                             *
 * Do not edit this file directly. Instead edit one of the corresponding       *
 * .header.rs oder .base.rs files.                                             *
 *                                                                             *
 *                                                                             *
 *                                                                             *
 * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * */

14
15
#![cfg(feature = "postgres")]

16
17
extern crate postgres;

18
19
20
use postgres::Connection;
use time;
use time::Duration;
21
22
23

use db_conn::{MedalConnection, MedalObject};
use db_objects::*;
24
use helpers;
25

26
trait Queryable {
Robert Czechowski's avatar
rustfmt    
Robert Czechowski committed
27
28
    fn query_map_one<T, F>(&self, sql: &str, params: &[&dyn postgres::types::ToSql], f: F)
                           -> postgres::Result<Option<T>>
29
        where F: FnOnce(postgres::rows::Row<'_>) -> T;
30
31
    fn query_map_many<T, F>(&self, sql: &str, params: &[&dyn postgres::types::ToSql], f: F) -> postgres::Result<Vec<T>>
        where F: FnMut(postgres::rows::Row<'_>) -> T;
32
    fn exists(&self, sql: &str, params: &[&dyn postgres::types::ToSql]) -> bool;
33
    fn get_last_id(&self) -> Option<i32>;
34
35
36
}

impl Queryable for Connection {
Robert Czechowski's avatar
rustfmt    
Robert Czechowski committed
37
38
    fn query_map_one<T, F>(&self, sql: &str, params: &[&dyn postgres::types::ToSql], f: F)
                           -> postgres::Result<Option<T>>
39
40
        where F: FnOnce(postgres::rows::Row<'_>) -> T {
        let rows = self.query(sql, params)?;
41

42
43
        Ok(rows.iter().next().map(f))
    }
44

45
46
47
48
49
    fn query_map_many<T, F>(&self, sql: &str, params: &[&dyn postgres::types::ToSql], f: F) -> postgres::Result<Vec<T>>
        where F: FnMut(postgres::rows::Row<'_>) -> T {
        Ok(self.query(sql, params)?.iter().map(f).collect())
    }

50
51
52
53
54
    fn exists(&self, sql: &str, params: &[&dyn postgres::types::ToSql]) -> bool {
        let stmt = self.prepare(sql).unwrap();
        !stmt.query(params).unwrap().is_empty()
    }

55
56
57
58
59
60
    fn get_last_id(&self) -> Option<i32> {
        self.query("SELECT lastval()", &[]).unwrap().iter().next().map(|row| {
                                                                      let r: i64 = row.get(0);
                                                                      r as i32
                                                                  })
    }
61
    // Empty line intended
62
63
}

64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
impl MedalObject<Connection> for Submission {
    fn save(&mut self, conn: &Connection) {
        match self.get_id() {
            Some(_id) => unimplemented!(),
            None => {
                let query = "INSERT INTO submission (task, session, grade, validated, nonvalidated_grade,
                                                     subtask_identifier, value, date, needs_validation)
                             VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9)";
                conn.execute(query,
                             &[&self.task,
                               &self.session_user,
                               &self.grade,
                               &self.validated,
                               &self.nonvalidated_grade,
                               &self.subtask_identifier,
                               &self.value,
                               &self.date,
                               &self.needs_validation])
                    .unwrap();
                self.set_id(conn.get_last_id().unwrap());
            }
        }
    }
}

impl MedalObject<Connection> for Grade {
    fn save(&mut self, conn: &Connection) {
        let query = "INSERT INTO grade (taskgroup, session, grade, validated)
                     VALUES ($1, $2, $3, $4)
                     ON CONFLICT ON CONSTRAINT grade_pkey DO UPDATE SET grade = excluded.grade, validated = excluded.validated";
        conn.execute(query, &[&self.taskgroup, &self.user, &self.grade, &self.validated]).unwrap();
    }
}
impl MedalObject<Connection> for Participation {
    fn save(&mut self, conn: &Connection) {
        let query = "INSERT INTO participation (contest, session, start_date)
                     VALUES ($1, $2, $3)";
        conn.execute(query, &[&self.contest, &self.user, &self.start]).unwrap();
    }
}

impl MedalObject<Connection> for Group {
    fn save(&mut self, conn: &Connection) {
        match self.get_id() {
            Some(_id) => unimplemented!(),
            None => {
                let query = "INSERT INTO usergroup (name, groupcode, tag, admin)
                             VALUES ($1, $2, $3, $4)";
                conn.execute(query, &[&self.name, &self.groupcode, &self.tag, &self.admin]).unwrap();
                self.set_id(conn.get_last_id().unwrap());
            }
        }
    }
}

impl MedalObject<Connection> for Task {
    fn save(&mut self, conn: &Connection) {
        let query = "SELECT id
                     FROM task
                     WHERE taskgroup = $1
                     AND location = $2";
        conn.query_map_one(query, &[&self.taskgroup, &self.location], |row| row.get(0))
            .unwrap_or(None)
            .and_then(|id| {
                self.set_id(id);
                Some(())
            })
            .unwrap_or(()); // Err means no entry yet and is expected result

        let id = match self.get_id() {
            Some(id) => {
                let query = "UPDATE task
                             SET taskgroup = $1, location = $2, stars = $3
                             WHERE id = $4";
                conn.execute(query, &[&self.taskgroup, &self.location, &self.stars, &id]).unwrap();
                id
            }
            None => {
                let query = "INSERT INTO task (taskgroup, location, stars)
                             VALUES ($1, $2, $3)";
                conn.execute(query, &[&self.taskgroup, &self.location, &self.stars]).unwrap();
                conn.get_last_id().unwrap()
            }
        };
        self.set_id(id);
    }
}

impl MedalObject<Connection> for Taskgroup {
    fn save(&mut self, conn: &Connection) {
        if let Some(first_task) = self.tasks.get(0) {
            let query = "SELECT taskgroup.id
                         FROM taskgroup
                         JOIN task
                         ON task.taskgroup = taskgroup.id
                         WHERE contest = $1
                         AND task.location = $2";
            conn.query_map_one(query, &[&self.contest, &first_task.location], |row| row.get(0))
                .unwrap_or(None)
                .and_then(|id| {
                    self.set_id(id);
                    Some(())
                })
                .unwrap_or(()); // Err means no entry yet and is expected result
        }

        let id = match self.get_id() {
            Some(id) => {
                let query = "UPDATE taskgroup
                             SET contest = $1, name = $2, positionalnumber = $3
                             WHERE id = $4";
                conn.execute(query, &[&self.contest, &self.name, &self.positionalnumber, &id]).unwrap();
                id
            }
            None => {
                let query = "INSERT INTO taskgroup (contest, name, positionalnumber)
                             VALUES ($1, $2, $3)";
                conn.execute(query, &[&self.contest, &self.name, &self.positionalnumber]).unwrap();
                conn.get_last_id().unwrap()
            }
        };
        self.set_id(id);
        for mut task in &mut self.tasks {
            task.taskgroup = id;
            task.save(conn);
        }
    }
}

impl MedalObject<Connection> for Contest {
    fn save(&mut self, conn: &Connection) {
        let query = "SELECT id
                     FROM contest
                     WHERE location = $1
                     AND filename = $2";
        conn.query_map_one(query, &[&self.location, &self.filename], |row| row.get(0))
            .unwrap_or(None)
            .and_then(|id| {
                self.set_id(id);
                Some(())
            })
            .unwrap_or(()); // Err means no entry yet and is expected result

        let id = match self.get_id() {
            Some(id) => {
                let query = "UPDATE contest
                             SET location = $1,filename = $2, name = $3, duration = $4, public = $5, start_date = $6, end_date = $7
                             WHERE id = $8";
                conn.execute(query,
                             &[&self.location,
                               &self.filename,
                               &self.name,
                               &self.duration,
                               &self.public,
                               &self.start,
                               &self.end,
                               &id])
                    .unwrap();
                id
            }
            None => {
                let query = "INSERT INTO contest (location, filename, name, duration, public, start_date, end_date)
                             VALUES ($1, $2, $3, $4, $5, $6, $7)";
                conn.execute(query,
                             &[&self.location,
                               &self.filename,
                               &self.name,
                               &self.duration,
                               &self.public,
                               &self.start,
                               &self.end])
                    .unwrap();
                conn.get_last_id().unwrap()
            }
        };
        self.set_id(id);
        for mut taskgroup in &mut self.taskgroups {
            taskgroup.contest = id;
            taskgroup.save(conn);
        }
    }
}

247
impl MedalConnection for Connection {
248
249
250
251
252
253
    fn dbtype(&self) -> &'static str { "postgres" }

    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();

254
255
        let query = "SELECT name FROM migrations WHERE name = $1";
        self.exists(query, &[&name])
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
    }

    fn apply_migration(&mut self, name: &str, contents: &str) {
        print!("Applying migration `{}` … ", name);

        let tx = self.transaction().unwrap();

        tx.batch_execute(&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> {
273
274
275
276
277
        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";
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
        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()??;
307
308
309

        let duration = if session.permanent_login { Duration::days(90) } else { Duration::minutes(90) };
        let now = time::get_time();
310

311
312
        if let Some(last_activity) = session.last_activity {
            if now - last_activity < duration {
313
314
315
316
                let query = "UPDATE session
                             SET last_activity = $1
                             WHERE id = $2";
                self.execute(query, &[&now, &session.id]).unwrap();
317
                return Some(session);
318
            } else {
319
320
321
322
                // Session timed out
                // Should remove session token from session
                return None;
            }
323
        }
324
325
326
        // last_activity undefined
        // TODO: What should happen here?
        None
327
328
329
330
331
332
333
334
335
336
337
338
    }
    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,
339
340
341
                      grade = $10,
                      is_teacher = $11
                      WHERE id = $12",
342
343
344
345
346
347
348
349
350
351
                     &[&session.username,
                       &session.password,
                       &session.salt,
                       &session.logincode,
                       &session.firstname,
                       &session.lastname,
                       &session.street,
                       &session.zip,
                       &session.city,
                       &session.grade,
352
                       &session.is_teacher,
353
354
355
356
                       &session.id])
            .unwrap();
    }
    fn new_session(&self, session_token: &str) -> SessionUser {
357
        let csrf_token = helpers::make_csrf_token();
358
359

        let now = time::get_time();
360
361
        let query = "INSERT INTO session (session_token, csrf_token, last_activity, permanent_login, grade,
                                          is_teacher)
362
363
                     VALUES ($1, $2, $3, $4, $5, $6)";
        self.execute(query, &[&session_token, &csrf_token, &now, &false, &0, &false]).unwrap();
364

365
366
        let id = self.get_last_id().expect("Expected to get last row id");

367
        SessionUser::minimal(id, session_token.to_owned(), csrf_token)
368
369
    }
    fn get_session_or_new(&self, key: &str) -> SessionUser {
370
371
372
        let query = "UPDATE session
                     SET session_token = $1
                     WHERE session_token = $2";
373
374
375
        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?
376
                                                 self.execute(query, &[&Option::<String>::None, &key]).unwrap();
377
378
                                                 self.new_session(&key)
                                             })
379
380
381
    }

    fn get_user_by_id(&self, user_id: i32) -> Option<SessionUser> {
382
383
384
385
386
        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";
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
        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) })
415
            .ok()?
416
417
418
419
420
421
422
423
424
425
    }

    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)),
        };

426
427
428
        let query = "SELECT name, groupcode, tag, admin
                     FROM usergroup
                     WHERE id = $1";
429
430
431
432
433
434
435
436
437
        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))),
438
439
440
441
442
443
            _ => Some((session, None)),
        }
    }

    //TODO: use session
    fn login(&self, _session: Option<&str>, username: &str, password: &str) -> Result<String, ()> {
444
445
446
447
        let query = "SELECT id, password, salt
                     FROM session
                     WHERE username = $1";
        self.query_map_one(query, &[&username], |row| {
448
449
450
451
                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
452
453
454
                if helpers::verify_password(&password,
                                            &salt.expect("salt from database empty"),
                                            &password_hash.expect("password from database empty"))
455
456
457
458
                {
                    // TODO: fail more pleasantly
                    // Login okay, update session now!

459
460
                    let session_token = helpers::make_session_token();
                    let csrf_token = helpers::make_csrf_token();
461
462
                    let now = time::get_time();

463
464
465
                    let query = "UPDATE session
                                 SET session_token = $1, csrf_token = $2, last_login = $3, last_activity = $3
                                 WHERE id = $4";
466
                    self.execute(query, &[&session_token, &csrf_token, &now, &id]).unwrap();
467
468
469
470
471

                    Ok(session_token)
                } else {
                    Err(())
                }
472
473
474
            })
            .map_err(|_| ())?
            .ok_or(())?
475
476
477
478
    }

    //TODO: use session
    fn login_with_code(&self, _session: Option<&str>, logincode: &str) -> Result<String, ()> {
479
480
481
482
        let query = "SELECT id
                     FROM session
                     WHERE logincode = $1";
        self.query_map_one(query, &[&logincode], |row| {
483
484
485
                // Login okay, update session now!
                let id: i32 = row.get(0);

486
487
                let session_token = helpers::make_session_token();
                let csrf_token = helpers::make_csrf_token();
488
489
                let now = time::get_time();

490
491
492
                let query = "UPDATE session
                             SET session_token = $1, csrf_token = $2, last_login = $3, last_activity = $3
                             WHERE id = $4";
493
                self.execute(query, &[&session_token, &csrf_token, &now, &id]).unwrap();
494

495
                session_token
496
497
498
            })
            .map_err(|_| ())?
            .ok_or(())
499
500
501
    }

    //TODO: use session
502
503
    fn login_foreign(&self, _session: Option<&str>, foreign_id: &str, is_teacher: bool, firstname: &str,
                     lastname: &str)
504
505
                     -> Result<String, ()>
    {
506
507
        let session_token = helpers::make_session_token();
        let csrf_token = helpers::make_csrf_token();
508
509
        let now = time::get_time();

510
511
512
        let query = "SELECT id
                     FROM session
                     WHERE oauth_foreign_id = $1";
513
514
        match self.query_map_one(query, &[&foreign_id], |row| -> i32 { row.get(0) }) {
            Ok(Some(id)) => {
515
516
517
                let query = "UPDATE session
                             SET session_token = $1, csrf_token = $2, last_login = $3, last_activity = $3
                             WHERE id = $4";
518
                self.execute(query, &[&session_token, &csrf_token, &now, &id]).unwrap();
519
520
521
522
523

                Ok(session_token)
            }
            // Add!
            _ => {
524
525
526
527
                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)";
528
529
530
531
532
533
534
535
536
537
538
                self.execute(query,
                             &[&session_token,
                               &csrf_token,
                               &now,
                               &false,
                               &0,
                               &is_teacher,
                               &foreign_id,
                               &firstname,
                               &lastname])
                    .unwrap();
539
540
541
542
543
544
545
546

                Ok(session_token)
            }
        }
    }

    //TODO: use session
    fn create_user_with_groupcode(&self, _session: Option<&str>, groupcode: &str) -> Result<String, ()> {
547
548
549
        let query = "SELECT id
                     FROM usergroup
                     WHERE groupcode = $1";
550
551
        let group_id =
            self.query_map_one(query, &[&groupcode], |row| -> i32 { row.get(0) }).map_err(|_| ())?.ok_or(())?;
552

553
554
555
        // Login okay, create session!
        let session_token = helpers::make_session_token();
        let csrf_token = helpers::make_csrf_token();
556
        let login_code = helpers::make_login_code(); // TODO: check for collisions
557
        let now = time::get_time();
558

559
560
561
        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)";
562
        self.execute(query, &[&session_token, &csrf_token, &now, &false, &login_code, &0, &false, &group_id]).unwrap();
563

564
        Ok(session_token)
565
566
    }

Robert Czechowski's avatar
rustfmt    
Robert Czechowski committed
567
    fn create_group_with_users(&self, mut group: Group) {
568
569
570
571
572
573
        // 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
Robert Czechowski's avatar
rustfmt    
Robert Czechowski committed
574

575
576
577
            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)";
578
579
580
581
582
583
584
585
586
587
            self.execute(query,
                         &[&user.firstname,
                           &user.lastname,
                           &csrf_token,
                           &false,
                           &login_code,
                           &user.grade,
                           &false,
                           &group.id])
                .unwrap();
588
        }
589
590
    }

591
    fn logout(&self, session: &str) {
592
593
594
        let query = "UPDATE session
                     SET session_token = NULL
                     WHERE session_token = $1";
595
        self.execute(query, &[&session]).unwrap();
596
597
598
599
    }

    fn load_submission(&self, session: &SessionUser, task: i32, subtask: Option<&str>) -> Option<Submission> {
        match subtask {
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
            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()?
            }
641
642
643
644
645
646
647
648
649
650
651
652
653
        }
    }
    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 {
654
655
656
657
658
659
        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";
660
661
662
663
664
665
666
        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
667
668
669
                         FROM submission
                         JOIN task ON task.id = submission.task
                         WHERE submission.id = $1";
670
671
672
673
674
675
676
                self.query_map_one(query, &[&submission_id], |row| Grade { taskgroup: row.get(0),
                                                                           user: row.get(1),
                                                                           grade: None,
                                                                           validated: false })
                    .unwrap()
                    .unwrap() // should this unwrap?
            })
677
678
679
680
    }

    fn get_contest_groups_grades(&self, session_id: i32, contest_id: i32)
                                 -> (Vec<String>, Vec<(Group, Vec<(UserInfo, Vec<Grade>)>)>) {
681
682
683
684
        let query = "SELECT id, name
                     FROM taskgroup
                     WHERE contest = $1
                     ORDER BY id ASC";
685
686
687
        let tasknames: Vec<(i32, String)> =
            self.query_map_many(query, &[&contest_id], |row| (row.get(0), row.get(1))).unwrap();

688
689
690
691
692
693
694
        let mut taskindex: ::std::collections::BTreeMap<i32, usize> = ::std::collections::BTreeMap::new();

        let n_tasks = tasknames.len();
        for (index, (i, _)) in tasknames.iter().enumerate() {
            taskindex.insert(*i, index);
        }

695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
        let query = "SELECT grade.taskgroup, grade.session, grade.grade, grade.validated, usergroup.id, usergroup.name,
                            usergroup.groupcode, usergroup.tag, student.id, student.username, student.logincode,
                            student.firstname, student.lastname
                     FROM grade
                     JOIN taskgroup ON grade.taskgroup = taskgroup.id
                     JOIN session AS student ON grade.session = student.id
                     JOIN usergroup ON student.managed_by = usergroup.id
                     WHERE usergroup.admin = $1
                     AND taskgroup.contest = $2
                     ORDER BY usergroup.id, student.id, taskgroup.id ASC";
        let gradeinfo =
            self.query_map_many(query, &[&session_id, &contest_id], |row| {
                    (Grade { taskgroup: row.get(0), user: row.get(1), grade: row.get(2), validated: row.get(3) },
                     Group { id: Some(row.get(4)),
                             name: row.get(5),
                             groupcode: row.get(6),
                             tag: row.get(7),
                             admin: session_id,
                             members: Vec::new() },
                     UserInfo { id: row.get(8),
                                username: row.get(9),
                                logincode: row.get(10),
                                firstname: row.get(11),
                                lastname: row.get(12) })
                })
                .unwrap();
        let mut gradeinfo_iter = gradeinfo.iter();
722
723

        if let Some(t /*Ok((grade, mut group, mut userinfo))*/) = gradeinfo_iter.next() {
724
            let (grade, mut group, mut userinfo) = t.clone();
725
726
727
728
729
730

            let mut grades: Vec<Grade> = vec![Default::default(); n_tasks];
            let mut users: Vec<(UserInfo, Vec<Grade>)> = Vec::new();
            let mut groups: Vec<(Group, Vec<(UserInfo, Vec<Grade>)>)> = Vec::new();

            let index = grade.taskgroup;
731
            grades[taskindex[&index]] = grade;
732
733

            for ggu in gradeinfo_iter {
734
735
                let (g, gr, ui) = ggu;
                if gr.id != group.id {
736
737
                    users.push((userinfo, grades));
                    userinfo = ui.clone();
738
739
                    grades = vec![Default::default(); n_tasks];

740
741
                    groups.push((group, users));
                    group = gr.clone();
742
743
                    users = Vec::new();
                } else if ui.id != userinfo.id {
744
745
                    users.push((userinfo, grades));
                    userinfo = ui.clone();
746
                    grades = vec![Default::default(); n_tasks];
747
                }
748
                let index = g.taskgroup;
749
                grades[taskindex[&index]] = *g;
750
            }
751
752
            users.push((userinfo, grades));
            groups.push((group, users));
753
754
755
756
757
758
759

            (tasknames.iter().map(|(_, name)| name.clone()).collect(), groups)
        } else {
            (Vec::new(), Vec::new()) // should those be default filled?
        }
    }
    fn get_contest_user_grades(&self, session_token: &str, contest_id: i32) -> Vec<Grade> {
760
761
762
763
        let query = "SELECT id, name
                     FROM taskgroup
                     WHERE contest = $1
                     ORDER BY id ASC";
764
765
        let tasknames: Vec<(i32, String)> =
            self.query_map_many(query, &[&contest_id], |row| (row.get(0), row.get(1))).unwrap();
766
767
768
769
770
771
772
        let mut taskindex: ::std::collections::BTreeMap<i32, usize> = ::std::collections::BTreeMap::new();

        let n_tasks = tasknames.len();
        for (index, (i, _)) in tasknames.iter().enumerate() {
            taskindex.insert(*i, index);
        }

773
774
775
776
777
778
779
780
781
782
783
784
785
786
        let query = "SELECT grade.taskgroup, grade.session, grade.grade, grade.validated
                     FROM grade
                     JOIN taskgroup ON grade.taskgroup = taskgroup.id
                     JOIN session ON session.id = grade.session
                     WHERE session.session_token = $1
                     AND taskgroup.contest = $2
                     ORDER BY taskgroup.id ASC";
        let gradeinfo =
            self.query_map_many(query, &[&session_token, &contest_id], |row| Grade { taskgroup: row.get(0),
                                                                                     user: row.get(1),
                                                                                     grade: row.get(2),
                                                                                     validated: row.get(3) })
                .unwrap();
        let gradeinfo_iter = gradeinfo.iter();
787
788
789
790
791

        let mut grades: Vec<Grade> = vec![Default::default(); n_tasks];

        for g in gradeinfo_iter {
            let index = g.taskgroup;
792
            grades[taskindex[&index]] = *g;
793
794
795
796
797
798
        }

        grades
    }

    fn get_taskgroup_user_grade(&self, session_token: &str, taskgroup_id: i32) -> Grade {
799
        let query = "SELECT grade.taskgroup, grade.session, grade.grade, grade.validated
800
801
802
803
                     FROM grade
                     JOIN session ON session.id = grade.session
                     WHERE session.session_token = $1
                     AND grade.taskgroup = $2";
804
805
806
807
808
809
        self.query_map_one(query, &[&session_token, &taskgroup_id], |row| Grade { taskgroup: row.get(0),
                                                                                  user: row.get(1),
                                                                                  grade: row.get(2),
                                                                                  validated: row.get(3) })
            .unwrap_or(None)
            .unwrap_or_default()
810
811
812
    }

    fn get_contest_list(&self) -> Vec<Contest> {
813
        let query = "SELECT id, location, filename, name, duration, public, start_date, end_date, min_grade, max_grade
814
815
                     FROM contest
                     ORDER BY id";
816
817
818
819
820
821
822
823
        self.query_map_many(query, &[], |row| Contest { id: Some(row.get(0)),
                                                        location: row.get(1),
                                                        filename: row.get(2),
                                                        name: row.get(3),
                                                        duration: row.get(4),
                                                        public: row.get(5),
                                                        start: row.get(6),
                                                        end: row.get(7),
824
825
                                                        min_grade: row.get(8),
                                                        max_grade: row.get(9),
826
827
                                                        taskgroups: Vec::new() })
            .unwrap()
828
829
830
    }

    fn get_contest_by_id(&self, contest_id: i32) -> Contest {
831
        let query = "SELECT location, filename, name, duration, public, start_date, end_date, min_grade, max_grade
832
833
                     FROM contest
                     WHERE id = $1";
834
835
836
837
838
839
840
841
        self.query_map_one(query, &[&contest_id], |row| Contest { id: Some(contest_id),
                                                                  location: row.get(0),
                                                                  filename: row.get(1),
                                                                  name: row.get(2),
                                                                  duration: row.get(3),
                                                                  public: row.get(4),
                                                                  start: row.get(5),
                                                                  end: row.get(6),
842
843
                                                                  min_grade: row.get(7),
                                                                  max_grade: row.get(8),
844
                                                                  taskgroups: Vec::new() })
845
846
847
848
849
            .unwrap()
            .unwrap() // TODO: Should return Option?
    }

    fn get_contest_by_id_complete(&self, contest_id: i32) -> Contest {
850
        let query = "SELECT contest.location, contest.filename, contest.name, contest.duration, contest.public,
851
852
                            contest.start_date, contest.end_date, contest.min_grade, contest.max_grade, taskgroup.id,
                            taskgroup.name, task.id, task.location, task.stars
853
854
855
856
                     FROM contest
                     JOIN taskgroup ON contest.id = taskgroup.contest
                     JOIN task ON taskgroup.id = task.taskgroup
                     WHERE contest.id = $1
857
                     ORDER BY taskgroup.positionalnumber";
858
859
860
861
862
863
864
865
866
867
        let taskgroupcontest =
            self.query_map_many(query, &[&contest_id], |row| {
                    (Contest { id: Some(contest_id),
                               location: row.get(0),
                               filename: row.get(1),
                               name: row.get(2),
                               duration: row.get(3),
                               public: row.get(4),
                               start: row.get(5),
                               end: row.get(6),
868
869
                               min_grade: row.get(7),
                               max_grade: row.get(8),
870
                               taskgroups: Vec::new() },
871
                     Taskgroup { id: Some(row.get(9)),
872
                                 contest: contest_id,
873
                                 name: row.get(10),
874
875
                                 positionalnumber: None,
                                 tasks: Vec::new() },
876
                     Task { id: Some(row.get(11)), taskgroup: row.get(9), location: row.get(12), stars: row.get(13) })
877
878
879
                })
                .unwrap();
        let mut taskgroupcontest_iter = taskgroupcontest.into_iter();
880
881
882
883

        let (mut contest, mut taskgroup, task) = taskgroupcontest_iter.next().unwrap();
        taskgroup.tasks.push(task);
        for tgc in taskgroupcontest_iter {
884
885
886
887
            let (_, tg, t) = tgc;
            if tg.id != taskgroup.id {
                contest.taskgroups.push(taskgroup);
                taskgroup = tg;
888
            }
889
            taskgroup.tasks.push(t);
890
891
892
893
894
895
        }
        contest.taskgroups.push(taskgroup);
        contest
    }

    fn get_contest_by_id_partial(&self, contest_id: i32) -> Contest {
896
        let query = "SELECT contest.location, contest.filename, contest.name, contest.duration, contest.public,
897
898
                            contest.start_date, contest.end_date, contest.min_grade, contest.max_grade, taskgroup.id,
                            taskgroup.name
899
900
901
                     FROM contest
                     JOIN taskgroup ON contest.id = taskgroup.contest
                     WHERE contest.id = $1";
902
903
904
905
906
907
908
909
910
        let taskgroupcontest = self.query_map_many(query, &[&contest_id], |row| {
                                       (Contest { id: Some(contest_id),
                                                  location: row.get(0),
                                                  filename: row.get(1),
                                                  name: row.get(2),
                                                  duration: row.get(3),
                                                  public: row.get(4),
                                                  start: row.get(5),
                                                  end: row.get(6),
911
912
                                                  min_grade: row.get(7),
                                                  max_grade: row.get(8),
913
                                                  taskgroups: Vec::new() },
914
                                        Taskgroup { id: Some(row.get(9)),
915
                                                    contest: contest_id,
916
                                                    name: row.get(10),
917
918
919
920
                                                    positionalnumber: None,
                                                    tasks: Vec::new() })
                                   })
                                   .unwrap();
921
        let mut taskgroupcontest_iter = taskgroupcontest.into_iter();
922
923
924
925

        let (mut contest, taskgroup) = taskgroupcontest_iter.next().unwrap();
        contest.taskgroups.push(taskgroup);
        for tgc in taskgroupcontest_iter {
926
927
            let (_, tg) = tgc;
            contest.taskgroups.push(tg);
928
929
930
931
932
        }
        contest
    }

    fn get_participation(&self, session: &str, contest_id: i32) -> Option<Participation> {
933
934
935
936
937
        let query = "SELECT session, start_date
                     FROM participation
                     JOIN session ON session.id = session
                     WHERE session.session_token = $1
                     AND contest = $2";
938
939
940
941
        self.query_map_one(query, &[&session, &contest_id], |row| Participation { contest: contest_id,
                                                                                  user: row.get(0),
                                                                                  start: row.get(1) })
            .ok()?
942
943
    }
    fn new_participation(&self, session: &str, contest_id: i32) -> Result<Participation, ()> {
944
945
946
947
948
        let query = "SELECT session, start_date
                     FROM participation
                     JOIN session ON session.id = session
                     WHERE session.session_token = $1
                     AND contest = $2";
949
950
        match self.query_map_one(query, &[&session, &contest_id], |_| {}).map_err(|_| ())? {
            Some(()) => Err(()),
951
952
953
            None => {
                let now = time::get_time();
                self.execute(
954
                             "INSERT INTO participation (contest, session, start_date)
955
                     SELECT $1, id, $2 FROM session WHERE session_token = $3",
956
957
958
                             &[&contest_id, &now, &session],
                )
                    .unwrap();
959
960
961
962
963
964

                Ok(self.get_participation(session, contest_id).unwrap()) // TODO: This errors if not logged in …
            }
        }
    }
    fn get_task_by_id(&self, task_id: i32) -> Task {
965
966
967
        let query = "SELECT location, stars, taskgroup
                     FROM task
                     WHERE id = $1";
968
969
970
971
        self.query_map_one(query, &[&task_id], |row| Task { id: Some(task_id),
                                                            taskgroup: row.get(2),
                                                            location: row.get(0),
                                                            stars: row.get(1) })
972
973
974
975
            .unwrap()
            .unwrap()
    }
    fn get_task_by_id_complete(&self, task_id: i32) -> (Task, Taskgroup, Contest) {
976
977
        let query = "SELECT task.location, task.stars, taskgroup.id, taskgroup.name, contest.id, contest.location,
                            contest.filename, contest.name, contest.duration, contest.public, contest.start_date,
978
                            contest.end_date, contest.min_grade, contest.max_grade
979
980
981
982
                     FROM contest
                     JOIN taskgroup ON taskgroup.contest = contest.id
                     JOIN task ON task.taskgroup = taskgroup.id
                     WHERE task.id = $1";
983
984
        self.query_map_one(query, &[&task_id], |row| {
                (Task { id: Some(task_id), taskgroup: row.get(2), location: row.get(0), stars: row.get(1) },
985
986
987
988
989
                 Taskgroup { id: Some(row.get(2)),
                             contest: row.get(4),
                             name: row.get(3),
                             positionalnumber: None,
                             tasks: Vec::new() },
990
991
992
993
994
995
996
997
                 Contest { id: Some(row.get(4)),
                           location: row.get(5),
                           filename: row.get(6),
                           name: row.get(7),
                           duration: row.get(8),
                           public: row.get(9),
                           start: row.get(10),
                           end: row.get(11),
998
999
                           min_grade: row.get(12),
                           max_grade: row.get(13),
1000
1001
1002
1003
                           taskgroups: Vec::new() })
            })
            .unwrap()
            .unwrap()
1004
1005
1006
1007
    }

    fn get_submission_to_validate(&self, tasklocation: &str, subtask: Option<&str>) -> i32 {
        match subtask {
1008
            Some(st) => {
1009
1010
1011
1012
1013
1014
1015
                let query = "SELECT id
                             FROM submission
                             JOIN task ON submission.task = task.id
                             WHERE task.location = $1
                             AND subtask_identifier = $2
                             AND needs_validation = 1
                             LIMIT 1";
1016
1017
1018
                self.query_map_one(query, &[&tasklocation, &st], |row| row.get(0)).unwrap().unwrap()
            }
            None => {
1019
1020
1021
1022
1023
1024
                let query = "SELECT id
                             FROM submission
                             JOIN task ON submission.task = task.id
                             WHERE task.location = $1
                             AND needs_validation = 1
                             LIMIT 1";
1025
1026
                self.query_map_one(query, &[&tasklocation], |row| row.get(0)).unwrap().unwrap()
            }
1027
1028
1029
1030
        }
    }

    fn find_next_submission_to_validate(&self, userid: i32, taskgroupid: i32) {
1031
1032
1033
1034
1035
1036
1037
        let query = "SELECT id, validated
                     FROM submission
                     JOIN task ON submission.task = task.id
                     WHERE task.taskgroup = $1
                     AND submission.session = $2
                     ORDER BY value DESC id DESC
                     LIMIT 1";
1038
1039
        let (id, validated): (i32, bool) =
            self.query_map_one(query, &[&taskgroupid, &userid], |row| (row.get(0), row.get(1))).unwrap().unwrap();
1040
        if !validated {
1041
1042
1043
            let query = "UPDATE submission
                         SET needs_validation = 1
                         WHERE id = $1";
1044
            self.execute(query, &[&id]).unwrap();
1045
1046
1047
1048
1049
1050
        }
    }

    fn add_group(&self, group: &mut Group) { group.save(self); }

    fn get_groups(&self, session_id: i32) -> Vec<Group> {
1051
1052
1053
        let query = "SELECT id, name, groupcode, tag
                     FROM usergroup
                     WHERE admin = $1";
1054
1055
1056
1057
1058
1059
        self.query_map_many(query, &[&session_id], |row| Group { id: Some(row.get(0)),
                                                                 name: row.get(1),
                                                                 groupcode: row.get(2),
                                                                 tag: row.get(3),
                                                                 admin: session_id,
                                                                 members: Vec::new() })
1060
1061
1062
1063
1064
1065
            .unwrap()
    }
    fn get_groups_complete(&self, _session_id: i32) -> Vec<Group> {
        unimplemented!();
    }
    fn get_group_complete(&self, group_id: i32) -> Option<Group> {
1066
1067
1068
        let query = "SELECT name, groupcode, tag, admin
                     FROM usergroup
                     WHERE id  = $1";
1069
1070
1071
1072
1073
1074
        let mut group = 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() })
1075
1076
1077
                            .unwrap()
                            .unwrap(); // TODO handle error

1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
        let query = "SELECT id, 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, oauth_provider, oauth_foreign_id, salt
                     FROM session
                     WHERE managed_by = $1";
        group.members = self.query_map_many(query, &[&group_id], |row| SessionUser { id: row.get(0),
                                                                                     session_token: row.get(1),
                                                                                     csrf_token: row.get(2),
                                                                                     last_login: row.get(3),
                                                                                     last_activity: row.get(4),
                                                                                     permanent_login: row.get(5),

                                                                                     username: row.get(6),
                                                                                     password: row.get(7),
                                                                                     salt: row.get(22),
                                                                                     logincode: row.get(8),
                                                                                     email: row.get(9),
                                                                                     email_unconfirmed: row.get(10),
                                                                                     email_confirmationcode:
                                                                                         row.get(11),

                                                                                     firstname: row.get(12),
                                                                                     lastname: row.get(13),
                                                                                     street: row.get(14),
                                                                                     zip: row.get(15),
                                                                                     city: row.get(16),
                                                                                     nation: row.get(17),
                                                                                     grade: row.get(18),

                                                                                     is_teacher: row.get(19),
                                                                                     managed_by: Some(group_id),

                                                                                     oauth_provider: row.get(20),
                                                                                     oauth_foreign_id: row.get(21) })
                            .unwrap();
1113
1114
        Some(group)
    }
1115

1116
    fn reset_all_contest_visibilities(&self) { self.execute("UPDATE contest SET public = $1", &[&false]).unwrap(); }
1117
}