Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

PIMS-1945: Property views exclude deleted rows #2589

Merged
merged 5 commits into from
Jul 31, 2024
Merged
Show file tree
Hide file tree
Changes from 2 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,8 @@ import { ViewColumn, ViewEntity } from 'typeorm';
SELECT b.id AS "building_id", b.pid, b.pin, p.id as "parcel_id"
FROM building b
LEFT OUTER JOIN parcel p
ON b.pid = p.pid OR b.pin = p.pin;
ON (b.pid = p.pid OR b.pin = p.pin) AND p.deleted_on IS NULL
WHERE b.deleted_on IS NULL;
`,
})
export class BuildingRelations {
Expand Down
4 changes: 2 additions & 2 deletions express-api/src/typeorm/Entities/views/MapPropertiesView.ts
Original file line number Diff line number Diff line change
Expand Up @@ -7,10 +7,10 @@ import { ViewColumn, ViewEntity } from 'typeorm';
SELECT c.id, c.pid, c.pin, c.location, c.property_type_id, c.address1, c.classification_id, c.agency_id, c.is_visible_to_other_agencies, c.administrative_area_id, c.name, aa.regional_district_id as regional_district_id
FROM (
SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name
FROM parcel
FROM parcel WHERE deleted_on IS NULL
UNION ALL
SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name
FROM building
FROM building WHERE deleted_on IS NULL
) c
LEFT JOIN administrative_area aa ON c.administrative_area_id = aa.id;
`,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@ import { ViewColumn, ViewEntity } from 'typeorm';
updated_on,
land_area
FROM parcel p
WHERE deleted_on IS NULL
UNION ALL
SELECT
'Building' AS property_type,
Expand All @@ -30,7 +31,8 @@ SELECT
is_sensitive,
updated_on,
NULL AS land_area
FROM building b)
FROM building b
WHERE deleted_on IS NULL)
SELECT
property.*,
agc."name" AS agency_name,
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,204 @@
import { MigrationInterface, QueryRunner } from 'typeorm';

export class PropertyViewsMissingDeletedOnClause1722362022034 implements MigrationInterface {
name = 'PropertyViewsMissingDeletedOnClause1722362022034';

public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(
`DELETE FROM "typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`,
['VIEW', 'property_union', 'public'],
);
await queryRunner.query(`DROP VIEW "property_union"`);
await queryRunner.query(
`DELETE FROM "typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`,
['VIEW', 'map_properties', 'public'],
);
await queryRunner.query(`DROP VIEW "map_properties"`);
await queryRunner.query(
`DELETE FROM "typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`,
['MATERIALIZED_VIEW', 'building_relations', 'public'],
);
await queryRunner.query(`DROP MATERIALIZED VIEW "building_relations"`);
await queryRunner.query(`CREATE VIEW "building_relations" AS
SELECT b.id AS "building_id", b.pid, b.pin, p.id as "parcel_id"
FROM building b
LEFT OUTER JOIN parcel p
ON (b.pid = p.pid OR b.pin = p.pin) AND p.deleted_on IS NULL
WHERE b.deleted_on IS NULL;
`);
await queryRunner.query(
`INSERT INTO "typeorm_metadata"("database", "schema", "table", "type", "name", "value") VALUES (DEFAULT, $1, DEFAULT, $2, $3, $4)`,
[
'public',
'VIEW',
'building_relations',
'SELECT b.id AS "building_id", b.pid, b.pin, p.id as "parcel_id"\n FROM building b\n LEFT OUTER JOIN parcel p\n ON (b.pid = p.pid OR b.pin = p.pin) AND p.deleted_on IS NULL\n WHERE b.deleted_on IS NULL;',
],
);
await queryRunner.query(`CREATE VIEW "map_properties" AS
SELECT c.id, c.pid, c.pin, c.location, c.property_type_id, c.address1, c.classification_id, c.agency_id, c.is_visible_to_other_agencies, c.administrative_area_id, c.name, aa.regional_district_id as regional_district_id
FROM (
SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name
FROM parcel WHERE deleted_on IS NULL
UNION ALL
SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name
FROM building WHERE deleted_on IS NULL
) c
LEFT JOIN administrative_area aa ON c.administrative_area_id = aa.id;
`);
await queryRunner.query(
`INSERT INTO "typeorm_metadata"("database", "schema", "table", "type", "name", "value") VALUES (DEFAULT, $1, DEFAULT, $2, $3, $4)`,
[
'public',
'VIEW',
'map_properties',
'SELECT c.id, c.pid, c.pin, c.location, c.property_type_id, c.address1, c.classification_id, c.agency_id, c.is_visible_to_other_agencies, c.administrative_area_id, c.name, aa.regional_district_id as regional_district_id\n FROM (\n SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name \n FROM parcel WHERE deleted_on IS NULL\n UNION ALL\n SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name \n FROM building WHERE deleted_on IS NULL\n ) c\n LEFT JOIN administrative_area aa ON c.administrative_area_id = aa.id;',
],
);
await queryRunner.query(`CREATE VIEW "property_union" AS WITH property AS (SELECT
'Parcel' AS property_type,
property_type_id,
id,
classification_id,
pid,
pin,
agency_id,
address1,
administrative_area_id,
is_sensitive,
updated_on,
land_area
FROM parcel p
WHERE deleted_on IS NULL
UNION ALL
SELECT
'Building' AS property_type,
property_type_id,
id,
classification_id,
pid,
pin,
agency_id,
address1,
administrative_area_id,
is_sensitive,
updated_on,
NULL AS land_area
FROM building b
WHERE deleted_on IS NULL)
SELECT
property.*,
agc."name" AS agency_name,
aa."name" AS administrative_area_name,
pc."name" AS property_classification_name
FROM property
LEFT JOIN agency agc ON property.agency_id = agc.id
LEFT JOIN administrative_area aa ON property.administrative_area_id = aa.id
LEFT JOIN property_classification pc ON property.classification_id = pc.id;`);
await queryRunner.query(
`INSERT INTO "typeorm_metadata"("database", "schema", "table", "type", "name", "value") VALUES (DEFAULT, $1, DEFAULT, $2, $3, $4)`,
[
'public',
'VIEW',
'property_union',
'WITH property AS (SELECT \n\t\'Parcel\' AS property_type,\n property_type_id,\n\tid,\n\tclassification_id,\n\tpid,\n\tpin,\n\tagency_id,\n\taddress1,\n\tadministrative_area_id,\n\tis_sensitive,\n\tupdated_on,\n\tland_area\nFROM parcel p\nWHERE deleted_on IS NULL\nUNION ALL\nSELECT \n\t\'Building\' AS property_type,\n property_type_id,\n\tid,\n\tclassification_id,\n\tpid,\n\tpin,\n\tagency_id,\n\taddress1,\n\tadministrative_area_id,\n\tis_sensitive,\n\tupdated_on,\n\tNULL AS land_area\nFROM building b\nWHERE deleted_on IS NULL)\nSELECT \n\tproperty.*, \n\tagc."name" AS agency_name,\n\taa."name" AS administrative_area_name,\n\tpc."name" AS property_classification_name\nFROM property \n\tLEFT JOIN agency agc ON property.agency_id = agc.id\n\tLEFT JOIN administrative_area aa ON property.administrative_area_id = aa.id\n\tLEFT JOIN property_classification pc ON property.classification_id = pc.id;',
],
);
}

