diff --git a/batch/script/daily_report.py b/batch/script/daily_report.py index 63384a8c..6a4a8c96 100644 --- a/batch/script/daily_report.py +++ b/batch/script/daily_report.py @@ -1,4 +1,5 @@ import os +from datetime import datetime from os import environ import schedule @@ -20,7 +21,7 @@ mycroft_db = DatabaseConnectionConfig( def build_report(): with connect_to_db(mycroft_db) as db: - user_metrics = AccountRepository(db).daily_report() + user_metrics = AccountRepository(db).daily_report(datetime.now()) email = EmailMessage( sender='reports@mycroft.ai', diff --git a/shared/selene/data/account/repository/account.py b/shared/selene/data/account/repository/account.py index dd379b1d..0ab79484 100644 --- a/shared/selene/data/account/repository/account.py +++ b/shared/selene/data/account/repository/account.py @@ -1,3 +1,4 @@ +from datetime import datetime, timedelta from logging import getLogger from os import environ @@ -193,20 +194,25 @@ class AccountRepository(RepositoryBase): ) self.cursor.delete(db_request) - def daily_report(self): + def daily_report(self, date: datetime): + base = date - timedelta(days=1) + end_date = base.strftime('%Y-%m-%d') + start_date_1_day = (base - timedelta(days=1)).strftime('%Y-%m-%d') + start_date_15_days = (base - timedelta(days=15)).strftime('%Y-%m-%d') + start_date_30_days = (base - timedelta(days=30)).strftime('%Y-%m-%d') db_request = self._build_db_request( sql_file_name='daily_report.sql', - args=dict(start='1 DAY') + args=dict(start_date=start_date_1_day, end_date=end_date) ) report_1_day = self.cursor.select_one(db_request) db_request = self._build_db_request( sql_file_name='daily_report.sql', - args=dict(start='15 DAY') + args=dict(start_date=start_date_15_days, end_date=end_date) ) report_15_days = self.cursor.select_one(db_request) db_request = self._build_db_request( sql_file_name='daily_report.sql', - args=dict(start='30 DAY') + args=dict(start_date=start_date_30_days, end_date=end_date) ) report_30_days = self.cursor.select_one(db_request) @@ -224,14 +230,17 @@ class AccountRepository(RepositoryBase): 'thirtyDaysMinus': 0 }, { 'type': 'Free Account', - 'current': report_1_day['free_total'], - 'oneDay': report_1_day['free_total'] - report_1_day['total_new'] + report_1_day['paid_new'], + 'current': report_1_day['total'] - report_1_day['paid_total'], + 'oneDay': report_1_day['total'] - report_1_day['paid_total'] - report_1_day['total_new'] + report_1_day[ + 'paid_new'], 'oneDayDelta': report_1_day['total_new'] - report_1_day['paid_new'], 'oneDayMinus': 0, - 'fifteenDays': report_15_days['free_total'] - report_15_days['total_new'] + report_15_days['paid_new'], + 'fifteenDays': report_15_days['total'] - report_15_days['paid_total'] - report_15_days['total_new'] + + report_15_days['paid_new'], 'fifteenDaysDelta': report_15_days['total_new'] - report_15_days['paid_new'], 'fifteenDaysMinus': 0, - 'thirtyDays': report_30_days['free_total'] - report_30_days['total_new'] + report_30_days['paid_new'], + 'thirtyDays': report_30_days['total'] - report_30_days['paid_total'] - report_30_days['total_new'] + + report_30_days['paid_new'], 'thirtyDaysDelta': report_30_days['total_new'] - report_30_days['paid_new'], 'thirtyDaysMinus': 0 }, { diff --git a/shared/selene/data/account/repository/sql/daily_report.sql b/shared/selene/data/account/repository/sql/daily_report.sql index 1928ced6..2d199efa 100644 --- a/shared/selene/data/account/repository/sql/daily_report.sql +++ b/shared/selene/data/account/repository/sql/daily_report.sql @@ -1,16 +1,15 @@ SELECT - COUNT(acc) AS total, - COUNT(acc) FILTER(WHERE acc.insert_ts::DATE >= (CURRENT_DATE - INTERVAL %(start)s)) AS total_new, - COUNT(acc) FILTER(WHERE acc_mem.account_id IS NULL) as free_total, - COUNT(mem) FILTER(WHERE mem.rate_period = 'month' AND UPPER(acc_mem.membership_ts_range) IS NULL) AS monthly_total, - COUNT(mem) FILTER(WHERE mem.rate_period = 'month' AND UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) >= (CURRENT_DATE - INTERVAL %(start)s)) AS monthly_new, - COUNT(mem) FILTER(WHERE mem.rate_period = 'month' AND UPPER(acc_mem.membership_ts_range) IS NOT NULL AND UPPER(acc_mem.membership_ts_range) >= (CURRENT_DATE - INTERVAL %(start)s)) AS monthly_minus, - COUNT(mem) FILTER(WHERE mem.rate_period = 'year' AND UPPER(acc_mem.membership_ts_range) IS NULL) AS yearly_total, - COUNT(mem) FILTER(WHERE mem.rate_period = 'year' AND UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) >= (CURRENT_DATE - INTERVAL %(start)s)) AS yearly_new, - COUNT(mem) FILTER(WHERE mem.rate_period = 'year' AND UPPER(acc_mem.membership_ts_range) IS NOT NULL AND UPPER(acc_mem.membership_ts_range) >= (CURRENT_DATE - INTERVAL %(start)s)) as yearly_minus, - COUNT(acc_mem) FILTER(WHERE UPPER(acc_mem.membership_ts_range) IS NULL) AS paid_total, - COUNT(acc_mem) FILTER(WHERE UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) >= (CURRENT_DATE - INTERVAL %(start)s)) AS paid_new, - COUNT(acc_mem) FILTER(WHERE UPPER(acc_mem.membership_ts_range) IS NOT NULL AND UPPER(acc_mem.membership_ts_range) >= (CURRENT_DATE - INTERVAL %(start)s)) AS paid_minus + COUNT(acc) FILTER(WHERE acc.insert_ts::DATE <= %(end_date)s) AS total, + COUNT(acc) FILTER(WHERE acc.insert_ts > %(start_date)s AND acc.insert_ts <= %(end_date)s) AS total_new, + COUNT(mem) FILTER(WHERE mem.rate_period = 'month' AND UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) <= %(end_date)s) AS monthly_total, + COUNT(mem) FILTER(WHERE mem.rate_period = 'month' AND UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) > %(start_date)s AND LOWER(acc_mem.membership_ts_range) <= %(end_date)s) AS monthly_new, + COUNT(mem) FILTER(WHERE mem.rate_period = 'month' AND UPPER(acc_mem.membership_ts_range) IS NOT NULL AND UPPER(acc_mem.membership_ts_range) > %(start_date)s AND UPPER(acc_mem.membership_ts_range) <= %(end_date)s) AS monthly_minus, + COUNT(mem) FILTER(WHERE mem.rate_period = 'year' AND UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) <= %(end_date)s) AS yearly_total, + COUNT(mem) FILTER(WHERE mem.rate_period = 'year' AND UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) > %(start_date)s AND LOWER(acc_mem.membership_ts_range) <= %(end_date)s) AS yearly_new, + COUNT(mem) FILTER(WHERE mem.rate_period = 'year' AND UPPER(acc_mem.membership_ts_range) IS NOT NULL AND UPPER(acc_mem.membership_ts_range) > %(start_date)s AND UPPER(acc_mem.membership_ts_range) <= %(end_date)s) as yearly_minus, + COUNT(acc_mem) FILTER(WHERE UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) <= %(end_date)s) AS paid_total, + COUNT(acc_mem) FILTER(WHERE UPPER(acc_mem.membership_ts_range) IS NULL AND LOWER(acc_mem.membership_ts_range) > %(start_date)s AND LOWER(acc_mem.membership_ts_range) <= %(end_date)s) AS paid_new, + COUNT(acc_mem) FILTER(WHERE UPPER(acc_mem.membership_ts_range) IS NOT NULL AND UPPER(acc_mem.membership_ts_range) > %(start_date)s AND UPPER(acc_mem.membership_ts_range) <= %(end_date)s) AS paid_minus FROM account.account acc LEFT JOIN