From e0e3873cb2386fb25c35d5c176995ea8f337701b Mon Sep 17 00:00:00 2001 From: Charlie Costanzo Date: Tue, 10 Oct 2023 12:03:10 -0400 Subject: [PATCH] Payments: Add string handling, refactor modeling of Elavon data (#2957) * refactored staging table to focus on cleaning * broke out intermediate tables to focus on billing and deposits exclusively, and deduplicate * removed cleaning steps and refactored to focus on union of billing and deposits * replace previous transactions table * broke out intermediate tables to focus on billing and deposits exclusively, and deduplicate * made parse_elavon_date macro, implemented in stg_elavon_transactions * combined import CTEs for conciseness * implement qualify for intermediate table deduplication * changed elavon fact table name back to fct_elavon__transactions for the time being * removed _deduped from elavon intermediate tables since this is now handled in staging * fixed table names downstream for renamed tables * missed some renaming downstream * removed always null columns from int_elavon__billing_transactions * moved elavon deduplication to staging table * updated dbt docs --- warehouse/macros/parse_elavon_date.sql | 9 + ..._history_transactions_deposits_billing.sql | 4 +- .../payments/fct_elavon__transactions.sql | 144 +++++------ .../staging/payments/elavon/_elavon.yml | 76 +++++- .../int_elavon__billing_transactions.sql | 43 ++++ .../int_elavon__deposit_transactions.sql | 64 +++++ .../elavon/stg_elavon__transactions.sql | 230 +++++++----------- 7 files changed, 341 insertions(+), 229 deletions(-) create mode 100644 warehouse/macros/parse_elavon_date.sql create mode 100644 warehouse/models/staging/payments/elavon/int_elavon__billing_transactions.sql create mode 100644 warehouse/models/staging/payments/elavon/int_elavon__deposit_transactions.sql diff --git a/warehouse/macros/parse_elavon_date.sql b/warehouse/macros/parse_elavon_date.sql new file mode 100644 index 0000000000..76337f9dba --- /dev/null +++ b/warehouse/macros/parse_elavon_date.sql @@ -0,0 +1,9 @@ +{% macro parse_elavon_date(column_name) %} + +CASE + WHEN LENGTH({{ column_name }}) < 8 + THEN PARSE_DATE('%m%d%Y', CONCAT(0, {{ column_name }})) + ELSE PARSE_DATE('%m%d%Y', {{ column_name }}) +END + +{% endmacro %} diff --git a/warehouse/models/mart/payments/elavon_littlepay__daily_history_transactions_deposits_billing.sql b/warehouse/models/mart/payments/elavon_littlepay__daily_history_transactions_deposits_billing.sql index a52f880423..3b5a9189fe 100644 --- a/warehouse/models/mart/payments/elavon_littlepay__daily_history_transactions_deposits_billing.sql +++ b/warehouse/models/mart/payments/elavon_littlepay__daily_history_transactions_deposits_billing.sql @@ -1,6 +1,8 @@ {{ config(materialized='table') }} -WITH fct_elavon__transactions AS ( +WITH + +fct_elavon__transactions AS ( SELECT *, diff --git a/warehouse/models/mart/payments/fct_elavon__transactions.sql b/warehouse/models/mart/payments/fct_elavon__transactions.sql index 0a9c092608..690e5dd187 100644 --- a/warehouse/models/mart/payments/fct_elavon__transactions.sql +++ b/warehouse/models/mart/payments/fct_elavon__transactions.sql @@ -1,98 +1,78 @@ {{ config(materialized='table') }} -WITH stg_elavon__transactions AS ( - SELECT * FROM {{ ref('stg_elavon__transactions') }} -), +WITH -remove_special_characters AS ( - SELECT +int_elavon__billing_transactions AS ( + SELECT * FROM {{ ref('int_elavon__billing_transactions') }} +), - * EXCEPT (fund_amt, batch_amt, amount, surchg_amount, convnce_amt, payment_date, transaction_date, settlement_date), +int_elavon__deposit_transactions AS ( + SELECT * FROM {{ ref('int_elavon__deposit_transactions') }} +), - CAST(REGEXP_REPLACE(fund_amt, r'\$|,', '') as NUMERIC) AS fund_amt, - CAST(REGEXP_REPLACE(batch_amt, r'\$|,', '') as NUMERIC) AS batch_amt, - CAST(REGEXP_REPLACE(amount, r'\$|,', '') as NUMERIC) AS amount, - CAST(REGEXP_REPLACE(surchg_amount, r'\$|,', '') as NUMERIC) AS surchg_amount, - CAST(REGEXP_REPLACE(convnce_amt, r'\$|,', '') as NUMERIC) AS convnce_amt, +union_deposits_and_billing AS ( - REGEXP_EXTRACT(payment_date, r'[^@\.]+') AS payment_date, - REGEXP_EXTRACT(transaction_date, r'[^@\.]+') AS transaction_date, - REGEXP_EXTRACT(settlement_date, r'[^@\.]+') AS settlement_date + SELECT + * + FROM int_elavon__billing_transactions + UNION ALL + SELECT + * + FROM int_elavon__deposit_transactions - FROM stg_elavon__transactions ), fct_elavon__transactions AS ( - SELECT - - * EXCEPT (payment_date, transaction_date, settlement_date), - CASE WHEN - LENGTH(payment_date) < 8 - THEN PARSE_DATE('%m%d%Y', CONCAT(0, payment_date)) - ELSE PARSE_DATE('%m%d%Y', payment_date) - END AS payment_date, + SELECT - CASE WHEN - LENGTH(transaction_date) < 8 - THEN PARSE_DATE('%m%d%Y', CONCAT(0, transaction_date)) - ELSE PARSE_DATE('%m%d%Y', transaction_date) - END AS transaction_date, + payment_reference, + payment_date, + account_number, + routing_number, + fund_amt, + batch_reference, + batch_type, + customer_batch_reference, + customer_name, + merchant_number, + external_mid, + store_number, + chain, + batch_amt, + amount, + surchg_amount, + convnce_amt, + card_type, + charge_type, + charge_type_description, + card_plan, + card_no, + chk_num, + transaction_date, + settlement_date, + authorization_code, + chargeback_control_no, + roc_text, + trn_aci, + card_scheme_ref, + trn_ref_num, + settlement_method, + currency_code, + cb_acq_ref_id, + chgbk_rsn_code, + chgbk_rsn_desc, + mer_ref, + purch_id, + cust_cod, + trn_arn, + term_id, + ent_num, + dt, + execution_ts - CASE WHEN - LENGTH(settlement_date) < 8 - THEN PARSE_DATE('%m%d%Y', CONCAT(0, settlement_date)) - ELSE PARSE_DATE('%m%d%Y', settlement_date) - END AS settlement_date + FROM union_deposits_and_billing - FROM remove_special_characters ) -SELECT - - payment_reference, - payment_date, - account_number, - routing_number, - fund_amt, - batch_reference, - batch_type, - customer_batch_reference, - customer_name, - merchant_number, - external_mid, - store_number, - chain, - batch_amt, - amount, - surchg_amount, - convnce_amt, - card_type, - charge_type, - charge_type_description, - card_plan, - card_no, - chk_num, - transaction_date, - settlement_date, - authorization_code, - chargeback_control_no, - roc_text, - trn_aci, - card_scheme_ref, - trn_ref_num, - settlement_method, - currency_code, - cb_acq_ref_id, - chgbk_rsn_code, - chgbk_rsn_desc, - mer_ref, - purch_id, - cust_cod, - trn_arn, - term_id, - ent_num, - dt, - execution_ts - -FROM fct_elavon__transactions +SELECT * FROM fct_elavon__transactions diff --git a/warehouse/models/staging/payments/elavon/_elavon.yml b/warehouse/models/staging/payments/elavon/_elavon.yml index 8074c8c71a..d3d76ac223 100644 --- a/warehouse/models/staging/payments/elavon/_elavon.yml +++ b/warehouse/models/staging/payments/elavon/_elavon.yml @@ -11,7 +11,81 @@ sources: models: - name: stg_elavon__transactions - description: Transactions processed by Elavon + description: Transactions processed by Elavon, cleaned and deduped. + columns: + - name: payment_reference + - name: payment_date + - name: account_number + - name: routing_number + - name: fund_amt + - name: batch_reference + - name: batch_type + - name: customer_batch_reference + - name: customer_name + - name: merchant_number + - name: external_mid + - name: store_number + - name: chain + - name: batch_amt + - name: amount + - name: surchg_amount + - name: convnce_amt + - name: card_type + - name: charge_type + - name: charge_type_description + - name: card_plan + - name: card_no + - name: chk_num + - name: transaction_date + - name: settlement_date + - name: authorization_code + - name: chargeback_control_no + - name: roc_text + - name: trn_aci + - name: card_scheme_ref + - name: trn_ref_num + - name: settlement_method + - name: currency_code + - name: cb_acq_ref_id + - name: chgbk_rsn_code + - name: chgbk_rsn_desc + - name: mer_ref + - name: purch_id + - name: cust_cod + - name: trn_arn + - name: term_id + - name: ent_num + - name: dt + - name: execution_ts + + - name: int_elavon__billing_transactions + description: Billing-specific transactions processed by Elavon + columns: + - name: payment_reference + - name: payment_date + - name: account_number + - name: routing_number + - name: fund_amt + - name: batch_reference + - name: batch_type + - name: customer_name + - name: merchant_number + - name: external_mid + - name: chain + - name: batch_amt + - name: amount + - name: card_type + - name: charge_type + - name: charge_type_description + - name: card_plan + - name: settlement_method + - name: currency_code + - name: ent_num + - name: dt + - name: execution_ts + + - name: int_elavon__deposit_transactions + description: Deposit-specific transactions processed by Elavon columns: - name: payment_reference - name: payment_date diff --git a/warehouse/models/staging/payments/elavon/int_elavon__billing_transactions.sql b/warehouse/models/staging/payments/elavon/int_elavon__billing_transactions.sql new file mode 100644 index 0000000000..5984138adf --- /dev/null +++ b/warehouse/models/staging/payments/elavon/int_elavon__billing_transactions.sql @@ -0,0 +1,43 @@ +{{ config(materialized='table') }} + +WITH + +billing_transactions AS ( + + SELECT * FROM {{ ref('stg_elavon__transactions') }} + WHERE batch_type = 'B' + +), + +int_elavon__billing_transactions AS ( + + SELECT + + payment_reference, + payment_date, + account_number, + routing_number, + fund_amt, + batch_reference, + batch_type, + customer_name, + merchant_number, + external_mid, + chain, + batch_amt, + amount, + card_type, + charge_type, + charge_type_description, + card_plan, + settlement_method, + currency_code, + ent_num, + dt, + execution_ts + + FROM billing_transactions + +) + +SELECT * FROM int_elavon__billing_transactions diff --git a/warehouse/models/staging/payments/elavon/int_elavon__deposit_transactions.sql b/warehouse/models/staging/payments/elavon/int_elavon__deposit_transactions.sql new file mode 100644 index 0000000000..182a3ab9c8 --- /dev/null +++ b/warehouse/models/staging/payments/elavon/int_elavon__deposit_transactions.sql @@ -0,0 +1,64 @@ +{{ config(materialized='table') }} + +WITH + +deposit_transactions AS ( + + SELECT * FROM {{ ref('stg_elavon__transactions') }} + WHERE batch_type = 'D' + +), + +int_elavon__deposit_transactions AS ( + + SELECT + payment_reference, + payment_date, + account_number, + routing_number, + fund_amt, + batch_reference, + batch_type, + customer_batch_reference, + customer_name, + merchant_number, + external_mid, + store_number, + chain, + batch_amt, + amount, + surchg_amount, + convnce_amt, + card_type, + charge_type, + charge_type_description, + card_plan, + card_no, + chk_num, + transaction_date, + settlement_date, + authorization_code, + chargeback_control_no, + roc_text, + trn_aci, + card_scheme_ref, + trn_ref_num, + settlement_method, + currency_code, + cb_acq_ref_id, + chgbk_rsn_code, + chgbk_rsn_desc, + mer_ref, + purch_id, + cust_cod, + trn_arn, + term_id, + ent_num, + dt, + execution_ts + + FROM deposit_transactions + +) + +SELECT * FROM int_elavon__deposit_transactions diff --git a/warehouse/models/staging/payments/elavon/stg_elavon__transactions.sql b/warehouse/models/staging/payments/elavon/stg_elavon__transactions.sql index a89f49bcc1..49f477f327 100644 --- a/warehouse/models/staging/payments/elavon/stg_elavon__transactions.sql +++ b/warehouse/models/staging/payments/elavon/stg_elavon__transactions.sql @@ -1,155 +1,93 @@ -WITH primary_batch_transactions AS ( - SELECT - transactions.payment_reference, - transactions.payment_date, - transactions.account_number, - transactions.routing_number, - transactions.fund_amt, - transactions.batch_reference, - transactions.batch_type, - transactions.customer_batch_reference, - transactions.customer_name, - transactions.merchant_number, - transactions.external_mid, - transactions.store_number, - transactions.chain, - transactions.batch_amt, - transactions.amount, - transactions.surchg_amount, - transactions.convnce_amt, - transactions.card_type, - transactions.charge_type, - transactions.charge_type_description, - transactions.card_plan, - transactions.card_no, - transactions.chk_num, - transactions.transaction_date, - transactions.settlement_date, - transactions.authorization_code, - transactions.chargeback_control_no, - transactions.roc_text, - transactions.trn_aci, - transactions.card_scheme_ref, - transactions.trn_ref_num, - transactions.settlement_method, - transactions.currency_code, - transactions.cb_acq_ref_id, - transactions.chgbk_rsn_code, - transactions.chgbk_rsn_desc, - transactions.mer_ref, - transactions.purch_id, - transactions.cust_cod, - transactions.trn_arn, - transactions.term_id, - transactions.ent_num, - transactions.dt, - transactions.execution_ts - FROM {{ source('elavon_external_tables', 'transactions') }} - INNER JOIN ( - SELECT trn_ref_num, MAX(execution_ts) AS max_ts FROM {{ source('elavon_external_tables', 'transactions') }} GROUP BY trn_ref_num - ) grouped_tbl ON transactions.trn_ref_num = grouped_tbl.trn_ref_num AND transactions.execution_ts = max_ts +{{ config(materialized='table') }} + +WITH + +source AS ( + SELECT * FROM {{ source('elavon_external_tables', 'transactions') }} ), -batch_b_transactions AS ( - SELECT - transactions.payment_reference, - transactions.payment_date, - transactions.account_number, - transactions.routing_number, - transactions.fund_amt, - transactions.batch_reference, - transactions.batch_type, - transactions.customer_batch_reference, - transactions.customer_name, - transactions.merchant_number, - transactions.external_mid, - transactions.store_number, - transactions.chain, - transactions.batch_amt, - transactions.amount, - transactions.surchg_amount, - transactions.convnce_amt, - transactions.card_type, - transactions.charge_type, - transactions.charge_type_description, - transactions.card_plan, - transactions.card_no, - transactions.chk_num, - transactions.transaction_date, - transactions.settlement_date, - transactions.authorization_code, - transactions.chargeback_control_no, - transactions.roc_text, - transactions.trn_aci, - transactions.card_scheme_ref, - transactions.trn_ref_num, - transactions.settlement_method, - transactions.currency_code, - transactions.cb_acq_ref_id, - transactions.chgbk_rsn_code, - transactions.chgbk_rsn_desc, - transactions.mer_ref, - transactions.purch_id, - transactions.cust_cod, - transactions.trn_arn, - transactions.term_id, - transactions.ent_num, - transactions.dt, - transactions.execution_ts - FROM {{ source('elavon_external_tables', 'transactions') }} - WHERE batch_type = 'B' - AND execution_ts = (SELECT MAX(execution_ts) FROM {{ source('elavon_external_tables', 'transactions') }}) +get_latest_extract AS( + + SELECT * + FROM source + -- we pull the whole world every day in the pipeline, so this gets only the latest extract + QUALIFY DENSE_RANK() OVER (ORDER BY execution_ts DESC) = 1 + ), -stg_elavon__transactions AS ( +handle_strings_and_remove_special_characters AS ( + SELECT - payment_reference, - payment_date, - account_number, - routing_number, - fund_amt, - batch_reference, - batch_type, - customer_batch_reference, - customer_name, - merchant_number, - external_mid, - store_number, - chain, - batch_amt, - amount, - surchg_amount, - convnce_amt, - card_type, - charge_type, - charge_type_description, - card_plan, - card_no, - chk_num, - transaction_date, - settlement_date, - authorization_code, - chargeback_control_no, - roc_text, - trn_aci, - card_scheme_ref, - trn_ref_num, - settlement_method, - currency_code, - cb_acq_ref_id, - chgbk_rsn_code, - chgbk_rsn_desc, - mer_ref, - purch_id, - cust_cod, - trn_arn, - term_id, - ent_num, + + {{ trim_make_empty_string_null('payment_reference') }} AS payment_reference, + REGEXP_EXTRACT({{ trim_make_empty_string_null('payment_date') }}, r'[^@\.]+') AS payment_date, + {{ trim_make_empty_string_null('account_number') }} AS account_number, + {{ trim_make_empty_string_null('routing_number') }} AS routing_number, + CAST(REGEXP_REPLACE({{ trim_make_empty_string_null('fund_amt') }}, r'\$|,', '') as NUMERIC) AS fund_amt, + {{ trim_make_empty_string_null('batch_reference') }} AS batch_reference, + {{ trim_make_empty_string_null('batch_type') }} AS batch_type, + {{ trim_make_empty_string_null('customer_batch_reference') }} AS customer_batch_reference, + {{ trim_make_empty_string_null('customer_name') }} AS customer_name, + {{ trim_make_empty_string_null('merchant_number') }} AS merchant_number, + {{ trim_make_empty_string_null('external_mid') }} AS external_mid, + {{ trim_make_empty_string_null('store_number') }} AS store_number, + {{ trim_make_empty_string_null('chain') }} AS chain, + CAST(REGEXP_REPLACE({{ trim_make_empty_string_null('batch_amt') }}, r'\$|,', '') as NUMERIC) AS batch_amt, + CAST(REGEXP_REPLACE({{ trim_make_empty_string_null('amount') }}, r'\$|,', '') as NUMERIC) AS amount, + CAST(REGEXP_REPLACE({{ trim_make_empty_string_null('surchg_amount') }}, r'\$|,', '') as NUMERIC) AS surchg_amount, + CAST(REGEXP_REPLACE({{ trim_make_empty_string_null('convnce_amt') }}, r'\$|,', '') as NUMERIC) AS convnce_amt, + {{ trim_make_empty_string_null('card_type') }} AS card_type, + {{ trim_make_empty_string_null('charge_type') }} AS charge_type, + {{ trim_make_empty_string_null('charge_type_description') }} AS charge_type_description, + {{ trim_make_empty_string_null('card_plan') }} AS card_plan, + {{ trim_make_empty_string_null('card_no') }} AS card_no, + {{ trim_make_empty_string_null('chk_num') }} AS chk_num, + REGEXP_EXTRACT({{ trim_make_empty_string_null('transaction_date') }}, r'[^@\.]+') AS transaction_date, + REGEXP_EXTRACT({{ trim_make_empty_string_null('settlement_date') }}, r'[^@\.]+') AS settlement_date, + {{ trim_make_empty_string_null('authorization_code') }} AS authorization_code, + {{ trim_make_empty_string_null('chargeback_control_no') }} AS chargeback_control_no, + {{ trim_make_empty_string_null('roc_text') }} AS roc_text, + {{ trim_make_empty_string_null('trn_aci') }} AS trn_aci, + {{ trim_make_empty_string_null('card_scheme_ref') }} AS card_scheme_ref, + {{ trim_make_empty_string_null('trn_ref_num') }} AS trn_ref_num, + {{ trim_make_empty_string_null('settlement_method') }} AS settlement_method, + {{ trim_make_empty_string_null('currency_code') }} AS currency_code, + {{ trim_make_empty_string_null('cb_acq_ref_id') }} AS cb_acq_ref_id, + {{ trim_make_empty_string_null('chgbk_rsn_code') }} AS chgbk_rsn_code, + {{ trim_make_empty_string_null('chgbk_rsn_desc') }} AS chgbk_rsn_desc, + {{ trim_make_empty_string_null('mer_ref') }} AS mer_ref, + {{ trim_make_empty_string_null('purch_id') }} AS purch_id, + {{ trim_make_empty_string_null('cust_cod') }} AS cust_cod, + {{ trim_make_empty_string_null('trn_arn') }} AS trn_arn, + {{ trim_make_empty_string_null('term_id') }} AS term_id, + {{ trim_make_empty_string_null('ent_num') }} AS ent_num, dt, execution_ts - FROM primary_batch_transactions - UNION ALL + + FROM get_latest_extract + +), + +format_dates AS ( + SELECT + + * EXCEPT (payment_date, transaction_date, settlement_date), + + {{ parse_elavon_date('payment_date') }} AS payment_date, + {{ parse_elavon_date('transaction_date') }} AS transaction_date, + {{ parse_elavon_date('settlement_date') }} AS settlement_date, + + FROM handle_strings_and_remove_special_characters + +), + + + +stg_elavon__transactions AS ( + + SELECT + payment_reference, payment_date, account_number, @@ -194,7 +132,9 @@ stg_elavon__transactions AS ( ent_num, dt, execution_ts - FROM batch_b_transactions + + FROM format_dates + ) SELECT * FROM stg_elavon__transactions