From 2faa47e7cb2c4bcd00247bcd6a0429fe5cdf6771 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 16 May 2024 18:11:53 +0200 Subject: [PATCH 01/15] staging model for credit notes --- models/staging/xero/_xero_sources.yml | 4 ++ .../staging/xero/stg_xero__credit_notes.sql | 37 +++++++++++++++++++ 2 files changed, 41 insertions(+) create mode 100644 models/staging/xero/stg_xero__credit_notes.sql diff --git a/models/staging/xero/_xero_sources.yml b/models/staging/xero/_xero_sources.yml index eec9672..2d2cf9d 100644 --- a/models/staging/xero/_xero_sources.yml +++ b/models/staging/xero/_xero_sources.yml @@ -15,3 +15,7 @@ sources: identifier: invoices description: | Invoices that we have raised within our accounting books. + - name: credit_notes + identifier: credit_notes + description: | + Credit notes that have been created within our accounting books. diff --git a/models/staging/xero/stg_xero__credit_notes.sql b/models/staging/xero/stg_xero__credit_notes.sql new file mode 100644 index 0000000..bd35342 --- /dev/null +++ b/models/staging/xero/stg_xero__credit_notes.sql @@ -0,0 +1,37 @@ +with + raw_credit_notes as (select * from {{ source("xero", "credit_notes") }}), + stg_xero__credit_notes as ( + select + {{ adapter.quote("CreditNoteID") }} as id_credit_note, + {{ adapter.quote("Reference") }} as reference, + {{ adapter.quote("CreditNoteNumber") }} as credit_note_number, + {{ adapter.quote("Date") }} as credit_note_issued_at_utc, + cast({{ adapter.quote("Date") }} as date) as credit_note_issued_date_utc, + {{ adapter.quote("Type") }} as credit_note_type, + {{ adapter.quote("CurrencyCode") }} as invoice_currency_iso_4217, + 1 / {{ adapter.quote("CurrencyRate") }} as exchange_rate_to_gbp, + {{ adapter.quote("Total") }} as total_amount_local_curr, + {{ adapter.quote("SubTotal") }} as subtotal_local_curr, + {{ adapter.quote("TotalTax") }} as total_tax_local_curr, + {{ adapter.quote("RemainingCredit") }} as remaining_credit_local_curr, + {{ adapter.quote("AppliedAmount") }} as applied_amount, + {{ adapter.quote("Status") }} as credit_note_status, + {{ adapter.quote("Contact") }} as full_contact_details, + {{ adapter.quote("DueDate") }} as credit_note_due_date, + {{ adapter.quote("LineItems") }} as line_items, + {{ adapter.quote("DateString") }} as date_string, + {{ adapter.quote("DueDateString") }} as due_date_string, + {{ adapter.quote("Allocations") }} as allocations, + {{ adapter.quote("SentToContact") }} as has_been_sent_to_contact, + {{ adapter.quote("HasAttachments") }} as has_attachments, + {{ adapter.quote("UpdatedDateUTC") }} as updated_at_utc, + {{ adapter.quote("BrandingThemeID") }} as id_branding_theme, + {{ adapter.quote("FullyPaidOnDate") }} as was_fully_paid_on_date_utc, + {{ adapter.quote("LineAmountTypes") }} as line_amount_tax_inclusiveness, + cast({{ adapter.quote("UpdatedDateUTC") }} as date) as updated_date_utc, + {{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc + + from raw_credit_notes + ) +select * +from stg_xero__credit_notes From 8f6e92c187fe51696ea3d662299d992653fb7c3a Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 16 May 2024 18:21:32 +0200 Subject: [PATCH 02/15] credit notes intermediate model --- .../xero/int_xero__credit_notes.sql | 41 +++++++++++++++++++ 1 file changed, 41 insertions(+) create mode 100644 models/intermediate/xero/int_xero__credit_notes.sql diff --git a/models/intermediate/xero/int_xero__credit_notes.sql b/models/intermediate/xero/int_xero__credit_notes.sql new file mode 100644 index 0000000..e4be166 --- /dev/null +++ b/models/intermediate/xero/int_xero__credit_notes.sql @@ -0,0 +1,41 @@ +with stg_xero__credit_notes as (select * from {{ ref("stg_xero__credit_notes") }}), + +select + id_credit_note, + full_contact_details ->> 'ContactID' as id_contact, + reference, + credit_note_number, + credit_note_issued_at_utc, + credit_note_issued_date_utc, + credit_note_type, + invoice_currency_iso_4217, + exchange_rate_to_gbp, + total_amount_local_curr, + (total_amount_local_curr * exchange_rate_to_gbp)::numeric( + 18, 4 + ) as total_amount_in_gbp, + subtotal_local_curr, + (subtotal_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as subtotal_in_gbp, + total_tax_local_curr, + (total_tax_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as total_tax_in_gbp, + remaining_credit_local_curr, + (remaining_credit_local_curr * exchange_rate_to_gbp)::numeric( + 18, 4 + ) as remaining_credit_in_gbp, + applied_amount, + credit_note_status, + full_contact_details, + credit_note_due_date, + line_items, + date_string, + due_date_string, + allocations, + has_been_sent_to_contact, + has_attachments, + updated_at_utc, + id_branding_theme, + was_fully_paid_on_date_utc, + line_amount_tax_inclusiveness, + updated_date_utc, + dwh_extracted_at_utc +from stg_xero__credit_notes From 791cbd47e8d43b38d92789674f066d7f6ae51842 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Fri, 17 May 2024 11:43:42 +0200 Subject: [PATCH 03/15] more credit note work --- .../xero/int_xero__credit_note_line_items.sql | 69 +++++++++++++++++++ .../xero/int_xero__credit_notes.sql | 4 +- .../staging/xero/stg_xero__credit_notes.sql | 2 +- 3 files changed, 72 insertions(+), 3 deletions(-) create mode 100644 models/intermediate/xero/int_xero__credit_note_line_items.sql diff --git a/models/intermediate/xero/int_xero__credit_note_line_items.sql b/models/intermediate/xero/int_xero__credit_note_line_items.sql new file mode 100644 index 0000000..254fc3b --- /dev/null +++ b/models/intermediate/xero/int_xero__credit_note_line_items.sql @@ -0,0 +1,69 @@ +with int_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}) + +select + cn.id_credit_note, + j.id_line_item, + j.id_item, + j.item_code, + j.quantity::numeric, + j.unit_amount::numeric, + j.line_amount_local_curr::numeric, + (j.line_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric( + 18, 4 + ) as line_amount_in_gbp, + case + when cn.line_amount_tax_inclusiveness = 'Inclusive' + then j.line_amount_local_curr::numeric - j.tax_amount_local_curr::numeric + when cn.line_amount_tax_inclusiveness = 'Exclusive' + then j.line_amount_local_curr::numeric + when cn.line_amount_tax_inclusiveness = 'NoTax' + then j.line_amount_local_curr::numeric + else null + end as line_amount_wo_taxes_local_curr, + case + when cn.line_amount_tax_inclusiveness = 'Inclusive' + then + (j.line_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric( + 18, + 4 + ) - (j.tax_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric( + 18, 4 + ) + when cn.line_amount_tax_inclusiveness = 'Exclusive' + then + (j.line_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric( + 18, 4 + ) + when cn.line_amount_tax_inclusiveness = 'NoTax' + then + (j.line_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric( + 18, 4 + ) + else null + end as line_amount_wo_taxes_in_gbp, + j.tax_amount_local_curr::numeric, + (j.tax_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric( + 18, 4 + ) as tax_amount_in_gbp, + j.tax_type, + cn.credit_note_currency_iso_4217, + j.line_description +from int_xero__credit_notes cn +cross join + lateral( + select + (jsonb_array_elements(cn.line_items) ->> 'LineItemID') as id_line_item, + (jsonb_array_elements(cn.line_items) -> 'Item') ->> 'ItemID' as id_item, + (jsonb_array_elements(cn.line_items) -> 'Item') ->> 'Code' as item_code, + (jsonb_array_elements(cn.line_items) -> 'Item') ->> 'Name' as item_name, + (jsonb_array_elements(cn.line_items) ->> 'Quantity') as quantity, + (jsonb_array_elements(cn.line_items) ->> 'UnitAmount') as unit_amount, + ( + jsonb_array_elements(cn.line_items) ->> 'LineAmount' + ) as line_amount_local_curr, + ( + jsonb_array_elements(cn.line_items) ->> 'TaxAmount' + ) as tax_amount_local_curr, + (jsonb_array_elements(cn.line_items) ->> 'TaxType') as tax_type, + (jsonb_array_elements(cn.line_items) ->> 'Description') as line_description + ) j diff --git a/models/intermediate/xero/int_xero__credit_notes.sql b/models/intermediate/xero/int_xero__credit_notes.sql index e4be166..f21090c 100644 --- a/models/intermediate/xero/int_xero__credit_notes.sql +++ b/models/intermediate/xero/int_xero__credit_notes.sql @@ -1,4 +1,4 @@ -with stg_xero__credit_notes as (select * from {{ ref("stg_xero__credit_notes") }}), +with stg_xero__credit_notes as (select * from {{ ref("stg_xero__credit_notes") }}) select id_credit_note, @@ -8,7 +8,7 @@ select credit_note_issued_at_utc, credit_note_issued_date_utc, credit_note_type, - invoice_currency_iso_4217, + credit_note_currency_iso_4217, exchange_rate_to_gbp, total_amount_local_curr, (total_amount_local_curr * exchange_rate_to_gbp)::numeric( diff --git a/models/staging/xero/stg_xero__credit_notes.sql b/models/staging/xero/stg_xero__credit_notes.sql index bd35342..d3b45a8 100644 --- a/models/staging/xero/stg_xero__credit_notes.sql +++ b/models/staging/xero/stg_xero__credit_notes.sql @@ -8,7 +8,7 @@ with {{ adapter.quote("Date") }} as credit_note_issued_at_utc, cast({{ adapter.quote("Date") }} as date) as credit_note_issued_date_utc, {{ adapter.quote("Type") }} as credit_note_type, - {{ adapter.quote("CurrencyCode") }} as invoice_currency_iso_4217, + {{ adapter.quote("CurrencyCode") }} as credit_note_currency_iso_4217, 1 / {{ adapter.quote("CurrencyRate") }} as exchange_rate_to_gbp, {{ adapter.quote("Total") }} as total_amount_local_curr, {{ adapter.quote("SubTotal") }} as subtotal_local_curr, From fb89652159fa68e6db236a73aeed33b315a58c11 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Fri, 17 May 2024 15:27:58 +0200 Subject: [PATCH 04/15] added credit note reporting models --- .../xero/xero__credit_note_line_items.sql | 22 +++++++++++ models/reporting/xero/xero__credit_notes.sql | 37 +++++++++++++++++++ 2 files changed, 59 insertions(+) create mode 100644 models/reporting/xero/xero__credit_note_line_items.sql create mode 100644 models/reporting/xero/xero__credit_notes.sql diff --git a/models/reporting/xero/xero__credit_note_line_items.sql b/models/reporting/xero/xero__credit_note_line_items.sql new file mode 100644 index 0000000..a05be83 --- /dev/null +++ b/models/reporting/xero/xero__credit_note_line_items.sql @@ -0,0 +1,22 @@ +with + int_xero__credit_note_line_items as ( + select * from {{ ref("int_xero__credit_note_line_items") }} + ) + +select + id_credit_note as id_credit_note, + id_line_item as id_line_item, + id_item as id_item, + item_code as item_code, + quantity as quantity, + unit_amount as unit_amount, + line_amount_local_curr as line_amount_local_curr, + line_amount_in_gbp as line_amount_in_gbp, + line_amount_wo_taxes_local_curr as line_amount_wo_taxes_local_curr, + line_amount_wo_taxes_in_gbp as line_amount_wo_taxes_in_gbp, + tax_amount_local_curr as tax_amount_local_curr, + tax_amount_in_gbp as tax_amount_in_gbp, + tax_type as tax_type, + credit_note_currency_iso_4217 as credit_note_currency_iso_4217, + line_description as line_description +from int_xero__credit_note_line_items li diff --git a/models/reporting/xero/xero__credit_notes.sql b/models/reporting/xero/xero__credit_notes.sql new file mode 100644 index 0000000..d4d0438 --- /dev/null +++ b/models/reporting/xero/xero__credit_notes.sql @@ -0,0 +1,37 @@ +with int_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}) + +select + id_credit_note as id_credit_note, + id_contact as id_contact, + reference as reference, + credit_note_number as credit_note_number, + credit_note_issued_at_utc as credit_note_issued_at_utc, + credit_note_issued_date_utc as credit_note_issued_date_utc, + credit_note_type as credit_note_type, + credit_note_currency_iso_4217 as credit_note_currency_iso_4217, + exchange_rate_to_gbp as exchange_rate_to_gbp, + total_amount_local_curr as total_amount_local_curr, + total_amount_in_gbp as total_amount_in_gbp, + subtotal_local_curr as subtotal_local_curr, + subtotal_in_gbp as subtotal_in_gbp, + total_tax_local_curr as total_tax_local_curr, + total_tax_in_gbp as total_tax_in_gbp, + remaining_credit_local_curr as remaining_credit_local_curr, + remaining_credit_in_gbp as remaining_credit_in_gbp, + applied_amount as applied_amount, + credit_note_status as credit_note_status, + full_contact_details as full_contact_details, + credit_note_due_date as credit_note_due_date, + line_items as line_items, + date_string as date_string, + due_date_string as due_date_string, + allocations as allocations, + has_been_sent_to_contact as has_been_sent_to_contact, + has_attachments as has_attachments, + updated_at_utc as updated_at_utc, + id_branding_theme as id_branding_theme, + was_fully_paid_on_date_utc as was_fully_paid_on_date_utc, + line_amount_tax_inclusiveness as line_amount_tax_inclusiveness, + updated_date_utc as updated_date_utc, + dwh_extracted_at_utc as dwh_extracted_at_utc +from int_xero__credit_notes From 75fe0e510a4e9f88bb97e5ce85d7cb98f618db0c Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Fri, 17 May 2024 15:44:58 +0200 Subject: [PATCH 05/15] kind of done, checkpoint before macro-ing --- models/reporting/xero/fee_model_macro.sql | 59 +++++++++++++++++++ .../reporting/xero/xero__booking_fees_net.sql | 54 +++++++++++++++++ 2 files changed, 113 insertions(+) create mode 100644 models/reporting/xero/fee_model_macro.sql create mode 100644 models/reporting/xero/xero__booking_fees_net.sql diff --git a/models/reporting/xero/fee_model_macro.sql b/models/reporting/xero/fee_model_macro.sql new file mode 100644 index 0000000..2afff48 --- /dev/null +++ b/models/reporting/xero/fee_model_macro.sql @@ -0,0 +1,59 @@ +{% macro generate_xero_net_fees_model(fees_to_include) %} + + {% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %} + + with + xero__invoice_line_items as ( + select * from {{ ref("xero__invoice_line_items") }} + ), + xero__invoices as (select * from {{ ref("xero__invoices") }}), + xero__credit_note_line_items as ( + select * from {{ ref("xero__credit_note_line_items") }} + ), + xero__credit_notes as (select * from {{ ref("xero__credit_notes") }}), + booking_fees_invoiced as ( + select + extract(year from i.invoice_issued_date_utc) as invoice_issued_year, + extract(month from i.invoice_issued_date_utc) as invoice_issued_month, + sum(ili.line_amount_wo_taxes_in_gbp) as fees_invoiced + from xero__invoice_line_items ili + left join xero__invoices i on i.id_invoice = ili.id_invoice + where + i.invoice_status in {{ relevant_document_statuses }} + and ili.item_code in {{ relevant_item_codes }} + group by + extract(year from i.invoice_issued_date_utc), + extract(month from i.invoice_issued_date_utc) + ), + booking_fees_credited as ( + select + extract( + year from cn.credit_note_issued_date_utc + ) as credit_note_issued_year, + extract( + month from cn.credit_note_issued_date_utc + ) as credit_note_issued_month, + sum(cnli.line_amount_wo_taxes_in_gbp) as fees_credited + from reporting.xero__credit_note_line_items cnli + left join + reporting.xero__credit_notes cn + on cn.id_credit_note = cnli.id_credit_note + where + cn.credit_note_status in {{ relevant_document_statuses }} + and cnli.item_code in {{ relevant_item_codes }} + group by + extract(year from cn.credit_note_issued_date_utc), + extract(month from cn.credit_note_issued_date_utc) + ) + select + i.invoice_issued_year as issued_year, + i.invoice_issued_month as issued_month, + coalesce(i.fees_invoiced, 0) as fees_invoiced, + coalesce(c.fees_credited, 0) as fees_credited, + (coalesce(i.fees_invoiced, 0) - coalesce(c.fees_credited, 0)) as net_fees + from booking_fees_invoiced i + left join + booking_fees_credited c + on i.invoice_issued_year = c.credit_note_issued_year + and i.invoice_issued_month = c.credit_note_issued_month + order by i.invoice_issued_year desc, i.invoice_issued_month desc diff --git a/models/reporting/xero/xero__booking_fees_net.sql b/models/reporting/xero/xero__booking_fees_net.sql new file mode 100644 index 0000000..6676354 --- /dev/null +++ b/models/reporting/xero/xero__booking_fees_net.sql @@ -0,0 +1,54 @@ +{% set relevant_item_codes = "('EU Booking Fee','ZAR Bookings','Booking fee - non-UK','USD Bookings','CAD Bookings','Booking fee - UK','AUD Bookings')" %} + +with + xero__invoice_line_items as (select * from {{ ref("xero__invoice_line_items") }}), + xero__invoices as (select * from {{ ref("xero__invoices") }}), + xero__credit_note_line_items as ( + select * from {{ ref("xero__credit_note_line_items") }} + ), + xero__credit_notes as (select * from {{ ref("xero__credit_notes") }}), + booking_fees_invoiced as ( + select + extract(year from i.invoice_issued_date_utc) as invoice_issued_year, + extract(month from i.invoice_issued_date_utc) as invoice_issued_month, + sum(ili.line_amount_wo_taxes_in_gbp) as fees_invoiced + from xero__invoice_line_items ili + left join xero__invoices i on i.id_invoice = ili.id_invoice + where + i.invoice_status in {{ relevant_document_statuses }} + and ili.item_code in {{ relevant_item_codes }} + group by + extract(year from i.invoice_issued_date_utc), + extract(month from i.invoice_issued_date_utc) + ), + booking_fees_credited as ( + select + extract( + year from cn.credit_note_issued_date_utc + ) as credit_note_issued_year, + extract( + month from cn.credit_note_issued_date_utc + ) as credit_note_issued_month, + sum(cnli.line_amount_wo_taxes_in_gbp) as fees_credited + from reporting.xero__credit_note_line_items cnli + left join + reporting.xero__credit_notes cn on cn.id_credit_note = cnli.id_credit_note + where + cn.credit_note_status in {{ relevant_document_statuses }} + and cnli.item_code in {{ relevant_item_codes }} + group by + extract(year from cn.credit_note_issued_date_utc), + extract(month from cn.credit_note_issued_date_utc) + ) +select + i.invoice_issued_year as issued_year, + i.invoice_issued_month as issued_month, + coalesce(i.fees_invoiced, 0) as fees_invoiced, + coalesce(c.fees_credited, 0) as fees_credited, + (coalesce(i.fees_invoiced, 0) - coalesce(c.fees_credited, 0)) as net_fees +from booking_fees_invoiced i +left join + booking_fees_credited c + on i.invoice_issued_year = c.credit_note_issued_year + and i.invoice_issued_month = c.credit_note_issued_month +order by i.invoice_issued_year desc, i.invoice_issued_month desc From 93c2de6f03e65e964ec3c050f638dff0ca9a7d12 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Fri, 17 May 2024 17:54:20 +0200 Subject: [PATCH 06/15] macro logic, need to clean a bit --- .../xero => macros}/fee_model_macro.sql | 9 +-- .../reporting/xero/xero__booking_fees_net.sql | 57 ++----------------- .../reporting/xero/xero__listing_fees_net.sql | 8 +++ .../xero/xero__verification_fees_net.sql | 8 +++ 4 files changed, 26 insertions(+), 56 deletions(-) rename {models/reporting/xero => macros}/fee_model_macro.sql (90%) create mode 100644 models/reporting/xero/xero__listing_fees_net.sql create mode 100644 models/reporting/xero/xero__verification_fees_net.sql diff --git a/models/reporting/xero/fee_model_macro.sql b/macros/fee_model_macro.sql similarity index 90% rename from models/reporting/xero/fee_model_macro.sql rename to macros/fee_model_macro.sql index 2afff48..0c767eb 100644 --- a/models/reporting/xero/fee_model_macro.sql +++ b/macros/fee_model_macro.sql @@ -1,4 +1,4 @@ -{% macro generate_xero_net_fees_model(fees_to_include) %} +{% macro generate_xero_net_fees_model(item_codes_to_include) %} {% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %} @@ -20,7 +20,7 @@ left join xero__invoices i on i.id_invoice = ili.id_invoice where i.invoice_status in {{ relevant_document_statuses }} - and ili.item_code in {{ relevant_item_codes }} + and ili.item_code in {{ item_codes_to_include }} group by extract(year from i.invoice_issued_date_utc), extract(month from i.invoice_issued_date_utc) @@ -40,7 +40,7 @@ on cn.id_credit_note = cnli.id_credit_note where cn.credit_note_status in {{ relevant_document_statuses }} - and cnli.item_code in {{ relevant_item_codes }} + and cnli.item_code in {{ item_codes_to_include }} group by extract(year from cn.credit_note_issued_date_utc), extract(month from cn.credit_note_issued_date_utc) @@ -56,4 +56,5 @@ booking_fees_credited c on i.invoice_issued_year = c.credit_note_issued_year and i.invoice_issued_month = c.credit_note_issued_month - order by i.invoice_issued_year desc, i.invoice_issued_month desc + +{% endmacro %} diff --git a/models/reporting/xero/xero__booking_fees_net.sql b/models/reporting/xero/xero__booking_fees_net.sql index 6676354..94b1239 100644 --- a/models/reporting/xero/xero__booking_fees_net.sql +++ b/models/reporting/xero/xero__booking_fees_net.sql @@ -1,54 +1,7 @@ +-- depends_on: {{ ref('xero__invoice_line_items') }} +-- depends_on: {{ ref('xero__invoices') }} +-- depends_on: {{ ref('xero__credit_note_line_items') }} +-- depends_on: {{ ref('xero__credit_notes') }} {% set relevant_item_codes = "('EU Booking Fee','ZAR Bookings','Booking fee - non-UK','USD Bookings','CAD Bookings','Booking fee - UK','AUD Bookings')" %} -with - xero__invoice_line_items as (select * from {{ ref("xero__invoice_line_items") }}), - xero__invoices as (select * from {{ ref("xero__invoices") }}), - xero__credit_note_line_items as ( - select * from {{ ref("xero__credit_note_line_items") }} - ), - xero__credit_notes as (select * from {{ ref("xero__credit_notes") }}), - booking_fees_invoiced as ( - select - extract(year from i.invoice_issued_date_utc) as invoice_issued_year, - extract(month from i.invoice_issued_date_utc) as invoice_issued_month, - sum(ili.line_amount_wo_taxes_in_gbp) as fees_invoiced - from xero__invoice_line_items ili - left join xero__invoices i on i.id_invoice = ili.id_invoice - where - i.invoice_status in {{ relevant_document_statuses }} - and ili.item_code in {{ relevant_item_codes }} - group by - extract(year from i.invoice_issued_date_utc), - extract(month from i.invoice_issued_date_utc) - ), - booking_fees_credited as ( - select - extract( - year from cn.credit_note_issued_date_utc - ) as credit_note_issued_year, - extract( - month from cn.credit_note_issued_date_utc - ) as credit_note_issued_month, - sum(cnli.line_amount_wo_taxes_in_gbp) as fees_credited - from reporting.xero__credit_note_line_items cnli - left join - reporting.xero__credit_notes cn on cn.id_credit_note = cnli.id_credit_note - where - cn.credit_note_status in {{ relevant_document_statuses }} - and cnli.item_code in {{ relevant_item_codes }} - group by - extract(year from cn.credit_note_issued_date_utc), - extract(month from cn.credit_note_issued_date_utc) - ) -select - i.invoice_issued_year as issued_year, - i.invoice_issued_month as issued_month, - coalesce(i.fees_invoiced, 0) as fees_invoiced, - coalesce(c.fees_credited, 0) as fees_credited, - (coalesce(i.fees_invoiced, 0) - coalesce(c.fees_credited, 0)) as net_fees -from booking_fees_invoiced i -left join - booking_fees_credited c - on i.invoice_issued_year = c.credit_note_issued_year - and i.invoice_issued_month = c.credit_note_issued_month -order by i.invoice_issued_year desc, i.invoice_issued_month desc +{{ generate_xero_net_fees_model(relevant_item_codes) }} diff --git a/models/reporting/xero/xero__listing_fees_net.sql b/models/reporting/xero/xero__listing_fees_net.sql new file mode 100644 index 0000000..c94f874 --- /dev/null +++ b/models/reporting/xero/xero__listing_fees_net.sql @@ -0,0 +1,8 @@ +-- depends_on: {{ ref('xero__invoice_line_items') }} +-- depends_on: {{ ref('xero__invoices') }} +-- depends_on: {{ ref('xero__credit_note_line_items') }} +-- depends_on: {{ ref('xero__credit_notes') }} +{% set relevant_item_codes = "('USD Listings','Listing fee - non UK','ZAR Listings','CAD Listings','Listing fee - UK','AUD Listings','EU Listings')" %} + + +{{ generate_xero_net_fees_model(relevant_item_codes) }} diff --git a/models/reporting/xero/xero__verification_fees_net.sql b/models/reporting/xero/xero__verification_fees_net.sql new file mode 100644 index 0000000..4627e41 --- /dev/null +++ b/models/reporting/xero/xero__verification_fees_net.sql @@ -0,0 +1,8 @@ +-- depends_on: {{ ref('xero__invoice_line_items') }} +-- depends_on: {{ ref('xero__invoices') }} +-- depends_on: {{ ref('xero__credit_note_line_items') }} +-- depends_on: {{ ref('xero__credit_notes') }} +{% set relevant_item_codes = "('Verification Fee')" %} + + +{{ generate_xero_net_fees_model(relevant_item_codes) }} From 319c743cec33c35ea98c40e468bf00de570c82b0 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Wed, 22 May 2024 11:42:42 +0200 Subject: [PATCH 07/15] macros docs --- macros/fee_model_macro.sql | 8 ++++++++ macros/generate_schema_name.sql | 18 +++++++++++------- 2 files changed, 19 insertions(+), 7 deletions(-) diff --git a/macros/fee_model_macro.sql b/macros/fee_model_macro.sql index 0c767eb..db1a295 100644 --- a/macros/fee_model_macro.sql +++ b/macros/fee_model_macro.sql @@ -1,3 +1,11 @@ +/* + +We have different tables computing fees for different line items coming. + +The only difference between these tables is what Xero Line Items are we looking +into. To avoid copying the same logic multiple times, we created this macro. + +*/ {% macro generate_xero_net_fees_model(item_codes_to_include) %} {% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %} diff --git a/macros/generate_schema_name.sql b/macros/generate_schema_name.sql index d9bb818..c32da69 100644 --- a/macros/generate_schema_name.sql +++ b/macros/generate_schema_name.sql @@ -1,14 +1,18 @@ +/* +This macro is necessary to allow different models to automatically be generated +in schemas different than the default one for the target database. + +To understand better, check: +- https://www.youtube.com/watch?v=AvrVQr5FHwk +- https://docs.getdbt.com/docs/build/custom-schemas +*/ {% macro generate_schema_name(custom_schema_name, node) -%} {%- set default_schema = target.schema -%} - {%- if custom_schema_name is none -%} + {%- if custom_schema_name is none -%} {{ default_schema }} - {{ default_schema }} - - {%- else -%} - - {{ custom_schema_name | trim }} + {%- else -%} {{ custom_schema_name | trim }} {%- endif -%} -{%- endmacro %} \ No newline at end of file +{%- endmacro %} From fcb951211d19c19e01b4d25492a9ea7bd76a6ed2 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Wed, 22 May 2024 11:44:59 +0200 Subject: [PATCH 08/15] remove a couple of unnecessary cols --- models/reporting/xero/xero__credit_notes.sql | 2 -- 1 file changed, 2 deletions(-) diff --git a/models/reporting/xero/xero__credit_notes.sql b/models/reporting/xero/xero__credit_notes.sql index d4d0438..c3aba6d 100644 --- a/models/reporting/xero/xero__credit_notes.sql +++ b/models/reporting/xero/xero__credit_notes.sql @@ -20,9 +20,7 @@ select remaining_credit_in_gbp as remaining_credit_in_gbp, applied_amount as applied_amount, credit_note_status as credit_note_status, - full_contact_details as full_contact_details, credit_note_due_date as credit_note_due_date, - line_items as line_items, date_string as date_string, due_date_string as due_date_string, allocations as allocations, From b34da23a94ae931be7e38c7a038f2cd137e52cfa Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Wed, 22 May 2024 11:45:04 +0200 Subject: [PATCH 09/15] update docs --- models/reporting/xero/schema.yaml | 264 ++++++++++++++++++++++++++++++ 1 file changed, 264 insertions(+) diff --git a/models/reporting/xero/schema.yaml b/models/reporting/xero/schema.yaml index 7eb3491..bccdeaf 100644 --- a/models/reporting/xero/schema.yaml +++ b/models/reporting/xero/schema.yaml @@ -850,3 +850,267 @@ models: - name: purchases_tracking_categories data_type: jsonb description: "" + - name: xero__credit_notes + description: | + Credit notes that we have raised within our accounting books. + + A credit note is a document representing a refund or decrease in invoiced + amount to a customer. For clarity, if we make an invoice charging someone + 100$, and we realise afterward that we should have charged him just 75$, + we will solve the situation by creating a credit note for them with 25$. + + Credit notes can be associated to a specific invoice for a customer, or + can be standalone documents. + + The data structure of credit notes it's pretty much identical to that of + invoices, with the way money is owed being the only difference. + + You can read more here: https://developer.xero.com/documentation/api/accounting/creditnotes + + columns: + - name: id_credit_note + data_type: character varying + description: Xero's unique identifier for the credit note. + + - name: id_contact + data_type: text + description: | + The ID of the contact related to this credit note. + + You can use this to join with the contacts table. + + - name: reference + data_type: character varying + description: | + The Superhog-set reference for the credit note. + + - name: credit_note_number + data_type: character varying + description: "" + + - name: credit_note_issued_at_utc + data_type: timestamp with time zone + description: Date on which the credit note was issued. + + - name: credit_note_issued_date_utc + data_type: date + description: The date were the invoice should be paid the latest. + + - name: credit_note_type + data_type: character varying + description: | + Indicates whether the credit note is an Accounts Receivable Credit + Note (ACCRECCREDIT) or an Accounts Payable Credit Note + (ACCPAYCREDIT). + + Most documents in our company will be ACCRECCREDIT, related to our + own customers. + + - name: credit_note_currency_iso_4217 + data_type: character varying + description: | + + The ISO 4217 code for the currency which this credit note uses as + unit of account. + + - name: exchange_rate_to_gbp + data_type: numeric + description: | + The implied exchange rate between the invoice currency and GBP. + + This is the XXX to GBP rate. So the number represented in this field + is the units of currency GBP that 1 unit of XXX buys you. + + For example, if the invoice is 135 ZAR, and this rate is 0.0167, the + invoice value in GBP is 2.25 (135ZAR * 0.0167GBP/ZAR = 2.25GBP). + + - name: total_amount_local_curr + data_type: numeric + description: | + The total amount to be credited, in the currency the note is + denominated in. + + - name: total_amount_in_gbp + data_type: numeric + description: The total amount to be credited, converted to GBP. + + - name: subtotal_local_curr + data_type: numeric + description: | + The total amount to be credited minus taxes, in the currency the + note is denominated in. + + - name: subtotal_in_gbp + data_type: numeric + description: The total amount to be credited minus taxes, in GBP. + + - name: total_tax_local_curr + data_type: numeric + description: | + The total tax, in the currency the credit note is denominated in. + + - name: total_tax_in_gbp + data_type: numeric + description: The total tax, in GBP. + + - name: remaining_credit_local_curr + data_type: numeric + description: "" + + - name: remaining_credit_in_gbp + data_type: numeric + description: "" + + - name: applied_amount + data_type: numeric + description: "" + + - name: credit_note_status + data_type: character varying + description: | + The status of the credit note. + + Can be one of: PAID, VOIDED, DRAFT, DELETED, AUTHORISED, SUBMITTED. + + - name: credit_note_due_date + data_type: timestamp with time zone + description: "" + + - name: date_string + data_type: timestamp with time zone + description: "" + + - name: due_date_string + data_type: timestamp with time zone + description: "" + + - name: allocations + data_type: jsonb + description: "" + + - name: has_been_sent_to_contact + data_type: boolean + description: "" + + - name: has_attachments + data_type: boolean + description: "" + + - name: updated_at_utc + data_type: timestamp with time zone + description: "" + + - name: id_branding_theme + data_type: character varying + description: "" + + - name: was_fully_paid_on_date_utc + data_type: timestamp with time zone + description: "" + + - name: line_amount_tax_inclusiveness + data_type: character varying + description: | + Indicates whether the amounts included in line items are tax + inclusive (Inclusive), tax exclusive (Exclusive) or simply, + there are no taxes on the invoice (NoTax). + + - name: updated_date_utc + data_type: date + description: "" + + - name: dwh_extracted_at_utc + data_type: timestamp with time zone + description: "" + - name: xero__credit_note_line_items + description: | + Credit note line items. Every record corresponds to a Line Item in Xero. + + A Line Item is a combination of a specific service or item being credited, + together with its quantity, price, total amount and taxes. + + You can read more here: https://developer.xero.com/documentation/api/accounting/invoices + + columns: + - name: id_credit_note + data_type: character varying + description: Xero's unique identifier for the credit note. + + - name: id_line_item + data_type: text + description: Xero's unique identifier for the line item. + + - name: id_item + data_type: text + description: Xero's unique identifier for the item of this line. + + - name: item_code + data_type: text + description: A text based code that describes the Item. + + - name: quantity + data_type: numeric + description: How much of the item is credited in this credit note. + + - name: unit_amount + data_type: numeric + description: The price of each unit of the item. + + - name: line_amount_local_curr + data_type: numeric + description: | + The total value to be charged for this line, in local currency. + + - name: line_amount_in_gbp + data_type: numeric + description: The total value to be charged for this line, in GBP. + + - name: line_amount_wo_taxes_local_curr + data_type: numeric + description: | + The total value to be charged for this line, minus taxes, in local + currency. + + In some cases, this will be the same value as the line amount. This + depends on whether there is any tax in the credit note, and whether + the credit note amounts are tax inclusive or tax exclusive. You can + find this out in the details of the credit note this line item belongs + to. + + - name: line_amount_wo_taxes_in_gbp + data_type: numeric + description: | + The total value to be charged for this line, minus taxes, in GBP. + + In some cases, this will be the same value as the line amount. This + depends on whether there is any tax in the credit note, and whether + the credit note amounts are tax inclusive or tax exclusive. You can + find this out in the details of the credit note this line item belongs + to. + + - name: tax_amount_local_curr + data_type: numeric + description: The total value of taxes for this line, in local currency. + + - name: tax_amount_in_gbp + data_type: numeric + description: The total value of taxes for this line, in GBP. + + - name: tax_type + data_type: text + description: "" + + - name: credit note_currency_iso_4217 + data_type: character varying + description: | + The currency in which this line item amounts are defined. + + Line items don't really have a currency definition of its own, this + field is populated for your convenience when working with this data. + The credit note currency is defined at the credit note level, and the + values you see in this field should always be the same as the currency + of the credit note this line item belongs to. + + - name: line_description + data_type: text + description: A text description of the line item. From b0528ec2c030b1ce6449f8c57ce9ef14b07946f0 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 23 May 2024 15:22:42 +0200 Subject: [PATCH 10/15] switch to a single model with a case, docs for it --- macros/fee_model_macro.sql | 68 ------------ models/reporting/xero/schema.yaml | 44 +++++++- .../reporting/xero/xero__booking_fees_net.sql | 7 -- .../reporting/xero/xero__listing_fees_net.sql | 8 -- models/reporting/xero/xero__net_fees.sql | 102 ++++++++++++++++++ .../xero/xero__verification_fees_net.sql | 8 -- 6 files changed, 145 insertions(+), 92 deletions(-) delete mode 100644 macros/fee_model_macro.sql delete mode 100644 models/reporting/xero/xero__booking_fees_net.sql delete mode 100644 models/reporting/xero/xero__listing_fees_net.sql create mode 100644 models/reporting/xero/xero__net_fees.sql delete mode 100644 models/reporting/xero/xero__verification_fees_net.sql diff --git a/macros/fee_model_macro.sql b/macros/fee_model_macro.sql deleted file mode 100644 index db1a295..0000000 --- a/macros/fee_model_macro.sql +++ /dev/null @@ -1,68 +0,0 @@ -/* - -We have different tables computing fees for different line items coming. - -The only difference between these tables is what Xero Line Items are we looking -into. To avoid copying the same logic multiple times, we created this macro. - -*/ -{% macro generate_xero_net_fees_model(item_codes_to_include) %} - - {% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %} - - with - xero__invoice_line_items as ( - select * from {{ ref("xero__invoice_line_items") }} - ), - xero__invoices as (select * from {{ ref("xero__invoices") }}), - xero__credit_note_line_items as ( - select * from {{ ref("xero__credit_note_line_items") }} - ), - xero__credit_notes as (select * from {{ ref("xero__credit_notes") }}), - booking_fees_invoiced as ( - select - extract(year from i.invoice_issued_date_utc) as invoice_issued_year, - extract(month from i.invoice_issued_date_utc) as invoice_issued_month, - sum(ili.line_amount_wo_taxes_in_gbp) as fees_invoiced - from xero__invoice_line_items ili - left join xero__invoices i on i.id_invoice = ili.id_invoice - where - i.invoice_status in {{ relevant_document_statuses }} - and ili.item_code in {{ item_codes_to_include }} - group by - extract(year from i.invoice_issued_date_utc), - extract(month from i.invoice_issued_date_utc) - ), - booking_fees_credited as ( - select - extract( - year from cn.credit_note_issued_date_utc - ) as credit_note_issued_year, - extract( - month from cn.credit_note_issued_date_utc - ) as credit_note_issued_month, - sum(cnli.line_amount_wo_taxes_in_gbp) as fees_credited - from reporting.xero__credit_note_line_items cnli - left join - reporting.xero__credit_notes cn - on cn.id_credit_note = cnli.id_credit_note - where - cn.credit_note_status in {{ relevant_document_statuses }} - and cnli.item_code in {{ item_codes_to_include }} - group by - extract(year from cn.credit_note_issued_date_utc), - extract(month from cn.credit_note_issued_date_utc) - ) - select - i.invoice_issued_year as issued_year, - i.invoice_issued_month as issued_month, - coalesce(i.fees_invoiced, 0) as fees_invoiced, - coalesce(c.fees_credited, 0) as fees_credited, - (coalesce(i.fees_invoiced, 0) - coalesce(c.fees_credited, 0)) as net_fees - from booking_fees_invoiced i - left join - booking_fees_credited c - on i.invoice_issued_year = c.credit_note_issued_year - and i.invoice_issued_month = c.credit_note_issued_month - -{% endmacro %} diff --git a/models/reporting/xero/schema.yaml b/models/reporting/xero/schema.yaml index bccdeaf..a0d92c0 100644 --- a/models/reporting/xero/schema.yaml +++ b/models/reporting/xero/schema.yaml @@ -1100,7 +1100,7 @@ models: data_type: text description: "" - - name: credit note_currency_iso_4217 + - name: credit_note_currency_iso_4217 data_type: character varying description: | The currency in which this line item amounts are defined. @@ -1114,3 +1114,45 @@ models: - name: line_description data_type: text description: A text description of the line item. + - name: xero__net_fees + description: | + A summary aggregation table showing the total raw and net fees by month + and year. + + Information comes from both Invoices and Credit notes. + + Only documents in statuses ('PAID', 'AUTHORISED') are kept. + + Net fees get computed by subtracting credited amounts from invoiced + amounts. + + columns: + - name: issued_year + data_type: numeric + description: The issuing year of the aggregated documents. + + - name: issued_month + data_type: numeric + description: The issuing month of the aggregated documents. + + - name: fee_category + data_type: text + description: | + A fee category, one of out of booking_fees, listing_fees, + verification_fees. + + - name: fees_invoiced_in_gbp + data_type: numeric + description: The total sum of invoiced fees. + + - name: fees_credited_in_gbp + data_type: numeric + description: The total sum of credited fees. + + - name: net_fees_in_gbp + data_type: numeric + description: | + Net fees are calculated by subtracting credited fees from invoiced + fees. It might be the case that net fees are negative in some month, + if it happens to be that we have given back to customers more than we + have invoiced them. diff --git a/models/reporting/xero/xero__booking_fees_net.sql b/models/reporting/xero/xero__booking_fees_net.sql deleted file mode 100644 index 94b1239..0000000 --- a/models/reporting/xero/xero__booking_fees_net.sql +++ /dev/null @@ -1,7 +0,0 @@ --- depends_on: {{ ref('xero__invoice_line_items') }} --- depends_on: {{ ref('xero__invoices') }} --- depends_on: {{ ref('xero__credit_note_line_items') }} --- depends_on: {{ ref('xero__credit_notes') }} -{% set relevant_item_codes = "('EU Booking Fee','ZAR Bookings','Booking fee - non-UK','USD Bookings','CAD Bookings','Booking fee - UK','AUD Bookings')" %} - -{{ generate_xero_net_fees_model(relevant_item_codes) }} diff --git a/models/reporting/xero/xero__listing_fees_net.sql b/models/reporting/xero/xero__listing_fees_net.sql deleted file mode 100644 index c94f874..0000000 --- a/models/reporting/xero/xero__listing_fees_net.sql +++ /dev/null @@ -1,8 +0,0 @@ --- depends_on: {{ ref('xero__invoice_line_items') }} --- depends_on: {{ ref('xero__invoices') }} --- depends_on: {{ ref('xero__credit_note_line_items') }} --- depends_on: {{ ref('xero__credit_notes') }} -{% set relevant_item_codes = "('USD Listings','Listing fee - non UK','ZAR Listings','CAD Listings','Listing fee - UK','AUD Listings','EU Listings')" %} - - -{{ generate_xero_net_fees_model(relevant_item_codes) }} diff --git a/models/reporting/xero/xero__net_fees.sql b/models/reporting/xero/xero__net_fees.sql new file mode 100644 index 0000000..b4b6097 --- /dev/null +++ b/models/reporting/xero/xero__net_fees.sql @@ -0,0 +1,102 @@ +{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %} +{% set booking_fee_items = "('EU Booking Fee','ZAR Bookings','Booking fee - non-UK','USD Bookings','CAD Bookings','Booking fee - UK','AUD Bookings')" %} +{% set listing_fee_items = "('USD Listings','Listing fee - non UK','ZAR Listings','CAD Listings','Listing fee - UK','AUD Listings','EU Listings')" %} +{% set verification_fee_items = "('Verification Fee')" %} + +with + xero__invoice_line_items as (select * from {{ ref("xero__invoice_line_items") }}), + xero__invoices as (select * from {{ ref("xero__invoices") }}), + xero__credit_note_line_items as ( + select * from {{ ref("xero__credit_note_line_items") }} + ), + xero__credit_notes as (select * from {{ ref("xero__credit_notes") }}), + fees_invoiced as ( + select + extract(year from i.invoice_issued_date_utc) as invoice_issued_year, + extract(month from i.invoice_issued_date_utc) as invoice_issued_month, + case + when ili.item_code in {{ booking_fee_items }} + then 'booking_fees' + when ili.item_code in {{ listing_fee_items }} + then 'listing_fees' + when ili.item_code in {{ verification_fee_items }} + then 'verification_fees' + else null + end as fee_category, + sum(ili.line_amount_wo_taxes_in_gbp) as fees_invoiced + from xero__invoice_line_items ili + left join xero__invoices i on i.id_invoice = ili.id_invoice + where + i.invoice_status in {{ relevant_document_statuses }} + and ( + ili.item_code in {{ booking_fee_items }} + or ili.item_code in {{ listing_fee_items }} + or ili.item_code in {{ verification_fee_items }} + ) + group by + extract(year from i.invoice_issued_date_utc), + extract(month from i.invoice_issued_date_utc), + case + when ili.item_code in {{ booking_fee_items }} + then 'booking_fees' + when ili.item_code in {{ listing_fee_items }} + then 'listing_fees' + when ili.item_code in {{ verification_fee_items }} + then 'verification_fees' + else null + end + ), + fees_credited as ( + select + extract( + year from cn.credit_note_issued_date_utc + ) as credit_note_issued_year, + extract( + month from cn.credit_note_issued_date_utc + ) as credit_note_issued_month, + case + when cnli.item_code in {{ booking_fee_items }} + then 'booking_fees' + when cnli.item_code in {{ listing_fee_items }} + then 'listing_fees' + when cnli.item_code in {{ verification_fee_items }} + then 'verification_fees' + else null + end as fee_category, + sum(cnli.line_amount_wo_taxes_in_gbp) as fees_credited + from reporting.xero__credit_note_line_items cnli + left join + reporting.xero__credit_notes cn on cn.id_credit_note = cnli.id_credit_note + where + cn.credit_note_status in {{ relevant_document_statuses }} + and ( + cnli.item_code in {{ booking_fee_items }} + or cnli.item_code in {{ listing_fee_items }} + or cnli.item_code in {{ verification_fee_items }} + ) + group by + extract(year from cn.credit_note_issued_date_utc), + extract(month from cn.credit_note_issued_date_utc), + case + when cnli.item_code in {{ booking_fee_items }} + then 'booking_fees' + when cnli.item_code in {{ listing_fee_items }} + then 'listing_fees' + when cnli.item_code in {{ verification_fee_items }} + then 'verification_fees' + else null + end + ) +select + i.invoice_issued_year as issued_year, + i.invoice_issued_month as issued_month, + i.fee_category, + coalesce(i.fees_invoiced, 0) as fees_invoiced_in_gbp, + coalesce(c.fees_credited, 0) as fees_credited_in_gbp, + (coalesce(i.fees_invoiced, 0) - coalesce(c.fees_credited, 0)) as net_fees_in_gbp +from fees_invoiced i +left join + fees_credited c + on i.invoice_issued_year = c.credit_note_issued_year + and i.invoice_issued_month = c.credit_note_issued_month + and i.fee_category = c.fee_category diff --git a/models/reporting/xero/xero__verification_fees_net.sql b/models/reporting/xero/xero__verification_fees_net.sql deleted file mode 100644 index 4627e41..0000000 --- a/models/reporting/xero/xero__verification_fees_net.sql +++ /dev/null @@ -1,8 +0,0 @@ --- depends_on: {{ ref('xero__invoice_line_items') }} --- depends_on: {{ ref('xero__invoices') }} --- depends_on: {{ ref('xero__credit_note_line_items') }} --- depends_on: {{ ref('xero__credit_notes') }} -{% set relevant_item_codes = "('Verification Fee')" %} - - -{{ generate_xero_net_fees_model(relevant_item_codes) }} From 65f5b7377a93c9e159c9512f6a0fa17476acfe29 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 23 May 2024 16:13:53 +0200 Subject: [PATCH 11/15] use date field instead of breaking things down --- models/reporting/xero/xero__net_fees.sql | 26 +++++++++--------------- 1 file changed, 10 insertions(+), 16 deletions(-) diff --git a/models/reporting/xero/xero__net_fees.sql b/models/reporting/xero/xero__net_fees.sql index b4b6097..af0529f 100644 --- a/models/reporting/xero/xero__net_fees.sql +++ b/models/reporting/xero/xero__net_fees.sql @@ -12,8 +12,9 @@ with xero__credit_notes as (select * from {{ ref("xero__credit_notes") }}), fees_invoiced as ( select - extract(year from i.invoice_issued_date_utc) as invoice_issued_year, - extract(month from i.invoice_issued_date_utc) as invoice_issued_month, + cast( + date_trunc('month', i.invoice_issued_date_utc) as date + ) as invoice_issued_year_month, case when ili.item_code in {{ booking_fee_items }} then 'booking_fees' @@ -34,8 +35,7 @@ with or ili.item_code in {{ verification_fee_items }} ) group by - extract(year from i.invoice_issued_date_utc), - extract(month from i.invoice_issued_date_utc), + date_trunc('month', i.invoice_issued_date_utc), case when ili.item_code in {{ booking_fee_items }} then 'booking_fees' @@ -48,12 +48,9 @@ with ), fees_credited as ( select - extract( - year from cn.credit_note_issued_date_utc - ) as credit_note_issued_year, - extract( - month from cn.credit_note_issued_date_utc - ) as credit_note_issued_month, + cast( + date_trunc('month', cn.credit_note_issued_date_utc) as date + ) as credit_note_issued_year_month, case when cnli.item_code in {{ booking_fee_items }} then 'booking_fees' @@ -75,8 +72,7 @@ with or cnli.item_code in {{ verification_fee_items }} ) group by - extract(year from cn.credit_note_issued_date_utc), - extract(month from cn.credit_note_issued_date_utc), + date_trunc('month', cn.credit_note_issued_date_utc), case when cnli.item_code in {{ booking_fee_items }} then 'booking_fees' @@ -88,8 +84,7 @@ with end ) select - i.invoice_issued_year as issued_year, - i.invoice_issued_month as issued_month, + i.invoice_issued_year_month as issued_year_month, i.fee_category, coalesce(i.fees_invoiced, 0) as fees_invoiced_in_gbp, coalesce(c.fees_credited, 0) as fees_credited_in_gbp, @@ -97,6 +92,5 @@ select from fees_invoiced i left join fees_credited c - on i.invoice_issued_year = c.credit_note_issued_year - and i.invoice_issued_month = c.credit_note_issued_month + on i.invoice_issued_year_month = c.credit_note_issued_year_month and i.fee_category = c.fee_category From 1f24965a2312989a037029f582d1e8cb392bb553 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 23 May 2024 16:14:44 +0200 Subject: [PATCH 12/15] remove outdated denom invoicing mart --- .../xero/xero__denom_invoicing_mart.sql | 93 ------------------- 1 file changed, 93 deletions(-) delete mode 100644 models/reporting/xero/xero__denom_invoicing_mart.sql diff --git a/models/reporting/xero/xero__denom_invoicing_mart.sql b/models/reporting/xero/xero__denom_invoicing_mart.sql deleted file mode 100644 index a42ae22..0000000 --- a/models/reporting/xero/xero__denom_invoicing_mart.sql +++ /dev/null @@ -1,93 +0,0 @@ -with - xero__invoices as (select * from {{ ref("xero__invoices") }}), - xero__contacts as (select * from {{ ref("xero__contacts") }}), - xero__invoice_line_items as (select * from {{ ref("xero__invoice_line_items") }}) - -select - li.id_line_item, - li.id_item, - li.item_code, - li.quantity, - li.unit_amount, - li.line_amount_local_curr, - li.line_amount_in_gbp, - li.line_amount_wo_taxes_local_curr, - li.line_amount_wo_taxes_in_gbp, - li.tax_amount_local_curr, - li.tax_amount_in_gbp, - li.tax_type, - li.line_description, - - i.id_invoice, - i.reference, - i.invoice_number, - i.invoice_issued_date_utc, - i.invoice_due_date_utc, - i.was_fully_paid_on_date_utc, - i.invoice_type, - i.invoice_currency_iso_4217, - i.exchange_rate_to_gbp, - i.total_amount_local_curr, - i.total_amount_in_gbp, - i.total_amount_wo_tax_local_curr, - i.total_amount_wo_tax_in_gbp, - i.total_tax_local_curr, - i.total_tax_in_gbp, - i.total_due_local_curr, - i.total_due_in_gbp, - i.total_paid_local_curr, - i.total_paid_in_gbp, - i.invoice_status, - i.has_errors, - i.is_discounted, - i.date_string, - i.due_date_string, - i.has_been_sent_to_contact, - i.total_discount, - i.total_credited_local_curr, - i.has_attachments, - i.line_amount_tax_inclusiveness, - i.payment_planned_date_utc, - i.payment_expected_date_utc, - - c.id_contact, - c.account_number, - c.id_deal, - c.contact_name, - c.is_customer, - c.is_supplier, - c.tax_number, - c.contact_first_name, - c.contact_last_name, - c.phones, - c.website, - c.balances, - c.discount, - c.addresses, - c.attachments, - c.email_addresses, - c.payment_terms, - c.batch_payments, - c.branding_theme, - c.contact_groups, - c.contact_number, - c.contact_status, - c.skyper_user_name, - c.contact_persons, - c.xero_network_key, - c.default_currency_iso_4217, - c.validation_errors, - c.bank_account_details, - c.has_validation_errors, - c.tracking_category_name, - c.account_payable_tax_type, - c.tracking_category_option, - c.sales_default_account_code, - c.sales_tracking_categories, - c.account_receivable_tax_type, - c.purchases_default_account_code, - c.purchases_tracking_categories - -from xero__invoice_line_items li -left join xero__invoices i on li.id_invoice = i.id_invoice -left join xero__contacts c on i.id_contact = c.id_contact From e2645814e45ed33ccf383190c34e885e17ec48de Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 23 May 2024 16:15:43 +0200 Subject: [PATCH 13/15] update exposures --- models/reporting/exposures.yaml | 6 ++++-- 1 file changed, 4 insertions(+), 2 deletions(-) diff --git a/models/reporting/exposures.yaml b/models/reporting/exposures.yaml index 4cae40a..912ece5 100644 --- a/models/reporting/exposures.yaml +++ b/models/reporting/exposures.yaml @@ -25,11 +25,13 @@ exposures: url: https://app.powerbi.com/Redirect?action=OpenReport&appId=33e55130-3a65-4fe8-86f2-11979fb2258a&reportObjectId=01d5648d-1c0b-4a22-988d-75e1cd64b5e5&ctid=862842df-2998-4826-bea9-b726bc01d3a7&reportPage=ReportSectiona542e78b23000f1cd14a&pbi_source=appShareLink&portalSessionId=86206797-4512-4ecb-a946-da8d0b58a757 description: | - A PBI report showcasing our revenue coming from host fees with a transaction point of view. + A PBI report showcasing our revenue coming from host fees with a + transactional point of view. Includes both data from the backend and from + Xero. depends_on: - ref('core__bookings') - - ref('xero__denom_invoicing_mart') + - ref('xero__net_fees') - ref('dates') owner: From 4cc9644febf0d827eb84c7f3a2487cac44556e82 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 23 May 2024 16:22:02 +0200 Subject: [PATCH 14/15] remove unnecessary nested objects since they can be joined in dwh --- models/intermediate/xero/int_xero__credit_notes.sql | 2 -- models/intermediate/xero/int_xero__invoices.sql | 2 -- 2 files changed, 4 deletions(-) diff --git a/models/intermediate/xero/int_xero__credit_notes.sql b/models/intermediate/xero/int_xero__credit_notes.sql index f21090c..9e7271d 100644 --- a/models/intermediate/xero/int_xero__credit_notes.sql +++ b/models/intermediate/xero/int_xero__credit_notes.sql @@ -24,9 +24,7 @@ select ) as remaining_credit_in_gbp, applied_amount, credit_note_status, - full_contact_details, credit_note_due_date, - line_items, date_string, due_date_string, allocations, diff --git a/models/intermediate/xero/int_xero__invoices.sql b/models/intermediate/xero/int_xero__invoices.sql index 5b7f8d2..d30f875 100644 --- a/models/intermediate/xero/int_xero__invoices.sql +++ b/models/intermediate/xero/int_xero__invoices.sql @@ -26,10 +26,8 @@ select total_paid_local_curr, (total_paid_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as total_paid_in_gbp, invoice_status, - full_contact_details, payments, has_errors, - line_items, credit_notes, prepayments, overpayments, From 3706a0c21c475051f6d66d8b0cad7e633317ea78 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 23 May 2024 16:23:52 +0200 Subject: [PATCH 15/15] Revert "remove unnecessary nested objects since they can be joined in dwh" This reverts commit 4cc9644febf0d827eb84c7f3a2487cac44556e82. --- models/intermediate/xero/int_xero__credit_notes.sql | 2 ++ models/intermediate/xero/int_xero__invoices.sql | 2 ++ 2 files changed, 4 insertions(+) diff --git a/models/intermediate/xero/int_xero__credit_notes.sql b/models/intermediate/xero/int_xero__credit_notes.sql index 9e7271d..f21090c 100644 --- a/models/intermediate/xero/int_xero__credit_notes.sql +++ b/models/intermediate/xero/int_xero__credit_notes.sql @@ -24,7 +24,9 @@ select ) as remaining_credit_in_gbp, applied_amount, credit_note_status, + full_contact_details, credit_note_due_date, + line_items, date_string, due_date_string, allocations, diff --git a/models/intermediate/xero/int_xero__invoices.sql b/models/intermediate/xero/int_xero__invoices.sql index d30f875..5b7f8d2 100644 --- a/models/intermediate/xero/int_xero__invoices.sql +++ b/models/intermediate/xero/int_xero__invoices.sql @@ -26,8 +26,10 @@ select total_paid_local_curr, (total_paid_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as total_paid_in_gbp, invoice_status, + full_contact_details, payments, has_errors, + line_items, credit_notes, prepayments, overpayments,