Skip to content
Draft
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
23 changes: 23 additions & 0 deletions dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -13,8 +13,31 @@ models:
netsuite2:
intermediate:
+materialized: ephemeral
# int_netsuite2__cash_flow_classifications:
# +materialized: table

vars:
cash_flow_defaults:
operations:
- condition: "lower(account_type_id) = 'acctrec'"
subcategory: "cash_from_customers"
- condition: "lower(account_type_id) = 'acctpay'"
subcategory: "cash_to_suppliers"
- condition: "lower(account_type_id) in ('expense', 'othcurrliab')"
subcategory: "cash_for_expenses"
- condition: "lower(account_name) like '%good%will%'"
exclude: true

investment:
- condition: "lower(account_type_id) in ('fixedasset', 'othasset', 'deferexpense')"
subcategory: "cash_spent_on_assets"
- condition: "lower(account_type_id) = 'unbilledrec'"
subcategory: "cash_spent_on_investments"

finance:
- condition: "lower(account_type_id) in ('equity', 'longtermliab')"
subcategory: "cash_from_financing"

netsuite:
## Netsuite staging models
netsuite_accounting_books: "{{ ref('stg_netsuite__accounting_books') }}"
Expand Down
2 changes: 1 addition & 1 deletion integration_tests/dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -11,7 +11,7 @@ vars:
netsuite_schema: netsuite_integration_tests_8
netsuite_data_model_override: netsuite

# Enable below when generating docs
## Enable below when generating docs
# netsuite2__multibook_accounting_enabled: true
# netsuite2__using_to_subsidiary: true

Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
{{ config(
enabled = var('netsuite_data_model', 'netsuite') == var('netsuite_data_model_override', 'netsuite2')
) }}

-- load the dictionary with the classification filters
{% set classifications = var('cash_flow_classifications', var('cash_flow_defaults', {})) %}

with transaction_details as (
select *
from {{ ref('netsuite2__transaction_details') }}
),

transaction_classifications as (
select
*,
-- iterate through the categories and filters in classifications
case
{% for category, filters in classifications.items() %}
{% for filter in filters %}
when {{ filter.condition }}
{% if filter.exclude is defined and filter.exclude %}
then null
{% else %}
then '{{ category }}_transactions'
{% endif %}
{% endfor %}
{% endfor %}
else null
end as cash_flow_category,

case
{% for category, filters in classifications.items() %}
{% for filter in filters %}
when {{ filter.condition }}
{% if filter.subcategory is defined %}
then '{{ filter.subcategory }}'
{% else %}
then null
{% endif %}
{% endfor %}
{% endfor %}
else null
end as cash_flow_subcategory
from transaction_details
)

select *
from transaction_classifications
where cash_flow_category is not null
2 changes: 1 addition & 1 deletion models/netsuite2/netsuite2__balance_sheet.sql
Original file line number Diff line number Diff line change
Expand Up @@ -317,4 +317,4 @@ balance_sheet as (
)

select *
from surrogate_key
from surrogate_key
113 changes: 113 additions & 0 deletions models/netsuite2/netsuite2__cash_flow.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,113 @@
{{ config(
enabled = var('netsuite_data_model', 'netsuite') == var('netsuite_data_model_override', 'netsuite2')
) }}

{%- set multibook_enabled = var('netsuite2__multibook_accounting_enabled', false) -%}
{%- set multibook_cols = ['accounting_book_id', 'accounting_book_name'] -%}

{%- set to_subsidiary_enabled = (var('netsuite2__using_to_subsidiary', false) and var('netsuite2__using_exchange_rate', true)) -%}
{%- set to_subsidiary_cols = ['to_subsidiary_id', 'to_subsidiary_name', 'to_subsidiary_currency_symbol'] -%}

{%- set base_cols_list = ['subsidiary_id', 'subsidiary_name'] -%}
{%- do base_cols_list.extend(multibook_cols) if multibook_enabled -%}
{%- do base_cols_list.extend(to_subsidiary_cols) if to_subsidiary_enabled -%}
{%- set base_cols_sql = base_cols_list | join(', ') -%}

{%- set categories = var('cash_flow_classifications', var('cash_flow_defaults', {})).keys() -%}

with cash_flow_classifications as (
select *
from {{ ref('int_netsuite2__cash_flow_classifications') }}
),

aggregated_by_category as (
select
{{ base_cols_sql }},
accounting_period_ending,
cash_flow_category,
sum(transaction_amount) as cash_net_period
from cash_flow_classifications
{{ dbt_utils.group_by(base_cols_list | length + 2) }}
),

pivoted_cash_flow as (
select
{{ base_cols_sql }},
accounting_period_ending,


{%- for category in categories %}
sum(
case when cash_flow_category = '{{ category }}_transactions'
then cash_net_period
else 0 end)
as {{ category }}_cash_flow {{ ',' if not loop.last }}
{%- endfor %}

from aggregated_by_category
{{ dbt_utils.group_by(base_cols_list | length + 1) }}
),

total_cash as (
select
*,
{%- for category in categories %}
{{ category }}_cash_flow {{ '+' if not loop.last }}
{%- endfor %}
as net_cash_flow
from pivoted_cash_flow
),

with_beginning_cash as (
select
*,
lag(net_cash_flow) over (
partition by {{ base_cols_sql }}
order by accounting_period_ending
) as beginning_cash
from total_cash
),

income_statement as (
select *
from {{ ref('netsuite2__income_statement') }}
),

income_statement_classifications as (
select
{{ base_cols_sql }},
accounting_period_ending,
sum(case when lower(account_category) in ('income', 'expense') then transaction_amount else 0 end) as net_income,
sum(case when lower(account_name) like '%depreciation%' or lower(account_name) like '%amortization%' then transaction_amount else 0 end) as non_cash_expenses
from income_statement
{{ dbt_utils.group_by(base_cols_list | length + 1) }}
),

final as (
select
with_beginning_cash.accounting_period_ending,
{% for col in base_cols_list %}
with_beginning_cash.{{ col }},
{% endfor %}

{%- for category in categories %}
with_beginning_cash.{{ category }}_cash_flow ,
{%- endfor %}

with_beginning_cash.net_cash_flow,
with_beginning_cash.beginning_cash,
coalesce(with_beginning_cash.beginning_cash, 0) + with_beginning_cash.net_cash_flow as ending_cash,
income_statement_classifications.net_income,
income_statement_classifications.non_cash_expenses
from with_beginning_cash
left join income_statement_classifications
on with_beginning_cash.accounting_period_ending = income_statement_classifications.accounting_period_ending
and {% for col in base_cols_list %}
with_beginning_cash.{{ col }} = income_statement_classifications.{{ col }}
{% if not loop.last %} and {% endif %}
{% endfor %}
)

select *
from final
order by accounting_period_ending
2 changes: 1 addition & 1 deletion models/netsuite2/netsuite2__income_statement.sql
Original file line number Diff line number Diff line change
Expand Up @@ -203,4 +203,4 @@ surrogate_key as (
)

select *
from surrogate_key
from surrogate_key
2 changes: 1 addition & 1 deletion models/netsuite2/netsuite2__transaction_details.sql
Original file line number Diff line number Diff line change
Expand Up @@ -344,4 +344,4 @@ surrogate_key as (
)

select *
from surrogate_key
from surrogate_key