public async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(
`DELETE FROM "typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`,
['VIEW', 'property_union', 'public'],
);
await queryRunner.query(`DROP VIEW "property_union"`);
await queryRunner.query(
`DELETE FROM "typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`,
['VIEW', 'map_properties', 'public'],
);
await queryRunner.query(`DROP VIEW "map_properties"`);
await queryRunner.query(
`DELETE FROM "typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`,
['VIEW', 'building_relations', 'public'],
);
await queryRunner.query(`DROP VIEW "building_relations"`);
await queryRunner.query(`CREATE MATERIALIZED VIEW "building_relations" AS SELECT b.id AS "building_id", b.pid, b.pin, p.id as "parcel_id"
FROM building b
LEFT OUTER JOIN parcel p
ON b.pid = p.pid OR b.pin = p.pin;`);
await queryRunner.query(
`INSERT INTO "typeorm_metadata"("database", "schema", "table", "type", "name", "value") VALUES (DEFAULT, $1, DEFAULT, $2, $3, $4)`,
[
'public',
'MATERIALIZED_VIEW',
'building_relations',
'SELECT b.id AS "building_id", b.pid, b.pin, p.id as "parcel_id"\n FROM building b\n LEFT OUTER JOIN parcel p\n ON b.pid = p.pid OR b.pin = p.pin;',
],
);
await queryRunner.query(`CREATE VIEW "map_properties" AS SELECT c.id, c.pid, c.pin, c.location, c.property_type_id, c.address1, c.classification_id, c.agency_id, c.is_visible_to_other_agencies, c.administrative_area_id, c.name, aa.regional_district_id as regional_district_id
FROM (
SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name
FROM parcel
UNION ALL
SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name
FROM building
) c
LEFT JOIN administrative_area aa ON c.administrative_area_id = aa.id;`);
await queryRunner.query(
`INSERT INTO "typeorm_metadata"("database", "schema", "table", "type", "name", "value") VALUES (DEFAULT, $1, DEFAULT, $2, $3, $4)`,
[
'public',
'VIEW',
'map_properties',
'SELECT c.id, c.pid, c.pin, c.location, c.property_type_id, c.address1, c.classification_id, c.agency_id, c.is_visible_to_other_agencies, c.administrative_area_id, c.name, aa.regional_district_id as regional_district_id\n FROM (\n SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name \n FROM parcel\n UNION ALL\n SELECT id, pid, pin, location, property_type_id, address1, classification_id, agency_id, is_visible_to_other_agencies, administrative_area_id, name \n FROM building\n ) c\n LEFT JOIN administrative_area aa ON c.administrative_area_id = aa.id;',
],
);
await queryRunner.query(`CREATE VIEW "property_union" AS WITH property AS (SELECT
'Parcel' AS property_type,
property_type_id,
id,
classification_id,
pid,
pin,
agency_id,
address1,
administrative_area_id,
is_sensitive,
updated_on,
land_area
FROM parcel p
UNION ALL
SELECT
'Building' AS property_type,
property_type_id,
id,
classification_id,
pid,
pin,
agency_id,
address1,
administrative_area_id,
is_sensitive,
updated_on,
NULL AS land_area
FROM building b)
SELECT
property.*,
agc."name" AS agency_name,
aa."name" AS administrative_area_name,
pc."name" AS property_classification_name
FROM property
LEFT JOIN agency agc ON property.agency_id = agc.id
LEFT JOIN administrative_area aa ON property.administrative_area_id = aa.id
LEFT JOIN property_classification pc ON property.classification_id = pc.id;`);
await queryRunner.query(
`INSERT INTO "typeorm_metadata"("database", "schema", "table", "type", "name", "value") VALUES (DEFAULT, $1, DEFAULT, $2, $3, $4)`,
[
'public',
'VIEW',
'property_union',
'WITH property AS (SELECT \n\t\'Parcel\' AS property_type,\n property_type_id,\n\tid,\n\tclassification_id,\n\tpid,\n\tpin,\n\tagency_id,\n\taddress1,\n\tadministrative_area_id,\n\tis_sensitive,\n\tupdated_on,\n\tland_area\nFROM parcel p\nUNION ALL\nSELECT \n\t\'Building\' AS property_type,\n property_type_id,\n\tid,\n\tclassification_id,\n\tpid,\n\tpin,\n\tagency_id,\n\taddress1,\n\tadministrative_area_id,\n\tis_sensitive,\n\tupdated_on,\n\tNULL AS land_area\nFROM building b)\nSELECT \n\tproperty.*, \n\tagc."name" AS agency_name,\n\taa."name" AS administrative_area_name,\n\tpc."name" AS property_classification_name\nFROM property \n\tLEFT JOIN agency agc ON property.agency_id = agc.id\n\tLEFT JOIN administrative_area aa ON property.administrative_area_id = aa.id\n\tLEFT JOIN property_classification pc ON property.classification_id = pc.id;',
],
);
}
}
10 changes: 10 additions & 0 deletions react-app/src/components/map/ParcelMap.tsx
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ import React, {
PropsWithChildren,
useContext,
useEffect,
useMemo,
useRef,
useState,
} from 'react';
Expand Down Expand Up @@ -76,6 +77,15 @@ const ParcelMap = (props: ParcelMapProps) => {
api.properties.propertiesGeoSearch(filter),
);

