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

Business hrs cc #13

Open
wants to merge 8 commits into
base: business-hour-calcs
Choose a base branch
from
Open
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
11 changes: 11 additions & 0 deletions biz-hours/data/expected_fct_support_tickets.csv
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
id,calendar_minutes_to_first_response,business_minutes_to_first_response,calendar_minutes_to_first_close,business_minutes_to_first_close,calendar_minutes_to_last_close,business_minutes_to_last_close
263c7e9022713fa39b62ac583fd26701,780,60,5071,1471,5453,1471
af23d77bb2d304f5649da474b81fedeb,1433,713,4620,2460,4620,2460
e8b40b51ae64949c2f3bac987840f042,784,64,8360,2600,8360,2600
793a0185de6dd851e395743c8c84b939,1553,833,4741,2581,4741,2581
f2721518d728f1a359517d1e1d432424,18,18,20,20,1458,738
aa0dfd6e6b3722d485f29cb09e1a2683,14,14,1112,392,1112,392
ee02aaa6e76c087e34211df44b694123,7,7,1848,1128,1848,1128
fc7ee5d4cbb678b7f85de637ff20496d,23,23,4409,809,4409,809
618e94c101c6b0ffd3b0ac887dc9e30b,1,1,,,,
8995d903fb57323dbc6821a0aee9cfa4,26,26,117,117,80621,28781
8 changes: 4 additions & 4 deletions biz-hours/data/sample_tickets.csv
Original file line number Diff line number Diff line change
@@ -1,11 +1,11 @@
id,user_id,state,subject,conversation_created_at_business,first_response_at_business,first_closed_at_business,last_closed_at_business
263c7e9022713fa39b62ac583fd26701,1234,closed,Porridge too hot,2021-03-24 19:29:23.000,2021-03-25 08:29:20.000,2021-01-28 08:00:00.000,2021-01-28 14:22:48.000
id,user_id,state,subject,conversation_created_at,first_response_at,first_closed_at,last_closed_at
263c7e9022713fa39b62ac583fd26701,1234,closed,Porridge too hot,2021-03-24 19:29:23.000,2021-03-25 08:29:20.000,2021-03-28 08:00:00.000,2021-03-28 14:22:48.000
af23d77bb2d304f5649da474b81fedeb,1234,closed,Porridge too cold,2021-01-04 10:01:34.000,2021-01-05 09:54:29.000,2021-01-07 15:01:43.000,2021-01-07 15:01:43.000
e8b40b51ae64949c2f3bac987840f042,1234,closed,Porridge just right!,2021-01-07 19:54:44.000,2021-01-08 08:58:34.000,2021-01-13 15:14:04.000,2021-01-13 15:14:04.000
793a0185de6dd851e395743c8c84b939,1234,closed,Bed too firm,2021-01-04 08:00:00.000,2021-01-05 09:53:02.000,2021-01-07 15:01:57.000,2021-01-07 15:01:57.000
f2721518d728f1a359517d1e1d432424,1234,closed,Bed too soft,2021-02-01 08:00:00.000,2021-02-02 08:18:24.000,2021-02-01 08:20:18.000,2021-02-02 08:18:36.000
f2721518d728f1a359517d1e1d432424,1234,closed,Bed too soft,2021-02-01 08:00:00.000,2021-02-01 08:18:24.000,2021-02-01 08:20:18.000,2021-02-02 08:18:36.000
8995d903fb57323dbc6821a0aee9cfa4,1234,closed,Bed just right! Can I have it?,2021-01-20 13:03:09.000,2021-01-20 13:29:37.000,2021-01-20 15:00:57.000,2021-03-17 12:44:53.000
aa0dfd6e6b3722d485f29cb09e1a2683,1234,closed,Chair is too big,2021-01-28 17:13:50.000,2021-01-28 17:27:10.000,2021-01-29 11:45:36.000,2021-01-29 11:45:36.000
ee02aaa6e76c087e34211df44b694123,1234,closed,Chair is too small,2021-03-17 09:44:29.000,2021-03-17 09:51:07.000,2021-03-18 16:32:07.000,2021-03-18 16:32:07.000
fc7ee5d4cbb678b7f85de637ff20496d,1234,closed,Chair is just right,2021-03-12 14:34:40.000,2021-03-12 14:57:09.000,2021-03-15 16:03:44.000,2021-03-15 16:03:44.000
618e94c101c6b0ffd3b0ac887dc9e30b,5432,open,Someone was in my home,2021-01-27 19:50:06.000,2021-01-27 19:51:38.000,,
618e94c101c6b0ffd3b0ac887dc9e30b,5432,open,Someone was in my home,2021-01-27 19:50:06.000,2021-01-27 19:51:38.000,,
9 changes: 9 additions & 0 deletions biz-hours/data/schema.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
version: 2

seeds:
- name: sample_tickets
tests:
- dbt_utils.expression_is_true:
expression: "last_closed_at >= first_closed_at or last_closed_at is null"
- dbt_utils.expression_is_true:
expression: "first_closed_at >= first_response_at or first_closed_at is null"
16 changes: 8 additions & 8 deletions biz-hours/dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -11,21 +11,21 @@ data-paths: ["data"]
macro-paths: ["macros"]
snapshot-paths: ["snapshots"]

