-
Notifications
You must be signed in to change notification settings - Fork 5
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
pass through gap data (target/met) values with rounding to 4 decimal …
…digits
- Loading branch information
Showing
3 changed files
with
154 additions
and
3 deletions.
There are no files selected for viewing
147 changes: 147 additions & 0 deletions
147
...ssing/1710497811000-IncludeDecimalDigitsWhenRoundingTargetAndCurrentDataInGapDataViews.ts
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,147 @@ | ||
import { MigrationInterface, QueryRunner } from 'typeorm'; | ||
|
||
export class IncludeDecimalDigitsWhenRoundingTargetAndCurrentDataInGapDataViews1710497811000 | ||
implements MigrationInterface | ||
{ | ||
public async up(queryRunner: QueryRunner): Promise<void> { | ||
await queryRunner.query(` | ||
drop view scenario_features_gap_data; | ||
create view scenario_features_gap_data as | ||
with gap_data as ( | ||
select | ||
sfd.api_feature_id as feature_id, | ||
scenario_id, | ||
sum(total_area) total_area, | ||
case when sum(current_pa) is not null | ||
then sum(current_pa) | ||
else 0 | ||
end as met_area, | ||
min(prop) as coverage_target | ||
from scenario_features_data sfd | ||
group by sfd.api_feature_id, feature_class_id, scenario_id) | ||
select | ||
scenario_id, | ||
feature_id, | ||
sum(total_area) as total_area, | ||
sum(met_area) as met_area, | ||
case | ||
when sum(total_area) > 0 | ||
then round(((sum(met_area)/sum(total_area))*100)::numeric, 4) | ||
else 0 | ||
end as met, | ||
sum(total_area) * min(coverage_target) as coverage_target_area, | ||
round((min(coverage_target) * 100)::numeric, 4) as coverage_target, | ||
sum(met_area) >= (sum(total_area) * min(coverage_target)) as on_target | ||
from gap_data | ||
group by feature_id, scenario_id; | ||
`); | ||
|
||
await queryRunner.query(` | ||
drop view scenario_features_output_gap_data; | ||
create view scenario_features_output_gap_data as | ||
with gap_data as ( | ||
select | ||
amount, | ||
occurrences, | ||
run_id, | ||
sfd.api_feature_id as feature_id, | ||
sfd.scenario_id, | ||
osfd.total_area, | ||
sfd.prop as coverage_target, | ||
osfd.target as target_met | ||
from output_scenarios_features_data osfd | ||
inner join scenario_features_data sfd on osfd.scenario_features_id=sfd.id) | ||
select | ||
scenario_id, | ||
feature_id, | ||
sum(total_area) as total_area, | ||
sum(amount) as met_area, | ||
case | ||
when sum(total_area) <> 0 and sum(total_area) is not null then | ||
round(((sum(amount)/sum(total_area))*100)::numeric, 4) | ||
else | ||
0 | ||
end as met, | ||
sum(occurrences) as met_occurrences, | ||
sum(total_area) * min(coverage_target) as coverage_target_area, | ||
round((min(coverage_target) * 100)::numeric, 4) as coverage_target, | ||
bool_and(target_met) as on_target, | ||
run_id | ||
from gap_data | ||
group by run_id, feature_id, scenario_id; | ||
`); | ||
} | ||
|
||
public async down(queryRunner: QueryRunner): Promise<void> { | ||
await queryRunner.query(` | ||
drop view scenario_features_gap_data; | ||
create view scenario_features_gap_data as | ||
with gap_data as ( | ||
select | ||
sfd.api_feature_id as feature_id, | ||
scenario_id, | ||
sum(total_area) total_area, | ||
case when sum(current_pa) is not null | ||
then sum(current_pa) | ||
else 0 | ||
end as met_area, | ||
min(prop) as coverage_target | ||
from scenario_features_data sfd | ||
group by sfd.api_feature_id, feature_class_id, scenario_id) | ||
select | ||
scenario_id, | ||
feature_id, | ||
sum(total_area) as total_area, | ||
sum(met_area) as met_area, | ||
case | ||
when sum(total_area) > 0 | ||
then round((sum(met_area)/sum(total_area))*100) | ||
else 0 | ||
end as met, | ||
sum(total_area) * min(coverage_target) as coverage_target_area, | ||
round(min(coverage_target) * 100) as coverage_target, | ||
sum(met_area) >= (sum(total_area) * min(coverage_target)) as on_target | ||
from gap_data | ||
group by feature_id, scenario_id; | ||
`); | ||
|
||
await queryRunner.query(` | ||
drop view scenario_features_output_gap_data; | ||
create view scenario_features_output_gap_data as | ||
with gap_data as ( | ||
select | ||
amount, | ||
occurrences, | ||
run_id, | ||
sfd.api_feature_id as feature_id, | ||
sfd.scenario_id, | ||
osfd.total_area, | ||
sfd.prop as coverage_target, | ||
osfd.target as target_met | ||
from output_scenarios_features_data osfd | ||
inner join scenario_features_data sfd on osfd.scenario_features_id=sfd.id) | ||
select | ||
scenario_id, | ||
feature_id, | ||
sum(total_area) as total_area, | ||
sum(amount) as met_area, | ||
case | ||
when sum(total_area) <> 0 and sum(total_area) is not null then | ||
round((sum(amount)/sum(total_area))*100) | ||
else | ||
0 | ||
end as met, | ||
sum(occurrences) as met_occurrences, | ||
sum(total_area) * min(coverage_target) as coverage_target_area, | ||
round(min(coverage_target) * 100) as coverage_target, | ||
bool_and(target_met) as on_target, | ||
run_id | ||
from gap_data | ||
group by run_id, feature_id, scenario_id; | ||
`); | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters