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

reply time updates #50

Merged
merged 3 commits into from
Oct 20, 2021
Merged
Show file tree
Hide file tree
Changes from 2 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
20 changes: 16 additions & 4 deletions models/reply_times/int_zendesk__comments_enriched.sql
Original file line number Diff line number Diff line change
Expand Up @@ -24,17 +24,29 @@ with ticket_comment as (
on commenter.user_id = ticket_comment.user_id

), add_previous_commenter_role as (

/*
In int_zendesk__ticket_reply_times we will only be focusing on reply times between public tickets.
The below union explicitly identifies the previous commentor roles of public and not public comments.
*/
select
*,
coalesce(
lag(commenter_role) over (partition by ticket_id order by valid_starting_at)
, 'first_comment')
as previous_commenter_role,
first_value(valid_starting_at) over (partition by ticket_id order by valid_starting_at desc, ticket_id rows unbounded preceding) as last_comment_added_at
as previous_commenter_role
from joined
where is_public

union all

select
*,
'non_public_comment' as previous_commenter_role
from joined
where not is_public
)

select *
select
*,
first_value(valid_starting_at) over (partition by ticket_id order by valid_starting_at desc, ticket_id rows unbounded preceding) as last_comment_added_at
from add_previous_commenter_role
Original file line number Diff line number Diff line change
Expand Up @@ -75,13 +75,13 @@ with ticket_reply_times as (
), intercepted_periods as (

select ticket_id,
week_number,
weekly_periods.schedule_id,
ticket_week_start_time,
ticket_week_end_time,
schedule.start_time_utc as schedule_start_time,
schedule.end_time_utc as schedule_end_time,
least(ticket_week_end_time, schedule.end_time_utc) - greatest(ticket_week_start_time, schedule.start_time_utc) as scheduled_minutes
week_number,
weekly_periods.schedule_id,
ticket_week_start_time,
ticket_week_end_time,
schedule.start_time_utc as schedule_start_time,
schedule.end_time_utc as schedule_end_time,
least(ticket_week_end_time, schedule.end_time_utc) - greatest(ticket_week_start_time, schedule.start_time_utc) as scheduled_minutes
from weekly_periods
join schedule on ticket_week_start_time <= schedule.end_time_utc
and ticket_week_end_time >= schedule.start_time_utc
Expand Down
26 changes: 20 additions & 6 deletions models/reply_times/int_zendesk__ticket_reply_times.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,21 +9,35 @@ with ticket_public_comments as (
select
ticket_id,
valid_starting_at as end_user_comment_created_at,
ticket_created_date,
commenter_role,
previous_commenter_role = 'first_comment' as is_first_comment
from ticket_public_comments
where commenter_role = 'external_comment'
and ticket_public_comments.previous_commenter_role != 'external_comment' -- we only care about net new end user comments
where (commenter_role = 'external_comment'
and ticket_public_comments.previous_commenter_role != 'external_comment') -- we only care about net new end user comments
or previous_commenter_role = 'first_comment' -- We also want to take into consideration internal first comment replies

), reply_timestamps as (

select
end_user_comments.*,
min(agent_comments.valid_starting_at) as agent_responded_at
end_user_comments.ticket_id,
-- If the commentor was internal and a first comment then we want the ticket created date to be the end user comment created date
-- Otherwise we will want to end user comment created date
case when end_user_comments.commenter_role = 'internal_comment' and end_user_comments.is_first_comment
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Make case when inclusive of all first comments.

Think customer made ticket Friday, no response, commented on Tuesday, response. That should be 2 days not 2 minutes.

then end_user_comments.ticket_created_date
else end_user_comments.end_user_comment_created_at
end as end_user_comment_created_at,
end_user_comments.is_first_comment,
-- If the commentor was internal and is the first comment then we want the end user comment to be the responded at date as this is the date the agent responded following the ticket created date
-- Otherwise we want the agent responded at date
min(case when end_user_comments.commenter_role = 'internal_comment' and end_user_comments.is_first_comment
then end_user_comments.end_user_comment_created_at
else agent_comments.valid_starting_at
end) as agent_responded_at
from end_user_comments
left join ticket_public_comments as agent_comments
on agent_comments.ticket_id = end_user_comments.ticket_id
and agent_comments.commenter_role = 'internal_comment'
and agent_comments.previous_commenter_role != 'first_comment' -- we only care about net new agent comments
and agent_comments.valid_starting_at > end_user_comments.end_user_comment_created_at
group by 1,2,3

Expand All @@ -36,4 +50,4 @@ with ticket_public_comments as (
'agent_responded_at',
'second') }} / 60) as reply_time_calendar_minutes
from reply_timestamps
order by 1,2
order by 1,2
2 changes: 1 addition & 1 deletion models/zendesk__ticket_metrics.sql
Original file line number Diff line number Diff line change
Expand Up @@ -99,7 +99,7 @@ select
ticket_work_time_calendar.requester_wait_time_in_calendar_minutes,
ticket_work_time_calendar.agent_work_time_in_calendar_minutes,
ticket_work_time_calendar.on_hold_time_in_calendar_minutes,
ticket_comments.count_internal_comments as total_agent_replies,
coalesce(ticket_comments.count_agent_comments, 0) as total_agent_replies,

case when ticket_enriched.is_requester_active = true and ticket_enriched.requester_last_login_at is not null
then ({{ dbt_utils.datediff("ticket_enriched.requester_last_login_at", dbt_utils.current_timestamp(), 'second') }} /60)
Expand Down