Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

WIP performance testing #137

Closed
wants to merge 2 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
16 changes: 16 additions & 0 deletions macros/common_filters.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
{% macro common_filters() -%}
and (
(
{org_filter:String} <> '[]'
and org in cast({org_filter:String}, 'Array(String)')
)
or {org_filter:String} = '[]'
)
and (
(
{course_key_filter:String} <> '[]'
and course_key in cast({course_key_filter:String}, 'Array(String)')
)
or {course_key_filter:String} = '[]'
)
{%- endmacro %}
20 changes: 20 additions & 0 deletions models/grading/at_risk_learners.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
{{
config(
materialized="materialized_view",
engine=get_engine("ReplacingMergeTree()"),
primary_key="(org, course_key, actor_id)",
order_by="(org, course_key, actor_id)",
)
}}

with
page_visits as (
select org, course_key, actor_id, max(emission_time) as last_visited
from {{ ref('fact_learner_last_course_visit') }}
where emission_time < subtractDays(now(), 7)
group by org, course_key, actor_id
)
select org, course_key, learners.actor_id as actor_id
from {{ ref('fact_student_status') }} learners
join page_visits using (org, course_key, actor_id)
where approving_state = 'failed' and enrollment_status = 'registered'
1 change: 1 addition & 0 deletions models/video/fact_video_plays.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,7 @@ with
actor_id
from {{ ref("video_playback_events") }}
where verb_id = 'https://w3id.org/xapi/video/verbs/played'
{{ common_filters() }}
)

select
Expand Down
109 changes: 109 additions & 0 deletions models/video/fact_watched_video_segments.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,109 @@
with
video_events as (
select
emission_time,
org,
course_key,
splitByString('/xblock/', object_id)[-1] as video_id,
object_id,
actor_id,
verb_id,
video_position,
video_duration
from {{ ref('video_playback_events') }}
where 1 = 1 {{ common_filters() }}
),
starts as (
select *
from video_events
where verb_id = 'https://w3id.org/xapi/video/verbs/played'
),
ends as (
select *
from video_events
where
verb_id in (
'http://adlnet.gov/expapi/verbs/completed',
'https://w3id.org/xapi/video/verbs/seeked',
'https://w3id.org/xapi/video/verbs/paused',
'http://adlnet.gov/expapi/verbs/terminated'
)
),
segments as (
select
starts.org as org,
starts.course_key as course_key,
starts.video_id as video_id,
starts.actor_id,
starts.object_id as object_id,
cast(starts.video_position as Int32) as start_position,
cast(ends.video_position as Int32) as end_position,
starts.emission_time as started_at,
ends.emission_time as ended_at,
ends.verb_id as end_type,
starts.video_duration as video_duration
from starts left
asof join
ends
on (
starts.org = ends.org
and starts.course_key = ends.course_key
and starts.video_id = ends.video_id
and starts.actor_id = ends.actor_id
and starts.emission_time < ends.emission_time
)
),
enriched_segments as (
select
segments.org as org,
segments.course_key as course_key,
blocks.course_name as course_name,
blocks.course_run as course_run,
blocks.section_with_name as section_with_name,
blocks.subsection_with_name as subsection_with_name,
blocks.block_name as video_name,
blocks.display_name_with_location as video_name_with_location,
segments.actor_id as actor_id,
segments.object_id as object_id,
segments.started_at as started_at,
segments.start_position - (segments.start_position % 5) as start_position,
segments.end_position - (segments.end_position % 5) as end_position,
segments.video_duration as video_duration,
segments.video_id as video_id
from segments
join
{{ ref('dim_course_blocks_extended') }} blocks
on (
segments.course_key = blocks.course_key
and segments.video_id = blocks.block_id
)
)

select
org,
course_key,
course_name,
course_run,
section_with_name,
subsection_with_name,
video_name,
video_name_with_location,
video_id,
concat(
'<a href="', object_id, '" target="_blank">', video_name_with_location, '</a>'
) as video_link,
actor_id,
started_at,
arrayJoin(range(start_position, end_position, 5)) as segment_start,
video_duration,
CONCAT(toString(segment_start), '-', toString(segment_start + 4)) as segment_range,
start_position,
username,
name,
email
from enriched_segments
left outer join
{{ ref('dim_user_pii') }} users
on (actor_id like 'mailto:%' and SUBSTRING(actor_id, 8) = users.email)
or actor_id = toString(users.external_user_id)
order by segment_start
15 changes: 1 addition & 14 deletions models/video/watched_video_duration.sql
Original file line number Diff line number Diff line change
Expand Up @@ -21,20 +21,7 @@ with
'http://adlnet.gov/expapi/verbs/terminated',
'https://w3id.org/xapi/video/verbs/seeked'
)
and (
(
{org_filter:String} <> '[]'
and org in cast({org_filter:String}, 'Array(String)')
)
or {org_filter:String} = '[]'
)
and (
(
{course_key_filter:String} <> '[]'
and course_key in cast({course_key_filter:String}, 'Array(String)')
)
or {course_key_filter:String} = '[]'
)
{{ common_filters() }}
),
matches as (
select
Expand Down
Loading