Skip to content
Open
Show file tree
Hide file tree
Changes from all 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
2,014 changes: 2,014 additions & 0 deletions lib/data/profiles/vd/projections.csv

Large diffs are not rendered by default.

263 changes: 96 additions & 167 deletions lib/data/sql/export_projections.sql
Original file line number Diff line number Diff line change
@@ -1,167 +1,96 @@
drop table if exists export.projections;
create table export.projections (id SERIAL, forestecoregion TEXT, altitudinalzone TEXT, foresttype TEXT, additional TEXT, silverfirarea TEXT, relief TEXT, slope TEXT, targetaltitudinalzone TEXT, targetforesttype TEXT);
truncate export.projections;
insert into
export.projections (forestecoregion, altitudinalzone, foresttype, additional, silverfirarea, relief, slope, targetaltitudinalzone, targetforesttype) -- 3.) Match CSV values to enum values.
with slopes as
(
select
slope,
array_to_string(regexp_matches(slope, '(<|>).*(\d{2})'), '') parsed_slope
from
projections_import
)
select distinct
processed_forest_ecoregion as forestecoregion,
altitudinal_zone_meta.code as altitudinalzone,
case
trim(both
from
forest_type) = any(
select
code
from
foresttype_meta)
when
true
then
forest_type
else
null
end
as foresttype,
case
additional_meta.target is null
when
true
then
'unknown'
else
additional_meta.target
end
as additional,
case
silver_fir_area_meta.target is null
when
true
then
'unknown'
else
silver_fir_area_meta.target
end
as silverfirarea,
case
relief_meta.target is null
when
true
then
'unknown'
else
relief_meta.target
end
as relief,
case
slopes.slope is null
when
true
then
'unknown'
else
slopes.parsed_slope
end
as slope, target_altitudinal_zone_meta.code as targetaltitudinalzone,
case
processed_target_forest_type = any(
select
code
from
foresttype_meta)
when
true
then
processed_target_forest_type
else
null
end
as targetforesttype
from
(
select
(regexp_matches(regexp_split_to_table(regexp_replace(regexp_replace(coalesce(forest_ecoregions, forest_ecoregions_specific), '2(,|\s)', '2a, 2b,'), 'R 5', '5a, 5b,'), ',\s?'),
(
select
string_agg(subcode, '|'::text)
from
forest_ecoregions
)
))[1] as processed_forest_ecoregion,
case
when
target_altitudinal_zone ~ 'Nebenareal'
then
'nebenareal'
when
target_altitudinal_zone ~ 'Hauptareal'
then
'hauptareal'
when
target_altitudinal_zone ~ 'Reliktareal'
then
'reliktareal'
else
processed_silver_fir_area
end
as processed_silver_fir_area2,
case
when
target_altitudinal_zone ~ 'hochmontan'
then
'hochmontan'
else
trim(target_altitudinal_zone)
end
as processed_target_altitudinal_zone, regexp_replace(trim(both
from
target_forest_type), ' ', ' ') as processed_target_forest_type, *
from
(
select
(regexp_matches(regexp_split_to_table(regexp_replace(regexp_replace(coalesce(trim(lower(silver_fir_area)), 'nicht relevant'), 'haupt- und nebenareal', 'hauptareal,nebenareal'), 'haupt- oder nebenareal', 'hauptareal,nebenareal'), ',\s?') ,
(
select
string_agg(lower(areal_de)::text, '|'::text) || '|nicht relevant'
from
silver_fir_areas
)
))[1] as processed_silver_fir_area,
*
from
projections_import
)
import_silver_fir_area
)
import
left join
altitudinal_zone_meta
on lower(altitudinal_zone_meta.source::text) = trim(lower(import.altitudinal_zone))
left join
altitudinal_zone_meta target_altitudinal_zone_meta
on lower(target_altitudinal_zone_meta.source::text) = lower(import.processed_target_altitudinal_zone)
left join
additional_meta
on lower(additional_meta.source) = lower(import.additional)
left join
silver_fir_area_meta
on lower(silver_fir_area_meta.source) = import.processed_silver_fir_area2
left join
relief_meta
on relief_meta.source = import.relief
left join
slopes
on slopes.slope = import.slope
order by
forestecoregion,
altitudinalzone,
foresttype,
targetaltitudinalzone,
targetforesttype;
-- Function to create and populate projections export tables
CREATE OR REPLACE FUNCTION create_projections_export_table(
export_table_name TEXT,
import_table_name TEXT
) RETURNS void AS $$
BEGIN
-- Drop and create the export table
EXECUTE format('DROP TABLE IF EXISTS export.%I', export_table_name);
EXECUTE format('CREATE TABLE export.%I (id SERIAL, forestecoregion TEXT, altitudinalzone TEXT, foresttype TEXT, additional TEXT, silverfirarea TEXT, relief TEXT, slope TEXT, targetaltitudinalzone TEXT, targetforesttype TEXT)', export_table_name);