const deletionBroadcastChannel = useMemo(() => new BroadcastChannel('property'), []);
useEffect(() =>
deletionBroadcastChannel.addEventListener('message', (event) => {
if (typeof event.data === 'string' && event.data === 'refresh') {
refreshData();
}
}),
dbarkowsky marked this conversation as resolved.
Show resolved Hide resolved
);

// Controls ClusterPopup contents
const [popupState, setPopupState] = useState<PopupState>({
open: false,
Expand Down
9 changes: 8 additions & 1 deletion react-app/src/components/property/PropertyDetail.tsx
Original file line number Diff line number Diff line change
Expand Up @@ -43,6 +43,7 @@ const PropertyDetail = (props: IPropertyDetail) => {
const parcelId = isNaN(Number(params.parcelId)) ? null : Number(params.parcelId);
const buildingId = isNaN(Number(params.buildingId)) ? null : Number(params.buildingId);
const api = usePimsApi();
const deletionBroadcastChannel = useMemo(() => new BroadcastChannel('property'), []);
const {
data: parcel,
refreshData: refreshParcel,
Expand Down Expand Up @@ -262,6 +263,12 @@ const PropertyDetail = (props: IPropertyDetail) => {
const [openNetBookDialog, setOpenNetBookDialog] = useState(false);
const [openAssessedValueDialog, setOpenAssessedValueDialog] = useState(false);

const deletionAction = async () => {
deletionBroadcastChannel.postMessage('refresh');
await deleteProperty();
navigate('/properties');
GrahamS-Quartech marked this conversation as resolved.
Show resolved Hide resolved
};

const sideBarItems = [
{ title: `${buildingOrParcel} Information` },
{ title: `${buildingOrParcel} Net Book Value` },
Expand Down Expand Up @@ -407,7 +414,7 @@ const PropertyDetail = (props: IPropertyDetail) => {
title={'Delete property'}
message={'Are you sure you want to delete this property?'}
confirmButtonProps={{ loading: deletingProperty }}
onDelete={async () => deleteProperty().then(() => navigate('/properties'))}
onDelete={async () => deletionAction()}
onClose={async () => setOpenDeleteDialog(false)}
/>
</CollapsibleSidebar>
Expand Down
Loading