diff --git a/dbt_project.yml b/dbt_project.yml index b9a8f65..763d2bd 100644 --- a/dbt_project.yml +++ b/dbt_project.yml @@ -1,4 +1,4 @@ -name: 'stripe' +name: 'airbyte_stripe' version: '0.1.0' require-dbt-version: ['>=1.0.0'] config-version: 2 @@ -18,9 +18,24 @@ clean-targets: models: airbyte_stripe: materialized: table - intermediate: - materialized: ephemeral + tmp: + materialized: view vars: airbyte_stripe: customers: "{{ source('airbyte_stripe','customers') }}" + customers_address: "{{ source('airbyte_stripe','customers_address') }}" + balance_transactions: "{{ source('airbyte_stripe','balance_transactions') }}" + charges_card: "{{ source('airbyte_stripe','charges_card') }}" + charges: "{{ source('airbyte_stripe','charges') }}" + payment_intents: "{{ source('airbyte_stripe','payment_intents') }}" + payouts: "{{ source('airbyte_stripe','payouts') }}" + refunds: "{{ source('airbyte_stripe','refunds') }}" + invoice_line_items: "{{ source('airbyte_stripe','invoice_line_items') }}" + invoice_line_items_period: "{{ source('airbyte_stripe','invoice_line_items_period') }}" + invoice_line_items_plan: "{{ source('airbyte_stripe','invoice_line_items_plan') }}" + invoices: "{{ source('airbyte_stripe','invoices') }}" + subscriptions: "{{ source('airbyte_stripe','subscriptions') }}" + plans: "{{ source('airbyte_stripe','plans') }}" + + "dbt_date:time_zone": "UTC" diff --git a/models/schema.yml b/models/schema.yml index 18762d1..9d1c6e9 100644 --- a/models/schema.yml +++ b/models/schema.yml @@ -6,13 +6,465 @@ sources: database: "{% if target.type != 'spark'%}{{ var('stripe_database', target.database) }}{% endif %}" tables: - name: customers - + - name: customers_address + - name: balance_transactions + - name: charges_card + - name: charges + - name: payment_intents + - name: payouts + - name: refunds + - name: invoice_line_items + - name: invoice_line_items_period + - name: invoice_line_items_plan + - name: invoices + - name: subscriptions + - name: plans models: - name: stripe__customers description: "A table storing all customer info" columns: - - name: id + - name: customer_id + description: "The unique identifier of the customer" + tests: + - unique + - not_null + - name: customer_description description: "The unique identifier for the customer" + tests: + - not_null + - name: customer_created_at + description: "The date the customer was created" + tests: + - not_null + - name: total_sales + description: "The total amount of sales for the customer" + tests: + - not_null + - name: total_refunds + description: "The total amount of refunds to the customer" + tests: + - not_null + - name: total_gross_transaction_amount + description: "The total gross transaction amount for the customer" + tests: + - not_null + - name: total_fees + description: "The total amount fees generated by the customer" + tests: + - not_null + - name: total_net_transaction_amount + description: "The total net transaction amount for the customer" + tests: + - not_null + - name: total_failed_charge_amount + description: "The total amount of failed charges to the customer" + tests: + - not_null + - name: total_failed_charge_count + description: "The total number of failed charges to this customer" + tests: + - not_null + - name: total_sales_count + description: "The total number of sales made to the customer" + tests: + - not_null + - name: total_refund_count + description: "The total number of refunds made to the customer" + tests: + - not_null + - name: sales_this_month + description: "The total amount of sales made this month" + tests: + - not_null + - name: refunds_this_month + description: "The total amount of refunds made this month" + tests: + - not_null + - name: gross_transaction_amount_this_month + description: "The total gross transaction amount this month" + tests: + - not_null + - name: net_transaction_amount_this_month + description: "The total net transaction amount this month" + tests: + - not_null + - name: sales_count_this_month + description: "The total number of sales made this month" + tests: + - not_null + - name: refund_count_this_month + description: "The total number of refund_count made this month" + tests: + - not_null + - name: failed_charge_count_this_month + description: "The total number of failed_charge_count made this month" + tests: + - not_null + - name: failed_charge_amount_this_month + description: "The total number of failed_charge_amount made this month" + tests: + - not_null + - name: customer_currency + description: "The currency set for this currency" + - name: default_card_id + description: "The unique identifier of the default customer card" + - name: shipping_name + description: "The name of the shipping service" + - name: shipping_address_line_1 + description: "The 1st line of the customer shipping address" + - name: shipping_address_line_2 + description: "The 2nd line of the customer shipping address" + - name: shipping_address_city + description: "The city of the customer shipping address" + - name: shipping_address_state + description: "The state of the customer shipping address" + - name: shipping_address_country + description: "The country of the customer shipping address" + - name: shipping_address_postal_code + description: "The postal code of the customer shipping address" + - name: phone_number + description: "The phone number of the customer" + - name: stripe__balance_transactions + description: "A table storing all balance transactions and associated charge data" + columns: + - name: balance_transaction_id + description: "The unique identifier for the balance transaction" tests: - unique - not_null + - name: created_at + description: "The date the balance transaction was created" + tests: + - not_null + - name: fee + description: "The fee associated with the balance transaction" + tests: + - not_null + - name: net_balance_change + description: "The net balance change due to the balance transaction" + tests: + - not_null + - name: type + description: "The type of balance transaction" + tests: + - not_null + - name: status + description: "The status of balance transaction" + tests: + - not_null + - name: amount + description: "The total transaction amount" + tests: + - not_null + - name: currency + description: "The currency associated with the balance transaction" + tests: + - not_null + - name: exchange_rate + description: "The exchange rate used for the balance transaction" + - name: charge_id + description: "The id of the charge associated with the balance transaction" + tests: + - not_null + - name: charge_created_at + description: "The date the charge was created" + - name: card_brand + description: "The card brand associated with the charge" + - name: card_funding + description: "The card funding type associated with the charge" + - name: card_country + description: "The country of the card charged" + - name: charge_amount + description: "The total charge amount" + - name: charge_currency + description: "The currency associated with the charge" + - name: customer_description + description: "The customer description associated with balance transaction" + - name: payout_id + description: "The id of the payout associated with the balance transaction" + - name: payout_arrival_date + description: "The date the payout is due to arrive" + - name: payout_status + description: "The status of payout" + - name: payout_type + description: "The type of payout" + - name: payout_description + description: "The user specified source of the payout" + - name: refund_reason + description: "The refund reason (if applicable)" + - name: stripe__invoice_line_items + description: "A table storing all line items associated with an invoice" + columns: + - name: invoice_id + description: "The unique identifier for the balance transaction" + tests: + - unique + - not_null + - name: invoice_number + description: "The invoice number" + tests: + - not_null + - name: invoice_created_at + description: "The date the invoice was created" + tests: + - not_null + - name: status + description: "The status of the invoice" + tests: + - not_null + - name: due_date + description: "The due date of the invoice" + tests: + - not_null + - name: amount_due + description: "The total amount due for the invoice" + tests: + - not_null + - name: subtotal + description: "The subtotal amount for the invoice" + tests: + - not_null + - name: tax + description: "The tax amount for the invoice" + tests: + - not_null + - name: total + description: "The total amount for the invoice" + tests: + - not_null + - name: amount_paid + description: "The total amount paid for the invoice" + - name: amount_remaining + description: "The amount remaining to be paid for the invoice" + - name: attempt_count + description: "The number of attempts sent for this invoice" + - name: description + description: "The description of the invoice" + - name: invoice_line_item_id + description: "The unique id of the invoice line item" + tests: + - not_null + - unique + - name: line_item_description + description: "The description of the line item" + - name: line_item_amount + description: "The price of line item" + - name: line_item_quantity + description: "The total quantity of the line item" + - name: period_start + description: "The datetime of the period start for the invoice" + - name: period_end + description: "The datetime of the period end for the invoice" + - name: balance_transaction_id + description: "The unique id of the associated balance transaction" + tests: + - not_null + - name: charge_amount + description: "The amount charged for the line item" + - name: charge_status + description: "The status of the charge for the line item" + - name: charge_created_at + description: "The datetime when the charge for the line item was created" + - name: customer_description + description: "The description of the customer associated with line item purchase" + - name: customer_email + description: "The email of the customer associated with line item purchase" + - name: customer_id + description: "The unique id of the customer associated with line item purchase" + - name: subscription_id + description: "The unique id of the subscription purchase (if applicable)" + - name: subscription_billing + description: "The billing used for the subscription purchase" + - name: subscription_start_date + description: "The start date of the subscription purchase" + - name: subscription_end_date + description: "The end date of the subscription purchase" + - name: plan_id + description: "The plan associated with the purchased subscription" + - name: is_plan_active + description: "A flag for whether the subscription plan is active" + - name: plan_amount + description: "The total amount for the subscription plan" + - name: plan_interval + description: "The interval the subscription plan is charged at" + - name: plan_interval_count + description: "The number of intervals the subscription plan is charged" + - name: plan_nickname + description: "The nickname of the subscription plan" + - name: plan_product_id + description: "The unique id of the product associated with subscription plan" + - name: stripe__subscriptions + description: "A table storing the details of all subscription plans used by customers" + columns: + - name: subscription_id + description: "The unique identifier for the subscription" + tests: + - unique + - not_null + - name: customer_id + description: "The unique identifier for the customer" + tests: + - not_null + - name: customer_description + description: "The description of the customer" + tests: + - not_null + - name: customer_email + description: "The email of the customer" + tests: + - not_null + - name: status + description: "The status of the subscription" + tests: + - not_null + - name: start_date + description: "The start date of the subscription" + tests: + - not_null + - name: end_date + description: "The end date of the subscription" + tests: + - not_null + - name: subscription_billing + description: "The type of billing used for the subscription" + tests: + - not_null + - name: billing_cycle_anchor + description: "The billing cycle anchor for the subscription" + tests: + - not_null + - name: canceled_at + description: "The datetime the invoice was canceled" + - name: created_at + description: "The datetime the invoice was created" + tests: + - not_null + - name: current_period_start + description: "The datetime the current subscription period starts" + tests: + - not_null + - name: current_period_end + description: "The datetime the current subscription period ends" + tests: + - not_null + - name: trial_start + description: "The datetime the trial starts" + - name: trial_end + description: "The datetime the trial ends" + - name: days_until_due + description: "The number of days until the subscription id canceled" + - name: is_cancel_at_period_end + description: "A flag for whether the subscription will be cancled at the end of the period" + - name: number_invoices_generated + description: "The number of invoice generated for this subscription" + tests: + - not_null + - name: total_amount_billed + description: "The total amount billed for the subscription" + tests: + - not_null + - name: total_amount_paid + description: "The total amount paid for the subscription" + tests: + - not_null + - name: total_amount_remaining + description: "The total amount remaining for the subscription" + tests: + - not_null + - name: most_recent_invoice_at + description: "The datetime the most recent invoice was generated" + - name: average_invoice_amount + description: "The average amount charged for the subscription" + tests: + - not_null + - name: average_line_item_amount + description: "The average amount of a line item which is bought as part of the subscription" + tests: + - not_null + - name: average_num_invoice_items + description: "The average amount of line items charged for a subscription" + tests: + - not_null + - name: "stripe__daily_overview" + description: "A table storing the daily overview statistics of your stripe account" + columns: + - name: date + description: "The date for the Stripe record" + tests: + - unique + - not_null + - name: total_sales + description: "The total amount of sales done on the date" + tests: + - not_null + - name: total_refunds + description: "The total amount of refunds done on the date" + tests: + - not_null + - name: total_adjustments + description: "The total amount of adjustments done on the date" + tests: + - not_null + - name: total_other_transactions + description: "The total amount of other transactions done on the date" + tests: + - not_null + - name: total_gross_transaction_amount + description: "The total amount of gross_transaction_amount done on the date" + tests: + - not_null + - name: total_payout_fees + description: "The total amount of payout_fees done on the date" + tests: + - not_null + - name: total_gross_payment_amount + description: "The total amount of gross_payment_amount done on the date" + tests: + - not_null + - name: total_failed_charge_amount + description: "The total amount of failed charges on the date" + tests: + - not_null + - name: total_sales_count + description: "The total number of sales done on the date" + tests: + - not_null + - name: total_payouts_count + description: "The total number of payouts done on the date" + tests: + - not_null + - name: total_adjustments_count + description: "The total number of adjustments done on the date" + tests: + - not_null + - name: total_failed_charge_count + description: "The total number of failed charges on the date" + tests: + - not_null + - name: daily_end_balance + description: "The daily end balance on the date" + tests: + - not_null + - name: churned_subscriptions + description: "The number of subscriptions that have been churned on the date" + - name: new_subscriptions + description: "The number of new subscriptions on the date" + - name: active_subscriptions + description: "The snapshot of the total number of subscriptions that were active at the date" + - name: churned_mrr + description: "The amount of monthly recurring revenue churned on that date" + - name: new_mrr + description: "The amount of new monthly recurring revenue gained on the date" + - name: mrr + description: "The snapshot of the total monthly recurring revenue on the date" + - name: mrr_per_subscription + description: "The monthly recurring revenue per active subscription" + - name: mrr_per_customer + description: "The monthly recurring revenue per active customer" + - name: customers_diff + description: "The change in number of customers from the previous date to the current date" + - name: subscriptions_diff + description: "The change in number of subscriptions from the previous date to the current date" + - name: mrr_diff + description: "The change in the number of customers from the previous date to the current date" + diff --git a/models/stripe__balance_transactions.sql b/models/stripe__balance_transactions.sql new file mode 100644 index 0000000..6d61154 --- /dev/null +++ b/models/stripe__balance_transactions.sql @@ -0,0 +1,71 @@ +with balance_transactions as ( + select + * + from {{ ref('stg_stripe__balance_transactions') }} +), + +charges as ( + select + * + from {{ ref('stg_stripe__charges')}} +), + +payouts as ( + select + * + from {{ ref('stg_stripe__payouts')}} +), + +customers as ( + select + * + from {{ ref('stg_stripe__customers')}} +), + +refunds as ( + select + * + from {{ ref('stg_stripe__refunds')}} +), + +balance_transactions_summary as ( + select + -- Balance Transactions + balance_transactions.*, + + -- Charges + charges.charge_id, + charges.created_at as charge_created_at, + charges.card_brand, + charges.card_funding, + charges.card_country, + case when + balance_transactions.type = 'charges' + then charges.charge_amount end + as charge_amount, + case when + balance_transactions.type = 'charges' + then charges.charge_currency end + as charge_currency, + + -- Customer details + charges.customer_id, + customers.customer_description, + payouts.payout_id, + payouts.arrival_date as payout_arrival_date, + payouts.status as payout_status, + payouts.type as payout_type, + payouts.description as payout_description, + refunds.refund_reason + from balance_transactions + left join charges + using(balance_transaction_id) + left join customers + using(customer_id) + left join payouts + using(balance_transaction_id) + left join refunds + using(balance_transaction_id) +) + +select * from balance_transactions_summary \ No newline at end of file diff --git a/models/stripe__customers.sql b/models/stripe__customers.sql index 1f2360b..605acf1 100644 --- a/models/stripe__customers.sql +++ b/models/stripe__customers.sql @@ -1,33 +1,248 @@ -with commit_comments_customer as ( +with balance_transactions as ( + select + * + from {{ ref('stripe__balance_transactions') }} +), + +incomplete_charges as ( + select + created_at, + customer_id, + charge_amount + from {{ ref('stg_stripe__charges')}} + where not charge_is_captured +), + +customers as ( select - id as customer_id, - url, - type, - login as customer_name - from {{ var('commit_comments_customer') }} + * + from {{ ref('stg_stripe__customers') }} ), -commit_comment_reactions_customer as ( +transactions_by_customer as ( select - id as customer_id, - url, - type, - login as customer_name - from {{ var('commit_comment_reactions_customer') }} + customer_id, + sum( + case when + type in ('charge', 'payment') + then amount + else 0 + end + ) as total_sales, + sum( + case when + type in ('payment_refund', 'refund') + then amount + else 0 + end + ) as total_refunds, + sum(amount) as total_gross_transaction_amount, + sum(fee) as total_fees, + sum(net_balance_change) as total_net_transaction_amount, + sum( + case when + type in ('charge', 'payment') + then 1 + else 0 + end + ) as total_sales_count, + sum( + case when + type in ('payment_refund', 'refund') + then 1 + else 0 + end + ) as total_refund_count, + sum( + case when + type in ('charge', 'payment') + and {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then amount + else 0 + end + ) as sales_this_month, + sum( + case when + type in ('payment_refund', 'refund') + and {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then amount + else 0 + end + ) as refunds_this_month, + sum( + case when + {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then amount + else 0 + end + ) as gross_transaction_amount_this_month, + sum( + case when + {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then fee + else 0 + end + ) as fees_this_month, + sum( + case when + {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then net_balance_change + else 0 + end + ) as net_transaction_amount_this_month, + sum( + case when + type in ('charge', 'payment') + and {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then 1 + else 0 + end + ) as sales_count_this_month, + sum( + case when + type in ('payment_refund', 'refund') + and {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then 1 + else 0 + end + ) as refund_count_this_month, + min( + case when + type in ('charge', 'payment') + then {{ dbt_utils.date_trunc("day", 'created_at') }} + else null + end + ) as first_sale_date, + max( + case when + type in ('charge', 'payment') + then {{ dbt_utils.date_trunc("day", 'created_at') }} + else null + end + ) as most_recent_sale_date + from balance_transactions + where type in ('payment', 'charge', 'payment_refund', 'refund') + {{ dbt_utils.group_by(1) }} ), -customers_union as ( - select * from commit_comments_customer - union all - select * from commit_comment_reactions_customer - union all - select * from issue_comment_reactions_customer +failed_charges_by_customer as ( + select + customer_id, + count(*) as total_failed_charge_count, + sum(charge_amount) as total_failed_charge_amount, + sum( + case when + {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then 1 + else 0 + end + ) as failed_charge_count_this_month, + sum( + case when + {{ dbt_utils.date_trunc("month", 'created_at') }} = {{ dbt_utils.date_trunc('month', dbt_date.today()) }} + then charge_amount + else 0 + end + ) as failed_charge_amount_this_month + from incomplete_charges + {{ dbt_utils.group_by(1) }} ), -customers as ( - select * - from customers_union - group by 1,2 +no_customer_transactions_overview as ( + select + customer_id, + 'No Associated Customer' as customer_description, + customers.customer_email, + customers.created_at as customer_created_at, + customers.is_delinquent, + coalesce(transactions_by_customer.total_sales/100.0, 0) as total_sales, + coalesce(transactions_by_customer.total_refunds/100.0, 0) as total_refunds, + coalesce(transactions_by_customer.total_gross_transaction_amount/100.0, 0) as total_gross_transaction_amount, + coalesce(transactions_by_customer.total_fees/100.0, 0) as total_fees, + coalesce(transactions_by_customer.total_net_transaction_amount/100.0, 0) as total_net_transaction_amount, + coalesce(transactions_by_customer.total_sales_count, 0) as total_sales_count, + coalesce(transactions_by_customer.total_refund_count, 0) as total_refund_count, + coalesce(transactions_by_customer.sales_this_month/100.0, 0) as sales_this_month, + coalesce(transactions_by_customer.refunds_this_month/100.0, 0) as refunds_this_month, + coalesce(transactions_by_customer.gross_transaction_amount_this_month/100.0, 0) as gross_transaction_amount_this_month, + coalesce(transactions_by_customer.fees_this_month/100.0, 0) as fees_this_month, + coalesce(transactions_by_customer.net_transaction_amount_this_month/100.0, 0) as net_transaction_amount_this_month, + coalesce(transactions_by_customer.sales_count_this_month, 0) as sales_count_this_month, + coalesce(transactions_by_customer.refund_count_this_month, 0) as refund_count_this_month, + transactions_by_customer.first_sale_date, + transactions_by_customer.most_recent_sale_date, + 0 as total_failed_charge_count, + 0 as total_failed_charge_amount, + 0 as failed_charge_count_this_month, + 0 as failed_charge_amount_this_month, + customers.customer_currency, + customers.default_card_id, + customers.shipping_name, + customers.shipping_address_line_1, + customers.shipping_address_line_2, + customers.shipping_address_city, + customers.shipping_address_state, + customers.shipping_address_country, + customers.shipping_address_postal_code, + customers.phone as phone_number + from transactions_by_customer + left join customers + using(customer_id) + where customers.customer_id is null and customers.customer_description is null +), + +customer_transactions_overview as ( + select + customer_id, + coalesce(customers.customer_description, customers.customer_id) as customer_description, + customers.customer_email, + customers.created_at as customer_created_at, + customers.is_delinquent, + coalesce(transactions_by_customer.total_sales/100.0, 0) as total_sales, + coalesce(transactions_by_customer.total_refunds/100.0, 0) as total_refunds, + coalesce(transactions_by_customer.total_gross_transaction_amount/100.0, 0) as total_gross_transaction_amount, + coalesce(transactions_by_customer.total_fees/100.0, 0) as total_fees, + coalesce(transactions_by_customer.total_net_transaction_amount/100.0, 0) as total_net_transaction_amount, + coalesce(transactions_by_customer.total_sales_count, 0) as total_sales_count, + coalesce(transactions_by_customer.total_refund_count, 0) as total_refund_count, + coalesce(transactions_by_customer.sales_this_month/100.0, 0) as sales_this_month, + coalesce(transactions_by_customer.refunds_this_month/100.0, 0) as refunds_this_month, + coalesce(transactions_by_customer.gross_transaction_amount_this_month/100.0, 0) as gross_transaction_amount_this_month, + coalesce(transactions_by_customer.fees_this_month/100.0, 0) as fees_this_month, + coalesce(transactions_by_customer.net_transaction_amount_this_month/100.0, 0) as net_transaction_amount_this_month, + coalesce(transactions_by_customer.sales_count_this_month, 0) as sales_count_this_month, + coalesce(transactions_by_customer.refund_count_this_month, 0) as refund_count_this_month, + transactions_by_customer.first_sale_date, + transactions_by_customer.most_recent_sale_date, + coalesce(failed_charges_by_customer.total_failed_charge_count, 0) as total_failed_charge_count, + coalesce(failed_charges_by_customer.total_failed_charge_amount/100, 0) as total_failed_charge_amount, + coalesce(failed_charges_by_customer.failed_charge_count_this_month, 0) as failed_charge_count_this_month, + coalesce(failed_charges_by_customer.failed_charge_amount_this_month/100, 0) as failed_charge_amount_this_month, + customers.customer_currency, + customers.default_card_id, + customers.shipping_name, + customers.shipping_address_line_1, + customers.shipping_address_line_2, + customers.shipping_address_city, + customers.shipping_address_state, + customers.shipping_address_country, + customers.shipping_address_postal_code, + customers.phone as phone_number + from customers + left join transactions_by_customer + using(customer_id) + left join failed_charges_by_customer + using(customer_id) +), + +customer_overview as ( + select + * + from no_customer_transactions_overview + union all + select + * + from customer_transactions_overview ) -select * from customers +select * from customer_overview \ No newline at end of file diff --git a/models/stripe__daily_overview.sql b/models/stripe__daily_overview.sql new file mode 100644 index 0000000..6d48ce6 --- /dev/null +++ b/models/stripe__daily_overview.sql @@ -0,0 +1,255 @@ +/* +The following select statements aim to best recreate the value for MRR found +on the Stripe Dashboard. They work filtering the data into a specific range +and using only the data from that range to create active subscription and MRR +values. + +As a baseline filter, all subscriptions not linked to a customer are discarded. + +We select distinct subscriptions from subscription_payments, taking the latest invoice +from the date range specified. +*/ + +with daily_transactions as ( + select + * + from {{ ref('int_stripe__daily_transactions') }} +), + +subscription_payments as ( + select + * + from {{ ref('int_stripe__subscription_payments') }} +), + +customer_stats as ( + select + * + from {{ ref('int_stripe__daily_customer_stats') }} +), + +sub_stats as ( + select + {{ dbt_utils.date_trunc("day", 'dt.date') }} as date, + ( + /* + Churned subscriptions are counted when the current day is + less than the day the subscription was canceled. + */ + select + count( + case when ( + filtered_subs.status = 'canceled' + and dt.date = date_trunc('day', filtered_subs.canceled_at) + and filtered_subs.customer_email is not null + ) + then 1 end + ) as "churned_subscriptions" + from ( + select distinct on (subscription_payments.subscription_id) + subscription_payments.date, + subscription_id, + status, + customer_email, + canceled_at + from + subscription_payments + where + subscription_payments.date <= date_trunc('day', dt.date) + order by + subscription_id, + date desc + ) as filtered_subs + ), + ( + /* + New subscriptions are counted on the first issued invoice. + */ + select + count( + case when ( + ( + filtered_subs.status = 'active' + or filtered_subs.status = 'past due' + or filtered_subs.status = 'canceled' + ) + and filtered_subs.invoice_number = 1 + and filtered_subs.customer_email is not null + ) + then 1 end + ) as "new_subscriptions" + from ( + select distinct on (subscription_payments.subscription_id) + subscription_payments.date, + subscription_id, + invoice_number, + status, + customer_email, + canceled_at + from + subscription_payments + where + subscription_payments.date = date_trunc('day', dt.date) + order by + subscription_id, + subscription_payments.date desc + ) as filtered_subs + ), + ( + /* + Active subscriptions are counted when the status is active or past due. + If the subscription is canceled, the sub will be counted only if the current + day is less than the day the sub was canceled. + */ + select + count( + case when ( + ( + filtered_subs.status = 'active' + or filtered_subs.status = 'past due' + or ( + filtered_subs.status = 'canceled' + and dt.date < date_trunc('day', filtered_subs.canceled_at) + ) + ) + and filtered_subs.customer_email is not null + ) + then 1 end + ) as "active_subscriptions" + from ( + select distinct on (subscription_payments.subscription_id) + subscription_payments.date, + subscription_id, + status, + customer_email, + canceled_at + from + subscription_payments + where + subscription_payments.date <= date_trunc('day', dt.date) + order by + subscription_id, + subscription_payments.date desc) as filtered_subs + ), + /* + There are multiple different values that can be used when summing mrr. Stripe + seems to use the average value of the subscription over its entire lifetime. + */ + ( + select + coalesce(round(sum( + case when ( + filtered_subs.status = 'canceled' + and dt.date = date_trunc('day', filtered_subs.canceled_at) + and filtered_subs.customer_email is not null + ) + then filtered_subs.plan_amount / 100 end + ), 2), 0) as "churned_mrr" + from ( + select distinct on (subscription_payments.subscription_id) + subscription_payments.date, + subscription_id, + plan_amount, + status, + customer_email, + canceled_at + from + subscription_payments + where + subscription_payments.date <= date_trunc('day', dt.date) + order by + subscription_id, + subscription_payments.date desc + ) as filtered_subs + ), + ( + select + coalesce(round(sum( + case when ( + ( + filtered_subs.status = 'active' + or filtered_subs.status = 'past due' + or filtered_subs.status = 'canceled' + ) + and filtered_subs.invoice_number = 1 + and filtered_subs.customer_email is not null + ) + then filtered_subs.plan_amount / 100 end + ), 2), 0) as "new_mrr" + from ( + select distinct on (subscription_payments.subscription_id) + subscription_payments.date, + subscription_id, + invoice_number, + plan_amount, + status, + customer_email + from + subscription_payments + where + subscription_payments.date = date_trunc('day', dt.date) + order by + subscription_id, + date desc + ) as filtered_subs + ), + ( + select + coalesce(round(sum( + case when ( + ( + filtered_subs.status = 'active' + or filtered_subs.status = 'past due' + or ( + filtered_subs.status = 'canceled' + and dt.date < date_trunc('day', filtered_subs.canceled_at) + ) + ) + and filtered_subs.customer_email is not null + ) + then filtered_subs.plan_amount / 100 end + ), 2), 0) as "mrr" + from ( + select distinct on (subscription_payments.subscription_id) + subscription_payments.date, + subscription_id, + plan_amount, + status, + customer_email, + canceled_at + from + subscription_payments + where + subscription_payments.date <= date_trunc('day', dt.date) + order by + subscription_id, + date desc + ) as filtered_subs + ) + from ( + select + date + from + daily_transactions + ) as dt +), + +daily_overview as ( + select + *, + coalesce(round(mrr/nullif(active_subscriptions, 0.0), 2), 0.0) as mrr_per_subscription, + coalesce(round(mrr/nullif(active_customers, 0.0), 2), 0.0) as mrr_per_customer, + coalesce(active_customers - lag(active_customers, 1) over (order by date), 0) as customers_diff, + coalesce(active_subscriptions - lag(active_subscriptions, 1) over (order by date), 0) as subscriptions_diff, + coalesce(mrr - lag(mrr, 1) over (order by date), 0.0) as mrr_diff + from + daily_transactions + left join sub_stats + using(date) + left join customer_stats + using(date) + order by + date asc +) + +select * from daily_overview \ No newline at end of file diff --git a/models/stripe__invoice_line_items.sql b/models/stripe__invoice_line_items.sql new file mode 100644 index 0000000..ce63950 --- /dev/null +++ b/models/stripe__invoice_line_items.sql @@ -0,0 +1,100 @@ +with invoices as ( + select + * + from {{ ref('stg_stripe__invoices') }} +), + +charges as ( + select + * + from {{ ref('stg_stripe__charges') }} +), + +invoice_line_items as ( + select + * + from {{ ref('stg_stripe__invoice_line_items') }} +), + +customers as ( + select + * + from {{ ref('stg_stripe__customers') }} + +), + +subscriptions as ( + select + * + from {{ ref('stg_stripe__subscriptions') }} + +), + +plans as ( + select + * + from {{ ref('stg_stripe__plans') }} +), + +line_items_summary as ( + select + -- Invoices + invoices.invoice_id, + invoices.invoice_number as invoice_number, + invoices.created_at as invoice_created_at, + invoices.status, + invoices.due_date, + invoices.amount_due, + invoices.subtotal, + invoices.tax, + invoices.total, + invoices.amount_paid, + invoices.amount_remaining, + invoices.attempt_count, + invoices.description, + + -- Line Items + invoice_line_items.invoice_line_item_id, + invoice_line_items.line_item_description, + invoice_line_items.line_item_amount, + invoice_line_items.line_item_quantity, + invoice_line_items.period_start, + invoice_line_items.period_end, + + -- Charges + charges.balance_transaction_id, + charges.charge_amount, + charges.charge_status, + charges.created_at as charge_created_at, + + -- Customer Details + customers.customer_description, + customers.customer_email, + customers.customer_id, + + -- Subscription Details + subscriptions.subscription_id, + subscriptions.subscription_billing, + subscriptions.start_date as subscription_start_date, + subscriptions.ended_at as subscription_ended_at, + plans.plan_id, + plans.is_plan_active, + plans.plan_amount, + plans.plan_interval, + plans.plan_interval_count, + plans.plan_nickname, + plans.plan_product_id + from invoices + left join charges + using(charge_id) + left join invoice_line_items + using(invoice_id) + left join subscriptions + on invoice_line_items.subscription_id = subscriptions.subscription_id + left join plans + on invoice_line_items.plan_id = plans.plan_id + left join customers + on customers.customer_id = invoices.customer_id +) + +select * from line_items_summary diff --git a/models/stripe__subscriptions.sql b/models/stripe__subscriptions.sql new file mode 100644 index 0000000..47be96a --- /dev/null +++ b/models/stripe__subscriptions.sql @@ -0,0 +1,101 @@ +with invoices as ( + select + * + from {{ ref('stg_stripe__invoices') }} +), + +charges as ( + select + * + from {{ ref('stg_stripe__charges') }} +), + +invoice_line_items as ( + select + * + from {{ ref('stg_stripe__invoice_line_items') }} + +), + +subscriptions as ( + select + * + from {{ ref('stg_stripe__subscriptions') }} + +), + +customers as ( + select + * + from {{ ref('stg_stripe__customers') }} + +), + +line_items_by_invoice as ( + select + invoices.invoice_id, + invoices.amount_due, + invoices.amount_paid, + invoices.amount_remaining, + invoices.created_at, + max(invoice_line_items.subscription_id) as subscription_id, + sum(invoice_line_items.line_item_amount) as total_item_amount, + count(distinct invoice_line_items.invoice_line_item_id) as number_line_items + from invoice_line_items + left join invoices + using(invoice_id) + {{ dbt_utils.group_by(5) }} +), + +invoice_stats_by_sub as ( + select + subscription_id, + count(distinct invoice_id) as number_invoices_generated, + sum(amount_due) as total_amount_billed, + sum(amount_paid) as total_amount_paid, + sum(amount_remaining) total_amount_remaining, + max(created_at) as most_recent_invoice_created_at, + avg(amount_due) as average_invoice_amount, + avg(total_item_amount) as average_line_item_amount, + avg(number_line_items) as average_num_invoice_items + from line_items_by_invoice + {{ dbt_utils.group_by(1) }} +), + +subscription_stats as ( + select + subscriptions.subscription_id, + subscriptions.customer_id, + customers.customer_description, + customers.customer_email, + subscriptions.status, + subscriptions.start_date, + subscriptions.ended_at, + subscriptions.subscription_billing, + subscriptions.billing_cycle_anchor, + subscriptions.canceled_at, + subscriptions.created_at, + subscriptions.current_period_start, + subscriptions.current_period_end, + subscriptions.trial_start, + subscriptions.trial_end, + subscriptions.days_until_due, + subscriptions.is_cancel_at_period_end, + number_invoices_generated, + total_amount_billed, + total_amount_paid, + total_amount_remaining, + most_recent_invoice_created_at, + average_invoice_amount, + average_line_item_amount, + average_num_invoice_items + from subscriptions + left join invoice_stats_by_sub + using(subscription_id) + left join customers + using(customer_id) +) + +select * from subscription_stats + + diff --git a/models/tmp/int_stripe__daily_customer_stats.sql b/models/tmp/int_stripe__daily_customer_stats.sql new file mode 100644 index 0000000..0c199ab --- /dev/null +++ b/models/tmp/int_stripe__daily_customer_stats.sql @@ -0,0 +1,73 @@ +with customers as ( + select + {{ dbt_utils.date_trunc("day", 'first_sale_date') }} as date, + count(*) as new_customers, + count( + case when + is_delinquent = false and total_sales > 0 + then 1 end + ) as active_new_customers + from + {{ ref('stripe__customers') }} + where + first_sale_date is not null + group by + {{ dbt_utils.date_trunc("day", 'first_sale_date') }} +), + +trials as ( + select + {{ dbt_utils.date_trunc("day", 'created_at') }} as date, + count( + case when + trial_start is not null + then 1 end + ) as trials, + count( + case when + trial_start is not null + and total_amount_billed > 0 + then 1 end + ) as trials_converted_on_day + from + {{ ref('stripe__subscriptions') }} + group by + {{ dbt_utils.date_trunc("day", 'created_at') }} +), + +-- consider a trial converted on the trial end date +trial_conversions as ( + select + {{ dbt_utils.date_trunc("day", 'trial_end') }} as date, + count( + case when + (trial_end is not null + and total_amount_billed > 0) + then 1 end + ) as trials_converted + from + {{ ref('stripe__subscriptions') }} + group by + {{ dbt_utils.date_trunc("day", 'trial_end') }} +), + +customers_over_time as ( + select + daily_overview.date, + coalesce(customers.new_customers, 0) as new_customers, + coalesce(customers.active_new_customers, 0) as new_paying_customers, + sum(coalesce(customers.active_new_customers, 0)) over (order by daily_overview.date rows unbounded preceding) as active_customers, + coalesce(trials.trials, 0) as trials, + coalesce(trial_conversions.trials_converted, 0) as trials_converted, + coalesce(round(cast(trials.trials_converted_on_day as decimal)/nullif(trials.trials, 0), 2) * 100, 0) as trial_conversion_rate + from + {{ref('int_stripe__daily_transactions')}} daily_overview + left join customers + using(date) + left join trials + using(date) + left join trial_conversions + using(date) +) + +select * from customers_over_time \ No newline at end of file diff --git a/models/tmp/int_stripe__daily_transactions.sql b/models/tmp/int_stripe__daily_transactions.sql new file mode 100644 index 0000000..8b7e4c4 --- /dev/null +++ b/models/tmp/int_stripe__daily_transactions.sql @@ -0,0 +1,150 @@ +{%- set date_range_query -%} + select + cast({{ dbt_utils.date_trunc("day",'created_at') }} as date) as min_date, + cast({{ dbt_utils.date_trunc("day", dbt_date.today()) }} as date) as max_date + from + {{ ref('stripe__balance_transactions') }} + order by + created_at asc + limit 1 +{%- endset -%} +{% set date_range = run_query(date_range_query) %} +-- The dbt parser will cause dbt run to fail as these variables are set dynamically. +-- We avoid this by only calling set "in execution" +{% if execute %} + {% set min_date = date_range.columns[0][0] %} + {% set max_date = date_range.columns[1][0] %} +{% endif %} + + +with balance_transactions as ( + select + * + from {{ ref('stripe__balance_transactions') }} +), + +incomplete_charges as ( + select + created_at, + customer_id, + charge_amount + from {{ ref('stg_stripe__charges')}} + where not charge_is_captured +), + +daily_balance_transactions as ( + select + case + when type = 'payout' + then {{ dbt_utils.date_trunc("day", 'available_on') }} + else {{ dbt_utils.date_trunc("day", 'created_at') }} + end as date, + sum( + case when + type in ('charge', 'payment') + then amount + else 0 end + ) as total_sales, + sum(case when + type in ('payment_refund', 'refund') + then amount + else 0 end + ) as total_refunds, + sum(case when + type = 'adjustment' + then amount + else 0 end + ) as total_adjustments, + sum(case when + type not in ('charge', 'payment', 'payment_refund', 'refund', 'adjustment', 'payout') + and type not like '%transfer%' + then amount + else 0 end + ) as total_other_transactions, + sum(case when + type <> 'payout' + and type not like '%transfer%' + then amount + else 0 end + ) as total_gross_transaction_amount, + sum(case when + type <> 'payout' + and type not like '%transfer%' + then net_balance_change + else 0 end + ) as total_net_transactions, + sum(case when + type = 'payout' + or type like '%transfer%' + then fee * -1.0 + else 0 end + ) as total_payout_fees, + sum(case when + type = 'payout' or type like '%transfer%' + then amount + else 0 end + ) as total_gross_payout_amount, + sum(case when + type = 'payout' or type like '%transfer%' + then fee * -1.0 + else net_balance_change end + ) as daily_net_activity, + sum(case when + type in ('payment', 'charge') + then 1 + else 0 end + ) as total_sales_count, + sum(case when + type = 'payout' + then 1 + else 0 end + ) as total_payouts_count, + count(distinct case when + type = 'adjustment' + then coalesce(source, payout_id) + else null end + ) as total_adjustments_count + from balance_transactions + {{ dbt_utils.group_by(1) }} +), + +daily_failed_charges as ( + select + {{ dbt_utils.date_trunc("day",'created_at') }} as date, + count(*) as total_failed_charge_count, + sum(charge_amount) as total_failed_charge_amount + from incomplete_charges + {{ dbt_utils.group_by(1) }} +), + + +date_spine as ( + {{ dbt_date.get_base_dates(start_date=min_date, end_date=max_date) }} +), + +daily_transactions as ( + select + date_spine.date_day as date, + round(coalesce(daily_balance_transactions.total_sales/100.0, 0), 2) as total_sales, + round(coalesce(daily_balance_transactions.total_refunds/100.0, 0), 2) as total_refunds, + round(coalesce(daily_balance_transactions.total_adjustments/100.0, 0), 2) as total_adjustments, + round(coalesce(daily_balance_transactions.total_other_transactions/100.0, 0), 2) as total_other_transactions, + round(coalesce(daily_balance_transactions.total_gross_transaction_amount/100.0, 0), 2) as total_gross_transaction_amount, + round(coalesce(daily_balance_transactions.total_net_transactions/100.0, 0), 2) as total_net_transactions, + round(coalesce(daily_balance_transactions.total_payout_fees/100.0, 0), 2) as total_payout_fees, + round(coalesce(daily_balance_transactions.total_gross_payout_amount/100.0, 0), 2) as total_gross_payout_amount, + round(coalesce(daily_balance_transactions.daily_net_activity/100.0, 0), 2) as daily_net_activity, + round(coalesce((daily_balance_transactions.daily_net_activity + daily_balance_transactions.total_gross_payout_amount)/100.0, 0), 2) as daily_end_balance, + coalesce(daily_balance_transactions.total_sales_count, 0) as total_sales_count, + coalesce(daily_balance_transactions.total_payouts_count, 0) total_payouts_count, + coalesce(daily_balance_transactions.total_adjustments_count, 0) as total_adjustments_count, + coalesce(daily_failed_charges.total_failed_charge_count, 0) as total_failed_charge_count, + round(coalesce(daily_failed_charges.total_failed_charge_amount/100, 0.0), 2) as total_failed_charge_amount + from daily_balance_transactions + left join daily_failed_charges + using(date) + right join date_spine + on daily_balance_transactions.date = date_spine.date_day +) + +select * from daily_transactions \ No newline at end of file diff --git a/models/tmp/int_stripe__subscription_payments.sql b/models/tmp/int_stripe__subscription_payments.sql new file mode 100644 index 0000000..0de4d5e --- /dev/null +++ b/models/tmp/int_stripe__subscription_payments.sql @@ -0,0 +1,63 @@ +with subscription_invoice_number as ( + select + subscription_id, + {{ dbt_utils.date_trunc("day", 'invoice_created_at') }} as created_date, + -- invoice_number is used to determine for the order in which the invoices for a subscription occur + -- This is useful when counting sources of new MRR. We use this as invoice number as it is cardinal. + count(subscription_id) over (partition by subscription_id order by invoice_created_at asc) as invoice_number + from + {{ ref('stripe__invoice_line_items') }} + where + subscription_id is not null + group by + subscription_id, + invoice_created_at +), + +balance_transactions as( + select + * + from + {{ ref('stripe__balance_transactions') }} +), + +subscription_items as ( + select + sub_items.subscription_id, + subscription_invoice_number.invoice_number, + balance_transactions.amount, + balance_transactions.net_balance_change, + balance_transactions.exchange_rate, + sub_items.plan_amount + from + {{ ref('stripe__invoice_line_items') }} sub_items + left join subscription_invoice_number + on subscription_invoice_number.subscription_id=sub_items.subscription_id + and created_date={{ dbt_utils.date_trunc("day", 'invoice_created_at') }} + left join balance_transactions + using(balance_transaction_id) + where + sub_items.subscription_id is not null +), + +subscription_payments as ( + select + subscription_items.subscription_id, + invoice_number, + {{ dbt_utils.date_trunc("day", 'subs.created_at') }} as date, + subs.canceled_at, + subs.customer_email, + subs.status, + subs.average_invoice_amount as average_revenue, + amount, + net_balance_change, + exchange_rate, + plan_amount + from + subscription_items + left join + {{ ref('stripe__subscriptions') }} subs + using(subscription_id) +) + +select * from subscription_payments \ No newline at end of file diff --git a/models/tmp/stg_stripe__balance_transactions.sql b/models/tmp/stg_stripe__balance_transactions.sql new file mode 100644 index 0000000..68beb52 --- /dev/null +++ b/models/tmp/stg_stripe__balance_transactions.sql @@ -0,0 +1,13 @@ +select + id as balance_transaction_id, + {{ dbt_date.from_unixtimestamp('created') }} as created_at, + {{ dbt_date.from_unixtimestamp('available_on') }} as available_on, + fee, + net as net_balance_change, + type, + status, + amount, + currency, + exchange_rate, + source +from {{ var('balance_transactions') }} \ No newline at end of file diff --git a/models/tmp/stg_stripe__charges.sql b/models/tmp/stg_stripe__charges.sql new file mode 100644 index 0000000..8872ec0 --- /dev/null +++ b/models/tmp/stg_stripe__charges.sql @@ -0,0 +1,26 @@ +with charges_card as ( + select + _airbyte_charges_hashid, + brand as card_brand, + funding as card_funding, + country as card_country + from {{ var('charges_card') }} +) + +select + id as charge_id, + customer as customer_id, + receipt_email, + payment_intent as payment_intent_id, + {{ dbt_date.from_unixtimestamp('created') }} as created_at, + status as charge_status, + amount as charge_amount, + currency as charge_currency, + captured as charge_is_captured, + balance_transaction as balance_transaction_id, + card_brand, + card_funding, + card_country +from {{ var('charges') }} +left join charges_card + using(_airbyte_charges_hashid) \ No newline at end of file diff --git a/models/tmp/stg_stripe__customers.sql b/models/tmp/stg_stripe__customers.sql new file mode 100644 index 0000000..29f1d4f --- /dev/null +++ b/models/tmp/stg_stripe__customers.sql @@ -0,0 +1,31 @@ +with customer_addresses as ( + select + _airbyte_customers_hashid, + line1, + line2, + city, + state, + country, + postal_code + from {{ var('customers_address') }} +) + +select + id as customer_id, + {{ dbt_date.from_unixtimestamp('created') }} as created_at, + description as customer_description, + email as customer_email, + delinquent as is_delinquent, + currency as customer_currency, + default_card as default_card_id, + shipping as shipping_name, + line1 as shipping_address_line_1, + line2 as shipping_address_line_2, + city as shipping_address_city, + state as shipping_address_state, + country as shipping_address_country, + postal_code as shipping_address_postal_code, + phone +from {{ var('customers')}} +left join customer_addresses + using(_airbyte_customers_hashid) \ No newline at end of file diff --git a/models/tmp/stg_stripe__invoice_line_items.sql b/models/tmp/stg_stripe__invoice_line_items.sql new file mode 100644 index 0000000..59e7c03 --- /dev/null +++ b/models/tmp/stg_stripe__invoice_line_items.sql @@ -0,0 +1,30 @@ +with invoice_line_items_period as ( + select + _airbyte_invoice_line_items_hashid, + {{ dbt_date.from_unixtimestamp('start') }} as period_start, + {{ dbt_date.from_unixtimestamp('"end"') }} as period_end + from {{ var('invoice_line_items_period') }} +), + +invoice_line_items_plan as ( + select + _airbyte_invoice_line_items_hashid, + id as plan_id + from {{ var('invoice_line_items_plan') }} +) + +select + id as invoice_line_item_id, + invoice_id, + subscription as subscription_id, + plan_id, + description as line_item_description, + amount as line_item_amount, + quantity as line_item_quantity, + period_start, + period_end +from {{ var('invoice_line_items') }} +left join invoice_line_items_period + using(_airbyte_invoice_line_items_hashid) +left join invoice_line_items_plan + using(_airbyte_invoice_line_items_hashid) \ No newline at end of file diff --git a/models/tmp/stg_stripe__invoices.sql b/models/tmp/stg_stripe__invoices.sql new file mode 100644 index 0000000..14085a7 --- /dev/null +++ b/models/tmp/stg_stripe__invoices.sql @@ -0,0 +1,18 @@ +select + id as invoice_id, + {{ dbt_date.from_unixtimestamp('created') }} as created_at, + number as invoice_number, + description, + paid, + total, + subtotal, + tax, + amount_due, + amount_paid, + amount_remaining, + {{ dbt_date.from_unixtimestamp('due_date') }} as due_date, + attempt_count, + charge as charge_id, + status, + customer as customer_id +from {{ var('invoices') }} \ No newline at end of file diff --git a/models/tmp/stg_stripe__payouts.sql b/models/tmp/stg_stripe__payouts.sql new file mode 100644 index 0000000..998e40c --- /dev/null +++ b/models/tmp/stg_stripe__payouts.sql @@ -0,0 +1,8 @@ +select + id as payout_id, + {{ dbt_date.from_unixtimestamp('arrival_date') }} as arrival_date, + status, + type, + description, + balance_transaction as balance_transaction_id +from {{ var('payouts')}} \ No newline at end of file diff --git a/models/tmp/stg_stripe__plans.sql b/models/tmp/stg_stripe__plans.sql new file mode 100644 index 0000000..f362eb2 --- /dev/null +++ b/models/tmp/stg_stripe__plans.sql @@ -0,0 +1,9 @@ +select + id as plan_id, + active as is_plan_active, + amount as plan_amount, + interval as plan_interval, + interval_count as plan_interval_count, + nickname as plan_nickname, + product as plan_product_id +from {{ var('plans') }} \ No newline at end of file diff --git a/models/tmp/stg_stripe__refunds.sql b/models/tmp/stg_stripe__refunds.sql new file mode 100644 index 0000000..ca0d262 --- /dev/null +++ b/models/tmp/stg_stripe__refunds.sql @@ -0,0 +1,8 @@ +select + id as refund_id, + charge as charge_id, + amount as refund_amount, + reason as refund_reason, + status as refund_status, + balance_transaction as balance_transaction_id +from {{ var('refunds')}} \ No newline at end of file diff --git a/models/tmp/stg_stripe__subscriptions.sql b/models/tmp/stg_stripe__subscriptions.sql new file mode 100644 index 0000000..238e4a9 --- /dev/null +++ b/models/tmp/stg_stripe__subscriptions.sql @@ -0,0 +1,17 @@ +select + id as subscription_id, + customer as customer_id, + status, + {{ dbt_date.from_unixtimestamp('start') }} as start_date, + {{ dbt_date.from_unixtimestamp('ended_at') }} as ended_at, + billing as subscription_billing, + {{ dbt_date.from_unixtimestamp('billing_cycle_anchor') }} as billing_cycle_anchor, + {{ dbt_date.from_unixtimestamp('canceled_at') }} as canceled_at, + {{ dbt_date.from_unixtimestamp('created') }} as created_at, + {{ dbt_date.from_unixtimestamp('current_period_start') }} as current_period_start, + {{ dbt_date.from_unixtimestamp('current_period_end') }} as current_period_end, + {{ dbt_date.from_unixtimestamp('trial_start') }} as trial_start, + {{ dbt_date.from_unixtimestamp('trial_end') }} as trial_end, + days_until_due, + cancel_at_period_end as is_cancel_at_period_end +from {{ var('subscriptions') }} \ No newline at end of file diff --git a/packages.yml b/packages.yml index 6482422..f695347 100644 --- a/packages.yml +++ b/packages.yml @@ -1,5 +1,5 @@ packages: - - package: dbt-labs/dbt_utils - version: 0.8.4 + - package: calogica/dbt_date + version: [">=0.5.0", "<0.6.0"] - package: dbt-labs/spark_utils version: [">=0.3.0", "<0.4.0"] \ No newline at end of file