headless_lms_models/
user_exercise_states.rs

1use derive_more::Display;
2use std::collections::HashMap;
3
4use futures::Stream;
5use headless_lms_utils::numbers::option_f32_to_f32_two_decimals_with_none_as_zero;
6use serde_json::Value;
7
8use crate::{
9    course_modules::{self, CourseModule},
10    courses,
11    exercises::{ActivityProgress, Exercise, GradingProgress},
12    prelude::*,
13};
14
15#[derive(Debug, Serialize, Deserialize, PartialEq, Eq, Clone, Copy, Type, Display)]
16#[sqlx(type_name = "reviewing_stage", rename_all = "snake_case")]
17#[cfg_attr(feature = "ts_rs", derive(TS))]
18/**
19Tells what stage of reviewing the user is currently in. Used for for peer review, self review, and manual review. If an exercise does not involve reviewing, the value of this stage will always be `NotStarted`.
20*/
21pub enum ReviewingStage {
22    /**
23    In this stage the user submits answers to the exercise. If the exercise allows it, the user can answer the exercise multiple times. If the exercise is not in this stage, the user cannot answer the exercise. Most exercises will never leave this stage because other stages are reseverved for situations when we cannot give the user points just based on the automatic gradings.
24    */
25    NotStarted,
26    /// In this stage the student is instructed to give peer reviews to other students.
27    PeerReview,
28    /// In this stage the student is instructed to review their own answer.
29    SelfReview,
30    /// In this stage the student has completed the neccessary peer and self reviews but is waiting for other students to peer review their answer before we can give points for this exercise.
31    WaitingForPeerReviews,
32    /**
33    In this stage the student has completed everything they need to do, but before we can give points for this exercise, we need a manual grading from the teacher.
34
35    Reasons for ending up in this stage may be one of these:
36
37    1. The exercise is configured to require all answers to be reviewed by the teacher.
38    2. The answer has received poor reviews from the peers, and the exercise has been configured so that the teacher has to double-check whether it is justified to not give full points to the student.
39    */
40    WaitingForManualGrading,
41    /**
42    In this stage the the reviews have been completed and the points have been awarded to the student. However, since the answer had to go though the review process, the student may no longer answer the exercise since because
43
44    1. It is likely that we revealed the model solution to the student during the review process.
45    2. In case of peer review, a new answer would have to be reviewed by other students again, and that would be unreasonable extra work for others.
46
47    If the teacher for some reasoon feels bad for the student and wants to give them a new chance, the answers for this exercise should be reset, the reason should be recorded somewhere in the database, and the value of this column should be set to `NotStarted`. Deleting the whole user_exercise_state may also be wise. However, if we end up doing this for a teacher, we should make sure that the teacher realizes that they should not give an unfair advantage to anyone.
48    */
49    ReviewedAndLocked,
50}
51
52#[cfg_attr(feature = "ts_rs", derive(TS))]
53#[derive(Debug, Serialize, Deserialize, PartialEq, Clone)]
54pub struct UserExerciseState {
55    pub id: Uuid,
56    pub user_id: Uuid,
57    pub exercise_id: Uuid,
58    pub course_id: Option<Uuid>,
59    pub exam_id: Option<Uuid>,
60    pub created_at: DateTime<Utc>,
61    pub updated_at: DateTime<Utc>,
62    pub deleted_at: Option<DateTime<Utc>>,
63    pub score_given: Option<f32>,
64    pub grading_progress: GradingProgress,
65    pub activity_progress: ActivityProgress,
66    pub reviewing_stage: ReviewingStage,
67    pub selected_exercise_slide_id: Option<Uuid>,
68}
69
70impl UserExerciseState {
71    pub fn get_course_id(&self) -> ModelResult<Uuid> {
72        self.course_id.ok_or_else(|| {
73            ModelError::new(
74                ModelErrorType::Generic,
75                "Exercise is not part of a course.".to_string(),
76                None,
77            )
78        })
79    }
80
81    pub fn get_selected_exercise_slide_id(&self) -> ModelResult<Uuid> {
82        self.selected_exercise_slide_id.ok_or_else(|| {
83            ModelError::new(
84                ModelErrorType::Generic,
85                "No exercise slide selected.".to_string(),
86                None,
87            )
88        })
89    }
90}
91
92#[derive(Debug, Serialize, Deserialize, PartialEq, Clone)]
93pub struct UserExerciseStateUpdate {
94    pub id: Uuid,
95    pub score_given: Option<f32>,
96    pub activity_progress: ActivityProgress,
97    pub reviewing_stage: ReviewingStage,
98    pub grading_progress: GradingProgress,
99}
100
101#[derive(Debug, Serialize, Deserialize, FromRow, PartialEq, Clone)]
102#[cfg_attr(feature = "ts_rs", derive(TS))]
103pub struct UserCourseProgress {
104    pub course_module_id: Uuid,
105    pub course_module_name: String,
106    pub course_module_order_number: i32,
107    pub score_given: f32,
108    pub score_required: Option<i32>,
109    pub score_maximum: Option<u32>,
110    pub total_exercises: Option<u32>,
111    pub attempted_exercises: Option<i32>,
112    pub attempted_exercises_required: Option<i32>,
113}
114
115#[derive(Debug, Serialize, Deserialize, FromRow, PartialEq, Clone)]
116#[cfg_attr(feature = "ts_rs", derive(TS))]
117pub struct UserCourseChapterExerciseProgress {
118    pub exercise_id: Uuid,
119    pub score_given: f32,
120}
121
122#[derive(Debug, Serialize, Deserialize, FromRow, PartialEq, Clone)]
123pub struct DatabaseUserCourseChapterExerciseProgress {
124    pub exercise_id: Uuid,
125    pub score_given: Option<f32>,
126}
127
128#[derive(Debug, Serialize, Deserialize, FromRow, PartialEq, Clone)]
129pub struct UserChapterMetrics {
130    pub score_given: Option<f32>,
131    pub attempted_exercises: Option<i64>,
132}
133
134#[derive(Debug, Serialize, Deserialize, FromRow, PartialEq, Clone)]
135pub struct UserCourseMetrics {
136    pub course_module_id: Uuid,
137    pub score_given: Option<f32>,
138    pub attempted_exercises: Option<i64>,
139}
140
141#[derive(Debug, Serialize, Deserialize, FromRow, PartialEq, Clone)]
142pub struct CourseExerciseMetrics {
143    course_module_id: Uuid,
144    total_exercises: Option<i64>,
145    score_maximum: Option<i64>,
146}
147
148#[derive(Debug, Serialize, Deserialize, FromRow, PartialEq, Clone)]
149#[cfg_attr(feature = "ts_rs", derive(TS))]
150pub struct ExerciseUserCounts {
151    exercise_name: String,
152    exercise_order_number: i32,
153    page_order_number: i32,
154    chapter_number: i32,
155    exercise_id: Uuid,
156    #[cfg_attr(feature = "ts_rs", ts(type = "number"))]
157    n_users_attempted: Option<i64>,
158    #[cfg_attr(feature = "ts_rs", ts(type = "number"))]
159    n_users_with_some_points: Option<i64>,
160    #[cfg_attr(feature = "ts_rs", ts(type = "number"))]
161    n_users_with_max_points: Option<i64>,
162}
163
164pub async fn get_course_metrics(
165    conn: &mut PgConnection,
166    course_id: Uuid,
167) -> ModelResult<Vec<CourseExerciseMetrics>> {
168    let res = sqlx::query_as!(
169        CourseExerciseMetrics,
170        r"
171SELECT chapters.course_module_id,
172  COUNT(exercises.id) AS total_exercises,
173  SUM(exercises.score_maximum) AS score_maximum
174FROM courses c
175  LEFT JOIN exercises ON (c.id = exercises.course_id)
176  LEFT JOIN chapters ON (exercises.chapter_id = chapters.id)
177WHERE exercises.deleted_at IS NULL
178  AND c.id = $1
179  AND chapters.course_module_id IS NOT NULL
180GROUP BY chapters.course_module_id
181        ",
182        course_id
183    )
184    .fetch_all(conn)
185    .await?;
186    Ok(res)
187}
188
189pub async fn get_course_metrics_indexed_by_module_id(
190    conn: &mut PgConnection,
191    course_id: Uuid,
192) -> ModelResult<HashMap<Uuid, CourseExerciseMetrics>> {
193    let res = get_course_metrics(conn, course_id)
194        .await?
195        .into_iter()
196        .map(|x| (x.course_module_id, x))
197        .collect();
198    Ok(res)
199}
200
201/// Gets course metrics for a single module.
202pub async fn get_single_module_metrics(
203    conn: &mut PgConnection,
204    course_id: Uuid,
205    course_module_id: Uuid,
206    user_id: Uuid,
207) -> ModelResult<UserCourseMetrics> {
208    let res = sqlx::query!(
209        "
210SELECT COUNT(ues.exercise_id) AS attempted_exercises,
211  COALESCE(SUM(ues.score_given), 0) AS score_given
212FROM user_exercise_states AS ues
213  LEFT JOIN exercises ON (ues.exercise_id = exercises.id)
214  LEFT JOIN chapters ON (exercises.chapter_id = chapters.id)
215WHERE chapters.course_module_id = $1
216  AND ues.course_id = $2
217  AND ues.activity_progress IN ('completed', 'submitted')
218  AND ues.user_id = $3
219  AND ues.deleted_at IS NULL
220        ",
221        course_module_id,
222        course_id,
223        user_id,
224    )
225    .map(|x| UserCourseMetrics {
226        course_module_id,
227        score_given: x.score_given,
228        attempted_exercises: x.attempted_exercises,
229    })
230    .fetch_one(conn)
231    .await?;
232    Ok(res)
233}
234
235pub async fn get_user_course_metrics(
236    conn: &mut PgConnection,
237    course_id: Uuid,
238    user_id: Uuid,
239) -> ModelResult<Vec<UserCourseMetrics>> {
240    let res = sqlx::query_as!(
241        UserCourseMetrics,
242        r"
243SELECT chapters.course_module_id,
244  COUNT(ues.exercise_id) AS attempted_exercises,
245  COALESCE(SUM(ues.score_given), 0) AS score_given
246FROM user_exercise_states AS ues
247  LEFT JOIN exercises ON (ues.exercise_id = exercises.id)
248  LEFT JOIN chapters ON (exercises.chapter_id = chapters.id)
249WHERE ues.course_id = $1
250  AND ues.activity_progress IN ('completed', 'submitted')
251  AND ues.user_id = $2
252  AND ues.deleted_at IS NULL
253GROUP BY chapters.course_module_id;
254        ",
255        course_id,
256        user_id,
257    )
258    .fetch_all(conn)
259    .await?;
260    Ok(res)
261}
262
263pub async fn get_user_course_metrics_indexed_by_module_id(
264    conn: &mut PgConnection,
265    course_id: Uuid,
266    user_id: Uuid,
267) -> ModelResult<HashMap<Uuid, UserCourseMetrics>> {
268    let res = get_user_course_metrics(conn, course_id, user_id)
269        .await?
270        .into_iter()
271        .map(|x| (x.course_module_id, x))
272        .collect();
273    Ok(res)
274}
275
276pub async fn get_user_course_chapter_metrics(
277    conn: &mut PgConnection,
278    course_id: Uuid,
279    exercise_ids: &[Uuid],
280    user_id: Uuid,
281) -> ModelResult<UserChapterMetrics> {
282    let res = sqlx::query_as!(
283        UserChapterMetrics,
284        r#"
285SELECT COUNT(ues.exercise_id) AS attempted_exercises,
286  COALESCE(SUM(ues.score_given), 0) AS score_given
287FROM user_exercise_states AS ues
288WHERE ues.exercise_id IN (
289    SELECT UNNEST($1::uuid [])
290  )
291  AND ues.deleted_at IS NULL
292  AND ues.activity_progress IN ('completed', 'submitted')
293  AND ues.user_id = $2
294  AND ues.course_id = $3;
295                "#,
296        &exercise_ids,
297        user_id,
298        course_id
299    )
300    .fetch_one(conn)
301    .await?;
302    Ok(res)
303}
304
305pub async fn get_user_course_progress(
306    conn: &mut PgConnection,
307    course_id: Uuid,
308    user_id: Uuid,
309) -> ModelResult<Vec<UserCourseProgress>> {
310    let course_metrics = get_course_metrics_indexed_by_module_id(&mut *conn, course_id).await?;
311    let user_metrics =
312        get_user_course_metrics_indexed_by_module_id(conn, course_id, user_id).await?;
313    let course_name = courses::get_course(conn, course_id).await?.name;
314    let course_modules = course_modules::get_by_course_id(conn, course_id).await?;
315    merge_modules_with_metrics(course_modules, &course_metrics, &user_metrics, &course_name)
316}
317
318/// Gets the total amount of points that the user has received from an exam.
319///
320/// The caller should take into consideration that for an ongoing exam the result will be volatile.
321pub async fn get_user_total_exam_points(
322    conn: &mut PgConnection,
323    user_id: Uuid,
324    exam_id: Uuid,
325) -> ModelResult<Option<f32>> {
326    let res = sqlx::query!(
327        r#"
328SELECT SUM(score_given) AS "points"
329FROM user_exercise_states
330WHERE user_id = $2
331  AND exam_id = $1
332  AND deleted_at IS NULL
333        "#,
334        exam_id,
335        user_id,
336    )
337    .map(|x| x.points)
338    .fetch_one(conn)
339    .await?;
340    Ok(res)
341}
342
343fn merge_modules_with_metrics(
344    course_modules: Vec<CourseModule>,
345    course_metrics_by_course_module_id: &HashMap<Uuid, CourseExerciseMetrics>,
346    user_metrics_by_course_module_id: &HashMap<Uuid, UserCourseMetrics>,
347    default_course_module_name_placeholder: &str,
348) -> ModelResult<Vec<UserCourseProgress>> {
349    course_modules
350        .into_iter()
351        .map(|course_module| {
352            let user_metrics = user_metrics_by_course_module_id.get(&course_module.id);
353            let course_metrics = course_metrics_by_course_module_id.get(&course_module.id);
354            let requirements = course_module.completion_policy.automatic();
355            let progress = UserCourseProgress {
356                course_module_id: course_module.id,
357                // Only default course module doesn't have a name.
358                course_module_name: course_module
359                    .name
360                    .unwrap_or_else(|| default_course_module_name_placeholder.to_string()),
361                course_module_order_number: course_module.order_number,
362                score_given: option_f32_to_f32_two_decimals_with_none_as_zero(
363                    user_metrics.and_then(|x| x.score_given),
364                ),
365                score_required: requirements.and_then(|x| x.number_of_points_treshold),
366                score_maximum: course_metrics
367                    .and_then(|x| x.score_maximum)
368                    .map(TryInto::try_into)
369                    .transpose()?,
370                total_exercises: course_metrics
371                    .and_then(|x| x.total_exercises)
372                    .map(TryInto::try_into)
373                    .transpose()?,
374                attempted_exercises: user_metrics
375                    .and_then(|x| x.attempted_exercises)
376                    .map(TryInto::try_into)
377                    .transpose()?,
378                attempted_exercises_required: requirements
379                    .and_then(|x| x.number_of_exercises_attempted_treshold),
380            };
381            Ok(progress)
382        })
383        .collect::<ModelResult<_>>()
384}
385
386pub async fn get_user_course_chapter_exercises_progress(
387    conn: &mut PgConnection,
388    course_id: Uuid,
389    exercise_ids: &[Uuid],
390    user_id: Uuid,
391) -> ModelResult<Vec<DatabaseUserCourseChapterExerciseProgress>> {
392    let res = sqlx::query_as!(
393        DatabaseUserCourseChapterExerciseProgress,
394        r#"
395SELECT COALESCE(ues.score_given, 0) AS score_given,
396  ues.exercise_id AS exercise_id
397FROM user_exercise_states AS ues
398WHERE ues.deleted_at IS NULL
399  AND ues.exercise_id IN (
400    SELECT UNNEST($1::uuid [])
401  )
402  AND ues.course_id = $2
403  AND ues.user_id = $3;
404        "#,
405        exercise_ids,
406        course_id,
407        user_id,
408    )
409    .fetch_all(conn)
410    .await?;
411    Ok(res)
412}
413
414pub async fn get_or_create_user_exercise_state(
415    conn: &mut PgConnection,
416    user_id: Uuid,
417    exercise_id: Uuid,
418    course_id: Option<Uuid>,
419    exam_id: Option<Uuid>,
420) -> ModelResult<UserExerciseState> {
421    let existing = sqlx::query_as!(
422        UserExerciseState,
423        r#"
424SELECT id,
425  user_id,
426  exercise_id,
427  course_id,
428  exam_id,
429  created_at,
430  updated_at,
431  deleted_at,
432  score_given,
433  grading_progress AS "grading_progress: _",
434  activity_progress AS "activity_progress: _",
435  reviewing_stage AS "reviewing_stage: _",
436  selected_exercise_slide_id
437FROM user_exercise_states
438WHERE user_id = $1
439  AND exercise_id = $2
440  AND (course_id = $3 OR exam_id = $4)
441  AND deleted_at IS NULL
442"#,
443        user_id,
444        exercise_id,
445        course_id,
446        exam_id
447    )
448    .fetch_optional(&mut *conn)
449    .await?;
450
451    let res = if let Some(existing) = existing {
452        existing
453    } else {
454        sqlx::query_as!(
455            UserExerciseState,
456            r#"
457    INSERT INTO user_exercise_states (user_id, exercise_id, course_id, exam_id)
458    VALUES ($1, $2, $3, $4)
459    RETURNING id,
460      user_id,
461      exercise_id,
462      course_id,
463      exam_id,
464      created_at,
465      updated_at,
466      deleted_at,
467      score_given,
468      grading_progress as "grading_progress: _",
469      activity_progress as "activity_progress: _",
470      reviewing_stage AS "reviewing_stage: _",
471      selected_exercise_slide_id
472      "#,
473            user_id,
474            exercise_id,
475            course_id,
476            exam_id
477        )
478        .fetch_one(&mut *conn)
479        .await?
480    };
481    Ok(res)
482}
483
484pub async fn get_or_create_user_exercise_state_for_users(
485    conn: &mut PgConnection,
486    user_ids: &[Uuid],
487    exercise_id: Uuid,
488    course_id: Option<Uuid>,
489    exam_id: Option<Uuid>,
490) -> ModelResult<HashMap<Uuid, UserExerciseState>> {
491    let existing = sqlx::query_as!(
492        UserExerciseState,
493        r#"
494SELECT id,
495  user_id,
496  exercise_id,
497  course_id,
498  exam_id,
499  created_at,
500  updated_at,
501  deleted_at,
502  score_given,
503  grading_progress AS "grading_progress: _",
504  activity_progress AS "activity_progress: _",
505  reviewing_stage AS "reviewing_stage: _",
506  selected_exercise_slide_id
507FROM user_exercise_states
508WHERE user_id IN (
509    SELECT UNNEST($1::uuid [])
510  )
511  AND exercise_id = $2
512  AND (course_id = $3 OR exam_id = $4)
513  AND deleted_at IS NULL
514"#,
515        user_ids,
516        exercise_id,
517        course_id,
518        exam_id
519    )
520    .fetch_all(&mut *conn)
521    .await?;
522
523    let mut res = HashMap::with_capacity(user_ids.len());
524    for item in existing.into_iter() {
525        res.insert(item.user_id, item);
526    }
527
528    let missing_user_ids = user_ids
529        .iter()
530        .filter(|user_id| !res.contains_key(user_id))
531        .copied()
532        .collect::<Vec<_>>();
533
534    let created = sqlx::query_as!(
535        UserExerciseState,
536        r#"
537    INSERT INTO user_exercise_states (user_id, exercise_id, course_id, exam_id)
538    SELECT UNNEST($1::uuid []), $2, $3, $4
539    RETURNING id,
540      user_id,
541      exercise_id,
542      course_id,
543      exam_id,
544      created_at,
545      updated_at,
546      deleted_at,
547      score_given,
548      grading_progress as "grading_progress: _",
549      activity_progress as "activity_progress: _",
550      reviewing_stage AS "reviewing_stage: _",
551      selected_exercise_slide_id
552      "#,
553        &missing_user_ids,
554        exercise_id,
555        course_id,
556        exam_id
557    )
558    .fetch_all(&mut *conn)
559    .await?;
560
561    for item in created.into_iter() {
562        res.insert(item.user_id, item);
563    }
564    Ok(res)
565}
566
567pub async fn get_by_id(conn: &mut PgConnection, id: Uuid) -> ModelResult<UserExerciseState> {
568    let res = sqlx::query_as!(
569        UserExerciseState,
570        r#"
571SELECT id,
572  user_id,
573  exercise_id,
574  course_id,
575  exam_id,
576  created_at,
577  updated_at,
578  deleted_at,
579  score_given,
580  grading_progress AS "grading_progress: _",
581  activity_progress AS "activity_progress: _",
582  reviewing_stage AS "reviewing_stage: _",
583  selected_exercise_slide_id
584FROM user_exercise_states
585WHERE id = $1
586  AND deleted_at IS NULL
587        "#,
588        id,
589    )
590    .fetch_one(conn)
591    .await?;
592    Ok(res)
593}
594
595pub async fn get_by_ids(
596    conn: &mut PgConnection,
597    ids: &[Uuid],
598) -> ModelResult<Vec<UserExerciseState>> {
599    let res = sqlx::query_as!(
600        UserExerciseState,
601        r#"
602SELECT id,
603  user_id,
604  exercise_id,
605  course_id,
606  exam_id,
607  created_at,
608  updated_at,
609  deleted_at,
610  score_given,
611  grading_progress AS "grading_progress: _",
612  activity_progress AS "activity_progress: _",
613  reviewing_stage AS "reviewing_stage: _",
614  selected_exercise_slide_id
615FROM user_exercise_states
616WHERE id = ANY($1)
617AND deleted_at IS NULL
618"#,
619        &ids
620    )
621    .fetch_all(conn)
622    .await?;
623    Ok(res)
624}
625
626pub async fn get_user_total_course_points(
627    conn: &mut PgConnection,
628    user_id: Uuid,
629    course_id: Uuid,
630) -> ModelResult<Option<f32>> {
631    let res = sqlx::query!(
632        r#"
633SELECT SUM(score_given) AS "total_points"
634FROM user_exercise_states
635WHERE user_id = $1
636  AND course_id = $2
637  AND deleted_at IS NULL
638  GROUP BY user_id
639        "#,
640        user_id,
641        course_id,
642    )
643    .map(|x| x.total_points)
644    .fetch_one(conn)
645    .await?;
646    Ok(res)
647}
648
649pub async fn get_users_current_by_exercise(
650    conn: &mut PgConnection,
651    user_id: Uuid,
652    exercise: &Exercise,
653) -> ModelResult<UserExerciseState> {
654    let course_or_exam_id =
655        CourseOrExamId::from_course_and_exam_ids(exercise.course_id, exercise.exam_id)?;
656
657    let user_exercise_state =
658        get_user_exercise_state_if_exists(conn, user_id, exercise.id, course_or_exam_id)
659            .await?
660            .ok_or_else(|| {
661                ModelError::new(
662                    ModelErrorType::PreconditionFailed,
663                    "Missing user exercise state.".to_string(),
664                    None,
665                )
666            })?;
667    Ok(user_exercise_state)
668}
669
670pub async fn get_user_exercise_state_if_exists(
671    conn: &mut PgConnection,
672    user_id: Uuid,
673    exercise_id: Uuid,
674    course_or_exam_id: CourseOrExamId,
675) -> ModelResult<Option<UserExerciseState>> {
676    let (course_id, exam_id) = course_or_exam_id.to_course_and_exam_ids();
677    let res = sqlx::query_as!(
678        UserExerciseState,
679        r#"
680SELECT id,
681  user_id,
682  exercise_id,
683  course_id,
684  exam_id,
685  created_at,
686  updated_at,
687  deleted_at,
688  score_given,
689  grading_progress AS "grading_progress: _",
690  activity_progress AS "activity_progress: _",
691  reviewing_stage AS "reviewing_stage: _",
692  selected_exercise_slide_id
693FROM user_exercise_states
694WHERE user_id = $1
695  AND exercise_id = $2
696  AND (course_id = $3 OR exam_id = $4)
697  AND deleted_at IS NULL
698      "#,
699        user_id,
700        exercise_id,
701        course_id,
702        exam_id
703    )
704    .fetch_optional(conn)
705    .await?;
706    Ok(res)
707}
708
709pub async fn get_all_for_user_and_course_or_exam(
710    conn: &mut PgConnection,
711    user_id: Uuid,
712    course_or_exam_id: CourseOrExamId,
713) -> ModelResult<Vec<UserExerciseState>> {
714    let (course_id, exam_id) = course_or_exam_id.to_course_and_exam_ids();
715    let res = sqlx::query_as!(
716        UserExerciseState,
717        r#"
718SELECT id,
719  user_id,
720  exercise_id,
721  course_id,
722  exam_id,
723  created_at,
724  updated_at,
725  deleted_at,
726  score_given,
727  grading_progress AS "grading_progress: _",
728  activity_progress AS "activity_progress: _",
729  reviewing_stage AS "reviewing_stage: _",
730  selected_exercise_slide_id
731FROM user_exercise_states
732WHERE user_id = $1
733  AND (course_id = $2 OR exam_id = $3)
734  AND deleted_at IS NULL
735      "#,
736        user_id,
737        course_id,
738        exam_id
739    )
740    .fetch_all(conn)
741    .await?;
742    Ok(res)
743}
744
745pub async fn upsert_selected_exercise_slide_id(
746    conn: &mut PgConnection,
747    user_id: Uuid,
748    exercise_id: Uuid,
749    course_id: Option<Uuid>,
750    exam_id: Option<Uuid>,
751    selected_exercise_slide_id: Option<Uuid>,
752) -> ModelResult<()> {
753    let existing = sqlx::query!(
754        "
755SELECT
756FROM user_exercise_states
757WHERE user_id = $1
758  AND exercise_id = $2
759  AND (course_id = $3 OR exam_id = $4)
760  AND deleted_at IS NULL
761",
762        user_id,
763        exercise_id,
764        course_id,
765        exam_id
766    )
767    .fetch_optional(&mut *conn)
768    .await?;
769    if existing.is_some() {
770        sqlx::query!(
771            "
772UPDATE user_exercise_states
773SET selected_exercise_slide_id = $4
774WHERE user_id = $1
775  AND exercise_id = $2
776  AND (course_id = $3 OR exam_id = $5)
777  AND deleted_at IS NULL
778    ",
779            user_id,
780            exercise_id,
781            course_id,
782            selected_exercise_slide_id,
783            exam_id
784        )
785        .execute(&mut *conn)
786        .await?;
787    } else {
788        sqlx::query!(
789            "
790    INSERT INTO user_exercise_states (
791        user_id,
792        exercise_id,
793        course_id,
794        selected_exercise_slide_id,
795        exam_id
796      )
797    VALUES ($1, $2, $3, $4, $5)
798    ",
799            user_id,
800            exercise_id,
801            course_id,
802            selected_exercise_slide_id,
803            exam_id
804        )
805        .execute(&mut *conn)
806        .await?;
807    }
808    Ok(())
809}
810
811/// TODO: should be moved to the user_exercise_state_updater as a private module so that this cannot be called outside of that module
812pub async fn update(
813    conn: &mut PgConnection,
814    user_exercise_state_update: UserExerciseStateUpdate,
815) -> ModelResult<UserExerciseState> {
816    let res = sqlx::query_as!(
817        UserExerciseState,
818        r#"
819UPDATE user_exercise_states
820SET score_given = $1,
821  activity_progress = $2,
822  reviewing_stage = $3,
823  grading_progress = $4
824WHERE id = $5
825  AND deleted_at IS NULL
826RETURNING id,
827  user_id,
828  exercise_id,
829  course_id,
830  exam_id,
831  created_at,
832  updated_at,
833  deleted_at,
834  score_given,
835  grading_progress AS "grading_progress: _",
836  activity_progress AS "activity_progress: _",
837  reviewing_stage AS "reviewing_stage: _",
838  selected_exercise_slide_id
839        "#,
840        user_exercise_state_update.score_given,
841        user_exercise_state_update.activity_progress as ActivityProgress,
842        user_exercise_state_update.reviewing_stage as ReviewingStage,
843        user_exercise_state_update.grading_progress as GradingProgress,
844        user_exercise_state_update.id,
845    )
846    .fetch_one(conn)
847    .await?;
848    Ok(res)
849}
850
851pub async fn update_reviewing_stage(
852    conn: &mut PgConnection,
853    user_id: Uuid,
854    course_or_exam_id: CourseOrExamId,
855    exercise_id: Uuid,
856    new_reviewing_stage: ReviewingStage,
857) -> ModelResult<UserExerciseState> {
858    let (course_id, exam_id) = course_or_exam_id.to_course_and_exam_ids();
859    let res = sqlx::query_as!(
860        UserExerciseState,
861        r#"
862UPDATE user_exercise_states
863SET reviewing_stage = $5
864WHERE user_id = $1
865AND (course_id = $2 OR exam_id = $3)
866AND exercise_id = $4
867RETURNING id,
868  user_id,
869  exercise_id,
870  course_id,
871  exam_id,
872  created_at,
873  updated_at,
874  deleted_at,
875  score_given,
876  grading_progress AS "grading_progress: _",
877  activity_progress AS "activity_progress: _",
878  reviewing_stage AS "reviewing_stage: _",
879  selected_exercise_slide_id
880        "#,
881        user_id,
882        course_id,
883        exam_id,
884        exercise_id,
885        new_reviewing_stage as ReviewingStage
886    )
887    .fetch_one(conn)
888    .await?;
889    Ok(res)
890}
891
892/// TODO: should be removed
893pub async fn update_exercise_progress(
894    conn: &mut PgConnection,
895    id: Uuid,
896    reviewing_stage: ReviewingStage,
897) -> ModelResult<UserExerciseState> {
898    let res = sqlx::query_as!(
899        UserExerciseState,
900        r#"
901UPDATE user_exercise_states
902SET reviewing_stage = $1
903WHERE id = $2
904  AND deleted_at IS NULL
905RETURNING id,
906  user_id,
907  exercise_id,
908  course_id,
909  exam_id,
910  created_at,
911  updated_at,
912  deleted_at,
913  score_given,
914  grading_progress AS "grading_progress: _",
915  activity_progress AS "activity_progress: _",
916  reviewing_stage AS "reviewing_stage: _",
917  selected_exercise_slide_id
918        "#,
919        reviewing_stage as ReviewingStage,
920        id
921    )
922    .fetch_one(conn)
923    .await?;
924    Ok(res)
925}
926
927/// Convenience struct that combines user state to the exercise.
928///
929/// Many operations require information about both the user state and the exercise. However, because
930/// exercises can either belong to a course or an exam it can get difficult to track the proper context.
931pub struct ExerciseWithUserState {
932    exercise: Exercise,
933    user_exercise_state: UserExerciseState,
934    type_data: EwusCourseOrExam,
935}
936
937impl ExerciseWithUserState {
938    pub fn new(exercise: Exercise, user_exercise_state: UserExerciseState) -> ModelResult<Self> {
939        let state = EwusCourseOrExam::from_exercise_and_user_exercise_state(
940            &exercise,
941            &user_exercise_state,
942        )?;
943        Ok(Self {
944            exercise,
945            user_exercise_state,
946            type_data: state,
947        })
948    }
949
950    /// Provides a reference to the inner `Exercise`.
951    pub fn exercise(&self) -> &Exercise {
952        &self.exercise
953    }
954
955    /// Provides a reference to the inner `UserExerciseState`.
956    pub fn user_exercise_state(&self) -> &UserExerciseState {
957        &self.user_exercise_state
958    }
959
960    pub fn exercise_context(&self) -> &EwusCourseOrExam {
961        &self.type_data
962    }
963
964    pub fn set_user_exercise_state(
965        &mut self,
966        user_exercise_state: UserExerciseState,
967    ) -> ModelResult<()> {
968        self.type_data = EwusCourseOrExam::from_exercise_and_user_exercise_state(
969            &self.exercise,
970            &user_exercise_state,
971        )?;
972        self.user_exercise_state = user_exercise_state;
973        Ok(())
974    }
975
976    pub fn is_exam_exercise(&self) -> bool {
977        match self.type_data {
978            EwusCourseOrExam::Course(_) => false,
979            EwusCourseOrExam::Exam(_) => true,
980        }
981    }
982}
983
984pub struct EwusCourse {
985    pub course_id: Uuid,
986}
987
988pub struct EwusExam {
989    pub exam_id: Uuid,
990}
991
992pub enum EwusContext<C, E> {
993    Course(C),
994    Exam(E),
995}
996
997pub enum EwusCourseOrExam {
998    Course(EwusCourse),
999    Exam(EwusExam),
1000}
1001
1002impl EwusCourseOrExam {
1003    pub fn from_exercise_and_user_exercise_state(
1004        exercise: &Exercise,
1005        user_exercise_state: &UserExerciseState,
1006    ) -> ModelResult<Self> {
1007        if exercise.id == user_exercise_state.exercise_id {
1008            let course_id = exercise.course_id;
1009            let exam_id = exercise.exam_id;
1010            match (course_id, exam_id) {
1011                (None, Some(exam_id)) => Ok(Self::Exam(EwusExam { exam_id })),
1012                (Some(course_id), None) => Ok(Self::Course(EwusCourse { course_id })),
1013                _ => Err(ModelError::new(
1014                    ModelErrorType::Generic,
1015                    "Invalid initializer data.".to_string(),
1016                    None,
1017                )),
1018            }
1019        } else {
1020            Err(ModelError::new(
1021                ModelErrorType::Generic,
1022                "Exercise doesn't match the state.".to_string(),
1023                None,
1024            ))
1025        }
1026    }
1027}
1028
1029#[derive(Debug, Serialize, Deserialize, PartialEq, Clone)]
1030pub struct CourseUserPoints {
1031    pub user_id: Uuid,
1032    pub points_for_each_chapter: Vec<CourseUserPointsInner>,
1033}
1034
1035#[derive(Debug, Serialize, Deserialize, PartialEq, Clone)]
1036pub struct CourseUserPointsInner {
1037    pub chapter_number: i32,
1038    pub points_for_chapter: f32,
1039}
1040
1041#[derive(Debug, Serialize, Deserialize, PartialEq, Clone)]
1042pub struct ExamUserPoints {
1043    pub user_id: Uuid,
1044    pub email: String,
1045    pub points_for_exercise: Vec<ExamUserPointsInner>,
1046}
1047
1048#[derive(Debug, Serialize, Deserialize, PartialEq, Clone)]
1049pub struct ExamUserPointsInner {
1050    pub exercise_id: Uuid,
1051    pub score_given: f32,
1052}
1053
1054pub fn stream_course_points(
1055    conn: &mut PgConnection,
1056    course_id: Uuid,
1057) -> impl Stream<Item = sqlx::Result<CourseUserPoints>> + '_ {
1058    sqlx::query!(
1059        "
1060SELECT user_id,
1061  to_jsonb(array_agg(to_jsonb(uue) - 'email' - 'user_id')) AS points_for_each_chapter
1062FROM (
1063    SELECT ud.email,
1064      u.id AS user_id,
1065      c.chapter_number,
1066      COALESCE(SUM(ues.score_given), 0) AS points_for_chapter
1067    FROM user_exercise_states ues
1068      JOIN users u ON u.id = ues.user_id
1069      JOIN user_details ud ON ud.user_id = u.id
1070      JOIN exercises e ON e.id = ues.exercise_id
1071      JOIN chapters c on e.chapter_id = c.id
1072    WHERE ues.course_id = $1
1073      AND ues.deleted_at IS NULL
1074      AND c.deleted_at IS NULL
1075      AND u.deleted_at IS NULL
1076      AND e.deleted_at IS NULL
1077    GROUP BY ud.email,
1078      u.id,
1079      c.chapter_number
1080  ) as uue
1081GROUP BY user_id
1082
1083",
1084        course_id
1085    )
1086    .try_map(|i| {
1087        let user_id = i.user_id;
1088        let points_for_each_chapter = i.points_for_each_chapter.unwrap_or(Value::Null);
1089        serde_json::from_value(points_for_each_chapter)
1090            .map(|points_for_each_chapter| CourseUserPoints {
1091                user_id,
1092                points_for_each_chapter,
1093            })
1094            .map_err(|e| sqlx::Error::Decode(Box::new(e)))
1095    })
1096    .fetch(conn)
1097}
1098
1099pub fn stream_exam_points(
1100    conn: &mut PgConnection,
1101    exam_id: Uuid,
1102) -> impl Stream<Item = sqlx::Result<ExamUserPoints>> + '_ {
1103    sqlx::query!(
1104        "
1105SELECT user_id,
1106  email,
1107  to_jsonb(array_agg(to_jsonb(uue) - 'email' - 'user_id')) AS points_for_exercises
1108FROM (
1109    SELECT u.id AS user_id,
1110      ud.email,
1111      exercise_id,
1112      COALESCE(score_given, 0) as score_given
1113    FROM user_exercise_states ues
1114      JOIN users u ON u.id = ues.user_id
1115      JOIN user_details ud ON ud.user_id = u.id
1116      JOIN exercises e ON e.id = ues.exercise_id
1117    WHERE ues.exam_id = $1
1118      AND ues.deleted_at IS NULL
1119      AND u.deleted_at IS NULL
1120      AND e.deleted_at IS NULL
1121  ) as uue
1122GROUP BY user_id,
1123  email
1124",
1125        exam_id
1126    )
1127    .try_map(|i| {
1128        let user_id = i.user_id;
1129        let points_for_exercises = i.points_for_exercises.unwrap_or(Value::Null);
1130        serde_json::from_value(points_for_exercises)
1131            .map(|points_for_exercise| ExamUserPoints {
1132                user_id,
1133                points_for_exercise,
1134                email: i.email,
1135            })
1136            .map_err(|e| sqlx::Error::Decode(Box::new(e)))
1137    })
1138    .fetch(conn)
1139}
1140
1141pub async fn get_course_users_counts_by_exercise(
1142    conn: &mut PgConnection,
1143    course_id: Uuid,
1144) -> ModelResult<Vec<ExerciseUserCounts>> {
1145    let res = sqlx::query_as!(
1146        ExerciseUserCounts,
1147        r#"
1148SELECT exercises.name as exercise_name,
1149  exercises.order_number as exercise_order_number,
1150  pages.order_number as page_order_number,
1151  chapters.chapter_number,
1152  stat_data.*
1153FROM (
1154    SELECT exercise_id,
1155      COUNT(DISTINCT user_id) FILTER (
1156        WHERE ues.activity_progress = 'completed'
1157      ) as n_users_attempted,
1158      COUNT(DISTINCT user_id) FILTER (
1159        WHERE ues.score_given IS NOT NULL
1160          and ues.score_given > 0
1161          AND ues.activity_progress = 'completed'
1162      ) as n_users_with_some_points,
1163      COUNT(DISTINCT user_id) FILTER (
1164        WHERE ues.score_given IS NOT NULL
1165          and ues.score_given >= exercises.score_maximum
1166          and ues.activity_progress = 'completed'
1167      ) as n_users_with_max_points
1168    FROM exercises
1169      JOIN user_exercise_states ues on exercises.id = ues.exercise_id
1170    WHERE exercises.course_id = $1
1171      AND exercises.deleted_at IS NULL
1172      AND ues.deleted_at IS NULL
1173    GROUP BY exercise_id
1174  ) as stat_data
1175  JOIN exercises ON stat_data.exercise_id = exercises.id
1176  JOIN pages on exercises.page_id = pages.id
1177  JOIN chapters on pages.chapter_id = chapters.id
1178WHERE exercises.deleted_at IS NULL
1179  AND pages.deleted_at IS NULL
1180  AND chapters.deleted_at IS NULL
1181          "#,
1182        course_id
1183    )
1184    .fetch_all(conn)
1185    .await?;
1186    Ok(res)
1187}
1188
1189#[derive(Debug, Serialize, Deserialize, PartialEq, Clone)]
1190#[cfg_attr(feature = "ts_rs", derive(TS))]
1191pub struct ExportedUserExerciseState {
1192    pub id: Uuid,
1193    pub user_id: Uuid,
1194    pub exercise_id: Uuid,
1195    pub course_id: Option<Uuid>,
1196    pub created_at: DateTime<Utc>,
1197    pub updated_at: DateTime<Utc>,
1198    pub score_given: Option<f32>,
1199    pub grading_progress: GradingProgress,
1200    pub activity_progress: ActivityProgress,
1201    pub reviewing_stage: ReviewingStage,
1202    pub selected_exercise_slide_id: Option<Uuid>,
1203}
1204
1205pub fn stream_user_exercise_states_for_course<'a>(
1206    conn: &'a mut PgConnection,
1207    course_ids: &'a [Uuid],
1208) -> impl Stream<Item = sqlx::Result<ExportedUserExerciseState>> + 'a {
1209    sqlx::query_as!(
1210        ExportedUserExerciseState,
1211        r#"
1212SELECT id,
1213  user_id,
1214  exercise_id,
1215  course_id,
1216  created_at,
1217  updated_at,
1218  score_given,
1219  grading_progress AS "grading_progress: _",
1220  activity_progress AS "activity_progress: _",
1221  reviewing_stage AS "reviewing_stage: _",
1222  selected_exercise_slide_id
1223FROM user_exercise_states
1224WHERE course_id = ANY($1)
1225  AND deleted_at IS NULL
1226        "#,
1227        course_ids
1228    )
1229    .fetch(conn)
1230}
1231
1232#[cfg(test)]
1233mod tests {
1234    use chrono::TimeZone;
1235
1236    use super::*;
1237    use crate::test_helper::*;
1238
1239    mod getting_single_module_course_metrics {
1240        use super::*;
1241
1242        #[tokio::test]
1243        async fn works_without_any_user_exercise_states() {
1244            insert_data!(:tx, :user, :org, :course, instance: _instance, :course_module);
1245            let res = get_single_module_metrics(tx.as_mut(), course, course_module.id, user).await;
1246            assert!(res.is_ok())
1247        }
1248    }
1249
1250    #[test]
1251    fn merges_course_modules_with_metrics() {
1252        let timestamp = Utc.with_ymd_and_hms(2022, 6, 22, 0, 0, 0).unwrap();
1253        let module_id = Uuid::parse_str("9e831ecc-9751-42f1-ae7e-9b2f06e523e8").unwrap();
1254        let course_modules = vec![
1255            CourseModule::new(
1256                module_id,
1257                Uuid::parse_str("3fa4bee6-7390-415e-968f-ecdc5f28330e").unwrap(),
1258            )
1259            .set_timestamps(timestamp, timestamp, None)
1260            .set_registration_info(None, Some(5.0), None, false),
1261        ];
1262        let course_metrics_by_course_module_id = HashMap::from([(
1263            module_id,
1264            CourseExerciseMetrics {
1265                course_module_id: module_id,
1266                total_exercises: Some(4),
1267                score_maximum: Some(10),
1268            },
1269        )]);
1270        let user_metrics_by_course_module_id = HashMap::from([(
1271            module_id,
1272            UserCourseMetrics {
1273                course_module_id: module_id,
1274                score_given: Some(1.0),
1275                attempted_exercises: Some(3),
1276            },
1277        )]);
1278        let metrics = merge_modules_with_metrics(
1279            course_modules,
1280            &course_metrics_by_course_module_id,
1281            &user_metrics_by_course_module_id,
1282            "Default module",
1283        )
1284        .unwrap();
1285        assert_eq!(metrics.len(), 1);
1286        let metric = metrics.first().unwrap();
1287        assert_eq!(metric.attempted_exercises, Some(3));
1288        assert_eq!(&metric.course_module_name, "Default module");
1289        assert_eq!(metric.score_given, 1.0);
1290        assert_eq!(metric.score_maximum, Some(10));
1291        assert_eq!(metric.total_exercises, Some(4));
1292    }
1293}