-- Insert data into the export table
EXECUTE format('
INSERT INTO export.%I (forestecoregion, altitudinalzone, foresttype, additional, silverfirarea, relief, slope, targetaltitudinalzone, targetforesttype)
WITH slopes AS (
SELECT
slope,
array_to_string(regexp_matches(slope, ''(<|>).*(\d{2})''), '''') parsed_slope
FROM %I
)
SELECT DISTINCT
processed_forest_ecoregion as forestecoregion,
altitudinal_zone_meta.code as altitudinalzone,
CASE
WHEN trim(both from forest_type) = any(select code from foresttype_meta)
THEN forest_type
ELSE null
END as foresttype,
CASE
WHEN additional_meta.target is null
THEN ''unknown''
ELSE additional_meta.target
END as additional,
CASE
WHEN silver_fir_area_meta.target is null
THEN ''unknown''
ELSE silver_fir_area_meta.target
END as silverfirarea,
CASE
WHEN relief_meta.target is null
THEN ''unknown''
ELSE relief_meta.target
END as relief,
CASE
WHEN slopes.slope is null
THEN ''unknown''
ELSE slopes.parsed_slope
END as slope,
target_altitudinal_zone_meta.code as targetaltitudinalzone,
CASE
WHEN processed_target_forest_type = any(select code from foresttype_meta)
THEN processed_target_forest_type
ELSE null
END as targetforesttype
FROM (
SELECT
(regexp_matches(regexp_split_to_table(regexp_replace(regexp_replace(coalesce(forest_ecoregions, forest_ecoregions_specific), ''2(,|\s)'', ''2a, 2b,''), ''R 5'', ''5a, 5b,''), '',\s?''),
(SELECT string_agg(subcode, ''|''::text) FROM forest_ecoregions)
))[1] as processed_forest_ecoregion,
CASE
WHEN target_altitudinal_zone ~ ''Nebenareal'' THEN ''nebenareal''
WHEN target_altitudinal_zone ~ ''Hauptareal'' THEN ''hauptareal''
WHEN target_altitudinal_zone ~ ''Reliktareal'' THEN ''reliktareal''
ELSE processed_silver_fir_area
END as processed_silver_fir_area2,
CASE
WHEN target_altitudinal_zone ~ ''hochmontan'' THEN ''hochmontan''
ELSE trim(target_altitudinal_zone)
END as processed_target_altitudinal_zone,
regexp_replace(trim(both from target_forest_type), '' '', '' '') as processed_target_forest_type,
*
FROM (
SELECT
(regexp_matches(regexp_split_to_table(regexp_replace(regexp_replace(coalesce(trim(lower(silver_fir_area)), ''nicht relevant''), ''haupt- und nebenareal'', ''hauptareal,nebenareal''), ''haupt- oder nebenareal'', ''hauptareal,nebenareal''), '',\s?'') ,
(SELECT string_agg(lower(areal_de)::text, ''|''::text) || ''|nicht relevant'' FROM silver_fir_areas)
))[1] as processed_silver_fir_area,
*
FROM %I
) import_silver_fir_area
) import
LEFT JOIN altitudinal_zone_meta ON lower(altitudinal_zone_meta.source::text) = trim(lower(import.altitudinal_zone))
LEFT JOIN altitudinal_zone_meta target_altitudinal_zone_meta ON lower(target_altitudinal_zone_meta.source::text) = lower(import.processed_target_altitudinal_zone)
LEFT JOIN additional_meta ON lower(additional_meta.source) = lower(import.additional)
LEFT JOIN silver_fir_area_meta ON lower(silver_fir_area_meta.source) = import.processed_silver_fir_area2
LEFT JOIN relief_meta ON relief_meta.source = import.relief
LEFT JOIN slopes ON slopes.slope = import.slope
ORDER BY forestecoregion, altitudinalzone, foresttype, targetaltitudinalzone, targetforesttype',
export_table_name, import_table_name, import_table_name
);
END;
$$ LANGUAGE plpgsql;

-- Create the standard projections export table
SELECT create_projections_export_table('projections', 'projections_import');

-- Create the VD projections export table
SELECT create_projections_export_table('vd_projections', 'vd_projections_import');
20 changes: 20 additions & 0 deletions lib/data/sql/import_data.sql
Original file line number Diff line number Diff line change
Expand Up @@ -951,6 +951,26 @@ COPY so_standorttypen
FROM
'/data/profiles/so/standorttypen.csv' DELIMITER ';' CSV HEADER;

-- Vaud
CREATE TABLE vd_projections_import (
forest_ecoregions TEXT, altitudinal_zone TEXT,
forest_type TEXT, slope TEXT, silver_fir_area TEXT,
forest_ecoregions_specific TEXT,
relief TEXT, additional TEXT, target_altitudinal_zone TEXT,
target_forest_type TEXT, "update" TEXT
);
COPY vd_projections_import
FROM
'/data/profiles/vd/projections.csv' DELIMITER ';' CSV HEADER;

UPDATE vd_projections_import
SET additional = 'tiefgründig'
WHERE lower(trim(additional)) = 'sol profond';

UPDATE vd_projections_import
SET additional = 'flachgründig'
WHERE lower(trim(additional)) = 'sol superficiel';



-- ########### PROJECTIONS ###########
Expand Down
1 change: 0 additions & 1 deletion lib/src/TreeClient/index.ts
Original file line number Diff line number Diff line change
Expand Up @@ -75,7 +75,6 @@ class TreeClient {
this.getAltitudinalZones = this.getAltitudinalZones.bind(this);
this.getProjections = this.getProjections.bind(this);
this.project = project.bind(this);
this.reduceProjections = reduceProjections.bind(this);
this.locate = locate.bind(this);
this.getProjectionOptions = this.getProjectionOptions.bind(this);
this.getField = this.getField.bind(this);
Expand Down
7 changes: 5 additions & 2 deletions lib/src/TreeClient/project.ts
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,7 @@ import {
Location,
ProjectOptionKey,
ProjectResult,
TreeAppProfile,
} from "../types";
import {
reduceHochmontanAz,
Expand All @@ -19,6 +20,7 @@ function project(
location: Location,
targetAltitude?: AltitudinalZoneCode,
previousResult: null | ProjectResult = null,
profile?: TreeAppProfile,
): ProjectResult {
const altitudinalZones = this.getAltitudinalZones();
const altitudeList = altitudinalZones
Expand All @@ -42,6 +44,7 @@ function project(
targetAltitudeIdx,
result,
altitudeList,
profile,
);

const last = result.projections?.slice(-1)[0];
Expand All @@ -58,12 +61,12 @@ function project(
...reducedLocation,
[secondaryField]: "unknown",
};
result = this.project(secondaryLocation, reducedTAZ, result);
result = this.project(secondaryLocation, reducedTAZ, result, profile);
break;
}
}
} else if (lastAltitudeIdx && lastAltitudeIdx < targetAltitudeIdx) {
result = this.project({ ...reducedLocation, ...last }, reducedTAZ, result);
result = this.project({ ...reducedLocation, ...last }, reducedTAZ, result, profile);
}

if (result && reducedLocation.forestType && altitudeIdx !== -1) {
Expand Down
13 changes: 10 additions & 3 deletions lib/src/TreeClient/reduceProjections.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ import {
ProjectOptionKey,
ProjectProjection,
ProjectResult,
TreeAppProfile,
} from "../types";
import {
primaryProjectionFields as primaryFields,
Expand All @@ -13,21 +14,27 @@ import { validateFieldValue } from "../utils";

import TreeClient from ".";

function projectionReducer(
function reduceProjections(
this: TreeClient,
location: Location,
targetAltitudePointer: number,
result: ProjectResult,
altitudeList: string[],
profile?: TreeAppProfile
): ProjectResult {
const { options } = result;

let projections: ProjectionQueryResult[] = [];
const tableName = this.executeQuery<{ name: string }>(`SELECT name
FROM sqlite_master
WHERE type='table' AND name='${profile}_projections';`)?.data?.[0]?.name || "projections";
const queryString = primaryFields.reduce(
(acc, fieldName: ProjectOptionKey, index) => {
let newString = acc;
const { value, values } = this.getField(fieldName, location);
validateFieldValue(fieldName, value, values);


if (index === 0 || location[primaryFields[index - 1]]) {
const newOptions = this.getProjectionOptions(
newString.replace(
Expand All @@ -44,7 +51,7 @@ function projectionReducer(
}
return newString;
},
"select * from projections",
`select * from ${tableName}`,
);

if (primaryFields.every((field) => location[field])) {
Expand Down Expand Up @@ -105,4 +112,4 @@ function projectionReducer(
return { ...result, options };
}

export default projectionReducer;
export default reduceProjections;
Binary file modified public/data/tree.sqlite
Binary file not shown.
Loading