Skip to content

Commit

Permalink
update methodology calc., integrate new indicators
Browse files Browse the repository at this point in the history
  • Loading branch information
alexeh committed Sep 4, 2023
1 parent 6d0a6f0 commit dee0774
Show file tree
Hide file tree
Showing 42 changed files with 681 additions and 369 deletions.
200 changes: 200 additions & 0 deletions api/src/migrations/1692854789441-UpdateImpactStoredFunctions.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,200 @@
import { MigrationInterface, QueryRunner } from 'typeorm';

export class UpdateImpactStoredFunctions1692854789441
implements MigrationInterface
{
public async up(queryRunner: QueryRunner): Promise<void> {
/**
* @description: This function is used to get the h3 table name and column name for a given indicator by its name code
*/
await queryRunner.query(`
CREATE OR REPLACE FUNCTION get_h3_table_column_for_indicators_by_name_code(name_code text)
RETURNS TABLE (h3_table_name varchar, h3_column_name varchar, h3_resolution int) AS
$$
SELECT h3_data."h3tableName", h3_data."h3columnName", h3_data."h3resolution"
FROM h3_data
INNER JOIN "indicator" ind ON ind."id" = h3_data."indicatorId"
WHERE ind."nameCode" = name_code
$$
LANGUAGE SQL;`);

/**
* @description: Calculates Impact for deforestation, climate risk, carbon and natural conversion
*
* @notes: ##NOTE: Assuming that deforestation-ghg emissions/human land use has been preprocessed and stored in the ddbb
* ## UPDATED DEFORESTATION, CLIMATE RISK FORMULAS/CARBON, NATURAL CONVERSION:
*/

await queryRunner.query(`
CREATE OR REPLACE FUNCTION get_annual_landscape_impact_over_georegion(
geo_region_id uuid,
name_code text,
material_id uuid,
h3_material_type material_to_h3_type_enum
)
RETURNS float AS
$$
DECLARE
h3_resolution integer;
indicator_h3_table_name varchar;
indicator_h3_column_name varchar;
h3_indicator_resolution varchar;
material_h3_table_name varchar;
material_h3_column_name varchar;
sum float;
BEGIN
-- Get h3data table name, column for indicator given name_code
SELECT * INTO indicator_h3_table_name, indicator_h3_column_name, h3_indicator_resolution
FROM get_h3_table_column_for_indicators_by_name_code(name_code);
-- Get h3data table name, column and resolution for the material, given the material id and h3_
SELECT * INTO material_h3_table_name, material_h3_column_name, h3_resolution
FROM get_h3_table_column_for_material(material_id, h3_material_type);
-- Sum landscape impact values
EXECUTE format(
'SELECT sum(h3ind.%I * h3prod.%I )
FROM
get_h3_uncompact_geo_region($1, $2) geo_region
INNER JOIN %I h3ind ON h3ind.h3index = geo_region.h3index
INNER JOIN %I h3prod ON h3ind.h3index = h3prod.h3index;
', indicator_h3_column_name, material_h3_column_name, indicator_h3_table_name, material_h3_table_name)
USING geo_region_id, h3_resolution
INTO sum;
RETURN sum;
END;
$$
LANGUAGE plpgsql;
`);
/**
* @description: Calculates Impact for new indicators added as part of this change
*
* @notes: ## NEW INDICATORS:
*
* ## Water quality - use the same function as the blue water footprint
* #I have slightly modified the formula to make it dependent on the indicator table
*/

await queryRunner.query(`
CREATE OR REPLACE FUNCTION get_indicator_coefficient_impact(
name_code text,
adminRegionId uuid,
material_id uuid)
RETURNS float AS
$$
DECLARE
indicator_id uuid;
value float;
BEGIN
--get indicatorId
SELECT "id" INTO indicator_id FROM "indicator"
WHERE "nameCode" = name_code;
-- get water footprint value by location, material and indicator
EXECUTE format(
'SELECT
COALESCE (
(
SELECT ic."value" /1000 --convert the m3 to Mm3
FROM "indicator_coefficient" ic
WHERE ic."adminRegionId" = $1
AND ic."materialId" = $2
AND ic."indicatorId" = $3
AND ic."value" IS NOT NULL
),
(
SELECT ic."value" /1000 --convert the m3 to Mm3
FROM "indicator_coefficient" ic
WHERE ic."adminRegionId" IS NULL
AND ic."materialId" = $2
AND ic."indicatorId" = $3
AND ic."value" IS NOT NULL
)
) AS value;'
)
USING adminRegionId, material_id, indicator_id
INTO value;
RETURN value;
END;
$$
LANGUAGE plpgsql;
`);

await queryRunner.query(`
DROP FUNCTION IF EXISTS get_percentage_water_stress_area;
CREATE OR REPLACE FUNCTION get_percentage_water_stress_area(
geo_region_id uuid,
name_code text
)
RETURNS float AS
$$
DECLARE
aqueduct_h3_table_name varchar;
aqueduct_h3_column_name varchar;
h3_resolution integer;
percentage float;
BEGIN
-- Get h3data table name, column
SELECT * INTO aqueduct_h3_table_name, aqueduct_h3_column_name, h3_resolution
FROM get_h3_table_column_for_indicators_by_name_code(name_code);
EXECUTE format(
'SELECT reduced.ws_area/ reduced.g_area as percentage
FROM
(SELECT
sum(case when aqueduct.%I > 3 then 1 else 0 end) ws_area, count(aqueduct.%I) g_area
FROM get_h3_uncompact_geo_region($1, $2) geo_region
INNER JOIN %I aqueduct ON aqueduct.h3index = geo_region.h3index) reduced
WHERE reduced.g_area > 0;',
aqueduct_h3_column_name,
aqueduct_h3_column_name,
aqueduct_h3_table_name
)
USING geo_region_id, h3_resolution
INTO percentage;
RETURN percentage;
END;
$$
LANGUAGE plpgsql;`);

await queryRunner.query(`DROP FUNCTION IF EXISTS sum_h3_cropland_area`);

await queryRunner.query(
`DROP FUNCTION IF EXISTS sum_weighted_deforestation_over_georegion`,
);

await queryRunner.query(
`DROP FUNCTION IF EXISTS sum_weighted_carbon_over_georegion`,
);

await queryRunner.query(`DROP FUNCTION IF EXISTS get_blfw_impact`);
}

/**
* @description: Remove procedures that are no longer needed
*/

public async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(
`DROP FUNCTION IF EXISTS get_annual_landscape_impact_over_georegion`,
);

await queryRunner.query(
`DROP FUNCTION IF EXISTS get_indicator_coefficient_impact`,
);

await queryRunner.query(
`DROP FUNCTION IF EXISTS get_h3_table_column_for_indicators_by_name_code`,
);

await queryRunner.query(
`DROP FUNCTION IF EXISTS get_percentage_water_stress_area`,
);
}
}
4 changes: 2 additions & 2 deletions api/src/modules/h3-data/h3-data.repository.ts
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,7 @@ import {
NotFoundException,
ServiceUnavailableException,
} from '@nestjs/common';
import { INDICATOR_TYPES } from 'modules/indicators/indicator.entity';
import { INDICATOR_NAME_CODES } from 'modules/indicators/indicator.entity';
import { MATERIAL_TO_H3_TYPE } from 'modules/materials/material-to-h3.entity';
import {
GetActualVsScenarioImpactMapDto,
Expand Down Expand Up @@ -237,7 +237,7 @@ export class H3DataRepository extends Repository<H3Data> {
* @param year
*/
async getIndicatorH3ByTypeAndClosestYear(
type: INDICATOR_TYPES,
type: INDICATOR_NAME_CODES,
year: number,
): Promise<H3Data | undefined> {
const queryBuilder: SelectQueryBuilder<H3Data> = this.dataSource
Expand Down
12 changes: 6 additions & 6 deletions api/src/modules/h3-data/h3-data.service.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,7 @@ import { H3Data, H3IndexValueData } from 'modules/h3-data/h3-data.entity';
import { MaterialsService } from 'modules/materials/materials.service';
import { IndicatorsService } from 'modules/indicators/indicators.service';
import { UnitConversionsService } from 'modules/unit-conversions/unit-conversions.service';
import { INDICATOR_TYPES } from 'modules/indicators/indicator.entity';
import { INDICATOR_NAME_CODES } from 'modules/indicators/indicator.entity';
import { SourcingRecordsService } from 'modules/sourcing-records/sourcing-records.service';
import { H3DataYearsService } from 'modules/h3-data/services/h3-data-years.service';
import { MaterialsToH3sService } from 'modules/materials/materials-to-h3s.service';
Expand Down Expand Up @@ -107,20 +107,20 @@ export class H3DataService {
}

getIndicatorH3sByTypeAndClosestYear(
indicatorTypes: INDICATOR_TYPES[],
indicatorTypes: INDICATOR_NAME_CODES[],
year: number,
): Promise<Map<INDICATOR_TYPES, H3Data>> {
): Promise<Map<INDICATOR_NAME_CODES, H3Data>> {
return indicatorTypes.reduce(
async (
previousValue: Promise<Map<INDICATOR_TYPES, H3Data>>,
currentValue: INDICATOR_TYPES,
previousValue: Promise<Map<INDICATOR_NAME_CODES, H3Data>>,
currentValue: INDICATOR_NAME_CODES,
) => {
const h3data: H3Data | undefined =
await this.h3DataRepository.getIndicatorH3ByTypeAndClosestYear(
currentValue,
year,
);
const map: Map<INDICATOR_TYPES, H3Data> = await previousValue;
const map: Map<INDICATOR_NAME_CODES, H3Data> = await previousValue;

if (h3data) {
map.set(currentValue, h3data);
Expand Down
2 changes: 2 additions & 0 deletions api/src/modules/impact/impact.module.ts
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,7 @@ import { ScenarioVsScenarioImpactService } from 'modules/impact/comparison/scena
import { MaterialsService } from 'modules/materials/materials.service';
import { SourcingLocationsModule } from 'modules/sourcing-locations/sourcing-locations.module';
import { AuthorizationModule } from 'modules/authorization/authorization.module';
import { ImpactViewUpdater } from 'modules/impact/views/impact-view.updater';

@Module({
imports: [
Expand All @@ -29,6 +30,7 @@ import { AuthorizationModule } from 'modules/authorization/authorization.module'
ActualVsScenarioImpactService,
ScenarioVsScenarioImpactService,
MaterialsService,
ImpactViewUpdater,
],
controllers: [ImpactController],
exports: [
Expand Down
19 changes: 3 additions & 16 deletions api/src/modules/impact/impact.service.ts
Original file line number Diff line number Diff line change
Expand Up @@ -30,8 +30,7 @@ import {
ImpactDataTableAuxMap,
} from 'modules/impact/base-impact.service';
import { SourcingLocationsService } from 'modules/sourcing-locations/sourcing-locations.service';
import { IMPACT_VIEW_NAME } from 'modules/impact/views/impact.materialized-view.entity';
import { DataSource } from 'typeorm';
import { ImpactViewUpdater } from 'modules/impact/views/impact-view.updater';

@Injectable()
export class ImpactService extends BaseImpactService {
Expand All @@ -45,7 +44,7 @@ export class ImpactService extends BaseImpactService {
protected readonly materialsService: MaterialsService,
protected readonly sourcingRecordService: SourcingRecordsService,
protected readonly sourcingLocationsService: SourcingLocationsService,
private readonly dataSource: DataSource,
private readonly viewUpdater: ImpactViewUpdater,
) {
super(
indicatorService,
Expand Down Expand Up @@ -217,19 +216,7 @@ export class ImpactService extends BaseImpactService {
}

async updateImpactView(): Promise<void> {
const result: any = await this.dataSource.query(
`SELECT * FROM pg_matviews WHERE matviewname = '${IMPACT_VIEW_NAME}'`,
);
if (!result[0].ispopulated) {
this.logger.warn('Populating Impact View for the first time...');
return this.dataSource.query(
`REFRESH MATERIALIZED VIEW ${IMPACT_VIEW_NAME} WITH DATA`,
);
}
this.logger.warn('Refreshing Impact View...');
return this.dataSource.query(
`REFRESH MATERIALIZED VIEW CONCURRENTLY ${IMPACT_VIEW_NAME} WITH DATA`,
);
return this.viewUpdater.updateImpactView();
}

private buildImpactTable(
Expand Down
38 changes: 38 additions & 0 deletions api/src/modules/impact/views/impact-view.updater.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@
import { Injectable, Logger } from '@nestjs/common';
import { DataSource } from 'typeorm';
import { IMPACT_VIEW_NAME } from 'modules/impact/views/impact.materialized-view.entity';

@Injectable()
export class ImpactViewUpdater {
logger: Logger = new Logger(ImpactViewUpdater.name);

constructor(private readonly dataSource: DataSource) {}

async updateImpactView(): Promise<void> {
if (await this.isViewEmpty()) {
return this.populateViewForTheFirstTime();
}
return this.refreshView();
}

private async isViewEmpty(): Promise<boolean> {
const result: any = await this.dataSource.query(
`SELECT * FROM pg_matviews WHERE matviewname = '${IMPACT_VIEW_NAME}'`,
);
return !result[0].ispopulated;
}

private async populateViewForTheFirstTime(): Promise<void> {
this.logger.warn('Populating Impact View for the first time...');
return this.dataSource.query(
`REFRESH MATERIALIZED VIEW ${IMPACT_VIEW_NAME} WITH DATA`,
);
}

private async refreshView(): Promise<void> {
this.logger.warn('Refreshing Impact View...');
return this.dataSource.query(
`REFRESH MATERIALIZED VIEW CONCURRENTLY ${IMPACT_VIEW_NAME} WITH DATA`,
);
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -185,11 +185,11 @@ export class SourcingDataImportService {
// TODO: Current approach calculates Impact for all Sourcing Records present in the DB
// Getting H3 data for calculations is done within DB so we need to improve the error handling
// TBD: What to do when there is no H3 for a Material

try {
await this.impactCalculator.calculateImpactForAllSourcingRecords(
activeIndicators,
);

this.logger.log('Indicator Records generated');
await this.impactService.updateImpactView();
} catch (err: any) {
Expand Down
Loading

0 comments on commit dee0774

Please sign in to comment.