diff --git a/src/main/resources/extracts/finance/invoice_adjustments_monthly.sql b/src/main/resources/extracts/finance/invoice_adjustments_monthly.sql deleted file mode 100644 index 6000e891..00000000 --- a/src/main/resources/extracts/finance/invoice_adjustments_monthly.sql +++ /dev/null @@ -1,29 +0,0 @@ -select - ia.invoice_number as "Invoice Number" -, ia.account_name as "Customer Name" -, ia.account_external_key as "Account Number" -, date_format(ia.created_date, '%m/%d/%Y') as "Adjustment Date" -, date_format(ia.invoice_date, '%m/%d/%Y') as "Invoice Date" -, date_format(ia.invoice_date, '%m/%d/%Y') as "Target Date" -, date_format(ia.created_date, '%m/%d/%Y') as "Creation Date" -- Adjustment date? -, ia.currency as "Currency" -, ia.invoice_original_amount_charged as "Invoice Amount" -, ia.invoice_balance as "Invoice Balance" -, ia.amount as "Invoice Adjustment Amount" -, abs(ia.amount) as "Impact Amount" -, round(cc.reference_rate * ia.invoice_original_amount_charged,4) as "Invoice Amount USD" -, round(cc.reference_rate * ia.invoice_balance,4) as "Invoice Balance USD" -, round(cc.reference_rate * ia.amount,4) as "Invoice Adjustment Amount USD" -, abs(round(cc.reference_rate * ia.amount,4)) as "Impact Amount USD" -, case when ia.amount > 0 then 'CREDIT' else 'CHARGE' end as "Adjustment Type" -, 'PROCESSED' as "Invoice Adjustment Status" -from - analytics_invoice_adjustments ia - join analytics_currency_conversion cc on ia.created_date >= cc.start_date and ia.created_date <= cc.end_date and cc.currency =ia.currency -where 1=1 - and ia.created_date >= cast(date_format(date_sub(sysdate(), interval '1' month), '%Y-%m-01') as date) - and ia.created_date < cast(date_format(sysdate(), '%Y-%m-01') as date) - and ia.report_group != 'test' -order by - invoice_number -, ia.record_id; -- just for well defined ordering diff --git a/src/main/resources/extracts/finance/invoice_aging.sql b/src/main/resources/extracts/finance/invoice_aging.sql deleted file mode 100644 index c4506470..00000000 --- a/src/main/resources/extracts/finance/invoice_aging.sql +++ /dev/null @@ -1,58 +0,0 @@ -select - account_name "Customer Name" -, account_external_key "Account Number" -, a.currency "Currency" -, case when invoice_creation_date > cast('2014-01-01' as date) - interval '30' day then invoice_original_amount_charged else 0 end as "Balance due 0-30 Days" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '60' day and cast('2014-01-01' as date) - interval '30' day then invoice_original_amount_charged else 0 end as "Balance due 30-60 Days" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '90' day and cast('2014-01-01' as date) - interval '60' day then invoice_original_amount_charged else 0 end as "Balance due 60-90 Days" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '120' day and cast('2014-01-01' as date) - interval '90' day then invoice_original_amount_charged else 0 end as "Balance due 90-120 Days" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '150' day and cast('2014-01-01' as date) - interval '120' day then invoice_original_amount_charged else 0 end as "Balance due 120-150 Days" -, case when invoice_creation_date < cast('2014-01-01' as date) - interval '150' day then invoice_original_amount_charged else 0 end as "Balance due 150+ Days" -, invoice_original_amount_charged as "Total Balance Due" -, case when invoice_creation_date > cast('2014-01-01' as date) - interval '30' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 0-30 Days USD" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '60' day and cast('2014-01-01' as date) - interval '30' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 30-60 Days USD" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '90' day and cast('2014-01-01' as date) - interval '60' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 60-90 Days USD" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '120' day and cast('2014-01-01' as date) - interval '90' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 90-120 Days USD" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '150' day and cast('2014-01-01' as date) - interval '120' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 120-150 Days USD" -, case when invoice_creation_date < cast('2014-01-01' as date) - interval '150' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 150+ Days USD" -, cc.reference_rate * invoice_original_amount_charged as "Total Balance Due USD" -, invoice_number "Invoice Number" -, bundle_external_key "Bundle External Key" -, slug "Slug" -, service_start_date "Service Start Date" -, service_end_date "Service End Date" -, invoice_date "Invoice Date" -, invoice_original_amount_charged "Invoice Amount" -, invoice_balance "Invoice Balance" -, round(cc.reference_rate * invoice_original_amount_charged,4) "Invoice Amount USD" -, round(cc.reference_rate * invoice_balance,4) "Invoice Balance USD" -from ( - select - ii.invoice_number - , ii.account_name - , ii.account_external_key - , cast(date_format(ii.created_date, '%m/%d/%Y') as date) invoice_creation_date - , cast(date_format(ii.invoice_date, '%m/%d/%Y') as date) invoice_date - , cast(date_format(ii.invoice_date, '%m/%d/%Y') as date) target_date - , ii.bundle_external_key - , ii.product_name - , ii.slug - , cast(date_format(ii.start_date, '%m/%d/%Y') as date) as service_start_date - , cast(date_format(ii.end_date, '%m/%d/%Y') as date) as service_end_date - , ii.currency - , ii.invoice_original_amount_charged - , ii.invoice_balance - , ii.amount - , ii.created_date - , ii.invoice_item_record_id - from analytics_invoice_items ii - where 1=1 - and ii.invoice_date < cast(date_format(sysdate(), '%Y-%m-01') as date) - and ii.report_group != 'test' - and ii.invoice_balance > 0 -) a -join analytics_currency_conversion cc on a.created_date >= cc.start_date and a.created_date <= cc.end_date and cc.currency = a.currency -order by - account_name -, invoice_number -, a.invoice_item_record_id; diff --git a/src/main/resources/extracts/finance/invoice_aging_no_pmt.sql b/src/main/resources/extracts/finance/invoice_aging_no_pmt.sql deleted file mode 100644 index 34442eb5..00000000 --- a/src/main/resources/extracts/finance/invoice_aging_no_pmt.sql +++ /dev/null @@ -1,60 +0,0 @@ -select - account_name "Customer Name" -, account_external_key "Account Number" -, a.currency "Currency" -, case when invoice_creation_date > cast('2014-01-01' as date) - interval '30' day then invoice_original_amount_charged else 0 end as "Balance due 0-30 Days" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '60' day and cast('2014-01-01' as date) - interval '30' day then invoice_original_amount_charged else 0 end as "Balance due 30-60 Days" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '90' day and cast('2014-01-01' as date) - interval '60' day then invoice_original_amount_charged else 0 end as "Balance due 60-90 Days" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '120' day and cast('2014-01-01' as date) - interval '90' day then invoice_original_amount_charged else 0 end as "Balance due 90-120 Days" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '150' day and cast('2014-01-01' as date) - interval '120' day then invoice_original_amount_charged else 0 end as "Balance due 120-150 Days" -, case when invoice_creation_date < cast('2014-01-01' as date) - interval '150' day then invoice_original_amount_charged else 0 end as "Balance due 150+ Days" -, invoice_original_amount_charged as "Total Balance Due" -, case when invoice_creation_date > cast('2014-01-01' as date) - interval '30' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 0-30 Days USD" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '60' day and cast('2014-01-01' as date) - interval '30' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 30-60 Days USD" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '90' day and cast('2014-01-01' as date) - interval '60' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 60-90 Days USD" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '120' day and cast('2014-01-01' as date) - interval '90' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 90-120 Days USD" -, case when invoice_creation_date between cast('2014-01-01' as date) - interval '150' day and cast('2014-01-01' as date) - interval '120' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 120-150 Days USD" -, case when invoice_creation_date < cast('2014-01-01' as date) - interval '150' day then round(cc.reference_rate * invoice_original_amount_charged,4) else 0 end as "Balance due 150+ Days USD" -, cc.reference_rate * invoice_original_amount_charged as "Total Balance Due USD" -, invoice_number "Invoice Number" -, bundle_external_key "Bundle External Key" -, slug "Slug" -, service_start_date "Service Start Date" -, service_end_date "Service End Date" -, invoice_date "Invoice Date" -, invoice_original_amount_charged "Invoice Amount" -, invoice_balance "Invoice Balance" -, round(cc.reference_rate * invoice_original_amount_charged,4) "Invoice Amount USD" -, round(cc.reference_rate * invoice_balance,4) "Invoice Balance USD" -from ( - select - ii.invoice_number - , ii.account_name - , ii.account_external_key - , cast(date_format(ii.created_date, '%m/%d/%Y') as date) invoice_creation_date - , cast(date_format(ii.invoice_date, '%m/%d/%Y') as date) invoice_date - , cast(date_format(ii.invoice_date, '%m/%d/%Y') as date) target_date - , ii.bundle_external_key - , ii.product_name - , ii.slug - , cast(date_format(ii.start_date, '%m/%d/%Y') as date) as service_start_date - , cast(date_format(ii.end_date, '%m/%d/%Y') as date) as service_end_date - , ii.currency - , ii.invoice_original_amount_charged - , ii.invoice_balance - , ii.amount - , ii.created_date - , ii.invoice_item_record_id - from analytics_invoice_items ii - where 1=1 - and ii.invoice_date < cast(date_format(sysdate(), '%Y-%m-01') as date) - and ii.report_group != 'test' - and ii.amount > 0 - and ii.invoice_amount_paid=0 - and ii.invoice_amount_charged=ii.invoice_original_amount_charged -) a -join analytics_currency_conversion cc on a.created_date >= cc.start_date and a.created_date <= cc.end_date and cc.currency = a.currency -order by - account_name -, invoice_number -, a.invoice_item_record_id; diff --git a/src/main/resources/extracts/finance/refunds_monthly.sql b/src/main/resources/extracts/finance/refunds_monthly.sql deleted file mode 100644 index 9a431f7a..00000000 --- a/src/main/resources/extracts/finance/refunds_monthly.sql +++ /dev/null @@ -1,37 +0,0 @@ -select - rfnd.account_name as "Customer Name" -, rfnd.account_external_key as "Account Number" -, rfnd.invoice_number as "Invoice Number" -, date_format(rfnd.invoice_date, '%m/%d/%Y') as "Invoice Date" -, rfnd.currency as "Currency" -, rfnd.invoice_original_amount_charged as "Invoice Amount" -, round(cc.reference_rate * rfnd.invoice_original_amount_charged,4) as "Invoice Amount USD" -, rfnd.plugin_name as "Payment Type" -, rfnd.plugin_pm_type as "Payment Method" -, rfnd.plugin_pm_cc_type as "Payment Card Type" -, case when plugin_name = 'killbill-litle' and plugin_pm_cc_type != 'AmericanExpress' then upper(lr.params_litleonelineresponse_saleresponse_litle_txn_id) else null end as "Litle Payment Reference ID" -- workaround -, case when plugin_name = 'killbill-litle' and plugin_pm_cc_type = 'AmericanExpress' then upper(lr.params_litleonelineresponse_saleresponse_id) else null end as "AmericanExpress Payment Reference ID" -- workaround -, case when plugin_name = 'killbill-paypal-express' then pp.paypal_express_txn_id else null end as "PayPal Payment Reference ID" -- workaround -, date_format(rfnd.created_date, '%m/%d/%Y') as "Payment Date" -, rfnd.currency as "Payment Currency" -, rfnd.amount as "Payment Amount" -, round(cc.reference_rate * rfnd.amount,4) as "Payment Amount USD" -, rfnd.record_id as "Refund Number" -, date_format(rfnd.created_date, '%m/%d/%Y') as "Refund Date" -, rfnd.currency as "Refund Currency" -, rfnd.amount as "Refund Amount" -, round(cc.reference_rate * rfnd.amount,4) as "Refund Amount USD" -, rfnd.invoice_amount_charged - rfnd.invoice_original_amount_charged "Total IA, IIA for Invoice" -, round(cc.reference_rate * (rfnd.invoice_amount_charged - rfnd.invoice_original_amount_charged),4) "Total IA, IIA for Invoice" -, rfnd.created_by as "User Responsible for Refund" -, 'REASON' as "Reason for Refund" -from - analytics_payment_refunds rfnd - join analytics_currency_conversion cc on rfnd.created_date >= cc.start_date and rfnd.created_date <= cc.end_date and cc.currency = rfnd.currency - left outer join paypal_express_transactions pp on pp.kb_payment_id=rfnd.payment_id and api_call = 'refund' -- workaround paypal # - left outer join litle_responses lr on lr.kb_payment_id=rfnd.payment_id and lr.success=1 and lr.api_call = 'charge' -- workaround litle # -where 1=1 - and rfnd.created_date >= cast(date_format(date_sub(sysdate(), interval '1' month), '%Y-%m-01') as date) - and rfnd.created_date < cast(date_format(sysdate(), '%Y-%m-01') as date) - and rfnd.report_group != 'test' -order by 1,rfnd.invoice_payment_record_id; -- just for well defined ordering diff --git a/src/main/resources/extracts/finance/test_accounts.sql b/src/main/resources/extracts/finance/test_accounts.sql deleted file mode 100644 index 647f071c..00000000 --- a/src/main/resources/extracts/finance/test_accounts.sql +++ /dev/null @@ -1,3 +0,0 @@ -select account_id,account_external_key -from analytics_account_tags -where name in ( 'TEST','PARTNER'); diff --git a/src/main/resources/reports/invoice_aging/README.md b/src/main/resources/reports/invoice_aging/README.md new file mode 100644 index 00000000..c50631b2 --- /dev/null +++ b/src/main/resources/reports/invoice_aging/README.md @@ -0,0 +1,31 @@ +# Invoice Aging Report + +This report lists all customer invoice aging with remaining balances, breaking them into standard aging buckets and converting amounts to USD for easy comparison. + +The snapshot view is: `v_report_invoice_aging` + +## Prerequisites + +This report requires the `analytics_currency_conversion` table to be populated. See [insertMonthlyCurrencyConversionRates.ddl](../utils/insertMonthlyCurrencyConversionRates.ddl) + +## Report Creation + +``` +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_invoice_aging", + "reportType": "TABLE", + "reportPrettyName": "Invoice Aging Report", + "sourceTableName": "report_invoice_aging", + "refreshProcedureName": "refresh_report_invoice_aging", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Report UI: + +![invoice-aging.png](invoice-aging.png) diff --git a/src/main/resources/reports/invoice_aging/invoice-aging.png b/src/main/resources/reports/invoice_aging/invoice-aging.png new file mode 100644 index 00000000..e4f749ca Binary files /dev/null and b/src/main/resources/reports/invoice_aging/invoice-aging.png differ diff --git a/src/main/resources/reports/invoice_aging/report_invoice_aging.ddl b/src/main/resources/reports/invoice_aging/report_invoice_aging.ddl new file mode 100644 index 00000000..f7fcd599 --- /dev/null +++ b/src/main/resources/reports/invoice_aging/report_invoice_aging.ddl @@ -0,0 +1,19 @@ +create table report_invoice_aging as select * from v_report_invoice_aging limit 0; + +drop procedure if exists refresh_report_invoice_aging; +DELIMITER // +CREATE PROCEDURE refresh_report_invoice_aging() +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_aging; + insert into report_invoice_aging select * from v_report_invoice_aging; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/invoice_aging/v_report_invoice_aging.ddl b/src/main/resources/reports/invoice_aging/v_report_invoice_aging.ddl new file mode 100644 index 00000000..bc81af6e --- /dev/null +++ b/src/main/resources/reports/invoice_aging/v_report_invoice_aging.ddl @@ -0,0 +1,77 @@ +CREATE OR REPLACE VIEW v_report_invoice_aging AS +WITH date_buckets AS ( + SELECT + CURRENT_DATE AS today, + CURRENT_DATE - INTERVAL 30 DAY AS d_0_30, + CURRENT_DATE - INTERVAL 60 DAY AS d_30_60, + CURRENT_DATE - INTERVAL 90 DAY AS d_60_90, + CURRENT_DATE - INTERVAL 120 DAY AS d_90_120, + CURRENT_DATE - INTERVAL 150 DAY AS d_120_150 +), +invoice_data AS ( + SELECT + ii.invoice_number, + ii.account_name, + ii.account_external_key, + CAST(ii.created_date AS DATE) AS invoice_creation_date, + CAST(ii.invoice_date AS DATE) AS invoice_date, + CAST(ii.start_date AS DATE) AS service_start_date, + CAST(ii.end_date AS DATE) AS service_end_date, + ii.bundle_external_key, + ii.product_name, + ii.slug, + ii.currency, + ii.invoice_original_amount_charged, + ii.invoice_balance, + ii.amount, + ii.created_date, + ii.invoice_item_record_id, + ii.tenant_record_id + FROM analytics_invoice_items ii + WHERE ii.invoice_date < CAST(DATE_FORMAT(SYSDATE(), '%Y-%m-01') AS DATE) + AND ii.report_group != 'test' + AND ii.invoice_balance > 0 +) +SELECT + a.account_name AS "Customer Name", + a.account_external_key AS "Account Number", + a.currency AS "Currency", + + -- Balance due buckets + CASE WHEN a.invoice_creation_date > b.d_0_30 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 0-30 Days", + CASE WHEN a.invoice_creation_date BETWEEN b.d_30_60 AND b.d_0_30 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 30-60 Days", + CASE WHEN a.invoice_creation_date BETWEEN b.d_60_90 AND b.d_30_60 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 60-90 Days", + CASE WHEN a.invoice_creation_date BETWEEN b.d_90_120 AND b.d_60_90 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 90-120 Days", + CASE WHEN a.invoice_creation_date BETWEEN b.d_120_150 AND b.d_90_120 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 120-150 Days", + CASE WHEN a.invoice_creation_date < b.d_120_150 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 150+ Days", + + a.invoice_original_amount_charged AS "Total Balance Due", + + -- Balance due in USD + CASE WHEN a.invoice_creation_date > b.d_0_30 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 0-30 Days USD", + CASE WHEN a.invoice_creation_date BETWEEN b.d_30_60 AND b.d_0_30 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 30-60 Days USD", + CASE WHEN a.invoice_creation_date BETWEEN b.d_60_90 AND b.d_30_60 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 60-90 Days USD", + CASE WHEN a.invoice_creation_date BETWEEN b.d_90_120 AND b.d_60_90 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 90-120 Days USD", + CASE WHEN a.invoice_creation_date BETWEEN b.d_120_150 AND b.d_90_120 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 120-150 Days USD", + CASE WHEN a.invoice_creation_date < b.d_120_150 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 150+ Days USD", + + CASE WHEN a.currency != 'USD' THEN cc.reference_rate * a.invoice_original_amount_charged ELSE a.invoice_original_amount_charged END AS "Total Balance Due USD" , + + a.invoice_number AS "Invoice Number", + a.bundle_external_key AS "Bundle External Key", + a.slug AS "Slug", + a.service_start_date AS "Service Start Date", + a.service_end_date AS "Service End Date", + a.invoice_date AS "Invoice Date", + a.invoice_original_amount_charged AS "Invoice Amount", + a.invoice_balance AS "Invoice Balance", + case when a.currency != 'USD' then ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) else a.invoice_original_amount_charged end AS "Invoice Amount USD", + case when a.currency != 'USD' then ROUND(cc.reference_rate * a.invoice_balance, 4) else a.invoice_balance end AS "Invoice Balance USD", + a.tenant_record_id +FROM invoice_data a +LEFT OUTER JOIN analytics_currency_conversion cc + ON a.created_date >= cc.start_date + AND a.created_date <= cc.end_date + AND cc.currency = a.currency +CROSS JOIN date_buckets b +ORDER BY a.account_name, a.invoice_number, a.invoice_item_record_id; \ No newline at end of file diff --git a/src/main/resources/reports/invoice_aging_no_payment/README.md b/src/main/resources/reports/invoice_aging_no_payment/README.md new file mode 100644 index 00000000..76daefd9 --- /dev/null +++ b/src/main/resources/reports/invoice_aging_no_payment/README.md @@ -0,0 +1,31 @@ +# Invoice Aging No Payments Report + +This report lists all customer invoices with no payments recorded, categorizing outstanding amounts into standard aging buckets and converting balances into USD for comparison. + +The snapshot view is: `v_report_invoice_aging_no_payment` + +## Prerequisites + +This report requires the `analytics_currency_conversion` table to be populated. See [insertMonthlyCurrencyConversionRates.ddl](../utils/insertMonthlyCurrencyConversionRates.ddl) + +## Report Creation + +``` +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_invoice_aging_no_payment", + "reportType": "TABLE", + "reportPrettyName": "Invoice Aging No Payments Report", + "sourceTableName": "report_invoice_aging_no_payment", + "refreshProcedureName": "refresh_report_invoice_aging_no_payment", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Report UI: + +![invoice-aging-no-payment.png](invoice-aging-no-payment.png) diff --git a/src/main/resources/reports/invoice_aging_no_payment/invoice-aging-no-payment.png b/src/main/resources/reports/invoice_aging_no_payment/invoice-aging-no-payment.png new file mode 100644 index 00000000..46fb60dd Binary files /dev/null and b/src/main/resources/reports/invoice_aging_no_payment/invoice-aging-no-payment.png differ diff --git a/src/main/resources/reports/invoice_aging_no_payment/report_invoice_aging_no_payment.ddl b/src/main/resources/reports/invoice_aging_no_payment/report_invoice_aging_no_payment.ddl new file mode 100644 index 00000000..cd7baf83 --- /dev/null +++ b/src/main/resources/reports/invoice_aging_no_payment/report_invoice_aging_no_payment.ddl @@ -0,0 +1,19 @@ +create table report_invoice_aging_no_payment as select * from v_report_invoice_aging_no_payment limit 0; + +drop procedure if exists refresh_report_invoice_aging_no_payment; +DELIMITER // +CREATE PROCEDURE refresh_report_invoice_aging_no_payment() +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_aging_no_payment; + insert into report_invoice_aging_no_payment select * from v_report_invoice_aging_no_payment; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/invoice_aging_no_payment/v_report_invoice_aging_no_payment.ddl b/src/main/resources/reports/invoice_aging_no_payment/v_report_invoice_aging_no_payment.ddl new file mode 100644 index 00000000..bf060190 --- /dev/null +++ b/src/main/resources/reports/invoice_aging_no_payment/v_report_invoice_aging_no_payment.ddl @@ -0,0 +1,79 @@ +CREATE OR REPLACE VIEW v_report_invoice_aging_no_payment AS +WITH date_buckets AS ( + SELECT + CURRENT_DATE AS today, + CURRENT_DATE - INTERVAL 30 DAY AS d_0_30, + CURRENT_DATE - INTERVAL 60 DAY AS d_30_60, + CURRENT_DATE - INTERVAL 90 DAY AS d_60_90, + CURRENT_DATE - INTERVAL 120 DAY AS d_90_120, + CURRENT_DATE - INTERVAL 150 DAY AS d_120_150 +), +invoice_data AS ( + SELECT + ii.invoice_number, + ii.account_name, + ii.account_external_key, + CAST(ii.created_date AS DATE) AS invoice_creation_date, + CAST(ii.invoice_date AS DATE) AS invoice_date, + CAST(ii.start_date AS DATE) AS service_start_date, + CAST(ii.end_date AS DATE) AS service_end_date, + ii.bundle_external_key, + ii.product_name, + ii.slug, + ii.currency, + ii.invoice_original_amount_charged, + ii.invoice_balance, + ii.amount, + ii.created_date, + ii.invoice_item_record_id, + ii.tenant_record_id + FROM analytics_invoice_items ii + WHERE ii.invoice_date < CAST(DATE_FORMAT(SYSDATE(), '%Y-%m-01') AS DATE) + AND ii.report_group != 'test' + and ii.amount > 0 + and ii.invoice_amount_paid=0 + and ii.invoice_amount_charged=ii.invoice_original_amount_charged +) +SELECT + a.account_name AS "Customer Name", + a.account_external_key AS "Account Number", + a.currency AS "Currency", + + -- Balance due buckets + CASE WHEN a.invoice_creation_date > b.d_0_30 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 0-30 Days", + CASE WHEN a.invoice_creation_date BETWEEN b.d_30_60 AND b.d_0_30 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 30-60 Days", + CASE WHEN a.invoice_creation_date BETWEEN b.d_60_90 AND b.d_30_60 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 60-90 Days", + CASE WHEN a.invoice_creation_date BETWEEN b.d_90_120 AND b.d_60_90 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 90-120 Days", + CASE WHEN a.invoice_creation_date BETWEEN b.d_120_150 AND b.d_90_120 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 120-150 Days", + CASE WHEN a.invoice_creation_date < b.d_120_150 THEN a.invoice_original_amount_charged ELSE 0 END AS "Balance due 150+ Days", + + a.invoice_original_amount_charged AS "Total Balance Due", + + -- Balance due in USD + CASE WHEN a.invoice_creation_date > b.d_0_30 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 0-30 Days USD", + CASE WHEN a.invoice_creation_date BETWEEN b.d_30_60 AND b.d_0_30 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 30-60 Days USD", + CASE WHEN a.invoice_creation_date BETWEEN b.d_60_90 AND b.d_30_60 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 60-90 Days USD", + CASE WHEN a.invoice_creation_date BETWEEN b.d_90_120 AND b.d_60_90 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 90-120 Days USD", + CASE WHEN a.invoice_creation_date BETWEEN b.d_120_150 AND b.d_90_120 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 120-150 Days USD", + CASE WHEN a.invoice_creation_date < b.d_120_150 THEN CASE WHEN a.currency != 'USD' THEN ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) ELSE a.invoice_original_amount_charged END ELSE 0 END AS "Balance due 150+ Days USD", + + CASE WHEN a.currency != 'USD' THEN cc.reference_rate * a.invoice_original_amount_charged ELSE a.invoice_original_amount_charged END AS "Total Balance Due USD" , + + a.invoice_number AS "Invoice Number", + a.bundle_external_key AS "Bundle External Key", + a.slug AS "Slug", + a.service_start_date AS "Service Start Date", + a.service_end_date AS "Service End Date", + a.invoice_date AS "Invoice Date", + a.invoice_original_amount_charged AS "Invoice Amount", + a.invoice_balance AS "Invoice Balance", + case when a.currency != 'USD' then ROUND(cc.reference_rate * a.invoice_original_amount_charged, 4) else a.invoice_original_amount_charged end AS "Invoice Amount USD", + case when a.currency != 'USD' then ROUND(cc.reference_rate * a.invoice_balance, 4) else a.invoice_balance end AS "Invoice Balance USD", + a.tenant_record_id +FROM invoice_data a +LEFT OUTER JOIN analytics_currency_conversion cc + ON a.created_date >= cc.start_date + AND a.created_date <= cc.end_date + AND cc.currency = a.currency +CROSS JOIN date_buckets b +ORDER BY a.account_name, a.invoice_number, a.invoice_item_record_id; \ No newline at end of file diff --git a/src/main/resources/reports/invoice_credits_monthly/README.md b/src/main/resources/reports/invoice_credits_monthly/README.md new file mode 100644 index 00000000..d888b94e --- /dev/null +++ b/src/main/resources/reports/invoice_credits_monthly/README.md @@ -0,0 +1,31 @@ +# Invoice Credits Monthly Report + +Report of all invoice credits from the previous month, showing amounts in both original currency and USD equivalents. + +The snapshot view is: `v_report_invoice_credits_monthly` + +## Prerequisites + +This report requires the `analytics_currency_conversion` table to be populated. See [insertMonthlyCurrencyConversionRates.ddl](../utils/insertMonthlyCurrencyConversionRates.ddl) + +## Report Creation + +``` +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_invoice_credits_monthly", + "reportType": "TABLE", + "reportPrettyName": "Invoice Credits Monthly Report", + "sourceTableName": "report_invoice_credits_monthly", + "refreshProcedureName": "refresh_report_invoice_credits_monthly", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Report UI: + +![invoice-credits-monthly.png](invoice-credits-monthly.png) diff --git a/src/main/resources/reports/invoice_credits_monthly/invoice-credits-monthly.png b/src/main/resources/reports/invoice_credits_monthly/invoice-credits-monthly.png new file mode 100644 index 00000000..b5ae99cb Binary files /dev/null and b/src/main/resources/reports/invoice_credits_monthly/invoice-credits-monthly.png differ diff --git a/src/main/resources/reports/invoice_credits_monthly/report_invoice_credits_monthly.ddl b/src/main/resources/reports/invoice_credits_monthly/report_invoice_credits_monthly.ddl new file mode 100644 index 00000000..a4368082 --- /dev/null +++ b/src/main/resources/reports/invoice_credits_monthly/report_invoice_credits_monthly.ddl @@ -0,0 +1,19 @@ +create table report_invoice_credits_monthly as select * from v_report_invoice_credits_monthly limit 0; + +drop procedure if exists refresh_report_invoice_credits_monthly; +DELIMITER // +CREATE PROCEDURE refresh_report_invoice_credits_monthly() +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_monthly; + insert into report_invoice_credits_monthly select * from v_report_invoice_credits_monthly; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/extracts/finance/invoice_credits_monthly.sql b/src/main/resources/reports/invoice_credits_monthly/v_report_invoice_credits_monthly.ddl similarity index 57% rename from src/main/resources/extracts/finance/invoice_credits_monthly.sql rename to src/main/resources/reports/invoice_credits_monthly/v_report_invoice_credits_monthly.ddl index 67a931b1..09829c9d 100644 --- a/src/main/resources/extracts/finance/invoice_credits_monthly.sql +++ b/src/main/resources/reports/invoice_credits_monthly/v_report_invoice_credits_monthly.ddl @@ -1,3 +1,4 @@ +CREATE OR REPLACE VIEW v_report_invoice_credits_monthly AS select ic.invoice_number as "Invoice Number" , ic.account_name as "Customer Name" @@ -14,16 +15,17 @@ select , ic.invoice_original_amount_charged as "Invoice Amount" , ic.invoice_balance as "Invoice Balance" , ic.amount as "Invoice Credit Amount" -, round(cc.reference_rate * ic.invoice_original_amount_charged,4) as "Invoice Amount USD" -, round(cc.reference_rate * ic.invoice_balance,4) as "Invoice Balance USD" -, round(cc.reference_rate * ic.amount,4) as "Invoice Credit Amount USD" +, case when ic.currency != 'USD' THEN round(cc.reference_rate * ic.invoice_original_amount_charged,4) else invoice_original_amount_charged end as "Invoice Amount USD" +, case when ic.currency != 'USD' THEN round(cc.reference_rate * ic.invoice_balance,4) else invoice_balance end as "Invoice Balance USD" +, case when ic.currency != 'USD' THEN round(cc.reference_rate * ic.amount,4) else amount end as "Invoice Credit Amount USD" +, ic.tenant_record_id from analytics_invoice_credits ic - join analytics_currency_conversion cc on ic.created_date >= cc.start_date and ic.created_date <= cc.end_date and cc.currency =ic.currency + left outer join analytics_currency_conversion cc on ic.created_date >= cc.start_date and ic.created_date <= cc.end_date and cc.currency =ic.currency where 1=1 and ic.created_date >= cast(date_format(date_sub(sysdate(), interval '1' month), '%Y-%m-01') as date) and ic.created_date < cast(date_format(sysdate(), '%Y-%m-01') as date) and ic.report_group != 'test' order by invoice_number -, ic.invoice_item_record_id; -- just for well defined ordering +, ic.invoice_item_record_id; -- just for well defined ordering \ No newline at end of file diff --git a/src/main/resources/reports/invoice_item_adjustments_monthly/README.md b/src/main/resources/reports/invoice_item_adjustments_monthly/README.md new file mode 100644 index 00000000..62f06eab --- /dev/null +++ b/src/main/resources/reports/invoice_item_adjustments_monthly/README.md @@ -0,0 +1,31 @@ +# Invoice Items Adjustments Monthly Report + +Report of all invoice item adjustments from the previous month, showing amounts in both original currency and USD equivalents. + +The snapshot view is: `v_report_invoice_item_adjustments_monthly` + +## Prerequisites + +This report requires the `analytics_currency_conversion` table to be populated. See [insertMonthlyCurrencyConversionRates.ddl](../utils/insertMonthlyCurrencyConversionRates.ddl) + +## Report Creation + +``` +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_invoice_item_adjustments_monthly", + "reportType": "TABLE", + "reportPrettyName": "Invoice Item Adjustments Monthly Report", + "sourceTableName": "report_invoice_item_adjustments_monthly", + "refreshProcedureName": "refresh_report_invoice_item_adjustments_monthly", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Report UI: + +![invoice-item-adjustments-monthly.png.png](invoice-item-adjustments-monthly.png.png) diff --git a/src/main/resources/reports/invoice_item_adjustments_monthly/invoice-item-adjustments-monthly.png b/src/main/resources/reports/invoice_item_adjustments_monthly/invoice-item-adjustments-monthly.png new file mode 100644 index 00000000..9fe7b5a2 Binary files /dev/null and b/src/main/resources/reports/invoice_item_adjustments_monthly/invoice-item-adjustments-monthly.png differ diff --git a/src/main/resources/reports/invoice_item_adjustments_monthly/report_invoice_item_adjustments_monthly.ddl b/src/main/resources/reports/invoice_item_adjustments_monthly/report_invoice_item_adjustments_monthly.ddl new file mode 100644 index 00000000..809fdbd4 --- /dev/null +++ b/src/main/resources/reports/invoice_item_adjustments_monthly/report_invoice_item_adjustments_monthly.ddl @@ -0,0 +1,19 @@ +create table report_invoice_item_adjustments_monthly as select * from v_report_invoice_item_adjustments_monthly limit 0; + +drop procedure if exists refresh_report_invoice_item_adjustments_monthly; +DELIMITER // +CREATE PROCEDURE refresh_report_invoice_item_adjustments_monthly() +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_monthly; + insert into report_invoice_item_adjustments_monthly select * from v_report_invoice_item_adjustments_monthly; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/extracts/finance/invoice_item_adjustments_monthly.sql b/src/main/resources/reports/invoice_item_adjustments_monthly/v_report_invoice_item_adjustments_monthly.ddl similarity index 51% rename from src/main/resources/extracts/finance/invoice_item_adjustments_monthly.sql rename to src/main/resources/reports/invoice_item_adjustments_monthly/v_report_invoice_item_adjustments_monthly.ddl index 9b51848b..261c37c6 100644 --- a/src/main/resources/extracts/finance/invoice_item_adjustments_monthly.sql +++ b/src/main/resources/reports/invoice_item_adjustments_monthly/v_report_invoice_item_adjustments_monthly.ddl @@ -1,3 +1,4 @@ +CREATE OR REPLACE VIEW v_report_invoice_item_adjustments_monthly AS select iia.invoice_number as "Invoice Number" , iia.account_name as "Customer Name" @@ -8,27 +9,26 @@ select , iia.bundle_external_key as "Bundle External Key" , iia.product_name as "Product" , iia.slug as "Slug" - -- , date_format(iia.start_date, '%m/%d/%Y') as "Service Start Date" - -- , date_format(iia.end_date, '%m/%d/%Y') as "Service End Date" -, date_format(ii.start_date, '%m/%d/%Y') as "Service Start Date" -, date_format(ii.end_date, '%m/%d/%Y') as "Service End Date" +, date_format(iia.start_date, '%m/%d/%Y') as "Service Start Date" +, date_format(iia.end_date, '%m/%d/%Y') as "Service End Date" , iia.currency as "Currency" , iia.invoice_original_amount_charged as "Invoice Amount" , iia.invoice_balance as "Invoice Balance" , iia.amount as "Invoice Item Adjustment Amount" , abs(iia.amount) as "Impact Amount" -, round(cc.reference_rate * iia.invoice_original_amount_charged,4) as "Invoice Amount USD" -, round(cc.reference_rate * iia.invoice_balance,4) as "Invoice Balance USD" -, round(cc.reference_rate * iia.amount,4) as "Invoice Item Adjustment Amount USD" -, abs(round(cc.reference_rate * iia.amount,4)) as "Impact Amount USD" +, case when iia.currency != 'USD' then round(cc.reference_rate * iia.invoice_original_amount_charged,4) else iia.invoice_original_amount_charged END as "Invoice Amount USD" +, case when iia.currency != 'USD' then round(cc.reference_rate * iia.invoice_balance,4) else iia.invoice_balance end as "Invoice Balance USD" +, case when iia.currency != 'USD' then round(cc.reference_rate * iia.amount,4) else iia.amount end as "Invoice Item Adjustment Amount USD" +, case when iia.currency != 'USD' then abs(round(cc.reference_rate * iia.amount,4)) else abs(iia.amount) end as "Impact Amount USD" , case when iia.amount < 0 then 'CREDIT' else 'CHARGE' end as "Adjustment Type" , 'PROCESSED' as "Invoice Item Adjustment Status" +, iia.tenant_record_id from analytics_invoice_item_adjustments iia join analytics_invoice_items ii on iia.linked_item_id = ii.item_id -- workaround - join analytics_currency_conversion cc on iia.created_date >= cc.start_date and iia.created_date <= cc.end_date and cc.currency = iia.currency + left outer join analytics_currency_conversion cc on iia.created_date >= cc.start_date and iia.created_date <= cc.end_date and cc.currency = iia.currency where 1=1 - and iia.created_date >= cast(date_format(date_sub(sysdate() - interval '1' month), '%Y-%m-01') as date) + and iia.created_date >= cast(date_format(date_sub(sysdate(), interval '1' month), '%Y-%m-01') as date) and iia.created_date < cast(date_format(sysdate(), '%Y-%m-01') as date) and iia.report_group != 'test' order by diff --git a/src/main/resources/reports/invoice_items_monthly/README.md b/src/main/resources/reports/invoice_items_monthly/README.md new file mode 100644 index 00000000..52c715d5 --- /dev/null +++ b/src/main/resources/reports/invoice_items_monthly/README.md @@ -0,0 +1,31 @@ +# Invoice Items Monthly Report + +Report of all invoice items from the previous month, showing amounts in both original currency and USD equivalents. + +The snapshot view is: `v_report_invoice_items_monthly` + +## Prerequisites + +This report requires the `analytics_currency_conversion` table to be populated. See [insertMonthlyCurrencyConversionRates.ddl](../utils/insertMonthlyCurrencyConversionRates.ddl) + +## Report Creation + +``` +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_invoice_items_monthly", + "reportType": "TABLE", + "reportPrettyName": "Invoice Items Monthly Report", + "sourceTableName": "report_invoice_items_monthly", + "refreshProcedureName": "refresh_report_invoice_items_monthly", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Report UI: + +![invoice-items-monthly.png](invoice-items-monthly.png) diff --git a/src/main/resources/reports/invoice_items_monthly/invoice-items-monthly.png b/src/main/resources/reports/invoice_items_monthly/invoice-items-monthly.png new file mode 100644 index 00000000..2fa3658c Binary files /dev/null and b/src/main/resources/reports/invoice_items_monthly/invoice-items-monthly.png differ diff --git a/src/main/resources/reports/invoice_items_monthly/report_invoice_items_monthly.ddl b/src/main/resources/reports/invoice_items_monthly/report_invoice_items_monthly.ddl new file mode 100644 index 00000000..f323080c --- /dev/null +++ b/src/main/resources/reports/invoice_items_monthly/report_invoice_items_monthly.ddl @@ -0,0 +1,19 @@ +create table report_invoice_items_monthly as select * from v_report_invoice_items_monthly limit 0; + +drop procedure if exists refresh_report_invoice_items_monthly; +DELIMITER // +CREATE PROCEDURE refresh_report_invoice_items_monthly() +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_items_monthly; + insert into report_invoice_items_monthly select * from v_report_invoice_items_monthly; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/extracts/finance/invoice_items_monthly.sql b/src/main/resources/reports/invoice_items_monthly/v_report_invoice_items_monthly.ddl similarity index 57% rename from src/main/resources/extracts/finance/invoice_items_monthly.sql rename to src/main/resources/reports/invoice_items_monthly/v_report_invoice_items_monthly.ddl index 62c7394b..a0744f49 100644 --- a/src/main/resources/extracts/finance/invoice_items_monthly.sql +++ b/src/main/resources/reports/invoice_items_monthly/v_report_invoice_items_monthly.ddl @@ -1,3 +1,4 @@ +CREATE OR REPLACE VIEW v_report_invoice_items_monthly AS select ii.invoice_number as "Invoice Number" , ii.account_name as "Customer Name" @@ -14,16 +15,17 @@ select , ii.invoice_original_amount_charged as "Invoice Amount" , ii.invoice_balance as "Invoice Balance" , ii.amount as "Invoice Item Amount" -, round(cc.reference_rate * ii.invoice_original_amount_charged,4) as "Invoice Amount USD" -, round(cc.reference_rate * ii.invoice_balance,4) as "Invoice Balance USD" -, round(cc.reference_rate * ii.amount,4) as "Invoice Item Amount USD" +, case when ii.currency != 'USD' THEN round(cc.reference_rate * ii.invoice_original_amount_charged,4) else ii.invoice_original_amount_charged END as "Invoice Amount USD" +, case when ii.currency != 'USD' THEN round(cc.reference_rate * ii.invoice_balance,4) else ii.invoice_balance END as "Invoice Balance USD" +, case when ii.currency != 'USD' THEN round(cc.reference_rate * ii.amount,4) else ii.amount END as "Invoice Item Amount USD" +, ii.tenant_record_id from analytics_invoice_items ii - join analytics_currency_conversion cc on ii.created_date >= cc.start_date and ii.created_date <= cc.end_date and cc.currency = ii.currency + left outer join analytics_currency_conversion cc on ii.created_date >= cc.start_date and ii.created_date <= cc.end_date and cc.currency = ii.currency where 1=1 and ii.invoice_date >= cast(date_format(sysdate() - interval '1' month, '%Y-%m-01') as date) and ii.invoice_date < cast(date_format(sysdate(), '%Y-%m-01') as date) and ii.report_group != 'test' order by invoice_number -, ii.invoice_item_record_id; -- just for well defined ordering +, ii.invoice_item_record_id; -- just for well defined ordering \ No newline at end of file diff --git a/src/main/resources/reports/invoices_monthly/README.md b/src/main/resources/reports/invoices_monthly/README.md new file mode 100644 index 00000000..a6199c39 --- /dev/null +++ b/src/main/resources/reports/invoices_monthly/README.md @@ -0,0 +1,31 @@ +# Invoice Monthly Report + +Report of all invoices from the previous month, showing amounts in both original currency and USD equivalents. + +The snapshot view is: `v_report_invoices_monthly` + +## Prerequisites + +This report requires the `analytics_currency_conversion` table to be populated. See [insertMonthlyCurrencyConversionRates.ddl](../utils/insertMonthlyCurrencyConversionRates.ddl) + +## Report Creation + +``` +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_invoices_monthly", + "reportType": "TABLE", + "reportPrettyName": "Invoices Monthly Report", + "sourceTableName": "report_invoices_monthly", + "refreshProcedureName": "refresh_report_invoices_monthly", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Report UI: + +![invoices-monthly.png](invoices-monthly.png) diff --git a/src/main/resources/reports/invoices_monthly/invoices-monthly.png b/src/main/resources/reports/invoices_monthly/invoices-monthly.png new file mode 100644 index 00000000..b2f58c3d Binary files /dev/null and b/src/main/resources/reports/invoices_monthly/invoices-monthly.png differ diff --git a/src/main/resources/reports/invoices_monthly/report_invoices_monthly.ddl b/src/main/resources/reports/invoices_monthly/report_invoices_monthly.ddl new file mode 100644 index 00000000..11bc733a --- /dev/null +++ b/src/main/resources/reports/invoices_monthly/report_invoices_monthly.ddl @@ -0,0 +1,19 @@ +create table report_invoices_monthly as select * from v_report_invoices_monthly limit 0; + +drop procedure if exists refresh_report_invoices_monthly; +DELIMITER // +CREATE PROCEDURE refresh_report_invoices_monthly() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +START TRANSACTION; + delete from report_invoices_monthly; + insert into report_invoices_monthly select * from v_report_invoices_monthly; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/extracts/finance/invoices_monthly.sql b/src/main/resources/reports/invoices_monthly/v_report_invoices_monthly.ddl similarity index 55% rename from src/main/resources/extracts/finance/invoices_monthly.sql rename to src/main/resources/reports/invoices_monthly/v_report_invoices_monthly.ddl index be5d31ab..25e17186 100644 --- a/src/main/resources/extracts/finance/invoices_monthly.sql +++ b/src/main/resources/reports/invoices_monthly/v_report_invoices_monthly.ddl @@ -1,3 +1,4 @@ +CREATE OR REPLACE VIEW v_report_invoices_monthly AS select inv.invoice_number as "Invoice Number" , inv.account_name as "Customer Name" @@ -8,15 +9,16 @@ select , inv.currency as "Currency" , inv.original_amount_charged as "Invoice Amount" , inv.balance as "Invoice Balance" -, round(cc.reference_rate * inv.original_amount_charged,4) as "Invoice Amount USD" -, round(cc.reference_rate * inv.balance,4) as "Invoice Balance USD" +, case when inv.currency != 'USD' THEN round(cc.reference_rate * inv.original_amount_charged,4) else inv.original_amount_charged END as "Invoice Amount USD" +, case when inv.currency != 'USD' THEN round(cc.reference_rate * inv.balance,4) else inv.balance END as "Invoice Balance USD" +, inv.tenant_record_id from analytics_invoices inv - join analytics_currency_conversion cc on inv.created_date >= cc.start_date and inv.created_date <= cc.end_date and cc.currency = inv.currency + left outer join analytics_currency_conversion cc on inv.created_date >= cc.start_date and inv.created_date <= cc.end_date and cc.currency = inv.currency where 1=1 and inv.invoice_date >= cast(date_format(date_sub(sysdate(), interval '1' month), '%Y-%m-01') as date) and inv.invoice_date < cast(date_format(sysdate(), '%Y-%m-01') as date) and inv.report_group != 'test' order by invoice_number -, inv.invoice_record_id; -- just for well defined ordering +, inv.invoice_record_id; -- just for well defined ordering \ No newline at end of file diff --git a/src/main/resources/reports/payments_monthly/README.md b/src/main/resources/reports/payments_monthly/README.md new file mode 100644 index 00000000..2b44f716 --- /dev/null +++ b/src/main/resources/reports/payments_monthly/README.md @@ -0,0 +1,31 @@ +# Payments Monthly Report + +Report of all payments from the previous month, showing amounts in both original currency and USD equivalents. + +The snapshot view is: `v_report_payments_monthly` + +## Prerequisites + +This report requires the `analytics_currency_conversion` table to be populated. See [insertMonthlyCurrencyConversionRates.ddl](../utils/insertMonthlyCurrencyConversionRates.ddl) + +## Report Creation + +``` +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_payments_monthly", + "reportType": "TABLE", + "reportPrettyName": "Payments Monthly Report", + "sourceTableName": "report_payments_monthly", + "refreshProcedureName": "refresh_report_payments_monthly", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Report UI: + +![payments-monthly.png](payments-monthly.png) diff --git a/src/main/resources/reports/payments_monthly/payments-monthly.png b/src/main/resources/reports/payments_monthly/payments-monthly.png new file mode 100644 index 00000000..3e8fe6af Binary files /dev/null and b/src/main/resources/reports/payments_monthly/payments-monthly.png differ diff --git a/src/main/resources/reports/payments_monthly/report_payments_monthly.ddl b/src/main/resources/reports/payments_monthly/report_payments_monthly.ddl new file mode 100644 index 00000000..b0e39bb6 --- /dev/null +++ b/src/main/resources/reports/payments_monthly/report_payments_monthly.ddl @@ -0,0 +1,19 @@ +create table report_payments_monthly as select * from v_report_payments_monthly limit 0; + +drop procedure if exists refresh_report_payments_monthly; +DELIMITER // +CREATE PROCEDURE refresh_report_payments_monthly() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +START TRANSACTION; + delete from report_payments_monthly; + insert into report_payments_monthly select * from v_report_payments_monthly; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/extracts/finance/payments_monthly.sql b/src/main/resources/reports/payments_monthly/v_report_payments_monthly.ddl similarity index 74% rename from src/main/resources/extracts/finance/payments_monthly.sql rename to src/main/resources/reports/payments_monthly/v_report_payments_monthly.ddl index 7fe66f3a..1540a722 100644 --- a/src/main/resources/extracts/finance/payments_monthly.sql +++ b/src/main/resources/reports/payments_monthly/v_report_payments_monthly.ddl @@ -1,3 +1,4 @@ +CREATE OR REPLACE VIEW v_report_payments_monthly AS select pmt.account_name as "Customer Name" , pmt.account_external_key as "Account Number" @@ -5,7 +6,7 @@ select , date_format(pmt.invoice_date, '%m/%d/%Y') as "Invoice Date" , pmt.currency as "Currency" , pmt.invoice_original_amount_charged as "Invoice Amount" -, round(cc.reference_rate * pmt.invoice_original_amount_charged,4) as "Invoice Amount USD" +, case when pmt.currency != 'USD' THEN round(cc.reference_rate * pmt.invoice_original_amount_charged,4) else pmt.invoice_original_amount_charged end as "Invoice Amount USD" , pmt.plugin_name as "Payment Gateway" , pmt.plugin_pm_type as "Payment Method" , pmt.plugin_pm_cc_type as "Payment Card Type" @@ -16,18 +17,16 @@ select , date_format(pmt.created_date, '%m/%d/%Y') as "Payment Date" , pmt.currency as "Payment Currency" , pmt.amount as "Payment Amount" -, round(cc.reference_rate * pmt.amount,4) as "Payment Amount USD" +, case when pmt.currency != 'USD' then round(cc.reference_rate * pmt.amount,4) else pmt.amount end as "Payment Amount USD" , pmt.payment_id +, pmt.tenant_record_id from analytics_payment_purchases pmt - join analytics_currency_conversion cc on pmt.created_date >= cc.start_date and pmt.created_date <= cc.end_date and cc.currency = pmt.currency + left outer join analytics_currency_conversion cc on pmt.created_date >= cc.start_date and pmt.created_date <= cc.end_date and cc.currency = pmt.currency where 1=1 and pmt.created_date >= cast(date_format(date_sub(sysdate(), interval '1' month), '%Y-%m-01') as date) and pmt.created_date < cast(date_format(sysdate(), '%Y-%m-01') as date) and pmt.report_group != 'test' order by account_name -, pmt.invoice_payment_record_id; -- just for well defined ordering - - - +, pmt.invoice_payment_record_id; -- just for well defined ordering \ No newline at end of file diff --git a/src/main/resources/reports/refunds-monthly/README.md b/src/main/resources/reports/refunds-monthly/README.md new file mode 100644 index 00000000..40b5fd51 --- /dev/null +++ b/src/main/resources/reports/refunds-monthly/README.md @@ -0,0 +1,31 @@ +# Refunds Monthly Report + +Report of all refunds from the previous month, showing amounts in both original currency and USD equivalents. + +The snapshot view is: `v_report_refunds_monthly` + +## Prerequisites + +This report requires the `analytics_currency_conversion` table to be populated. See [insertMonthlyCurrencyConversionRates.ddl](../utils/insertMonthlyCurrencyConversionRates.ddl) + +## Report Creation + +``` +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_refunds_monthly", + "reportType": "TABLE", + "reportPrettyName": "Refunds Monthly Report", + "sourceTableName": "report_refunds_monthly", + "refreshProcedureName": "refresh_report_refunds_monthly", + "refreshFrequency": "DAILY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Report UI: + +![refunds-monthly.png](refunds-monthly.png) diff --git a/src/main/resources/reports/refunds-monthly/refunds-monthly.png b/src/main/resources/reports/refunds-monthly/refunds-monthly.png new file mode 100644 index 00000000..65674b2b Binary files /dev/null and b/src/main/resources/reports/refunds-monthly/refunds-monthly.png differ diff --git a/src/main/resources/reports/refunds-monthly/report_refunds_monthly.ddl b/src/main/resources/reports/refunds-monthly/report_refunds_monthly.ddl new file mode 100644 index 00000000..6010ccb0 --- /dev/null +++ b/src/main/resources/reports/refunds-monthly/report_refunds_monthly.ddl @@ -0,0 +1,19 @@ +create table report_refunds_monthly as select * from v_report_refunds_monthly limit 0; + +drop procedure if exists refresh_report_refunds_monthly; +DELIMITER // +CREATE PROCEDURE refresh_report_refunds_monthly() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +START TRANSACTION; + delete from report_refunds_monthly; + insert into report_refunds_monthly select * from v_report_refunds_monthly; +COMMIT; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/refunds-monthly/v_report_refunds_monthly.ddl b/src/main/resources/reports/refunds-monthly/v_report_refunds_monthly.ddl new file mode 100644 index 00000000..90d7bdf7 --- /dev/null +++ b/src/main/resources/reports/refunds-monthly/v_report_refunds_monthly.ddl @@ -0,0 +1,34 @@ +CREATE OR REPLACE VIEW v_report_refunds_monthly AS +select + rfnd.account_name as "Customer Name" +, rfnd.account_external_key as "Account Number" +, rfnd.invoice_number as "Invoice Number" +, date_format(rfnd.invoice_date, '%m/%d/%Y') as "Invoice Date" +, rfnd.currency as "Currency" +, rfnd.invoice_original_amount_charged as "Invoice Amount" +, case when rfnd.currency != 'USD' then round(cc.reference_rate * rfnd.invoice_original_amount_charged,4) else rfnd.invoice_original_amount_charged end as "Invoice Amount USD" +, rfnd.plugin_name as "Payment Type" +, rfnd.plugin_pm_type as "Payment Method" +, rfnd.plugin_pm_cc_type as "Payment Card Type" +, date_format(rfnd.created_date, '%m/%d/%Y') as "Payment Date" +, rfnd.currency as "Payment Currency" +, rfnd.amount as "Payment Amount" +, case when rfnd.currency != 'USD' then round(cc.reference_rate * rfnd.amount,4) else rfnd.amount end as "Payment Amount USD" +, rfnd.record_id as "Refund Number" +, date_format(rfnd.created_date, '%m/%d/%Y') as "Refund Date" +, rfnd.currency as "Refund Currency" +, rfnd.amount as "Refund Amount" +, case when rfnd.currency != 'USD' then round(cc.reference_rate * rfnd.amount,4) else rfnd.amount end as "Refund Amount USD" +, rfnd.invoice_amount_charged - rfnd.invoice_original_amount_charged "Total IA, IIA for Invoice" +, case when rfnd.currency != 'USD' then round(cc.reference_rate * (rfnd.invoice_amount_charged - rfnd.invoice_original_amount_charged),4) else rfnd.invoice_amount_charged - rfnd.invoice_original_amount_charged end "Total IA, IIA for Invoice USD" +, rfnd.created_by as "User Responsible for Refund" +, 'REASON' as "Reason for Refund" +, rfnd.tenant_record_id +from + analytics_payment_refunds rfnd + left outer join analytics_currency_conversion cc on rfnd.created_date >= cc.start_date and rfnd.created_date <= cc.end_date and cc.currency = rfnd.currency +where 1=1 + and rfnd.created_date >= cast(date_format(date_sub(sysdate(), interval '1' month), '%Y-%m-01') as date) + and rfnd.created_date < cast(date_format(sysdate(), '%Y-%m-01') as date) + and rfnd.report_group != 'test' +order by 1,rfnd.invoice_payment_record_id; -- just for well defined ordering \ No newline at end of file diff --git a/src/main/resources/reports/utils/README.md b/src/main/resources/reports/utils/README.md new file mode 100644 index 00000000..b726c0da --- /dev/null +++ b/src/main/resources/reports/utils/README.md @@ -0,0 +1,72 @@ +# Insert Monthly Currency Conversion Rates + +This procedure inserts the monthly currency conversion rates (AUD, BRL, EUR, GBP, MXN → USD) into the `analytics_currency_conversion` table. +It validates the input month/year, checks for duplicate or missing previous entries, ensures rates don’t deviate beyond a threshold, updates prior rows, and inserts the new month’s rates. + +## Initialization + +Before executing the procedure, the following initialization script needs to be run: + +```` +insert into analytics_currency_conversion values (1, 'AUD', date_sub(str_to_date(concat(cast(year(now()) as char(4)),'-',cast(month(now()) as char(2)),'-01'),'%Y-%m-%d'), interval 1 month), '2020-01-01', 0.77, 'USD'); +insert into analytics_currency_conversion values (2, 'BRL', date_sub(str_to_date(concat(cast(year(now()) as char(4)),'-',cast(month(now()) as char(2)),'-01'),'%Y-%m-%d'), interval 1 month), '2020-01-01', 0.31, 'USD'); +insert into analytics_currency_conversion values (3, 'EUR', date_sub(str_to_date(concat(cast(year(now()) as char(4)),'-',cast(month(now()) as char(2)),'-01'),'%Y-%m-%d'), interval 1 month), '2020-01-01', 1.12, 'USD'); +insert into analytics_currency_conversion values (4, 'GBP', date_sub(str_to_date(concat(cast(year(now()) as char(4)),'-',cast(month(now()) as char(2)),'-01'),'%Y-%m-%d'), interval 1 month), '2020-01-01', 1.29, 'USD'); +insert into analytics_currency_conversion values (5, 'MXN', date_sub(str_to_date(concat(cast(year(now()) as char(4)),'-',cast(month(now()) as char(2)),'-01'),'%Y-%m-%d'), interval 1 month), '2020-01-01', 0.052, 'USD'); +```` + +## Executing The Procedure + +The stored procedure can be executed as follows: + +```` +CALL updateAnalyticsCurrConvMonth( + 9, -- month = September + 2025, -- year + 0.78, -- AUD + 0.30, -- BRL + 1.13, -- EUR + 1.28, -- GBP + 0.051 -- MXN +); +```` + +## How it works + +- The procedure verifies that the previous month has entries for all five currencies. +- It ensures the current month’s entries don’t already exist. +- Rates are validated to be positive and within a 10% deviation from the previous month. +- The end_date of previous month entries is updated to the start of the new month. +- New records are inserted for the current month with `end_date = 2020-01-01`. + +Here is an example. + +Suppose the `analytics_currency_conversion` table has the conversion rates for August 2025: + +| Currency | Start Date | End Date | Reference Rate | Reference Currency | +|----------|------------|------------|----------------|--------------------| +| AUD | 2025-08-01 | 2020-01-01 | 0.77 | USD | +| BRL | 2025-08-01 | 2020-01-01 | 0.31 | USD | +| EUR | 2025-08-01 | 2020-01-01 | 1.12 | USD | +| GBP | 2025-08-01 | 2020-01-01 | 1.29 | USD | +| MXN | 2025-08-01 | 2020-01-01 | 0.052 | USD | +Notice how all `end_date = 2020-01-01`. +This is a placeholder meaning “open-ended” (valid until a new record replaces it). + +2. After calling the procedure for September 2025 as mentioned above, the table now looks as follows: + +```` +| Currency | Start Date | End Date | Reference Rate | Reference Currency | +|----------|------------|------------|----------------|--------------------| +| AUD | 2025-08-01 | 2025-09-01 | 0.77 | USD | +| BRL | 2025-08-01 | 2025-09-01 | 0.31 | USD | +| EUR | 2025-08-01 | 2025-09-01 | 1.12 | USD | +| GBP | 2025-08-01 | 2025-09-01 | 1.29 | USD | +| MXN | 2025-08-01 | 2025-09-01 | 0.052 | USD | +| AUD | 2025-09-01 | 2020-01-01 | 0.78 | USD | +| BRL | 2025-09-01 | 2020-01-01 | 0.30 | USD | +| EUR | 2025-09-01 | 2020-01-01 | 1.13 | USD | +| GBP | 2025-09-01 | 2020-01-01 | 1.28 | USD | +| MXN | 2025-09-01 | 2020-01-01 | 0.051 | USD | +```` + diff --git a/src/main/resources/utils/updateAnalyticsCurrConvMonth.prc b/src/main/resources/reports/utils/insertMonthlyCurrencyConversionRates.ddl similarity index 96% rename from src/main/resources/utils/updateAnalyticsCurrConvMonth.prc rename to src/main/resources/reports/utils/insertMonthlyCurrencyConversionRates.ddl index 5b731ee7..7cbaeb37 100644 --- a/src/main/resources/utils/updateAnalyticsCurrConvMonth.prc +++ b/src/main/resources/reports/utils/insertMonthlyCurrencyConversionRates.ddl @@ -94,19 +94,19 @@ BEGIN SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Not Allowed: New AUD rate differs from previous rate by more than allowed threshhold'; - elseif abs(v_old_brl_rate-p_brl_rate)/v_old_aud_rate >v_conv_rate_test_threshhold then + elseif abs(v_old_brl_rate-p_brl_rate)/v_old_brl_rate >v_conv_rate_test_threshhold then SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Not Allowed: New BRL rate differs from previous rate by more than allowed threshhold'; - elseif abs(v_old_eur_rate-p_eur_rate)/v_old_aud_rate >v_conv_rate_test_threshhold then + elseif abs(v_old_eur_rate-p_eur_rate)/v_old_eur_rate >v_conv_rate_test_threshhold then SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Not Allowed: New EUR rate differs from previous rate by more than allowed threshhold'; - elseif abs(v_old_gbp_rate-p_gbp_rate)/v_old_aud_rate >v_conv_rate_test_threshhold then + elseif abs(v_old_gbp_rate-p_gbp_rate)/v_old_gbp_rate >v_conv_rate_test_threshhold then SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Not Allowed: New GBP rate differs from previous rate by more than allowed threshhold'; - elseif abs(v_old_mxn_rate-p_mxn_rate)/v_old_aud_rate >v_conv_rate_test_threshhold then + elseif abs(v_old_mxn_rate-p_mxn_rate)/v_old_mxn_rate >v_conv_rate_test_threshhold then SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Not Allowed: New MXN rate differs from previous rate by more than allowed threshhold'; end if;