Skip to content

Commit

Permalink
Merge pull request #88 from openedx/cag/individual-learner-reports
Browse files Browse the repository at this point in the history
feat: migrate fact_*_engagement reports
  • Loading branch information
bmtcril authored May 9, 2024
2 parents eb3999a + fadaf03 commit b16a795
Show file tree
Hide file tree
Showing 10 changed files with 608 additions and 70 deletions.
36 changes: 36 additions & 0 deletions models/learners/learner_summary.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
with
latest_emission_time as (
select course_key, actor_id, MAX(emission_time) as last_visited
from {{ ref("fact_navigation") }}
group by course_key, actor_id
),
enrollment_status as (
select course_key, actor_id, MAX(emission_time) as max_emission_time
from {{ ref("fact_enrollment_status") }}
group by course_key, actor_id
)
select
fss.org as org,
fss.course_key as course_key,
fss.actor_id as actor_id,
fss.course_name as course_name,
fss.course_run as course_run,
fss.approving_state as approving_state,
fss.enrollment_mode as enrollment_mode,
fss.enrollment_status as enrollment_status,
fss.course_grade as course_grade,
fss.grade_bucket as grade_bucket,
fss.username as username,
fss.name as name,
fss.email as email,
fes.max_emission_time as emission_time,
let.last_visited as last_visited
from {{ ref("fact_student_status") }} fss
left join
enrollment_status fes
on fss.course_key = fes.course_key
and fss.actor_id = fes.actor_id
left join
latest_emission_time let
on fss.course_key = let.course_key
and fss.actor_id = let.actor_id
53 changes: 53 additions & 0 deletions models/learners/schema.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
version: 2

models:
- name: learner_summary
description: Summary of a learner with their grade and enrollment status
columns:
- name: org
data_type: string
description: "The organization that the course belongs to"
- name: course_key
data_type: string
description: "The course key for the course"
- name: actor_id
data_type: string
description: "The xAPI actor identifier"
- name: course_name
data_type: string
description: "The name of the course"
- name: course_run
data_type: string
description: "The course run for the course"
- name: approving_state
data_type: string
description: "The most recent approving state for the learner"
- name: enrollment_mode
data_type: string
description: "The mode of enrollment"
- name: enrollment_status
description: "Whether a learner is actively enrolled in a course"
tests:
- accepted_values:
values: ["registered", "unregistered"]
- name: course_grade
data_type: float64
description: "The most recent grade for the learner"
- name: grade_bucket
data_type: string
description: "A displayable value of grades sorted into 10% buckets. Useful for grouping grades together to show high-level learner performance"
- name: username
data_type: String
description: "The username of the learner"
- name: name
data_type: String
description: "The full name of the learner"
- name: email
data_type: String
description: "The email address of the learner"
- name: emission_time
data_type: DateTime
description: "The timestamp, to the second, of the most recent enrollment action for this learner and course."
- name: last_visited
data_type: DateTime
description: "The timestamp, to the second, of the most recent time the learner visited the course."
97 changes: 97 additions & 0 deletions models/navigation/fact_pageview_engagement.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,97 @@
with
subsection_counts as (
select
org,
course_key,
course_run,
section_with_name,
subsection_with_name,
actor_id,
page_count,
count(distinct block_id) as pages_visited,
case
when pages_visited = 0
then 'No pages viewed yet'
when pages_visited = page_count
then 'All pages viewed'
else 'At least one page viewed'
end as engagement_level
from {{ ref("fact_navigation_completion") }}
group by
org,
course_key,
course_run,
section_with_name,
subsection_with_name,
actor_id,
page_count
),
section_counts as (
select
org,
course_key,
course_run,
section_with_name,
'' as subsection_with_name,
actor_id,
sum(page_count) as page_count,
sum(pages_visited) as pages_visited,
case
when pages_visited = 0
then 'No pages viewed yet'
when pages_visited = page_count
then 'All pages viewed'
else 'At least one page viewed'
end as engagement_level
from subsection_counts
group by
org,
course_key,
course_run,
section_with_name,
subsection_with_name,
actor_id
),
pageview_counts as (
select
org,
course_key,
course_run,
section_with_name as section_with_name,
subsection_with_name as subsection_with_name,
subsection_with_name as section_subsection_name,
'subsection' as content_level,
actor_id as actor_id,
engagement_level as section_subsection_page_engagement
from subsection_counts
union all
select
org,
course_key,
course_run,
section_with_name as section_with_name,
subsection_with_name as subsection_with_name,
section_with_name as section_subsection_name,
'section' as content_level,
actor_id as actor_id,
engagement_level as section_subsection_page_engagement
from section_counts

)

