diff --git a/src/main/resources/reports/invoice_credits_daily/README.md b/src/main/resources/reports/invoice_credits_daily/README.md new file mode 100644 index 00000000..24e1dc2a --- /dev/null +++ b/src/main/resources/reports/invoice_credits_daily/README.md @@ -0,0 +1,42 @@ +# Daily Invoice Credits Report + +Total of invoice credits per tenant, per currency and per day. + +So if there is an unpaid invoice for `$20` on `2025-09-22`, and an account credit is added for `$100` on the same day, there is a invoice credit of `$80` which will be shown on this report. If however, a new charge of `$200` is created later on on the same day, the `$80` credit is consumed so the total credit displayed by the report for `2025-09-22` is now `$0`. + +The snapshot view is: [v_report_invoice_item_credits_daily](v_report_invoice_item_credits_daily.ddl) + +## Timeline configuration + +``` +curl -v \ + -X POST \ + -u admin:password \ + -H "X-Killbill-ApiKey:bob" \ + -H "X-Killbill-ApiSecret:lazar" \ + -H 'Content-Type: application/json' \ + -d '{"reportName": "report_daily_invoice_credits", + "reportType": "TIMELINE", + "reportPrettyName": "Invoice Credits Daily", + "sourceTableName": "report_invoice_credits_daily", + "refreshProcedureName": "refresh_report_invoice_credits_daily", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Sample Data + +| Tenant Record Id | Currency | Day | Count | +|------------------|----------|------------|----------| +| 1 | USD | 2025-05-05 | 0.0000 | +| 1 | USD | 2025-09-19 | 80.0000 | +| 22 | USD | 2025-09-19 | 125.0000 | +| 22 | EUR | 2025-09-22 | 45.0000 | +| 22 | USD | 2025-09-18 | -10.0000 | + +This means that on `2025-09-19`, there was a total invoice credit of `$80` for the tenant_record_id=1. + + +## Report UI: + +![invoice-credits-daily.png](invoice-credits-daily.png) \ No newline at end of file diff --git a/src/main/resources/reports/invoice_credits_daily/invoice-credits-daily.png b/src/main/resources/reports/invoice_credits_daily/invoice-credits-daily.png new file mode 100644 index 00000000..720d0fba Binary files /dev/null and b/src/main/resources/reports/invoice_credits_daily/invoice-credits-daily.png differ diff --git a/src/main/resources/reports/invoice_credits_daily/report_invoice_credits_daily.ddl b/src/main/resources/reports/invoice_credits_daily/report_invoice_credits_daily.ddl new file mode 100644 index 00000000..a3906e67 --- /dev/null +++ b/src/main/resources/reports/invoice_credits_daily/report_invoice_credits_daily.ddl @@ -0,0 +1,19 @@ +create table report_invoice_credits_daily as select * from v_report_invoice_credits_daily limit 0; + +drop procedure if exists refresh_report_invoice_credits_daily; +DELIMITER // +CREATE PROCEDURE refresh_report_invoice_credits_daily() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +START TRANSACTION; + delete from report_invoice_credits_daily; + insert into report_invoice_credits_daily select * from v_report_invoice_credits_daily; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/v_report_invoice_item_credits_daily.ddl b/src/main/resources/reports/invoice_credits_daily/v_report_invoice_credits_daily.ddl similarity index 77% rename from src/main/resources/reports/v_report_invoice_item_credits_daily.ddl rename to src/main/resources/reports/invoice_credits_daily/v_report_invoice_credits_daily.ddl index f8252cae..0f87f90e 100644 --- a/src/main/resources/reports/v_report_invoice_item_credits_daily.ddl +++ b/src/main/resources/reports/invoice_credits_daily/v_report_invoice_credits_daily.ddl @@ -1,4 +1,4 @@ -create or replace view v_report_invoice_item_credits_daily as +create or replace view v_report_invoice_credits_daily as select aic.tenant_record_id , aic.currency diff --git a/src/main/resources/reports/invoice_item_adjustments_daily/README.md b/src/main/resources/reports/invoice_item_adjustments_daily/README.md new file mode 100644 index 00000000..11d12fdb --- /dev/null +++ b/src/main/resources/reports/invoice_item_adjustments_daily/README.md @@ -0,0 +1,45 @@ +# Daily Invoice Item Adjustments report + +Total of invoice item adjustments per tenant, per currency and per day. + +So if there is an invoice for `$100` created on `2025-09-21` and the invoice is adjusted for `$20`, this report will show a value of `-20` for the date `2025-09-21` for the particular tenant. If there are multiple invoice item adjustments for the tenant on the same day, they will be added up. + +The snapshot view is: [v_report_invoice_item_adjustments_daily](v_report_invoice_item_adjustments_daily.ddl) + +## Timeline configuration + +``` +curl -v \ + -X POST \ + -u admin:password \ + -H "X-Killbill-ApiKey:bob" \ + -H "X-Killbill-ApiSecret:lazar" \ + -H 'Content-Type: application/json' \ + -d '{"reportName": "report_daily_invoice_item_adjustments", + "reportType": "TIMELINE", + "reportPrettyName": "Invoice Item Adjustments Daily", + "sourceTableName": "report_invoice_item_adjustments_daily", + "refreshProcedureName": "refresh_report_invoice_item_adjustments_daily", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Sample Data + +| Tenant Record Id | Currency | Date | Count | +|------------------|----------|------------|-----------| +| 1 | EUR | 2025-08-28 | -10.0000 | +| 1 | USD | 2025-08-29 | | +| 1 | EUR | 2025-08-29 | -50.0000 | +| 1 | EUR | 2025-09-01 | -16.0000 | +| 1 | USD | 2025-09-16 | | +| 1 | EUR | 2025-09-02 | -19.9500 | +| 5 | USD | 2025-09-05 | -109.9500 | +| 1 | USD | 2025-09-19 | -19.3100 | +| 489 | USD | 2025-09-19 | -10.0000 | + +This means that on the date `2025-08-28`, the tenant with record id=1 had a total invoice adjustments of EUR 10. + +## Report UI: + +![invoice_item_adjustments_daily.png](invoice_item_adjustments_daily.png) \ No newline at end of file diff --git a/src/main/resources/reports/invoice_item_adjustments_daily/invoice_item_adjustments_daily.png b/src/main/resources/reports/invoice_item_adjustments_daily/invoice_item_adjustments_daily.png new file mode 100644 index 00000000..863630e5 Binary files /dev/null and b/src/main/resources/reports/invoice_item_adjustments_daily/invoice_item_adjustments_daily.png differ diff --git a/src/main/resources/reports/invoice_item_adjustments_daily/report_invoice_item_adjustments_daily.ddl b/src/main/resources/reports/invoice_item_adjustments_daily/report_invoice_item_adjustments_daily.ddl new file mode 100644 index 00000000..ec961ea9 --- /dev/null +++ b/src/main/resources/reports/invoice_item_adjustments_daily/report_invoice_item_adjustments_daily.ddl @@ -0,0 +1,19 @@ +create table report_invoice_item_adjustments_daily as select * from v_report_invoice_item_adjustments_daily limit 0; + +drop procedure if exists refresh_report_invoice_item_adjustments_daily; +DELIMITER // +CREATE PROCEDURE refresh_report_invoice_item_adjustments_daily() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +START TRANSACTION; + delete from report_invoice_item_adjustments_daily; + insert into report_invoice_item_adjustments_daily select * from v_report_invoice_item_adjustments_daily; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/v_report_invoice_item_adjustments_daily.ddl b/src/main/resources/reports/invoice_item_adjustments_daily/v_report_invoice_item_adjustments_daily.ddl similarity index 100% rename from src/main/resources/reports/v_report_invoice_item_adjustments_daily.ddl rename to src/main/resources/reports/invoice_item_adjustments_daily/v_report_invoice_item_adjustments_daily.ddl diff --git a/src/main/resources/reports/overdue-states-count-daily/README.md b/src/main/resources/reports/overdue-states-count-daily/README.md new file mode 100644 index 00000000..e377e89b --- /dev/null +++ b/src/main/resources/reports/overdue-states-count-daily/README.md @@ -0,0 +1,44 @@ +# Daily Overdue Count Report + +Count of overdue states per tenant and per day. + +The snapshot view is: [v_report_overdue_states_count_daily](v_report_overdue_states_count_daily.ddl) + +## Timeline configuration + +``` +curl -v \ + -X POST \ + -u admin:password \ + -H "X-Killbill-ApiKey:bob" \ + -H "X-Killbill-ApiSecret:lazar" \ + -H 'Content-Type: application/json' \ + -d '{"reportName": "report_overdue_states_count_daily", + "reportType": "TIMELINE", + "reportPrettyName": "Daily Overdue Count", + "sourceTableName": "report_overdue_states_count_daily", + "refreshProcedureName": "refresh_report_overdue_states_count_daily", + "refreshFrequency": "HOURLY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Sample Data + +| Tenant Record Id | State | Day | Count | +|------------------|--------------|------------|-------| +| 1 | BLOCKED | 2025-09-15 | 5 | +| 1 | BLOCKED | 2025-09-16 | 5 | +| 22 | BLOCKED | 2025-09-17 | 6 | +| 22 | CANCELLATION | 2025-09-18 | 3 | +| 1 | BLOCKED | 2025-09-18 | 1 | +| 23 | BLOCKED | 2025-09-19 | 7 | +| 45 | CANCELLATION | 2025-09-19 | 5 | + +This means that on `2025-09-15`, 5 accounts were in `BLOCKED` overdue state for the tenant_record_id=1. + +## Report UI: + +![overdue-states-count-daily.png](overdue-states-count-daily.png) + + + diff --git a/src/main/resources/reports/overdue-states-count-daily/overdue-states-count-daily.png b/src/main/resources/reports/overdue-states-count-daily/overdue-states-count-daily.png new file mode 100644 index 00000000..576a5c97 Binary files /dev/null and b/src/main/resources/reports/overdue-states-count-daily/overdue-states-count-daily.png differ diff --git a/src/main/resources/reports/overdue-states-count-daily/report_overdue_states_count_daily.ddl b/src/main/resources/reports/overdue-states-count-daily/report_overdue_states_count_daily.ddl new file mode 100644 index 00000000..1400f5ec --- /dev/null +++ b/src/main/resources/reports/overdue-states-count-daily/report_overdue_states_count_daily.ddl @@ -0,0 +1,19 @@ +create table report_overdue_states_count_daily as select * from v_report_overdue_states_count_daily limit 0; + +drop procedure if exists refresh_report_overdue_states_count_daily; +DELIMITER // +CREATE PROCEDURE refresh_report_overdue_states_count_daily() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +START TRANSACTION; + delete from report_overdue_states_count_daily; + insert into report_overdue_states_count_daily select * from v_report_overdue_states_count_daily; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/v_report_overdue_states_count_daily.ddl b/src/main/resources/reports/overdue-states-count-daily/v_report_overdue_states_count_daily.ddl similarity index 100% rename from src/main/resources/reports/v_report_overdue_states_count_daily.ddl rename to src/main/resources/reports/overdue-states-count-daily/v_report_overdue_states_count_daily.ddl diff --git a/src/main/resources/reports/trial-starts-count-daily/README.md b/src/main/resources/reports/trial-starts-count-daily/README.md new file mode 100644 index 00000000..1a1f2a60 --- /dev/null +++ b/src/main/resources/reports/trial-starts-count-daily/README.md @@ -0,0 +1,42 @@ +# Daily Trials Count Report + +Count of new trial subscriptions per tenant, per day and per product. + +The snapshot view is: [v_report_trial_starts_count_daily](v_report_trial_starts_count_daily.md) + +## Timeline configuration + +``` +curl -v \ + -X POST \ + -u admin:password \ + -H "X-Killbill-ApiKey:bob" \ + -H "X-Killbill-ApiSecret:lazar" \ + -H 'Content-Type: application/json' \ + -d '{"reportName": "report_trials_start_count_daily", + "reportType": "TIMELINE", + "reportPrettyName": "Daily Trials Count", + "sourceTableName": "report_trial_starts_count_daily", + "refreshProcedureName": "refresh_report_trial_starts_count_daily", + "refreshFrequency": "HOURLY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +### Sample Data + +| Tenant Record Id | Day | Product | Count | +|------------------|------------|---------------|-------| +| 1 | 2025-07-01 | Assault-Rifle | 1 | +| 1 | 2025-05-05 | Pistol | 5 | +| 22 | 2025-09-18 | Pistol | 2 | +| 22 | 2025-07-01 | Pistol | 1 | +| 44 | 2025-07-08 | Blowdart | 8 | +| 44 | 2025-06-12 | Pistol | 6 | + +This means that on `2025-09-18`, 2 new subscriptions were started in the `TRIAL` phase for the `Pistol` product and `tenant_record_id=1`. + +## Report UI: + +![daily-trials-count.png](daily-trials-count.png) + + diff --git a/src/main/resources/reports/trial-starts-count-daily/daily-trials-count.png b/src/main/resources/reports/trial-starts-count-daily/daily-trials-count.png new file mode 100644 index 00000000..22c02d93 Binary files /dev/null and b/src/main/resources/reports/trial-starts-count-daily/daily-trials-count.png differ diff --git a/src/main/resources/reports/trial-starts-count-daily/report_trial_starts_count_daily.ddl b/src/main/resources/reports/trial-starts-count-daily/report_trial_starts_count_daily.ddl new file mode 100644 index 00000000..0d131301 --- /dev/null +++ b/src/main/resources/reports/trial-starts-count-daily/report_trial_starts_count_daily.ddl @@ -0,0 +1,19 @@ +create table report_trial_starts_count_daily as select * from v_report_trial_starts_count_daily limit 0; + +drop procedure if exists refresh_report_trial_starts_count_daily; +DELIMITER // +CREATE PROCEDURE refresh_report_trial_starts_count_daily() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +START TRANSACTION; + delete from report_trial_starts_count_daily; + insert into report_trial_starts_count_daily select * from v_report_trial_starts_count_daily; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/v_report_trial_starts_count_daily.ddl b/src/main/resources/reports/trial-starts-count-daily/v_report_trial_starts_count_daily.ddl similarity index 100% rename from src/main/resources/reports/v_report_trial_starts_count_daily.ddl rename to src/main/resources/reports/trial-starts-count-daily/v_report_trial_starts_count_daily.ddl diff --git a/src/main/resources/reports/trial-to-no-trial-conversions_daily/README.md b/src/main/resources/reports/trial-to-no-trial-conversions_daily/README.md new file mode 100644 index 00000000..e1528101 --- /dev/null +++ b/src/main/resources/reports/trial-to-no-trial-conversions_daily/README.md @@ -0,0 +1,45 @@ +# Daily Trials To No Trials Count Report + +Count of subscriptions converting from trial to non-trial per tenant per day. + +The snapshot view is: [v_report_trial_to_no_trial_conversions_daily](v_report_trial_to_no_trial_conversions_daily.ddl) + +## Timeline configuration + +``` +curl -v \ + -X POST \ + -u admin:password \ + -H "X-Killbill-ApiKey:bob" \ + -H "X-Killbill-ApiSecret:lazar" \ + -H 'Content-Type: application/json' \ + -d '{"reportName": "report_trial_to_no_trial_conversions_daily", + "reportType": "TIMELINE", + "reportPrettyName": "Daily Trials to No Trials Count", + "sourceTableName": "report_trial_to_no_trial_conversions_daily", + "refreshProcedureName": "refresh_report_trial_to_no_trial_conversions_daily", + "refreshFrequency": "HOURLY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Sample Data + +| Tenant Record Id | Day | Count | +|------------------|------------|-------| +| 1 | 2025-06-04 | 1 | +| 1 | 2025-10-18 | 3 | +| 22 | 2025-08-07 | 1 | +| 22 | 2025-07-12 | 1 | +| 1 | 2025-01-31 | 1 | +| 45 | 2025-04-04 | 1 | +| 489 | 2025-09-05 | 1 | + +This means that on `2025-10-18`, 3 subscriptions transitioned from the `TRIAL` phase to some other phase for the `tenant_record_id=1`. + + +## Report UI: + +![trial-to-no-trial-conversions.png](trial-to-no-trial-conversions.png) + + + diff --git a/src/main/resources/reports/trial-to-no-trial-conversions_daily/report_trial-to-no-trial-conversions_daily.ddl b/src/main/resources/reports/trial-to-no-trial-conversions_daily/report_trial-to-no-trial-conversions_daily.ddl new file mode 100644 index 00000000..4b16adf0 --- /dev/null +++ b/src/main/resources/reports/trial-to-no-trial-conversions_daily/report_trial-to-no-trial-conversions_daily.ddl @@ -0,0 +1,19 @@ +create table report_trial_to_no_trial_conversions_daily as select * from v_report_trial_to_no_trial_conversions_daily limit 0; + +drop procedure if exists refresh_report_trial_to_no_trial_conversions_daily; +DELIMITER // +CREATE PROCEDURE refresh_report_trial_to_no_trial_conversions_daily() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +START TRANSACTION; + delete from report_trial_to_no_trial_conversions_daily; + insert into report_trial_to_no_trial_conversions_daily select * from v_report_trial_to_no_trial_conversions_daily; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/trial-to-no-trial-conversions_daily/trial-to-no-trial-conversions.png b/src/main/resources/reports/trial-to-no-trial-conversions_daily/trial-to-no-trial-conversions.png new file mode 100644 index 00000000..e0428e70 Binary files /dev/null and b/src/main/resources/reports/trial-to-no-trial-conversions_daily/trial-to-no-trial-conversions.png differ diff --git a/src/main/resources/reports/v_report_conversions_daily.ddl b/src/main/resources/reports/trial-to-no-trial-conversions_daily/v_report_trial-to-no-trial-conversions_daily.ddl similarity index 70% rename from src/main/resources/reports/v_report_conversions_daily.ddl rename to src/main/resources/reports/trial-to-no-trial-conversions_daily/v_report_trial-to-no-trial-conversions_daily.ddl index 2df30a45..db7fa14a 100644 --- a/src/main/resources/reports/v_report_conversions_daily.ddl +++ b/src/main/resources/reports/trial-to-no-trial-conversions_daily/v_report_trial-to-no-trial-conversions_daily.ddl @@ -1,4 +1,4 @@ -create or replace view v_report_conversions_daily as +create or replace view v_report_trial_to_no_trial_conversions_daily as select ast.tenant_record_id , date_format(ast.next_start_date,'%Y-%m-%d') as day @@ -8,6 +8,7 @@ from where 1=1 and ast.prev_phase='TRIAL' and ast.next_phase!='TRIAL' + and ast.prev_service='billing-service' and ast.report_group='default' group by 1,2 ; diff --git a/src/main/resources/reports/v_report_invoice_adjustments_daily.ddl b/src/main/resources/reports/v_report_invoice_adjustments_daily.ddl deleted file mode 100644 index ad815459..00000000 --- a/src/main/resources/reports/v_report_invoice_adjustments_daily.ddl +++ /dev/null @@ -1,12 +0,0 @@ -create or replace view v_report_invoice_adjustments_daily as -select - aia.tenant_record_id -, aia.currency -, date_format(aia.created_date,'%Y-%m-%d') as day -, sum(aia.converted_amount) as count -from - analytics_invoice_adjustments aia -where 1=1 - and aia.report_group='default' -group by 1,2,3 -; diff --git a/src/main/resources/sanity/README.md b/src/main/resources/sanity/README.md deleted file mode 100644 index 2d47a855..00000000 --- a/src/main/resources/sanity/README.md +++ /dev/null @@ -1,4 +0,0 @@ -These sanity queries verify that the data in the Analytics tables are in sync with the core Kill Bill tables. - -* [account_record_id_sanity.sql](https://github.com/killbill/killbill-analytics-plugin/blob/master/src/main/resources/sanity/account_record_id_sanity.sql): check the account_id/account_record_id mapping in each table is correct -* [sanity.sql](https://github.com/killbill/killbill-analytics-plugin/blob/master/src/main/resources/sanity/sanity.sql): check invariants to make sure the Analytics tables are self-consistent diff --git a/src/main/resources/sanity/account_record_id_sanity.sql b/src/main/resources/sanity/account_record_id_sanity.sql deleted file mode 100644 index 690a7ccd..00000000 --- a/src/main/resources/sanity/account_record_id_sanity.sql +++ /dev/null @@ -1,253 +0,0 @@ -select - 'BAC' as table_name -, count(1) count -from analytics_accounts bac -left outer join accounts a on bac.account_id = a.id -where 1 = 1 -and ( - bac.account_record_id != a.record_id - or bac.account_record_id is null -) -union -select - 'BAC_FIELDS' as table_name -, count(1) count -from analytics_account_fields bac -left outer join accounts a on bac.account_id = a.id -where 1 = 1 -and ( - bac.account_record_id != a.record_id - or a.record_id is null -) -union -select - 'BAC_TAGS' as table_name -, count(1) count -from analytics_account_tags bac -left outer join accounts a on bac.account_id = a.id -where 1 = 1 -and ( - bac.account_record_id != a.record_id - or bac.account_record_id is null -) -union -select - 'BBU' as table_name -, count(1) count -from analytics_bundles bbu -left outer join accounts a on bbu.account_id = a.id -where 1 = 1 -and ( - bbu.account_record_id != a.record_id - or bbu.account_record_id is null -) -union -select - 'BBU_FIELDS' as table_name -, count(1) count -from analytics_bundle_fields bbu -left outer join accounts a on bbu.account_id = a.id -where 1 = 1 -and ( - bbu.account_record_id != a.record_id - or bbu.account_record_id is null -) -union -select - 'BBU_TAGS' as table_name -, count(1) count -from analytics_bundle_tags bbu -left outer join accounts a on bbu.account_id = a.id -where 1 = 1 -and ( - bbu.account_record_id != a.record_id - or bbu.account_record_id is null -) -union -select - 'BII' as table_name -, count(1) count -from analytics_invoice_items bii -left outer join accounts a on bii.account_id = a.id -where 1 = 1 -and ( - bii.account_record_id != a.record_id - or bii.account_record_id is null -) -union -select - 'BIA' as table_name -, count(1) count -from analytics_invoice_adjustments bia -left outer join accounts a on bia.account_id = a.id -where 1 = 1 -and ( - bia.account_record_id != a.record_id - or bia.account_record_id is null -) -union -select - 'BIIA' as table_name -, count(1) count -from analytics_invoice_item_adjustments biia -left outer join accounts a on biia.account_id = a.id -where 1 = 1 -and ( - biia.account_record_id != a.record_id - or biia.account_record_id is null -) -union -select - 'BIC' as table_name -, count(1) count -from analytics_invoice_credits bic -left outer join accounts a on bic.account_id = a.id -where 1 = 1 -and ( - bic.account_record_id != a.record_id - or bic.account_record_id is null -) -union -select - 'BIN' as table_name -, count(1) count -from analytics_invoices bin -left outer join accounts a on bin.account_id = a.id -where 1 = 1 -and ( - bin.account_record_id != a.record_id - or bin.account_record_id is null -) -union -select - 'BIN_FIELDS' as table_name -, count(1) count -from analytics_invoice_fields bin -left outer join accounts a on bin.account_id = a.id -where 1 = 1 -and ( - bin.account_record_id != a.record_id - or bin.account_record_id is null -) -union -select - 'BIN_TAGS' as table_name -, count(1) count -from analytics_invoice_tags bin -left outer join accounts a on bin.account_id = a.id -where 1 = 1 -and ( - bin.account_record_id != a.record_id - or bin.account_record_id is null -) -union -select - 'BIP_AUTHS' as table_name -, count(1) count -from analytics_payment_auths bip -left outer join accounts a on bip.account_id = a.id -where 1 = 1 -and ( - bip.account_record_id != a.record_id - or bip.account_record_id is null -) -union -select - 'BIP_CAPTURES' as table_name -, count(1) count -from analytics_payment_captures bip -left outer join accounts a on bip.account_id = a.id -where 1 = 1 -and ( - bip.account_record_id != a.record_id - or bip.account_record_id is null -) -union -select - 'BIP_PURCHASES' as table_name -, count(1) count -from analytics_payment_purchases bip -left outer join accounts a on bip.account_id = a.id -where 1 = 1 -and ( - bip.account_record_id != a.record_id - or bip.account_record_id is null -) -union -select - 'BIP_REFUNDS' as table_name -, count(1) count -from analytics_payment_refunds bip -left outer join accounts a on bip.account_id = a.id -where 1 = 1 -and ( - bip.account_record_id != a.record_id - or bip.account_record_id is null -) -union -select - 'BIP_CREDITS' as table_name -, count(1) count -from analytics_payment_credits bip -left outer join accounts a on bip.account_id = a.id -where 1 = 1 -and ( - bip.account_record_id != a.record_id - or bip.account_record_id is null -) -union -select - 'BIP_CHARGEBACKS' as table_name -, count(1) count -from analytics_payment_chargebacks bip -left outer join accounts a on bip.account_id = a.id -where 1 = 1 -and ( - bip.account_record_id != a.record_id - or bip.account_record_id is null -) -union -select - 'BIP_FIELDS' as table_name -, count(1) count -from analytics_payment_fields bip -left outer join accounts a on bip.account_id = a.id -where 1 = 1 -and ( - bip.account_record_id != a.record_id - or bip.account_record_id is null -) -union -select - 'BIP_TAGS' as table_name -, count(1) count -from analytics_payment_tags bip -left outer join accounts a on bip.account_id = a.id -where 1 = 1 -and ( - bip.account_record_id != a.record_id - or bip.account_record_id is null -) -union -select - 'BOS' as table_name -, count(1) count -from analytics_account_transitions bos -left outer join accounts a on bos.account_id = a.id -where 1 = 1 -and ( - bos.account_record_id != a.record_id - or bos.account_record_id is null -) -union -select - 'BST' as table_name -, count(1) count -from analytics_subscription_transitions bst -left outer join accounts a on bst.account_id = a.id -where 1 = 1 -and ( - bst.account_record_id != a.record_id - or bst.account_record_id is null -) -; diff --git a/src/main/resources/sanity/plugin_sanity/README.md b/src/main/resources/sanity/plugin_sanity/README.md deleted file mode 100644 index 792fffc9..00000000 --- a/src/main/resources/sanity/plugin_sanity/README.md +++ /dev/null @@ -1 +0,0 @@ -Any sanity queries that are plugin specific should go here. \ No newline at end of file diff --git a/src/main/resources/sanity/plugin_sanity/cybersource/sanity.sql b/src/main/resources/sanity/plugin_sanity/cybersource/sanity.sql deleted file mode 100644 index d82dd3e9..00000000 --- a/src/main/resources/sanity/plugin_sanity/cybersource/sanity.sql +++ /dev/null @@ -1,78 +0,0 @@ -select 'CyberSource sanity' as sanity_query_name; -select - 'payment_transactions in cybersource_transactions' as description - ,sum(case when b.kb_payment_transaction_id is null then 1 else 0 end) as row_missing - ,sum(case when b.kb_payment_transaction_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.transaction_type!='VOID' then - case when a.id=b.kb_payment_transaction_id and a.payment_id=b.kb_payment_id and a.transaction_type=b.transaction_type and a.amount*100=b.amount_in_cents and a.currency=b.currency and a.payment_id=b.kb_payment_id and a.transaction_type=b.transaction_type and p.account_id=b.kb_account_id - then 1 else 0 end - when a.transaction_type='VOID' then - case when a.id=b.kb_payment_transaction_id and a.payment_id=b.kb_payment_id and a.transaction_type=b.transaction_type and p.account_id=b.kb_account_id - then 1 else 0 end - end) as matches - ,count(1) total -from - payment_transactions a - inner join payments p on - a.payment_id=p.id - inner join payment_methods pm on - p.payment_method_id=pm.id - and pm.plugin_name='killbill-cybersource' - left outer join cybersource_transactions b on - a.id=b.kb_payment_transaction_id -where 1=1 - and a.transaction_status='SUCCESS' -UNION -select - 'cybersource_transactions in payment_transactions' - ,sum(case when b.id is null then 1 else 0 end) as row_missing - ,sum(case when b.id is not null then 1 else 0 end) as row_exists - ,count(1) matches - ,count(1) total -from - cybersource_transactions a - left outer join payment_transactions b on - a.kb_payment_transaction_id=b.id -UNION -select - 'payment_responses in cybersource_transactions' as description - ,sum(case when b.kb_payment_transaction_id is null then 1 else 0 end) as row_missing - ,sum(case when b.kb_payment_transaction_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.kb_payment_transaction_id and a.payment_id=b.kb_payment_id and a.transaction_type=b.transaction_type and p.account_id=b.kb_account_id then 1 else 0 end) as matches - ,count(1) total -from - payment_transactions a - inner join payments p on - a.payment_id=p.id - inner join payment_methods pm on - p.payment_method_id=pm.id - and pm.plugin_name='killbill-cybersource' - left outer join cybersource_responses b on - a.id=b.kb_payment_transaction_id -where 1=1 - and a.transaction_status='SUCCESS' -UNION -select - 'cybersource_responses in payment_transactions' - ,sum(case when b.id is null then 1 else 0 end) as row_missing - ,sum(case when b.id is not null then 1 else 0 end) as row_exists - ,count(1) matches - ,count(1) total -from - cybersource_responses a - left outer join payment_transactions b on - a.kb_payment_transaction_id=b.id -where 1=1 - and a.api_call !='add_payment_method' -UNION -select - 'cybersource_responses in cybersource_transactions' - ,sum(case when b.id is null then 1 else 0 end) as row_missing - ,sum(case when b.id is not null then 1 else 0 end) as row_exists - ,count(1) matches - ,count(1) total -from - cybersource_transactions a - left outer join cybersource_responses b on - a.cybersource_response_id = b.id -; \ No newline at end of file diff --git a/src/main/resources/sanity/plugin_sanity/payU/sanity.sql b/src/main/resources/sanity/plugin_sanity/payU/sanity.sql deleted file mode 100644 index 593fe319..00000000 --- a/src/main/resources/sanity/plugin_sanity/payU/sanity.sql +++ /dev/null @@ -1,78 +0,0 @@ -select 'payU sanity' as sanity_query_name; -select - 'payment_transactions in payu_latam_transactions' as description - ,sum(case when b.kb_payment_transaction_id is null then 1 else 0 end) as row_missing - ,sum(case when b.kb_payment_transaction_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.transaction_type!='VOID' then - case when a.id=b.kb_payment_transaction_id and a.payment_id=b.kb_payment_id and a.transaction_type=b.transaction_type and a.amount*100=b.amount_in_cents and a.currency=b.currency and a.payment_id=b.kb_payment_id and a.transaction_type=b.transaction_type and p.account_id=b.kb_account_id - then 1 else 0 end - when a.transaction_type='VOID' then - case when a.id=b.kb_payment_transaction_id and a.payment_id=b.kb_payment_id and a.transaction_type=b.transaction_type and p.account_id=b.kb_account_id - then 1 else 0 end - end) as matches - ,count(1) total -from - payment_transactions a - inner join payments p on - a.payment_id=p.id - inner join payment_methods pm on - p.payment_method_id=pm.id - and pm.plugin_name='killbill-payu-latam' - left outer join payu_latam_transactions b on - a.id=b.kb_payment_transaction_id -where 1=1 - and a.transaction_status='SUCCESS' -UNION -select - 'payu_latam_transactions in payment_transactions' - ,sum(case when b.id is null then 1 else 0 end) as row_missing - ,sum(case when b.id is not null then 1 else 0 end) as row_exists - ,count(1) matches - ,count(1) total -from - payu_latam_transactions a - left outer join payment_transactions b on - a.kb_payment_transaction_id=b.id -UNION -select - 'payment_responses in payu_latam_transactions' as description - ,sum(case when b.kb_payment_transaction_id is null then 1 else 0 end) as row_missing - ,sum(case when b.kb_payment_transaction_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.kb_payment_transaction_id and a.payment_id=b.kb_payment_id and a.transaction_type=b.transaction_type and p.account_id=b.kb_account_id then 1 else 0 end) as matches - ,count(1) total -from - payment_transactions a - inner join payments p on - a.payment_id=p.id - inner join payment_methods pm on - p.payment_method_id=pm.id - and pm.plugin_name='killbill-payu-latam' - left outer join payu_latam_responses b on - a.id=b.kb_payment_transaction_id -where 1=1 - and a.transaction_status='SUCCESS' -UNION -select - 'payu_latam_responses in payment_transactions' - ,sum(case when b.id is null then 1 else 0 end) as row_missing - ,sum(case when b.id is not null then 1 else 0 end) as row_exists - ,count(1) matches - ,count(1) total -from - payu_latam_responses a - left outer join payment_transactions b on - a.kb_payment_transaction_id=b.id -where 1=1 - and a.api_call !='add_payment_method' -UNION -select - 'payu_latam_responses in payu_latam_transactions' - ,sum(case when b.id is null then 1 else 0 end) as row_missing - ,sum(case when b.id is not null then 1 else 0 end) as row_exists - ,count(1) matches - ,count(1) total -from - payu_latam_transactions a - left outer join payu_latam_responses b on - a.payu_latam_response_id = b.id -; \ No newline at end of file diff --git a/src/main/resources/sanity/plugin_sanity/zuora/sanity.sql b/src/main/resources/sanity/plugin_sanity/zuora/sanity.sql deleted file mode 100644 index 6e4a5b01..00000000 --- a/src/main/resources/sanity/plugin_sanity/zuora/sanity.sql +++ /dev/null @@ -1,35 +0,0 @@ -select 'G6ai' as sanity_query_name; -select * -from bip -left outer join invoice_payments ip on bip.invoice_payment_id = ip.id -left outer join _zuora_payments pp on ip.payment_id = pp.kb_p_id -where (coalesce(pp.z_created_date, 'NULL') != coalesce(bip.plugin_created_date, 'NULL') -or coalesce(pp.z_effective_date, 'NULL') != coalesce(bip.plugin_effective_date, 'NULL') -or coalesce(pp.z_status, 'NULL') != coalesce(bip.plugin_status, 'NULL') -or coalesce(pp.z_gateway_error, 'NULL') != coalesce(bip.plugin_gateway_error, 'NULL') -or coalesce(pp.z_gateway_error_code, 'NULL') != coalesce(bip.plugin_gateway_error_code, 'NULL') -or coalesce(pp.z_reference_id, 'NULL') != coalesce(bip.plugin_first_reference_id, 'NULL') -or coalesce(pp.z_snd_reference_id, 'NULL') != coalesce(bip.plugin_second_reference_id, 'NULL') ) and pp.kb_p_id is not null -- workaround until we get plugin name, query will miss missing rows -; - -select 'G6bi' as sanity_query_name; -select * -from _zuora_payments pp -left outer join invoice_payments ip on ip.payment_id = pp.kb_p_id -left outer join analytics_payments bip on bip.invoice_payment_id = ip.id -where (coalesce(pp.z_created_date, 'NULL') != coalesce(bip.plugin_created_date, 'NULL') -or coalesce(pp.z_effective_date, 'NULL') != coalesce(bip.plugin_effective_date, 'NULL') -or coalesce(pp.z_status, 'NULL') != coalesce(bip.plugin_status, 'NULL') -or coalesce(pp.z_gateway_error, 'NULL') != coalesce(bip.plugin_gateway_error, 'NULL') -or coalesce(pp.z_gateway_error_code, 'NULL') != coalesce(bip.plugin_gateway_error_code, 'NULL') -or coalesce(pp.z_reference_id, 'NULL') != coalesce(bip.plugin_first_reference_id, 'NULL') -or coalesce(pp.z_snd_reference_id, 'NULL') != coalesce(bip.plugin_second_reference_id, 'NULL')) and z_status != 'Error' -; - -select 'G7i' as sanity_query_name; -select * -from analytics_payments bip -left outer join _zuora_payment_methods ppm on bip.plugin_pm_id = ppm.z_pm_id -where (coalesce(ppm.z_pm_id, 'NULL') != coalesce(bip.plugin_pm_id, 'NULL') -or coalesce(ppm.z_default, 'NULL') != coalesce(bip.plugin_pm_is_default, 'NULL')) and ppm.z_pm_id is not null -- workaround until we get plugin name, query will miss missing rows -; \ No newline at end of file diff --git a/src/main/resources/sanity/sanity.sql b/src/main/resources/sanity/sanity.sql deleted file mode 100644 index 940e8c16..00000000 --- a/src/main/resources/sanity/sanity.sql +++ /dev/null @@ -1,2045 +0,0 @@ --- ACCOUNTS - -select 'A1a' as sanity_query_name; -select distinct a.record_id -from accounts a -left outer join analytics_accounts bac on a.id = bac.account_id -where a.record_id != bac.account_record_id -or (coalesce(a.id, '') != coalesce(bac.account_id, '')) -or a.external_key != bac.account_external_key -or (coalesce(a.email, '') != coalesce(bac.email, '')) -or (coalesce(a.name, '') != coalesce(bac.account_name, '')) -or (coalesce(a.first_name_length, -1) != coalesce(bac.first_name_length, -1)) -or (coalesce(a.currency, '') != coalesce(bac.currency, '')) -or (coalesce(a.billing_cycle_day_local, -1) != coalesce(bac.billing_cycle_day_local, -1)) -or (coalesce(a.payment_method_id, '') != coalesce(bac.payment_method_id, '')) -or (coalesce(a.time_zone, '') != coalesce(bac.time_zone, '')) -or (coalesce(a.locale, '') != coalesce(bac.locale, '')) -or (coalesce(a.address1, '') != coalesce(bac.address1, '')) -or (coalesce(a.address2, '') != coalesce(bac.address2, '')) -or (coalesce(a.company_name, '') != coalesce(bac.company_name, '')) -or (coalesce(a.city, '') != coalesce(bac.city, '')) -or (coalesce(a.state_or_province, '') != coalesce(bac.state_or_province, '')) -or (coalesce(a.country, '') != coalesce(bac.country, '')) -or (coalesce(a.postal_code, '') != coalesce(bac.postal_code, '')) -or (coalesce(a.phone, '') != coalesce(bac.phone, '')) -or (coalesce(a.migrated, false) != coalesce(bac.migrated, false)) -or a.created_date != bac.created_date -or a.updated_date != bac.updated_date -or a.tenant_record_id != bac.tenant_record_id -; - -select 'A1b' as sanity_query_name; -select distinct bac.account_record_id -from analytics_accounts bac -left outer join accounts a on a.id = bac.account_id -where a.record_id != bac.account_record_id -or (coalesce(a.id, '') != coalesce(bac.account_id, '')) -or a.external_key != bac.account_external_key -or (coalesce(a.email, '') != coalesce(bac.email, '')) -or (coalesce(a.name, '') != coalesce(bac.account_name, '')) -or (coalesce(a.first_name_length, -1) != coalesce(bac.first_name_length, -1)) -or (coalesce(a.currency, '') != coalesce(bac.currency, '')) -or (coalesce(a.billing_cycle_day_local, -1) != coalesce(bac.billing_cycle_day_local, -1)) -or (coalesce(a.payment_method_id, '') != coalesce(bac.payment_method_id, '')) -or (coalesce(a.time_zone, '') != coalesce(bac.time_zone, '')) -or (coalesce(a.locale, '') != coalesce(bac.locale, '')) -or (coalesce(a.address1, '') != coalesce(bac.address1, '')) -or (coalesce(a.address2, '') != coalesce(bac.address2, '')) -or (coalesce(a.company_name, '') != coalesce(bac.company_name, '')) -or (coalesce(a.city, '') != coalesce(bac.city, '')) -or (coalesce(a.state_or_province, '') != coalesce(bac.state_or_province, '')) -or (coalesce(a.country, '') != coalesce(bac.country, '')) -or (coalesce(a.postal_code, '') != coalesce(bac.postal_code, '')) -or (coalesce(a.phone, '') != coalesce(bac.phone, '')) -or (coalesce(a.migrated, false) != coalesce(bac.migrated, false)) -or (coalesce(a.created_date, cast('1970-01-01' as date)) != coalesce(bac.created_date, cast('1970-01-01' as date))) -or (coalesce(a.updated_date, cast('1970-01-01' as date)) != coalesce(bac.updated_date, cast('1970-01-01' as date))) -or (coalesce(a.tenant_record_id, -1) != coalesce(bac.tenant_record_id, -1)) -; - -select 'A2' as sanity_query_name; -select distinct b.account_record_id -from analytics_accounts b -join account_history ah on b.account_record_id = ah.target_record_id -join audit_log al on ah.record_id = al.target_record_id and al.change_type = 'INSERT' and al.table_name = 'ACCOUNT_HISTORY' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- ACCOUNT FIELDS - -select 'K1a' as sanity_query_name; -select distinct cf.account_record_id -from custom_fields cf -left outer join analytics_account_fields b on cf.record_id = b.custom_field_record_id and cf.object_id = b.account_id /* To use the index */ -where 1 = 1 -and ( - coalesce(b.name, 'NULL') != coalesce(cf.field_name, 'NULL') - or coalesce(b.value, 'NULL') != coalesce(cf.field_value, 'NULL') - or coalesce(b.created_date, cast('1970-01-01' as date)) != coalesce(cf.created_date, cast('1970-01-01' as date)) - or coalesce(b.account_record_id, -1) != coalesce(cf.account_record_id, -1) - or coalesce(b.tenant_record_id, -1) != coalesce(cf.tenant_record_id, -1) -) -and cf.object_type = 'ACCOUNT' -; - -select 'K1b' as sanity_query_name; -select distinct b.account_record_id -from analytics_account_fields b -left outer join custom_fields cf on cf.record_id = b.custom_field_record_id and cf.object_id = b.account_id /* To use the index */ -where 1 = 1 -and ( - coalesce(b.name, 'NULL') != coalesce(cf.field_name, 'NULL') - or coalesce(b.value, 'NULL') != coalesce(cf.field_value, 'NULL') - or coalesce(b.created_date, cast('1970-01-01' as date)) != coalesce(cf.created_date, cast('1970-01-01' as date)) - or coalesce(b.account_record_id, -1) != coalesce(cf.account_record_id, -1) - or coalesce(b.tenant_record_id, -1) != coalesce(cf.tenant_record_id, -1) - or cf.object_type != 'ACCOUNT' -) -; - -select 'K2' as sanity_query_name; -select distinct b.account_record_id -from analytics_account_fields b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.id, '') != coalesce(b.account_id, '') -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'K3' as sanity_query_name; -select distinct b.account_record_id -from analytics_account_fields b -join custom_field_history cfh on b.custom_field_record_id = cfh.target_record_id -join audit_log al on cfh.record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'CUSTOM_FIELD_HISTORY' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- ACCOUNT TAGS - -select 'L1a' as sanity_query_name; -select distinct t.account_record_id -from tags t -join tag_definitions td on t.tag_definition_id = td.id -left outer join analytics_account_tags b on t.record_id = b.tag_record_id and t.object_id = b.account_id /* To use the index */ -where 1 = 1 -and ( - coalesce(b.tag_record_id, -1) != coalesce(t.record_id, -1) - or coalesce(b.name, 'NULL') != coalesce(td.name, 'NULL') - or coalesce(b.created_date, cast('1970-01-01' as date)) != coalesce(t.created_date, cast('1970-01-01' as date)) - or coalesce(b.account_record_id, -1) != coalesce(t.account_record_id, -1) - or coalesce(b.tenant_record_id, -1) != coalesce(t.tenant_record_id, -1) -) -and t.object_type = 'ACCOUNT' -; - -select 'L1b' as sanity_query_name; -select distinct b.account_record_id -from analytics_account_tags b -left outer join tags t on t.record_id = b.tag_record_id -left outer join tag_definitions td on t.tag_definition_id = td.id -where (coalesce(b.tag_record_id, -1) != coalesce(t.record_id, -1) -or coalesce(b.name, 'NULL') != coalesce(td.name, 'NULL') -or coalesce(b.created_date, cast('1970-01-01' as date)) != coalesce(t.created_date, cast('1970-01-01' as date)) -or coalesce(b.account_record_id, -1) != coalesce(t.account_record_id, -1) -or coalesce(b.tenant_record_id, -1) != coalesce(t.tenant_record_id, -1)) -and t.object_type = 'ACCOUNT' --- Ignore system tags -and t.tag_definition_id not in ('00000000-0000-0000-0000-000000000001', - '00000000-0000-0000-0000-000000000002', - '00000000-0000-0000-0000-000000000003', - '00000000-0000-0000-0000-000000000004', - '00000000-0000-0000-0000-000000000005', - '00000000-0000-0000-0000-000000000006', - '00000000-0000-0000-0000-000000000007') -; - -select 'L2' as sanity_query_name; -select distinct b.account_record_id -from analytics_account_tags b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.id, '') != coalesce(b.account_id, '') -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'L3' as sanity_query_name; -select distinct b.account_record_id -from analytics_account_tags b -join tag_history th on b.tag_record_id = th.target_record_id -join audit_log al on th.record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'TAG_HISTORY' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- INVOICE ADJUSTMENTS - -select 'B1a' as sanity_query_name; --- this will find things it thinks should be in bia but it's correct that they're not there -select distinct b.account_record_id -from invoice_items ii -left outer join analytics_invoice_adjustments b on ii.id = b.item_id -where ii.type in ('CREDIT_ADJ','REFUND_ADJ') -and (coalesce(ii.record_id, -1) != coalesce(b.invoice_item_record_id, -1) -or (coalesce(ii.id, '') != coalesce(b.item_id, '')) -or (coalesce(ii.type, '') != coalesce(b.item_type, '')) -or (coalesce(ii.invoice_id, '') != coalesce(b.invoice_id, '')) -or (coalesce(ii.account_id, '')!= coalesce(b.account_id, '')) -or (coalesce(ii.phase_name, '') != coalesce(b.slug, '')) -or (coalesce(ii.start_date, cast('1970-01-01' as date)) != coalesce(b.start_date, cast('1970-01-01' as date))) -or (coalesce(ii.amount, -1) != coalesce(b.amount, -1)) -or (coalesce(ii.currency, '') != coalesce(b.currency, '')) -or (coalesce(ii.linked_item_id, '') != coalesce(b.linked_item_id, '')) -or (coalesce(ii.created_date, cast('1970-01-01' as date)) != coalesce(b.created_date, cast('1970-01-01' as date))) -or (coalesce(ii.account_record_id, -1) != coalesce(b.account_record_id, -1)) -or (coalesce(ii.tenant_record_id, -1) != coalesce(b.tenant_record_id, -1))) -; - -select 'B1b' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_adjustments b -left outer join invoice_items ii on ii.id = b.item_id -where (coalesce(ii.record_id, -1) != coalesce(b.invoice_item_record_id, -1)) -or (coalesce(ii.id, '') != coalesce(b.item_id, '')) -or (coalesce(ii.type, '') != coalesce(b.item_type, '')) -or (coalesce(ii.invoice_id, '') != coalesce(b.invoice_id, '')) -or (coalesce(ii.account_id, '')!= coalesce(b.account_id, '')) -or (coalesce(ii.phase_name, '') != coalesce(b.slug, '')) -or (coalesce(ii.start_date, cast('1970-01-01' as date)) != coalesce(b.start_date, cast('1970-01-01' as date))) -or (coalesce(ii.amount, -1) != coalesce(b.amount, -1)) -or (coalesce(ii.currency, '') != coalesce(b.currency, '')) -or (coalesce(ii.linked_item_id, '') != coalesce(b.linked_item_id, '')) -or (coalesce(ii.created_date, cast('1970-01-01' as date)) != coalesce(b.created_date, cast('1970-01-01' as date))) -or (coalesce(ii.account_record_id, -1) != coalesce(b.account_record_id, -1)) -or (coalesce(ii.tenant_record_id, -1) != coalesce(b.tenant_record_id, -1)) -or ii.type not in ('CREDIT_ADJ','REFUND_ADJ') -; - -select 'B2' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_adjustments b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.id, '') != coalesce(b.account_id, '') -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'B3' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_adjustments b -left outer join invoices i on i.id = b.invoice_id -where coalesce(i.record_id, -1) != coalesce(b.invoice_number, -1) -or coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce(b.invoice_created_date, cast('1970-01-01' as date)) -or coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(b.invoice_date, cast('1970-01-01' as date)) -or coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(b.invoice_target_date, cast('1970-01-01' as date)) -or coalesce(i.currency, 'NULL') != coalesce(b.invoice_currency, 'NULL') -; - -select 'B4' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_adjustments b -left outer join bundles bndl on b.bundle_id = bndl.id -where coalesce(bndl.external_key, 'NULL') != coalesce(b.bundle_external_key, 'NULL') -; - -select 'B5' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_adjustments b -left outer join analytics_invoices bin on b.invoice_id = bin.invoice_id -where b.invoice_balance != bin.balance -or b.invoice_amount_paid != bin.amount_paid -or b.invoice_amount_charged != bin.amount_charged -or b.invoice_original_amount_charged != bin.original_amount_charged -or b.invoice_amount_credited != bin.amount_credited -; - -select 'B6' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_adjustments b -join audit_log al on b.invoice_item_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'INVOICE_ITEMS' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- INVOICE ITEMS - -select 'C1a' as sanity_query_name; -select distinct ii.account_record_id -from invoice_items ii -left outer join analytics_invoice_items bii on ii.id = bii.item_id -where ii.type in ('FIXED','RECURRING','EXTERNAL_CHARGE') -and (coalesce(ii.record_id, -1) != coalesce(bii.invoice_item_record_id, -1) -or (coalesce(ii.id, '') != coalesce(bii.item_id, '')) -or (coalesce(ii.type, '') != coalesce(bii.item_type, '')) -or (coalesce(ii.invoice_id, '') != coalesce(bii.invoice_id, '')) -or (coalesce(ii.account_id, '') != coalesce(bii.account_id, '')) -or (coalesce(ii.phase_name, '') != coalesce(bii.slug, '')) -or (coalesce(ii.start_date, cast('1970-01-01' as date)) != coalesce(bii.start_date, cast('1970-01-01' as date))) -or (coalesce(ii.amount, -1) != coalesce(bii.amount, -1)) -or (coalesce(ii.currency, '') != coalesce(bii.currency, '')) -or (coalesce(ii.linked_item_id, '') != coalesce(bii.linked_item_id, '')) -or (coalesce(ii.created_date, cast('1970-01-01' as date)) != coalesce(bii.created_date, cast('1970-01-01' as date))) -or (coalesce(ii.account_record_id, -1) != coalesce(bii.account_record_id, -1)) -or (coalesce(ii.tenant_record_id, -1) != coalesce(bii.tenant_record_id, -1))) -; - -select 'C1b' as sanity_query_name; -select distinct bii.account_record_id -from analytics_invoice_items bii -left outer join invoice_items ii on ii.id = bii.item_id -where (coalesce(ii.record_id, -1) != coalesce(bii.invoice_item_record_id, -1)) -or (coalesce(ii.id, '') != coalesce(bii.item_id, '')) -or (coalesce(ii.type, '') != coalesce(bii.item_type, '')) -or (coalesce(ii.invoice_id, '') != coalesce(bii.invoice_id, '')) -or (coalesce(ii.account_id, '')!= coalesce(bii.account_id, '')) -or (coalesce(ii.phase_name, '') != coalesce(bii.slug, '')) -or (coalesce(ii.start_date, cast('1970-01-01' as date)) != coalesce(bii.start_date, cast('1970-01-01' as date))) -or (coalesce(ii.amount, -1) != coalesce(bii.amount, -1)) -or (coalesce(ii.currency, '') != coalesce(bii.currency, '')) -or (coalesce(ii.linked_item_id, '') != coalesce(bii.linked_item_id, '')) -or (coalesce(ii.created_date, cast('1970-01-01' as date)) != coalesce(bii.created_date, cast('1970-01-01' as date))) -or (coalesce(ii.account_record_id, -1) != coalesce(bii.account_record_id, -1)) -or (coalesce(ii.tenant_record_id, -1) != coalesce(bii.tenant_record_id, -1)) -or ii.type not in ('FIXED','RECURRING','EXTERNAL_CHARGE') -; - -select 'C2' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_items b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.id, '') != coalesce(b.account_id, '') -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'C3' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_items b -left outer join invoices i on i.id = b.invoice_id -where coalesce(i.record_id, -1) != coalesce(b.invoice_number, -1) -or coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce(b.invoice_created_date, cast('1970-01-01' as date)) -or coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(b.invoice_date, cast('1970-01-01' as date)) -or coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(b.invoice_target_date, cast('1970-01-01' as date)) -or coalesce(i.currency, 'NULL') != coalesce(b.invoice_currency, 'NULL') -; - -select 'C4' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_items b -left outer join bundles bndl on b.bundle_id = bndl.id -where coalesce(bndl.external_key, 'NULL') != coalesce(b.bundle_external_key, 'NULL') -; - -select 'C5' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_items b -left outer join analytics_invoices bin on b.invoice_id = bin.invoice_id -where b.invoice_balance != bin.balance -or b.invoice_amount_paid != bin.amount_paid -or b.invoice_amount_charged != bin.amount_charged -or b.invoice_original_amount_charged != bin.original_amount_charged -or b.invoice_amount_credited != bin.amount_credited -; - -select 'C6' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_items b -join audit_log al on b.invoice_item_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'INVOICE_ITEMS' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- INVOICE ITEM ADJUSTMENTS - -select 'D1a' as sanity_query_name; -select distinct ii.account_record_id -from invoice_items ii -left outer join analytics_invoice_item_adjustments b on ii.id = b.item_id -where ii.type in ('ITEM_ADJ', 'REPAIR_ADJ') -and (coalesce(ii.record_id, -1) != coalesce(b.invoice_item_record_id, -1) -or (coalesce(ii.id, '') != coalesce(b.item_id, '')) -or (coalesce(ii.type, '') != coalesce(b.item_type, '')) -or (coalesce(ii.invoice_id, '') != coalesce(b.invoice_id, '')) -or (coalesce(ii.account_id, '')!= coalesce(b.account_id, '')) -or ((coalesce(ii.phase_name, '') != coalesce(b.slug,'')) and ii.phase_name is not null) -or (coalesce(ii.start_date, cast('1970-01-01' as date)) != coalesce(b.start_date, cast('1970-01-01' as date))) -or (coalesce(ii.amount, -1) != coalesce(b.amount, -1)) -or (coalesce(ii.currency, '') != coalesce(b.currency, '')) -or (coalesce(ii.linked_item_id, '') != coalesce(b.linked_item_id, '')) -or (coalesce(ii.created_date, cast('1970-01-01' as date)) != coalesce(b.created_date, cast('1970-01-01' as date))) -or (coalesce(ii.account_record_id, -1) != coalesce(b.account_record_id, -1)) -or (coalesce(ii.tenant_record_id, -1) != coalesce(b.tenant_record_id, -1))) -; - -select 'D1b' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_item_adjustments b -left outer join invoice_items ii on ii.id = b.item_id -where coalesce(ii.record_id, -1) != coalesce(b.invoice_item_record_id, -1) -or (coalesce(ii.id, '') != coalesce(b.item_id, '')) -or (coalesce(ii.type, '') != coalesce(b.item_type, '')) -or (coalesce(ii.invoice_id, '') != coalesce(b.invoice_id, '')) -or (coalesce(ii.account_id, '')!= coalesce(b.account_id, '')) -/* The code is smart and will populate NULL columns from the linked item id */ -or (ii.phase_name is not null and ii.phase_name != b.slug) -or (coalesce(ii.start_date, cast('1970-01-01' as date)) != coalesce(b.start_date, cast('1970-01-01' as date))) -or ( (coalesce(ii.amount, -1) != coalesce(b.amount, -1)) and ii.type != 'REPAIR_ADJ' ) -- need to calc correct amount in case of REPAIR_ADJ case -or (coalesce(ii.currency, '') != coalesce(b.currency, '')) -or (coalesce(ii.linked_item_id, '') != coalesce(b.linked_item_id, '')) -or (coalesce(ii.created_date, cast('1970-01-01' as date)) != coalesce(b.created_date, cast('1970-01-01' as date))) -or (coalesce(ii.account_record_id, -1) != coalesce(b.account_record_id, -1)) -or (coalesce(ii.tenant_record_id, -1) != coalesce(b.tenant_record_id, -1)) -or ii.type not in ('ITEM_ADJ','REPAIR_ADJ') -; - -select 'D2' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_item_adjustments b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.id, '') != coalesce(b.account_id, '') -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'D3' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_item_adjustments b -left outer join invoices i on i.id = b.invoice_id -where coalesce(i.record_id, -1) != coalesce(b.invoice_number, -1) -or coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce(b.invoice_created_date, cast('1970-01-01' as date)) -or coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(b.invoice_date, cast('1970-01-01' as date)) -or coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(b.invoice_target_date, cast('1970-01-01' as date)) -or coalesce(i.currency, 'NULL') != coalesce(b.invoice_currency, 'NULL') -; - -select 'D4' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_item_adjustments b -left outer join bundles bndl on b.bundle_id = bndl.id -where coalesce(bndl.external_key, 'NULL') != coalesce(b.bundle_external_key, 'NULL') -and b.bundle_id is not null -; - -select 'D5' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_item_adjustments b -left outer join analytics_invoices bin on b.invoice_id = bin.invoice_id -where b.invoice_balance != bin.balance -or b.invoice_amount_paid != bin.amount_paid -or b.invoice_amount_charged != bin.amount_charged -or b.invoice_original_amount_charged != bin.original_amount_charged -or b.invoice_amount_credited != bin.amount_credited -; - -select 'D6' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_item_adjustments b -join audit_log al on b.invoice_item_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'INVOICE_ITEMS' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- INVOICE CREDITS - -select 'E1a' as sanity_query_name; -select distinct ii.account_record_id -from invoice_items ii -left outer join analytics_invoice_credits b on ii.id = b.item_id -where ii.type in ('CBA_ADJ') -and (coalesce(ii.record_id, -1) != coalesce(b.invoice_item_record_id, -1) -or (coalesce(ii.id, '') != coalesce(b.item_id, '')) -or (coalesce(ii.type, '') != coalesce(b.item_type, '')) -or (coalesce(ii.invoice_id, '') != coalesce(b.invoice_id, '')) -or (coalesce(ii.account_id, '')!= coalesce(b.account_id, '')) -or (coalesce(ii.phase_name, '') != coalesce(b.slug, '')) -or (coalesce(ii.start_date, cast('1970-01-01' as date)) != coalesce(b.start_date, cast('1970-01-01' as date))) -or (coalesce(ii.amount, -1) != coalesce(b.amount, -1)) -or (coalesce(ii.currency, '') != coalesce(b.currency, '')) -or (coalesce(ii.linked_item_id, '') != coalesce(b.linked_item_id, '')) -or (coalesce(ii.created_date, cast('1970-01-01' as date)) != coalesce(b.created_date, cast('1970-01-01' as date))) -or (coalesce(ii.account_record_id, -1) != coalesce(b.account_record_id, -1)) -or (coalesce(ii.tenant_record_id, -1) != coalesce(b.tenant_record_id, -1))) -; - -select 'E1b' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_credits b -left outer join invoice_items ii on ii.id = b.item_id -where (coalesce(ii.record_id, -1) != coalesce(b.invoice_item_record_id, -1)) -or (coalesce(ii.id, '') != coalesce(b.item_id, '')) -or (coalesce(ii.type, '') != coalesce(b.item_type, '')) -or (coalesce(ii.invoice_id, '') != coalesce(b.invoice_id, '')) -or (coalesce(ii.account_id, '')!= coalesce(b.account_id, '')) -or (coalesce(ii.phase_name, '') != coalesce(b.slug, '')) -or (coalesce(ii.start_date, cast('1970-01-01' as date)) != coalesce(b.start_date, cast('1970-01-01' as date))) -or (coalesce(ii.amount, -1) != coalesce(b.amount, -1)) -or (coalesce(ii.currency, '') != coalesce(b.currency, '')) -or (coalesce(ii.linked_item_id, '') != coalesce(b.linked_item_id, '')) -or (coalesce(ii.created_date, cast('1970-01-01' as date)) != coalesce(b.created_date, cast('1970-01-01' as date))) -or (coalesce(ii.account_record_id, -1) != coalesce(b.account_record_id, -1)) -or (coalesce(ii.tenant_record_id, -1) != coalesce(b.tenant_record_id, -1)) -or ii.type not in ('CBA_ADJ') -; - -select 'E2' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_credits b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.id, '') != coalesce(b.account_id, '') -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'E3' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_credits b -left outer join invoices i on i.id = b.invoice_id -where coalesce(i.record_id, -1) != coalesce(b.invoice_number, -1) -or coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce(b.invoice_created_date, cast('1970-01-01' as date)) -or coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(b.invoice_date, cast('1970-01-01' as date)) -or coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(b.invoice_target_date, cast('1970-01-01' as date)) -or coalesce(i.currency, 'NULL') != coalesce(b.invoice_currency, 'NULL') -; - -select 'E4' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_credits b -left outer join bundles bndl on b.bundle_id = bndl.id -where coalesce(bndl.external_key, 'NULL') != coalesce(b.bundle_external_key, 'NULL') -; - -select 'E5' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_credits b -left outer join analytics_invoices bin on b.invoice_id = bin.invoice_id -where b.invoice_balance != bin.balance -or b.invoice_amount_paid != bin.amount_paid -or b.invoice_amount_charged != bin.amount_charged -or b.invoice_original_amount_charged != bin.original_amount_charged -or b.invoice_amount_credited != bin.amount_credited -; - -select 'E6' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoice_credits b -join audit_log al on b.invoice_item_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'INVOICE_ITEMS' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- INVOICE FIELDS -/* table not currently used */ - - --- INVOICE TAGS -/* table not currently used */ - - --- INVOICES - -select 'F1a' as sanity_query_name; -select distinct i.account_record_id -from invoices i -left outer join analytics_invoices bin on i.id = bin.invoice_id -where coalesce(i.record_id, -1) != coalesce(bin.invoice_record_id, -1) -or coalesce(i.record_id, -1) != coalesce(bin.invoice_number, -1) -or coalesce(i.id, '') != coalesce(bin.invoice_id, '') -or (coalesce(i.account_id, '') != coalesce(bin.account_id, '')) -or (coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(bin.invoice_date, cast('1970-01-01' as date))) -or (coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(bin.target_date, cast('1970-01-01' as date))) -or (coalesce(i.currency, '') != coalesce(bin.currency, '')) -or (coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce( bin.created_date, cast('1970-01-01' as date))) -or (coalesce(i.account_record_id, -1) != coalesce(bin.account_record_id, -1)) -or (coalesce(i.tenant_record_id, -1) != coalesce(bin.tenant_record_id, -1)) -; - -select 'F1b' as sanity_query_name; -select distinct bin.account_record_id -from analytics_invoices bin -left outer join invoices i on i.id = bin.invoice_id -where (coalesce(i.record_id, -1) != coalesce(bin.invoice_record_id, -1)) -or (coalesce(i.id, '') != coalesce(bin.invoice_id, '')) -or (coalesce(i.account_id, '') != coalesce(bin.account_id, '')) -or (coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(bin.invoice_date, cast('1970-01-01' as date))) -or (coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(bin.target_date, cast('1970-01-01' as date))) -or (coalesce(i.currency, '') != coalesce(bin.currency, '')) -or (coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce(bin.created_date, cast('1970-01-01' as date))) -or (coalesce(i.account_record_id, -1) != coalesce(bin.account_record_id, -1)) -; - -select 'F2' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoices b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.id, '') != coalesce(b.account_id, '') -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'F3a' as sanity_query_name; -select * -from ( - select - invoice_id - , invoice_amount_charged - , sum(coalesce(amount,0)) bii_sum - from analytics_invoice_items - group by invoice_id, invoice_amount_charged, invoice_original_amount_charged -) bii_sum -left outer join ( - select - invoice_id - , sum(coalesce(amount,0)) bia_sum - from analytics_invoice_adjustments - group by invoice_id -) bia_sum using (invoice_id) -left outer join ( - select - invoice_id - , sum(coalesce(amount,0)) biia_sum - from analytics_invoice_item_adjustments - group by invoice_id -) biia_sum using (invoice_id) -where bii_sum + coalesce(bia_sum,0) + coalesce(biia_sum,0) != bii_sum.invoice_amount_charged -; - -select 'F3b' as sanity_query_name; -select - bin.invoice_id -, bin.original_amount_charged -, sum(bii.amount) -from analytics_invoice_items bii -join analytics_invoices bin on bii.invoice_id = bin.invoice_id and bii.created_date = bin.created_date -group by bin.invoice_id, bin.original_amount_charged -having sum(bii.amount) != bin.original_amount_charged -; - -select 'F3c' as sanity_query_name; -select * -from ( - select - invoice_id - , invoice_amount_credited - , sum(coalesce(amount,0)) biic_sum - from analytics_invoice_credits biic - group by invoice_id,invoice_amount_credited -) biic_sum -where biic_sum != biic_sum.invoice_amount_credited -; - -select 'F3d' as sanity_query_name; -select - * -, bip_sum invoice_amount_paid -from ( - select - invoice_id - , invoice_amount_paid - , sum(coalesce(amount,0)) bip_sum - from analytics_payment_purchases bip - group by invoice_id, invoice_amount_paid -) bip_sum -where bip_sum != bip_sum.invoice_amount_paid -; - -select 'F3e' as sanity_query_name; -select * -from ( - select - invoice_id - , balance - , amount_charged - , amount_credited - , amount_paid - , amount_refunded - , original_amount_charged - from analytics_invoices -) bin -left outer join ( - select - invoice_id - , sum(coalesce(amount,0)) bipc_sum - from analytics_payment_chargebacks bipc - group by invoice_id -) bipc_sum using (invoice_id) -left outer join ( - select - invoice_id - , sum(coalesce(amount,0)) bipr_sum - from analytics_payment_refunds bipr - group by invoice_id -) bipr_sum using (invoice_id) -where bipc_sum + bipr_sum != bin.amount_refunded -; - -select 'F3f' as sanity_query_name; -select distinct bin.account_record_id -from analytics_invoices bin -where bin.amount_charged + bin.amount_credited - bin.amount_paid - bin.amount_refunded != bin.balance -and (bin.amount_charged != 0 and bin.amount_paid != 0 and bin.amount_refunded != 0 and bin.balance != 0) -- deal w / acct credit -; - - -select 'F6' as sanity_query_name; -select distinct b.account_record_id -from analytics_invoices b -join audit_log al on b.invoice_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'INVOICES' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- PAYMENTS - -select 'G1a' as sanity_query_name; -select distinct ip.account_record_id -from invoice_payments ip -left outer join analytics_payment_purchases bip on ip.id = bip.invoice_payment_id -where (coalesce(ip.record_id, -1) != coalesce(bip.invoice_payment_record_id, -1) -or coalesce(ip.ID, 'NULL') != coalesce(bip.invoice_payment_id, 'NULL') -or coalesce(ip.invoice_id, 'NULL') != coalesce(bip.invoice_id, 'NULL') -or coalesce(ip.type, 'NULL') != coalesce(bip.invoice_payment_type, 'NULL') -or coalesce(ip.linked_invoice_payment_id, 'NULL') != coalesce(bip.linked_invoice_payment_id, 'NULL') -or coalesce(ip.amount, -1) != coalesce(bip.amount, -1) -or coalesce(ip.currency, 'NULL') != coalesce(bip.currency, 'NULL') -or coalesce(ip.created_date, cast('1970-01-01' as date)) != coalesce(bip.created_date, cast('1970-01-01' as date)) -or coalesce(ip.account_record_id, -1) != coalesce(bip.account_record_id, -1) -or coalesce(ip.tenant_record_id, -1) != coalesce(bip.tenant_record_id, -1)) -and ip.type = 'ATTEMPT' -; - -select 'G1b' as sanity_query_name; -select distinct bip.account_record_id -from analytics_payment_purchases bip -left outer join invoice_payments ip on ip.id = bip.invoice_payment_id -where (coalesce(ip.record_id, -1) != coalesce(bip.invoice_payment_record_id, -1) -or coalesce(ip.ID, 'NULL') != coalesce(bip.invoice_payment_id, 'NULL') -or coalesce(ip.invoice_id, 'NULL') != coalesce(bip.invoice_id, 'NULL') -or coalesce(ip.type, 'NULL') != coalesce(bip.invoice_payment_type, 'NULL') -or coalesce(ip.linked_invoice_payment_id, 'NULL') != coalesce(bip.linked_invoice_payment_id, 'NULL') -or coalesce(ip.amount, -1) != coalesce(bip.amount, -1) -or coalesce(ip.currency, 'NULL') != coalesce(bip.currency, 'NULL') -or coalesce(ip.created_date, cast('1970-01-01' as date)) != coalesce(bip.created_date, cast('1970-01-01' as date)) -or coalesce(ip.account_record_id, -1) != coalesce(bip.account_record_id, -1) -or coalesce(ip.tenant_record_id, -1) != coalesce(bip.tenant_record_id, -1) -or bip.invoice_payment_type != 'ATTEMPT') -and bip.invoice_payment_record_id !=0 -; - -select 'G2' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_purchases b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'G3' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_purchases b -left outer join invoices i on i.id = b.invoice_id -where coalesce(i.record_id, -1) != coalesce(b.invoice_number, -1) -or coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce(b.invoice_created_date, cast('1970-01-01' as date)) -or coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(b.invoice_date, cast('1970-01-01' as date)) -or coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(b.invoice_target_date, cast('1970-01-01' as date)) -or coalesce(i.currency, 'NULL') != coalesce(b.invoice_currency, 'NULL') -; - -select 'G4' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_purchases b -left outer join analytics_invoices bin on b.invoice_id = bin.invoice_id -where b.invoice_balance != bin.balance -or b.invoice_amount_paid != bin.amount_paid -or b.invoice_amount_charged != bin.amount_charged -or b.invoice_original_amount_charged != bin.original_amount_charged -or b.invoice_amount_credited != bin.amount_credited -; - -select 'G5' as sanity_query_name; -select distinct bip.account_record_id -from analytics_payment_purchases bip -left outer join invoice_payments ip on bip.invoice_payment_id = ip.id -left outer join payments p on ip.payment_id = p.id -where coalesce(p.record_id, -1) != coalesce(bip.payment_number, -1) -and bip.invoice_payment_record_id!=0 -; - -select 'G8' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_purchases b -join audit_log al on b.invoice_payment_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'INVOICE_PAYMENTS' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- PAYMENT FIELDS -/* table not currently used */ - - --- PAYMENT TAGS -/* table not currently used */ - - --- CHARGEBACKS - -select 'H1a' as sanity_query_name; -select distinct ip.account_record_id -from invoice_payments ip -left outer join analytics_payment_chargebacks bipc on ip.id = bipc.invoice_payment_id -where (coalesce(ip.record_id, -1) != coalesce(bipc.invoice_payment_record_id, -1) -or coalesce(ip.ID, 'NULL') != coalesce(bipc.invoice_payment_id, 'NULL') -or coalesce(ip.invoice_id, 'NULL') != coalesce(bipc.invoice_id, 'NULL') -or coalesce(ip.type, 'NULL') != coalesce(bipc.invoice_payment_type, 'NULL') -or coalesce(ip.linked_invoice_payment_id, 'NULL') != coalesce(bipc.linked_invoice_payment_id, 'NULL') -or coalesce(ip.amount, -1) != coalesce(bipc.amount, -1) -or coalesce(ip.currency, 'NULL') != coalesce(bipc.currency, 'NULL') -or coalesce(ip.created_date, cast('1970-01-01' as date)) != coalesce(bipc.created_date, cast('1970-01-01' as date)) -or coalesce(ip.account_record_id, -1) != coalesce(bipc.account_record_id, -1) -or coalesce(ip.tenant_record_id, -1) != coalesce(bipc.tenant_record_id, -1)) -and ip.type = 'CHARGED_BACK' -; - -select 'H1b' as sanity_query_name; -select distinct bipc.account_record_id -from analytics_payment_chargebacks bipc -left outer join invoice_payments ip on ip.id = bipc.invoice_payment_id -where (coalesce(ip.record_id, -1) != coalesce(bipc.invoice_payment_record_id, -1) -or coalesce(ip.ID, 'NULL') != coalesce(bipc.invoice_payment_id, 'NULL') -or coalesce(ip.invoice_id, 'NULL') != coalesce(bipc.invoice_id, 'NULL') -or coalesce(ip.type, 'NULL') != coalesce(bipc.invoice_payment_type, 'NULL') -or coalesce(ip.linked_invoice_payment_id, 'NULL') != coalesce(bipc.linked_invoice_payment_id, 'NULL') -or coalesce(ip.amount, -1) != coalesce(bipc.amount, -1) -or coalesce(ip.currency, 'NULL') != coalesce(bipc.currency, 'NULL') -or coalesce(ip.created_date, cast('1970-01-01' as date)) != coalesce(bipc.created_date, cast('1970-01-01' as date)) -or coalesce(ip.account_record_id, -1) != coalesce(bipc.account_record_id, -1) -or coalesce(ip.tenant_record_id, -1) != coalesce(bipc.tenant_record_id, -1) -or bipc.invoice_payment_type != 'CHARGED_BACK') -and bipc.invoice_payment_record_id!=0 -; - -select 'H2' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_chargebacks b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'H3' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_chargebacks b -left outer join invoices i on i.id = b.invoice_id -where coalesce(i.record_id, -1) != coalesce(b.invoice_number, -1) -or coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce(b.invoice_created_date, cast('1970-01-01' as date)) -or coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(b.invoice_date, cast('1970-01-01' as date)) -or coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(b.invoice_target_date, cast('1970-01-01' as date)) -or coalesce(i.currency, 'NULL') != coalesce(b.invoice_currency, 'NULL') -; - -select 'H4' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_chargebacks b -left outer join analytics_invoices bin on b.invoice_id = bin.invoice_id -where b.invoice_balance != bin.balance -or b.invoice_amount_paid != bin.amount_paid -or b.invoice_amount_charged != bin.amount_charged -or b.invoice_original_amount_charged != bin.original_amount_charged -or b.invoice_amount_credited != bin.amount_credited -; - -select 'H5' as sanity_query_name; -select distinct bipc.account_record_id -from analytics_payment_chargebacks bipc -left outer join invoice_payments ip on bipc.invoice_payment_id = ip.id -left outer join payments p on ip.payment_id = p.id -where coalesce(p.record_id, -1) != coalesce(bipc.payment_number, -1) -and bipc.invoice_payment_record_id!=0 -; - -select 'H8' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_chargebacks b -join audit_log al on b.invoice_payment_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'INVOICE_PAYMENTS' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- REFUNDS - -select 'H1a' as sanity_query_name; -select distinct ip.account_record_id -from invoice_payments ip -left outer join analytics_payment_refunds bipr on ip.id = bipr.invoice_payment_id -where (coalesce(ip.record_id, -1) != coalesce(bipr.invoice_payment_record_id, -1) -or coalesce(ip.ID, 'NULL') != coalesce(bipr.invoice_payment_id, 'NULL') -or coalesce(ip.invoice_id, 'NULL') != coalesce(bipr.invoice_id, 'NULL') -or coalesce(ip.type, 'NULL') != coalesce(bipr.invoice_payment_type, 'NULL') -or coalesce(ip.linked_invoice_payment_id, 'NULL') != coalesce(bipr.linked_invoice_payment_id, 'NULL') -or coalesce(ip.amount, -1) != coalesce(bipr.amount, -1) -or coalesce(ip.currency, 'NULL') != coalesce(bipr.currency, 'NULL') -or coalesce(ip.created_date, cast('1970-01-01' as date)) != coalesce(bipr.created_date, cast('1970-01-01' as date)) -or coalesce(ip.account_record_id, -1) != coalesce(bipr.account_record_id, -1) -or coalesce(ip.tenant_record_id, -1) != coalesce(bipr.tenant_record_id, -1)) -and ip.type = 'REFUND' -; - -select 'H1b' as sanity_query_name; -select distinct bipr.account_record_id -from analytics_payment_refunds bipr -left outer join invoice_payments ip on ip.id = bipr.invoice_payment_id -where (coalesce(ip.record_id, -1) != coalesce(bipr.invoice_payment_record_id, -1) -or coalesce(ip.id, 'NULL') != coalesce(bipr.invoice_payment_id, 'NULL') -or coalesce(ip.invoice_id, 'NULL') != coalesce(bipr.invoice_id, 'NULL') -or coalesce(ip.type, 'NULL') != coalesce(bipr.invoice_payment_type, 'NULL') -or coalesce(ip.linked_invoice_payment_id, 'NULL') != coalesce(bipr.linked_invoice_payment_id, 'NULL') -or coalesce(ip.amount, -1) != coalesce(bipr.amount, -1) -or coalesce(ip.currency, 'NULL') != coalesce(bipr.currency, 'NULL') -or coalesce(ip.created_date, cast('1970-01-01' as date)) != coalesce(bipr.created_date, cast('1970-01-01' as date)) -or coalesce(ip.account_record_id, -1) != coalesce(bipr.account_record_id, -1) -or coalesce(ip.tenant_record_id, -1) != coalesce(bipr.tenant_record_id, -1) -or bipr.invoice_payment_type != 'REFUND') -and bipr.invoice_payment_record_id!=0 -; - -select 'H2' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_refunds b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'H3' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_refunds b -left outer join invoices i on i.id = b.invoice_id -where coalesce(i.record_id, -1) != coalesce(b.invoice_number, -1) -or coalesce(i.created_date, cast('1970-01-01' as date)) != coalesce(b.invoice_created_date, cast('1970-01-01' as date)) -or coalesce(i.invoice_date, cast('1970-01-01' as date)) != coalesce(b.invoice_date, cast('1970-01-01' as date)) -or coalesce(i.target_date, cast('1970-01-01' as date)) != coalesce(b.invoice_target_date, cast('1970-01-01' as date)) -or coalesce(i.currency, 'NULL') != coalesce(b.invoice_currency, 'NULL') -; - -select 'H4' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_refunds b -left outer join analytics_invoices bin on b.invoice_id = bin.invoice_id -where b.invoice_balance != bin.balance -or b.invoice_amount_paid != bin.amount_paid -or b.invoice_amount_charged != bin.amount_charged -or b.invoice_original_amount_charged != bin.original_amount_charged -or b.invoice_amount_credited != bin.amount_credited -; - -select 'H5' as sanity_query_name; -select distinct bipr.account_record_id -from analytics_payment_refunds bipr -left outer join invoice_payments ip on bipr.invoice_payment_id = ip.id -left outer join payments p on ip.payment_id = p.id -where coalesce(p.record_id, -1) != coalesce(bipr.payment_number, -1) -and bipr.invoice_payment_record_id!=0 -; - -select 'H8' as sanity_query_name; -select distinct b.account_record_id -from analytics_payment_refunds b -join audit_log al on b.invoice_payment_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'INVOICE_PAYMENTS' -where coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '') -; - - --- ACCOUNT TRANSITIONS - -select 'I1a' as sanity_query_name; -select distinct bs.account_record_id -from blocking_states bs -join analytics_account_transitions bos on bs.record_id = bos.blocking_state_record_id -where 1 = 1 -and bs.is_active = true -and ( - coalesce(bs.record_id, -1) != coalesce(bos.blocking_state_record_id, -1) - or coalesce(bs.state, 'NULL') != coalesce(bos.state, 'NULL') - /* TODO SubscriptionEvent is not an entity, we don't have that info yet - or coalesce(bs.created_date, cast('1970-01-01' as date)) != coalesce(bos.created_date, cast('1970-01-01' as date)) */ - or ( - /* Tricky... Need to look at the account timezone */ - coalesce(date(bs.effective_date), cast('1970-01-01' as date)) != coalesce(date(bos.start_date), cast('1970-01-01' as date)) - and coalesce(date(bs.effective_date), cast('1970-01-01' as date)) != coalesce(date_add(date(bos.start_date), INTERVAL '1' DAY), cast('1970-01-01' as date)) - and coalesce(date(bs.effective_date), cast('1970-01-01' as date)) != coalesce(date_sub(date(bos.start_date), INTERVAL '1' DAY), cast('1970-01-01' as date)) - ) - or coalesce(bs.account_record_id, -1) != coalesce(bos.account_record_id, -1) - or coalesce(bs.tenant_record_id, -1) != coalesce(bos.tenant_record_id, -1) -) -; - -select 'I1b' as sanity_query_name; -select distinct bos.account_record_id -from analytics_account_transitions bos -join blocking_states bs on bs.record_id = bos.blocking_state_record_id -where 1 = 1 -and bs.is_active = true -and ( - coalesce(bs.record_id, -1) != coalesce(bos.blocking_state_record_id, -1) - or coalesce(bs.state, 'NULL') != coalesce(bos.state, 'NULL') - /* TODO SubscriptionEvent is not an entity, we don't have that info yet - or coalesce(bs.created_date, cast('1970-01-01' as date)) != coalesce(bos.created_date, cast('1970-01-01' as date)) */ - /* Tricky... Need to look at the account timezone */ - or (coalesce(date(bs.effective_date), cast('1970-01-01' as date)) != coalesce(date(bos.start_date), cast('1970-01-01' as date)) - and coalesce(date(bs.effective_date), cast('1970-01-01' as date)) != coalesce(date_add(date(bos.start_date), INTERVAL '1' DAY), cast('1970-01-01' as date)) - and coalesce(date(bs.effective_date), cast('1970-01-01' as date)) != coalesce(date_sub(date(bos.start_date), INTERVAL '1' DAY), cast('1970-01-01' as date))) - or coalesce(bs.account_record_id, -1) != coalesce(bos.account_record_id, -1) - or coalesce(bs.tenant_record_id, -1) != coalesce(bos.tenant_record_id, -1) -) -; - -select 'I2' as sanity_query_name; -select distinct b.account_record_id -from analytics_account_transitions b -left outer join accounts a on a.id = b.account_id -where 1 = 1 -and ( - coalesce(a.record_id) != coalesce(b.account_record_id, -1) - or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') - or coalesce(a.name, '') != coalesce(b.account_name, '') -) -; - -select 'I3' as sanity_query_name; -select distinct b.account_record_id -from analytics_account_transitions b -join audit_log al on b.blocking_state_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'BLOCKING_STATES' -where 1 = 1 -and ( - coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') - or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') - or coalesce(b.created_by, '') != coalesce(al.created_by, '') -) -; - - --- SUBSCRIPTION TRANSITIONS - -select 'J1' as sanity_query_name; -select distinct bst.account_record_id -from analytics_subscription_transitions bst -left outer join subscription_events se on bst.subscription_event_record_id = se.record_id -/* TODO Look at entilement rows only, ignore in-memory events and blocking states */ -where (coalesce(bst.prev_service, 'entitlement-service') = 'entitlement-service' -and coalesce(bst.next_service, 'entitlement-service') = 'entitlement-service' -and bst.subscription_event_record_id is not null) -/* Tricky... Need to look at the account timezone */ -and ((coalesce(date(se.requested_date), cast('1970-01-01' as date)) != coalesce(date(bst.requested_timestamp), cast('1970-01-01' as date)) -and coalesce(date(se.requested_date), cast('1970-01-01' as date)) != coalesce(date_add(date(bst.requested_timestamp), INTERVAL '1' DAY), cast('1970-01-01' as date)) -and coalesce(date(se.requested_date), cast('1970-01-01' as date)) != coalesce(date_sub(date(bst.requested_timestamp), INTERVAL '1' DAY), cast('1970-01-01' as date))) -or (coalesce(date(se.effective_date), cast('1970-01-01' as date)) != coalesce(date(bst.next_start_date), cast('1970-01-01' as date)) -and coalesce(date(se.effective_date), cast('1970-01-01' as date)) != coalesce(date_add(date(bst.next_start_date), INTERVAL '1' DAY), cast('1970-01-01' as date)) -and coalesce(date(se.effective_date), cast('1970-01-01' as date)) != coalesce(date_sub(date(bst.next_start_date), INTERVAL '1' DAY), cast('1970-01-01' as date))) -or coalesce(se.subscription_id, '') != coalesce(bst.subscription_id, '') -or coalesce(se.phase_name, '') != coalesce(bst.next_slug, '') -/* See https://github.com/killbill/killbill/issues/65: subscription_events won't have the pricelist but the SubscriptionEvent object will at runtime */ -or (se.price_list_name is not null and se.price_list_name != coalesce(bst.next_price_list, '')) -/* TODO SubscriptionEvent is not an entity, we don't have that info yet (we currently look at audit logs but this doesn't work for in-memory events) -or coalesce(se.created_date, cast('1970-01-01' as date)) != coalesce(bst.created_date, cast('1970-01-01' as date)) */ -or coalesce(se.account_record_id, -1) != coalesce(bst.account_record_id, -1) -or coalesce(se.tenant_record_id, -1) != coalesce(bst.tenant_record_id, -1)) -; - -select 'J2' as sanity_query_name; -select distinct b.account_record_id -from analytics_subscription_transitions b -left outer join accounts a on a.id = b.account_id -where coalesce(a.record_id) != coalesce(b.account_record_id, -1) -or coalesce(a.id, '') != coalesce(b.account_id, '') -or coalesce(a.external_key, '') != coalesce(b.account_external_key, '') -or coalesce(a.name, '') != coalesce(b.account_name, '') -; - -select 'J4' as sanity_query_name; -select distinct b.account_record_id -from analytics_subscription_transitions b -join audit_log al on b.subscription_event_record_id = al.target_record_id and al.change_type = 'INSERT' and table_name = 'SUBSCRIPTION_EVENTS' -/* TODO Look at entilement rows only, ignore in-memory events and blocking states */ -where (coalesce(b.prev_service, 'entitlement-service') = 'entitlement-service' -and coalesce(b.next_service, 'entitlement-service') = 'entitlement-service' -and b.subscription_event_record_id is not null) -and (coalesce(b.created_reason_code, 'NULL') != coalesce(al.reason_code, 'NULL') -or coalesce(b.created_comments, 'NULL') != coalesce(al.comments, 'NULL') -or coalesce(b.created_by, '') != coalesce(al.created_by, '')) -; - -select 'J5a' as sanity_query_name; -select distinct account_record_id -from analytics_subscription_transitions -where 1 = 1 -and event like 'START%' -and prev_product_name is not null -; - -select 'J5b' as sanity_query_name; -select distinct account_record_id -from analytics_subscription_transitions -where 1 = 1 -and event like 'START%' -and next_product_name is null -; - -select 'J6' as sanity_query_name; -select distinct account_record_id -from analytics_subscription_transitions -where 1 = 1 -and event like 'STOP%' -and prev_product_name is null -; - -select 'J7' as sanity_query_name; -select distinct account_record_id -from analytics_subscription_transitions -where 1 = 1 -and event like 'ERROR%' -; - -select 'J8' as sanity_query_name; -select distinct account_record_id -from analytics_subscription_transitions -where 1 = 1 -and prev_service != next_service -; - -select 'J9' as sanity_query_name; -select distinct account_record_id -from analytics_subscription_transitions -where 1 = 1 -and coalesce(prev_product_category, next_product_category) != coalesce(next_product_category, prev_product_category) -; - -select 'J10' as sanity_query_name; -select distinct account_record_id -from analytics_subscription_transitions ast -join ( - select - subscription_id - , event - , count(*) - from analytics_subscription_transitions - where 1 = 1 - and (event like 'START_%' or event like 'STOP_%') - group by 1, 2 - having(count(*)) > 1 -) duplicates using(subscription_id) -; - -select 'J11' as sanity_query_name; -select distinct account_record_id -from analytics_subscription_transitions ast -join ( - select - account_record_id - , event - , next_service - from analytics_subscription_transitions - where 1 = 1 - and ( - (event like '%ENTITLEMENT%' and next_service = 'billing-service') - or (event like '%BILLING%' and next_service = 'entitlement-service') - ) -) wrong_service using(account_record_id) -; - --- BUNDLE FIELDS -/* table not currently used */ - - --- BUNDLE TAGS -/* table not currently used */ - -select 'K1: Validate consistency of states between payments and payment_transactions' as sanity_query_name; -select * from ( -select - p.id - ,case when first_failure_record_id is not null then - case when first_failure_ptrx.transaction_status in ('UNKNOWN','PLUGIN_FAILURE') then - case when first_failure_ptrx.transaction_type='AUTHORIZE' then 'AUTH_ERRORED' - when first_failure_ptrx.transaction_type='CAPTURE' then 'CAPTURE_ERRORED' - when first_failure_ptrx.transaction_type='CHARGEBACK' then'CHARGEBACK_ERRORED' - when first_failure_ptrx.transaction_type='CREDIT' then 'CREDIT_ERRORED' - when first_failure_ptrx.transaction_type='PURCHASE' then 'PURCHASE_ERRORED' - when first_failure_ptrx.transaction_type='REFUND' then 'REFUND_ERRORED' - when first_failure_ptrx.transaction_type='VOID' then 'VOID_ERRORED' - end - when first_failure_ptrx.transaction_status='PAYMENT_FAILURE' then - case when first_failure_ptrx.transaction_type='AUTHORIZE' then 'AUTH_FAILED' - when first_failure_ptrx.transaction_type='CAPTURE' then 'CAPTURE_FAILED' - when first_failure_ptrx.transaction_type='CHARGEBACK' then'CHARGEBACK_FAILED' - when first_failure_ptrx.transaction_type='CREDIT' then 'CREDIT_FAILED' - when first_failure_ptrx.transaction_type='PURCHASE' then 'PURCHASE_FAILED' - when first_failure_ptrx.transaction_type='REFUND' then 'REFUND_FAILED' - when first_failure_ptrx.transaction_type='VOID' then 'VOID_FAILED' - end - end - when first_failure_record_id is null and last_success_record_id is not null then - case when last_success_ptrx.transaction_type='AUTHORIZE' then 'AUTH_SUCCESS' - when last_success_ptrx.transaction_type='CAPTURE' then 'CAPTURE_SUCCESS' - when last_success_ptrx.transaction_type='CHARGEBACK' then'CHARGEBACK_SUCCESS' - when last_success_ptrx.transaction_type='CREDIT' then 'CREDIT_SUCCESS' - when last_success_ptrx.transaction_type='PURCHASE' then 'PURCHASE_SUCCESS' - when last_success_ptrx.transaction_type='REFUND' then 'REFUND_SUCCESS' - when last_success_ptrx.transaction_type='VOID' then 'VOID_SUCCESS' - end - when first_failure_record_id is null and last_success_record_id is null and first_record_id is not null then - case when first_ptrx.transaction_status in ('UNKNOWN','PLUGIN_FAILURE') then - case when first_ptrx.transaction_type='AUTHORIZE' then 'AUTH_ERRORED' - when first_ptrx.transaction_type='CAPTURE' then 'CAPTURE_ERRORED' - when first_ptrx.transaction_type='CHARGEBACK' then'CHARGEBACK_ERRORED' - when first_ptrx.transaction_type='CREDIT' then 'CREDIT_ERRORED' - when first_ptrx.transaction_type='PURCHASE' then 'PURCHASE_ERRORED' - when first_ptrx.transaction_type='REFUND' then 'REFUND_ERRORED' - when first_ptrx.transaction_type='VOID' then 'VOID_ERRORED' - end - when first_ptrx.transaction_status='PAYMENT_FAILURE' then - case when first_ptrx.transaction_type='AUTHORIZE' then 'AUTH_FAILED' - when first_ptrx.transaction_type='CAPTURE' then 'CAPTURE_FAILED' - when first_ptrx.transaction_type='CHARGEBACK' then'CHARGEBACK_FAILED' - when first_ptrx.transaction_type='CREDIT' then 'CREDIT_FAILED' - when first_ptrx.transaction_type='PURCHASE' then 'PURCHASE_FAILED' - when first_ptrx.transaction_type='REFUND' then 'REFUND_FAILED' - when first_ptrx.transaction_type='VOID' then 'VOID_FAILED' - end - end - end as expected_value - ,p.state_name -from ( - select - first_ptrx.payment_id - ,first_ptrx.record_id first_record_id - ,latest_success.record_id as last_success_record_id - ,min(pt.record_id) as first_failure_record_id - from ( - select - pt.payment_id - ,min(pt.record_id) record_id - from payment_transactions pt - group by 1 - ) first_ptrx - left outer join ( - select - pt.payment_id - ,max(pt.record_id) record_id - from payment_transactions pt - where 1=1 - and pt.transaction_status = 'SUCCESS' - group by 1 - ) latest_success on first_ptrx.payment_id=latest_success.payment_id - left outer join payment_transactions pt on - pt.payment_id=latest_success.payment_id - and pt.record_id>latest_success.record_id - and pt.transaction_status != 'SUCCESS' - group by 1,2 - ) ptrx - inner join payments p on - ptrx.payment_id = p.id - left outer join payment_transactions first_ptrx on - ptrx.first_record_id=first_ptrx.record_id - left outer join payment_transactions last_success_ptrx on - ptrx.last_success_record_id=last_success_ptrx.record_id - left outer join payment_transactions first_failure_ptrx on - ptrx.first_failure_record_id=first_failure_ptrx.record_id -) t1 -where 1=1 - and expected_value != state_name -; - -select 'K2: payments.last_success_state_name and payment_transactions.transaction_state and payment_transactions.transaction_status' as sanity_query_name; -select - * -from ( -select - pt.transaction_type - ,pt.transaction_status - ,case when pt.transaction_type='AUTHORIZE' then 'AUTH_SUCCESS' - when pt.transaction_type='CAPTURE' then 'CAPTURE_SUCCESS' - when pt.transaction_type='CHARGEBACK' then'CHARGEBACK_SUCCESS' - when pt.transaction_type='CREDIT' then 'CREDIT_SUCCESS' - when pt.transaction_type='PURCHASE' then 'PURCHASE_SUCCESS' - when pt.transaction_type='REFUND' then 'REFUND_SUCCESS' - when pt.transaction_type='VOID' then 'VOID_SUCCESS' - end as expected_value - ,p.last_success_state_name - ,count(1) -from ( -select - pt.payment_id - ,max(pt.record_id) latest_record_id -from payment_transactions pt -where 1=1 - and pt.transaction_status = 'SUCCESS' -group by 1 -) latest_pt - inner join payment_transactions pt on - latest_pt.payment_id=pt.payment_id - and latest_pt.latest_record_id=pt.record_id - inner join payments p on - latest_pt.payment_id=p.id -group by 1,2,3,4 -) t1 -where 1=1 - and expected_value != last_success_state_name -; - -select 'K3: At least on payment trx for each payment' as sanity_query_name; -select - * -from - payments p - left outer join payment_transactions pt on - p.id=pt.payment_id -where 1=1 - and pt.payment_id is null -; - -select 'L1: Validate consistency between base payments tables and anlytics_payment_* tables' as sanity_query_name; -select - a.tenant_record_id - ,'analytics_payment_auths' as table_name - ,sum(case when b.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when b.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - and p.id=b.payment_id and p.external_key=b.payment_external_key and p.record_id=b.payment_number and p.account_id=b.account_id - then 1 else 0 end) matches - ,count(1) total -from - payments p - inner join payment_transactions a on - p.id=a.payment_id - left outer join analytics_payment_auths b on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='AUTHORIZE' -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_captures' as table_name - ,sum(case when b.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when b.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - and p.id=b.payment_id and p.external_key=b.payment_external_key and p.record_id=b.payment_number and p.account_id=b.account_id - then 1 else 0 end) matches - ,count(1) total -from - payments p - inner join payment_transactions a on - p.id=a.payment_id - left outer join analytics_payment_captures b on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='CAPTURE' -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_credits' as table_name - ,sum(case when b.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when b.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - and p.id=b.payment_id and p.external_key=b.payment_external_key and p.record_id=b.payment_number and p.account_id=b.account_id - then 1 else 0 end) matches - ,count(1) total -from - payments p - inner join payment_transactions a on - p.id=a.payment_id - left outer join analytics_payment_credits b on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='CREDIT' -- ?? -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_chargebacks' as table_name - ,sum(case when b.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when b.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - and p.id=b.payment_id and p.external_key=b.payment_external_key and p.record_id=b.payment_number and p.account_id=b.account_id - then 1 else 0 end) matches - ,count(1) total -from - payments p - inner join payment_transactions a on - p.id=a.payment_id - left outer join analytics_payment_chargebacks b on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='CHARGEBACK' -- ?? -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_purchases' as table_name - ,sum(case when b.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when b.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - and p.id=b.payment_id and p.external_key=b.payment_external_key and p.record_id=b.payment_number and p.account_id=b.account_id - then 1 else 0 end) matches - ,count(1) total -from - payments p - inner join payment_transactions a on - p.id=a.payment_id - left outer join analytics_payment_purchases b on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='PURCHASE' -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_refunds' as table_name - ,sum(case when b.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when b.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - and p.id=b.payment_id and p.external_key=b.payment_external_key and p.record_id=b.payment_number and p.account_id=b.account_id - then 1 else 0 end) matches - ,count(1) total -from - payments p - inner join payment_transactions a on - p.id=a.payment_id - left outer join analytics_payment_refunds b on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='REFUND' -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_voids' as table_name - ,sum(case when b.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when b.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - and p.id=b.payment_id and p.external_key=b.payment_external_key and p.record_id=b.payment_number and p.account_id=b.account_id - then 1 else 0 end) matches - ,count(1) total -from - payments p - inner join payment_transactions a on - p.id=a.payment_id - left outer join analytics_payment_voids b on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='VOID' -group by 1,2 -; - -select 'L2: Validate consistency between base payment_transactions tables and anlytics_payment_* tables' as sanity_query_name; -select - a.tenant_record_id - ,'analytics_payment_auths' as table_name - ,sum(case when a.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when a.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_auths b - left outer join payment_transactions a on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='AUTHORIZE' -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_captures' as table_name - ,sum(case when a.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when a.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_captures b - left outer join payment_transactions a on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='CAPTURE' -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_credits' as table_name - ,sum(case when a.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when a.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_credits b - left outer join payment_transactions a on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='CREDIT' -- ?? -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_chargebacks' as table_name - ,sum(case when a.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when a.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_chargebacks b - left outer join payment_transactions a on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='CHARGEBACK' -- ?? -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_purchases' as table_name - ,sum(case when a.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when a.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_purchases b - left outer join payment_transactions a on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='PURCHASE' -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_refunds' as table_name - ,sum(case when a.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when a.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_refunds b - left outer join payment_transactions a on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='REFUND' -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_voids' as table_name - ,sum(case when a.payment_id is null then 1 else 0 end) as row_missing - ,sum(case when a.payment_id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_transaction_id and a.transaction_external_key=b.payment_transaction_external_key - and a.transaction_status=b.payment_transaction_status -- and a.amount=b.amount and a.currency=b.currency and a.tenant_record_id=b.tenant_record_id - then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_voids b - left outer join payment_transactions a on - a.id=b.payment_transaction_id -where 1=1 - and a.transaction_type='VOID' -group by 1,2 -; - -select 'L3: Validate consistency between anlytics_payment_* tables and base payments tables' as sanity_query_name; -select - a.tenant_record_id - ,'analytics_payment_auths' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_id and a.record_id=b.payment_number and a.external_key=b.payment_external_key then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_auths b - left outer join payments a on - a.id=b.payment_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_captures' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_id and a.record_id=b.payment_number and a.external_key=b.payment_external_key then 1 else 0 end) matches ,count(1) total -from - analytics_payment_captures b - left outer join payments a on - a.id=b.payment_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_credits' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_id and a.record_id=b.payment_number and a.external_key=b.payment_external_key then 1 else 0 end) matches ,count(1) total -from - analytics_payment_credits b - left outer join payments a on - a.id=b.payment_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_chargebacks' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_id and a.record_id=b.payment_number and a.external_key=b.payment_external_key then 1 else 0 end) matches ,count(1) total -from - analytics_payment_chargebacks b - left outer join payments a on - a.id=b.payment_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_purchases' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_id and a.record_id=b.payment_number and a.external_key=b.payment_external_key then 1 else 0 end) matches ,count(1) total -from - analytics_payment_purchases b - left outer join payments a on - a.id=b.payment_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_refunds' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_id and a.record_id=b.payment_number and a.external_key=b.payment_external_key then 1 else 0 end) matches ,count(1) total -from - analytics_payment_refunds b - left outer join payments a on - a.id=b.payment_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_voids' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.payment_id and a.record_id=b.payment_number and a.external_key=b.payment_external_key then 1 else 0 end) matches ,count(1) total -from - analytics_payment_voids b - left outer join payments a on - a.id=b.payment_id -group by 1,2 -; - -select 'L4: Validate consistency between anlytics_payment_* tables and base accounts tables' as sanity_query_name; -select - a.tenant_record_id - ,'analytics_payment_auths' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.account_id and a.record_id=b.account_record_id and a.external_key=b.account_external_key then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_auths b - left outer join accounts a on - a.id=b.account_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_captures' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.account_id and a.record_id=b.account_record_id and a.external_key=b.account_external_key then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_captures b - left outer join accounts a on - a.id=b.account_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_credits' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.account_id and a.record_id=b.account_record_id and a.external_key=b.account_external_key then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_credits b - left outer join accounts a on - a.id=b.account_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_chargebacks' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.account_id and a.record_id=b.account_record_id and a.external_key=b.account_external_key then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_chargebacks b - left outer join accounts a on - a.id=b.account_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_purchases' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.account_id and a.record_id=b.account_record_id and a.external_key=b.account_external_key then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_purchases b - left outer join accounts a on - a.id=b.account_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_refunds' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.account_id and a.record_id=b.account_record_id and a.external_key=b.account_external_key then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_refunds b - left outer join accounts a on - a.id=b.account_id -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_voids' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id=b.account_id and a.record_id=b.account_record_id and a.external_key=b.account_external_key then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_voids b - left outer join accounts a on - a.id=b.account_id -group by 1,2 -; - -select 'L5: Validate consistency between anlytics_payment_* tables and base invoice_payments tables' as sanity_query_name; -select - a.tenant_record_id - ,'analytics_payment_auths' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_payment_id and a.record_id = b.invoice_payment_record_id and a.type = b.invoice_payment_type then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_auths b - left outer join invoice_payments a on - a.id=b.invoice_payment_id -where 1=1 - and b.invoice_payment_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_captures' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_payment_id and a.record_id = b.invoice_payment_record_id and a.type = b.invoice_payment_type then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_captures b - left outer join invoice_payments a on - a.id=b.invoice_payment_id -where 1=1 - and b.invoice_payment_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_credits' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_payment_id and a.record_id = b.invoice_payment_record_id and a.type = b.invoice_payment_type then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_credits b - left outer join invoice_payments a on - a.id=b.invoice_payment_id -where 1=1 - and b.invoice_payment_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_chargebacks' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_payment_id and a.record_id = b.invoice_payment_record_id and a.type = b.invoice_payment_type then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_chargebacks b - left outer join invoice_payments a on - a.id=b.invoice_payment_id -where 1=1 - and b.invoice_payment_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_purchases' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_payment_id and a.record_id = b.invoice_payment_record_id and a.type = b.invoice_payment_type then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_purchases b - left outer join invoice_payments a on - a.id=b.invoice_payment_id -where 1=1 - and b.invoice_payment_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_refunds' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_payment_id and a.record_id = b.invoice_payment_record_id and a.type = b.invoice_payment_type then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_refunds b - left outer join invoice_payments a on - a.id=b.invoice_payment_id -where 1=1 - and b.invoice_payment_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_voids' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_payment_id and a.record_id = b.invoice_payment_record_id and a.type = b.invoice_payment_type then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_voids b - left outer join invoice_payments a on - a.id=b.invoice_payment_id -where 1=1 - and b.invoice_payment_id is not null -group by 1,2 -; - -select 'L6: Validate consistency between anlytics_payment_* tables and base invoices tables' as sanity_query_name; -select - a.tenant_record_id - ,'analytics_payment_auths' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_id and a.currency = b.invoice_currency and a.record_id = b.invoice_number - and a.invoice_date = b.invoice_date and a.target_date = b.invoice_target_date then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_auths b - left outer join invoices a on - a.id=b.invoice_id -where 1=1 - and b.invoice_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_captures' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_id and a.currency = b.invoice_currency and a.record_id = b.invoice_number - and a.invoice_date = b.invoice_date and a.target_date = b.invoice_target_date then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_captures b - left outer join invoices a on - a.id=b.invoice_id -where 1=1 - and b.invoice_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_credits' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_id and a.currency = b.invoice_currency and a.record_id = b.invoice_number - and a.invoice_date = b.invoice_date and a.target_date = b.invoice_target_date then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_credits b - left outer join invoices a on - a.id=b.invoice_id -where 1=1 - and b.invoice_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_chargebacks' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_id and a.currency = b.invoice_currency and a.record_id = b.invoice_number - and a.invoice_date = b.invoice_date and a.target_date = b.invoice_target_date then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_chargebacks b - left outer join invoices a on - a.id=b.invoice_id -where 1=1 - and b.invoice_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_purchases' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_id and a.currency = b.invoice_currency and a.record_id = b.invoice_number - and a.invoice_date = b.invoice_date and a.target_date = b.invoice_target_date then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_purchases b - left outer join invoices a on - a.id=b.invoice_id -where 1=1 - and b.invoice_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_refunds' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_id and a.currency = b.invoice_currency and a.record_id = b.invoice_number - and a.invoice_date = b.invoice_date and a.target_date = b.invoice_target_date then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_refunds b - left outer join invoices a on - a.id=b.invoice_id -where 1=1 - and b.invoice_id is not null -group by 1,2 -UNION -select - a.tenant_record_id - ,'analytics_payment_voids' as table_name - ,sum(case when a.id is null then 1 else 0 end) as row_missing - ,sum(case when a.id is not null then 1 else 0 end) as row_exists - ,sum(case when a.id = b.invoice_id and a.currency = b.invoice_currency and a.record_id = b.invoice_number - and a.invoice_date = b.invoice_date and a.target_date = b.invoice_target_date then 1 else 0 end) matches - ,count(1) total -from - analytics_payment_voids b - left outer join invoices a on - a.id=b.invoice_id -where 1=1 - and b.invoice_id is not null -group by 1,2 -; - -select 'L7: Validate no duplicate rows in analytics_payment_*' as sanity_query_name; -select - table_name as "Table Name" - ,repeat_count as "Repeated Row Count" -from ( -select 'analytics_accounts' as table_name, ifnull(count(1),0) as repeat_count from ( - select account_record_id from analytics_accounts a group by 1 having count(1)>1 ) b -UNION -select 'analytics_bundles' as table_name, count(1) from ( - select bundle_record_id from analytics_bundles a group by 1 having count(1)>1 ) b -UNION -select 'analytics_invoice_adjustments' as table_name, ifnull(count(1),0) as repeat_count from ( - select invoice_item_record_id from analytics_invoice_adjustments a group by 1 having count(1)>1 ) b -UNION -select 'analytics_invoice_credits' as table_name, ifnull(count(1),0) as repeat_count from ( - select invoice_item_record_id from analytics_invoice_credits a group by 1 having count(1)>1 ) b -UNION -select 'analytics_invoice_item_adjustments' as table_name, ifnull(count(1),0) as repeat_count from ( - select invoice_item_record_id from analytics_invoice_item_adjustments a group by 1 having count(1)>1 ) b -UNION -select 'analytics_invoice_items' as table_name, ifnull(count(1),0) as repeat_count from ( - select invoice_item_record_id from analytics_invoice_items a group by 1 having count(1)>1 ) b -UNION -select 'analytics_invoices' as table_name, ifnull(count(1),0) as repeat_count from ( - select invoice_record_id from analytics_invoices a group by 1 having count(1)>1 ) b -UNION -select 'analytics_payment_auths' as table_name, ifnull(count(1),0) as repeat_count from ( - select payment_transaction_id from analytics_payment_auths a group by 1 having count(1)>1 ) b -UNION -select 'analytics_payment_captures' as table_name, count(1) from ( - select payment_transaction_id from analytics_payment_captures a group by 1 having count(1)>1 ) b -UNION -select 'analytics_payment_credits' as table_name, count(1) from ( - select payment_transaction_id from analytics_payment_credits a group by 1 having count(1)>1 ) b -UNION -select 'analytics_payment_chargebacks' as table_name, count(1) from ( - select payment_transaction_id from analytics_payment_chargebacks a group by 1 having count(1)>1 ) b -UNION -select 'analytics_payment_purchases' as table_name, count(1) from ( - select payment_transaction_id from analytics_payment_purchases a group by 1 having count(1)>1 ) b -UNION -select 'analytics_payment_refunds' as table_name, count(1) from ( - select payment_transaction_id from analytics_payment_refunds a group by 1 having count(1)>1 ) b -UNION -select 'analytics_payment_voids' as table_name, count(1) from ( - select payment_transaction_id from analytics_payment_voids a group by 1 having count(1)>1 ) b -) c -order by 2 desc, 1 -; diff --git a/src/main/resources/system/README.md b/src/main/resources/system/README.md deleted file mode 100644 index e8d17f78..00000000 --- a/src/main/resources/system/README.md +++ /dev/null @@ -1,7 +0,0 @@ -These system queries help verify the health of Kill Bill. - -* [system_report_control_tag_no_test.sql](https://github.com/killbill/killbill-analytics-plugin/blob/master/src/main/resources/system/system_report_control_tag_no_test.sql): for each system tag, count the number of non-test accounts -* [system_report_notifications_per_queue_name.sql](https://github.com/killbill/killbill-analytics-plugin/blob/master/src/main/resources/system/system_report_notifications_per_queue_name.sql): for each notification queue and date, list the number of *AVAILABLE* notifications -* [system_report_notifications_per_queue_name_late.sql](https://github.com/killbill/killbill-analytics-plugin/blob/master/src/main/resources/system/system_report_notifications_per_queue_name_late.sql): for each notification queue, count the number of late notifications -* [system_report_payments.sql](https://github.com/killbill/killbill-analytics-plugin/blob/master/src/main/resources/system/system_report_payments.sql): count the number of payments in each state -* [system_report_payments_per_day.sql](https://github.com/killbill/killbill-analytics-plugin/blob/master/src/main/resources/system/system_report_payments_per_day.sql): count the number of payments in each state per day diff --git a/src/main/resources/system/system_report_control_tag_no_test.sql b/src/main/resources/system/system_report_control_tag_no_test.sql deleted file mode 100644 index 371f47dc..00000000 --- a/src/main/resources/system/system_report_control_tag_no_test.sql +++ /dev/null @@ -1,13 +0,0 @@ -create or replace view v_system_report_control_tag_no_test as -select - a1.tenant_record_id -, a1.name as tag_name -, count(distinct(a1.account_id)) as count -from analytics_account_tags a1 -left outer join analytics_account_tags a2 -on a1.account_id = a2.account_id and a2.name = 'TEST' -where 1=1 -and a2.record_id IS NULL -and a1.name IN ('OVERDUE_ENFORCEMENT_OFF', 'AUTO_PAY_OFF', 'AUTO_INVOICING_OFF', 'MANUAL_PAY', 'PARTNER') -group by 1, 2 -; diff --git a/src/main/resources/system/system_report_notifications_per_queue_name.sql b/src/main/resources/system/system_report_notifications_per_queue_name.sql deleted file mode 100644 index 88971e9a..00000000 --- a/src/main/resources/system/system_report_notifications_per_queue_name.sql +++ /dev/null @@ -1,11 +0,0 @@ -create or replace view v_system_report_notifications_per_queue_name as -select - search_key2 as tenant_record_id -, queue_name -, date_format(effective_date, '%Y-%m-%d') as day -, count(*) as count -from notifications -where processing_state = 'AVAILABLE' -group by 1, 2, 3 -order by 1, 2, 3 asc -; diff --git a/src/main/resources/system/system_report_notifications_per_queue_name_late.sql b/src/main/resources/system/system_report_notifications_per_queue_name_late.sql deleted file mode 100644 index 33599f6b..00000000 --- a/src/main/resources/system/system_report_notifications_per_queue_name_late.sql +++ /dev/null @@ -1,13 +0,0 @@ -create or replace view v_system_report_notifications_per_queue_name_late as -select - search_key2 as tenant_record_id -, queue_name as label -, count(*) as count -from notifications -where 1=1 -and processing_state = 'AVAILABLE' -and effective_date < NOW() --- and (processing_owner IS NULL OR processing_available_date <= NOW()) -group by 1, 2 -order by 1, 2 asc -; diff --git a/src/main/resources/system/system_report_payments.sql b/src/main/resources/system/system_report_payments.sql deleted file mode 100644 index 36152c14..00000000 --- a/src/main/resources/system/system_report_payments.sql +++ /dev/null @@ -1,8 +0,0 @@ -create or replace view v_system_report_payments as -select - tenant_record_id -, state_name as label -, count(*) as count -from payments -group by 1, 2 -; diff --git a/src/main/resources/system/system_report_payments_per_day.sql b/src/main/resources/system/system_report_payments_per_day.sql deleted file mode 100644 index e25f3adc..00000000 --- a/src/main/resources/system/system_report_payments_per_day.sql +++ /dev/null @@ -1,16 +0,0 @@ -create or replace view v_system_report_payments_per_day as -select - tenant_record_id -, date_format(greatest(created_date, updated_date), '%Y-%m-%d') as day -, case - when state_name IN ('AUTH_ERRORED', 'CAPTURE_ERRORED', 'CHARGEBACK_ERRORED', 'CREDIT_ERRORED', 'PURCHASE_ERRORED', 'REFUND_ERRORED', 'VOID_ERRORED') then 'ERRORED' - when state_name IN ('AUTH_FAILED', 'CAPTURE_FAILED', 'CHARGEBACK_FAILED', 'CREDIT_FAILED', 'PURCHASE_FAILED', 'REFUND_FAILED', 'VOID_FAILED') then 'FAILED' - when state_name IN ('AUTH_PENDING', 'CAPTURE_PENDING', 'CHARGEBACK_PENDING', 'CREDIT_PENDING', 'PURCHASE_PENDING', 'REFUND_PENDING', 'VOID_PENDING') then 'PENDING' - when state_name IN ('AUTH_SUCCESS', 'CAPTURE_SUCCESS', 'CHARGEBACK_SUCCESS', 'CREDIT_SUCCESS', 'PURCHASE_SUCCESS', 'REFUND_SUCCESS', 'VOID_SUCCESS') then 'SUCCESS' - else 'OTHER' - end as payment_status -, count(*) as count -from payments -group by 1, 2, 3 -order by 1, 2, 3 asc -;