diff --git a/api/apps/api/src/modules/scenarios/input-files/puvspr.dat.service.ts b/api/apps/api/src/modules/scenarios/input-files/puvspr.dat.service.ts index 6ceeff052b..861c80dc07 100644 --- a/api/apps/api/src/modules/scenarios/input-files/puvspr.dat.service.ts +++ b/api/apps/api/src/modules/scenarios/input-files/puvspr.dat.service.ts @@ -1,27 +1,48 @@ -import { Repository } from 'typeorm'; +import { Connection, getConnection } from 'typeorm'; import { Injectable } from '@nestjs/common'; -import { InjectRepository } from '@nestjs/typeorm'; - -import { ScenarioPuvsprGeoEntity } from '@marxan/scenario-puvspr'; import { DbConnections } from '@marxan-api/ormconfig.connections'; - +import { InjectConnection } from '@nestjs/typeorm'; @Injectable() export class PuvsprDatService { constructor( - @InjectRepository(ScenarioPuvsprGeoEntity, DbConnections.geoprocessingDB) - private readonly puvsprRepo: Repository, + @InjectConnection(DbConnections.geoprocessingDB) + private readonly connection: Connection, ) {} async getPuvsprDatContent(scenarioId: string): Promise { - const rows = await this.puvsprRepo.find({ - where: { - scenarioId, - }, - }); + /** + * @TODO further performance savings: limiting scans to planning_units_geom + * by partition (we need to get the grid shape from the parent project); use + * && operator instead of st_intersects() for bbox-based calculation of + * intersections. + */ + const rows: { + scenario_id: string; + pu_id: number; + feature_id: number; + amount: number; + }[] = await this.connection.query(` + select pu.scenario_id as scenario_id, puid as pu_id, feature_id, ST_Area(ST_Transform(st_intersection(species.the_geom, pu.the_geom),3410)) as amount + from + ( + select scenario_id, the_geom, sfd.feature_id + from scenario_features_data sfd + inner join features_data fd on sfd.feature_class_id = fd.id where sfd.scenario_id = '${scenarioId}' + ) species, + ( + select the_geom, spd.puid, spd.scenario_id + from planning_units_geom pug + inner join scenarios_pu_data spd on pug.id = spd.pu_geom_id where spd.scenario_id = '${scenarioId}' order by puid asc + ) pu + where pu.scenario_id = '${scenarioId}' and species.the_geom && pu.the_geom + order by puid, feature_id asc; + `); return ( 'species\tpu\tamount\n' + rows - .map((row) => `${row.featureId}\t${row.puId}\t${row.amount.toFixed(6)}`) + .map( + (row) => `${row.feature_id}\t${row.pu_id}\t${row.amount.toFixed(6)}`, + ) .join('\n') ); } diff --git a/api/apps/api/src/modules/scenarios/input-files/puvspr.data.service.spec.ts b/api/apps/api/src/modules/scenarios/input-files/puvspr.data.service.spec.ts index ef7fb68f3d..ef228e8a03 100644 --- a/api/apps/api/src/modules/scenarios/input-files/puvspr.data.service.spec.ts +++ b/api/apps/api/src/modules/scenarios/input-files/puvspr.data.service.spec.ts @@ -1,6 +1,6 @@ import { Repository } from 'typeorm'; import { ScenarioPuvsprGeoEntity } from '@marxan/scenario-puvspr'; -import { getRepositoryToken } from '@nestjs/typeorm'; +import { getConnectionToken, getRepositoryToken } from '@nestjs/typeorm'; import { Test } from '@nestjs/testing'; import { DbConnections } from '@marxan-api/ormconfig.connections'; @@ -10,17 +10,14 @@ let sut: PuvsprDatService; let dataRepo: jest.Mocked>; beforeEach(async () => { - const token = getRepositoryToken( - ScenarioPuvsprGeoEntity, - DbConnections.geoprocessingDB, - ); + const token = getConnectionToken(DbConnections.geoprocessingDB); const sandbox = await Test.createTestingModule({ providers: [ PuvsprDatService, { provide: token, useValue: { - find: jest.fn(), + query: jest.fn(), } as any, }, ], @@ -32,7 +29,7 @@ beforeEach(async () => { describe(`when there are no rows`, () => { beforeEach(() => { - dataRepo.find.mockImplementationOnce(async () => []); + dataRepo.query.mockImplementationOnce(async () => []); }); it(`should return headers only`, async () => { @@ -44,24 +41,24 @@ describe(`when there are no rows`, () => { describe(`when there is data available`, () => { beforeEach(() => { - dataRepo.find.mockImplementationOnce(async () => [ + dataRepo.query.mockImplementationOnce(async () => [ { amount: 1000.0, - scenarioId: 'scenarioId', - featureId: 'feature-1', - puId: 'pu-1,', + scenario_id: 'scenarioId', + feature_id: 'feature-1', + pu_id: 'pu-1,', }, { amount: 0.001, - scenarioId: 'scenarioId', - featureId: 'feature-1', - puId: 'pu-2,', + scenario_id: 'scenarioId', + feature_id: 'feature-1', + pu_id: 'pu-2,', }, { amount: 99.995, - scenarioId: 'scenarioId', - featureId: 'feature-1', - puId: 'pu-3,', + scenario_id: 'scenarioId', + feature_id: 'feature-1', + pu_id: 'pu-3,', }, ]); }); diff --git a/api/apps/geoprocessing/src/migrations/geoprocessing/1627980508000-AddIndexesForPuVSprQueries.ts b/api/apps/geoprocessing/src/migrations/geoprocessing/1627980508000-AddIndexesForPuVSprQueries.ts new file mode 100644 index 0000000000..aef1cfe9af --- /dev/null +++ b/api/apps/geoprocessing/src/migrations/geoprocessing/1627980508000-AddIndexesForPuVSprQueries.ts @@ -0,0 +1,20 @@ +import { MigrationInterface, QueryRunner } from 'typeorm'; + +export class AddIndexesForPuVSprQueries1627980508000 + implements MigrationInterface { + public async up(queryRunner: QueryRunner): Promise { + await queryRunner.query(` +create index scenario_features_data__scenario_id__idx on scenario_features_data(scenario_id); +create index scenarios_pu_data__scenario_id__idx on scenarios_pu_data(scenario_id); +create index scenario_features_data__feature_class_id__idx on scenario_features_data(feature_class_id); + `); + } + + public async down(queryRunner: QueryRunner): Promise { + await queryRunner.query(` +drop index scenario_features_data__scenario_id__idx; +drop index scenarios_pu_data__scenario_id__idx; +drop index scenario_features_data__feature_class_id__idx; + `); + } +} diff --git a/api/libs/scenario-puvspr/src/scenario-puvspr.geo.entity.ts b/api/libs/scenario-puvspr/src/scenario-puvspr.geo.entity.ts index b537be4e40..10dec94cad 100644 --- a/api/libs/scenario-puvspr/src/scenario-puvspr.geo.entity.ts +++ b/api/libs/scenario-puvspr/src/scenario-puvspr.geo.entity.ts @@ -1,5 +1,10 @@ import { ViewColumn, ViewEntity } from 'typeorm'; +/** + * @deprecated Due to performance limitations of the approach using a db view, + * we have moved this logic to a query which is run directly from the service + * responsible for retrieving this data. + */ @ViewEntity({ expression: ` select pu.scenario_id as scenario_id, puid as pu_id, feature_id, ST_Area(ST_Transform(st_intersection(species.the_geom, pu.the_geom),3410)) as amount