Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Payments: Add string handling, refactor modeling of Elavon data #2957

Merged
merged 15 commits into from
Oct 10, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
9 changes: 9 additions & 0 deletions warehouse/macros/parse_elavon_date.sql
Original file line number Diff line number Diff line change
@@ -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 %}
Original file line number Diff line number Diff line change
@@ -1,6 +1,8 @@
{{ config(materialized='table') }}

WITH fct_elavon__transactions AS (
WITH

fct_elavon__transactions AS (
SELECT

*,
Expand Down
144 changes: 62 additions & 82 deletions warehouse/models/mart/payments/fct_elavon__transactions.sql
Original file line number Diff line number Diff line change
@@ -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
76 changes: 75 additions & 1 deletion warehouse/models/staging/payments/elavon/_elavon.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -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
Loading
Loading