From b0528ec2c030b1ce6449f8c57ce9ef14b07946f0 Mon Sep 17 00:00:00 2001 From: Pablo Martin Date: Thu, 23 May 2024 15:22:42 +0200 Subject: [PATCH] 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) }}