Skip to content

Commit

Permalink
Handle amended licence refs in rtn versions import
Browse files Browse the repository at this point in the history
https://eaflood.atlassian.net/browse/WATER-4794

While working on WATER-4734, we pulled together a list of all licences deleted from NALD that still exist in WRLS.

Because we have the latest version of the WATER-4654 (return version data clean-up) changes in our non-prod environments (excluding pre), we were expecting no deleted licences to be flagged as having return logs. However, six came back in the results.

We know our previous changes to clean the return versions handle return versions linked to 'completed' return logs. If this scenario occurs, we won't delete it until it can be looked at. So, when it comes to cleaning the licences, we can do a bit of a shortcut: any WRLS licence due to be deleted which still has a `water.return_version` record must do so because it is linked to a 'completed' return log.

Taking **MD/0280003/012** as an example, we confirmed there are no return logs but it was one of the six returned in the results. Huh? If this licence is deleted in NALD, then so must be the return versions and all child records, so why have we not deleted it in our clean job?

What we found is the NALD return version has not been deleted. It and all the child records remain in NALD. However, when we look at the NALD licence record it is linked to, it has a `LIC_NO` of **MD/028/0003/012**. Can you spot the difference?! 😂

We've deduced that when first creating the licence in NALD, a typo was made with the licence reference. But WRLS would have imported the record and created a **MD/0280003/012** `water.licences` record. When the typo was spotted, rather than creating a new NALD licence record, the typo was corrected.

If the previous team had used the NALD table ID, as they do with all other tables, then the import would have just corrected the WRLS licence record. However, they use the licence reference as the unique identifier for reasons known only to them! This means the import thinks **MD/028/0003/012** is an entirely new licence, so it creates a second WRLS record.

During the nightly import, the NALD return version records update the existing information, but they point to the wrong WRLS licence record!

Initially, we thought this would require a manual intervention so added [a fix migration to water-abstraction-service](DEFRA/water-abstraction-service#2660). However, after double checking the import query for the return versions we realised if we include `licence_id` in the `ON CONFLICT DO UPDATE` statement, this would also fix the issue. Plus, this would fix any future licence reference amendments.
  • Loading branch information
Cruikshanks committed Nov 26, 2024
1 parent 86e5c52 commit d40b2c5
Showing 1 changed file with 43 additions and 20 deletions.
63 changes: 43 additions & 20 deletions src/modules/return-versions/lib/import-queries.js
Original file line number Diff line number Diff line change
@@ -1,25 +1,48 @@
'use strict'

const importReturnVersions = `insert into water.return_versions (licence_id, version_number, start_date, end_date, status, external_id, date_created, date_updated) select
l.licence_id,
nrv."VERS_NO"::integer as version_number,
to_date(nrv."EFF_ST_DATE", 'DD/MM/YYYY') as start_date,
case nrv."EFF_END_DATE"
when 'null' then null
else to_date(nrv."EFF_END_DATE", 'DD/MM/YYYY')
end AS end_date,
(case nrv."STATUS"
when 'SUPER' THEN 'superseded'
when 'DRAFT' THEN 'draft'
when 'CURR' THEN 'current'
end
)::water.return_version_status as status,
concat_ws(':', nrv."FGAC_REGION_CODE", nrv."AABL_ID", nrv."VERS_NO") AS external_id,
NOW() as date_created,
NOW() as date_updated from import."NALD_RET_VERSIONS" nrv join import."NALD_ABS_LICENCES" nl on nrv."AABL_ID"=nl."ID" AND nrv."FGAC_REGION_CODE"=nl."FGAC_REGION_CODE" join water.licences l on l.licence_ref=nl."LIC_NO" on conflict (external_id) do update set start_date=excluded.start_date,
end_date=excluded.end_date,
status=excluded.status,
date_updated=excluded.date_updated;
const importReturnVersions = `
INSERT INTO water.return_versions (
licence_id,
version_number,
start_date,
end_date,
status,
external_id,
date_created,
date_updated
)
SELECT
l.licence_id,
nrv."VERS_NO"::integer AS version_number,
to_date(nrv."EFF_ST_DATE", 'DD/MM/YYYY') AS start_date,
CASE nrv."EFF_END_DATE"
WHEN 'null' THEN NULL
ELSE to_date(nrv."EFF_END_DATE", 'DD/MM/YYYY')
END AS end_date,
(
CASE nrv."STATUS"
WHEN 'SUPER' THEN 'superseded'
WHEN 'DRAFT' THEN 'draft'
WHEN 'CURR' THEN 'current'
END
)::water.return_version_status AS status,
concat_ws(':', nrv."FGAC_REGION_CODE", nrv."AABL_ID", nrv."VERS_NO") AS external_id,
NOW() AS date_created,
NOW() AS date_updated
FROM
import."NALD_RET_VERSIONS" nrv
JOIN import."NALD_ABS_LICENCES" nl
ON nrv."AABL_ID" = nl."ID"
AND nrv."FGAC_REGION_CODE" = nl."FGAC_REGION_CODE"
JOIN water.licences l
ON l.licence_ref = nl."LIC_NO"
ON CONFLICT (external_id) DO
UPDATE SET
licence_id = excluded.licence_id,
start_date = excluded.start_date,
end_date = excluded.end_date,
status = excluded.status,
date_updated = excluded.date_updated;
`

const importReturnRequirements = `insert into water.return_requirements ( return_version_id, legacy_id, abstraction_period_start_day, abstraction_period_start_month,
Expand Down

0 comments on commit d40b2c5

Please sign in to comment.