Skip to content

Commit

Permalink
Update account IDs when registrations become historical. (#1954)
Browse files Browse the repository at this point in the history
Signed-off-by: Doug Lovett <doug@diamante.ca>
doug-lovett authored Jun 26, 2024
1 parent aa83ffc commit ce98a2f
Showing 25 changed files with 988 additions and 2 deletions.
18 changes: 18 additions & 0 deletions jobs/permanent/ppr-registrations-historical/.dockerignore
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
Dockerfile
.dockerignore
.pytest_cache
__pycache__
db
venv
.env
.env*
.eggs
Makefile
devops
k8s
manage.py
migrations
pre-hook-update-db.sh
requirements
test_data
tests
21 changes: 21 additions & 0 deletions jobs/permanent/ppr-registrations-historical/.gcloudignore
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
.pytest_cache
__pycache__

venv

streaming_pull.py
test_run.py

.env
.env*
.eggs
Makefile
devops
k8s
manage.py
migrations
requirements
test_data
tests

flags.json
35 changes: 35 additions & 0 deletions jobs/permanent/ppr-registrations-historical/Dockerfile
Original file line number Diff line number Diff line change
@@ -0,0 +1,35 @@
# platform=linux/amd64
FROM python:3.11-buster

ARG VCS_REF="missing"
ARG BUILD_DATE="missing"

ENV VCS_REF=${VCS_REF}
ENV BUILD_DATE=${BUILD_DATE}

LABEL org.label-schema.vcs-ref=${VCS_REF} \
org.label-schema.build-date=${BUILD_DATE}

USER root

# Create working directory
RUN mkdir /opt/app-root && chmod 755 /opt/app-root
WORKDIR /opt/app-root

# Install the requirements
COPY ./requirements.txt .

RUN pip install --upgrade pip
#RUN pip install pip==22.1.2
RUN pip install --no-cache-dir -r requirements.txt

COPY . .

RUN pip install .

USER 1001

# Set Python path
ENV PYTHONPATH=/opt/app-root/src

CMD [ "python", "-m", "ppr_registrations_historical" ]
13 changes: 13 additions & 0 deletions jobs/permanent/ppr-registrations-historical/LICENSE
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
Copyright © 2018 Province of British Columbia

Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at

http://www.apache.org/licenses/LICENSE-2.0

Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.
48 changes: 48 additions & 0 deletions jobs/permanent/ppr-registrations-historical/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@

[![License](https://img.shields.io/badge/License-Apache%202.0-blue.svg)](LICENSE)
[![codecov](https://codecov.io/gh/bcgov/lear/branch/master/graph/badge.svg?flag=entityefiler)](https://codecov.io/gh/bcgov/lear/tree/master/queue_services/entity-filer)

# Application Name

BC Registries PPR Account Registrations Historical Service

## Technology Stack Used
* Python
* Postgres - psycopg2-binary
* GCP Artifact Registry
* GCP Cloud Run Jobs
* GCP Cloud Scheduler

## Project Status

## Documnentation

## Security

## Getting Help or Reporting an Issue

To report bugs/issues/feature requests, please file an [issue](../../issues).

## How to Contribute

If you would like to contribute, please see our [CONTRIBUTING](./CONTRIBUTING.md) guidelines.

Please note that this project is released with a [Contributor Code of Conduct](./CODE_OF_CONDUCT.md).
By participating in this project you agree to abide by its terms.

## License

Copyright 2024 Province of British Columbia

Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at

http://www.apache.org/licenses/LICENSE-2.0

Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.

16 changes: 16 additions & 0 deletions jobs/permanent/ppr-registrations-historical/requirements.txt
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
cachetools==5.3.0
certifi==2022.12.7
charset-normalizer==3.1.0
grpcio-status==1.51.3
grpcio==1.60.1
idna==3.4
proto-plus==1.22.2
protobuf==4.22.1
psycopg2-binary==2.9.9
pyasn1-modules==0.2.8
pyasn1==0.4.8
python-dotenv==1.0.0
requests==2.28.2
rsa==4.9
six==1.16.0
urllib3==1.26.15
17 changes: 17 additions & 0 deletions jobs/permanent/ppr-registrations-historical/requirements/dev.txt
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
# Testing
freezegun
pytest

# Lint and code style
autopep8
flake8
flake8-blind-except
flake8-debugger
flake8-docstrings
flake8-isort
flake8-quotes
pep8-naming
pydocstyle
pylint
isort
pytest-cov
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
google-auth
google-cloud-secret-manager
google-cloud-storage
google-crc32c
six
psycopg2-binary
python-dotenv
requests
117 changes: 117 additions & 0 deletions jobs/permanent/ppr-registrations-historical/setup.cfg
Original file line number Diff line number Diff line change
@@ -0,0 +1,117 @@
[metadata]
name = ppr_registrations_historical
url = https://github.com/thorwolpert/ppr/jobs/permanent/ppr-registrations-historical
author = team-le
author_email = thor@wolpert.ca
classifiers =
Development Status :: Beta
Intended Audience :: Developers / QA
Topic :: Legal Entities
License :: OSI Approved :: Apache Software License
Natural Language :: English
Programming Language :: Python :: 3.11
license = Apache Software License Version 2.0
description = A short description of the project
long_description = file: README.md
keywords =

[options]
zip_safe = True
python_requires = >=3.9
include_package_data = True
packages = find:

[options.package_data]
entity_filer =

[wheel]
universal = 1

[bdist_wheel]
universal = 1

[aliases]
test = pytest

[flake8]
exclude = .git,*migrations*
max-line-length = 120
docstring-min-length=10
per-file-ignores =
*/__init__.py:F401
*.py: B902

[pycodestyle]
max_line_length = 120
ignore = E501
docstring-min-length=10
notes=FIXME,XXX # TODO is ignored
match_dir = src/ppr_registrations_historical
per-file-ignores =
*/__init__.py:F401
good-names=
b,
d,
i,
e,
f,
k,
u,
v,
ar,
cb, #common shorthand for callback
nc,
rv,
sc,
event_loop,
logger,
loop,

[pylint]
ignore=migrations,test
max_line_length=120
notes=FIXME,XXX,TODO
disable=C0301,W0511,W0613,R0801,R0902

[isort]
line_length = 120
indent = 4
multi_line_output = 3
lines_after_imports = 2
include_trailing_comma = True

[tool:pytest]
minversion = 2.0
testpaths = tests
addopts = --verbose
--strict
-p no:warnings
--cov=src --cov-report html:htmlcov --cov-report xml:coverage.xml
python_files = tests/*/test*.py
norecursedirs = .git .tox venv* requirements* build
log_cli = true
log_cli_level = 1
filterwarnings =
ignore::UserWarning
markers =
slow
serial

[coverage:run]
branch = True
source =
src/ppr_discharges_for_mhr
omit =

[report:run]
exclude_lines =
pragma: no cover
from
import
def __repr__
if self.debug:
if settings.DEBUG
raise AssertionError
raise NotImplementedError
if 0:
if __name__ == .__main__.:
69 changes: 69 additions & 0 deletions jobs/permanent/ppr-registrations-historical/setup.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,69 @@
# Copyright © 2019 Province of British Columbia.
#
# Licensed under the Apache License, Version 2.0 (the "License");
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# http://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an "AS IS" BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
"""Installer and setup for this module
"""
import ast
from glob import glob
from os.path import basename, splitext
import re

from setuptools import setup, find_packages

_version_re = re.compile(r'__version__\s+=\s+(.*)') # pylint: disable=invalid-name

with open('src/ppr_registrations_historical/version.py', 'rb') as f:
version = str(ast.literal_eval(_version_re.search( # pylint: disable=invalid-name
f.read().decode('utf-8')).group(1)))


def read_requirements(filename):
"""
Get application requirements from
the requirements.txt file.
:return: Python requirements
"""
with open(filename, 'r') as req:
requirements = req.readlines()
install_requires = [r.strip() for r in requirements if r.find('git+') != 0]
return install_requires


def read(filepath):
"""
Read the contents from a file.
:param str filepath: path to the file to be read
:return: file contents
"""
with open(filepath, 'r') as file_handle:
content = file_handle.read()
return content


REQUIREMENTS = read_requirements('requirements.txt')

setup(
name='ppr_registrations_historical',
version=version,
author_email='thor@wolpert.ca',
packages=find_packages('src'),
package_dir={'': 'src'},
py_modules=[splitext(basename(path))[0] for path in glob('src/*.py')],
include_package_data=True,
license=read('LICENSE'),
long_description=read('README.md'),
zip_safe=False,
install_requires=REQUIREMENTS,
setup_requires=['pytest-runner', ],
tests_require=['pytest', ],
)
Empty file.
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
import json
import os
import sys

from .config import Config
from .job import job

# Retrieve Job-defined env vars
TASK_INDEX = os.getenv("CLOUD_RUN_TASK_INDEX", 0)
TASK_ATTEMPT = os.getenv("CLOUD_RUN_TASK_ATTEMPT", 0)


# Start script
if __name__ == "__main__":
try:
config = Config()
job(config)
except Exception as err:
message = f"Task #{TASK_INDEX}, " \
+ f"Attempt #{TASK_ATTEMPT} failed: {str(err)}"

print(json.dumps({"message": message, "severity": "ERROR"}))
sys.exit(1) # Retry Job Task by exiting the process

Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
# Copyright © 2021 Province of British Columbia
#
# Licensed under the Apache License, Version 2.0 (the "License");
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# http://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an "AS IS" BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
"""Common routines, classes and functions for the Document Delivery Service."""

from .enum import BaseEnum, auto

__all__ = ['BaseEnum', 'auto']
Original file line number Diff line number Diff line change
@@ -0,0 +1,33 @@
# Copyright © 2019 Province of British Columbia
#
# Licensed under the Apache License, Version 2.0 (the "License");
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# http://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an "AS IS" BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
"""Date time utilities."""
# from datetime import datetime, timezone
import time as _time
from datetime import date, datetime as _datetime, timezone # pylint: disable=unused-import # noqa: F401, I001, I005
# noqa: I003,I005


class datetime(_datetime): # pylint: disable=invalid-name; # noqa: N801; ha datetime is invalid??
"""Alternative to the built-in datetime that has a timezone on the UTC call."""

@classmethod
def utcnow(cls):
"""Construct a UTC non-naive datetime, meaning it includes timezone from time.time()."""
time_stamp = _time.time()
return super().utcfromtimestamp(time_stamp).replace(tzinfo=timezone.utc)

@classmethod
def from_date(cls, date_obj):
"""Get a datetime object from a date object."""
return datetime(date_obj.year, date_obj.month, date_obj.day)
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
# Copyright © 2021 Province of British Columbia
#
# Licensed under the Apache License, Version 2.0 (the "License");
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# http://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an "AS IS" BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
"""This provides a base Enum class that supports standard functionality."""
from __future__ import annotations

from enum import Enum, EnumMeta, auto # pylint: disable=unused-import
from typing import Optional


class BaseMeta(EnumMeta):
"""Meta class for the enum."""

def __contains__(self, other): # pylint: disable=C0203
"""Return True if 'in' the Enum."""
try:
self(other) # pylint: disable=no-value-for-parameter
except ValueError:
return False
else:
return True


class BaseEnum(str, Enum, metaclass=BaseMeta):
"""Replace autoname from Enum class."""

@classmethod
def get_enum_by_value(cls, value: str) -> Optional[str]:
"""Return the enum by value."""
for enum_value in cls:
if enum_value.value == value:
return enum_value
return None

#pragma warning disable S5720; # noqa: E265
# disable sonar cloud complaining about this signature
def _generate_next_value_(name, start, count, last_values): # noqa: N805 # pylint: disable=E0213
"""Return the name of the key."""
return name
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
# Copyright © 2021 Province of British Columbia
#
# Licensed under the Apache License, Version 2.0 (the "License");
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# http://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an "AS IS" BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
"""The application common configuration."""
import os

from dotenv import find_dotenv, load_dotenv

load_dotenv(find_dotenv())


class BaseConfig:
"""Base configuration."""


class Config(BaseConfig):
"""Production configuration."""

LOG_LEVEL = os.getenv('LOG_LEVEL', 'DEBUG')

APP_DB_USER = os.getenv('APP_DATABASE_USERNAME', '')
APP_DB_PASSWORD = os.getenv('APP_DATABASE_PASSWORD', '')
APP_DB_NAME = os.getenv('APP_DATABASE_NAME', '')
APP_DB_HOST = os.getenv('APP_DATABASE_HOST', '')
APP_DB_PORT = os.getenv('APP_DATABASE_PORT', '5432')
START_DATE_OFFSET = os.getenv('START_DATE_OFFSET', '32')
# POSTGRESQL
# POSTGRESQL
if (APP_DB_UNIX_SOCKET := os.getenv('APP_DATABASE_UNIX_SOCKET', None)):
APP_DATABASE_URI = f'postgresql://{APP_DB_USER}:{APP_DB_PASSWORD}@/{APP_DB_NAME}?host={APP_DB_UNIX_SOCKET}'
else:
APP_DATABASE_URI = f'postgresql://{APP_DB_USER}:{APP_DB_PASSWORD}@{APP_DB_HOST}:{APP_DB_PORT}/{APP_DB_NAME}'
Original file line number Diff line number Diff line change
@@ -0,0 +1,145 @@
import sys
from contextlib import suppress
from http import HTTPStatus
from typing import Final

import psycopg2

from .services.logging import logging


EVENT_JOB_ID = 777777001
UPDATE_ACCOUNT_DISCHARGED = """
UPDATE registrations
SET account_id = account_id || '_HIS'
WHERE financing_id IN
(SELECT DISTINCT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts BETWEEN ((now() at time zone 'utc') - interval '{start_offset} days')
AND ((now() at time zone 'utc') - interval '30 days')))
"""
UPDATE_FINANCING_HEX = """
UPDATE financing_statements
SET state_type = 'HEX'
WHERE id IN
(SELECT DISTINCT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND (fs.expire_date IS NOT NULL AND
(fs.expire_date at time zone 'utc') BETWEEN ((now() at time zone 'utc') - interval '{start_offset} days')
AND ((now() at time zone 'utc') - interval '30 days'))
AND NOT EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts BETWEEN ((now() at time zone 'utc') - interval '{start_offset} days')
AND ((now() at time zone 'utc') - interval '30 days')))
AND state_type = 'ACT'
"""
UPDATE_ACCOUNT_EXPIRED = """
UPDATE registrations
SET account_id = account_id || '_HIS'
WHERE financing_id IN
(SELECT DISTINCT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND (fs.expire_date IS NOT NULL AND
(fs.expire_date at time zone 'utc') BETWEEN ((now() at time zone 'utc') - interval '{start_offset} days')
AND ((now() at time zone 'utc') - interval '30 days'))
AND NOT EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts BETWEEN ((now() at time zone 'utc') - interval '{start_offset} days')
AND ((now() at time zone 'utc') - interval '30 days')))
"""
DELETE_EXTRA_HISTORICAL = """
DELETE
FROM user_extra_registrations uer2
WHERE uer2.id IN (SELECT uer.id
FROM registrations r, user_extra_registrations uer
WHERE r.registration_number = uer.registration_number
AND r.account_id LIKE '%_HIS')
"""
INSERT_EVENT: Final = """
INSERT INTO event_tracking(id, key_id, event_ts, event_tracking_type, status, message)
VALUES(nextval('event_tracking_id_seq'), {job_id}, CURRENT_TIMESTAMP at time zone 'utc', 'REG_HIST_JOB',
{job_status}, '{job_message}')
"""

def track_event(db_conn: psycopg2.extensions.connection,
db_cursor: psycopg2.extensions.cursor,
status: int,
message: str):
"""Capture the job run in the event tracking table."""
try:
if not db_conn or not db_cursor:
return
sql_statement = INSERT_EVENT.format(job_id=EVENT_JOB_ID, job_status=status, job_message=message)
db_cursor.execute(sql_statement)
db_conn.commit()
except (psycopg2.Error, Exception) as err:
error_message = f"Error attempting event_tracking insert: {err}"
logging.error(error_message)

# Start job
def job(config):

db_conn: psycopg2.extensions.connection
db_cursor: psycopg2.extensions.cursor
job_message: str = '1. Update account discharged registrations.'
try:
logging.info('Getting database connection and cursor.')
db_conn = psycopg2.connect(dsn=config.APP_DATABASE_URI)
db_cursor = db_conn.cursor()

# Update account ids for registrations discharged more than 30 days.
sql_statement = UPDATE_ACCOUNT_DISCHARGED.format(start_offset=config.START_DATE_OFFSET)
logging.info(f'Starting step 1: update account discharged registrations: {sql_statement}')
db_cursor.execute(sql_statement)
db_conn.commit()

# Update financing statements status to HEX for statements expired more than 30 days.
job_message += '\n2. Update financing_statements.state_type=HEX for expired registrations.'
sql_statement = UPDATE_FINANCING_HEX.format(start_offset=config.START_DATE_OFFSET)
logging.info(f'Starting step 2: update financing_statements.state_type=HEX: {sql_statement}')
db_cursor.execute(sql_statement)
db_conn.commit()

# Update account ids for registrations expired more than 30 days.
job_message += '\n3. Update account expired registrations.'
sql_statement = UPDATE_ACCOUNT_EXPIRED.format(start_offset=config.START_DATE_OFFSET)
logging.info(f'Starting step 3: update account expired registrations: {sql_statement}')
db_cursor.execute(sql_statement)
db_conn.commit()

# Update account ids for registrations expired more than 30 days.
job_message += '\n4. Delete account extra registrations historical.'
logging.info('Starting step 4: delete account extra registrations that are now historical:')
logging.info(DELETE_EXTRA_HISTORICAL)
db_cursor.execute(DELETE_EXTRA_HISTORICAL)
db_conn.commit()

logging.info('Run completed without error.')
track_event(db_conn, db_cursor, HTTPStatus.OK, job_message)
except (psycopg2.Error, Exception) as err:
track_event(db_conn, db_cursor, HTTPStatus.INTERNAL_SERVER_ERROR, job_message + '\n' + str(err))
logging.error(f'Job run failed: {err}', err)
sys.exit(1) # Retry Job Task by exiting the process
finally:
# Clean up: Close the database cursor and connection
with suppress(Exception):
db_cursor.close()
with suppress(Exception):
db_conn.close()
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
# Copyright © 2021 Province of British Columbia
#
# Licensed under the Apache License, Version 2.0 (the 'License');
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# http://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an 'AS IS' BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
"""This module contains the services used by the Delivery Service."""
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
# Copyright © 2021 Province of British Columbia
#
# Licensed under the Apache License, Version 2.0 (the 'License');
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# http://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an 'AS IS' BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
"""Logging service."""
import logging

from ..config import Config
logging.basicConfig(format='%(asctime)s - %(name)s - %(levelname)s:%(message)s',
datefmt='%m/%d/%Y %I:%M:%S %p',
level=Config.LOG_LEVEL)
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@

__version__ = '0.1.0' # pylint: disable=invalid-name
214 changes: 214 additions & 0 deletions ppr-api/src/database/patch/21973-ppr-registrations-historical.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,214 @@
-- 21973 begin PPR API build 1.2.5
-- 1. Append _HIS to the account id of all existing registrations expired/discharged more than 30 days.
-- 2. Set the status for all existing registrations expired more than 30 days that have not been discharged
-- to HEX Historical Expired.
-- 3. Cleanup: delete from user_extra_registrations all registration numbers for base registrations that
-- have been discharged or expired more than 30 days.

INSERT INTO event_tracking_types(event_tracking_type, event_tracking_desc)
VALUES('REG_HIST_JOB', 'Job to updated account IDs when registrations become historical.');


-- 3638712 PROD 2024-06-24
select max(id)
from registrations
;

-- 1886177
select max(id)
from registrations
where account_id = '0'
;

-- PROD 2024-06-24 827,202
SELECT COUNT(fs.id)
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts < ((now() at time zone 'utc') - interval '30 days'))
AND r.id between 1886178 and 2300000 -- 231025
-- AND r.id between 2300001 and 2800000 -- 259057
-- AND r.id between 2800001 and 3300000 -- 228484
-- AND r.id > 3300000 -- 108635
;

-- PROD 2024-06-24 46,687
SELECT COUNT(fs.id)
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND (fs.expire_date IS NOT NULL AND
(fs.expire_date at time zone 'utc') < ((now() at time zone 'utc') - interval '30 days'))
AND NOT EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts < ((now() at time zone 'utc') - interval '30 days'))
;

UPDATE registrations
SET account_id = account_id || '_HIS'
WHERE financing_id IN (SELECT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts < ((now() at time zone 'utc') - interval '30 days'))
AND r.id between 1886178 and 2300000)
;
UPDATE registrations
SET account_id = account_id || '_HIS'
WHERE financing_id IN (SELECT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts < ((now() at time zone 'utc') - interval '30 days'))
AND r.id between 2300001 and 2800000)
;
UPDATE registrations
SET account_id = account_id || '_HIS'
WHERE financing_id IN (SELECT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts < ((now() at time zone 'utc') - interval '30 days'))
AND r.id between 2800001 and 3300000)
;
UPDATE registrations
SET account_id = account_id || '_HIS'
WHERE financing_id IN (SELECT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts < ((now() at time zone 'utc') - interval '30 days'))
AND r.id > 3300000)
;

UPDATE financing_statements
SET state_type = 'HEX'
WHERE id IN (SELECT DISTINCT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND (fs.expire_date IS NOT NULL AND
(fs.expire_date at time zone 'utc') < ((now() at time zone 'utc') - interval '30 days'))
AND NOT EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts < ((now() at time zone 'utc') - interval '30 days')))
AND state_type = 'ACT'
;
UPDATE registrations
SET account_id = account_id || '_HIS'
WHERE financing_id IN (SELECT fs.id
FROM registrations r, financing_statements fs
WHERE fs.id = r.financing_id
AND r.account_id != '0'
AND r.account_id NOT LIKE '%_HIS'
AND (fs.expire_date IS NOT NULL AND
(fs.expire_date at time zone 'utc') < ((now() at time zone 'utc') - interval '30 days'))
AND NOT EXISTS (SELECT r3.id
FROM registrations r3
WHERE r3.financing_id = fs.id
AND r3.registration_type_cl = 'DISCHARGE'
AND r3.registration_ts < ((now() at time zone 'utc') - interval '30 days')))
;

SELECT COUNT(uer.id)
FROM registrations r, user_extra_registrations uer
WHERE r.registration_number = uer.registration_number
AND r.account_id LIKE '%_HIS'
;
DELETE
FROM user_extra_registrations uer2
WHERE uer2.id IN (SELECT uer.id
FROM registrations r, user_extra_registrations uer
WHERE r.registration_number = uer.registration_number
AND r.account_id LIKE '%_HIS')
;
-- PROD 462,576 before historical delete
SELECT count(r.id)
FROM registrations r, user_extra_registrations uer
WHERE r.registration_number = uer.registration_number
AND r.account_id = uer.account_id
AND uer.removed_ind IS NOT NULL
AND uer.removed_ind = 'Y'
AND r.id <= 2800000 -- 257132
-- AND r.id > 2800000 -- 205442
;
UPDATE registrations
SET account_id = registrations.account_id || '_R'
FROM user_extra_registrations
WHERE registrations.account_id = user_extra_registrations.account_id
AND user_extra_registrations.removed_ind IS NOT NULL
AND user_extra_registrations.removed_ind = 'Y'
AND registrations.financing_id = (SELECT DISTINCT fs.id
FROM financing_statements fs, registrations r
WHERE r.financing_id = fs.id
AND r.account_id = user_extra_registrations.account_id
AND r.registration_number = user_extra_registrations.registration_number)
;


-- 5797 teranet +1000000 8.9s
-- 5838 ESC 243696 3.09s
-- Testing PROD before/after update.
SELECT * FROM
(
SELECT document_number, create_ts, registration_type, registration_type_cl, registration_desc, base_reg_num, draft_type,
last_update_ts, client_reference_id, registering_party, secured_party, registering_name, account_id
FROM account_draft_vw adv
WHERE account_id = '5797'
AND NOT EXISTS (SELECT r.draft_id FROM registrations r WHERE r.account_id = adv.account_id AND r.draft_id = adv.id)
AND NOT EXISTS (SELECT uer.id
FROM user_extra_registrations uer
WHERE uer.registration_number = adv.registration_number
AND uer.account_id = adv.account_id
AND uer.removed_ind = 'Y')
) AS q WHERE account_id = '5797'
ORDER BY create_ts DESC
FETCH FIRST 1000 ROWS ONLY
;
-- 5797 teranet +1000000 19.9s
-- 5838 ESC 243696 3.6s
SELECT * FROM
(
SELECT registration_number, registration_ts, registration_type, registration_type_cl, account_id,
registration_desc, base_reg_number, state, expire_days, last_update_ts, registering_party,
secured_party, client_reference_id, registering_name, orig_account_id, pending_count, vehicle_count
FROM account_registration_vw arv
WHERE arv.account_id = '5797'
AND arv.registration_type_cl IN ('CROWNLIEN', 'MISCLIEN', 'PPSALIEN')
) AS q
ORDER BY registration_ts DESC
LIMIT 100 OFFSET 1
;

-- 21973 end PPR API build 1.2.5
36 changes: 36 additions & 0 deletions ppr-api/src/ppr_api/models/registration_utils.py
Original file line number Diff line number Diff line change
@@ -16,9 +16,11 @@

"""This module holds methods to support registration model updates - mostly account registration summary."""
from flask import current_app
from sqlalchemy.sql import text
from ppr_api.models import utils as model_utils
from ppr_api.services.authz import is_all_staff_account

from .db import db
from .securities_act_notice import SecuritiesActNotice


@@ -83,6 +85,24 @@
QUERY_ACCOUNT_CHANGE_REG_DATE_CLAUSE = """
AND arv2.registration_ts BETWEEN TO_TIMESTAMP(start_ts) AND TO_TIMESTAMP(end_ts)
"""
QUERY_UPDATE_ACCOUNT_ID_REMOVE = """
UPDATE registrations
SET account_id = account_id || '_R'
WHERE account_id = :query_account
AND financing_id = (SELECT fs.id
FROM financing_statements fs, registrations r
WHERE r.financing_id = fs.id
AND r.registration_number = :query_reg_num)
"""
QUERY_UPDATE_ACCOUNT_ID_RESTORE = """
UPDATE registrations
SET account_id = :query_account
WHERE account_id = :query_account || '_R'
AND financing_id = (SELECT fs.id
FROM financing_statements fs, registrations r
WHERE r.financing_id = fs.id
AND r.registration_number = :query_reg_num)
"""
GC_LEGACY_STATUS_ADDED = 'A'
GC_LEGACY_STATUS_DELETED = 'D'

@@ -543,3 +563,19 @@ def set_securities_notices_json(registration, json_data, registration_id):
del_notice.append(notice_json)
if del_notice:
json_data['deleteSecuritiesActNotices'] = del_notice


def update_account_reg_remove(account_id: str, reg_num: str) -> int:
"""Mark registrations created by an account as removed by appending _R to the account id."""
db.session.execute(text(QUERY_UPDATE_ACCOUNT_ID_REMOVE),
{'query_account': account_id, 'query_reg_num': reg_num})
current_app.logger.debug(f'update_account_reg_remove account={account_id} reg_num={reg_num}')
db.session.commit()


def update_account_reg_restore(account_id: str, reg_num: str):
"""Mark registrations created by an account as restored by removing _R from the end of the account id."""
db.session.execute(text(QUERY_UPDATE_ACCOUNT_ID_RESTORE),
{'query_account': account_id, 'query_reg_num': reg_num})
current_app.logger.debug(f'update_account_reg_restore account={account_id} reg_num={reg_num}')
db.session.commit()
7 changes: 5 additions & 2 deletions ppr-api/src/ppr_api/resources/v1/financing_statements.py
Original file line number Diff line number Diff line change
@@ -21,7 +21,8 @@
from ppr_api.exceptions import BusinessException, DatabaseException
from ppr_api.models import AccountBcolId, EventTracking, FinancingStatement, Registration, User, UserExtraRegistration
from ppr_api.models import utils as model_utils
from ppr_api.models.registration_utils import AccountRegistrationParams
from ppr_api.models.registration_utils import AccountRegistrationParams, update_account_reg_remove, \
update_account_reg_restore
from ppr_api.reports import ReportTypes
from ppr_api.resources import financing_utils as fs_utils
from ppr_api.resources import utils as resource_utils
@@ -608,8 +609,9 @@ def post_account_registrations(registration_num: str):
# Save the base registration: request may be a change registration number.
base_reg_num = registration['baseRegistrationNumber']
# Check if registration was created by the account and deleted. If so, restore it.
if registration['accountId'] == account_id and registration['existsCount'] > 0:
if registration['accountId'] in (account_id, account_id + '_R') and registration['existsCount'] > 0:
UserExtraRegistration.delete(base_reg_num, account_id)
update_account_reg_restore(account_id, base_reg_num)
# Check if duplicate.
elif registration['accountId'] == account_id or registration['existsCount'] > 0:
message = fs_utils.DUPLICATE_REGISTRATION_ERROR.format(registration_num)
@@ -699,6 +701,7 @@ def delete_account_registrations(registration_num: str):
extra_registration = UserExtraRegistration(account_id=account_id, registration_number=registration_num)
extra_registration.removed_ind = UserExtraRegistration.REMOVE_IND
extra_registration.save()
update_account_reg_remove(account_id, registration_num)
return '', HTTPStatus.NO_CONTENT
except DatabaseException as db_exception:
return resource_utils.db_exception_response(db_exception, account_id,
6 changes: 6 additions & 0 deletions ppr-api/tests/unit/api/test_financing.py
Original file line number Diff line number Diff line change
@@ -606,6 +606,9 @@ def test_account_add_registration(session, client, jwt, desc, roles, status, acc

# check
assert response.status_code == status
if desc == 'Valid Request User':
registration: Registration = Registration.find_by_registration_number(reg_num, account_id, True)
assert registration.account_id == account_id


@pytest.mark.parametrize('desc,roles,status,account_id,reg_num', TEST_USER_LIST_DELETE)
@@ -624,6 +627,9 @@ def test_account_delete_registration(session, client, jwt, desc, roles, status,

# check
assert response.status_code == status
if desc == 'User Valid Request':
registration: Registration = Registration.find_by_registration_number(reg_num, account_id, True)
assert registration.account_id == account_id + '_R'


@pytest.mark.parametrize('desc,roles,status,account_id,reg_num', TEST_USER_LIST_GET)
18 changes: 18 additions & 0 deletions ppr-api/tests/unit/models/test_registration_utils.py
Original file line number Diff line number Diff line change
@@ -117,6 +117,24 @@
('Valid', 'TEST0022', 'PS00002', 200000000, True),
('No results', 'TEST0022', 'PS00002', 200000001, False)
]
# testdata pattern is ({reg_id}, {reg_num}, {account_id_remove}, {account_id_add})
TEST_ADD_REMOVE_DATA = [
(200000005, 'TEST0005', 'PS12345', 'PS12345_R')
]


@pytest.mark.parametrize('reg_id,reg_num,account_id_before,account_id_after', TEST_ADD_REMOVE_DATA)
def test_add_remove_account_reg(session, reg_id, reg_num, account_id_before, account_id_after):
"""Assert that removing a registration from an account and restoring it works as expected."""
registration: Registration = Registration.find_by_id(reg_id)
assert registration.account_id == account_id_before
assert registration.registration_num == reg_num
registration_utils.update_account_reg_remove(account_id_before, reg_num)
registration: Registration = Registration.find_by_id(reg_id)
assert registration.account_id == account_id_after
registration_utils.update_account_reg_restore(account_id_before, reg_num)
registration: Registration = Registration.find_by_id(reg_id)
assert registration.account_id == account_id_before


@pytest.mark.parametrize('desc,reg_num,account_id,notice_id,has_data', TEST_AMEND_SE_DELETE_DATA)

0 comments on commit ce98a2f

Please sign in to comment.