Skip to content

Commit

Permalink
[MDS-6227] Add administrative amendments and filter to now_gis_export…
Browse files Browse the repository at this point in the history
… API (#3292)

* take out the filter in the materialized view, add app type code to the select, add it to the API model, add it as a filter, do some very basic testing
  • Loading branch information
taraepp authored Nov 4, 2024
1 parent 1ab7b52 commit da65aec
Show file tree
Hide file tree
Showing 5 changed files with 86 additions and 50 deletions.
80 changes: 40 additions & 40 deletions migrations/sql-prod/R__now_gis_export_materialized_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ END $$;

CREATE MATERIALIZED VIEW public.now_application_gis_export_view
TABLESPACE pg_default
AS select na.mine_purpose,appv.latest_response_date,appv.regional_contact, nai.now_application_guid::character varying AS now_application_guid,
AS select na.mine_purpose,appv.latest_response_date,nai.application_type_code,appv.regional_contact, nai.now_application_guid::character varying AS now_application_guid,
lpad(nai.now_number::text, 15, '0'::text) AS now_number,
nai.messageid,
nai.mms_cid,
Expand Down Expand Up @@ -308,44 +308,44 @@ AS select na.mine_purpose,appv.latest_response_date,appv.regional_contact, nai.n
disturbed_area.now_activity_surface_bulk_sample_total_disturbed_area,
disturbed_area.now_activity_placer_operation_total_disturbed_area
FROM crosstab(' SELECT
a.now_application_id,
a.activity_type_code,
SUM(a.disturbed_area) as disturbed_area
FROM
(SELECT a.activity_type_code,
ad.disturbed_area,
a.now_application_id
FROM activity_summary a
LEFT JOIN activity_summary_detail_xref ax ON a.activity_summary_id = ax.activity_summary_id
LEFT JOIN activity_detail ad ON ax.activity_detail_id = ad.activity_detail_id
UNION ALL
SELECT a.activity_type_code,
ad.disturbed_area,
a.now_application_id
FROM activity_summary a
LEFT JOIN activity_summary_building_detail_xref bx ON bx.activity_summary_id = a.activity_summary_id
LEFT JOIN activity_detail ad ON bx.activity_detail_id = ad.activity_detail_id
UNION ALL
SELECT a.activity_type_code,
ad.disturbed_area,
a.now_application_id
FROM activity_summary a
LEFT JOIN activity_summary_staging_area_detail_xref stx ON stx.activity_summary_id = a.activity_summary_id
LEFT JOIN activity_detail ad ON stx.activity_detail_id = ad.activity_detail_id) a
GROUP BY
a.now_application_id,
a.activity_type_code
ORDER BY now_application_id '::text, ' VALUES
(''cut_lines_polarization_survey''::TEXT),
(''settling_pond''),
(''exploration_surface_drilling''),
(''sand_gravel_quarry_operation''),
(''exploration_access''),
(''underground_exploration''),
(''camp''),
(''mechanical_trenching''),
(''surface_bulk_sample''),
(''placer_operation'') '::text) disturbed_area(now_application_id integer, now_activity_cut_lines_polarization_survey_total_disturbed_area numeric, now_activity_settling_pond_total_disturbed_area numeric, now_activity_exploration_surface_drilling_total_disturbed_area numeric, now_activity_sand_gravel_quarry_operation_total_disturbed_area numeric, now_activity_exploration_access_total_disturbed_area numeric, now_activity_underground_exploration_total_disturbed_area numeric, now_activity_camp_total_disturbed_area numeric, now_activity_mechanical_trenching_total_disturbed_area numeric, now_activity_surface_bulk_sample_total_disturbed_area numeric, now_activity_placer_operation_total_disturbed_area numeric)) activity_disturbed_areas ON activity_disturbed_areas.now_application_id = nai.now_application_id
a.now_application_id,
a.activity_type_code,
SUM(a.disturbed_area) as disturbed_area
FROM
(SELECT a.activity_type_code,
ad.disturbed_area,
a.now_application_id
FROM activity_summary a
LEFT JOIN activity_summary_detail_xref ax ON a.activity_summary_id = ax.activity_summary_id
LEFT JOIN activity_detail ad ON ax.activity_detail_id = ad.activity_detail_id
UNION ALL
SELECT a.activity_type_code,
ad.disturbed_area,
a.now_application_id
FROM activity_summary a
LEFT JOIN activity_summary_building_detail_xref bx ON bx.activity_summary_id = a.activity_summary_id
LEFT JOIN activity_detail ad ON bx.activity_detail_id = ad.activity_detail_id
UNION ALL
SELECT a.activity_type_code,
ad.disturbed_area,
a.now_application_id
FROM activity_summary a
LEFT JOIN activity_summary_staging_area_detail_xref stx ON stx.activity_summary_id = a.activity_summary_id
LEFT JOIN activity_detail ad ON stx.activity_detail_id = ad.activity_detail_id) a
GROUP BY
a.now_application_id,
a.activity_type_code
ORDER BY now_application_id '::text, ' VALUES
(''cut_lines_polarization_survey''::TEXT),
(''settling_pond''),
(''exploration_surface_drilling''),
(''sand_gravel_quarry_operation''),
(''exploration_access''),
(''underground_exploration''),
(''camp''),
(''mechanical_trenching''),
(''surface_bulk_sample''),
(''placer_operation'') '::text) disturbed_area(now_application_id integer, now_activity_cut_lines_polarization_survey_total_disturbed_area numeric, now_activity_settling_pond_total_disturbed_area numeric, now_activity_exploration_surface_drilling_total_disturbed_area numeric, now_activity_sand_gravel_quarry_operation_total_disturbed_area numeric, now_activity_exploration_access_total_disturbed_area numeric, now_activity_underground_exploration_total_disturbed_area numeric, now_activity_camp_total_disturbed_area numeric, now_activity_mechanical_trenching_total_disturbed_area numeric, now_activity_surface_bulk_sample_total_disturbed_area numeric, now_activity_placer_operation_total_disturbed_area numeric)) activity_disturbed_areas ON activity_disturbed_areas.now_application_id = nai.now_application_id
LEFT JOIN ( SELECT a.now_application_id,
sum(a.disturbed_area) AS now_total_disturbed_area
FROM ( SELECT ad.disturbed_area,
Expand Down Expand Up @@ -442,7 +442,7 @@ AS select na.mine_purpose,appv.latest_response_date,appv.regional_contact, nai.n
FROM nris.inspection
ORDER BY inspection.mine_no, inspection.inspection_date DESC) nris_i ON nris_i.mine_no = m.mine_no::text
LEFT JOIN nris.inspection_type nris_it ON nris_i.inspection_type_id = nris_it.inspection_type_id
WHERE m.deleted_ind = false AND nai.application_type_code::text <> 'ADA'::text AND (nai.messageid IS NOT NULL AND sub.processed::text = 'Y'::text OR nai.messageid IS NULL) AND (sub.originating_system IS NULL OR sub.originating_system IS NOT NULL AND nai.now_number IS NOT NULL)
WHERE m.deleted_ind = false AND (nai.messageid IS NOT NULL AND sub.processed::text = 'Y'::text OR nai.messageid IS NULL) AND (sub.originating_system IS NULL OR sub.originating_system IS NOT NULL AND nai.now_number IS NOT NULL)
GROUP by na.mine_purpose, appv.latest_response_date,appv.regional_contact, nai.now_application_guid, nai.now_number, na.status_reason, na.now_application_status_code, nas.description, na.type_of_application, na.notice_of_work_type_code, nat.description, na.submitted_date, sub.submitteddate, msub.proposedstartdate, sub.proposedstartdate, msub.proposedenddate, sub.proposedenddate, msub.typeofapplication, sub.typeofapplication, msub.noticeofworktype, sub.noticeofworktype, na.property_name, msub.nameofproperty, sub.nameofproperty, na.latitude, msub.latitude, sub.latitude, na.longitude, msub.longitude, sub.longitude, na.is_applicant_individual_or_company, sub.applicantindividualorcompany, na.relationship_to_applicant, sub.applicantrelationship, na.term_of_application, sub.termofapplication, na.proposed_start_date, na.imported_date, na.proposed_end_date, na.proposed_annual_maximum_tonnage, na.adjusted_annual_maximum_tonnage, sub.maxannualtonnage, na.directions_to_site, msub.sitedirections, sub.sitedirections, na.is_access_gated, na.tenure_number, msub.tenurenumbers, sub.tenurenumbers, sub.isaccessgated, sub.accessauthorizationskeyprovided, na.has_key_for_inspector, activity_disturbed_area_total.now_total_disturbed_area, activity_submission_disturbed_areas.now_submission_total_disturbed_area, activity_disturbed_areas.now_activity_cut_lines_polarization_survey_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_cut_lines_polarization_survey_total_dis, activity_disturbed_areas.now_activity_settling_pond_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_settling_pond_total_disturbed_area, activity_disturbed_areas.now_activity_exploration_surface_drilling_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_exploration_surface_drilling_total_dist, activity_disturbed_areas.now_activity_sand_gravel_quarry_operation_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_sand_gravel_quarry_operation_total_dist, activity_disturbed_areas.now_activity_exploration_access_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_exploration_access_total_disturbed_area, activity_disturbed_areas.now_activity_underground_exploration_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_underground_exploration_total_disturbed, activity_disturbed_areas.now_activity_camp_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_camp_total_disturbed_area, activity_disturbed_areas.now_activity_mechanical_trenching_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_mechanical_trenching_total_disturbed_ar, activity_disturbed_areas.now_activity_surface_bulk_sample_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_surface_bulk_sample_total_disturbed_are, activity_disturbed_areas.now_activity_placer_operation_total_disturbed_area, activity_submission_disturbed_areas.now_submission_activity_placer_operation_total_disturbed_area, nap_con.start_date, nap_con.end_date, nap_pub.start_date, nap_pub.end_date, nap_dft.start_date, nap_dft.end_date, nap_rev.start_date, nap_rev.end_date, nap_ref.start_date, nap_ref.end_date, nad.now_application_client_delay_days, p.permit_guid, p.permit_no, p.permit_status_code, psc.description, pa.issue_date, pa.authorization_end_date, pt.first_name, pt.party_name, pt.party_guid, m.mine_guid, m.mine_name, m.mine_no, m.mine_region, mrc.description, na.now_application_id, (m.latitude::character varying), (m.longitude::character varying), (m.create_timestamp::character varying), (ms.effective_date::character varying), m.major_mine_ind, (
CASE
WHEN m.major_mine_ind IS TRUE THEN 'Major Mine'::text
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@ class NowApplicationGisExport(Base):
now_application_status_code = db.Column(db.String)
now_application_status_description = db.Column(db.String)
type_of_application = db.Column(db.String)
application_type_code = db.Column(db.String)
now_application_type_code = db.Column(db.String)
now_application_type_description = db.Column(db.String)
now_application_submitted_date = db.Column(db.String)
Expand Down Expand Up @@ -134,3 +135,9 @@ class NowApplicationGisExport(Base):
def csv_row(self):
model = inspect(self.__class__)
return [str(getattr(self, c.name) or "") for c in model.columns]

@staticmethod
def query_by_application_type(application_type_code=None):
if application_type_code is not None:
return NowApplicationGisExport.query.filter_by(application_type_code=application_type_code)
return NowApplicationGisExport.query
Original file line number Diff line number Diff line change
@@ -1,22 +1,32 @@
import time
from io import StringIO

from flask import stream_with_context, Response, current_app
from flask import stream_with_context, Response, request, current_app
import csv
from sqlalchemy.inspection import inspect
from flask_restx import Resource
from werkzeug.exceptions import BadRequest
from ..models.now_application_gis_export import NowApplicationGisExport
from app.extensions import api, cache
from app.api.now_applications.models.application_type_code import ApplicationTypeCode
from app.extensions import api
from app.api.utils.access_decorators import VIEW_ALL, GIS, requires_any_of
from app.api.constants import NOW_APPLICATION_GIS_EXPORT, TIMEOUT_60_MINUTES

class NowApplicationGisExportResource(Resource):

@api.doc(
description=
'This endpoint returns a CSV export of Notice of Work details intended for uses by the GIS team.'
'This endpoint returns a CSV export of Notice of Work details intended for uses by the GIS team.',
params={'application_type_code': 'NOW to filter for Notice of Work or ADA for Administrative Amendments'}
)
@requires_any_of([VIEW_ALL, GIS])
def get(self):
application_type_code = request.args.get("application_type_code", None)

if application_type_code:
application_type = ApplicationTypeCode.find_by_application_type_code(application_type_code)

if application_type is None:
raise BadRequest("Invalid application type code")

model = inspect(NowApplicationGisExport)
headers = [c.name or "" for c in model.columns]

Expand All @@ -28,7 +38,9 @@ def generate():
data.seek(0)
data.truncate(0)

for r in NowApplicationGisExport.query.yield_per(50):
query = NowApplicationGisExport.query_by_application_type(application_type_code)

for r in query.yield_per(50):
writer.writerow(r.csv_row())
yield data.getvalue()
data.seek(0)
Expand Down
2 changes: 2 additions & 0 deletions services/core-api/tests/auth/test_expected_auth.py
Original file line number Diff line number Diff line change
Expand Up @@ -61,6 +61,7 @@
from app.api.now_applications.resources.now_application_document_resource import NOWApplicationDocumentIdentityResource
from app.api.mines.alerts.resources.mine_alert import GlobalMineAlertListResource
from app.api.help.resources.help_resource import HelpResource, HelpListResource
from app.api.exports.now_application.resources.now_application_gis_export_resource import NowApplicationGisExportResource

@pytest.mark.parametrize(
"resource,method,expected_roles",
Expand Down Expand Up @@ -173,6 +174,7 @@
(HelpResource, 'post', [EDIT_HELPDESK]),
(HelpResource, 'put', [EDIT_HELPDESK]),
(HelpResource, 'delete', [EDIT_HELPDESK]),
(NowApplicationGisExportResource, 'get', [VIEW_ALL, GIS])
])

def test_endpoint_auth(resource, method, expected_roles):
Expand Down
23 changes: 19 additions & 4 deletions services/core-api/tests/exports/test_export_success.py
Original file line number Diff line number Diff line change
Expand Up @@ -5,13 +5,13 @@

def test_mine_summary_export_success(test_client, db_session, auth_headers):
get_resp = test_client.get(
f'/exports/mine-summary-csv', headers=auth_headers['full_auth_header'])
'/exports/mine-summary-csv', headers=auth_headers['full_auth_header'])

assert get_resp.status_code == 200

def test_mine_summary_export_paginated(test_client, db_session, auth_headers):
get_resp = test_client.get(
f'/exports/mine-summary', headers=auth_headers['full_auth_header'])
'/exports/mine-summary', headers=auth_headers['full_auth_header'])

assert get_resp.status_code == 200

Expand All @@ -24,6 +24,21 @@ def test_mine_summary_export_paginated(test_client, db_session, auth_headers):

def test_core_static_content_success(test_client, db_session, auth_headers):
get_resp = test_client.get(
f'/exports/core-static-content', headers=auth_headers['full_auth_header'])
'/exports/core-static-content', headers=auth_headers['full_auth_header'])

assert get_resp.status_code == 200
assert get_resp.status_code == 200

def test_now_application_gis_export_success_no_filter(test_client, db_session, auth_headers):
get_resp = test_client.get('/exports/now-application-gis-export', headers=auth_headers['full_auth_header'])

assert get_resp.status_code == 200

def test_now_application_gis_export_success_ada_filter(test_client, db_session, auth_headers):
get_resp = test_client.get('/exports/now-application-gis-export?application_type_code=ADA', headers=auth_headers['full_auth_header'])

assert get_resp.status_code == 200

def test_now_application_gis_export_failure_bad_filter(test_client, db_session, auth_headers):
get_resp = test_client.get('/exports/now-application-gis-export?application_type_code=ZZZ', headers=auth_headers['full_auth_header'])

assert get_resp.status_code == 400

0 comments on commit da65aec

Please sign in to comment.