Merged PR 2290: Refactor mtd joins to improve performance

Refactor mtd joins to improve performance, as stated in the ticket:

We noticed that some of the new models for MTD purposes (KPIs reporting) take quite a bit of time to run some simple joins.

The main reason is that there's a double join that can be simplified. The current state is:

```
from int_dates_mtd d
        inner join
            sometable t
            on extract(year from t.table_date) = d.year
            and extract(month from t.table_date) = d.month
            and extract(day from t.table_date) <= d.day
```

and it can be changed to:

```
from int_dates_mtd d
        inner join
            sometable t
            ​on date_trunc('month', t.table_date)::date = d.first_day_month
            and extract(day from t.table_date) <= d.day
```

which is way faster, and keeps the same computation

Related work items: #18330
This commit is contained in:
Oriol Roqué Paniagua 2024-07-12 12:53:00 +00:00
parent 2130226939
commit 8a639413f1
3 changed files with 9 additions and 19 deletions

View file

@ -13,8 +13,7 @@ with
from int_dates_mtd d
inner join
int_core__bookings b
on extract(year from b.created_date_utc) = d.year
and extract(month from b.created_date_utc) = d.month
on date_trunc('month', b.created_date_utc)::date = d.first_day_month
and extract(day from b.created_date_utc) <= d.day
group by 1
),
@ -24,8 +23,7 @@ with
from int_dates_mtd d
inner join
int_core__bookings b
on extract(year from b.check_out_date_utc) = d.year
and extract(month from b.check_out_date_utc) = d.month
on date_trunc('month', b.check_out_date_utc)::date = d.first_day_month
and extract(day from b.check_out_date_utc) <= d.day
group by 1
),
@ -36,8 +34,7 @@ with
from int_dates_mtd d
inner join
int_core__bookings b
on extract(year from b.updated_date_utc) = d.year
and extract(month from b.updated_date_utc) = d.month
on date_trunc('month', b.updated_date_utc)::date = d.first_day_month
and extract(day from b.updated_date_utc) <= d.day
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
group by 1

View file

@ -29,8 +29,7 @@ with
from int_dates_mtd d
inner join
int_core__verification_requests vr
on extract(year from vr.created_date_utc) = d.year
and extract(month from vr.created_date_utc) = d.month
on date_trunc('month', vr.created_date_utc)::date = d.first_day_month
and extract(day from vr.created_date_utc) <= d.day
group by 1
),
@ -41,8 +40,7 @@ with
from int_dates_mtd d
inner join
int_core__verification_requests vr
on extract(year from vr.verification_estimated_started_date_utc) = d.year
and extract(month from vr.verification_estimated_started_date_utc) = d.month
on date_trunc('month', vr.verification_estimated_started_date_utc)::date = d.first_day_month
and extract(day from vr.verification_estimated_started_date_utc) <= d.day
group by 1
),
@ -54,9 +52,7 @@ with
from int_dates_mtd d
inner join
int_core__verification_requests vr
on extract(year from vr.verification_estimated_completed_date_utc) = d.year
and extract(month from vr.verification_estimated_completed_date_utc)
= d.month
on date_trunc('month', vr.verification_estimated_completed_date_utc)::date = d.first_day_month
and extract(day from vr.verification_estimated_completed_date_utc) <= d.day
group by 1
),
@ -66,8 +62,7 @@ with
from int_dates_mtd d
inner join
first_payment_per_verification_request p
on extract(year from p.first_payment_paid_date_utc) = d.year
and extract(month from p.first_payment_paid_date_utc) = d.month
on date_trunc('month', p.first_payment_paid_date_utc)::date = d.first_day_month
and extract(day from p.first_payment_paid_date_utc) <= d.day
group by 1
)

View file

@ -34,8 +34,7 @@ with
from int_dates_mtd d
inner join
int_core__verification_payments vp
on extract(year from vp.payment_paid_date_utc) = d.year
and extract(month from vp.payment_paid_date_utc) = d.month
on date_trunc('month', vp.payment_paid_date_utc)::date = d.first_day_month
and extract(day from vp.payment_paid_date_utc) <= d.day
where upper(vp.payment_status) = {{ var("paid_payment_state") }}
group by 1
@ -48,8 +47,7 @@ with
from int_dates_mtd d
inner join
int_xero__credit_notes cn
on extract(year from cn.credit_note_issued_date_utc) = d.year
and extract(month from cn.credit_note_issued_date_utc) = d.month
on date_trunc('month', cn.credit_note_issued_date_utc)::date = d.first_day_month
and extract(day from cn.credit_note_issued_date_utc) <= d.day
inner join
int_xero__credit_note_line_items cnli