From 617259a1ec013d3d623d209a525d9cabca54f10c Mon Sep 17 00:00:00 2001 From: Yevgeniy Date: Fri, 6 May 2016 16:16:57 -0400 Subject: [PATCH 1/2] prelim zendesk models --- analysis/zendesk/avg_hours_to_close.sql | 14 ++++++++ .../zendesk/avg_hours_to_first_response.sql | 35 +++++++++++++++++++ dbt_project.yml | 9 ++--- models/zendesk/zendesk_audits.sql | 5 +++ models/zendesk/zendesk_audits_events.sql | 8 +++++ models/zendesk/zendesk_ticket_audit_info.sql | 9 +++++ models/zendesk/zendesk_tickets.sql | 7 ++++ models/zendesk/zendesk_users.sql | 6 ++++ 8 files changed, 89 insertions(+), 4 deletions(-) create mode 100644 analysis/zendesk/avg_hours_to_close.sql create mode 100644 analysis/zendesk/avg_hours_to_first_response.sql create mode 100644 models/zendesk/zendesk_audits.sql create mode 100644 models/zendesk/zendesk_audits_events.sql create mode 100644 models/zendesk/zendesk_ticket_audit_info.sql create mode 100644 models/zendesk/zendesk_tickets.sql create mode 100644 models/zendesk/zendesk_users.sql diff --git a/analysis/zendesk/avg_hours_to_close.sql b/analysis/zendesk/avg_hours_to_close.sql new file mode 100644 index 0000000..ff50250 --- /dev/null +++ b/analysis/zendesk/avg_hours_to_close.sql @@ -0,0 +1,14 @@ +with ticket_opens_closes as +( + select + ticket_id, ticket_date, date_trunc('week', ticket_date)::date as ticket_week, + datediff(hour, ticket_date, audit_date) as hours_to_close + from {{ref("zendesk_ticket_audit_info")}} + where audit_value = 'closed' +) + +-- find average time to close a ticket +select distinct ticket_week, avg(hours_to_close) avg_hours_to_close +from ticket_opens_closes +group by ticket_week +order by ticket_week \ No newline at end of file diff --git a/analysis/zendesk/avg_hours_to_first_response.sql b/analysis/zendesk/avg_hours_to_first_response.sql new file mode 100644 index 0000000..67e5d33 --- /dev/null +++ b/analysis/zendesk/avg_hours_to_first_response.sql @@ -0,0 +1,35 @@ +with admins_and_agents as +( + select distinct user_id + from {{ref("zendesk_users")}} + where role in ('admin', 'agent') +), + +first_audit_dates as +( + select ticket_id, ticket_date, min(audit_date) as first_audit_date + from {{ref("zendesk_ticket_audit_info")}} + where + -- look at events from admins and agents only + audit_author_id in (select * from admins_and_agents) + -- look at comments only + and audit_type = 'Comment' + -- look at public audits only + and is_audit_public = 1 + group by ticket_id, ticket_date +), + +mins_to_reply as +( + select + ticket_id, ticket_date, date_trunc('week',ticket_date)::date as ticket_week, + datediff(mins, ticket_date, first_audit_date) mins_to_reply + from first_audit_dates +) + +select ticket_week, avg(mins_to_reply)/60.0 avg_hours_to_first_responsea +from mins_to_reply +group by ticket_week +order by ticket_week asc + + diff --git a/dbt_project.yml b/dbt_project.yml index 1ab3d0d..8d462be 100644 --- a/dbt_project.yml +++ b/dbt_project.yml @@ -7,8 +7,9 @@ test-paths: ["test"] model-defaults: materialized: false - enabled: true + enabled: false -#models: -# zuora: -# materialized: true +models: + zendesk: + enabled: true + materialized: false diff --git a/models/zendesk/zendesk_audits.sql b/models/zendesk/zendesk_audits.sql new file mode 100644 index 0000000..d843914 --- /dev/null +++ b/models/zendesk/zendesk_audits.sql @@ -0,0 +1,5 @@ +select + id as audit_id, + ticket_id, + created_at::datetime as audit_date +FROM zendesk_pipeline.audits \ No newline at end of file diff --git a/models/zendesk/zendesk_audits_events.sql b/models/zendesk/zendesk_audits_events.sql new file mode 100644 index 0000000..fae2f4e --- /dev/null +++ b/models/zendesk/zendesk_audits_events.sql @@ -0,0 +1,8 @@ +select + id as event_id, + type as audit_type, + public as is_audit_public, + author_id, + _rjm_source_key_id as audit_id, + value +from zendesk_pipeline.audits__events \ No newline at end of file diff --git a/models/zendesk/zendesk_ticket_audit_info.sql b/models/zendesk/zendesk_ticket_audit_info.sql new file mode 100644 index 0000000..d86b9a1 --- /dev/null +++ b/models/zendesk/zendesk_ticket_audit_info.sql @@ -0,0 +1,9 @@ +select + a.ticket_id, t.ticket_date, a.audit_date, + e.audit_type, e.value as audit_value, + e.is_audit_public, e.author_id as audit_author_id +from {{ref("zendesk_audits")}} a +inner join {{ref("zendesk_audits_events")}} e + on a.audit_id = e.audit_id +inner join {{ref("zendesk_tickets")}} t + on a.ticket_id = t.ticket_id \ No newline at end of file diff --git a/models/zendesk/zendesk_tickets.sql b/models/zendesk/zendesk_tickets.sql new file mode 100644 index 0000000..25220bc --- /dev/null +++ b/models/zendesk/zendesk_tickets.sql @@ -0,0 +1,7 @@ +select + id as ticket_id, + status, + type, + via__channel as channel, + created_at::datetime as ticket_date +from zendesk_pipeline.tickets \ No newline at end of file diff --git a/models/zendesk/zendesk_users.sql b/models/zendesk/zendesk_users.sql new file mode 100644 index 0000000..b0b1b99 --- /dev/null +++ b/models/zendesk/zendesk_users.sql @@ -0,0 +1,6 @@ +select + id as user_id, + name, + email, + role +from zendesk_pipeline.users \ No newline at end of file From d3442c4eba1c8a7b79de0d1aeb20587952adf4a5 Mon Sep 17 00:00:00 2001 From: Yevgeniy Date: Fri, 6 May 2016 16:25:09 -0400 Subject: [PATCH 2/2] zendesk update --- dbt_project.yml | 3 +++ 1 file changed, 3 insertions(+) diff --git a/dbt_project.yml b/dbt_project.yml index 8d462be..1ebff9f 100644 --- a/dbt_project.yml +++ b/dbt_project.yml @@ -1,5 +1,8 @@ #settings specifically for this models directory #config other dbt settings within ~/.dbt/profiles.yml +name: 'ac_zendesk' +version: '1.0' + source-paths: ["models"] target-path: "target" clean-targets: ["target"]