diff --git a/reports/README.md b/reports/README.md index 19f8c2b7..33e465c8 100644 --- a/reports/README.md +++ b/reports/README.md @@ -1,46 +1,41 @@ -# KillBill Analytics Reports Setup Script +# Kill Bill Reports Overview -This script installs all necessary database DDLs and creates KillBill analytics reports for your KillBill environment. +This document provides details about the built-in reports provided by the analytics plugin. It also provides instructions for installing the reports as well as details of the script that can be used to install all the reports. ---- - -## Table of Contents +## Reports Creation -- [Overview](#overview) -- [Prerequisites](#prerequisites) -- [Usage](#usage) -- [Environment Variables](#environment-variables) -- [Script Behavior](#script-behavior) -- [Examples](#examples) -- [Reports List](#reports_list) +All the built-in reports are present in the [reports](https://github.com/killbill/killbill-analytics-plugin/reports) directory. Within this directory, there are separate directories for each report. +The following files are present in each report directory: ---- +* `v_report_xxx` - This is the DDL for the view corresponding to the report +* `report_xxx` - This is the DDL corresponding to the database table/stored procedure corresponding to the report +* `README` - This includes the documentation for the report as well as the `curl` command to create the report +* `xxx.png` - This is a screenshot for the report -## Overview +In order to create a report, you need to do the following: -This Bash script performs the following tasks: +1. Run the DDL inside the `v_report_xxx` to create the view. +2. Run the DDL inside `report_xxx` to create the stored procedure. +3. Run the `curl` command within the README -1. Installs database DDL files (`.sql` or `.ddl`) into the configured MySQL database. -2. Creates KillBill analytics reports via the KillBill Analytics plugin REST API. -3. Supports optional dropping of existing reports before creation. -The script recursively installs DDL files, ensuring `v_report_*.ddl` files are installed before corresponding `report_*.ddl` files. If no `v_report_*.ddl` exists in a folder, all `.ddl` files in that folder are installed. +## Report Script ---- +In addition, we also provide the [reports_setup.sh](reports_setup.sh) script. This script automatically creates all the reports in the `reports` directory. -## Prerequisites +### Prerequisites - **Bash shell** (Linux, macOS, or Windows Git Bash) - **MySQL client** installed and accessible in PATH -- KillBill server running with the KillBill Analytics plugin installed -- Appropriate permissions for the MySQL database and KillBill API +- Kill Bill running with the Kill Bill Analytics plugin installed +- Appropriate permissions for the MySQL database and Kill Bill API --- -## Usage +### Usage -Run the script from the directory containing your DDL files: +Run the script as follows: ```bash ./setup_reports.sh @@ -50,19 +45,19 @@ By default, the script installs DDLs and creates all reports. --- -## Environment Variables +### Environment Variables -The script uses environment variables to configure MySQL and KillBill settings. Defaults are provided if variables are not set: +The script uses environment variables to configure MySQL and Kill Bill settings. Defaults are provided if variables are not set: | Variable | Default | Description | |--------------------------|--------------------------|---------------------------------------------------------------------------| -| `KILLBILL_HTTP_PROTOCOL` | `http` | KillBill API protocol | -| `KILLBILL_HOST` | `127.0.0.1` | KillBill host | -| `KILLBILL_PORT` | `8080` | KillBill port | -| `KILLBILL_USER` | `admin` | KillBill username | -| `KILLBILL_PASSWORD` | `password` | KillBill password | -| `KILLBILL_API_KEY` | `bob` | KillBill API key | -| `KILLBILL_API_SECRET` | `lazar` | KillBill API secret | +| `KILLBILL_HTTP_PROTOCOL` | `http` | Kill Bill API protocol | +| `KILLBILL_HOST` | `127.0.0.1` | Kill Bill host | +| `KILLBILL_PORT` | `8080` | Kill Bill port | +| `KILLBILL_USER` | `admin` | Kill Bill username | +| `KILLBILL_PASSWORD` | `password` | Kill Bill password | +| `KILLBILL_API_KEY` | `bob` | Kill Bill API key | +| `KILLBILL_API_SECRET` | `lazar` | Kill Bill API secret | | `MYSQL_HOST` | `127.0.0.1` | MySQL host | | `MYSQL_USER` | `root` | MySQL user | | `MYSQL_PASSWORD` | `killbill` | MySQL password | @@ -82,22 +77,7 @@ export INSTALL_DDL=false --- -## Script Behavior - -1. **DDL Installation** - - Installs ddl from the `utils` directory first. - - Recursively installs DDLs from the other subdirectories: - - If `v_report_*.ddl` files exist, they are installed first, followed by `report_*.ddl`. - - If no `v_report_*.ddl` exists, all `.ddl` files in the folder are installed. - -2. **Report Creation** - - All reports defined in the `create_all_reports` function are created. - - If `DROP_EXISTING_REPORT=true`, existing reports are deleted before creation. - - Reports are created via the KillBill Analytics plugin REST API. - ---- - -## Examples +### Examples - **Run with default configuration:** @@ -119,7 +99,7 @@ export DROP_EXISTING_REPORT=false ./setup_reports.sh ``` -- **Override KillBill host and MySQL password:** +- **Override Kill Bill host and MySQL password:** ```bash export KILLBILL_HOST=192.168.1.10 @@ -127,39 +107,46 @@ export MYSQL_PASSWORD=mysecret ./setup_reports.sh ``` -## Reports List - -The script creates the following reports: - -|Report Name| Underlying Report Table |Report Description| -|--|---------------------------------------|--| -| [accounts_summary](accounts_summary/README.md) | report_accounts_summary |Provides an account summary. Provides details like account balance, account status, currency, etc.| -| [active_by_product_term_monthly](active_by_product_term_monthly/README.md) | report_active_by_product_term_monthly |Compute (at the end of each month) the total number of active subscriptions per product and billing period.| -| [bundles_summary](bundles_summary/README.md) | report_bundles_summary |Provides a subscription bundle summary. Provides details like CTD, plan name, price, for the base subscription in a bundle.| -| [cancellations_daily](cancellations_daily/README.md) | report_cancellations_daily |Compute the total number of cancellations per day per phase.| -| [chargebacks_daily](chargebacks_daily/README.md) | report_chargebacks_daily |Compute the total value (in the reference currency) of chargebacks per day per currency.| -| [conversion-total-dollar-amount](conversion-total-dollar-amount/README.md) | report_conversion-total-dollar-amount |Compute (monthly) the total revenue from subscriptions converting out of trial, grouped by tenant and billing period.| -| [invoice_aging](invoice_aging/README.md) | report_invoice_aging |This report lists all customer invoice aging with remaining balances, breaking them into standard aging buckets and converting amounts to USD for easy comparison.| -| [invoice_aging_no_payment](invoice_aging_no_payment/README.md) | report_invoice_aging_no_payment |This report lists all customer invoices with no payments recorded, categorizing outstanding amounts into standard aging buckets and converting balances into USD for comparison. +## Reports Overview + +The following table provides an overview of all the available reports. + +| Report Name | Underlying Report Table | Report Description | +|--------------------------------------------------------------------------------------|---------------------------------------|----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| +| [accounts_summary](accounts_summary/README.md) | report_accounts_summary | Provides an account summary. Provides details like account balance, account status, currency, etc. | +| [active_by_product_term_monthly](active_by_product_term_monthly/README.md) | report_active_by_product_term_monthly | Compute (at the end of each month) the total number of active subscriptions per product and billing period. | +| [bundles_summary](bundles_summary/README.md) | report_bundles_summary | Provides a subscription bundle summary. Provides details like CTD, plan name, price, for the base subscription in a bundle. | +| [cancellations_daily](cancellations_daily/README.md) | report_cancellations_daily | Compute the total number of cancellations per day per phase. | +| [chargebacks_daily](chargebacks_daily/README.md) | report_chargebacks_daily | Compute the total value (in the reference currency) of chargebacks per day per currency. | +| [churn](churn/README.md) | report_churn_percent | Shows the churn percentage for monthly and annual subscriptions on a per-tenant, per-month basis. | +| [churn](churn/README.md) | report_churn_total_usd | Shows the total churned revenue for monthly and annual subscriptions on a per-tenant, per-month basis. | +| [conversion-total-dollar-amount](conversion-total-dollar-amount/README.md) | report_conversion-total-dollar-amount | Compute (monthly) the total revenue from subscriptions converting out of trial, grouped by tenant and billing period. | +| [invoice_aging](invoice_aging/README.md) | report_invoice_aging | This report lists all customer invoice aging with remaining balances, breaking them into standard aging buckets and converting amounts to USD for easy comparison. | +| [invoice_aging_no_payment](invoice_aging_no_payment/README.md) | report_invoice_aging_no_payment | This report lists all customer invoices with no payments recorded, categorizing outstanding amounts into standard aging buckets and converting balances into USD for comparison. | -| [invoice_credits_daily](invoice_credits_daily/README.md) | report_invoice_credits_daily |Total of invoice credits per tenant, per currency and per day.| -| [invoice_credits_monthly](invoice_credits_monthly/README.md) | report_invoice_credits_monthly |Report of all invoice credits from the previous month, showing amounts in both original currency and USD equivalents.| -| [invoice_item_adjustments_daily](invoice_item_adjustments_daily/README.md) | report_invoice_item_adjustments_daily |Total of invoice item adjustments per tenant, per currency and per day.| -| [invoice_item_adjustments_monthly](invoice_item_adjustments_monthly/README.md) | report_invoice_item_adjustments_monthly |Report of all invoice item adjustments from the previous month, showing amounts in both original currency and USD equivalents.| -| [invoice_items_monthly](invoice_items_monthly/README.md) | report_invoice_items_monthly |Report of all invoice items from the previous month, showing amounts in both original currency and USD equivalents.| -| [invoices_balance_daily](invoices_balance_daily/README.md) | report_invoices_balance_daily |Compute the total sum of invoices balance (in the reference currency) per invoice created day. +| [invoice_credits_daily](invoice_credits_daily/README.md) | report_invoice_credits_daily | Total of invoice credits per tenant, per currency and per day. | +| [invoice_credits_monthly](invoice_credits_monthly/README.md) | report_invoice_credits_monthly | Report of all invoice credits from the previous month, showing amounts in both original currency and USD equivalents. | +| [invoice_item_adjustments_daily](invoice_item_adjustments_daily/README.md) | report_invoice_item_adjustments_daily | Total of invoice item adjustments per tenant, per currency and per day. | +| [invoice_item_adjustments_monthly](invoice_item_adjustments_monthly/README.md) | report_invoice_item_adjustments_monthly | Report of all invoice item adjustments from the previous month, showing amounts in both original currency and USD equivalents. | +| [invoice_items_monthly](invoice_items_monthly/README.md) | report_invoice_items_monthly | Report of all invoice items from the previous month, showing amounts in both original currency and USD equivalents. | +| [invoices_balance_daily](invoices_balance_daily/README.md) | report_invoices_balance_daily | Compute the total sum of invoices balance (in the reference currency) per invoice created day. | -| [invoices_daily](invoices_daily/README.md) | report_invoices_daily |Compute the total invoice amount charged (in the reference currency) per day per currency.| -| [invoices_monthly](invoices_monthly/README.md) | report_invoices_monthly |Report of all invoices from the previous month, showing amounts in both original currency and USD equivalents.| -| [mrr_daily](mrr_daily/README.md) | report_mrr_daily |Computes the total active MRR (monthly recurring revenue), broken down both by product and as a tenant-wide total (ALL) for each tenant and each day.| -| [new_accounts_daily](new_accounts_daily/README.md) | report_new_accounts_daily |Compute the total amount of new accounts created per day for each tenant.| -| [overdue-states-count-daily](overdue-states-count-daily/README.md) | report_overdue-states-count-daily |Count of overdue states per tenant and per day.| -| [payments_monthly](payments_monthly/README.md) | report_payments_monthly |Report of all payments from the previous month, showing amounts in both original currency and USD equivalents.| -| [payments_summary](payments_summary/README.md) | report_payments_summary |Provides payment summary. Provides details like payment_id, amount, etc.| -| [payments_total_daily](payments_total_daily/README.md) | report_payments_total_daily |Compute the total value (in the reference currency) of payments per day per currency.| -| [refunds-monthly](refunds-monthly/README.md) | report_refunds-monthly |Report of all refunds from the previous month, showing amounts in both original currency and USD equivalents.| -| [refunds_total_daily](refunds_total_daily/README.md) | report_refunds_total_daily |Compute the total value (in the reference currency) of refunds per day per currency for each tenant.| -| [subscribers-vs-non-subscribers](subscribers-vs-non-subscribers/README.md) | report_subscribers-vs-non-subscribers |Compute the total number of active (i.e. with at least one active subscription) and non-active accounts per tenant.| -| [trial-starts-count-daily](trial-starts-count-daily/README.md) | report_trial-starts-count-daily |Count of new trial subscriptions per tenant, per day and per product.| -| [trial-to-no-trial-conversions_daily](trial-to-no-trial-conversions_daily/README.md) | report_trial-to-no-trial-conversions_daily |Count of subscriptions converting from trial to non-trial per tenant per day.| +| [invoices_daily](invoices_daily/README.md) | report_invoices_daily | Compute the total invoice amount charged (in the reference currency) per day per currency. | +| [invoices_monthly](invoices_monthly/README.md) | report_invoices_monthly | Report of all invoices from the previous month, showing amounts in both original currency and USD equivalents. | +| [mrr_daily](mrr_daily/README.md) | report_mrr_daily | Computes the total active MRR (monthly recurring revenue), broken down both by product and as a tenant-wide total (ALL) for each tenant and each day. | +| [new_accounts_daily](new_accounts_daily/README.md) | report_new_accounts_daily | Compute the total amount of new accounts created per day for each tenant. | +| [overdue-states-count-daily](overdue-states-count-daily/README.md) | report_overdue-states-count-daily | Count of overdue states per tenant and per day. | +| [payment_provider_conversions](payment_provider_conversions/README.md) | report_payment_provider_conversions | Compare the total number of transactions and the number of successful transactions that have occurred in a recent 15 minutes period to the same metrics that occurred in the corresponding 15 minutes from 14 days ago. | +| [payment_provider_errors](payment_provider_errors/README.md) | report_payment_provider_errors | Compute the top errors per provider and currency, per day. | +| [payment_provider_monitor](payment_provider_monitor/README.md) | report_payment_provider_monitor | Compute the number of successful transactions that have occurred in the past hour, for each payment service provider that has had transactions within the last week. | +| [payments_by_provider](payments_by_provider/README.md) | report_payments_by_provider | Compute the number of payments by transaction state over different timeframes for each payment service provider (plugin). | +| [payments_by_provider](payments_by_provider/README.md) | report_payments_by_provider_last_24h_summary | Compute the number of payments by transaction state over different timeframes for each payment service provider (plugin). | +| [payments_monthly](payments_monthly/README.md) | report_payments_monthly | Report of all payments from the previous month, showing amounts in both original currency and USD equivalents. | +| [payments_summary](payments_summary/README.md) | report_payments_summary | Provides payment summary. Provides details like payment_id, amount, etc. | +| [payments_total_daily](payments_total_daily/README.md) | report_payments_total_daily | Compute the total value (in the reference currency) of payments per day per currency. | +| [refunds-monthly](refunds-monthly/README.md) | report_refunds-monthly | Report of all refunds from the previous month, showing amounts in both original currency and USD equivalents. | +| [refunds_total_daily](refunds_total_daily/README.md) | report_refunds_total_daily | Compute the total value (in the reference currency) of refunds per day per currency for each tenant. | +| [subscribers-vs-non-subscribers](subscribers-vs-non-subscribers/README.md) | report_subscribers-vs-non-subscribers | Compute the total number of active (i.e. with at least one active subscription) and non-active accounts per tenant. | +| [trial-starts-count-daily](trial-starts-count-daily/README.md) | report_trial-starts-count-daily | Count of new trial subscriptions per tenant, per day and per product. | +| [trial-to-no-trial-conversions_daily](trial-to-no-trial-conversions_daily/README.md) | report_trial-to-no-trial-conversions_daily | Count of subscriptions converting from trial to non-trial per tenant per day. | diff --git a/src/main/resources/reports/churn/README.md b/reports/churn/README.md similarity index 84% rename from src/main/resources/reports/churn/README.md rename to reports/churn/README.md index ca872722..0d931a2a 100644 --- a/src/main/resources/reports/churn/README.md +++ b/reports/churn/README.md @@ -4,6 +4,10 @@ This report tracks customer churn in dollar terms, showing both the total churne The snapshot view is: `v_report_churn_percent_and_total_usd` +## Database Indices + +The churn reports requires some additional database indices to be created. See [churn-indices.ddl](churn-indices.ddl) + ## Churn Percent Configuration ``` @@ -18,13 +22,13 @@ curl -v \ "reportPrettyName": "Churn Percent (Monthly and Annual)", "sourceTableName": "report_churn_percent", "refreshProcedureName": "refresh_report_churn_percent", - "refreshFrequency": "DAILY"}' \ + "refreshFrequency": "HOURLY"}' \ "http://127.0.0.1:8080/plugins/killbill-analytics/reports" ``` ## Churn Percentage Report UI - +![churn-percent.png.png](churn-percent.png) ## Churn Amount Configuration @@ -47,3 +51,4 @@ curl -v \ ## Churn Amount Report UI +![churn-amount.png](churn-amount.png) \ No newline at end of file diff --git a/reports/churn/churn-amount.png b/reports/churn/churn-amount.png new file mode 100644 index 00000000..94d462f9 Binary files /dev/null and b/reports/churn/churn-amount.png differ diff --git a/reports/churn/churn-indices.ddl b/reports/churn/churn-indices.ddl new file mode 100644 index 00000000..af24f219 --- /dev/null +++ b/reports/churn/churn-indices.ddl @@ -0,0 +1,4 @@ +CREATE INDEX idx_ai_tenant_bundle ON analytics_invoice_items(tenant_record_id, bundle_id, invoice_original_amount_charged, invoice_balance); +CREATE INDEX idx_ast_bundle_tenant_event ON analytics_subscription_transitions(bundle_id, tenant_record_id, event, next_start_date, next_end_date, next_billing_period); +CREATE INDEX idx_subs_id_tenant ON subscriptions(id, tenant_record_id); +CREATE INDEX idx_se_sub_tenant_type ON subscription_events(subscription_id, tenant_record_id, user_type); \ No newline at end of file diff --git a/reports/churn/churn-percent.png b/reports/churn/churn-percent.png new file mode 100644 index 00000000..080e8ab7 Binary files /dev/null and b/reports/churn/churn-percent.png differ diff --git a/src/main/resources/reports/churn/report_churn_percent.ddl b/reports/churn/report_churn_percent.ddl similarity index 100% rename from src/main/resources/reports/churn/report_churn_percent.ddl rename to reports/churn/report_churn_percent.ddl diff --git a/src/main/resources/reports/churn/report_churn_total_usd.ddl b/reports/churn/report_churn_total_usd.ddl similarity index 100% rename from src/main/resources/reports/churn/report_churn_total_usd.ddl rename to reports/churn/report_churn_total_usd.ddl diff --git a/src/main/resources/reports/churn/v_report_churn_percent_and_total_usd.ddl b/reports/churn/v_report_churn_percent_and_total_usd.ddl similarity index 100% rename from src/main/resources/reports/churn/v_report_churn_percent_and_total_usd.ddl rename to reports/churn/v_report_churn_percent_and_total_usd.ddl diff --git a/reports/new_subscriptions_daily/README.md b/reports/new_subscriptions_daily/README.md new file mode 100644 index 00000000..5e4947b7 --- /dev/null +++ b/reports/new_subscriptions_daily/README.md @@ -0,0 +1,44 @@ +# Daily New Subscriptions Report + +Compute the total amount of new subscriptions created per day for each tenant. + +The snapshot view is: `v_report_new_subscriptions_daily` + +## 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_new_subscriptions_daily", + "reportType": "TIMELINE", + "reportPrettyName": "Daily New Subscriptions", + "sourceTableName": "report_new_subscriptions_daily", + "refreshProcedureName": "refresh_report_new_subscriptions_daily", + "refreshFrequency": "HOURLY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + + +## Sample Data + +| Tenant Record Id | Slug | Day | Count | +|------------------|------------------------------------|------------|-------| +| 1 | blowdart-monthly-notrial-evergreen | 2025-08-20 | 9 | +| 1 | pistol-monthly-notrial-evergreen | 2025-08-20 | 2 | +| 1 | pistol-monthly-notrial-evergreen | 2025-09-01 | 5 | +| 1 | blowdart-monthly-notrial-evergreen | 2025-09-02 | 6 | +| 25 | gold-monthly-notrial-evergreen | 2025-09-02 | 5 | +| 25 | silver-monthly-notrial-evergreen | 2025-09-03 | 6 | + + +The first row in the above table indicates that on the date `2025-08-20`, the tenant with record id=1 had 9 new subscriptions created. + + +## Report UI: + + +![daily-new-subscriptions.png](daily-new-subscriptions.png) diff --git a/reports/new_subscriptions_daily/daily-new-subscriptions.png b/reports/new_subscriptions_daily/daily-new-subscriptions.png new file mode 100644 index 00000000..c89f8e0b Binary files /dev/null and b/reports/new_subscriptions_daily/daily-new-subscriptions.png differ diff --git a/reports/new_subscriptions_daily/report_new_subscriptions_daily.ddl b/reports/new_subscriptions_daily/report_new_subscriptions_daily.ddl new file mode 100644 index 00000000..c9a9de3e --- /dev/null +++ b/reports/new_subscriptions_daily/report_new_subscriptions_daily.ddl @@ -0,0 +1,19 @@ +create table report_new_subscriptions_daily as select * from v_report_new_subscriptions_daily limit 0; + +drop procedure if exists refresh_report_new_subscriptions_daily; +DELIMITER // +CREATE PROCEDURE refresh_report_report_new_subscriptions_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_new_subscriptions_daily; + insert into report_new_subscriptions_daily select * from v_report_new_subscriptions_daily; +COMMIT; + +END; +// +DELIMITER ; diff --git a/reports/new_subscriptions_daily/v_report_new_subscriptions_daily.ddl b/reports/new_subscriptions_daily/v_report_new_subscriptions_daily.ddl new file mode 100644 index 00000000..ced1b864 --- /dev/null +++ b/reports/new_subscriptions_daily/v_report_new_subscriptions_daily.ddl @@ -0,0 +1,11 @@ +create or replace view v_report_new_subscriptions_daily AS +select ast.tenant_record_id AS tenant_record_id, +ast.next_slug AS slug, +date_format(ast.next_start_date,'%Y-%m-%d') AS day, +count(0) AS count +from analytics_subscription_transitions ast +where ((1 = 1) and +(ast.event = 'START_BILLING_BASE') and +(ast.report_group = 'default')) group by +ast.tenant_record_id,ast.next_slug, +date_format(ast.next_start_date,'%Y-%m-%d') \ No newline at end of file diff --git a/reports/overdue_accounts_summary/README.md b/reports/overdue_accounts_summary/README.md new file mode 100644 index 00000000..4ef34641 --- /dev/null +++ b/reports/overdue_accounts_summary/README.md @@ -0,0 +1,43 @@ +# Overdue Accounts Summary Report + +Breakdown of current vs. overdue accounts by tenant. + +The snapshot view is: [v_report_overdue_account_summary](v_report_overdue_account_summary.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_overdue_accounts_summary", + "reportType": "COUNTERS", + "reportPrettyName": "Overdue Accounts Summary", + "sourceTableName": "report_overdue_accounts_summary", + "refreshProcedureName": "refresh_report_overdue_accounts_summary", + "refreshFrequency": "HOURLY"}' \ + "http://127.0.0.1:8080/plugins/killbill-analytics/reports" +``` + +## Sample Data + +| Tenant Record Id | Label | Count | +|------------------|---------|-------| +| 515 | Overdue | 5 | +| 518 | Overdue | 1 | +| 1 | Overdue | 74 | +| 1 | Current | 23 | +| 256 | Overdue | 3 | + + +The first row in the above table indicates that the tenant with record id=1 had 5 accounts in the `Overdue` state. + +## Report UI: + +![overdue-accounts-summary.png](overdue-accounts-summary.png) + + + diff --git a/reports/overdue_accounts_summary/overdue-accounts-summary.png b/reports/overdue_accounts_summary/overdue-accounts-summary.png new file mode 100644 index 00000000..397cdb64 Binary files /dev/null and b/reports/overdue_accounts_summary/overdue-accounts-summary.png differ diff --git a/reports/overdue_accounts_summary/report_overdue_account_summary.ddl b/reports/overdue_accounts_summary/report_overdue_account_summary.ddl new file mode 100644 index 00000000..6f3faff1 --- /dev/null +++ b/reports/overdue_accounts_summary/report_overdue_account_summary.ddl @@ -0,0 +1,19 @@ +create table report_overdue_accounts_summary as select * from v_report_overdue_accounts_summary limit 0; + +drop procedure if exists refresh_report_overdue_accounts_summary; +DELIMITER // +CREATE PROCEDURE refresh_report_overdue_accounts_summary() +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_accounts_summary; + insert into report_overdue_accounts_summary select * from v_report_overdue_accounts_summary; +COMMIT; + +END; +// +DELIMITER ; diff --git a/reports/overdue_accounts_summary/v_report_overdue_account_summary.ddl b/reports/overdue_accounts_summary/v_report_overdue_account_summary.ddl new file mode 100644 index 00000000..f7571371 --- /dev/null +++ b/reports/overdue_accounts_summary/v_report_overdue_account_summary.ddl @@ -0,0 +1,10 @@ +create or replace view v_report_overdue_accounts_summary AS +select a.tenant_record_id AS tenant_record_id, +(case when (a.balance <= 0) then 'Current' else 'Overdue' end) AS label, +count(0) AS count +from analytics_accounts a +where +((1 = 1) and +(a.report_group = 'default')) +group by a.tenant_record_id, +(case when (a.balance <= 0) then 'Current' else 'Overdue' end) \ No newline at end of file diff --git a/src/main/resources/reports/payment_provider_conversion/README.md b/reports/payment_provider_conversions/README.md similarity index 76% rename from src/main/resources/reports/payment_provider_conversion/README.md rename to reports/payment_provider_conversions/README.md index c5e0dcc1..093227aa 100644 --- a/src/main/resources/reports/payment_provider_conversion/README.md +++ b/reports/payment_provider_conversions/README.md @@ -1,11 +1,10 @@ # Payment Provider Conversion report -Compare the total number of transactions and the number of successful transactions that have occurred in a recent 15 minutes -period to the same metrics that occurred in the corresponding 15 minutes from 14 days ago. +Compare the total number of transactions and the number of successful transactions that have occurred in a recent 15 minutes period to the same metrics that occurred in the corresponding 15 minutes from 14 days ago. The snapshot view is: `v_report_payment_provider_conversion`. -## History table configuration +## Report Creation ``` curl -v \ @@ -17,8 +16,8 @@ curl -v \ -d '{"reportName": "report_payment_provider_conversion", "reportType": "TABLE", "reportPrettyName": "Payment Provider Conversion", - "sourceTableName": "report_payment_provider_conversion_history", - "refreshProcedureName": "refresh_report_payment_provider_conversion_history", + "sourceTableName": "report_payment_provider_conversion", + "refreshProcedureName": "refresh_report_payment_provider_conversion", "refreshFrequency": "HOURLY"}' \ "http://127.0.0.1:8080/plugins/killbill-analytics/reports" ``` diff --git a/reports/payment_provider_conversions/report_payment_provider_conversions.ddl b/reports/payment_provider_conversions/report_payment_provider_conversions.ddl new file mode 100644 index 00000000..cdaa90fd --- /dev/null +++ b/reports/payment_provider_conversions/report_payment_provider_conversions.ddl @@ -0,0 +1,16 @@ +create table report_payment_provider_conversion as select * from v_report_payment_provider_conversion limit 0; + +drop procedure if exists refresh_report_payment_provider_conversion; +DELIMITER // +CREATE PROCEDURE refresh_report_payment_provider_conversion() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +insert into report_payment_provider_conversion select * from v_report_payment_provider_conversion; + +END; +// +DELIMITER ; diff --git a/reports/payment_provider_conversions/v_report_payment_provider_conversions.ddl b/reports/payment_provider_conversions/v_report_payment_provider_conversions.ddl new file mode 100644 index 00000000..266320f4 --- /dev/null +++ b/reports/payment_provider_conversions/v_report_payment_provider_conversions.ddl @@ -0,0 +1,122 @@ +create or replace view v_report_payment_provider_conversion_sub1 as +SELECT + apa.plugin_name +, ifnull(apa.plugin_property_4,'unknown') as merchant_account +, ifnull(apa.plugin_property_5,'unknown') as payment_method +, apa.tenant_record_id +, sum(case when apa.payment_transaction_status='SUCCESS' then 1 else 0 end) as current_success_count +, count(1) as current_transaction_count +, count(distinct apa.account_id) as current_customer_count +FROM + analytics_payment_auths apa +WHERE 1=1 +AND apa.created_date >= FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60)%(15*60)) +AND cast(FROM_UNIXTIME(UNIX_TIMESTAMP(apa.created_date) - UNIX_TIMESTAMP(apa.created_date)%(15*60)) as time) = cast(FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60 - (UNIX_TIMESTAMP(NOW()) - 15*60)%(15*60)) as time) +GROUP BY + apa.plugin_name +, ifnull(apa.plugin_property_4,'unknown') +, ifnull(apa.plugin_property_5,'unknown') +, apa.tenant_record_id +UNION +SELECT + app.plugin_name +, ifnull(app.plugin_property_4,'unknown') as merchant_account +, ifnull(app.plugin_property_5,'unknown') as payment_method +, app.tenant_record_id +, sum(case when app.payment_transaction_status='SUCCESS' then 1 else 0 end) as current_success_count +, count(1) as current_transaction_count +, count(distinct app.account_id) as current_customer_count +FROM + analytics_payment_purchases app +WHERE 1=1 +AND app.created_date >= FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60)%(15*60)) +AND cast(FROM_UNIXTIME(UNIX_TIMESTAMP(app.created_date) - UNIX_TIMESTAMP(app.created_date)%(15*60)) as time) = cast(FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60 - (UNIX_TIMESTAMP(NOW()) - 15*60)%(15*60)) as time) +GROUP BY + app.plugin_name +, ifnull(app.plugin_property_4,'unknown') +, ifnull(app.plugin_property_5,'unknown') +, app.tenant_record_id +; + +create or replace view v_report_payment_provider_conversion_sub2 as +SELECT + apa.plugin_name +, ifnull(apa.plugin_property_4,'unknown') as merchant_account +, ifnull(apa.plugin_property_5,'unknown') as payment_method +, apa.tenant_record_id +, sum(case when apa.payment_transaction_status='SUCCESS' then 1 else 0 end) as historical_success_count +, count(1) as historical_transaction_count +, count(distinct apa.account_id) as historical_customer_count +FROM + analytics_payment_auths apa +WHERE 1=1 +AND apa.created_date < FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60) + 15*60) +AND cast(FROM_UNIXTIME(UNIX_TIMESTAMP(apa.created_date) - UNIX_TIMESTAMP(apa.created_date)%(15*60)) as time) = cast(FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60)) as time) +AND apa.created_date >= FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60)) +GROUP BY + apa.plugin_name +, ifnull(apa.plugin_property_4,'unknown') +, ifnull(apa.plugin_property_5,'unknown') +, apa.tenant_record_id +UNION +SELECT + app.plugin_name +, ifnull(app.plugin_property_4,'unknown') as merchant_account +, ifnull(app.plugin_property_5,'unknown') as payment_method +, app.tenant_record_id +, sum(case when app.payment_transaction_status='SUCCESS' then 1 else 0 end) as historical_success_count +, count(1) as historical_transaction_count +, count(distinct app.account_id) as historical_customer_count +FROM + analytics_payment_purchases app +WHERE 1=1 +AND app.created_date < FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60) + 15*60) +AND cast(FROM_UNIXTIME(UNIX_TIMESTAMP(app.created_date) - UNIX_TIMESTAMP(app.created_date)%(15*60)) as time) = cast(FROM_UNIXTIME(UNIX_TIMESTAMP(NOW() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60)) as time) +AND app.created_date >= FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60)) +GROUP BY + app.plugin_name +, ifnull(app.plugin_property_4,'unknown') +, ifnull(app.plugin_property_5,'unknown') +, app.tenant_record_id +; + +create or replace view v_report_payment_provider_conversion as +with agg as ( + select + rpccs1.plugin_name, + rpccs1.merchant_account, + rpccs1.payment_method, + rpccs1.tenant_record_id, + ifnull(sum(rpccs1.current_success_count),0) as current_success_count, + ifnull(sum(rpccs1.current_transaction_count),0) as current_transaction_count, + ifnull(sum(rpccs1.current_customer_count),0) as current_customer_count, + ifnull(sum(rpccs2.historical_success_count),0) as historical_success_count, + ifnull(sum(rpccs2.historical_transaction_count),0) as historical_transaction_count, + ifnull(sum(rpccs2.historical_customer_count),0) as historical_customer_count + from v_report_payment_provider_conversion_sub2 rpccs2 + left join v_report_payment_provider_conversion_sub1 rpccs1 + on rpccs1.plugin_name=rpccs2.plugin_name + and rpccs1.merchant_account=rpccs2.merchant_account + and rpccs1.payment_method=rpccs2.payment_method + and rpccs1.tenant_record_id=rpccs2.tenant_record_id + group by + rpccs1.plugin_name, + rpccs1.merchant_account, + rpccs1.payment_method, + rpccs1.tenant_record_id +) +select *, + case when historical_success_count > 0 + then concat(round(((current_success_count-historical_success_count)/historical_success_count)*100,2),'%') + else '0%' + end as success_delta, + case when historical_transaction_count > 0 + then concat(round(((current_transaction_count-historical_transaction_count)/historical_transaction_count)*100,2),'%') + else '0%' + end as transaction_delta, + case when historical_customer_count > 0 + then concat(round(((current_customer_count-historical_customer_count)/historical_customer_count)*100,2),'%') + else '0%' + end as customer_delta, + sysdate() as refresh_date +from agg; diff --git a/src/main/resources/reports/payment_provider_errors/README.md b/reports/payment_provider_errors/README.md similarity index 84% rename from src/main/resources/reports/payment_provider_errors/README.md rename to reports/payment_provider_errors/README.md index 06b20b42..2cdec97d 100644 --- a/src/main/resources/reports/payment_provider_errors/README.md +++ b/reports/payment_provider_errors/README.md @@ -1,10 +1,10 @@ -# Payment Provider Errors report +# Payment Provider Errors Report Compute the top errors per provider and currency, per day. The snapshot view is: `v_report_payment_provider_errors` -## Timeline configuration +## Report Creation ``` curl -v \ @@ -21,3 +21,7 @@ curl -v \ "refreshFrequency": "HOURLY"}' \ "http://127.0.0.1:8080/plugins/killbill-analytics/reports" ``` + +## Report UI: + +![payment-provider-errors.png](payment-provider-errors.png) diff --git a/reports/payment_provider_errors/payment-provider-errors.png b/reports/payment_provider_errors/payment-provider-errors.png new file mode 100644 index 00000000..3d3f4b2b Binary files /dev/null and b/reports/payment_provider_errors/payment-provider-errors.png differ diff --git a/reports/payment_provider_errors/report_payment_provider_errors.ddl b/reports/payment_provider_errors/report_payment_provider_errors.ddl new file mode 100644 index 00000000..02eff80c --- /dev/null +++ b/reports/payment_provider_errors/report_payment_provider_errors.ddl @@ -0,0 +1,21 @@ +create table report_payment_provider_errors as select * from v_report_payment_provider_errors limit 0; +drop procedure if exists refresh_report_payment_provider_errors; +DELIMITER // +CREATE PROCEDURE refresh_report_payment_provider_errors() +BEGIN + + DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; + DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + + SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + + START TRANSACTION; + + delete from report_payment_provider_errors; + insert into report_payment_provider_errors select * from v_report_payment_provider_errors; + + COMMIT; + +END; +// +DELIMITER ; diff --git a/reports/payment_provider_errors/v_report_payment_provider_errors.ddl b/reports/payment_provider_errors/v_report_payment_provider_errors.ddl new file mode 100644 index 00000000..5c19ab43 --- /dev/null +++ b/reports/payment_provider_errors/v_report_payment_provider_errors.ddl @@ -0,0 +1,64 @@ +create or replace view v_report_payment_provider_errors_sub1 as +select + aa.tenant_record_id +, 'AUTH' as op +, date_format(aa.created_date,'%Y-%m-%d') as day +, aa.currency +, aa.plugin_name +, aa.record_id +from analytics_payment_auths aa +where 1=1 + and aa.payment_transaction_status not in ('PENDING', 'SUCCESS') + and aa.report_group = 'default' + and aa.created_date > utc_timestamp() - interval '60' day +union +select + ap.tenant_record_id +, 'PURCHASE' as op +, date_format(ap.created_date,'%Y-%m-%d') as day +, ap.currency +, ap.plugin_name +, ap.record_id +from analytics_payment_purchases ap +where 1=1 + and ap.payment_transaction_status not in ('PENDING', 'SUCCESS') + and ap.report_group = 'default' + and ap.created_date > utc_timestamp() - interval '60' day +; + +create or replace view v_report_payment_provider_errors_sub2 as +select + v1.tenant_record_id +, v1.day +, v1.currency +, v1.plugin_name +, substring_index(ifnull(apa.plugin_gateway_error, app.plugin_gateway_error), ' ', 10) as plugin_gateway_error +, count(1) as count +from v_report_payment_provider_errors_sub1 v1 +left join analytics_payment_auths apa on apa.record_id = v1.record_id and v1.op = 'AUTH' +left join analytics_payment_purchases app on app.record_id = v1.record_id and v1.op = 'PURCHASE' +where 1=1 +and ifnull(apa.plugin_gateway_error, app.plugin_gateway_error) is not null +group by 1,2,3,4,5 +; + +create or replace view v_report_payment_provider_errors as +select + tenant_record_id +, day +, currency +, plugin_name +, plugin_gateway_error +, count +from v_report_payment_provider_errors_sub2 sub2 +where ( + select count(*) from v_report_payment_provider_errors_sub2 as sub21 + where 1=1 + and sub21.tenant_record_id = sub2.tenant_record_id + and sub21.day = sub2.day + and sub21.currency = sub2.currency + and sub21.plugin_name = sub2.plugin_name + and sub21.count >= sub2.count +) <= 3 +; + diff --git a/src/main/resources/reports/payment_provider_monitor/README.md b/reports/payment_provider_monitor/README.md similarity index 76% rename from src/main/resources/reports/payment_provider_monitor/README.md rename to reports/payment_provider_monitor/README.md index 8982c0ce..cfcfbc78 100644 --- a/src/main/resources/reports/payment_provider_monitor/README.md +++ b/reports/payment_provider_monitor/README.md @@ -4,7 +4,7 @@ Compute the number of successful transactions that have occurred in the past hou The snapshot view is: `v_report_payment_provider_monitor` -## History table configuration +## Report Creation ``` curl -v \ @@ -16,8 +16,12 @@ curl -v \ -d '{"reportName": "report_payment_provider_monitor", "reportType": "TABLE", "reportPrettyName": "Payment Provider Monitor", - "sourceTableName": "report_payment_provider_monitor_history", - "refreshProcedureName": "refresh_report_payment_provider_monitor_history", - "refreshFrequency": "DAILY"}' \ + "sourceTableName": "report_payment_provider_monitor", + "refreshProcedureName": "refresh_report_payment_provider_monitor", + "refreshFrequency": "HOURLY"}' \ "http://127.0.0.1:8080/plugins/killbill-analytics/reports" ``` + +## Report UI: + +![payment-provider-monitor.png](payment-provider-monitor.png) \ No newline at end of file diff --git a/reports/payment_provider_monitor/payment-provider-monitor.png b/reports/payment_provider_monitor/payment-provider-monitor.png new file mode 100644 index 00000000..4de7ce08 Binary files /dev/null and b/reports/payment_provider_monitor/payment-provider-monitor.png differ diff --git a/reports/payment_provider_monitor/report_payment_provider_monitor.ddl b/reports/payment_provider_monitor/report_payment_provider_monitor.ddl new file mode 100644 index 00000000..6a5c28fc --- /dev/null +++ b/reports/payment_provider_monitor/report_payment_provider_monitor.ddl @@ -0,0 +1,16 @@ +create table report_payment_provider_monitor as select * from v_report_payment_provider_monitor limit 0; + +drop procedure if exists refresh_report_payment_provider_monitor; +DELIMITER // +CREATE PROCEDURE refresh_report_payment_provider_monitor() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +insert into report_payment_provider_monitor select * from v_report_payment_provider_monitor; + +END; +// +DELIMITER ; diff --git a/reports/payment_provider_monitor/v_report_payment_provider_monitor.ddl b/reports/payment_provider_monitor/v_report_payment_provider_monitor.ddl new file mode 100644 index 00000000..a952a500 --- /dev/null +++ b/reports/payment_provider_monitor/v_report_payment_provider_monitor.ddl @@ -0,0 +1,88 @@ +create or replace view v_report_payment_provider_monitor_sub1 as +SELECT distinct + apa.plugin_name +, ifnull(apa.plugin_property_4,'unknown') as merchant_account +, ifnull(apa.plugin_property_5,'unknown') as payment_method +, apa.tenant_record_id +FROM analytics_payment_auths apa +WHERE 1=1 +AND apa.created_date > utc_timestamp() - interval '7' day +UNION +SELECT distinct + app.plugin_name +, ifnull(app.plugin_property_4,'unknown') as merchant_account +, ifnull(app.plugin_property_5,'unknown') as payment_method +, app.tenant_record_id +FROM analytics_payment_purchases app +WHERE 1=1 +AND app.created_date > utc_timestamp() - interval '7' day +; + +create or replace view v_report_payment_provider_monitor_sub2 as +SELECT + apa.plugin_name +, ifnull(apa.plugin_property_4,'unknown') as merchant_account +, ifnull(apa.plugin_property_5,'unknown') as payment_method +, apa.tenant_record_id +, sum(case when apa.created_date > utc_timestamp() - interval 1 hour then 1 else 0 end) success_count_last_hour +, count(1) success_count_last_12_hours +FROM analytics_payment_auths apa +WHERE 1=1 +AND apa.payment_transaction_status = 'SUCCESS' +AND apa.created_date > utc_timestamp() - interval '12' hour +GROUP BY + apa.plugin_name +, ifnull(apa.plugin_property_4,'unknown') +, ifnull(apa.plugin_property_5,'unknown') +, apa.tenant_record_id +UNION +SELECT + app.plugin_name +, ifnull(app.plugin_property_4,'unknown') as merchant_account +, ifnull(app.plugin_property_5,'unknown') as payment_method +, app.tenant_record_id +, sum(case when app.created_date > utc_timestamp() - interval 1 hour then 1 else 0 end) success_count_last_hour +, count(1) success_count_last_12_hours +FROM analytics_payment_purchases app +WHERE 1=1 +AND app.payment_transaction_status = 'SUCCESS' +AND app.created_date > utc_timestamp() - interval '12' hour +GROUP BY + app.plugin_name +, ifnull(app.plugin_property_4,'unknown') +, ifnull(app.plugin_property_5,'unknown') +, app.tenant_record_id +; + +create or replace view v_report_payment_provider_monitor_sub3 as +SELECT + plugin_name +, merchant_account +, payment_method +, tenant_record_id +, sum(ifnull(success_count_last_hour,0)) as success_count_last_hour +, sum(ifnull(success_count_last_12_hours,0)) as success_count_last_12_hours +FROM v_report_payment_provider_monitor_sub2 t2 +GROUP BY + plugin_name +, merchant_account +, payment_method +, tenant_record_id +; + +create or replace view v_report_payment_provider_monitor as +SELECT + plugin_list.plugin_name +, plugin_list.merchant_account +, plugin_list.payment_method +, plugin_list.tenant_record_id +, ifnull(recent_success_trx.success_count_last_hour,0) as success_count_last_hour +, ifnull(recent_success_trx.success_count_last_12_hours,0) as success_count_last_12_hours +, sysdate() as refresh_date +FROM v_report_payment_provider_monitor_sub1 plugin_list +LEFT OUTER JOIN v_report_payment_provider_monitor_sub3 recent_success_trx on + plugin_list.plugin_name=recent_success_trx.plugin_name +AND plugin_list.merchant_account=recent_success_trx.merchant_account +AND plugin_list.payment_method=recent_success_trx.payment_method +AND plugin_list.tenant_record_id=recent_success_trx.tenant_record_id +; \ No newline at end of file diff --git a/src/main/resources/reports/payments_by_provider/README.md b/reports/payments_by_provider/README.md similarity index 74% rename from src/main/resources/reports/payments_by_provider/README.md rename to reports/payments_by_provider/README.md index ed9000cc..ac74566d 100644 --- a/src/main/resources/reports/payments_by_provider/README.md +++ b/reports/payments_by_provider/README.md @@ -4,7 +4,7 @@ Compute the number of payments by transaction state over different timeframes fo The snapshot view is: `v_report_payments_by_provider` -## History table configuration +## Report Creation (Payment by Provider) ``` curl -v \ @@ -16,13 +16,17 @@ curl -v \ -d '{"reportName": "report_payments_by_provider", "reportType": "TABLE", "reportPrettyName": "Payments By Provider", - "sourceTableName": "report_payments_by_provider_history", - "refreshProcedureName": "refresh_report_payments_by_provider_history", + "sourceTableName": "report_payments_by_provider", + "refreshProcedureName": "refresh_report_payments_by_provider", "refreshFrequency": "HOURLY"}' \ "http://127.0.0.1:8080/plugins/killbill-analytics/reports" ``` -## Summary pie charts configuration +## Payment by Provider Report UI + +![payment-by-provider.png](payment-by-provider.png) + +## Report Creation (Payment by Provider - Last 24 Hours Summary) ``` curl -v \ @@ -36,6 +40,10 @@ curl -v \ "reportPrettyName": "Payments By Provider Summary (last 24hrs)", "sourceTableName": "report_payments_by_provider_last_24h_summary", "refreshProcedureName": "refresh_report_payments_by_provider_last_24h_summary", - "refreshFrequency": "DAILY"}' \ + "refreshFrequency": "HOURLY"}' \ "http://127.0.0.1:8080/plugins/killbill-analytics/reports" ``` + +## Payment by Provider - Last 24 Hours Summary UI + +![payment-by-provider-last-24-hr-summary.png](payment-by-provider-last-24-hr-summary.png) \ No newline at end of file diff --git a/reports/payments_by_provider/payment-by-provider-last-24-hr-summary.png b/reports/payments_by_provider/payment-by-provider-last-24-hr-summary.png new file mode 100644 index 00000000..4dbab796 Binary files /dev/null and b/reports/payments_by_provider/payment-by-provider-last-24-hr-summary.png differ diff --git a/reports/payments_by_provider/payment-by-provider.png b/reports/payments_by_provider/payment-by-provider.png new file mode 100644 index 00000000..efca829e Binary files /dev/null and b/reports/payments_by_provider/payment-by-provider.png differ diff --git a/reports/payments_by_provider/report_payments_by_provider.ddl b/reports/payments_by_provider/report_payments_by_provider.ddl new file mode 100644 index 00000000..89224aed --- /dev/null +++ b/reports/payments_by_provider/report_payments_by_provider.ddl @@ -0,0 +1,16 @@ +create table report_payments_by_provider as select * from v_report_payments_by_provider limit 0; + +drop procedure if exists refresh_report_payments_by_provider; +DELIMITER // +CREATE PROCEDURE refresh_report_payments_by_provider() +BEGIN + +DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; +DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; + +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; +insert into report_payments_by_provider select * from v_report_payments_by_provider; + +END; +// +DELIMITER ; diff --git a/src/main/resources/reports/payments_by_provider/refresh_report_payments_by_provider_last_24h_summary.ddl b/reports/payments_by_provider/report_payments_by_provider_last_24h_summary.ddl similarity index 100% rename from src/main/resources/reports/payments_by_provider/refresh_report_payments_by_provider_last_24h_summary.ddl rename to reports/payments_by_provider/report_payments_by_provider_last_24h_summary.ddl diff --git a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub1.ddl b/reports/payments_by_provider/v_report_payments_by_provider.ddl similarity index 75% rename from src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub1.ddl rename to reports/payments_by_provider/v_report_payments_by_provider.ddl index abe3fc4c..2c075149 100644 --- a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub1.ddl +++ b/reports/payments_by_provider/v_report_payments_by_provider.ddl @@ -15,7 +15,7 @@ SELECT FROM analytics_payment_auths a FORCE INDEX(analytics_payment_auths_created_date) WHERE 1=1 -AND a.created_date>now() - interval '7' day +AND a.created_date>utc_timestamp() - interval '7' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -39,7 +39,7 @@ SELECT FROM analytics_payment_captures a FORCE INDEX(analytics_payment_captures_created_date) WHERE 1=1 -AND a.created_date>now() - interval '7' day +AND a.created_date>utc_timestamp() - interval '7' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -63,7 +63,7 @@ SELECT FROM analytics_payment_chargebacks a FORCE INDEX(analytics_payment_chargebacks_created_date) WHERE 1=1 -AND a.created_date>now() - interval '7' day +AND a.created_date>utc_timestamp() - interval '7' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -87,7 +87,7 @@ SELECT FROM analytics_payment_credits a FORCE INDEX(analytics_payment_credits_created_date) WHERE 1=1 -AND a.created_date>now() - interval '7' day +AND a.created_date>utc_timestamp() - interval '7' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -111,7 +111,7 @@ SELECT FROM analytics_payment_purchases a FORCE INDEX(analytics_payment_purchases_created_date) WHERE 1=1 -AND a.created_date>now() - interval '7' day +AND a.created_date>utc_timestamp() - interval '7' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -135,7 +135,7 @@ SELECT FROM analytics_payment_refunds a FORCE INDEX(analytics_payment_refunds_created_date) WHERE 1=1 -AND a.created_date>now() - interval '7' day +AND a.created_date>utc_timestamp() - interval '7' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -159,7 +159,7 @@ SELECT FROM analytics_payment_voids a FORCE INDEX(analytics_payment_voids_created_date) WHERE 1=1 -AND a.created_date>now() - interval '7' day +AND a.created_date>utc_timestamp() - interval '7' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -183,7 +183,7 @@ SELECT , a.converted_currency FROM analytics_payment_auths a WHERE 1=1 -AND a.created_date>now() - interval '1' day +AND a.created_date>utc_timestamp() - interval '1' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -206,7 +206,7 @@ SELECT , a.converted_currency FROM analytics_payment_captures a WHERE 1=1 -AND a.created_date>now() - interval '1' day +AND a.created_date>utc_timestamp() - interval '1' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -229,7 +229,7 @@ SELECT , a.converted_currency FROM analytics_payment_chargebacks a WHERE 1=1 -AND a.created_date>now() - interval '1' day +AND a.created_date>utc_timestamp() - interval '1' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -252,7 +252,7 @@ SELECT , a.converted_currency FROM analytics_payment_credits a WHERE 1=1 -AND a.created_date>now() - interval '1' day +AND a.created_date>utc_timestamp() - interval '1' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -275,7 +275,7 @@ SELECT , a.converted_currency FROM analytics_payment_purchases a WHERE 1=1 -AND a.created_date>now() - interval '1' day +AND a.created_date>utc_timestamp() - interval '1' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -298,7 +298,7 @@ SELECT , a.converted_currency FROM analytics_payment_refunds a WHERE 1=1 -AND a.created_date>now() - interval '1' day +AND a.created_date>utc_timestamp() - interval '1' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -321,7 +321,7 @@ SELECT , a.converted_currency FROM analytics_payment_voids a WHERE 1=1 -AND a.created_date>now() - interval '1' day +AND a.created_date>utc_timestamp() - interval '1' day GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -345,8 +345,8 @@ SELECT , a.converted_currency FROM analytics_payment_auths a WHERE 1=1 -AND a.created_date>now() - interval '34' minute -AND a.created_date<=now() - interval '4' minute +AND a.created_date>utc_timestamp() - interval '34' minute +AND a.created_date<=utc_timestamp() - interval '4' minute GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -369,8 +369,8 @@ SELECT , a.converted_currency FROM analytics_payment_captures a WHERE 1=1 -AND a.created_date>now() - interval '34' minute -AND a.created_date<=now() - interval '4' minute +AND a.created_date>utc_timestamp() - interval '34' minute +AND a.created_date<=utc_timestamp() - interval '4' minute GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -393,8 +393,8 @@ SELECT , a.converted_currency FROM analytics_payment_chargebacks a WHERE 1=1 -AND a.created_date>now() - interval '34' minute -AND a.created_date<=now() - interval '4' minute +AND a.created_date>utc_timestamp() - interval '34' minute +AND a.created_date<=utc_timestamp() - interval '4' minute GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -417,8 +417,8 @@ SELECT , a.converted_currency FROM analytics_payment_credits a WHERE 1=1 -AND a.created_date>now() - interval '34' minute -AND a.created_date<=now() - interval '4' minute +AND a.created_date>utc_timestamp() - interval '34' minute +AND a.created_date<=utc_timestamp() - interval '4' minute GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -441,8 +441,8 @@ SELECT , a.converted_currency FROM analytics_payment_purchases a WHERE 1=1 -AND a.created_date>now() - interval '34' minute -AND a.created_date<=now() - interval '4' minute +AND a.created_date>utc_timestamp() - interval '34' minute +AND a.created_date<=utc_timestamp() - interval '4' minute GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -465,8 +465,8 @@ SELECT , a.converted_currency FROM analytics_payment_refunds a WHERE 1=1 -AND a.created_date>now() - interval '34' minute -AND a.created_date<=now() - interval '4' minute +AND a.created_date>utc_timestamp() - interval '34' minute +AND a.created_date<=utc_timestamp() - interval '4' minute GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -489,8 +489,8 @@ SELECT , a.converted_currency FROM analytics_payment_voids a WHERE 1=1 -AND a.created_date>now() - interval '34' minute -AND a.created_date<=now() - interval '4' minute +AND a.created_date>utc_timestamp() - interval '34' minute +AND a.created_date<=utc_timestamp() - interval '4' minute GROUP BY a.plugin_name , ifnull(a.plugin_property_4,'unknown') @@ -498,3 +498,99 @@ GROUP BY , a.converted_currency , a.tenant_record_id ; + + +create or replace view v_report_payments_by_provider_sub2 as +select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_auths force index(analytics_payment_auths_date_trid_plugin_name) where created_date > utc_timestamp() - interval '7' day +union +select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_captures force index(analytics_payment_captures_date_trid_plugin_name) where created_date > utc_timestamp() - interval '7' day +union +select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_chargebacks force index(analytics_payment_chargebacks_date_trid_plugin_name) where created_date > utc_timestamp() - interval '7' day +union +select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_credits force index(analytics_payment_credits_date_trid_plugin_name) where created_date > utc_timestamp() - interval '7' day +union +select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_purchases force index(analytics_payment_purchases_date_trid_plugin_name) where created_date > utc_timestamp() - interval '7' day +union +select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_refunds force index(analytics_payment_refunds_date_trid_plugin_name) where created_date > utc_timestamp() - interval '7' day +union +select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_voids force index(analytics_payment_voids_date_trid_plugin_name) where created_date > utc_timestamp() - interval '7' day +; + +create or replace view v_report_payments_by_provider_sub3 as +select 1 as timeframe union +select 2 as timeframe union +select 3 as timeframe union +select 4 as timeframe +; + +create or replace view v_report_payments_by_provider as +SELECT + t1.plugin_name +, t1.merchant_account +, t1.payment_method +, t1.tenant_record_id +, t2.timeframe +, transaction_type +, case when t2.timeframe=1 then 'Last 30 days' + when t2.timeframe=2 then 'Last 7 days' + when t2.timeframe=3 then 'Last 24 hours' + when t2.timeframe=4 then 'Last 30 min' + end as period +, sum(ifnull(total,0)) as total +, sum(ifnull(failed,0)) as failed +, sum(ifnull(pending,0)) as pending +, sum(ifnull(good,0)) as good +, case when sum(failed) is not null and sum(total) is not null + then concat(round(((sum(failed)/sum(total))*100),2),'%') + else '0%' + end as pct_failed +, case when sum(pending) is not null and sum(total) is not null + then concat(round(((sum(pending)/sum(total))*100),2),'%') + else '0%' + end as pct_pending +, case when sum(good) is not null and sum(total) is not null + then concat(round(((sum(good)/sum(total))*100),2),'%') + else '0%' + end as pct_good +, sum(ifnull(v1.converted_amount,0)) as converted_amount +, t1.converted_currency +, CAST(sysdate() AS DATETIME) as refresh_date -- ✅ cast to DATETIME +FROM v_report_payments_by_provider_sub2 t1 +INNER JOIN v_report_payments_by_provider_sub3 t2 +LEFT OUTER JOIN v_report_payments_by_provider_sub1 v1 + on v1.plugin_name = t1.plugin_name + and v1.merchant_account = t1.merchant_account + and v1.payment_method = t1.payment_method + and v1.timeframe = t2.timeframe + and v1.converted_currency = t1.converted_currency + and v1.tenant_record_id = t1.tenant_record_id +GROUP BY + t1.plugin_name +, t1.merchant_account +, t1.payment_method +, t2.timeframe +, transaction_type +, t1.converted_currency +, t1.tenant_record_id +ORDER BY + t1.tenant_record_id +, t1.merchant_account +, t1.payment_method +, t1.plugin_name +, t2.timeframe +, transaction_type +, t1.converted_currency +; + + +create or replace view v_report_payments_by_provider_last_24h_summary as +select + tenant_record_id +, payment_method as label +, sum(total) as count +from v_report_payments_by_provider +where 1 = 1 +and timeframe = 3 +and transaction_type in ('AUTHORIZE', 'PURCHASE') +group by 1,2 +; \ No newline at end of file diff --git a/reports/reports_setup.sh b/reports/reports_setup.sh index 7851913b..319aff8d 100644 --- a/reports/reports_setup.sh +++ b/reports/reports_setup.sh @@ -116,6 +116,8 @@ create_all_reports() { "bundles_summary|Bundles Summary|TABLE|report_bundles_summary|refresh_report_bundles_summary" "cancellations_daily|Cancellations Daily|TIMELINE|report_cancellations_daily|refresh_report_cancellations_daily" "chargebacks_daily|Chargebacks Daily|TIMELINE|report_chargebacks_daily|refresh_report_chargebacks_daily" + "churn_percent|Churn Percent|TIMELINE|report_churn_percent|refresh_report_churn_percent" + "churn_amount|Churn Total USD|TIMELINE|report_churn_total_usd|refresh_report_churn_total_usd" "conversion-total-dollar-amount|Conversions Daily|TIMELINE|report_conversions_daily|refresh_report_conversions_daily" "invoice_aging|Invoice Aging|TABLE|report_invoice_aging|refresh_report_invoice_aging" "invoice_aging_no_payments_monthly|Invoice Aging No Payments|TABLE|report_invoice_aging_no_payment|refresh_report_invoice_aging_no_payment" @@ -130,6 +132,11 @@ create_all_reports() { "mrr_daily|MRR|TIMELINE|report_mrr_daily|refresh_report_mrr_daily" "new_accounts_daily|New Accounts Daily|TIMELINE|report_new_accounts_daily|refresh_report_new_accounts_daily" "overdue_states_count_daily|Overdue States Count|TIMELINE|report_overdue_states_count_daily|refresh_report_overdue_states_count_daily" + "payment_provider_conversions|Payment Provider Conversions|TABLE|report_payment_provider_conversions|refresh_payment_provider_conversions" + "payment_provider_errors|Payment Provider Errors|TIMELINE|report_payment_provider_errors|refresh_report_payment_provider_errors" + "payment_provider_monitor|Payment Provider Monitor|TABLE|report_payment_provider_monitor|refresh_payment_provider_monitor" + "payments_by_provider|Payments By Provider|TABLE|report_payments_by_provider|refresh_report_payments_by_provider" + "payments_by_provider_summary_last_24_hr_|Payments By Provider Summary (Last 24hrs)|COUNTERS|report_payments_by_provider_last_24h_summary|refresh_report_payments_by_provider_last_24h_summary" "payments_monthly|Payments Monthly|TABLE|report_payments_monthly|refresh_report_payments_monthly" "payments_summary|Payments Summary|TABLE|report_payments_summary|refresh_report_payments_summary" "payments_total_daily|Payment Total Daily|TIMELINE|report_payments_total_daily|refresh_report_payments_total_daily" diff --git a/reports/utils/README.md b/reports/utils/README.md index b726c0da..b5994900 100644 --- a/reports/utils/README.md +++ b/reports/utils/README.md @@ -50,10 +50,13 @@ Suppose the `analytics_currency_conversion` table has the conversion rates for A | 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: + +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 | diff --git a/src/main/resources/reports/payment_provider_conversion/refresh_report_payment_provider_conversion_history.ddl b/src/main/resources/reports/payment_provider_conversion/refresh_report_payment_provider_conversion_history.ddl deleted file mode 100644 index a63fee42..00000000 --- a/src/main/resources/reports/payment_provider_conversion/refresh_report_payment_provider_conversion_history.ddl +++ /dev/null @@ -1,16 +0,0 @@ -create table report_payment_provider_conversion_history as select * from v_report_payment_provider_conversion limit 0; - -drop procedure if exists refresh_report_payment_provider_conversion_history; -DELIMITER // -CREATE PROCEDURE refresh_report_payment_provider_conversion_history() -BEGIN - -DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; -DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; - -SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -insert into report_payment_provider_conversion_history select * from v_report_payment_provider_conversion; - -END; -// -DELIMITER ; diff --git a/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion.ddl b/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion.ddl deleted file mode 100644 index 973cdbb4..00000000 --- a/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion.ddl +++ /dev/null @@ -1,37 +0,0 @@ -create or replace view v_report_payment_provider_conversion as -select - rpccs1.plugin_name -, rpccs1.merchant_account -, rpccs1.payment_method -, rpccs1.tenant_record_id -, ifnull(sum(rpccs1.current_success_count),0) as current_success_count -, ifnull(sum(rpccs1.current_transaction_count),0) as current_transaction_count -, ifnull(sum(rpccs1.current_customer_count),0) as current_customer_count -, ifnull(sum(rpccs2.historical_success_count),0) as historical_success_count -, ifnull(sum(rpccs2.historical_transaction_count),0) as historical_transaction_count -, ifnull(sum(rpccs2.historical_customer_count),0) as historical_customer_count -, case when current_success_count is not null and historical_success_count is not null - then concat(round((((sum(rpccs1.current_success_count)-sum(rpccs2.historical_success_count))/sum(rpccs2.historical_success_count))*100),2),'%') - else '0%' - end success_delta -, case when current_transaction_count is not null and historical_transaction_count is not null - then concat(round((((sum(rpccs1.current_transaction_count)-sum(rpccs2.historical_transaction_count))/sum(rpccs2.historical_transaction_count))*100),2),'%') - else '0%' - end transaction_delta -, case when current_customer_count is not null and historical_customer_count is not null - then concat(round((((sum(rpccs1.current_customer_count)-sum(rpccs2.historical_customer_count))/sum(rpccs2.historical_customer_count))*100),2),'%') - else '0%' - end customer_delta -, sysdate() as refresh_date -from v_report_payment_provider_conversion_sub2 rpccs2 -LEFT OUTER JOIN v_report_payment_provider_conversion_sub1 rpccs1 ON - rpccs1.plugin_name=rpccs2.plugin_name -AND rpccs1.merchant_account=rpccs2.merchant_account -AND rpccs1.payment_method=rpccs2.payment_method -AND rpccs1.tenant_record_id=rpccs2.tenant_record_id -GROUP BY - plugin_name -, merchant_account -, payment_method -, tenant_record_id -; diff --git a/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion_sub1.ddl b/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion_sub1.ddl deleted file mode 100644 index 21697b0f..00000000 --- a/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion_sub1.ddl +++ /dev/null @@ -1,39 +0,0 @@ -create or replace view v_report_payment_provider_conversion_sub1 as -SELECT - apa.plugin_name -, ifnull(apa.plugin_property_4,'unknown') as merchant_account -, ifnull(apa.plugin_property_5,'unknown') as payment_method -, apa.tenant_record_id -, sum(case when apa.payment_transaction_status='SUCCESS' then 1 else 0 end) as current_success_count -, count(1) as current_transaction_count -, count(distinct apa.account_id) as current_customer_count -FROM - analytics_payment_auths apa -WHERE 1=1 -AND apa.created_date >= FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60)%(15*60)) -AND cast(FROM_UNIXTIME(UNIX_TIMESTAMP(apa.created_date) - UNIX_TIMESTAMP(apa.created_date)%(15*60)) as time) = cast(FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60 - (UNIX_TIMESTAMP(NOW()) - 15*60)%(15*60)) as time) -GROUP BY - apa.plugin_name -, ifnull(apa.plugin_property_4,'unknown') -, ifnull(apa.plugin_property_5,'unknown') -, apa.tenant_record_id -UNION -SELECT - app.plugin_name -, ifnull(app.plugin_property_4,'unknown') as merchant_account -, ifnull(app.plugin_property_5,'unknown') as payment_method -, app.tenant_record_id -, sum(case when app.payment_transaction_status='SUCCESS' then 1 else 0 end) as current_success_count -, count(1) as current_transaction_count -, count(distinct app.account_id) as current_customer_count -FROM - analytics_payment_purchases app -WHERE 1=1 -AND app.created_date >= FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60)%(15*60)) -AND cast(FROM_UNIXTIME(UNIX_TIMESTAMP(app.created_date) - UNIX_TIMESTAMP(app.created_date)%(15*60)) as time) = cast(FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP()) - 15*60 - (UNIX_TIMESTAMP(NOW()) - 15*60)%(15*60)) as time) -GROUP BY - app.plugin_name -, ifnull(app.plugin_property_4,'unknown') -, ifnull(app.plugin_property_5,'unknown') -, app.tenant_record_id -; diff --git a/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion_sub2.ddl b/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion_sub2.ddl deleted file mode 100644 index 21b2fdf4..00000000 --- a/src/main/resources/reports/payment_provider_conversion/v_report_payment_provider_conversion_sub2.ddl +++ /dev/null @@ -1,41 +0,0 @@ -create or replace view v_report_payment_provider_conversion_sub2 as -SELECT - apa.plugin_name -, ifnull(apa.plugin_property_4,'unknown') as merchant_account -, ifnull(apa.plugin_property_5,'unknown') as payment_method -, apa.tenant_record_id -, sum(case when apa.payment_transaction_status='SUCCESS' then 1 else 0 end) as historical_success_count -, count(1) as historical_transaction_count -, count(distinct apa.account_id) as historical_customer_count -FROM - analytics_payment_auths apa -WHERE 1=1 -AND apa.created_date < FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60) + 15*60) -AND cast(FROM_UNIXTIME(UNIX_TIMESTAMP(apa.created_date) - UNIX_TIMESTAMP(apa.created_date)%(15*60)) as time) = cast(FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60)) as time) -AND apa.created_date >= FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60)) -GROUP BY - apa.plugin_name -, ifnull(apa.plugin_property_4,'unknown') -, ifnull(apa.plugin_property_5,'unknown') -, apa.tenant_record_id -UNION -SELECT - app.plugin_name -, ifnull(app.plugin_property_4,'unknown') as merchant_account -, ifnull(app.plugin_property_5,'unknown') as payment_method -, app.tenant_record_id -, sum(case when app.payment_transaction_status='SUCCESS' then 1 else 0 end) as historical_success_count -, count(1) as historical_transaction_count -, count(distinct app.account_id) as historical_customer_count -FROM - analytics_payment_purchases app -WHERE 1=1 -AND app.created_date < FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60) + 15*60) -AND cast(FROM_UNIXTIME(UNIX_TIMESTAMP(app.created_date) - UNIX_TIMESTAMP(app.created_date)%(15*60)) as time) = cast(FROM_UNIXTIME(UNIX_TIMESTAMP(NOW() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60)) as time) -AND app.created_date >= FROM_UNIXTIME(UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60 - (UNIX_TIMESTAMP(UTC_TIMESTAMP() - interval '14' day) - 15*60)%(15*60)) -GROUP BY - app.plugin_name -, ifnull(app.plugin_property_4,'unknown') -, ifnull(app.plugin_property_5,'unknown') -, app.tenant_record_id -; diff --git a/src/main/resources/reports/payment_provider_errors/report_payment_provider_errors.ddl b/src/main/resources/reports/payment_provider_errors/report_payment_provider_errors.ddl deleted file mode 100644 index 3b499733..00000000 --- a/src/main/resources/reports/payment_provider_errors/report_payment_provider_errors.ddl +++ /dev/null @@ -1,42 +0,0 @@ -create table report_payment_provider_errors_sub2 as select * from v_report_payment_provider_errors_sub2 limit 0; -create table report_payment_provider_errors as select * from v_report_payment_provider_errors limit 0; - -drop procedure if exists refresh_report_payment_provider_errors; -DELIMITER // -CREATE PROCEDURE refresh_report_payment_provider_errors() -BEGIN - -DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; -DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; - -SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - -START TRANSACTION; - delete from report_payment_provider_errors_sub2; - insert into report_payment_provider_errors_sub2 select * from v_report_payment_provider_errors_sub2; - - delete from report_payment_provider_errors; - insert into report_payment_provider_errors - select - tenant_record_id - , day - , currency - , plugin_name - , plugin_gateway_error - , count - from report_payment_provider_errors_sub2 sub2 - where ( - select count(*) from report_payment_provider_errors_sub2 as sub21 - where 1=1 - and sub21.tenant_record_id = sub2.tenant_record_id - and sub21.day = sub2.day - and sub21.currency = sub2.currency - and sub21.plugin_name = sub2.plugin_name - and sub21.count >= sub2.count - ) <= 3 - ; -COMMIT; - -END; -// -DELIMITER ; diff --git a/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors.ddl b/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors.ddl deleted file mode 100644 index 0103dd5e..00000000 --- a/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors.ddl +++ /dev/null @@ -1,19 +0,0 @@ -create or replace view v_report_payment_provider_errors as -select - tenant_record_id -, day -, currency -, plugin_name -, plugin_gateway_error -, count -from v_report_payment_provider_errors_sub2 sub2 -where ( - select count(*) from v_report_payment_provider_errors_sub2 as sub21 - where 1=1 - and sub21.tenant_record_id = sub2.tenant_record_id - and sub21.day = sub2.day - and sub21.currency = sub2.currency - and sub21.plugin_name = sub2.plugin_name - and sub21.count >= sub2.count -) <= 3 -; diff --git a/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors_sub1.ddl b/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors_sub1.ddl deleted file mode 100644 index 7b650b13..00000000 --- a/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors_sub1.ddl +++ /dev/null @@ -1,27 +0,0 @@ -create or replace view v_report_payment_provider_errors_sub1 as -select - aa.tenant_record_id -, 'AUTH' as op -, date_format(aa.created_date,'%Y-%m-%d') as day -, aa.currency -, aa.plugin_name -, aa.record_id -from analytics_payment_auths aa -where 1=1 - and aa.payment_transaction_status not in ('PENDING', 'SUCCESS') - and aa.report_group = 'default' - and aa.created_date > now() - interval '60' day -union -select - ap.tenant_record_id -, 'PURCHASE' as op -, date_format(ap.created_date,'%Y-%m-%d') as day -, ap.currency -, ap.plugin_name -, ap.record_id -from analytics_payment_purchases ap -where 1=1 - and ap.payment_transaction_status not in ('PENDING', 'SUCCESS') - and ap.report_group = 'default' - and ap.created_date > now() - interval '60' day -; diff --git a/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors_sub2.ddl b/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors_sub2.ddl deleted file mode 100644 index d887f621..00000000 --- a/src/main/resources/reports/payment_provider_errors/v_report_payment_provider_errors_sub2.ddl +++ /dev/null @@ -1,15 +0,0 @@ -create or replace view v_report_payment_provider_errors_sub2 as -select - v1.tenant_record_id -, v1.day -, v1.currency -, v1.plugin_name -, substring_index(ifnull(apa.plugin_gateway_error, app.plugin_gateway_error), ' ', 10) as plugin_gateway_error -, count(1) as count -from v_report_payment_provider_errors_sub1 v1 -left join analytics_payment_auths apa on apa.record_id = v1.record_id and v1.op = 'AUTH' -left join analytics_payment_purchases app on app.record_id = v1.record_id and v1.op = 'PURCHASE' -where 1=1 -and ifnull(apa.plugin_gateway_error, app.plugin_gateway_error) is not null -group by 1,2,3,4,5 -; diff --git a/src/main/resources/reports/payment_provider_monitor/refresh_report_payment_provider_monitor_history.ddl b/src/main/resources/reports/payment_provider_monitor/refresh_report_payment_provider_monitor_history.ddl deleted file mode 100644 index 20c5a9c0..00000000 --- a/src/main/resources/reports/payment_provider_monitor/refresh_report_payment_provider_monitor_history.ddl +++ /dev/null @@ -1,16 +0,0 @@ -create table report_payment_provider_monitor_history as select * from v_report_payment_provider_monitor limit 0; - -drop procedure if exists refresh_report_payment_provider_monitor_history; -DELIMITER // -CREATE PROCEDURE refresh_report_payment_provider_monitor_history() -BEGIN - -DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; -DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; - -SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -insert into report_payment_provider_monitor_history select * from v_report_payment_provider_monitor; - -END; -// -DELIMITER ; diff --git a/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor.ddl b/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor.ddl deleted file mode 100644 index 983e044f..00000000 --- a/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor.ddl +++ /dev/null @@ -1,16 +0,0 @@ -create or replace view v_report_payment_provider_monitor as -SELECT - plugin_list.plugin_name -, plugin_list.merchant_account -, plugin_list.payment_method -, plugin_list.tenant_record_id -, ifnull(recent_success_trx.success_count_last_hour,0) as success_count_last_hour -, ifnull(recent_success_trx.success_count_last_12_hours,0) as success_count_last_12_hours -, sysdate() as refresh_date -FROM v_report_payment_provider_monitor_sub1 plugin_list -LEFT OUTER JOIN v_report_payment_provider_monitor_sub3 recent_success_trx on - plugin_list.plugin_name=recent_success_trx.plugin_name -AND plugin_list.merchant_account=recent_success_trx.merchant_account -AND plugin_list.payment_method=recent_success_trx.payment_method -AND plugin_list.tenant_record_id=recent_success_trx.tenant_record_id -; diff --git a/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub1.ddl b/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub1.ddl deleted file mode 100644 index 10baac09..00000000 --- a/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub1.ddl +++ /dev/null @@ -1,19 +0,0 @@ -create or replace view v_report_payment_provider_monitor_sub1 as -SELECT distinct - apa.plugin_name -, ifnull(apa.plugin_property_4,'unknown') as merchant_account -, ifnull(apa.plugin_property_5,'unknown') as payment_method -, apa.tenant_record_id -FROM analytics_payment_auths apa -WHERE 1=1 -AND apa.created_date > now() - interval '7' day -UNION -SELECT distinct - app.plugin_name -, ifnull(app.plugin_property_4,'unknown') as merchant_account -, ifnull(app.plugin_property_5,'unknown') as payment_method -, app.tenant_record_id -FROM analytics_payment_purchases app -WHERE 1=1 -AND app.created_date > now() - interval '7' day -; diff --git a/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub2.ddl b/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub2.ddl deleted file mode 100644 index d2306067..00000000 --- a/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub2.ddl +++ /dev/null @@ -1,35 +0,0 @@ -create or replace view v_report_payment_provider_monitor_sub2 as -SELECT - apa.plugin_name -, ifnull(apa.plugin_property_4,'unknown') as merchant_account -, ifnull(apa.plugin_property_5,'unknown') as payment_method -, apa.tenant_record_id -, sum(case when apa.created_date > now() - interval 1 hour then 1 else 0 end) success_count_last_hour -, count(1) success_count_last_12_hours -FROM analytics_payment_auths apa -WHERE 1=1 -AND apa.payment_transaction_status = 'SUCCESS' -AND apa.created_date > now() - interval '12' hour -GROUP BY - apa.plugin_name -, ifnull(apa.plugin_property_4,'unknown') -, ifnull(apa.plugin_property_5,'unknown') -, apa.tenant_record_id -UNION -SELECT - app.plugin_name -, ifnull(app.plugin_property_4,'unknown') as merchant_account -, ifnull(app.plugin_property_5,'unknown') as payment_method -, app.tenant_record_id -, sum(case when app.created_date > now() - interval 1 hour then 1 else 0 end) success_count_last_hour -, count(1) success_count_last_12_hours -FROM analytics_payment_purchases app -WHERE 1=1 -AND app.payment_transaction_status = 'SUCCESS' -AND app.created_date > now() - interval '12' hour -GROUP BY - app.plugin_name -, ifnull(app.plugin_property_4,'unknown') -, ifnull(app.plugin_property_5,'unknown') -, app.tenant_record_id -; diff --git a/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub3.ddl b/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub3.ddl deleted file mode 100644 index 3c4b8697..00000000 --- a/src/main/resources/reports/payment_provider_monitor/v_report_payment_provider_monitor_sub3.ddl +++ /dev/null @@ -1,15 +0,0 @@ -create or replace view v_report_payment_provider_monitor_sub3 as -SELECT - plugin_name -, merchant_account -, payment_method -, tenant_record_id -, sum(ifnull(success_count_last_hour,0)) as success_count_last_hour -, sum(ifnull(success_count_last_12_hours,0)) as success_count_last_12_hours -FROM v_report_payment_provider_monitor_sub2 t2 -GROUP BY - plugin_name -, merchant_account -, payment_method -, tenant_record_id -; diff --git a/src/main/resources/reports/payments_by_provider/refresh_report_payments_by_provider_history.ddl b/src/main/resources/reports/payments_by_provider/refresh_report_payments_by_provider_history.ddl deleted file mode 100644 index cf6b7c89..00000000 --- a/src/main/resources/reports/payments_by_provider/refresh_report_payments_by_provider_history.ddl +++ /dev/null @@ -1,16 +0,0 @@ -create table report_payments_by_provider_history as select * from v_report_payments_by_provider limit 0; - -drop procedure if exists refresh_report_payments_by_provider_history; -DELIMITER // -CREATE PROCEDURE refresh_report_payments_by_provider_history() -BEGIN - -DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; -DECLARE EXIT HANDLER FOR SQLWARNING ROLLBACK; - -SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -insert into report_payments_by_provider_history select * from v_report_payments_by_provider; - -END; -// -DELIMITER ; diff --git a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider.ddl b/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider.ddl deleted file mode 100644 index 3184a98a..00000000 --- a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider.ddl +++ /dev/null @@ -1,54 +0,0 @@ -create or replace view v_report_payments_by_provider as -SELECT - t1.plugin_name -, t1.merchant_account -, t1.payment_method -, t1.tenant_record_id -, t2.timeframe -, transaction_type -, case when t2.timeframe=1 then 'Last 30 days' - when t2.timeframe=2 then 'Last 7 days' - when t2.timeframe=3 then 'Last 24 hours' - when t2.timeframe=4 then 'Last 30 min' - end as period -, sum(ifnull(total,0)) as total -, sum(ifnull(failed,0)) as failed -, sum(ifnull(pending,0)) as pending -, sum(ifnull(good,0)) as good -, case when failed is not null and total is not null then concat(round(((sum(failed)/sum(total))*100),2),'%') - else '0%' - end as pct_failed -, case when failed is not null and total is not null then concat(round(((sum(pending)/sum(total))*100),2),'%') - else '0%' - end as pct_pending -, case when failed is not null and total is not null then concat(round(((sum(good)/sum(total))*100),2),'%') - else '0%' - end as pct_good -, converted_amount -, t1.converted_currency -, sysdate() as refresh_date -FROM v_report_payments_by_provider_sub2 t1 -INNER JOIN v_report_payments_by_provider_sub3 t2 -LEFT OUTER JOIN v_report_payments_by_provider_sub1 v1 on v1.plugin_name=t1.plugin_name -AND v1.merchant_account=t1.merchant_account -AND v1.payment_method=t1.payment_method -AND v1.timeframe=t2.timeframe -AND v1.converted_currency=t1.converted_currency -AND v1.tenant_record_id=t1.tenant_record_id -GROUP BY - plugin_name -, merchant_account -, payment_method -, timeframe -, transaction_type -, converted_currency -, tenant_record_id -ORDER BY - tenant_record_id -, merchant_account -, payment_method -, plugin_name -, timeframe -, transaction_type -, converted_currency -; diff --git a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_last_24h_summary.ddl b/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_last_24h_summary.ddl deleted file mode 100644 index 85a234a0..00000000 --- a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_last_24h_summary.ddl +++ /dev/null @@ -1,11 +0,0 @@ -create or replace view v_report_payments_by_provider_last_24h_summary as -select - tenant_record_id -, payment_method as label -, sum(total) as count -from v_report_payments_by_provider -where 1 = 1 -and timeframe = 3 -and transaction_type in ('AUTHORIZE', 'PURCHASE') -group by 1,2 -; diff --git a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub2.ddl b/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub2.ddl deleted file mode 100644 index e21931b7..00000000 --- a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub2.ddl +++ /dev/null @@ -1,15 +0,0 @@ -create or replace view v_report_payments_by_provider_sub2 as -select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_auths force index(analytics_payment_auths_date_trid_plugin_name) where created_date > now() - interval '7' day -union -select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_captures force index(analytics_payment_captures_date_trid_plugin_name) where created_date > now() - interval '7' day -union -select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_chargebacks force index(analytics_payment_chargebacks_date_trid_plugin_name) where created_date > now() - interval '7' day -union -select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_credits force index(analytics_payment_credits_date_trid_plugin_name) where created_date > now() - interval '7' day -union -select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_purchases force index(analytics_payment_purchases_date_trid_plugin_name) where created_date > now() - interval '7' day -union -select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_refunds force index(analytics_payment_refunds_date_trid_plugin_name) where created_date > now() - interval '7' day -union -select distinct plugin_name,ifnull(plugin_property_4,'unknown') as merchant_account,ifnull(plugin_property_5,'unknown') as payment_method,converted_currency,tenant_record_id from analytics_payment_voids force index(analytics_payment_voids_date_trid_plugin_name) where created_date > now() - interval '7' day -; diff --git a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub3.ddl b/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub3.ddl deleted file mode 100644 index f743cd15..00000000 --- a/src/main/resources/reports/payments_by_provider/v_report_payments_by_provider_sub3.ddl +++ /dev/null @@ -1,3 +0,0 @@ -create or replace view v_report_payments_by_provider_sub3 as -select 1 as timeframe union select 2 as timeframe union select 3 as timeframe union select 4 as timeframe -; \ No newline at end of file