diff --git a/macros/calculate_aggregation_between_preceeding_x_and_y.sql b/macros/calculate_aggregation_between_preceeding_x_and_y.sql index 55153b6..d9199f9 100644 --- a/macros/calculate_aggregation_between_preceeding_x_and_y.sql +++ b/macros/calculate_aggregation_between_preceeding_x_and_y.sql @@ -3,6 +3,8 @@ This macro calculates the aggregation of a metric over a partition of a column, ordered by another column, with a window of x and y preceeding rows. It's designed to be placed within a SELECT statement. + +If include_all_history is True, then X is ignored. */ {% macro calculate_aggregation_between_preceeding_x_and_y( metric, @@ -10,10 +12,18 @@ It's designed to be placed within a SELECT statement. partition_by="id_deal", order_by="date", x=12, - y=1 + y=1, + include_all_history=False ) %} {{ aggregation }} ({{ metric }}) over ( partition by {{ partition_by }} - order by {{ order_by }} rows between {{ x }} preceding and {{ y }} preceding + order by + {{ order_by }} rows between + {% if include_all_history %} + unbounded preceding + {% else %} + {{ x }} preceding + {% endif %} + and {{ y }} preceding ) as {{ aggregation }}_{{ metric }} {% endmacro %} diff --git a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql index 1559470..bff173c 100644 --- a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql +++ b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql @@ -6,6 +6,105 @@ with int_hubspot__deal as ( select * from {{ ref("int_hubspot__deal") }} ), + metric_aggregation_all_history as ( + select + date, + id_deal, + main_deal_name, + main_billing_country_iso_3_per_deal, + deal_lifecycle_state, + 'All History' as time_window, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "date", "min", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "date", "max", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "created_bookings", "sum", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "listings_booked_in_month", "avg", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "total_revenue_in_gbp", "sum", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "total_guest_payments_in_gbp", "sum", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_operator_net_fees_in_gbp", "sum", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_apis_net_fees_in_gbp", "sum", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_waiver_paid_back_to_host_in_gbp", + "sum", + "id_deal", + "date", + "", + 1, + True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_host_resolution_amount_paid_in_gbp", + "sum", + "id_deal", + "date", + "", + 1, + True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_host_resolution_payment_count", + "sum", + "id_deal", + "date", + "", + 1, + True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "revenue_retained_in_gbp", "sum", "id_deal", "date", "", 1, True + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "revenue_retained_post_resolutions_in_gbp", + "sum", + "id_deal", + "date", + "", + 1, + True + ) + }} + from int_monthly_aggregated_metrics_history_by_deal + ), metric_aggregation_previous_12_months as ( select date, @@ -359,6 +458,9 @@ with from int_monthly_aggregated_metrics_history_by_deal ), metric_aggregation_by_deal as ( + select * + from metric_aggregation_all_history + union all select * from metric_aggregation_previous_12_months union all diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index a73694e..460b47a 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1438,6 +1438,7 @@ models: - not_null - accepted_values: values: + - All History - Previous 12 months - Previous 6 months - Previous 3 months diff --git a/models/reporting/exposures.yml b/models/reporting/exposures.yml index ab1298a..9c5bdac 100644 --- a/models/reporting/exposures.yml +++ b/models/reporting/exposures.yml @@ -268,6 +268,26 @@ exposures: name: Oriol Roqué email: oriol.roque@superhog.com + - name: account_managers_margin + label: Account Margin + type: dashboard + maturity: high + url: https://app.powerbi.com/groups/me/apps/bb1a782f-cccc-4427-ab1a-efc207d49b62/reports/a35ab979-71a2-4dad-a0d9-b0ad513f9957/ReportSectionddc493aece54c925670a?experience=power-bi + description: | + A PBI report that shows the revenue, retained revenue after + host takehome payments and after host resolutions payments per + account, within different time windows. + It can help Account Managers to focus on those accounts that are + at different margin levels. It can also benefit Resolution Agents + to better balance generosity on resolutions payments. + + depends_on: + - ref('monthly_aggregated_metrics_history_by_deal_by_time_window') + + owner: + name: Oriol Roqué + email: oriol.roque@superhog.com + - name: guest_kpis label: Guest KPIs type: dashboard diff --git a/models/reporting/general/schema.yml b/models/reporting/general/schema.yml index 2e966e5..ce9d3b3 100644 --- a/models/reporting/general/schema.yml +++ b/models/reporting/general/schema.yml @@ -1406,6 +1406,7 @@ models: - not_null - accepted_values: values: + - All History - Previous 12 months - Previous 6 months - Previous 3 months