diff --git a/CHANGELOG.md b/CHANGELOG.md index 4a5f5d06..dc50abab 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -39,6 +39,13 @@ - Dependencies on `fivetran/fivetran_utils` have been upgraded, previously `[">=0.3.0", "<0.4.0"]` now `[">=0.4.0", "<0.5.0"]`. # dbt_zendesk v0.9.1 + +## Create zendesk__reply_metrics model +- Creates a new end model called `zendesk__reply_metrics` to surface data at the reply granularity, which none of the existing end models do. It is a modified version of the `int_zendesk__ticket_first_reply_time_business` model. +- There are minimal changes to existing models, just including the `user_id` field in the `int_zendesk__ticket_reply_times` model +## Contributiors +- [zhoward101](https://github.com/zhoward101) + ## Bugfix: - If doing a _dbt_compile_ prior to _dbt_run_, it fails at `int_zendesk__calendar_spine` because the staging model it references is not built yet. This PR changes the intermediate models to reference source tables instead of staging models. ([#79](https://github.com/fivetran/dbt_zendesk/pull/79)) ## Contributors diff --git a/README.md b/README.md index 3db0837f..77823a9d 100644 --- a/README.md +++ b/README.md @@ -25,6 +25,7 @@ The following table provides a detailed list of final models materialized within | **model** | **description** | | ---------------------------- | --------------------------------------------------------------------------------------------------------------------------------------------------------------- | +| [zendesk__reply_metrics](https://fivetran.github.io/dbt_zendesk/#!/model/model.zendesk.zendesk__reply_metrics) | Each record represents a communication between an end user and a responding agent, enriched with metrics about reply times. Calendar and business hours are supported. | | [zendesk__ticket_metrics](https://fivetran.github.io/dbt_zendesk/#!/model/model.zendesk.zendesk__ticket_metrics) | Each record represents a Zendesk ticket, enriched with metrics about reply times, resolution times, and work times. Calendar and business hours are supported. | | [zendesk__ticket_enriched](https://fivetran.github.io/dbt_zendesk/#!/model/model.zendesk.zendesk__ticket_enriched) | Each record represents a Zendesk ticket, enriched with data about its tags, assignees, requester, submitter, organization, and group. | | [zendesk__ticket_summary](https://fivetran.github.io/dbt_zendesk/#!/model/model.zendesk.zendesk__ticket_summary) | A single record table containing Zendesk ticket and user summary metrics. | diff --git a/models/reply_times/int_zendesk__comments_enriched.sql b/models/reply_times/int_zendesk__comments_enriched.sql index 34313cf9..cf6a3341 100644 --- a/models/reply_times/int_zendesk__comments_enriched.sql +++ b/models/reply_times/int_zendesk__comments_enriched.sql @@ -14,9 +14,13 @@ with ticket_comment as ( select ticket_comment.*, + commenter.name as commenter_name, + commenter.email as commenter_email, case when commenter.role = 'end-user' then 'external_comment' when commenter.role in ('agent','admin') then 'internal_comment' else 'unknown' end as commenter_role + -- For some reason some of the tickets started with voicemails do not have the voicemail recorded as a public comment? + , (is_public is true or value like 'Voicemail from%') as is_public_comment from ticket_comment @@ -35,7 +39,7 @@ with ticket_comment as ( , 'first_comment') as previous_commenter_role from joined - where is_public + where is_public_comment union all @@ -43,7 +47,7 @@ with ticket_comment as ( *, 'non_public_comment' as previous_commenter_role from joined - where not is_public + where not is_public_comment ) select diff --git a/models/reply_times/int_zendesk__ticket_reply_times.sql b/models/reply_times/int_zendesk__ticket_reply_times.sql index cb6cd720..ac50e364 100644 --- a/models/reply_times/int_zendesk__ticket_reply_times.sql +++ b/models/reply_times/int_zendesk__ticket_reply_times.sql @@ -1,14 +1,19 @@ -with ticket_public_comments as ( +with commenter as ( + + select * from {{ ref('stg_zendesk__user') }} + +), ticket_public_comments as ( select * from {{ ref('int_zendesk__comments_enriched') }} - where is_public + where is_public_comment ), end_user_comments as ( select ticket_id, - valid_starting_at as end_user_comment_created_at, + user_id, + valid_starting_at as comment_created_at, ticket_created_date, commenter_role, previous_internal_comment_count, @@ -24,27 +29,39 @@ with ticket_public_comments as ( end_user_comments.ticket_id, -- If the commentor was internal, a first comment, and had previous non public internal comments 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 is_first_comment then end_user_comments.ticket_created_date else end_user_comments.end_user_comment_created_at end as end_user_comment_created_at, + case when is_first_comment then end_user_comments.ticket_created_date else end_user_comments.comment_created_at end as end_user_comment_created_at, end_user_comments.is_first_comment, + agent_comments.user_id as responding_agent_user_id, min(case when is_first_comment and end_user_comments.commenter_role != 'external_comment' and (end_user_comments.previous_internal_comment_count > 0) - then end_user_comments.end_user_comment_created_at - else agent_comments.valid_starting_at end) as agent_responded_at + then end_user_comments.comment_created_at + else agent_comments.valid_starting_at end) as agent_responded_at, + rank() over (partition by end_user_comments.ticket_id, end_user_comment_created_at order by agent_responded_at asc) as rank + 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.valid_starting_at > end_user_comments.end_user_comment_created_at - group by 1,2,3 + and agent_comments.valid_starting_at > end_user_comments.comment_created_at + group by 1,2,3,4 + +), joined as ( + + select + reply_timestamps.*, + commenter.name as responding_agent_name, + commenter.email as responding_agent_email, + ({{ fivetran_utils.timestamp_diff( + 'end_user_comment_created_at', + 'agent_responded_at', + 'second') }} / 60.0) as reply_time_calendar_minutes + + from reply_timestamps + left join commenter on commenter.user_id = reply_timestamps.responding_agent_user_id + where rank = 1 + order by 1,2 ) - select - *, - ({{ dbt.datediff( - 'end_user_comment_created_at', - 'agent_responded_at', - 'second') }} / 60) as reply_time_calendar_minutes - from reply_timestamps - order by 1,2 \ No newline at end of file + select * from joined \ No newline at end of file diff --git a/models/zendesk.yml b/models/zendesk.yml index 5fc509e0..11221e4d 100644 --- a/models/zendesk.yml +++ b/models/zendesk.yml @@ -547,4 +547,22 @@ models: - name: assignee_name description: The assignee name assigned to the ticket - name: priority - description: The tickets priority ranking \ No newline at end of file + description: The tickets priority ranking + + - name: zendesk__reply_metrics + description: Each record represents an end user comment and the responding agent reply time + columns: + - name: ticket_id + description: A ticket's unique identifier, it is automatically assigned when the ticket is created + - name: end_user_comment_created_at + description: The time the end user created the comment + - name: agent_responded_at + description: Time the agent reponded to that end user comment + - name: responding_agent_name + description: Name of responding agent + - name: responding_agent_email + description: Email of responding agent + - name: reply_time_calendar_minutes + description: Time from end user comment created to agent response in calendar minutes + - name: reply_time_business_minutes + description: Time from end user comment created to agent response in business minutes \ No newline at end of file diff --git a/models/zendesk__reply_metrics.sql b/models/zendesk__reply_metrics.sql new file mode 100644 index 00000000..7937eb2f --- /dev/null +++ b/models/zendesk__reply_metrics.sql @@ -0,0 +1,86 @@ +with ticket_reply_times as ( + + select * from {{ ref('int_zendesk__ticket_reply_times') }} + +), ticket_schedules as ( + + select * from {{ ref('int_zendesk__ticket_schedules') }} + +), schedule as ( + + select * from {{ ref('int_zendesk__schedule_spine') }} + +), replies as ( + + select ticket_reply_times.ticket_id + , ticket_reply_times.end_user_comment_created_at + , ticket_reply_times.agent_responded_at + , ticket_reply_times.responding_agent_name + , ticket_reply_times.responding_agent_email + , ticket_reply_times.reply_time_calendar_minutes + , ticket_schedules.schedule_created_at + , ticket_schedules.schedule_invalidated_at + , ticket_schedules.schedule_id + + , ({{ fivetran_utils.timestamp_diff( + "cast(" ~ dbt_date.week_start('ticket_reply_times.end_user_comment_created_at','UTC') ~ "as " ~ dbt.type_timestamp() ~ ")", + "cast(ticket_reply_times.end_user_comment_created_at as " ~ dbt.type_timestamp() ~ ")", + 'second') }} / 60.0 + ) as start_time_in_minutes_from_week + + from ticket_reply_times + join ticket_schedules on ticket_reply_times.ticket_id = ticket_schedules.ticket_id + group by 1,2,3,4,5,6,7,8,9 + +), weeks as ( + + {{ dbt_utils.generate_series(208) }} + +), weeks_cross_ticket_reply_times 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 replies.* + , generated_number - 1 as week_number + + from replies + cross join weeks + where floor((start_time_in_minutes_from_week + reply_time_calendar_minutes) / (7*24*60)) >= generated_number - 1 + +), weekly_periods as ( + + select weeks_cross_ticket_reply_times.* + , greatest(0, start_time_in_minutes_from_week - week_number * (7*24*60)) as ticket_week_start_time + , least(start_time_in_minutes_from_week + reply_time_calendar_minutes - week_number * (7*24*60), (7*24*60)) as ticket_week_end_time + + from weeks_cross_ticket_reply_times + +), intercepted_periods as ( + + select weekly_periods.* + , 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 + and weekly_periods.schedule_id = schedule.schedule_id + -- this chooses the Daylight Savings Time or Standard Time version of the schedule + and weekly_periods.agent_responded_at >= cast(schedule.valid_from as {{ dbt.type_timestamp() }}) + and weekly_periods.agent_responded_at < cast(schedule.valid_until as {{ dbt.type_timestamp() }}) + +), aggregated as ( + + select ticket_id + , end_user_comment_created_at + , agent_responded_at + , responding_agent_name + , responding_agent_email + , reply_time_calendar_minutes + , sum(scheduled_minutes) as reply_time_business_minutes + + from intercepted_periods + group by 1,2,3,4,5,6 + +) + + select * from aggregated \ No newline at end of file