From 671d5abee8c50842fd45e6a840e78c1eff817ca7 Mon Sep 17 00:00:00 2001 From: Michael Irvine Date: Sun, 17 Jul 2022 20:40:03 -0400 Subject: [PATCH] trino/snowflake works --- integration_tests/seeds/raw_orders_simple.csv | 3 ++- macros/funnel.sql | 26 ++++++++++++++----- 2 files changed, 21 insertions(+), 8 deletions(-) diff --git a/integration_tests/seeds/raw_orders_simple.csv b/integration_tests/seeds/raw_orders_simple.csv index ab25ba7..30d2b1f 100644 --- a/integration_tests/seeds/raw_orders_simple.csv +++ b/integration_tests/seeds/raw_orders_simple.csv @@ -18,4 +18,5 @@ id,customer_id,order_date,status 17,7,2018-01-18,completed 18,6,2018-01-20,completed 19,5,2018-01-22,returned -20,2,2018-01-23,completed \ No newline at end of file +20,2,2018-01-23,completed +21,3,2018-01-24,returned \ No newline at end of file diff --git a/macros/funnel.sql b/macros/funnel.sql index b40b1c3..85ee30d 100644 --- a/macros/funnel.sql +++ b/macros/funnel.sql @@ -47,15 +47,24 @@ {% macro snowflake__funnel(steps, event_stream) %} with event_stream as ( {% if not (event_stream|string|trim).startswith('select ') %} select * from {% endif %} {{ event_stream }} ) + , steps as ( + {% for step in steps %} + select + '{{ step.event_type }}' as event_type + , {{ loop.index }} as index + {% if not loop.last %} + union all + {% endif %} + {% endfor %} + ) , event_funnel as ( - select event_type, count(*) unique_users + select event_type, count(distinct user_id) as unique_users from event_stream match_recognize( partition by user_id order by event_date - measures event_type as event_type - one row per match - pattern({% for step in steps %} step_{{ loop.index }} {% endfor %} ) + all rows per match + pattern({% for step in steps %} ({% for i in range(loop.length - loop.index + 1) %} step_{{ loop.index }}+{% endfor %}) {% if not loop.last %} | {% endif %} {% endfor %} ) define {% for step in steps %} step_{{ loop.index }} as event_type = '{{ step.event_type }}' {% if not loop.last %} , {% endif %} @@ -65,10 +74,13 @@ ) , final as ( - select event_type - , unique_users, 1.0 * unique_users / nullif(first_value(unique_users) over(), 0) as pct_conversion - , 1.0 * unique_users / nullif(lag(unique_users) over(order by unique_users), 0) as pct_of_previous + select event_funnel.event_type + , unique_users, cast(unique_users as double) / nullif(first_value(unique_users) over(order by steps.index), 0) as pct_conversion + , 1.0 * cast(unique_users as double) / nullif(lag(unique_users) over(order by steps.index), 0) as pct_of_previous from event_funnel + left join steps + on event_funnel.event_type = steps.event_type + order by steps.index ) select * from final