From 8456ea78f81ec103ef86221fd6aaa5991563a322 Mon Sep 17 00:00:00 2001 From: Mohammed Sohail Date: Fri, 26 Aug 2022 07:23:26 +0000 Subject: [PATCH] patch: cameroon specific dashboard queries --- config.toml | 1 + internal/dashboard/charts.go | 37 ++++++++++++++++++++++++++-------- queries/dashboard.sql | 39 ++++++++++++++++++++++++++++++++++++ 3 files changed, 69 insertions(+), 8 deletions(-) diff --git a/config.toml b/config.toml index f3f9ca8..fb09986 100644 --- a/config.toml +++ b/config.toml @@ -8,6 +8,7 @@ cors = [ "https://dashboard.sarafu.network", "https://dashboard.grassecon.org", "https://dashboard.grassrootseconomics.org", + "https://dashboard.localvoucherscameroon.org", "http://localhost:3000" ] diff --git a/internal/dashboard/charts.go b/internal/dashboard/charts.go index 4cd4b89..982534e 100644 --- a/internal/dashboard/charts.go +++ b/internal/dashboard/charts.go @@ -7,6 +7,7 @@ import ( "time" "github.com/georgysavva/scany/pgxscan" + "github.com/jackc/pgx/v4" "github.com/labstack/echo/v4" ) @@ -18,15 +19,25 @@ type lineChartRes struct { func handleNewRegistrations(c echo.Context) error { var ( api = c.Get("api").(*api) + qP = c.QueryParams() + rows pgx.Rows + err error data []lineChartRes ) - from, to := date_range.ParseDateRange(c.QueryParams()) + from, to := date_range.ParseDateRange(qP) - rows, err := api.db.Query(context.Background(), api.q["new-user-registrations"], from, to) - if err != nil { - return err + if qP.Get("country") == "cmr" { + rows, err = api.db.Query(context.Background(), api.q["new-user-registrations-cmr"], from, to) + if err != nil { + return err + } + } else { + rows, err = api.db.Query(context.Background(), api.q["new-user-registrations"], from, to) + if err != nil { + return err + } } if err := pgxscan.ScanAll(&data, rows); err != nil { @@ -39,15 +50,25 @@ func handleNewRegistrations(c echo.Context) error { func handleTransactionsCount(c echo.Context) error { var ( api = c.Get("api").(*api) + qP = c.QueryParams() + rows pgx.Rows + err error data []lineChartRes ) - from, to := date_range.ParseDateRange(c.QueryParams()) + from, to := date_range.ParseDateRange(qP) - rows, err := api.db.Query(context.Background(), api.q["transactions-count"], from, to) - if err != nil { - return err + if qP.Get("country") == "cmr" { + rows, err = api.db.Query(context.Background(), api.q["transactions-count-cmr"], from, to) + if err != nil { + return err + } + } else { + rows, err = api.db.Query(context.Background(), api.q["transactions-count"], from, to) + if err != nil { + return err + } } if err := pgxscan.ScanAll(&data, rows); err != nil { diff --git a/queries/dashboard.sql b/queries/dashboard.sql index 81e11e4..8fba96b 100644 --- a/queries/dashboard.sql +++ b/queries/dashboard.sql @@ -12,6 +12,22 @@ GROUP BY date_range.day ORDER BY date_range.day LIMIT 730; +-- name: new-user-registrations-cmr +-- This is a patch to support CMR dashboard +-- This query generates a date range and left joins the users table to include days with no registrations +-- Produces x, y results for displaying on a line chart +WITH date_range AS ( + SELECT day::date FROM generate_series('08-01-2022', '08-26-2022', INTERVAL '1 day') day +) + +SELECT date_range.day AS x, COUNT(users.id) AS y +FROM date_range +LEFT JOIN users ON date_range.day = CAST(users.date_registered AS date) +WHERE users.phone_number LIKE '237%' +GROUP BY date_range.day +ORDER BY date_range.day +LIMIT 730; + -- name: transactions-count -- This query generates a date range and left joins the transactions table to include days with no transactions -- Produces x, y results for displaying on a line chart @@ -31,6 +47,29 @@ GROUP BY date_range.day ORDER BY date_range.day LIMIT 730; +-- name: transaction-count-cmr +-- This is a patch to support CMR dashboard +-- This query generates a date range and left joins the transactions table to include days with no transactions +-- Produces x, y results for displaying on a line chart +WITH date_range AS ( + SELECT day::date FROM generate_series('08-01-2022', '08-26-2022', INTERVAL '1 day') day +), +exclude AS ( + SELECT sys_address FROM sys_accounts WHERE sys_address IS NOT NULL +), +cmr_tokens AS ( + SELECT token_address from tokens WHERE token_symbol IN ('MBIP') +) +SELECT date_range.day AS x, COUNT(transactions.id) AS y +FROM date_range +LEFT JOIN transactions ON date_range.day = CAST(transactions.date_block AS date) +AND transactions.sender_address NOT IN (SELECT sys_address FROM exclude) AND transactions.recipient_address NOT IN (SELECT sys_address FROM exclude) +AND transactions.success = true +AND transactions.token_address IN (SELECT token_address FROM cmr_tokens) +GROUP BY date_range.day +ORDER BY date_range.day +LIMIT 730; + -- name: token-transactions-count -- This query gets transactions for a specific token for a given date range WITH date_range AS (