From 3920b802773907979c6564c2ffb927edc32faaa8 Mon Sep 17 00:00:00 2001 From: Vincent Pochet Date: Thu, 18 Jul 2024 14:42:12 +0200 Subject: [PATCH] feat(event): Add pay_in_advance flag in grouped charges view (#2300) ## Context This PR update the `billable_metrics_grouped_charges` view introduced in https://github.com/getlago/lago-api/pull/2231 to allow a better filtering of events related to in advance charges. Today all event having the code of a billable metric related to an in advance charge is sent to the event_worker even if no subscription is attached to it leading to a lot of load on the worker for jobs that will in the end not be charged ## Description This PR will allow us to the update the ingest service so that only event related to an in advance charge on a active subscription are sent to the event worker --- ...le_metrics_grouped_charges_to_version_3.rb | 8 +++ db/schema.rb | 53 ++++++++++--------- .../billable_metrics_grouped_charges_v03.sql | 50 +++++++++++++++++ 3 files changed, 85 insertions(+), 26 deletions(-) create mode 100644 db/migrate/20240718080929_update_billable_metrics_grouped_charges_to_version_3.rb create mode 100644 db/views/billable_metrics_grouped_charges_v03.sql diff --git a/db/migrate/20240718080929_update_billable_metrics_grouped_charges_to_version_3.rb b/db/migrate/20240718080929_update_billable_metrics_grouped_charges_to_version_3.rb new file mode 100644 index 000000000000..3cd03be035e9 --- /dev/null +++ b/db/migrate/20240718080929_update_billable_metrics_grouped_charges_to_version_3.rb @@ -0,0 +1,8 @@ +# frozen_string_literal: true + +class UpdateBillableMetricsGroupedChargesToVersion3 < ActiveRecord::Migration[7.1] + def change + drop_view :billable_metrics_grouped_charges + create_view :billable_metrics_grouped_charges, version: 3 + end +end diff --git a/db/schema.rb b/db/schema.rb index 57d394410b6f..5f0bec76ce14 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -10,7 +10,7 @@ # # It's strongly recommended that you check this file into your version control system. -ActiveRecord::Schema[7.1].define(version: 2024_07_16_154636) do +ActiveRecord::Schema[7.1].define(version: 2024_07_18_080929) do # These are extensions that must be enabled in order to support this database enable_extension "pgcrypto" enable_extension "plpgsql" @@ -1176,31 +1176,6 @@ add_foreign_key "webhook_endpoints", "organizations" add_foreign_key "webhooks", "webhook_endpoints" - create_view "billable_metrics_grouped_charges", sql_definition: <<-SQL - SELECT billable_metrics.organization_id, - billable_metrics.code, - billable_metrics.aggregation_type, - billable_metrics.field_name, - charges.plan_id, - charges.id AS charge_id, - CASE - WHEN (charges.charge_model = 0) THEN (charges.properties -> 'grouped_by'::text) - ELSE NULL::jsonb - END AS grouped_by, - charge_filters.id AS charge_filter_id, - json_object_agg(billable_metric_filters.key, COALESCE(charge_filter_values."values", '{}'::character varying[]) ORDER BY billable_metric_filters.key) FILTER (WHERE (billable_metric_filters.key IS NOT NULL)) AS filters, - CASE - WHEN (charges.charge_model = 0) THEN (charge_filters.properties -> 'grouped_by'::text) - ELSE NULL::jsonb - END AS filters_grouped_by - FROM ((((billable_metrics - JOIN charges ON ((charges.billable_metric_id = billable_metrics.id))) - LEFT JOIN charge_filters ON ((charge_filters.charge_id = charges.id))) - LEFT JOIN charge_filter_values ON ((charge_filter_values.charge_filter_id = charge_filters.id))) - LEFT JOIN billable_metric_filters ON ((charge_filter_values.billable_metric_filter_id = billable_metric_filters.id))) - WHERE ((billable_metrics.deleted_at IS NULL) AND (charges.deleted_at IS NULL) AND (charges.pay_in_advance = false) AND (charge_filters.deleted_at IS NULL) AND (charge_filter_values.deleted_at IS NULL) AND (billable_metric_filters.deleted_at IS NULL)) - GROUP BY billable_metrics.organization_id, billable_metrics.code, billable_metrics.aggregation_type, billable_metrics.field_name, charges.plan_id, charges.id, charge_filters.id; - SQL create_view "last_hour_events_mv", materialized: true, sql_definition: <<-SQL WITH billable_metric_filters AS ( SELECT billable_metrics_1.organization_id AS bm_organization_id, @@ -1227,4 +1202,30 @@ LEFT JOIN billable_metric_filters ON ((billable_metrics.id = billable_metric_filters.bm_id))) WHERE ((events.deleted_at IS NULL) AND (events.created_at >= (date_trunc('hour'::text, now()) - 'PT1H'::interval)) AND (events.created_at < date_trunc('hour'::text, now())) AND (billable_metrics.deleted_at IS NULL)); SQL + create_view "billable_metrics_grouped_charges", sql_definition: <<-SQL + SELECT billable_metrics.organization_id, + billable_metrics.code, + billable_metrics.aggregation_type, + billable_metrics.field_name, + charges.plan_id, + charges.id AS charge_id, + charges.pay_in_advance, + CASE + WHEN (charges.charge_model = 0) THEN (charges.properties -> 'grouped_by'::text) + ELSE NULL::jsonb + END AS grouped_by, + charge_filters.id AS charge_filter_id, + json_object_agg(billable_metric_filters.key, COALESCE(charge_filter_values."values", '{}'::character varying[]) ORDER BY billable_metric_filters.key) FILTER (WHERE (billable_metric_filters.key IS NOT NULL)) AS filters, + CASE + WHEN (charges.charge_model = 0) THEN (charge_filters.properties -> 'grouped_by'::text) + ELSE NULL::jsonb + END AS filters_grouped_by + FROM ((((billable_metrics + JOIN charges ON ((charges.billable_metric_id = billable_metrics.id))) + LEFT JOIN charge_filters ON ((charge_filters.charge_id = charges.id))) + LEFT JOIN charge_filter_values ON ((charge_filter_values.charge_filter_id = charge_filters.id))) + LEFT JOIN billable_metric_filters ON ((charge_filter_values.billable_metric_filter_id = billable_metric_filters.id))) + WHERE ((billable_metrics.deleted_at IS NULL) AND (charges.deleted_at IS NULL) AND (charge_filters.deleted_at IS NULL) AND (charge_filter_values.deleted_at IS NULL) AND (billable_metric_filters.deleted_at IS NULL)) + GROUP BY billable_metrics.organization_id, billable_metrics.code, billable_metrics.aggregation_type, billable_metrics.field_name, charges.plan_id, charges.id, charge_filters.id; + SQL end diff --git a/db/views/billable_metrics_grouped_charges_v03.sql b/db/views/billable_metrics_grouped_charges_v03.sql new file mode 100644 index 000000000000..5962faafb2d2 --- /dev/null +++ b/db/views/billable_metrics_grouped_charges_v03.sql @@ -0,0 +1,50 @@ +select + billable_metrics.organization_id, + billable_metrics.code, + billable_metrics.aggregation_type, + billable_metrics.field_name, + charges.plan_id, + charges.id as charge_id, + charges.pay_in_advance, + ( + case when charges.charge_model = 0 -- Standard + then + charges.properties->'grouped_by' + else + null + end + ) as grouped_by, + charge_filters.id as charge_filter_id, + json_object_agg( + billable_metric_filters.key, + coalesce(charge_filter_values.values, '{}') + order by billable_metric_filters.key asc + ) FILTER (WHERE billable_metric_filters.key IS NOT NULL) AS filters, + ( + case when charges.charge_model = 0 -- Standard + then + charge_filters.properties->'grouped_by' + else + null + end + ) AS filters_grouped_by + +from billable_metrics + inner join charges on charges.billable_metric_id = billable_metrics.id + left join charge_filters on charge_filters.charge_id = charges.id + left join charge_filter_values on charge_filter_values.charge_filter_id = charge_filters.id + left join billable_metric_filters on charge_filter_values.billable_metric_filter_id = billable_metric_filters.id +where + billable_metrics.deleted_at is null + and charges.deleted_at is null + and charge_filters.deleted_at is null + and charge_filter_values.deleted_at is null + and billable_metric_filters.deleted_at is null +group by + billable_metrics.organization_id, + billable_metrics.code, + billable_metrics.aggregation_type, + billable_metrics.field_name, + charges.plan_id, + charges.id, + charge_filters.id