From c5487fea195d899b05b3bcf7f384602f146b6487 Mon Sep 17 00:00:00 2001 From: Joe Markiewicz <74217849+fivetran-joemarkiewicz@users.noreply.github.com> Date: Fri, 2 Aug 2024 11:29:14 -0500 Subject: [PATCH] bugfix/changing-transactions --- CHANGELOG.md | 15 ++++++ README.md | 2 +- dbt_project.yml | 2 +- integration_tests/.gitignore | 3 +- integration_tests/dbt_project.yml | 4 +- .../netsuite2_accounting_period_data.csv | 6 +-- ...ite2_accounting_period_fiscal_cal_data.csv | 6 +-- .../seeds/netsuite2_subsidiary_data.csv | 4 +- .../seeds/netsuite2_tran_acct_line_data.csv | 6 +-- .../seeds/netsuite2_transaction_data.csv | 7 +-- .../seeds/netsuite2_transaction_line_data.csv | 6 +-- .../consistency_balance_sheet.sql | 46 +++++++++++++++++ .../consistency_income_statement.sql | 46 +++++++++++++++++ .../consistency_transaction_details.sql | 46 +++++++++++++++++ .../row_counts/row_count_balance_sheet.sql | 51 +++++++++++++++++++ .../row_counts/row_count_income_statement.sql | 51 +++++++++++++++++++ .../row_count_transaction_details.sql | 51 +++++++++++++++++++ models/netsuite2/netsuite2__balance_sheet.sql | 3 +- .../netsuite2/netsuite2__income_statement.sql | 2 + .../netsuite2__transaction_details.sql | 3 +- 20 files changed, 337 insertions(+), 23 deletions(-) create mode 100644 integration_tests/tests/consistency/row_comparisons/consistency_balance_sheet.sql create mode 100644 integration_tests/tests/consistency/row_comparisons/consistency_income_statement.sql create mode 100644 integration_tests/tests/consistency/row_comparisons/consistency_transaction_details.sql create mode 100644 integration_tests/tests/consistency/row_counts/row_count_balance_sheet.sql create mode 100644 integration_tests/tests/consistency/row_counts/row_count_income_statement.sql create mode 100644 integration_tests/tests/consistency/row_counts/row_count_transaction_details.sql diff --git a/CHANGELOG.md b/CHANGELOG.md index 5df3c7ae..629856ad 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,20 @@ # dbt_netsuite v0.13.0 +[PR #TBD](https://github.com/fivetran/dbt_netsuite/pull/TBD) includes the following updates: + +## 🚨 Breaking Changes 🚨 +- Adjusts the `transactions_with_converted_amounts` join within the `netsuite2__transaction_details` model to account for the `account_id` which ensures the proper transactions within the designated reporting period are accurately included. Previously, if a transaction had an adjustment to the account_id at the source, duplicates would be brought into the final model for users leveraging incremental strategies. + - A similar join update was applied to the `netsuite2__balance_sheet` and `netsuite2__income_statement` models for when users are leveraging the `balance_sheet_transaction_detail_columns` and `income_statement_transaction_detail_columns` variables respectively. + +## Under the Hood +- Updates to the Netsuite2 seed data to ensure the end models are populated with data during integration tests. +- Addition of Consistency (comparison and row count) tests for the following models: + - `netsuite2__transaction_details` + - `netsuite2__balance_sheet` + - `netsuite2__income_statement` + +# dbt_netsuite v0.13.0 + For Netsuite2, [PR #116](https://github.com/fivetran/dbt_netsuite/pull/116) includes the following updates: ## 🚨 Breaking Changes 🚨 diff --git a/README.md b/README.md index fb64fbe9..56212074 100644 --- a/README.md +++ b/README.md @@ -101,7 +101,7 @@ Include the following netsuite package version in your `packages.yml` file: ```yaml packages: - package: fivetran/netsuite - version: [">=0.13.0", "<0.14.0"] + version: [">=0.14.0", "<0.15.0"] ``` ## Step 3: Define Netsuite.com or Netsuite2 Source As of April 2022 Fivetran made available a new Netsuite connector which leverages the Netsuite2 endpoint opposed to the original Netsuite.com endpoint. This package is designed to run for either or, not both. By default the `netsuite_data_model` variable for this package is set to the original `netsuite` value which runs the netsuite.com version of the package. If you would like to run the package on Netsuite2 data, you may adjust the `netsuite_data_model` variable to run the `netsuite2` version of the package. diff --git a/dbt_project.yml b/dbt_project.yml index d74644d7..3a85094e 100644 --- a/dbt_project.yml +++ b/dbt_project.yml @@ -1,6 +1,6 @@ config-version: 2 name: 'netsuite' -version: '0.13.0' +version: '0.14.0' require-dbt-version: [">=1.3.0", "<2.0.0"] models: diff --git a/integration_tests/.gitignore b/integration_tests/.gitignore index 081571e6..3d970820 100644 --- a/integration_tests/.gitignore +++ b/integration_tests/.gitignore @@ -2,4 +2,5 @@ target/ dbt_modules/ dbt_packages/ env/ -logs/ \ No newline at end of file +logs/ +package-lock.yml \ No newline at end of file diff --git a/integration_tests/dbt_project.yml b/integration_tests/dbt_project.yml index 792e0389..bdc9b2e6 100644 --- a/integration_tests/dbt_project.yml +++ b/integration_tests/dbt_project.yml @@ -1,10 +1,11 @@ name: 'netsuite_integration_tests' -version: '0.13.0' +version: '0.14.0' profile: 'integration_tests' config-version: 2 models: +schema: "{{ 'netsuite_integrations_tests_sqlw' if target.name == 'databricks-sql' else 'netsuite' }}" + # +schema: "netsuite_{{ var('directed_schema','dev') }}" vars: netsuite_schema: netsuite_integration_tests_5 @@ -56,6 +57,7 @@ vars: netsuite2_account_type_identifier: "netsuite2_account_type_data" netsuite2_entity_address_identifier: "netsuite2_entity_address_data" netsuite2_location_main_address_identifier: "netsuite2_location_main_address_data" + seeds: +quote_columns: "{{ true if target.type in ('redshift','postgres') else false }}" netsuite_integration_tests: diff --git a/integration_tests/seeds/netsuite2_accounting_period_data.csv b/integration_tests/seeds/netsuite2_accounting_period_data.csv index bd82e80e..fd636275 100644 --- a/integration_tests/seeds/netsuite2_accounting_period_data.csv +++ b/integration_tests/seeds/netsuite2_accounting_period_data.csv @@ -1,6 +1,6 @@ id,_fivetran_deleted,_fivetran_synced,alllocked,allownonglchanges,aplocked,arlocked,closed,closedondate,date_deleted,enddate,isadjust,isinactive,isposting,isquarter,isyear,lastmodifieddate,parent,periodname,startdate -5,FALSE,2022-07-10 23:00:33,T,F,T,T,T,2002-03-31 0:00:00,,2002-03-31 0:00:00,F,F,T,F,F,2019-02-20 12:32:15,2,Mar 2002,2002-03-01 00:00:00 -8,FALSE,2022-07-10 23:00:33,T,F,T,T,T,2002-05-31 0:00:00,,2002-05-31 0:00:00,F,F,T,F,F,2019-02-20 12:32:15,6,May 2002,2002-05-01 00:00:00 -9,FALSE,2022-07-10 23:00:33,T,F,T,T,T,2002-06-30 0:00:00,,2002-06-30 0:00:00,F,F,T,F,F,2019-02-20 12:32:15,6,Jun 2002,2002-06-01 00:00:00 +280,FALSE,2022-07-10 23:00:33,T,F,T,T,T,2002-03-31 0:00:00,,2002-03-31 0:00:00,F,F,T,F,F,2019-02-20 12:32:15,2,Mar 2002,2002-03-01 00:00:00 +330,FALSE,2022-07-10 23:00:33,T,F,T,T,T,2002-05-31 0:00:00,,2002-05-31 0:00:00,F,F,T,F,F,2019-02-20 12:32:15,6,May 2002,2002-05-01 00:00:00 +348,FALSE,2022-07-10 23:00:33,T,F,T,T,T,2002-06-30 0:00:00,,2002-06-30 0:00:00,F,F,T,F,F,2019-02-20 12:32:15,6,Jun 2002,2002-06-01 00:00:00 21,FALSE,2022-07-10 23:00:33,T,F,T,T,T,2001-02-28 0:00:00,,2001-02-28 0:00:00,F,F,T,F,F,2019-02-20 12:32:15,19,Feb 2001,2001-02-01 00:00:00 20,FALSE,2022-07-10 23:00:33,T,F,T,T,T,2001-01-31 0:00:00,,2001-01-31 0:00:00,F,F,T,F,F,2019-02-20 12:32:15,19,Jan 2001,2001-01-01 00:00:00 \ No newline at end of file diff --git a/integration_tests/seeds/netsuite2_accounting_period_fiscal_cal_data.csv b/integration_tests/seeds/netsuite2_accounting_period_fiscal_cal_data.csv index 7c4d4c21..4886961f 100644 --- a/integration_tests/seeds/netsuite2_accounting_period_fiscal_cal_data.csv +++ b/integration_tests/seeds/netsuite2_accounting_period_fiscal_cal_data.csv @@ -1,7 +1,7 @@ _fivetran_id,_fivetran_deleted,_fivetran_synced,accountingperiod,date_deleted,fiscalcalendar,parent -t6+LTClexXfChh/pMhoj1F9SpSs=,FALSE,2022-07-10 22:17:10,245,,1,244 -hbwug8y6jPTTembEaYVZlsljZuQ=,FALSE,2022-07-10 22:17:10,252,,1,239 -hxkIkIIeDjsG8OgPAlvQVe9a6TE=,FALSE,2022-07-10 22:17:10,275,,1,274 +t6+LTClexXfChh/pMhoj1F9SpSs=,FALSE,2022-07-10 22:17:10,280,,1,244 +hbwug8y6jPTTembEaYVZlsljZuQ=,FALSE,2022-07-10 22:17:10,330,,1,239 +hxkIkIIeDjsG8OgPAlvQVe9a6TE=,FALSE,2022-07-10 22:17:10,348,,1,274 H00Ert0t6kQHovZX4pHHC4N4d0Y=,FALSE,2022-07-10 22:17:10,6,,1,1 KI+pra1uPLFPsBHFuvT/tXCaWdg=,FALSE,2022-07-10 22:17:10,184,,1,171 JIpeyH5xsYzCF0YbPKr7obXrkhA=,FALSE,2022-07-10 22:17:10,218,,1,205 \ No newline at end of file diff --git a/integration_tests/seeds/netsuite2_subsidiary_data.csv b/integration_tests/seeds/netsuite2_subsidiary_data.csv index b0a1f8af..04bf6461 100644 --- a/integration_tests/seeds/netsuite2_subsidiary_data.csv +++ b/integration_tests/seeds/netsuite2_subsidiary_data.csv @@ -1,3 +1,3 @@ id,_fivetran_deleted,_fivetran_synced,country,currency,date_deleted,dropdownstate,edition,email,externalid,fax,federalidnumber,fiscalcalendar,fullname,iselimination,isinactive,languagelocale,lastmodifieddate,legalname,mainaddress,name,parent,purchaseorderamount,purchaseorderquantity,purchaseorderquantitydiff,receiptamount,receiptquantity,receiptquantitydiff,returnaddress,shippingaddress,showsubsidiaryname,ssnortin,state,state1taxnumber,tranprefix,url -4,FALSE,2022-07-10 23:14:17,US,1,,AK,US,,,,,1,CeCe,F,F,en_US,2019-07-06 21:13:49,,1126,Meow Meow,3,,,,,,,,,F,,AK,,, -6,FALSE,2022-05-27 13:56:54,US,1,,GA,US,,,,,1,Cat Jam,F,F,en_US,2017-06-13 5:39:53,,4659,Purr,3,,,,,,,,,F,,GA,,, \ No newline at end of file +4,FALSE,2022-07-10 23:14:17,US,1,,AK,US,,,,,1,CeCe,F,F,en_US,2019-07-06 21:13:49,,1126,Meow Meow,4,,,,,,,,,F,,AK,,, +6,FALSE,2022-05-27 13:56:54,US,1,,GA,US,,,,,1,Cat Jam,F,F,en_US,2017-06-13 5:39:53,,4659,Purr,,,,,,,,,,F,,GA,,, \ No newline at end of file diff --git a/integration_tests/seeds/netsuite2_tran_acct_line_data.csv b/integration_tests/seeds/netsuite2_tran_acct_line_data.csv index aef24e63..3010a501 100644 --- a/integration_tests/seeds/netsuite2_tran_acct_line_data.csv +++ b/integration_tests/seeds/netsuite2_tran_acct_line_data.csv @@ -1,6 +1,6 @@ accountingbook,transaction,transactionline,_fivetran_deleted,_fivetran_synced,account,amount,amountpaid,amountunpaid,credit,date_deleted,debit,exchangerate,netamount,overheadparentitem,paymentamountunused,paymentamountused,posting,amountlinked -1,4735,0,FALSE,2022-07-10 22:40:48,,,,,,,,1,,,,,T,0 -1,4455,0,FALSE,2022-07-10 22:40:48,,,,,,,,1,,,,,T,0 -1,2399,0,FALSE,2022-07-10 22:40:48,,,,,,,,1,,,,,T,0 +1,5914,5,FALSE,2022-07-10 22:40:48,133,,,,,,,1,,,,,T,0 +1,3,5,FALSE,2022-07-10 22:40:48,157,,,,,,,1,,,,,T,0 +1,302,4,FALSE,2022-07-10 22:40:48,118,,,,,,,1,,,,,T,0 1,4458,0,FALSE,2022-07-10 22:40:48,,,,,,,,1,,,,,T,0 1,4533,0,FALSE,2022-07-10 22:40:48,,,,,,,,1,,,,,T,0 \ No newline at end of file diff --git a/integration_tests/seeds/netsuite2_transaction_data.csv b/integration_tests/seeds/netsuite2_transaction_data.csv index 9bcf7c2b..a1d9b00e 100644 --- a/integration_tests/seeds/netsuite2_transaction_data.csv +++ b/integration_tests/seeds/netsuite2_transaction_data.csv @@ -1,4 +1,5 @@ _fivetran_synced,id,transactionnumber,type,memo,trandate,status,createddate,duedate,closedate,currency,entity,postingperiod,posting,isreversal -2022-05-27 13:41:13,5914,,VendBill,,2017-05-07 0:00:00,A,2017-05-07 10:34:43,2017-05-05 0:00:00,,1,1570,,T,F -2022-05-27 13:41:13,3,,VendBill,,2015-09-10 0:00:00,B,2017-05-12 3:41:25,2015-10-09 0:00:00,2015-10-05 0:00:00,1,36,251,T,F -2022-05-27 13:41:13,302,,VendBill,ZZZZZ,2016-03-20 0:00:00,B,2017-04-25 3:41:25,2016-04-19 0:00:00,2017-05-07 0:00:00,1,5,261,T,F \ No newline at end of file +2022-05-27 13:41:13,5914,,VendBill,,2024-08-02,A,2024-08-02,2024-08-02,,1,1570,280,T,F +2022-05-27 13:41:13,3,,VendBill,,2024-08-02,B,2024-08-02,2024-08-02,2024-08-02,1,36,330,T,F +2022-05-27 13:41:13,302,,VendBill,ZZZZZ,2024-08-02,B,2024-08-02,2024-08-02,2024-08-02,1,5,348,T,F +,,,,,,,,,,,,,, \ No newline at end of file diff --git a/integration_tests/seeds/netsuite2_transaction_line_data.csv b/integration_tests/seeds/netsuite2_transaction_line_data.csv index 9854895a..f32a5749 100644 --- a/integration_tests/seeds/netsuite2_transaction_line_data.csv +++ b/integration_tests/seeds/netsuite2_transaction_line_data.csv @@ -1,6 +1,6 @@ id,transaction,_fivetran_deleted,_fivetran_synced,actualshipdate,amortizationenddate,amortizationresidual,amortizationsched,amortizstartdate,amountlinked,assemblycomponent,billeddate,billingschedule,billvariancestatus,blandedcost,bomquantity,buildvariance,category,chargetype,class,cleared,cleareddate,commitinventory,commitmentfirm,componentyield,costestimate,costestimaterate,costestimatetype,createdfrom,createdpo,creditforeignamount,custcol1,custcol3,custcol4,custcol5,custcol6,custcol_far_trn_relatedasset,custcol_gw_inv,custcol_hand,custcol_helmetsize,custcol_pfc_configuration,custcol_pfc_pfconfigurator,custcol_pfc_wo,custcol_ropetype,date_deleted,debitforeignamount,department,documentnumber,donotdisplayline,dropship,entity,estgrossprofit,estgrossprofitpercent,estimatedamount,expectedreceiptdate,expectedshipdate,expenseaccount,foreignamount,foreignamountpaid,foreignamountunpaid,foreignpaymentamountunused,foreignpaymentamountused,fulfillable,fxamountlinked,hasfulfillableitems,inventoryreportinglocation,isbillable,isclosed,iscogs,isfullyshipped,isfxvariance,isinventoryaffecting,isrevrectransaction,isscrap,item,itemsource,itemtype,kitcomponent,kitmemberof,landedcostcategory,landedcostperline,linelastmodifieddate,linesequencenumber,location,mainline,matchbilltoreceipt,memo,netamount,oldcommitmentfirm,operationdisplaytext,orderpriority,paymentmethod,price,processedbyrevcommit,quantity,quantitybackordered,quantitybilled,quantitycommitted,quantitypacked,quantitypicked,quantityrejected,quantityshiprecv,rate,rateamount,ratepercent,requestnote,revenueelement,shipmethod,specialorder,subsidiary,taxline,transactiondiscount,transactionlinetype,transferorderitemlineid,uniquekey,units,vsoeisestimate -5,2542,FALSE,2022-05-27 13:29:19,,,,,,,T,,,,F,,,,,,F,,1,F,,,,,,,,,,,,,,,,,,,,,,,,,T,F,541,,,,,2017-05-31 0:00:00,,,,,,,T,0,F,,F,F,F,F,F,F,F,F,80,,InvtPart,F,1,,F,2017-05-01 19:42:52,5,,F,F,Elden Ring,,F,,,,1,,-2,,0,,0,0,0,0,,,,,,,F,1,F,F,,,1471,, -5,2187,FALSE,2022-05-27 13:29:17,,,,,,,T,,,,F,,,,,,F,,1,F,,,,,2186,,,,,,,,,,,,,,,,,,,,T,F,1296,,,,,2017-05-26 0:00:00,,,,,,,T,0,F,,F,F,F,F,F,F,F,F,252,,InvtPart,F,1,,F,2017-05-16 11:46:05,5,,F,F,The Witcher 3: The Wild Hunt,,F,,,,1,,-2,,0,,0,0,0,0,,,,,,,F,1,F,F,,,17717,, -4,2248,FALSE,2022-05-27 13:29:17,,,,,,,T,,,,F,,,,,,F,,1,F,,,,,2247,,,,,,,,,,,,,,,,,,,,T,F,1049,,,,,,,,,,,,T,0,F,,F,F,F,F,F,F,F,F,385,WORK_ORDER,InvtPart,F,1,,F,2017-05-29 10:35:27,4,,F,F,Outer Wilds,,F,,,,1,,-4,,0,,0,0,0,0,,,,,,,F,1,F,F,,,29504,, +5,5914,FALSE,2022-05-27 13:29:19,,,,,,,T,,,,F,,,,,,F,,1,F,,,,,,,,,,,,,,,,,,,,,,,,,T,F,541,,,,,2017-05-31 0:00:00,,,,,,,T,0,F,,F,F,F,F,F,F,F,F,80,,InvtPart,F,1,,F,2017-05-01 19:42:52,5,,F,F,Elden Ring,,F,,,,1,,-2,,0,,0,0,0,0,,,,,,,F,4,F,F,,,1471,, +5,3,FALSE,2022-05-27 13:29:17,,,,,,,T,,,,F,,,,,,F,,1,F,,,,,2186,,,,,,,,,,,,,,,,,,,,T,F,1296,,,,,2017-05-26 0:00:00,,,,,,,T,0,F,,F,F,F,F,F,F,F,F,252,,InvtPart,F,1,,F,2017-05-16 11:46:05,5,,F,F,The Witcher 3: The Wild Hunt,,F,,,,1,,-2,,0,,0,0,0,0,,,,,,,F,4,F,F,,,17717,, +4,302,FALSE,2022-05-27 13:29:17,,,,,,,T,,,,F,,,,,,F,,1,F,,,,,2247,,,,,,,,,,,,,,,,,,,,T,F,1049,,,,,,,,,,,,T,0,F,,F,F,F,F,F,F,F,F,385,WORK_ORDER,InvtPart,F,1,,F,2017-05-29 10:35:27,4,,F,F,Outer Wilds,,F,,,,1,,-4,,0,,0,0,0,0,,,,,,,F,4,F,F,,,29504,, 3,725,FALSE,2022-05-27 13:29:17,,,,,,,F,,,,F,,,,,,F,,1,F,,,,,,,,,,,,,,,,,,,,,,,,,T,F,827,,,,,,,,,,,,T,0,F,,F,F,F,F,F,F,F,F,57,,InvtPart,T,2,,F,2017-05-02 10:13:14,3,,F,F,Xcom,,F,,,,-1,,-120,,0,,0,0,0,0,,,,,,,F,1,F,F,,,19043,, 5,613,FALSE,2022-05-27 13:29:17,,,,,,,F,,,,F,,,,,,F,,1,F,,,,,,,,,,,,,,,,,,,,,,,,,T,F,737,,,,,,,,,,,,T,0,F,,F,F,F,F,F,F,F,F,53,,InvtPart,T,4,,F,2017-05-02 10:13:14,5,,F,F,Dark Souls,,F,,,,-1,,-10,,0,,0,0,0,0,,,,,,,F,1,F,F,,,27854,, \ No newline at end of file diff --git a/integration_tests/tests/consistency/row_comparisons/consistency_balance_sheet.sql b/integration_tests/tests/consistency/row_comparisons/consistency_balance_sheet.sql new file mode 100644 index 00000000..add542a9 --- /dev/null +++ b/integration_tests/tests/consistency/row_comparisons/consistency_balance_sheet.sql @@ -0,0 +1,46 @@ +{{ config( + tags="fivetran_validations", + enabled=var('fivetran_validation_tests_enabled', false) +) }} + +-- this test ensures the daily_activity end model matches the prior version +with prod as ( + select * + from {{ target.schema }}_netsuite_prod.netsuite2__balance_sheet +), + +dev as ( + select * + from {{ target.schema }}_netsuite_dev.netsuite2__balance_sheet +), + +prod_not_in_dev as ( + -- rows from prod not found in dev + select * from prod + except distinct + select * from dev +), + +dev_not_in_prod as ( + -- rows from dev not found in prod + select * from dev + except distinct + select * from prod +), + +final as ( + select + *, + 'from prod' as source + from prod_not_in_dev + + union all -- union since we only care if rows are produced + + select + *, + 'from dev' as source + from dev_not_in_prod +) + +select * +from final \ No newline at end of file diff --git a/integration_tests/tests/consistency/row_comparisons/consistency_income_statement.sql b/integration_tests/tests/consistency/row_comparisons/consistency_income_statement.sql new file mode 100644 index 00000000..1657ef41 --- /dev/null +++ b/integration_tests/tests/consistency/row_comparisons/consistency_income_statement.sql @@ -0,0 +1,46 @@ +{{ config( + tags="fivetran_validations", + enabled=var('fivetran_validation_tests_enabled', false) +) }} + +-- this test ensures the daily_activity end model matches the prior version +with prod as ( + select * + from {{ target.schema }}_netsuite_prod.netsuite2__income_statement +), + +dev as ( + select * + from {{ target.schema }}_netsuite_dev.netsuite2__income_statement +), + +prod_not_in_dev as ( + -- rows from prod not found in dev + select * from prod + except distinct + select * from dev +), + +dev_not_in_prod as ( + -- rows from dev not found in prod + select * from dev + except distinct + select * from prod +), + +final as ( + select + *, + 'from prod' as source + from prod_not_in_dev + + union all -- union since we only care if rows are produced + + select + *, + 'from dev' as source + from dev_not_in_prod +) + +select * +from final \ No newline at end of file diff --git a/integration_tests/tests/consistency/row_comparisons/consistency_transaction_details.sql b/integration_tests/tests/consistency/row_comparisons/consistency_transaction_details.sql new file mode 100644 index 00000000..fd1318a1 --- /dev/null +++ b/integration_tests/tests/consistency/row_comparisons/consistency_transaction_details.sql @@ -0,0 +1,46 @@ +{{ config( + tags="fivetran_validations", + enabled=var('fivetran_validation_tests_enabled', false) +) }} + +-- this test ensures the daily_activity end model matches the prior version +with prod as ( + select * + from {{ target.schema }}_netsuite_prod.netsuite2__transaction_details +), + +dev as ( + select * + from {{ target.schema }}_netsuite_dev.netsuite2__transaction_details +), + +prod_not_in_dev as ( + -- rows from prod not found in dev + select * from prod + except distinct + select * from dev +), + +dev_not_in_prod as ( + -- rows from dev not found in prod + select * from dev + except distinct + select * from prod +), + +final as ( + select + *, + 'from prod' as source + from prod_not_in_dev + + union all -- union since we only care if rows are produced + + select + *, + 'from dev' as source + from dev_not_in_prod +) + +select * +from final \ No newline at end of file diff --git a/integration_tests/tests/consistency/row_counts/row_count_balance_sheet.sql b/integration_tests/tests/consistency/row_counts/row_count_balance_sheet.sql new file mode 100644 index 00000000..29d62dc2 --- /dev/null +++ b/integration_tests/tests/consistency/row_counts/row_count_balance_sheet.sql @@ -0,0 +1,51 @@ +{{ config( + tags="fivetran_validations", + enabled=var('fivetran_validation_tests_enabled', false) +) }} + +-- this test is to make sure the rows counts are the same between versions +with prod as ( + select + account_id, + accounting_period_id, + subsidiary_id, + count(*) as prod_rows, + sum(converted_amount) as prod_total_sum + from {{ target.schema }}_netsuite_prod.netsuite2__balance_sheet + where date(accounting_period_ending) < date({{ dbt.current_timestamp() }}) + group by 1,2,3 +), + +dev as ( + select + account_id, + accounting_period_id, + subsidiary_id, + count(*) as dev_rows, + sum(converted_amount) as dev_total_sum + from {{ target.schema }}_netsuite_dev.netsuite2__balance_sheet + where date(accounting_period_ending) < date({{ dbt.current_timestamp() }}) + group by 1,2,3 +), + +final as ( + select + prod.account_id, + prod.accounting_period_id, + prod.subsidiary_id, + round(prod.prod_rows,2) as prod_rows, + round(dev.dev_rows,2) as dev_rows, + round(prod.prod_total_sum,2) as prod_total_sum, + round(dev.dev_total_sum,2) as dev_total_sum + from prod + full outer join dev + on dev.account_id = prod.account_id + and dev.subsidiary_id = prod.subsidiary_id + and dev.accounting_period_id = prod.accounting_period_id +) + +select * +from final +where prod_rows != dev_rows + or prod_total_sum != dev_total_sum + diff --git a/integration_tests/tests/consistency/row_counts/row_count_income_statement.sql b/integration_tests/tests/consistency/row_counts/row_count_income_statement.sql new file mode 100644 index 00000000..5259e2d9 --- /dev/null +++ b/integration_tests/tests/consistency/row_counts/row_count_income_statement.sql @@ -0,0 +1,51 @@ +{{ config( + tags="fivetran_validations", + enabled=var('fivetran_validation_tests_enabled', false) +) }} + +-- this test is to make sure the rows counts are the same between versions +with prod as ( + select + account_id, + accounting_period_id, + subsidiary_id, + count(*) as prod_rows, + sum(converted_amount) as prod_total_sum + from {{ target.schema }}_netsuite_prod.netsuite2__income_statement + where date(accounting_period_ending) < date({{ dbt.current_timestamp() }}) + group by 1,2,3 +), + +dev as ( + select + account_id, + accounting_period_id, + subsidiary_id, + count(*) as dev_rows, + sum(converted_amount) as dev_total_sum + from {{ target.schema }}_netsuite_dev.netsuite2__income_statement + where date(accounting_period_ending) < date({{ dbt.current_timestamp() }}) + group by 1,2,3 +), + +final as ( + select + prod.account_id, + prod.accounting_period_id, + prod.subsidiary_id, + round(prod.prod_rows,2) as prod_rows, + round(dev.dev_rows,2) as dev_rows, + round(prod.prod_total_sum,2) as prod_total_sum, + round(dev.dev_total_sum,2) as dev_total_sum + from prod + full outer join dev + on dev.account_id = prod.account_id + and dev.subsidiary_id = prod.subsidiary_id + and dev.accounting_period_id = prod.accounting_period_id +) + +select * +from final +where prod_rows != dev_rows + or prod_total_sum != dev_total_sum + diff --git a/integration_tests/tests/consistency/row_counts/row_count_transaction_details.sql b/integration_tests/tests/consistency/row_counts/row_count_transaction_details.sql new file mode 100644 index 00000000..4bd1a644 --- /dev/null +++ b/integration_tests/tests/consistency/row_counts/row_count_transaction_details.sql @@ -0,0 +1,51 @@ +{{ config( + tags="fivetran_validations", + enabled=var('fivetran_validation_tests_enabled', false) +) }} + +-- this test is to make sure the rows counts are the same between versions +with prod as ( + select + account_id, + accounting_period_id, + subsidiary_id, + count(*) as prod_rows, + sum(converted_amount) as prod_total_sum + from {{ target.schema }}_netsuite_prod.netsuite2__transaction_details + where date(transaction_date) < date({{ dbt.current_timestamp() }}) + group by 1,2,3 +), + +dev as ( + select + account_id, + accounting_period_id, + subsidiary_id, + count(*) as dev_rows, + sum(converted_amount) as dev_total_sum + from {{ target.schema }}_netsuite_dev.netsuite2__transaction_details + where date(transaction_date) < date({{ dbt.current_timestamp() }}) + group by 1,2,3 +), + +final as ( + select + prod.account_id, + prod.accounting_period_id, + prod.subsidiary_id, + round(prod.prod_rows,2) as prod_rows, + round(dev.dev_rows,2) as dev_rows, + round(prod.prod_total_sum,2) as prod_total_sum, + round(dev.dev_total_sum,2) as dev_total_sum + from prod + full outer join dev + on dev.account_id = prod.account_id + and dev.subsidiary_id = prod.subsidiary_id + and dev.accounting_period_id = prod.accounting_period_id +) + +select * +from final +where prod_rows != dev_rows + or prod_total_sum != dev_total_sum + diff --git a/models/netsuite2/netsuite2__balance_sheet.sql b/models/netsuite2/netsuite2__balance_sheet.sql index 89ff096b..d51f0f3f 100644 --- a/models/netsuite2/netsuite2__balance_sheet.sql +++ b/models/netsuite2/netsuite2__balance_sheet.sql @@ -246,7 +246,8 @@ balance_sheet as ( left join transaction_details on transaction_details.transaction_id = transactions_with_converted_amounts.transaction_id and transaction_details.transaction_line_id = transactions_with_converted_amounts.transaction_line_id - + and transaction_details.account_id = transactions_with_converted_amounts.account_id + {% if var('netsuite2__multibook_accounting_enabled', false) %} and transaction_details.accounting_book_id = transactions_with_converted_amounts.accounting_book_id {% endif %} diff --git a/models/netsuite2/netsuite2__income_statement.sql b/models/netsuite2/netsuite2__income_statement.sql index ab1568bb..9cbc9e81 100644 --- a/models/netsuite2/netsuite2__income_statement.sql +++ b/models/netsuite2/netsuite2__income_statement.sql @@ -168,6 +168,8 @@ income_statement as ( join transaction_details on transaction_details.transaction_id = transactions_with_converted_amounts.transaction_id and transaction_details.transaction_line_id = transactions_with_converted_amounts.transaction_line_id + and transaction_details.account_id = transactions_with_converted_amounts.account_id + {% if var('netsuite2__multibook_accounting_enabled', false) %} and transaction_details.accounting_book_id = transactions_with_converted_amounts.accounting_book_id {% endif %} diff --git a/models/netsuite2/netsuite2__transaction_details.sql b/models/netsuite2/netsuite2__transaction_details.sql index 2e15584a..e0d50bd0 100644 --- a/models/netsuite2/netsuite2__transaction_details.sql +++ b/models/netsuite2/netsuite2__transaction_details.sql @@ -199,7 +199,8 @@ transaction_details as ( on transactions_with_converted_amounts.transaction_line_id = transaction_lines.transaction_line_id and transactions_with_converted_amounts.transaction_id = transaction_lines.transaction_id and transactions_with_converted_amounts.transaction_accounting_period_id = transactions_with_converted_amounts.reporting_accounting_period_id - + and transactions_with_converted_amounts.account_id = transaction_lines.account_id + {% if var('netsuite2__multibook_accounting_enabled', false) %} and transactions_with_converted_amounts.accounting_book_id = transaction_lines.accounting_book_id {% endif %}