Skip to content

Commit

Permalink
feature/first_reply_time_hours_performance_fix (#152)
Browse files Browse the repository at this point in the history
* feature/first_reply_time_hours_performance_fix

* cleanup adjustments and documentation

* fix for databricks
  • Loading branch information
fivetran-joemarkiewicz authored Apr 30, 2024
1 parent b4b7759 commit 414849d
Show file tree
Hide file tree
Showing 3 changed files with 70 additions and 12 deletions.
3 changes: 2 additions & 1 deletion CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,8 @@
- Fixes the issue of `sla_event_id`'s occurring in the `zendesk__sla_policies` model.
- This involved updating the `int_zendesk__schedule_spine` which was previously outputting overlapping schedule windows, to account for when holidays transcended a given schedule week.
- This also involved updating the `int_zendesk__reply_time_business_hours` model, where within the model two different versions of a schedule would exist due to daylight savings time.

- Adjusted the `int_zendesk__reply_time_business_hours` model to only perform the weeks cartesian join on tickets that require the further look into the future.
- Previously the `int_zendesk__reply_time_business_hours` would perform a cartesian join on all tickets to calculate weeks into the future. This was required to accurately calculate sla elapsed time for tickets with first replies far into the future. However, this was only necessary for a handful of tickets. Therefore, this has been adjusted to accurately only calculate the future weeks as far as either the first reply time or first solved time.

## Documentation Updates
- Addition of the reference to the Fivetran prebuilt [Zendesk Streamlit report](https://fivetran-zendesk.streamlit.app/) in the README.
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,35 @@ with ticket_schedules as (
select *
from {{ ref('int_zendesk__sla_policy_applied') }}

), users as (

select *
from {{ ref('int_zendesk__user_aggregates') }}

), ticket_updates as (

select *
from {{ ref('int_zendesk__updates') }}

), ticket_solved_times as (
select
ticket_id,
valid_starting_at as solved_at
from ticket_updates
where field_name = 'status'
and value in ('solved','closed')

), reply_time as (
select
ticket_comment.ticket_id,
ticket_comment.valid_starting_at as reply_at,
commenter.role
from ticket_updates as ticket_comment
join users as commenter
on commenter.user_id = ticket_comment.user_id
where field_name = 'comment'
and ticket_comment.is_public
and commenter.role in ('agent','admin')

), schedule_business_hours as (

Expand Down Expand Up @@ -48,20 +77,53 @@ with ticket_schedules as (
on ticket_schedules.schedule_id = schedule_business_hours.schedule_id
where sla_policy_applied.in_business_hours
and metric in ('next_reply_time', 'first_reply_time')


), first_reply_solve_times as (
select
ticket_sla_applied_with_schedules.ticket_id,
ticket_sla_applied_with_schedules.ticket_created_at,
ticket_sla_applied_with_schedules.valid_starting_at,
ticket_sla_applied_with_schedules.ticket_current_status,
ticket_sla_applied_with_schedules.metric,
ticket_sla_applied_with_schedules.latest_sla,
ticket_sla_applied_with_schedules.sla_applied_at,
ticket_sla_applied_with_schedules.target,
ticket_sla_applied_with_schedules.in_business_hours,
ticket_sla_applied_with_schedules.sla_policy_name,
ticket_sla_applied_with_schedules.schedule_id,
ticket_sla_applied_with_schedules.start_time_in_minutes_from_week,
ticket_sla_applied_with_schedules.total_schedule_weekly_business_minutes,
ticket_sla_applied_with_schedules.start_week_date,
min(reply_time.reply_at) as first_reply_time,
min(ticket_solved_times.solved_at) as first_solved_time
from ticket_sla_applied_with_schedules
left join reply_time
on reply_time.ticket_id = ticket_sla_applied_with_schedules.ticket_id
and reply_time.reply_at > ticket_sla_applied_with_schedules.sla_applied_at
left join ticket_solved_times
on ticket_sla_applied_with_schedules.ticket_id = ticket_solved_times.ticket_id
and ticket_solved_times.solved_at > ticket_sla_applied_with_schedules.sla_applied_at
{{ dbt_utils.group_by(n=14) }}

), week_index_calc as (
select
*,
{{ dbt.datediff("sla_applied_at", "least(first_reply_time, first_solved_time)", "week") }} + 1 as week_index
from first_reply_solve_times

), weeks as (

{{ dbt_utils.generate_series(52) }}

), weeks_cross_ticket_sla_applied as (
-- because time is reported in minutes since the beginning of the week, we have to split up time spent on the ticket into calendar weeks
select

ticket_sla_applied_with_schedules.*,
cast(generated_number - 1 as {{ dbt.type_int() }}) as week_number
select
week_index_calc.*,
cast(weeks.generated_number - 1 as {{ dbt.type_int() }}) as week_number

from ticket_sla_applied_with_schedules
from week_index_calc
cross join weeks
where week_index >= generated_number - 1

), weekly_periods as (

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -107,11 +107,6 @@ with reply_time_calendar_hours_sla as (
and ticket_solved_times.solved_at > reply_time_breached_at.sla_applied_at
{{ dbt_utils.group_by(n=10) }}

{% if var('using_schedules', True) %}
having (in_business_hours and week_number <= min({{ dbt.datediff("reply_time_breached_at.sla_applied_at", "coalesce(reply_time.reply_at, ticket_solved_times.solved_at, " ~ dbt.current_timestamp() ~ ")", 'week') }}))
or not in_business_hours
{% endif %}

), lagging_time_block as (
select
*,
Expand Down

0 comments on commit 414849d

Please sign in to comment.