target-path: "target"
clean-targets:
target-path: "target"
clean-targets:
- "target"
- "dbt_modules"

# these variables will need to be in H24 format!
vars:
working_hour_start: 8
working_hour_end: 20


models:
business_hours:
+materialized: view

seeds:
business_hours:
sample_tickets:
Expand All @@ -34,7 +34,7 @@ seeds:
user_id: varchar
state: varchar
subject: varchar
conversation_created_at_business: timestamp_ntz
first_response_at_business: timestamp_ntz
first_closed_at_business: timestamp_ntz
last_closed_at_business: timestamp_ntz
conversation_created_at: timestamp_ntz
first_response_at: timestamp_ntz
first_closed_at: timestamp_ntz
last_closed_at: timestamp_ntz
41 changes: 41 additions & 0 deletions biz-hours/models/business_hours.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
with hours as (
{{ dbt_utils.date_spine(
datepart="hour",
start_date="to_date('01/01/2021', 'mm/dd/yyyy')",
end_date="dateadd(month, 1, current_date)"
)
}}
),

converted_hours as (

select distinct

convert_timezone(
'UTC',
date_hour
)::timestamp_ntz as date_hour

from hours
),

business_hours as (

select

converted_hours.date_hour as date_hour_start,
dateadd('hour', 1, converted_hours.date_hour) as date_hour_end,

-- this logic might change over time to take into account whether the
-- schedule has changed
(
dayofweek(converted_hours.date_hour) not in (0,6)
and hour(converted_hours.date_hour) between 8 and 19
) as is_business_hour

from converted_hours

)

select * from business_hours

43 changes: 32 additions & 11 deletions biz-hours/models/fct_support_tickets.sql
Original file line number Diff line number Diff line change
@@ -1,20 +1,41 @@
with
with

tickets as (
select * from {{ ref('sample_tickets') }}
),

ticket_hours as (
select * from {{ ref('ticket_hours') }}
),

aggregated_ticket_hours as (
select
id,
sum(calendar_minutes_to_first_response) as calendar_minutes_to_first_response,
sum(business_minutes_to_first_response) as business_minutes_to_first_response,
sum(calendar_minutes_to_first_close) as calendar_minutes_to_first_close,
sum(business_minutes_to_first_close) as business_minutes_to_first_close,
sum(calendar_minutes_to_last_close) as calendar_minutes_to_last_close,
sum(business_minutes_to_last_close) as business_minutes_to_last_close

from ticket_hours
group by 1
),

final as (
select

select
tickets.*,
{{ weekdays_between('conversation_created_at_business', 'first_response_at_business') }} as weekdays_to_first_response,
{{ non_business_hours_between('conversation_created_at_business', 'first_response_at_business') }} as non_working_hours,
{{ business_minutes_between('conversation_created_at_business', 'first_response_at_business') }} as business_minutes


from tickets

aggregated_ticket_hours.calendar_minutes_to_first_response,
aggregated_ticket_hours.business_minutes_to_first_response,
aggregated_ticket_hours.calendar_minutes_to_first_close,
aggregated_ticket_hours.business_minutes_to_first_close,
aggregated_ticket_hours.calendar_minutes_to_last_close,
aggregated_ticket_hours.business_minutes_to_last_close

from tickets
left join aggregated_ticket_hours using (id)

)

select * from final
select * from final
74 changes: 74 additions & 0 deletions biz-hours/models/ticket_hours.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
with

tickets as (
select * from {{ ref('sample_tickets') }}
),

business_hours as (
select * from {{ ref('business_hours') }}
),

-- one record per ticket per hour that it is "active"
ticket_hours as (
select
*,

greatest(
datediff(
'minutes',
greatest(business_hours.date_hour_start, tickets.conversation_created_at),
least(business_hours.date_hour_end, tickets.first_response_at)
),
0
) as calendar_minutes_to_first_response,

case
when business_hours.is_business_hour
then calendar_minutes_to_first_response
else 0
end as business_minutes_to_first_response,

greatest(
datediff(
'minutes',
greatest(business_hours.date_hour_start, tickets.conversation_created_at),
least(business_hours.date_hour_end, tickets.first_closed_at)
),
0
) as calendar_minutes_to_first_close,

case
when business_hours.is_business_hour
then calendar_minutes_to_first_close
else 0
end as business_minutes_to_first_close,

greatest(
datediff(
'minutes',
greatest(business_hours.date_hour_start, tickets.conversation_created_at),
least(business_hours.date_hour_end, tickets.last_closed_at)
),
0
) as calendar_minutes_to_last_close,

case
when business_hours.is_business_hour
then calendar_minutes_to_last_close
else 0
end as business_minutes_to_last_close


from tickets

left join business_hours
on date_trunc('hour', tickets.conversation_created_at) <= business_hours.date_hour_start
-- since last_closed_at is null for some tickets, this join ignores them
and (
date_trunc('hour', tickets.last_closed_at) >= business_hours.date_hour_start
or tickets.last_closed_at is null
)
)

select * from ticket_hours

3 changes: 3 additions & 0 deletions biz-hours/packages.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
packages:
- package: fishtown-analytics/dbt_utils
version: 0.6.4