select
pv.org as org,
pv.course_key as course_key,
pv.course_run as course_run,
pv.section_with_name as section_with_name,
pv.subsection_with_name as subsection_with_name,
pv.section_subsection_name as section_subsection_name,
pv.content_level as content_level,
pv.actor_id as actor_id,
pv.section_subsection_page_engagement as section_subsection_page_engagement,
users.username as username,
users.name as name,
users.email as email
from pageview_counts pv
left outer join
{{ ref("dim_user_pii") }} users on toUUID(actor_id) = users.external_user_id
43 changes: 43 additions & 0 deletions models/navigation/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -200,3 +200,46 @@ models:
- name: course_order
data_type: Int32
description: "The sort order of this block in the course across all course blocks"

- name: fact_pageview_engagement
description: "A view for analyzing the number of page views per learner per section and subsection"
columns:
- name: org
data_type: string
description: "The organization that the course belongs to"
- name: course_key
data_type: string
description: "The course identifier"
- name: course_run
data_type: string
description: "The course run for the course"
- name: section_with_name
data_type: string
description: "The name of the section"
- name: subsection_with_name
data_type: string
description: "The name of the subsection"
- name: section_subsection_name
data_type: string
description: "The name of the section or subsection"
- name: content_level
data_type: string
description: "The level at which page views are counted"
tests:
- accepted_values:
values: ["section", "subsection"]
- name: actor_id
data_type: string
description: "The xAPI actor identifier"
- name: section_subsection_page_engagement
data_type: uint64
description: "The total number of times a learner viewed pages in this section or subsection"
- name: username
data_type: String
description: "The username of the learner"
- name: name
data_type: String
description: "The full name of the learner"
- name: email
data_type: String
description: "The email address of the learner"
131 changes: 96 additions & 35 deletions models/problems/fact_problem_engagement.sql
Original file line number Diff line number Diff line change
@@ -1,43 +1,104 @@
with
attempted_subsection_problems as (
select distinct
date(emission_time) as attempted_on,
subsection_counts as (
select
org,
course_key,
course_run,
{{ section_from_display("problem_name_with_location") }} as section_number,
{{ subsection_from_display("problem_name_with_location") }}
as subsection_number,
course_order as course_order,
graded,
section_with_name,
subsection_with_name,
actor_id,
problem_id
from {{ ref("fact_problem_responses") }}
item_count,
count(distinct problem_id) as problems_attempted,
case
when problems_attempted = 0
then 'No problems attempted yet'
when problems_attempted = item_count
then 'All problems attempted'
else 'At least one problem attempted'
end as engagement_level,
username,
name,
email
from {{ ref("fact_problem_engagement_per_subsection") }}
group by
org,
course_key,
course_run,
section_with_name,
subsection_with_name,
actor_id,
item_count,
username,
name,
email
),
section_counts as (
select
org,
course_key,
course_run,
section_with_name,
actor_id,
sum(item_count) as item_count,
sum(problems_attempted) as problems_attempted,
case
when problems_attempted = 0
then 'No problems attempted yet'
when problems_attempted = item_count
then 'All problems attempted'
else 'At least one problem attempted'
end as engagement_level,
username,
name,
email
from subsection_counts
group by
org,
course_key,
course_run,
section_with_name,
actor_id,
username,
name,
email
),
problem_engagement as (
select
org,
course_key,
course_run,
subsection_with_name as section_subsection_name,
'subsection' as content_level,
actor_id as actor_id,
engagement_level as section_subsection_problem_engagement,
username,
name,
email
from subsection_counts
union all
select
org,
course_key,
course_run,
section_with_name as section_subsection_name,
'section' as content_level,
actor_id as actor_id,
engagement_level as section_subsection_problem_engagement,
username,
name,
email
from section_counts
)

select
attempts.attempted_on as attempted_on,
attempts.org as org,
attempts.course_key as course_key,
attempts.course_run as course_run,
problems.section_with_name as section_with_name,
problems.subsection_with_name as subsection_with_name,
problems.item_count as item_count,
attempts.actor_id as actor_id,
attempts.problem_id as problem_id,
attempts.course_order as course_order,
attempts.graded as graded,
users.username as username,
users.name as name,
users.email as email
from attempted_subsection_problems attempts
join
{{ ref("int_problems_per_subsection") }} problems
on (
attempts.org = problems.org
and attempts.course_key = problems.course_key
and attempts.section_number = problems.section_number
and attempts.subsection_number = problems.subsection_number
)
left outer join
{{ ref("dim_user_pii") }} users on toUUID(actor_id) = users.external_user_id
pe.org as org,
pe.course_key as course_key,
pe.course_run as course_run,
pe.section_subsection_name as section_subsection_name,
pe.content_level as content_level,
pe.actor_id as actor_id,
pe.section_subsection_problem_engagement as section_subsection_problem_engagement,
pe.username as username,
pe.name as name,
pe.email as email
from problem_engagement pe
Loading

0 comments on commit b16a795

Please sign in to comment.