From f8a90138c254e7b2120748d1184cc0b16dc8e2bb Mon Sep 17 00:00:00 2001 From: Odysseus Chiu Date: Thu, 7 Dec 2023 14:21:37 -0800 Subject: [PATCH] 18758 - split notebooks for different partners, update vs queries --- .gitignore | 1 + jobs/notebook-report/config.py | 4 +- ...ipynb => cso_reconciliation_details.ipynb} | 0 .../daily/vs_reconciliation_details.ipynb | 260 +++++++++++++++ ...ipynb => cso_reconciliation_summary.ipynb} | 0 .../monthly/vs_reconciliation_summary.ipynb | 311 ++++++++++++++++++ jobs/notebook-report/notebookreport.py | 6 +- 7 files changed, 577 insertions(+), 5 deletions(-) rename jobs/notebook-report/daily/{reconciliation_details.ipynb => cso_reconciliation_details.ipynb} (100%) create mode 100644 jobs/notebook-report/daily/vs_reconciliation_details.ipynb rename jobs/notebook-report/monthly/{reconciliation_summary.ipynb => cso_reconciliation_summary.ipynb} (100%) create mode 100644 jobs/notebook-report/monthly/vs_reconciliation_summary.ipynb diff --git a/.gitignore b/.gitignore index 09737c877..27cfab6f5 100644 --- a/.gitignore +++ b/.gitignore @@ -126,3 +126,4 @@ jobs/payment-jobs/tests/docker/ftp ACK.INBOX.F12022020202 queue_services/payment-reconciliations/ACK.* queue_services/payment-reconciliations/FEEDBACK.* +jobs/notebook-report/data/ diff --git a/jobs/notebook-report/config.py b/jobs/notebook-report/config.py index 6080c767b..6ac3a9d31 100644 --- a/jobs/notebook-report/config.py +++ b/jobs/notebook-report/config.py @@ -19,8 +19,8 @@ class Config(object): CSO_MONTHLY_RECONCILIATION_RECIPIENTS = os.getenv('CSO_MONTHLY_RECONCILIATION_RECIPIENTS', '') EMAIL_SMTP = os.getenv('EMAIL_SMTP', '') ENVIRONMENT = os.getenv('ENVIRONMENT', '') - WEEKLY_REPORT_DATES = os.getenv('WEEKLY_REPORT_DATES', '1') - MONTHLY_REPORT_DATES = os.getenv('MONTHLY_REPORT_DATES', '1') + WEEKLY_REPORT_DATES = os.getenv('WEEKLY_REPORT_DATES', '[1]') + MONTHLY_REPORT_DATES = os.getenv('MONTHLY_REPORT_DATES', '[1]') PARTNER_CODES = os.getenv('PARTNER_CODES', 'CSO,VS') # POSTGRESQL diff --git a/jobs/notebook-report/daily/reconciliation_details.ipynb b/jobs/notebook-report/daily/cso_reconciliation_details.ipynb similarity index 100% rename from jobs/notebook-report/daily/reconciliation_details.ipynb rename to jobs/notebook-report/daily/cso_reconciliation_details.ipynb diff --git a/jobs/notebook-report/daily/vs_reconciliation_details.ipynb b/jobs/notebook-report/daily/vs_reconciliation_details.ipynb new file mode 100644 index 000000000..0796e728e --- /dev/null +++ b/jobs/notebook-report/daily/vs_reconciliation_details.ipynb @@ -0,0 +1,260 @@ +{ + "cells": [ + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "source": [ + "# Invoice Reconciliation Daily Stats" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "pycharm": { + "is_executing": false, + "name": "#%%\n" + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "import os\n", + "from datetime import datetime, timedelta\n", + "from config import Config\n", + "\n", + "%load_ext sql\n", + "%config SqlMagic.displaylimit = 5" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "editable": true, + "slideshow": { + "slide_type": "" + }, + "tags": [ + "parameters" + ] + }, + "source": [ + "# Parameters cell for external parameters via papermill (job running this notebook will insert a parameter cell below this). This cell has a tag of with the name \"parameters\" that is used by papermill\n", + "\n", + "e.g.\n", + "param1 = \"some_value\"" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "source": [ + "This will create the connection to the database and prep the jupyter magic for SQL" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "pycharm": { + "is_executing": false, + "name": "#%%\n" + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "%sql $Config.SQLALCHEMY_DATABASE_URI" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "jupyter": { + "outputs_hidden": false + } + }, + "source": [ + "Simplest query to run to ensure our libraries are loaded and our DB connection is working" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "collapsed": false, + "jupyter": { + "outputs_hidden": false + }, + "pycharm": { + "is_executing": false, + "name": "#%%\n" + } + }, + "outputs": [], + "source": [ + "%%sql\n", + "select now() AT TIME ZONE 'PST' as current_date" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "jupyter": { + "outputs_hidden": false + } + }, + "source": [ + "Daily query for details data." + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "pycharm": { + "is_executing": false, + "name": "#%%\n" + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "%%sql daily_reconciliation_details <<\n", + "SELECT i.created_on, i.updated_on, i.id, ir.invoice_number, (i.total - i.service_fees) AS subtotal, i.service_fees, i.total, i.disbursement_status_code, i.payment_method_code, i.invoice_status_code, i.corp_type_code\n", + "FROM invoices i join invoice_references ir on ir.invoice_id = i.id\n", + "WHERE i.corp_type_code = :partner_code\n", + "AND i.invoice_status_code IN ('PAID', 'REFUNDED', 'CANCELLED', 'CREDITED')\n", + "AND i.payment_method_code IN ('PAD','EJV', 'DRAWDOWN')\n", + "AND date(i.created_on) > date(current_date - 1 - interval '1 days')\n", + "AND date(i.created_on) <= date(current_date - 1)\n", + "ORDER BY 1;" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "jupyter": { + "outputs_hidden": false + } + }, + "source": [ + "Save to CSV" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "pycharm": { + "is_executing": false, + "name": "#%%\n" + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "filename = os.path.join(os.getcwd(), r'data/')+partner_code+'_daily_reconciliation_' + datetime.strftime(datetime.now()-timedelta(1), '%Y-%m-%d') +'.csv'\n", + "df = daily_reconciliation_details.DataFrame()\n", + "\n", + "with open(filename, 'w') as f:\n", + " f.write('Daily Reconciliation Details:\\n\\n')\n", + " if df.empty:\n", + " f.write('No Data Retrieved')\n", + " else:\n", + " df.to_csv(f, sep=',', encoding='utf-8', index=False)\n" + ] + } + ], + "metadata": { + "celltoolbar": "Tags", + "kernelspec": { + "display_name": "Python 3 (ipykernel)", + "language": "python", + "name": "python3" + }, + "language_info": { + "codemirror_mode": { + "name": "ipython", + "version": 3 + }, + "file_extension": ".py", + "mimetype": "text/x-python", + "name": "python", + "nbconvert_exporter": "python", + "pygments_lexer": "ipython3", + "version": "3.11.4" + }, + "pycharm": { + "stem_cell": { + "cell_type": "raw", + "metadata": { + "collapsed": false + }, + "source": [] + } + }, + "vscode": { + "interpreter": { + "hash": "fcb35bce15c55b4cacb5112e543368f86c7f98ed17acd45e6841ee83ed1df6e3" + } + } + }, + "nbformat": 4, + "nbformat_minor": 4 +} diff --git a/jobs/notebook-report/monthly/reconciliation_summary.ipynb b/jobs/notebook-report/monthly/cso_reconciliation_summary.ipynb similarity index 100% rename from jobs/notebook-report/monthly/reconciliation_summary.ipynb rename to jobs/notebook-report/monthly/cso_reconciliation_summary.ipynb diff --git a/jobs/notebook-report/monthly/vs_reconciliation_summary.ipynb b/jobs/notebook-report/monthly/vs_reconciliation_summary.ipynb new file mode 100644 index 000000000..a78fadc05 --- /dev/null +++ b/jobs/notebook-report/monthly/vs_reconciliation_summary.ipynb @@ -0,0 +1,311 @@ +{ + "cells": [ + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "source": [ + "# Reconciliation Monthly Stats" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "jupyter": { + "outputs_hidden": false + } + }, + "source": [ + "We need to load in these libraries into our notebook in order to query, load, manipulate and view the data" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "pycharm": { + "is_executing": false, + "name": "#%%\n" + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "import os\n", + "from datetime import datetime, timedelta\n", + "from config import Config\n", + "\n", + "%load_ext sql\n", + "%config SqlMagic.displaylimit = 5" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "editable": true, + "slideshow": { + "slide_type": "" + }, + "tags": [ + "parameters" + ] + }, + "source": [ + "# Parameters cell for external parameters via papermill (job running this notebook will insert a parameter cell below this). This cell has a tag of with the name \"parameters\" that is used by papermill\n", + "\n", + "e.g.\n", + "param1 = \"some_value\"" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "jupyter": { + "outputs_hidden": false + } + }, + "source": [ + "This will create the connection to the database and prep the jupyter magic for SQL" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "collapsed": false, + "editable": true, + "jupyter": { + "outputs_hidden": false + }, + "pycharm": { + "is_executing": false, + "name": "#%%\n" + }, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "%sql $Config.SQLALCHEMY_DATABASE_URI" + ] + }, + { + "cell_type": "markdown", + "metadata": { + "collapsed": false, + "jupyter": { + "outputs_hidden": false + } + }, + "source": [ + "Simplest query to run to ensure our libraries are loaded and our DB connection is working" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "collapsed": false, + "jupyter": { + "outputs_hidden": false + }, + "pycharm": { + "is_executing": false, + "name": "#%%\n" + } + }, + "outputs": [], + "source": [ + "%%sql\n", + "select now() AT TIME ZONE 'PST' as current_date" + ] + }, + { + "cell_type": "markdown", + "metadata": {}, + "source": [ + "Query ..." + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "editable": true, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "%%sql monthly_reconciliation_summary <<\n", + "SELECT count(*) AS transaction_count,\n", + "sum(pli.total) AS subtotal,\n", + "sum(pli.service_fees) AS service_fees,\n", + "sum(pli.total + pli.service_fees) AS total,\n", + "(i.payment_date)::date,\n", + "pli.description,\n", + "i.payment_method_code,\n", + "i.corp_type_code\n", + "FROM invoices i\n", + "JOIN payment_line_items pli ON i.id = pli.invoice_id\n", + "WHERE i.corp_type_code = :partner_code\n", + "AND i.invoice_status_code = 'PAID'\n", + "AND i.payment_method_code IN ('PAD', 'EJV', 'DIRECT_PAY', 'DRAWDOWN')\n", + "AND date(i.payment_date) > date(current_date - 1 - interval '1 months')\n", + "AND date(i.payment_date) <= date(current_date - 1)\n", + "GROUP BY (i.payment_date)::date, i.payment_method_code, i.corp_type_code, pli.description\n", + "ORDER BY (i.payment_date)::date, pli.description, i.payment_method_code;" + ] + }, + { + "cell_type": "markdown", + "metadata": {}, + "source": [ + "Save to CSV" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "editable": true, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "filename_summary = os.path.join(os.getcwd(), r'data/')+partner_code+'_monthly_reconciliation_summary_' + datetime.strftime(datetime.now()-timedelta(1), '%Y-%m') +'.csv'\n", + "df_summary = monthly_reconciliation_summary.DataFrame()\n", + "with open(filename_summary, 'w') as f:\n", + " f.write('Monthly Reconciliation Summary:\\n\\n')\n", + " if df_summary.empty:\n", + " f.write('No Data Retrieved')\n", + " else:\n", + " df_summary.to_csv(f, sep=',', encoding='utf-8', index=False)" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "editable": true, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "%%sql monthly_reconciliation_disbursed <<\n", + "SELECT count(*) AS transaction_count,\n", + "sum(pli.total) AS sub_total,\n", + "sum(pli.service_fees) AS service_fees,\n", + "sum(pli.total + pli.service_fees) AS total,\n", + "(i.disbursement_date)::date,\n", + "pli.description,\n", + "i.payment_method_code,\n", + "i.corp_type_code\n", + "FROM invoices i\n", + "JOIN payment_line_items pli ON i.id = pli.invoice_id\n", + "WHERE i.corp_type_code = 'VS'\n", + "AND i.invoice_status_code = 'PAID'\n", + "AND i.payment_method_code IN ('PAD', 'EJV', 'DIRECT_PAY')\n", + "AND i.disbursement_status_code = 'COMPLETED'\n", + "AND date(disbursement_date) > date(current_date - 1 - interval '1 months')\n", + "AND date(disbursement_date) <= date(current_date - 1)\n", + "GROUP BY (disbursement_date)::date, payment_method_code, corp_type_code, pli.description\n", + "ORDER BY (disbursement_date)::date, pli.description, i.payment_method_code;" + ] + }, + { + "cell_type": "markdown", + "metadata": {}, + "source": [ + "Save to another CSV" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "metadata": { + "editable": true, + "slideshow": { + "slide_type": "" + }, + "tags": [] + }, + "outputs": [], + "source": [ + "filename_disbursed = os.path.join(os.getcwd(), r'data/')+partner_code+'_monthly_reconciliation_disbursed_' + datetime.strftime(datetime.now()-timedelta(1), '%Y-%m') +'.csv'\n", + "df_disbursed = monthly_reconciliation_disbursed.DataFrame()\n", + "with open(filename_disbursed, 'a') as f:\n", + " f.write('Monthly Reconciliation Disbursed:\\n\\n')\n", + " if df_disbursed.empty:\n", + " f.write('No Data Retrieved')\n", + " else:\n", + " df_disbursed.to_csv(f, sep=',', encoding='utf-8', index=False)\n" + ] + } + ], + "metadata": { + "celltoolbar": "Tags", + "kernelspec": { + "display_name": "Python 3 (ipykernel)", + "language": "python", + "name": "python3" + }, + "language_info": { + "codemirror_mode": { + "name": "ipython", + "version": 3 + }, + "file_extension": ".py", + "mimetype": "text/x-python", + "name": "python", + "nbconvert_exporter": "python", + "pygments_lexer": "ipython3", + "version": "3.11.4" + }, + "pycharm": { + "stem_cell": { + "cell_type": "raw", + "metadata": { + "collapsed": false + }, + "source": [] + } + }, + "vscode": { + "interpreter": { + "hash": "fcb35bce15c55b4cacb5112e543368f86c7f98ed17acd45e6841ee83ed1df6e3" + } + } + }, + "nbformat": 4, + "nbformat_minor": 4 +} diff --git a/jobs/notebook-report/notebookreport.py b/jobs/notebook-report/notebookreport.py index 8b1691938..28e44eb1c 100644 --- a/jobs/notebook-report/notebookreport.py +++ b/jobs/notebook-report/notebookreport.py @@ -45,7 +45,7 @@ def findfiles(directory, pattern): yield os.path.join(directory, filename) -def send_email(file_processing, emailtype, errormessage, partner_code=None): +def send_email(file_processing, emailtype, errormessage, partner_code=None): # pylint: disable = too-many-locals """Send email for results.""" message = MIMEMultipart() date_str = datetime.strftime(datetime.now() - timedelta(1), '%Y-%m-%d') @@ -132,11 +132,11 @@ def execute_notebook(notebookdirectory: str, data_dir: str, partner_code: str = """Execute notebook and send emails.""" parameters = {'partner_code': partner_code} if partner_code else None - for file in findfiles(notebookdirectory, '*.ipynb'): + for file in findfiles(notebookdirectory, f'{partner_code.lower()}_*.ipynb'): try: pm.execute_notebook(file, data_dir + 'temp.ipynb', parameters=parameters) # send email to receivers and remove files/directories which we don't want to keep - send_email(file, '', '') + send_email(file, '', '', partner_code) os.remove(data_dir + 'temp.ipynb') except Exception: # noqa: B902 logging.exception('Error: %s.', file)