From 4cf3432ffc1b14531f0e9d3afdd821563a9ff265 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 06:16:40 +0100 Subject: [PATCH 01/20] Rename LoadArea dataset to OsmLanduse Dataset has wrong name --- src/egon/data/airflow/dags/pipeline.py | 8 ++++---- src/egon/data/datasets/loadarea/__init__.py | 4 ++-- 2 files changed, 6 insertions(+), 6 deletions(-) diff --git a/src/egon/data/airflow/dags/pipeline.py b/src/egon/data/airflow/dags/pipeline.py index a1e10a6abb..74b313f730 100644 --- a/src/egon/data/airflow/dags/pipeline.py +++ b/src/egon/data/airflow/dags/pipeline.py @@ -63,7 +63,7 @@ ) from egon.data.datasets.industrial_sites import MergeIndustrialSites from egon.data.datasets.industry import IndustrialDemandCurves -from egon.data.datasets.loadarea import LoadArea +from egon.data.datasets.loadarea import OsmLanduse from egon.data.datasets.mastr import mastr_data_setup from egon.data.datasets.mv_grid_districts import mv_grid_districts_setup from egon.data.datasets.osm import OpenStreetMap @@ -210,7 +210,7 @@ ) # Extract landuse areas from the `osm` dataset - load_area = LoadArea(dependencies=[osm, vg250]) + osm_landuse = OsmLanduse(dependencies=[osm, vg250]) # Calculate feedin from renewables renewable_feedin = RenewableFeedin( @@ -300,7 +300,7 @@ dependencies=[ demandregio, industrial_sites, - load_area, + osm_landuse, mv_grid_districts, osm, ] @@ -448,7 +448,7 @@ demand_curves_industry, district_heating_areas, industrial_sites, - load_area, + osm_landuse, mastr_data, mv_grid_districts, scenario_capacities, diff --git a/src/egon/data/datasets/loadarea/__init__.py b/src/egon/data/datasets/loadarea/__init__.py index 3e18ae871a..2b473bdef5 100644 --- a/src/egon/data/datasets/loadarea/__init__.py +++ b/src/egon/data/datasets/loadarea/__init__.py @@ -31,10 +31,10 @@ class OsmPolygonUrban(Base): geom = Column(Geometry("MultiPolygon", 3035)) -class LoadArea(Dataset): +class OsmLanduse(Dataset): def __init__(self, dependencies): super().__init__( - name="LoadArea", + name="OsmLanduse", version="0.0.0", dependencies=dependencies, tasks=( From 1d8fb6eda12c0385418297247be02afb6349388f Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 19:12:38 +0100 Subject: [PATCH 02/20] Update changelog --- CHANGELOG.rst | 2 ++ 1 file changed, 2 insertions(+) diff --git a/CHANGELOG.rst b/CHANGELOG.rst index 0d8fb5bfb3..fd0ff7a0e4 100755 --- a/CHANGELOG.rst +++ b/CHANGELOG.rst @@ -225,6 +225,8 @@ Added `#868 `_ * Write simBEV metadata to DB table `PR #978 `_ +* Add load areas + `#1014 `_ .. _PR #159: https://github.com/openego/eGon-data/pull/159 .. _PR #703: https://github.com/openego/eGon-data/pull/703 From 9a1db27adf28f0b26385fe30ba1e4cf3de8b5c6b Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 19:14:30 +0100 Subject: [PATCH 03/20] Adapt landuse extraction script --- .../loadarea/osm_landuse_extraction.sql | 75 +++++++++---------- 1 file changed, 37 insertions(+), 38 deletions(-) diff --git a/src/egon/data/datasets/loadarea/osm_landuse_extraction.sql b/src/egon/data/datasets/loadarea/osm_landuse_extraction.sql index 6ce0f899d9..f62863e78c 100644 --- a/src/egon/data/datasets/loadarea/osm_landuse_extraction.sql +++ b/src/egon/data/datasets/loadarea/osm_landuse_extraction.sql @@ -10,7 +10,7 @@ Divide into 4 landuse sectors: __copyright__ = "Reiner Lemoine Institut" __license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" __url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" -__author__ = "Ludee, IlkaCu" +__author__ = "Ludee, IlkaCu, nesnoj" */ @@ -18,9 +18,9 @@ __author__ = "Ludee, IlkaCu" -- Filter OSM Urban Landuse ---------- ---------- ---------- --- Polygons with tags related to settlements are extracted from the original OSM data set and stored in table 'openstreetmap.osm_landuse. +-- Polygons with tags related to settlements are extracted from the original OSM data set and stored in table 'openstreetmap.osm_landuse. -DELETE FROM openstreetmap.osm_landuse; +DELETE FROM openstreetmap.osm_landuse; -- filter urban @@ -29,30 +29,30 @@ INSERT INTO openstreetmap.osm_landuse osm.osm_id ::integer AS osm_id, osm.name ::text AS name, '0' ::integer AS sector, - 'undefined'::text AS sector_name, + 'undefined'::text AS sector_name, ST_AREA(ST_TRANSFORM(osm.geom,3035))/10000 ::double precision AS area_ha, osm.tags ::hstore AS tags, 'outside' ::text AS vg250, ST_MULTI(ST_TRANSFORM(osm.geom,3035)) ::geometry(MultiPolygon,3035) AS geom FROM openstreetmap.osm_polygon AS osm WHERE - tags @> '"landuse"=>"residential"'::hstore OR - tags @> '"landuse"=>"commercial"'::hstore OR - tags @> '"landuse"=>"retail"'::hstore OR - tags @> '"landuse"=>"industrial;retail"'::hstore OR - tags @> '"landuse"=>"industrial"'::hstore OR - tags @> '"landuse"=>"port"'::hstore OR + tags @> '"landuse"=>"residential"'::hstore OR + tags @> '"landuse"=>"commercial"'::hstore OR + tags @> '"landuse"=>"retail"'::hstore OR + tags @> '"landuse"=>"industrial;retail"'::hstore OR + tags @> '"landuse"=>"industrial"'::hstore OR + tags @> '"landuse"=>"port"'::hstore OR tags @> '"man_made"=>"wastewater_plant"'::hstore OR - tags @> '"aeroway"=>"terminal"'::hstore OR - tags @> '"aeroway"=>"gate"'::hstore OR - tags @> '"man_made"=>"works"'::hstore OR - tags @> '"landuse"=>"farmyard"'::hstore OR - tags @> '"landuse"=>"greenhouse_horticulture"'::hstore + tags @> '"aeroway"=>"terminal"'::hstore OR + tags @> '"aeroway"=>"gate"'::hstore OR + tags @> '"man_made"=>"works"'::hstore OR + tags @> '"landuse"=>"farmyard"'::hstore OR + tags @> '"landuse"=>"greenhouse_horticulture"'::hstore ORDER BY osm.id; - + -- Create index using GIST (geom) -DROP INDEX IF EXISTS openstreetmap.osm_landuse_geom_idx; +DROP INDEX IF EXISTS openstreetmap.osm_landuse_geom_idx; CREATE INDEX osm_landuse_geom_idx ON openstreetmap.osm_landuse USING GIST (geom); @@ -74,7 +74,7 @@ UPDATE openstreetmap.osm_landuse AS t1 ) AS t2 WHERE t1.id = t2.id; --- Identify polygons which are spatially overlapping with the defined boundaries +-- Identify polygons which are spatially overlapping with the defined boundaries UPDATE openstreetmap.osm_landuse AS t1 SET vg250 = t2.vg250 FROM ( @@ -110,7 +110,7 @@ DROP SEQUENCE IF EXISTS openstreetmap.osm_landuse_vg250_cut_id CASCADE; CREATE SEQUENCE openstreetmap.osm_landuse_vg250_cut_id; --- Create materialized views to identify and store intersecting parts of polygons overlapping the external borders +-- Create materialized views to identify and store intersecting parts of polygons overlapping the external borders DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_landuse_vg250_cut; CREATE MATERIALIZED VIEW openstreetmap.osm_landuse_vg250_cut AS SELECT nextval('openstreetmap.osm_landuse_vg250_cut_id') ::integer AS cut_id, @@ -172,7 +172,7 @@ CREATE MATERIALIZED VIEW openstreetmap.osm_landuse_vg250_clean_cut AS cut.osm_id ::integer AS osm_id, cut.name ::text AS name, cut.sector ::integer AS sector, - cut.sector_name::text AS sector_name, + cut.sector_name::text AS sector_name, cut.area_ha ::double precision AS area_ha, cut.tags ::hstore AS tags, cut.vg250 ::text AS vg250, @@ -183,9 +183,9 @@ CREATE MATERIALIZED VIEW openstreetmap.osm_landuse_vg250_clean_cut AS -- index (id) CREATE UNIQUE INDEX osm_landuse_vg250_clean_cut_id_idx ON openstreetmap.osm_landuse_vg250_clean_cut (id); - + ---------------------------------------------------------------------------- --- Remove all faulty entries from table openstreetmap.osm_landuse +-- Remove all faulty entries from table openstreetmap.osm_landuse -- and insert those parts of the polygons lying within the (German) borders ---------------------------------------------------------------------------- @@ -211,47 +211,46 @@ INSERT INTO openstreetmap.osm_landuse ---------- ---------- ---------- --- Update Sector Information +-- Update Sector Information ---------- ---------- ---------- -- Sector 1. Residential -- update sector UPDATE openstreetmap.osm_landuse -SET sector = '1', +SET sector = '1', sector_name = 'residential' WHERE tags @> '"landuse"=>"residential"'::hstore; -- Sector 2. Retail -- update sector UPDATE openstreetmap.osm_landuse -SET sector = '2', +SET sector = '2', sector_name = 'retail' -WHERE tags @> '"landuse"=>"commercial"'::hstore OR - tags @> '"landuse"=>"retail"'::hstore OR +WHERE tags @> '"landuse"=>"commercial"'::hstore OR + tags @> '"landuse"=>"retail"'::hstore OR tags @> '"landuse"=>"industrial;retail"'::hstore; - + -- Sector 3. Industrial -- update sector UPDATE openstreetmap.osm_landuse -SET sector = '3', +SET sector = '3', sector_name = 'industrial' -WHERE tags @> '"landuse"=>"industrial"'::hstore OR - tags @> '"landuse"=>"port"'::hstore OR +WHERE tags @> '"landuse"=>"industrial"'::hstore OR + tags @> '"landuse"=>"port"'::hstore OR tags @> '"man_made"=>"wastewater_plant"'::hstore OR - tags @> '"aeroway"=>"terminal"'::hstore OR - tags @> '"aeroway"=>"gate"'::hstore OR + tags @> '"aeroway"=>"terminal"'::hstore OR + tags @> '"aeroway"=>"gate"'::hstore OR tags @> '"man_made"=>"works"'::hstore; - + -- Sector 4. Agricultural -- update sector UPDATE openstreetmap.osm_landuse - SET sector = '4', + SET sector = '4', sector_name = 'agricultural' - WHERE tags @> '"landuse"=>"farmyard"'::hstore OR + WHERE tags @> '"landuse"=>"farmyard"'::hstore OR tags @> '"landuse"=>"greenhouse_horticulture"'::hstore; --- Drop MViews which are not of special interest for downstream tasks +-- Drop MViews which are not of special interest for downstream tasks DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_landuse_error_geom_vg250 CASCADE; DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_landuse_vg250_clean_cut_multi CASCADE; DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_landuse_vg250_cut CASCADE; - From 7744ff23e0273a0fc4475c6c84d1ba7a30e0d951 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 19:15:56 +0100 Subject: [PATCH 04/20] Add load areas dataset and functions for SQL execution --- src/egon/data/datasets/loadarea/__init__.py | 81 +++++++++++++++++++++ 1 file changed, 81 insertions(+) diff --git a/src/egon/data/datasets/loadarea/__init__.py b/src/egon/data/datasets/loadarea/__init__.py index 2b473bdef5..94565681c7 100644 --- a/src/egon/data/datasets/loadarea/__init__.py +++ b/src/egon/data/datasets/loadarea/__init__.py @@ -2,6 +2,8 @@ extraction. """ +import os + from airflow.operators.postgres_operator import PostgresOperator from geoalchemy2.types import Geometry from sqlalchemy import Column, Float, Integer, String @@ -51,6 +53,23 @@ def __init__(self, dependencies): ) +class LoadArea(Dataset): + def __init__(self, dependencies): + super().__init__( + name="LoadArea", + version="0.0.1", + dependencies=dependencies, + tasks=( + osm_landuse_melt, + census_cells_melt, + osm_landuse_census_cells_melt, + loadareas_create, + loadareas_load_data, + drop_temp_tables, + ), + ) + + def create_landuse_table(): """Create tables for landuse data Returns @@ -70,3 +89,65 @@ def create_landuse_table(): engine = db.engine() OsmPolygonUrban.__table__.create(bind=engine, checkfirst=True) + + +def execute_sql_script(script): + """Execute SQL script + + Parameters + ---------- + script : str + Filename of script + """ + db.execute_sql_script(os.path.join(os.path.dirname(__file__), script)) + + +def osm_landuse_melt(): + """Melt all OSM landuse areas by: buffer, union, unbuffer""" + print("Melting OSM landuse areas from openstreetmap.osm_landuse...") + execute_sql_script("osm_landuse_melt.sql") + + +def census_cells_melt(): + """Melt all census cells: buffer, union, unbuffer""" + print( + "Melting census cells from " + "society.destatis_zensus_population_per_ha_inside_germany..." + ) + execute_sql_script("census_cells_melt.sql") + + +def osm_landuse_census_cells_melt(): + """Melt OSM landuse areas and census cells""" + print( + "Melting OSM landuse areas from openstreetmap.osm_landuse_melted and " + "census cells from " + "society.egon_destatis_zensus_cells_melted_cluster..." + ) + execute_sql_script("osm_landuse_census_cells_melt.sql") + + +def loadareas_create(): + """Create load areas from merged OSM landuse and census cells: + + * Cut Loadarea with MV Griddistrict + * Identify and exclude Loadarea smaller than 100m². + * Generate Centre of Loadareas with Centroid and PointOnSurface. + * Calculate population from Census 2011. + * Cut all 4 OSM sectors with MV Griddistricts. + * Calculate statistics like NUTS and AGS code. + * Check for Loadareas without AGS code. + """ + print("Create initial load areas and add some sector stats...") + execute_sql_script("loadareas_create.sql") + + +def loadareas_load_data(): + """Adds consumption and peak load per sector to load areas""" + print("Add consumption and peak loads to load areas...") + execute_sql_script("loadareas_load_data.sql") + + +def drop_temp_tables(): + print("Dropping temp tables...") + execute_sql_script("drop_temp_tables.sql") From 678241314ea0740e805727dd003a424ee0e1e4f3 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 19:18:25 +0100 Subject: [PATCH 05/20] Add skeleton for pipeline task integration --- src/egon/data/airflow/dags/pipeline.py | 5 ++++- 1 file changed, 4 insertions(+), 1 deletion(-) diff --git a/src/egon/data/airflow/dags/pipeline.py b/src/egon/data/airflow/dags/pipeline.py index 74b313f730..717dad7fcb 100644 --- a/src/egon/data/airflow/dags/pipeline.py +++ b/src/egon/data/airflow/dags/pipeline.py @@ -63,7 +63,7 @@ ) from egon.data.datasets.industrial_sites import MergeIndustrialSites from egon.data.datasets.industry import IndustrialDemandCurves -from egon.data.datasets.loadarea import OsmLanduse +from egon.data.datasets.loadarea import LoadArea, OsmLanduse from egon.data.datasets.mastr import mastr_data_setup from egon.data.datasets.mv_grid_districts import mv_grid_districts_setup from egon.data.datasets.osm import OpenStreetMap @@ -242,6 +242,9 @@ dependencies=[mv_grid_districts, vg250] ) + # Create load areas + load_areas = LoadArea(dependencies=[osm_landuse]) + # Create household demand profiles on zensus level hh_demand_profiles_setup = hh_profiles.HouseholdDemands( dependencies=[ From 8f23fa1bb9b7b86f6b59f27da8d4f6da49dfb981 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 19:55:43 +0100 Subject: [PATCH 06/20] Add SQL script: OSM landuse melt --- .../datasets/loadarea/osm_landuse_melt.sql | 66 +++++++++++++++++++ 1 file changed, 66 insertions(+) create mode 100644 src/egon/data/datasets/loadarea/osm_landuse_melt.sql diff --git a/src/egon/data/datasets/loadarea/osm_landuse_melt.sql b/src/egon/data/datasets/loadarea/osm_landuse_melt.sql new file mode 100644 index 0000000000..0a33185bf2 --- /dev/null +++ b/src/egon/data/datasets/loadarea/osm_landuse_melt.sql @@ -0,0 +1,66 @@ +/* +OSM Loads from landuse +Excludes large scale consumer. +Buffer OSM urban sectors with 100m +Unbuffer buffer with -100m + +__copyright__ = "Reiner Lemoine Institut" +__license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" +__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__author__ = "Ludee, nesnoj" +*/ + + +-- 28.10.22: CHECK IF NECESSARY!!! +-- exclude large scale consumer +--DELETE FROM openstreetmap.osm_landuse +-- WHERE gid IN (SELECT polygon_id FROM model_draft.ego_demand_hv_largescaleconsumer); + + +-- sequence +DROP SEQUENCE IF EXISTS openstreetmap.osm_landuse_buffer100_mview_id CASCADE; +CREATE SEQUENCE openstreetmap.osm_landuse_buffer100_mview_id; + +-- buffer with 100m +DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_landuse_buffer100_mview CASCADE; +CREATE MATERIALIZED VIEW openstreetmap.osm_landuse_buffer100_mview AS + SELECT nextval('openstreetmap.osm_landuse_buffer100_mview_id') ::integer AS id, + (ST_DUMP(ST_MULTI(ST_UNION( + ST_BUFFER(geom, 100) + )))).geom ::geometry(Polygon,3035) AS geom + FROM openstreetmap.osm_landuse; + +-- index (id) +CREATE UNIQUE INDEX osm_landuse_buffer100_mview_gid_idx + ON openstreetmap.osm_landuse_buffer100_mview (id); + +-- index GIST (geom) +CREATE INDEX osm_landuse_buffer100_mview_geom_idx + ON openstreetmap.osm_landuse_buffer100_mview USING GIST (geom); + + +-- unbuffer with 100m +DROP TABLE IF EXISTS openstreetmap.osm_landuse_melted CASCADE; +CREATE TABLE openstreetmap.osm_landuse_melted ( + id SERIAL NOT NULL, + area_ha double precision, + geom geometry(Polygon,3035), + CONSTRAINT osm_landuse_melted_pkey PRIMARY KEY (id)); + +-- insert buffer +INSERT INTO openstreetmap.osm_landuse_melted(area_ha,geom) + SELECT ST_AREA(buffer.geom)/10000 ::double precision AS area_ha, + buffer.geom ::geometry(Polygon,3035) AS geom + FROM (SELECT (ST_DUMP(ST_MULTI(ST_UNION( + ST_BUFFER(osm.geom, -100) + )))).geom ::geometry(Polygon,3035) AS geom + FROM openstreetmap.osm_landuse_buffer100_mview AS osm +-- ORDER BY id + ) AS buffer; + +-- index GIST (geom) +CREATE INDEX osm_landuse_melted_geom_idx + ON openstreetmap.osm_landuse_melted USING GIST (geom); + + +DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_landuse_buffer100_mview CASCADE; From 1be05e5997a7ebfbace527601c7e27070da2e724 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 19:56:25 +0100 Subject: [PATCH 07/20] Add SQL script: census cells melt --- .../datasets/loadarea/census_cells_melt.sql | 159 ++++++++++++++++++ 1 file changed, 159 insertions(+) create mode 100644 src/egon/data/datasets/loadarea/census_cells_melt.sql diff --git a/src/egon/data/datasets/loadarea/census_cells_melt.sql b/src/egon/data/datasets/loadarea/census_cells_melt.sql new file mode 100644 index 0000000000..3e8d02ec01 --- /dev/null +++ b/src/egon/data/datasets/loadarea/census_cells_melt.sql @@ -0,0 +1,159 @@ +/* +Loads from Census 2011 +Include Census 2011 population per ha. +Identify population in OSM loads. +Include Census cells with CTS demand. + +__copyright__ = "Reiner Lemoine Institut" +__license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" +__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__author__ = "Ludee, nesnoj" +*/ + + +-- zensus load +DROP TABLE IF EXISTS society.egon_destatis_zensus_cells_melted CASCADE; +CREATE TABLE society.egon_destatis_zensus_cells_melted ( + id SERIAL NOT NULL, + gid integer, + population integer, + inside_la boolean, + geom_point geometry(Point,3035), + geom geometry(Polygon,3035), + CONSTRAINT egon_destatis_zensus_cells_melted_pkey PRIMARY KEY (id)); + +-- insert zensus loads +INSERT INTO society.egon_destatis_zensus_cells_melted (gid,population,inside_la,geom_point,geom) + SELECT id ::integer AS gid, + population ::integer, + 'FALSE' ::boolean AS inside_la, + geom_point ::geometry(Point,3035), + geom ::geometry(Polygon,3035) + --FROM model_draft.destatis_zensus_population_per_ha_invg_mview + FROM society.destatis_zensus_population_per_ha_inside_germany + ORDER BY gid; + +-- zensus cells with CTS loads +INSERT INTO society.egon_destatis_zensus_cells_melted (gid,population,inside_la,geom_point,geom) + SELECT + id ::integer AS gid, + 0 AS population, + 'FALSE' ::boolean AS inside_la, + geom_point ::geometry(Point,3035), + geom ::geometry(Polygon,3035) + FROM society.destatis_zensus_population_per_ha + WHERE id in ( + SELECT DISTINCT zensus_population_id + FROM demand.egon_demandregio_zensus_electricity + WHERE scenario = 'eGon2035' AND sector = 'service' + ) + ORDER BY gid; + +-- index gist (geom_point) +CREATE INDEX egon_destatis_zensus_cells_melted_geom_point_idx + ON society.egon_destatis_zensus_cells_melted USING GIST (geom_point); + +-- index gist (geom) +CREATE INDEX egon_destatis_zensus_cells_melted_geom_idx + ON society.egon_destatis_zensus_cells_melted USING GIST (geom); + +-- population in osm loads +UPDATE society.egon_destatis_zensus_cells_melted AS t1 + SET inside_la = t2.inside_la + FROM ( + SELECT zensus.id AS id, + 'TRUE' ::boolean AS inside_la + FROM society.egon_destatis_zensus_cells_melted AS zensus, + openstreetmap.osm_landuse_melted AS osm + WHERE osm.geom && zensus.geom_point AND + ST_CONTAINS(osm.geom,zensus.geom_point) + ) AS t2 + WHERE t1.id = t2.id; + +-- remove identified population +DELETE FROM society.egon_destatis_zensus_cells_melted AS lp + WHERE lp.inside_la IS TRUE; + + + +-- cluster from zensus load lattice +DROP TABLE IF EXISTS society.egon_destatis_zensus_cells_melted_cluster CASCADE; +CREATE TABLE society.egon_destatis_zensus_cells_melted_cluster ( + cid serial, + zensus_sum INT, + area_ha INT, + geom geometry(Polygon,3035), + geom_buffer geometry(Polygon,3035), + geom_centroid geometry(Point,3035), + geom_surfacepoint geometry(Point,3035), + CONSTRAINT egon_destatis_zensus_cells_melted_cluster_pkey PRIMARY KEY (cid)); + +-- insert cluster +INSERT INTO society.egon_destatis_zensus_cells_melted_cluster(geom) + SELECT (ST_DUMP(ST_MULTI(ST_UNION(geom)))).geom ::geometry(Polygon,3035) + FROM society.egon_destatis_zensus_cells_melted; +-- ORDER BY gid; + +-- index gist (geom) +CREATE INDEX egon_destatis_zensus_cells_melted_cluster_geom_idx + ON society.egon_destatis_zensus_cells_melted_cluster USING GIST (geom); + +-- index gist (geom_centroid) +CREATE INDEX egon_destatis_zensus_cells_melted_cluster_geom_centroid_idx + ON society.egon_destatis_zensus_cells_melted_cluster USING GIST (geom_centroid); + +-- index gist (geom_surfacepoint) +CREATE INDEX egon_destatis_zensus_cells_melted_cluster_geom_surfacepoint_idx + ON society.egon_destatis_zensus_cells_melted_cluster USING GIST (geom_surfacepoint); + +-- insert cluster +INSERT INTO society.egon_destatis_zensus_cells_melted_cluster(geom) + SELECT (ST_DUMP(ST_MULTI(ST_UNION(grid.geom)))).geom ::geometry(Polygon,3035) AS geom + FROM society.egon_destatis_zensus_cells_melted AS grid; + +-- cluster data +UPDATE society.egon_destatis_zensus_cells_melted_cluster AS t1 + SET zensus_sum = t2.zensus_sum, + area_ha = t2.area_ha, + geom_buffer = t2.geom_buffer, + geom_centroid = t2.geom_centroid, + geom_surfacepoint = t2.geom_surfacepoint + FROM ( + SELECT cl.cid AS cid, + SUM(lp.population) AS zensus_sum, + COUNT(lp.geom) AS area_ha, + ST_BUFFER(cl.geom, 100) AS geom_buffer, + ST_Centroid(cl.geom) AS geom_centroid, + ST_PointOnSurface(cl.geom) AS geom_surfacepoint + FROM society.egon_destatis_zensus_cells_melted AS lp, + society.egon_destatis_zensus_cells_melted_cluster AS cl + WHERE cl.geom && lp.geom AND + ST_CONTAINS(cl.geom,lp.geom) + GROUP BY cl.cid + ORDER BY cl.cid + ) AS t2 + WHERE t1.cid = t2.cid; + + +-- zensus stats +DROP MATERIALIZED VIEW IF EXISTS openstreetmap.ego_society_zensus_per_la_mview CASCADE; +CREATE MATERIALIZED VIEW openstreetmap.ego_society_zensus_per_la_mview AS +-- SELECT 'destatis_zensus_population_per_ha_mview' AS name, +-- sum(population), +-- count(geom) AS census_count +-- FROM openstreetmap.destatis_zensus_population_per_ha_mview +-- UNION ALL + SELECT 'destatis_zensus_population_per_ha_inside_germany' AS name, + sum(population), + count(geom) AS census_count + FROM society.destatis_zensus_population_per_ha_inside_germany + UNION ALL + SELECT 'egon_destatis_zensus_cells_melted' AS name, + sum(population), + count(geom) AS census_count + FROM society.egon_destatis_zensus_cells_melted + UNION ALL + SELECT 'egon_destatis_zensus_cells_melted_cluster' AS name, + sum(zensus_sum), + count(geom) AS census_count + FROM society.egon_destatis_zensus_cells_melted_cluster; From 72f4fed053d393bfb52fc4cc64c81274adedb67c Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 19:56:51 +0100 Subject: [PATCH 08/20] Add SQL script: melt OSM landuse and census cells --- .../osm_landuse_census_cells_melt.sql | 170 ++++++++++++++++++ 1 file changed, 170 insertions(+) create mode 100644 src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql diff --git a/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql b/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql new file mode 100644 index 0000000000..19b654cb59 --- /dev/null +++ b/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql @@ -0,0 +1,170 @@ +/* +Melt loads from OSM landuse and Census 2011 +Collect loads from both sources. +Buffer collected loads with with 100m. +Unbuffer the collection with 100m. +Validate the melted geometries. +Fix geometries with error. +Check again for errors. + +__copyright__ = "Reiner Lemoine Institut" +__license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" +__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__author__ = "Ludee, nesnoj" +*/ + +-- collect loads +DROP TABLE IF EXISTS demand.egon_loadarea_load_collect CASCADE; +CREATE TABLE demand.egon_loadarea_load_collect ( + id SERIAL, + geom geometry(Polygon,3035), + CONSTRAINT egon_loadarea_load_collect_pkey PRIMARY KEY (id)); + +-- insert loads OSM +INSERT INTO demand.egon_loadarea_load_collect (geom) + SELECT geom + FROM openstreetmap.osm_landuse_melted; +-- ORDER BY gid; + +-- insert loads zensus cluster +INSERT INTO demand.egon_loadarea_load_collect (geom) + SELECT geom + FROM society.egon_destatis_zensus_cells_melted_cluster; +-- ORDER BY cid; + +-- index GIST (geom) +CREATE INDEX egon_loadarea_load_collect_geom_idx + ON demand.egon_loadarea_load_collect USING GIST (geom); + +-- buffer with 100m +DROP TABLE IF EXISTS demand.egon_loadarea_load_collect_buffer100 CASCADE; +CREATE TABLE demand.egon_loadarea_load_collect_buffer100 ( + id SERIAL, + geom geometry(Polygon,3035), + CONSTRAINT egon_loadarea_load_collect_buffer100_pkey PRIMARY KEY (id)); + +-- insert buffer +INSERT INTO demand.egon_loadarea_load_collect_buffer100 (geom) + SELECT (ST_DUMP(ST_MULTI(ST_UNION( + ST_BUFFER(geom, 100) + )))).geom ::geometry(Polygon,3035) AS geom + FROM demand.egon_loadarea_load_collect; +-- ORDER BY id; + +-- index GIST (geom) +CREATE INDEX egon_loadarea_load_collect_buffer100_geom_idx + ON demand.egon_loadarea_load_collect_buffer100 USING GIST (geom); + +-- unbuffer with 99m +DROP TABLE IF EXISTS demand.egon_loadarea_load_melt CASCADE; +CREATE TABLE demand.egon_loadarea_load_melt ( + id SERIAL, + geom geometry(Polygon,3035), + CONSTRAINT egon_loadarea_load_melt_pkey PRIMARY KEY (id)); + +-- insert buffer +INSERT INTO demand.egon_loadarea_load_melt (geom) + SELECT (ST_DUMP(ST_MULTI(ST_UNION( + ST_BUFFER(buffer.geom, -99) + )))).geom ::geometry(Polygon,3035) AS geom + FROM demand.egon_loadarea_load_collect_buffer100 AS buffer + GROUP BY buffer.id + ORDER BY buffer.id; + +-- index GIST (geom) +CREATE INDEX egon_loadarea_load_melt_geom_idx + ON demand.egon_loadarea_load_melt USING GIST (geom); + + +-- Validate the melted geometries +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_geom_mview CASCADE; +CREATE MATERIALIZED VIEW demand.egon_loadarea_load_melt_error_geom_mview AS + SELECT test.id, + test.error, + reason(ST_IsValidDetail(test.geom)) AS error_reason, + ST_SetSRID(location(ST_IsValidDetail(test.geom)),3035) ::geometry(Point,3035) AS error_location, + test.geom ::geometry(Polygon,3035) AS geom + FROM ( + SELECT source.id AS id, -- PK + ST_IsValid(source.geom) AS error, + source.geom AS geom + FROM demand.egon_loadarea_load_melt AS source -- Table + ) AS test + WHERE test.error = FALSE; + +-- index (id) +CREATE UNIQUE INDEX egon_loadarea_load_melt_error_geom_mview_id_idx + ON demand.egon_loadarea_load_melt_error_geom_mview (id); + +-- index GIST (geom) +CREATE INDEX egon_loadarea_load_melt_error_geom_mview_geom_idx + ON demand.egon_loadarea_load_melt_error_geom_mview USING GIST (geom); + +-- Fix geometries with error +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_geom_fix_mview CASCADE; +CREATE MATERIALIZED VIEW demand.egon_loadarea_load_melt_error_geom_fix_mview AS + SELECT fix.id AS id, + ST_IsValid(fix.geom) AS error, + GeometryType(fix.geom) AS geom_type, + ST_AREA(fix.geom) AS area, + fix.geom_buffer ::geometry(POLYGON,3035) AS geom_buffer, + fix.geom ::geometry(POLYGON,3035) AS geom + FROM ( + SELECT fehler.id AS id, + ST_BUFFER(fehler.geom, -1) AS geom_buffer, + (ST_DUMP(ST_BUFFER(ST_BUFFER(fehler.geom, -1), 1))).geom AS geom + FROM demand.egon_loadarea_load_melt_error_geom_mview AS fehler + ) AS fix + ORDER BY fix.id; + +-- index (id) +CREATE UNIQUE INDEX egon_loadarea_load_melt_error_geom_fix_mview_id_idx + ON demand.egon_loadarea_load_melt_error_geom_fix_mview (id); + +-- index GIST (geom) +CREATE INDEX egon_loadarea_load_melt_error_geom_fix_mview_geom_idx + ON demand.egon_loadarea_load_melt_error_geom_fix_mview USING GIST (geom); + +-- update fixed geoms +UPDATE demand.egon_loadarea_load_melt AS t1 + SET geom = t2.geom + FROM ( + SELECT fix.id AS id, + fix.geom AS geom + FROM demand.egon_loadarea_load_melt_error_geom_fix_mview AS fix + ) AS t2 + WHERE t1.id = t2.id; + +-- Check again for errors. +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_2_geom_mview CASCADE; +CREATE MATERIALIZED VIEW demand.egon_loadarea_load_melt_error_2_geom_mview AS + SELECT test.id AS id, + test.error AS error, + reason(ST_IsValidDetail(test.geom)) AS error_reason, + ST_SetSRID(location(ST_IsValidDetail(test.geom)),3035) ::geometry(Point,3035) AS error_location, + ST_TRANSFORM(test.geom,3035) ::geometry(Polygon,3035) AS geom + FROM ( + SELECT source.id AS id, + ST_IsValid(source.geom) AS error, + source.geom ::geometry(Polygon,3035) AS geom + FROM demand.egon_loadarea_load_melt AS source + ) AS test + WHERE test.error = FALSE; + +-- index (id) +CREATE UNIQUE INDEX egon_loadarea_load_melt_error_2_geom_mview_id_idx + ON demand.egon_loadarea_load_melt_error_2_geom_mview (id); + +-- index GIST (geom) +CREATE INDEX egon_loadarea_load_melt_error_2_geom_mview_geom_idx + ON demand.egon_loadarea_load_melt_error_2_geom_mview USING GIST (geom); + + +/* -- drop temp +DROP TABLE IF EXISTS demand.egon_loadarea_load_collect CASCADE; +DROP TABLE IF EXISTS demand.egon_loadarea_load_collect_buffer100 CASCADE; +DROP TABLE IF EXISTS demand.egon_loadarea_load_melt CASCADE; +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_geom_mview CASCADE; +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_geom_fix_mview CASCADE; +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_2_geom_mview CASCADE; + */ From d1d43baf99d89f34c14ac73c98da2b794d431992 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 19:57:31 +0100 Subject: [PATCH 09/20] Add SQL script: create load areas --- .../datasets/loadarea/loadareas_create.sql | 470 ++++++++++++++++++ 1 file changed, 470 insertions(+) create mode 100644 src/egon/data/datasets/loadarea/loadareas_create.sql diff --git a/src/egon/data/datasets/loadarea/loadareas_create.sql b/src/egon/data/datasets/loadarea/loadareas_create.sql new file mode 100644 index 0000000000..4ddb28de59 --- /dev/null +++ b/src/egon/data/datasets/loadarea/loadareas_create.sql @@ -0,0 +1,470 @@ +/* +Cut Loadarea with MV Griddistrict +Identify and exclude Loadarea smaller than 100m². +Generate Centre of Loadareas with Centroid and PointOnSurface. +Calculate population from Census 2011. +Cut all 4 OSM sectors with MV Griddistricts. +Calculate statistics like NUTS and AGS code. +Check for Loadareas without AGS code. + +__copyright__ = "Reiner Lemoine Institut" +__license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" +__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__author__ = "Ludee, nesnoj" +*/ + +-- loadareas per mv-griddistrict +DROP TABLE IF EXISTS demand.egon_loadarea CASCADE; +CREATE TABLE demand.egon_loadarea ( + id SERIAL NOT NULL, + bus_id integer, + area_ha numeric, + nuts varchar(5), + rs_0 varchar(12), + ags_0 varchar(12), + zensus_sum integer, + zensus_count integer, + zensus_density numeric, + sector_area_residential numeric, + sector_area_retail numeric, + sector_area_industrial numeric, + sector_area_agricultural numeric, + sector_area_sum numeric, + sector_share_residential numeric, + sector_share_retail numeric, + sector_share_industrial numeric, + sector_share_agricultural numeric, + sector_share_sum numeric, + sector_count_residential integer, + sector_count_retail integer, + sector_count_industrial integer, + sector_count_agricultural integer, + sector_count_sum integer, + sector_consumption_residential double precision, + sector_consumption_retail double precision, + sector_consumption_industrial double precision, + sector_consumption_agricultural double precision, + sector_consumption_sum double precision, + sector_peakload_retail double precision, + sector_peakload_residential double precision, + sector_peakload_industrial double precision, + sector_peakload_agricultural double precision, + geom_centroid geometry(POINT,3035), + geom_surfacepoint geometry(POINT,3035), + geom_centre geometry(POINT,3035), + geom geometry(Polygon,3035), + CONSTRAINT egon_loadarea_pkey PRIMARY KEY (id)); + +-- insert cutted load melt +INSERT INTO demand.egon_loadarea (geom) + SELECT c.geom ::geometry(Polygon,3035) + FROM ( + SELECT (ST_DUMP(ST_INTERSECTION(a.geom,b.geom))).geom AS geom + FROM demand.egon_loadarea_load_melt AS a, + grid.egon_mv_grid_district AS b + WHERE a.geom && b.geom + ) AS c + WHERE ST_GeometryType(c.geom) = 'ST_Polygon'; + +-- index GIST (geom_centroid) +CREATE INDEX egon_loadarea_geom_centroid_idx + ON demand.egon_loadarea USING GIST (geom_centroid); + +-- index GIST (geom_surfacepoint) +CREATE INDEX egon_loadarea_geom_surfacepoint_idx + ON demand.egon_loadarea USING GIST (geom_surfacepoint); + +-- index GIST (geom_centre) +CREATE INDEX egon_loadarea_geom_centre_idx + ON demand.egon_loadarea USING gist (geom_centre); + +-- index GIST (geom) +CREATE INDEX egon_loadarea_geom_idx + ON demand.egon_loadarea USING gist (geom); + +-- update area (area_ha) +UPDATE demand.egon_loadarea AS t1 + SET area_ha = t2.area + FROM (SELECT loads.id, + ST_AREA(ST_TRANSFORM(loads.geom,3035))/10000 AS area + FROM demand.egon_loadarea AS loads + ) AS t2 + WHERE t1.id = t2.id; + +-- Identify Loadarea smaller than 100m² +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_smaller100m2_mview CASCADE; +CREATE MATERIALIZED VIEW demand.egon_loadarea_smaller100m2_mview AS + SELECT loads.id AS id, + loads.area_ha AS area_ha, + loads.geom AS geom + FROM demand.egon_loadarea AS loads + WHERE loads.area_ha < 0.001; + +-- index (id) +CREATE UNIQUE INDEX egon_loadarea_smaller100m2_mview_id_idx + ON demand.egon_loadarea_smaller100m2_mview (id); + +-- index GIST (geom) +CREATE INDEX egon_loadarea_smaller100m2_mview_geom_idx + ON demand.egon_loadarea_smaller100m2_mview USING GIST (geom); + +-- Exclude Loadarea smaller than 100m² +DELETE FROM demand.egon_loadarea AS loads + WHERE loads.area_ha < 0.001; + + +-- Generate Centre of Loadareas with Centroid and PointOnSurface +-- centroid +UPDATE demand.egon_loadarea AS t1 + SET geom_centroid = t2.geom_centroid + FROM ( + SELECT loads.id AS id, + ST_Centroid(loads.geom) AS geom_centroid + FROM demand.egon_loadarea AS loads + ) AS t2 + WHERE t1.id = t2.id; + +-- surfacepoint +UPDATE demand.egon_loadarea AS t1 + SET geom_surfacepoint = t2.geom_surfacepoint + FROM ( + SELECT loads.id AS id, + ST_PointOnSurface(loads.geom) AS geom_surfacepoint + FROM demand.egon_loadarea AS loads + ) AS t2 + WHERE t1.id = t2.id; + +-- centre with centroid if inside loadarea +UPDATE demand.egon_loadarea AS t1 + SET geom_centre = t2.geom_centre + FROM ( + SELECT loads.id AS id, + loads.geom_centroid AS geom_centre + FROM demand.egon_loadarea AS loads + WHERE loads.geom && loads.geom_centroid AND + ST_CONTAINS(loads.geom,loads.geom_centroid) + )AS t2 + WHERE t1.id = t2.id; + +-- centre with surfacepoint if outside area +UPDATE demand.egon_loadarea AS t1 + SET geom_centre = t2.geom_centre + FROM ( + SELECT loads.id AS id, + loads.geom_surfacepoint AS geom_centre + FROM demand.egon_loadarea AS loads + WHERE loads.geom_centre IS NULL + )AS t2 + WHERE t1.id = t2.id; + +/* -- validate geom_centre +SELECT loads.id AS id +FROM demand.egon_loadarea AS loads +WHERE NOT ST_CONTAINS(loads.geom,loads.geom_centre); */ + + +-- zensus 2011 population +UPDATE demand.egon_loadarea AS t1 + SET zensus_sum = t2.zensus_sum, + zensus_count = t2.zensus_count, + zensus_density = t2.zensus_density + FROM ( + SELECT a.id AS id, + SUM(b.population)::integer AS zensus_sum, + COUNT(b.geom_point)::integer AS zensus_count, + (SUM(b.population)/COUNT(b.geom_point))::numeric AS zensus_density + FROM demand.egon_loadarea AS a, + society.destatis_zensus_population_per_ha_inside_germany AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom,b.geom_point) + GROUP BY a.id + )AS t2 + WHERE t1.id = t2.id; + +-- Cut all 4 OSM sectors with MV Griddistricts +-- 1. Residential sector +DROP TABLE IF EXISTS openstreetmap.ego_osm_sector_per_griddistrict_1_residential CASCADE; +CREATE TABLE openstreetmap.ego_osm_sector_per_griddistrict_1_residential ( + id SERIAL NOT NULL, + geom geometry(Polygon,3035), + CONSTRAINT urban_sector_per_grid_district_1_residential_pkey PRIMARY KEY (id)); + +-- intersect sector with mv-griddistrict +INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_1_residential (geom) + SELECT loads.geom ::geometry(Polygon,3035) + FROM ( + SELECT (ST_DUMP(ST_INTERSECTION(loads.geom,dis.geom))).geom AS geom + FROM openstreetmap.osm_polygon_urban_sector_1_residential_mview AS loads, + grid.egon_mv_grid_district AS dis + WHERE loads.geom && dis.geom + ) AS loads + WHERE ST_GeometryType(loads.geom) = 'ST_Polygon'; + +-- index GIST (geom) +CREATE INDEX urban_sector_per_grid_district_1_residential_geom_idx + ON openstreetmap.ego_osm_sector_per_griddistrict_1_residential USING GIST (geom); + +-- sector stats +UPDATE demand.egon_loadarea AS t1 + SET sector_area_residential = t2.sector_area, + sector_count_residential = t2.sector_count, + sector_share_residential = t2.sector_area / t2.area_ha + FROM ( + SELECT loads.id AS id, + SUM(ST_AREA(sector.geom)/10000) AS sector_area, + COUNT(sector.geom) AS sector_count, + loads.area_ha AS area_ha + FROM openstreetmap.ego_osm_sector_per_griddistrict_1_residential AS sector, + demand.egon_loadarea AS loads + WHERE loads.geom && sector.geom AND + ST_INTERSECTS(loads.geom,ST_BUFFER(sector.geom,-1)) + GROUP BY loads.id + ) AS t2 + WHERE t1.id = t2.id; + +-- 2. Retail sector +DROP TABLE IF EXISTS openstreetmap.ego_osm_sector_per_griddistrict_2_retail CASCADE; +CREATE TABLE openstreetmap.ego_osm_sector_per_griddistrict_2_retail ( + id SERIAL NOT NULL, + geom geometry(Polygon,3035), + CONSTRAINT urban_sector_per_grid_district_2_retail_pkey PRIMARY KEY (id)); + +-- intersect sector with mv-griddistrict +INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_2_retail (geom) + SELECT loads.geom ::geometry(Polygon,3035) + FROM ( + SELECT (ST_DUMP(ST_INTERSECTION(loads.geom,dis.geom))).geom AS geom + FROM openstreetmap.osm_polygon_urban_sector_2_retail_mview AS loads, + grid.egon_mv_grid_district AS dis + WHERE loads.geom && dis.geom + ) AS loads + WHERE ST_GeometryType(loads.geom) = 'ST_Polygon'; + +-- index GIST (geom) +CREATE INDEX urban_sector_per_grid_district_2_retail_geom_idx + ON openstreetmap.ego_osm_sector_per_griddistrict_2_retail USING GIST (geom); + +-- sector stats +UPDATE demand.egon_loadarea AS t1 + SET sector_area_retail = t2.sector_area, + sector_count_retail = t2.sector_count, + sector_share_retail = t2.sector_area / t2.area_ha + FROM ( + SELECT loads.id AS id, + SUM(ST_AREA(sector.geom)/10000) AS sector_area, + COUNT(sector.geom) AS sector_count, + loads.area_ha AS area_ha + FROM openstreetmap.ego_osm_sector_per_griddistrict_2_retail AS sector, + demand.egon_loadarea AS loads + WHERE loads.geom && sector.geom AND + ST_INTERSECTS(loads.geom,ST_BUFFER(sector.geom,-1)) + GROUP BY loads.id + ) AS t2 + WHERE t1.id = t2.id; + +-- filter Industrial without largescale +DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_polygon_urban_sector_3_industrial_nolargescale_mview CASCADE; +CREATE MATERIALIZED VIEW openstreetmap.osm_polygon_urban_sector_3_industrial_nolargescale_mview AS + SELECT osm.* + FROM openstreetmap.osm_polygon_urban AS osm + WHERE sector = '3' --AND gid NOT IN (SELECT polygon_id FROM model_draft.ego_demand_hv_largescaleconsumer) -- 31.10.22: COMMENTED OUT! CHECK IF NECESSARY!!! +ORDER BY osm.id; + +-- index (id) +CREATE UNIQUE INDEX osm_polygon_urban_sector_3_industrial_nolargescale_mview_gid_idx + ON openstreetmap.osm_polygon_urban_sector_3_industrial_nolargescale_mview (id); + +-- index GIST (geom) +CREATE INDEX osm_polygon_urban_sector_3_industrial_nolargescale_mview_geom_idx + ON openstreetmap.osm_polygon_urban_sector_3_industrial_nolargescale_mview USING GIST (geom); + + +/* -- check +SELECT 'industrial' AS name, + count(ind.*) AS cnt +FROM openstreetmap.osm_deu_polygon_urban_sector_3_industrial_mview ind +UNION ALL +SELECT 'largescale' AS name, + count(ls.*) AS cnt +FROM model_draft.ego_demand_hv_largescaleconsumer ls +UNION ALL +SELECT 'nolargescale' AS name, + count(nols.*) AS cnt +FROM openstreetmap.osm_deu_polygon_urban_sector_3_industrial_nolargescale_mview nols; +*/ + + +-- 3. industrial sector +DROP TABLE IF EXISTS openstreetmap.ego_osm_sector_per_griddistrict_3_industrial CASCADE; +CREATE TABLE openstreetmap.ego_osm_sector_per_griddistrict_3_industrial ( + id SERIAL NOT NULL, + geom geometry(Polygon,3035), + CONSTRAINT urban_sector_per_grid_district_3_industrial_pkey PRIMARY KEY (id)); + +-- intersect sector with mv-griddistrict +INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_3_industrial (geom) + SELECT loads.geom ::geometry(Polygon,3035) + FROM ( + SELECT (ST_DUMP(ST_INTERSECTION(loads.geom,dis.geom))).geom AS geom + FROM openstreetmap.osm_polygon_urban_sector_3_industrial_nolargescale_mview AS loads, + grid.egon_mv_grid_district AS dis + WHERE loads.geom && dis.geom + ) AS loads + WHERE ST_GeometryType(loads.geom) = 'ST_Polygon'; + +-- index GIST (geom) +CREATE INDEX urban_sector_per_grid_district_3_industrial_geom_idx + ON openstreetmap.ego_osm_sector_per_griddistrict_3_industrial USING GIST (geom); + +-- sector stats +UPDATE demand.egon_loadarea AS t1 + SET sector_area_industrial = t2.sector_area, + sector_count_industrial = t2.sector_count, + sector_share_industrial = t2.sector_area / t2.area_ha + FROM ( + SELECT loads.id AS id, + SUM(ST_AREA(sector.geom)/10000) AS sector_area, + COUNT(sector.geom) AS sector_count, + loads.area_ha AS area_ha + FROM openstreetmap.ego_osm_sector_per_griddistrict_3_industrial AS sector, + demand.egon_loadarea AS loads + WHERE loads.geom && sector.geom AND + ST_INTERSECTS(loads.geom,ST_BUFFER(sector.geom,-1)) + GROUP BY loads.id + ) AS t2 + WHERE t1.id = t2.id; + +-- 4. agricultural sector +DROP TABLE IF EXISTS openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural CASCADE; +CREATE TABLE openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural ( + id SERIAL NOT NULL, + geom geometry(Polygon,3035), + CONSTRAINT urban_sector_per_grid_district_4_agricultural_pkey PRIMARY KEY (id)); + +-- intersect sector with mv-griddistrict +INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural (geom) + SELECT loads.geom ::geometry(Polygon,3035) + FROM ( + SELECT (ST_DUMP(ST_INTERSECTION(loads.geom,dis.geom))).geom AS geom + FROM openstreetmap.osm_polygon_urban_sector_4_agricultural_mview AS loads, + grid.egon_mv_grid_district AS dis + WHERE loads.geom && dis.geom + ) AS loads + WHERE ST_GeometryType(loads.geom) = 'ST_Polygon'; + +-- index GIST (geom) +CREATE INDEX urban_sector_per_grid_district_4_agricultural_geom_idx + ON openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural USING GIST (geom); + +-- sector stats +UPDATE demand.egon_loadarea AS t1 + SET sector_area_agricultural = t2.sector_area, + sector_count_agricultural = t2.sector_count, + sector_share_agricultural = t2.sector_area / t2.area_ha + FROM ( + SELECT loads.id AS id, + SUM(ST_AREA(sector.geom)/10000) AS sector_area, + COUNT(sector.geom) AS sector_count, + loads.area_ha AS area_ha + FROM openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural AS sector, + demand.egon_loadarea AS loads + WHERE loads.geom && sector.geom AND + ST_INTERSECTS(loads.geom,ST_BUFFER(sector.geom,-1)) + GROUP BY loads.id + ) AS t2 + WHERE t1.id = t2.id; + +-- sector stats +UPDATE demand.egon_loadarea AS t1 + SET sector_area_sum = t2.sector_area_sum, + sector_share_sum = t2.sector_share_sum, + sector_count_sum = t2.sector_count_sum + FROM ( + SELECT id, + coalesce(load.sector_area_residential,0) + + coalesce(load.sector_area_retail,0) + + coalesce(load.sector_area_industrial,0) + + coalesce(load.sector_area_agricultural,0) AS sector_area_sum, + coalesce(load.sector_share_residential,0) + + coalesce(load.sector_share_retail,0) + + coalesce(load.sector_share_industrial,0) + + coalesce(load.sector_share_agricultural,0) AS sector_share_sum, + coalesce(load.sector_count_residential,0) + + coalesce(load.sector_count_retail,0) + + coalesce(load.sector_count_industrial,0) + + coalesce(load.sector_count_agricultural,0) AS sector_count_sum + FROM demand.egon_loadarea AS load + ) AS t2 + WHERE t1.id = t2.id; + + + +-- Calculate statistics like NUTS and AGS code +-- nuts code (nuts) +UPDATE demand.egon_loadarea AS t1 + SET nuts = t2.nuts + FROM ( + SELECT loads.id AS id, + vg.nuts AS nuts + FROM demand.egon_loadarea AS loads, + boundaries.vg250_gem_clean AS vg + WHERE vg.geometry && loads.geom_centre AND + ST_CONTAINS(vg.geometry,loads.geom_centre) + ) AS t2 + WHERE t1.id = t2.id; + +-- regionalschlüssel (rs_0) +UPDATE demand.egon_loadarea AS t1 + SET rs_0 = t2.rs_0 + FROM ( + SELECT loads.id, + vg.rs_0 + FROM demand.egon_loadarea AS loads, + boundaries.vg250_gem_clean AS vg + WHERE vg.geometry && loads.geom_centre AND + ST_CONTAINS(vg.geometry,loads.geom_centre) + ) AS t2 + WHERE t1.id = t2.id; + +-- gemeindeschlüssel (ags_0) +UPDATE demand.egon_loadarea AS t1 + SET ags_0 = t2.ags_0 + FROM ( + SELECT loads.id AS id, + vg.ags_0 AS ags_0 + FROM demand.egon_loadarea AS loads, + boundaries.vg250_gem_clean AS vg + WHERE vg.geometry && loads.geom_centre AND + ST_CONTAINS(vg.geometry,loads.geom_centre) + ) AS t2 + WHERE t1.id = t2.id; + +-- substation id +UPDATE demand.egon_loadarea AS t1 + SET bus_id = t2.bus_id + FROM ( + SELECT a.id AS id, + b.bus_id AS bus_id + FROM demand.egon_loadarea AS a, + grid.egon_mv_grid_district AS b + WHERE b.geom && a.geom_centre AND + ST_CONTAINS(b.geom,a.geom_centre) + ) AS t2 + WHERE t1.id = t2.id; + + +-- Check for Loadareas without AGS code +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_error_noags_mview CASCADE; +CREATE MATERIALIZED VIEW demand.egon_loadarea_error_noags_mview AS + SELECT loads.id, + loads.geom + FROM demand.egon_loadarea AS loads + WHERE loads.ags_0 IS NULL; + +-- index (id) +CREATE UNIQUE INDEX egon_loadarea_error_noags_mview_id_idx + ON demand.egon_loadarea_error_noags_mview (id); + +-- index GIST (geom) +CREATE INDEX egon_loadarea_error_noags_mview_geom_idx + ON demand.egon_loadarea_error_noags_mview USING GIST (geom); From 97565f762a6e68519a7af2ef1ac21ac7fb7aa785 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 23:34:04 +0100 Subject: [PATCH 10/20] Rename task --- src/egon/data/datasets/loadarea/__init__.py | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/src/egon/data/datasets/loadarea/__init__.py b/src/egon/data/datasets/loadarea/__init__.py index 94565681c7..1347366c13 100644 --- a/src/egon/data/datasets/loadarea/__init__.py +++ b/src/egon/data/datasets/loadarea/__init__.py @@ -64,7 +64,7 @@ def __init__(self, dependencies): census_cells_melt, osm_landuse_census_cells_melt, loadareas_create, - loadareas_load_data, + loadareas_add_demand, drop_temp_tables, ), ) @@ -142,10 +142,10 @@ def loadareas_create(): execute_sql_script("loadareas_create.sql") -def loadareas_load_data(): +def loadareas_add_demand(): """Adds consumption and peak load per sector to load areas""" print("Add consumption and peak loads to load areas...") - execute_sql_script("loadareas_load_data.sql") + execute_sql_script("loadareas_add_demand.sql") def drop_temp_tables(): From 00c9e49227d5f23f7b0dbbcd924ac4223e2e77ec Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 23:35:45 +0100 Subject: [PATCH 11/20] Rename and add further columns on consumption and peak load for scenarios --- .../data/datasets/loadarea/loadareas_create.sql | 16 ++++++++++++++-- 1 file changed, 14 insertions(+), 2 deletions(-) diff --git a/src/egon/data/datasets/loadarea/loadareas_create.sql b/src/egon/data/datasets/loadarea/loadareas_create.sql index 4ddb28de59..9aabce1926 100644 --- a/src/egon/data/datasets/loadarea/loadareas_create.sql +++ b/src/egon/data/datasets/loadarea/loadareas_create.sql @@ -41,14 +41,26 @@ CREATE TABLE demand.egon_loadarea ( sector_count_agricultural integer, sector_count_sum integer, sector_consumption_residential double precision, + sector_consumption_residential_2035 double precision, + sector_consumption_residential_2050 double precision, sector_consumption_retail double precision, + sector_consumption_retail_2035 double precision, + sector_consumption_retail_2050 double precision, sector_consumption_industrial double precision, - sector_consumption_agricultural double precision, + sector_consumption_industrial_2035 double precision, + sector_consumption_industrial_2050 double precision, + --sector_consumption_agricultural double precision, sector_consumption_sum double precision, sector_peakload_retail double precision, + sector_peakload_retail_2035 double precision, + sector_peakload_retail_2050 double precision, sector_peakload_residential double precision, + sector_peakload_residential_2035 double precision, + sector_peakload_residential_2050 double precision, sector_peakload_industrial double precision, - sector_peakload_agricultural double precision, + sector_peakload_industrial_2035 double precision, + sector_peakload_industrial_2050 double precision, + --sector_peakload_agricultural double precision, geom_centroid geometry(POINT,3035), geom_surfacepoint geometry(POINT,3035), geom_centre geometry(POINT,3035), From 546be49f9a7c1db732efdf2bb7120b91b9ecb5a1 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 23:48:03 +0100 Subject: [PATCH 12/20] Add SQL script: add consumption and peak load to load areas for residential+cts --- .../loadarea/loadareas_add_demand.sql | 252 ++++++++++++++++++ 1 file changed, 252 insertions(+) create mode 100644 src/egon/data/datasets/loadarea/loadareas_add_demand.sql diff --git a/src/egon/data/datasets/loadarea/loadareas_add_demand.sql b/src/egon/data/datasets/loadarea/loadareas_add_demand.sql new file mode 100644 index 0000000000..1bd040e331 --- /dev/null +++ b/src/egon/data/datasets/loadarea/loadareas_add_demand.sql @@ -0,0 +1,252 @@ +/* +Add consumption and peak loads to load areas + +__copyright__ = "Reiner Lemoine Institut" +__license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" +__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__author__ = "nesnoj" +*/ + +------------------------ +-- Scenario: eGon2035 -- +------------------------ + +-- Add residential consumption +UPDATE demand.egon_loadarea AS t1 + SET sector_consumption_residential_2035 = t2.demand + FROM ( + SELECT a.id AS id, + SUM(b.demand)::float AS demand + FROM demand.egon_loadarea AS a, + ( + SELECT + dem.demand AS demand, + census.geom_point AS geom_point + FROM + demand.egon_demandregio_zensus_electricity as dem, + society.destatis_zensus_population_per_ha AS census + WHERE + dem.scenario = 'eGon2035' AND + dem.sector = 'residential' AND + dem.zensus_population_id = census.id + ) AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom, b.geom_point) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; + +-- Add CTS consumption +UPDATE demand.egon_loadarea AS t1 + SET sector_consumption_retail_2035 = t2.demand + FROM ( + SELECT a.id AS id, + SUM(b.demand)::float AS demand + FROM demand.egon_loadarea AS a, + ( + SELECT + dem.demand AS demand, + census.geom_point AS geom_point + FROM + demand.egon_demandregio_zensus_electricity as dem, + society.destatis_zensus_population_per_ha AS census + WHERE + dem.scenario = 'eGon2035' AND + dem.sector = 'service' AND + dem.zensus_population_id = census.id + ) AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom, b.geom_point) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; + +-- Add industrial consumption +-- TBD! + +-- Add residential peak load +UPDATE demand.egon_loadarea AS t1 + SET sector_peakload_residential_2035 = t2.peak_load_in_mw + FROM ( + SELECT a.id AS id, + SUM(b.peak_load_in_w)/1000000::float AS peak_load_in_mw + FROM demand.egon_loadarea AS a, + ( + SELECT + peak.peak_load_in_w AS peak_load_in_w, + bld.geom_point AS geom_point + FROM + demand.egon_building_electricity_peak_loads as peak, + ( + SELECT "id"::integer, geom_point + FROM openstreetmap.osm_buildings_synthetic + UNION + SELECT "id"::integer, geom_point + FROM openstreetmap.osm_buildings_filtered + ) AS bld + WHERE + peak.scenario = 'eGon2035' AND + peak.sector = 'residential' AND + peak.building_id = bld.id + ) AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom, b.geom_point) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; + +-- Add CTS peak load +UPDATE demand.egon_loadarea AS t1 + SET sector_peakload_retail_2035 = t2.peak_load_in_mw + FROM ( + SELECT a.id AS id, + SUM(b.peak_load_in_w)/1000000::float AS peak_load_in_mw + FROM demand.egon_loadarea AS a, + ( + SELECT + peak.peak_load_in_w AS peak_load_in_w, + bld.geom_point AS geom_point + FROM + demand.egon_building_electricity_peak_loads as peak, + ( + SELECT "id"::integer, geom_point + FROM openstreetmap.osm_buildings_synthetic + UNION + SELECT "id"::integer, geom_point + FROM openstreetmap.osm_buildings_filtered + ) AS bld + WHERE + peak.scenario = 'eGon2035' AND + peak.sector = 'cts' AND + peak.building_id = bld.id + ) AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom, b.geom_point) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; + +-- Add industrial peak load +-- TBD! + +------------------------- +-- Scenario: eGon100RE -- +------------------------- + +-- Add residential consumption +UPDATE demand.egon_loadarea AS t1 + SET sector_consumption_residential_2050 = t2.demand + FROM ( + SELECT a.id AS id, + SUM(b.demand)::float AS demand + FROM demand.egon_loadarea AS a, + ( + SELECT + dem.demand AS demand, + census.geom_point AS geom_point + FROM + demand.egon_demandregio_zensus_electricity as dem, + society.destatis_zensus_population_per_ha AS census + WHERE + dem.scenario = 'eGon100RE' AND + dem.sector = 'residential' AND + dem.zensus_population_id = census.id + ) AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom, b.geom_point) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; + +-- Add CTS consumption +UPDATE demand.egon_loadarea AS t1 + SET sector_consumption_retail_2050 = t2.demand + FROM ( + SELECT a.id AS id, + SUM(b.demand)::float AS demand + FROM demand.egon_loadarea AS a, + ( + SELECT + dem.demand AS demand, + census.geom_point AS geom_point + FROM + demand.egon_demandregio_zensus_electricity as dem, + society.destatis_zensus_population_per_ha AS census + WHERE + dem.scenario = 'eGon100RE' AND + dem.sector = 'service' AND + dem.zensus_population_id = census.id + ) AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom, b.geom_point) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; + +-- Add industrial consumption +-- TBD! + +-- Add residential peak load +UPDATE demand.egon_loadarea AS t1 + SET sector_peakload_residential_2050 = t2.peak_load_in_mw + FROM ( + SELECT a.id AS id, + SUM(b.peak_load_in_w)/1000000::float AS peak_load_in_mw + FROM demand.egon_loadarea AS a, + ( + SELECT + peak.peak_load_in_w AS peak_load_in_w, + bld.geom_point AS geom_point + FROM + demand.egon_building_electricity_peak_loads as peak, + ( + SELECT "id"::integer, geom_point + FROM openstreetmap.osm_buildings_synthetic + UNION + SELECT "id"::integer, geom_point + FROM openstreetmap.osm_buildings_filtered + ) AS bld + WHERE + peak.scenario = 'eGon100RE' AND + peak.sector = 'residential' AND + peak.building_id = bld.id + ) AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom, b.geom_point) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; + +-- Add CTS peak load +UPDATE demand.egon_loadarea AS t1 + SET sector_peakload_retail_2050 = t2.peak_load_in_mw + FROM ( + SELECT a.id AS id, + SUM(b.peak_load_in_w)/1000000::float AS peak_load_in_mw + FROM demand.egon_loadarea AS a, + ( + SELECT + peak.peak_load_in_w AS peak_load_in_w, + bld.geom_point AS geom_point + FROM + demand.egon_building_electricity_peak_loads as peak, + ( + SELECT "id"::integer, geom_point + FROM openstreetmap.osm_buildings_synthetic + UNION + SELECT "id"::integer, geom_point + FROM openstreetmap.osm_buildings_filtered + ) AS bld + WHERE + peak.scenario = 'eGon100RE' AND + peak.sector = 'cts' AND + peak.building_id = bld.id + ) AS b + WHERE a.geom && b.geom_point AND + ST_CONTAINS(a.geom, b.geom_point) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; + +-- Add industrial peak load +-- TBD! From e146c0ba0f062ab7d77636e43688f9c7d0339485 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 1 Nov 2022 23:48:48 +0100 Subject: [PATCH 13/20] Remove table column --- src/egon/data/datasets/loadarea/loadareas_create.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/src/egon/data/datasets/loadarea/loadareas_create.sql b/src/egon/data/datasets/loadarea/loadareas_create.sql index 9aabce1926..ea17a8a8e7 100644 --- a/src/egon/data/datasets/loadarea/loadareas_create.sql +++ b/src/egon/data/datasets/loadarea/loadareas_create.sql @@ -50,7 +50,6 @@ CREATE TABLE demand.egon_loadarea ( sector_consumption_industrial_2035 double precision, sector_consumption_industrial_2050 double precision, --sector_consumption_agricultural double precision, - sector_consumption_sum double precision, sector_peakload_retail double precision, sector_peakload_retail_2035 double precision, sector_peakload_retail_2050 double precision, From 05f18d76ef07ce3139d91615de63127d8e4d2b20 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 8 Nov 2022 09:53:13 +0100 Subject: [PATCH 14/20] Add industrial demand to load areas --- .../loadarea/loadareas_add_demand.sql | 48 ++++++++++++++++++- 1 file changed, 46 insertions(+), 2 deletions(-) diff --git a/src/egon/data/datasets/loadarea/loadareas_add_demand.sql b/src/egon/data/datasets/loadarea/loadareas_add_demand.sql index 1bd040e331..92cb883abf 100644 --- a/src/egon/data/datasets/loadarea/loadareas_add_demand.sql +++ b/src/egon/data/datasets/loadarea/loadareas_add_demand.sql @@ -62,7 +62,29 @@ UPDATE demand.egon_loadarea AS t1 WHERE t1.id = t2.id; -- Add industrial consumption --- TBD! +UPDATE demand.egon_loadarea AS t1 + SET sector_consumption_industrial_2035 = t2.demand + FROM ( + SELECT a.id AS id, + SUM(b.demand)::float AS demand + FROM demand.egon_loadarea AS a, + ( + SELECT + sum(dem.demand) as demand, + ST_PointOnSurface(osm.geom) AS geom_surfacepoint + FROM + openstreetmap.osm_landuse as osm, + demand.egon_demandregio_osm_ind_electricity as dem + WHERE + dem.scenario = 'eGon2035' AND + dem.osm_id = osm.id + GROUP BY osm.id + ) AS b + WHERE a.geom && b.geom_surfacepoint AND + ST_CONTAINS(a.geom, b.geom_surfacepoint) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; -- Add residential peak load UPDATE demand.egon_loadarea AS t1 @@ -184,7 +206,29 @@ UPDATE demand.egon_loadarea AS t1 WHERE t1.id = t2.id; -- Add industrial consumption --- TBD! +UPDATE demand.egon_loadarea AS t1 + SET sector_consumption_industrial_2050 = t2.demand + FROM ( + SELECT a.id AS id, + SUM(b.demand)::float AS demand + FROM demand.egon_loadarea AS a, + ( + SELECT + sum(dem.demand) as demand, + ST_PointOnSurface(osm.geom) AS geom_surfacepoint + FROM + openstreetmap.osm_landuse as osm, + demand.egon_demandregio_osm_ind_electricity as dem + WHERE + dem.scenario = 'eGon100RE' AND + dem.osm_id = osm.id + GROUP BY osm.id + ) AS b + WHERE a.geom && b.geom_surfacepoint AND + ST_CONTAINS(a.geom, b.geom_surfacepoint) + GROUP BY a.id + ) AS t2 + WHERE t1.id = t2.id; -- Add residential peak load UPDATE demand.egon_loadarea AS t1 From 5c6c5d1fbe8ff8be922d270cdebfe08ff5cbdafe Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 8 Nov 2022 10:15:40 +0100 Subject: [PATCH 15/20] Add SQL script: drop temp tables --- src/egon/data/datasets/loadarea/__init__.py | 2 +- .../datasets/loadarea/drop_temp_tables.sql | 28 +++++++++++++++++++ 2 files changed, 29 insertions(+), 1 deletion(-) create mode 100644 src/egon/data/datasets/loadarea/drop_temp_tables.sql diff --git a/src/egon/data/datasets/loadarea/__init__.py b/src/egon/data/datasets/loadarea/__init__.py index 1347366c13..2ee5ad80e7 100644 --- a/src/egon/data/datasets/loadarea/__init__.py +++ b/src/egon/data/datasets/loadarea/__init__.py @@ -149,5 +149,5 @@ def loadareas_add_demand(): def drop_temp_tables(): - print("Dropping temp tables...") + print("Dropping temp tables, views and sequences...") execute_sql_script("drop_temp_tables.sql") diff --git a/src/egon/data/datasets/loadarea/drop_temp_tables.sql b/src/egon/data/datasets/loadarea/drop_temp_tables.sql new file mode 100644 index 0000000000..1824359996 --- /dev/null +++ b/src/egon/data/datasets/loadarea/drop_temp_tables.sql @@ -0,0 +1,28 @@ +-- Drop temp tables, views and sequences + +-- From script: osm_landuse_melt.sql +DROP SEQUENCE IF EXISTS openstreetmap.osm_landuse_buffer100_mview_id CASCADE; +DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_landuse_buffer100_mview CASCADE; +DROP TABLE IF EXISTS openstreetmap.osm_landuse_melted CASCADE; + +-- From script: census_cells_melt.sql +DROP TABLE IF EXISTS society.egon_destatis_zensus_cells_melted CASCADE; +DROP TABLE IF EXISTS society.egon_destatis_zensus_cells_melted_cluster CASCADE; +DROP MATERIALIZED VIEW IF EXISTS openstreetmap.egon_society_zensus_per_la_mview CASCADE; + +-- From script: osm_landuse_census_cells_melt.sql +DROP TABLE IF EXISTS demand.egon_loadarea_load_collect CASCADE; +DROP TABLE IF EXISTS demand.egon_loadarea_load_collect_buffer100 CASCADE; +DROP TABLE IF EXISTS demand.egon_loadarea_load_melt CASCADE; +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_geom_mview CASCADE; +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_geom_fix_mview CASCADE; +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_2_geom_mview CASCADE; + +-- From script: loadareas_create.sql +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_smaller100m2_mview CASCADE; +DROP TABLE IF EXISTS openstreetmap.egon_osm_sector_per_griddistrict_1_residential CASCADE; +DROP TABLE IF EXISTS openstreetmap.egon_osm_sector_per_griddistrict_2_retail CASCADE; +DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_polygon_urban_sector_3_industrial_nolargescale_mview CASCADE; +DROP TABLE IF EXISTS openstreetmap.egon_osm_sector_per_griddistrict_3_industrial CASCADE; +DROP TABLE IF EXISTS openstreetmap.egon_osm_sector_per_griddistrict_4_agricultural CASCADE; +DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_error_noags_mview CASCADE; From 9fac776523999e007477237d8532752eb7f95955 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 8 Nov 2022 10:16:50 +0100 Subject: [PATCH 16/20] Change tables' prefix to egon --- .../datasets/loadarea/census_cells_melt.sql | 4 +- .../datasets/loadarea/loadareas_create.sql | 44 +++++++++---------- .../datasets/loadarea/osm_landuse_melt.sql | 2 +- 3 files changed, 25 insertions(+), 25 deletions(-) diff --git a/src/egon/data/datasets/loadarea/census_cells_melt.sql b/src/egon/data/datasets/loadarea/census_cells_melt.sql index 3e8d02ec01..752d657fdc 100644 --- a/src/egon/data/datasets/loadarea/census_cells_melt.sql +++ b/src/egon/data/datasets/loadarea/census_cells_melt.sql @@ -136,8 +136,8 @@ UPDATE society.egon_destatis_zensus_cells_melted_cluster AS t1 -- zensus stats -DROP MATERIALIZED VIEW IF EXISTS openstreetmap.ego_society_zensus_per_la_mview CASCADE; -CREATE MATERIALIZED VIEW openstreetmap.ego_society_zensus_per_la_mview AS +DROP MATERIALIZED VIEW IF EXISTS openstreetmap.egon_society_zensus_per_la_mview CASCADE; +CREATE MATERIALIZED VIEW openstreetmap.egon_society_zensus_per_la_mview AS -- SELECT 'destatis_zensus_population_per_ha_mview' AS name, -- sum(population), -- count(geom) AS census_count diff --git a/src/egon/data/datasets/loadarea/loadareas_create.sql b/src/egon/data/datasets/loadarea/loadareas_create.sql index ea17a8a8e7..697a6d348d 100644 --- a/src/egon/data/datasets/loadarea/loadareas_create.sql +++ b/src/egon/data/datasets/loadarea/loadareas_create.sql @@ -194,14 +194,14 @@ UPDATE demand.egon_loadarea AS t1 -- Cut all 4 OSM sectors with MV Griddistricts -- 1. Residential sector -DROP TABLE IF EXISTS openstreetmap.ego_osm_sector_per_griddistrict_1_residential CASCADE; -CREATE TABLE openstreetmap.ego_osm_sector_per_griddistrict_1_residential ( +DROP TABLE IF EXISTS openstreetmap.egon_osm_sector_per_griddistrict_1_residential CASCADE; +CREATE TABLE openstreetmap.egon_osm_sector_per_griddistrict_1_residential ( id SERIAL NOT NULL, geom geometry(Polygon,3035), CONSTRAINT urban_sector_per_grid_district_1_residential_pkey PRIMARY KEY (id)); -- intersect sector with mv-griddistrict -INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_1_residential (geom) +INSERT INTO openstreetmap.egon_osm_sector_per_griddistrict_1_residential (geom) SELECT loads.geom ::geometry(Polygon,3035) FROM ( SELECT (ST_DUMP(ST_INTERSECTION(loads.geom,dis.geom))).geom AS geom @@ -213,7 +213,7 @@ INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_1_residential (geo -- index GIST (geom) CREATE INDEX urban_sector_per_grid_district_1_residential_geom_idx - ON openstreetmap.ego_osm_sector_per_griddistrict_1_residential USING GIST (geom); + ON openstreetmap.egon_osm_sector_per_griddistrict_1_residential USING GIST (geom); -- sector stats UPDATE demand.egon_loadarea AS t1 @@ -225,7 +225,7 @@ UPDATE demand.egon_loadarea AS t1 SUM(ST_AREA(sector.geom)/10000) AS sector_area, COUNT(sector.geom) AS sector_count, loads.area_ha AS area_ha - FROM openstreetmap.ego_osm_sector_per_griddistrict_1_residential AS sector, + FROM openstreetmap.egon_osm_sector_per_griddistrict_1_residential AS sector, demand.egon_loadarea AS loads WHERE loads.geom && sector.geom AND ST_INTERSECTS(loads.geom,ST_BUFFER(sector.geom,-1)) @@ -234,14 +234,14 @@ UPDATE demand.egon_loadarea AS t1 WHERE t1.id = t2.id; -- 2. Retail sector -DROP TABLE IF EXISTS openstreetmap.ego_osm_sector_per_griddistrict_2_retail CASCADE; -CREATE TABLE openstreetmap.ego_osm_sector_per_griddistrict_2_retail ( +DROP TABLE IF EXISTS openstreetmap.egon_osm_sector_per_griddistrict_2_retail CASCADE; +CREATE TABLE openstreetmap.egon_osm_sector_per_griddistrict_2_retail ( id SERIAL NOT NULL, geom geometry(Polygon,3035), CONSTRAINT urban_sector_per_grid_district_2_retail_pkey PRIMARY KEY (id)); -- intersect sector with mv-griddistrict -INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_2_retail (geom) +INSERT INTO openstreetmap.egon_osm_sector_per_griddistrict_2_retail (geom) SELECT loads.geom ::geometry(Polygon,3035) FROM ( SELECT (ST_DUMP(ST_INTERSECTION(loads.geom,dis.geom))).geom AS geom @@ -253,7 +253,7 @@ INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_2_retail (geom) -- index GIST (geom) CREATE INDEX urban_sector_per_grid_district_2_retail_geom_idx - ON openstreetmap.ego_osm_sector_per_griddistrict_2_retail USING GIST (geom); + ON openstreetmap.egon_osm_sector_per_griddistrict_2_retail USING GIST (geom); -- sector stats UPDATE demand.egon_loadarea AS t1 @@ -265,7 +265,7 @@ UPDATE demand.egon_loadarea AS t1 SUM(ST_AREA(sector.geom)/10000) AS sector_area, COUNT(sector.geom) AS sector_count, loads.area_ha AS area_ha - FROM openstreetmap.ego_osm_sector_per_griddistrict_2_retail AS sector, + FROM openstreetmap.egon_osm_sector_per_griddistrict_2_retail AS sector, demand.egon_loadarea AS loads WHERE loads.geom && sector.geom AND ST_INTERSECTS(loads.geom,ST_BUFFER(sector.geom,-1)) @@ -278,7 +278,7 @@ DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_polygon_urban_sector_3_indust CREATE MATERIALIZED VIEW openstreetmap.osm_polygon_urban_sector_3_industrial_nolargescale_mview AS SELECT osm.* FROM openstreetmap.osm_polygon_urban AS osm - WHERE sector = '3' --AND gid NOT IN (SELECT polygon_id FROM model_draft.ego_demand_hv_largescaleconsumer) -- 31.10.22: COMMENTED OUT! CHECK IF NECESSARY!!! + WHERE sector = '3' --AND gid NOT IN (SELECT polygon_id FROM model_draft.egon_demand_hv_largescaleconsumer) -- 31.10.22: COMMENTED OUT! CHECK IF NECESSARY!!! ORDER BY osm.id; -- index (id) @@ -297,7 +297,7 @@ FROM openstreetmap.osm_deu_polygon_urban_sector_3_industrial_mview ind UNION ALL SELECT 'largescale' AS name, count(ls.*) AS cnt -FROM model_draft.ego_demand_hv_largescaleconsumer ls +FROM model_draft.egon_demand_hv_largescaleconsumer ls UNION ALL SELECT 'nolargescale' AS name, count(nols.*) AS cnt @@ -306,14 +306,14 @@ FROM openstreetmap.osm_deu_polygon_urban_sector_3_industrial_nolargescale_mvi -- 3. industrial sector -DROP TABLE IF EXISTS openstreetmap.ego_osm_sector_per_griddistrict_3_industrial CASCADE; -CREATE TABLE openstreetmap.ego_osm_sector_per_griddistrict_3_industrial ( +DROP TABLE IF EXISTS openstreetmap.egon_osm_sector_per_griddistrict_3_industrial CASCADE; +CREATE TABLE openstreetmap.egon_osm_sector_per_griddistrict_3_industrial ( id SERIAL NOT NULL, geom geometry(Polygon,3035), CONSTRAINT urban_sector_per_grid_district_3_industrial_pkey PRIMARY KEY (id)); -- intersect sector with mv-griddistrict -INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_3_industrial (geom) +INSERT INTO openstreetmap.egon_osm_sector_per_griddistrict_3_industrial (geom) SELECT loads.geom ::geometry(Polygon,3035) FROM ( SELECT (ST_DUMP(ST_INTERSECTION(loads.geom,dis.geom))).geom AS geom @@ -325,7 +325,7 @@ INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_3_industrial (geom -- index GIST (geom) CREATE INDEX urban_sector_per_grid_district_3_industrial_geom_idx - ON openstreetmap.ego_osm_sector_per_griddistrict_3_industrial USING GIST (geom); + ON openstreetmap.egon_osm_sector_per_griddistrict_3_industrial USING GIST (geom); -- sector stats UPDATE demand.egon_loadarea AS t1 @@ -337,7 +337,7 @@ UPDATE demand.egon_loadarea AS t1 SUM(ST_AREA(sector.geom)/10000) AS sector_area, COUNT(sector.geom) AS sector_count, loads.area_ha AS area_ha - FROM openstreetmap.ego_osm_sector_per_griddistrict_3_industrial AS sector, + FROM openstreetmap.egon_osm_sector_per_griddistrict_3_industrial AS sector, demand.egon_loadarea AS loads WHERE loads.geom && sector.geom AND ST_INTERSECTS(loads.geom,ST_BUFFER(sector.geom,-1)) @@ -346,14 +346,14 @@ UPDATE demand.egon_loadarea AS t1 WHERE t1.id = t2.id; -- 4. agricultural sector -DROP TABLE IF EXISTS openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural CASCADE; -CREATE TABLE openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural ( +DROP TABLE IF EXISTS openstreetmap.egon_osm_sector_per_griddistrict_4_agricultural CASCADE; +CREATE TABLE openstreetmap.egon_osm_sector_per_griddistrict_4_agricultural ( id SERIAL NOT NULL, geom geometry(Polygon,3035), CONSTRAINT urban_sector_per_grid_district_4_agricultural_pkey PRIMARY KEY (id)); -- intersect sector with mv-griddistrict -INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural (geom) +INSERT INTO openstreetmap.egon_osm_sector_per_griddistrict_4_agricultural (geom) SELECT loads.geom ::geometry(Polygon,3035) FROM ( SELECT (ST_DUMP(ST_INTERSECTION(loads.geom,dis.geom))).geom AS geom @@ -365,7 +365,7 @@ INSERT INTO openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural (geom) -- index GIST (geom) CREATE INDEX urban_sector_per_grid_district_4_agricultural_geom_idx - ON openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural USING GIST (geom); + ON openstreetmap.egon_osm_sector_per_griddistrict_4_agricultural USING GIST (geom); -- sector stats UPDATE demand.egon_loadarea AS t1 @@ -377,7 +377,7 @@ UPDATE demand.egon_loadarea AS t1 SUM(ST_AREA(sector.geom)/10000) AS sector_area, COUNT(sector.geom) AS sector_count, loads.area_ha AS area_ha - FROM openstreetmap.ego_osm_sector_per_griddistrict_4_agricultural AS sector, + FROM openstreetmap.egon_osm_sector_per_griddistrict_4_agricultural AS sector, demand.egon_loadarea AS loads WHERE loads.geom && sector.geom AND ST_INTERSECTS(loads.geom,ST_BUFFER(sector.geom,-1)) diff --git a/src/egon/data/datasets/loadarea/osm_landuse_melt.sql b/src/egon/data/datasets/loadarea/osm_landuse_melt.sql index 0a33185bf2..3035361534 100644 --- a/src/egon/data/datasets/loadarea/osm_landuse_melt.sql +++ b/src/egon/data/datasets/loadarea/osm_landuse_melt.sql @@ -14,7 +14,7 @@ __author__ = "Ludee, nesnoj" -- 28.10.22: CHECK IF NECESSARY!!! -- exclude large scale consumer --DELETE FROM openstreetmap.osm_landuse --- WHERE gid IN (SELECT polygon_id FROM model_draft.ego_demand_hv_largescaleconsumer); +-- WHERE gid IN (SELECT polygon_id FROM model_draft.egon_demand_hv_largescaleconsumer); -- sequence From d730c7b78e8ac961446bebb0bf775a44aecc8ff8 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 8 Nov 2022 10:17:11 +0100 Subject: [PATCH 17/20] Remove old drop statements --- .../loadarea/osm_landuse_census_cells_melt.sql | 10 ---------- src/egon/data/datasets/loadarea/osm_landuse_melt.sql | 3 --- 2 files changed, 13 deletions(-) diff --git a/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql b/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql index 19b654cb59..d5a59ed5d9 100644 --- a/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql +++ b/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql @@ -158,13 +158,3 @@ CREATE UNIQUE INDEX egon_loadarea_load_melt_error_2_geom_mview_id_idx -- index GIST (geom) CREATE INDEX egon_loadarea_load_melt_error_2_geom_mview_geom_idx ON demand.egon_loadarea_load_melt_error_2_geom_mview USING GIST (geom); - - -/* -- drop temp -DROP TABLE IF EXISTS demand.egon_loadarea_load_collect CASCADE; -DROP TABLE IF EXISTS demand.egon_loadarea_load_collect_buffer100 CASCADE; -DROP TABLE IF EXISTS demand.egon_loadarea_load_melt CASCADE; -DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_geom_mview CASCADE; -DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_geom_fix_mview CASCADE; -DROP MATERIALIZED VIEW IF EXISTS demand.egon_loadarea_load_melt_error_2_geom_mview CASCADE; - */ diff --git a/src/egon/data/datasets/loadarea/osm_landuse_melt.sql b/src/egon/data/datasets/loadarea/osm_landuse_melt.sql index 3035361534..bc28753021 100644 --- a/src/egon/data/datasets/loadarea/osm_landuse_melt.sql +++ b/src/egon/data/datasets/loadarea/osm_landuse_melt.sql @@ -61,6 +61,3 @@ INSERT INTO openstreetmap.osm_landuse_melted(area_ha,geom) -- index GIST (geom) CREATE INDEX osm_landuse_melted_geom_idx ON openstreetmap.osm_landuse_melted USING GIST (geom); - - -DROP MATERIALIZED VIEW IF EXISTS openstreetmap.osm_landuse_buffer100_mview CASCADE; From b71d0fe03a47bf4f6517d466ed1d890e82112aa1 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 8 Nov 2022 10:23:42 +0100 Subject: [PATCH 18/20] Update license paths in SQL scripts --- src/egon/data/datasets/loadarea/census_cells_melt.sql | 2 +- src/egon/data/datasets/loadarea/loadareas_add_demand.sql | 2 +- src/egon/data/datasets/loadarea/loadareas_create.sql | 2 +- .../data/datasets/loadarea/osm_landuse_census_cells_melt.sql | 2 +- src/egon/data/datasets/loadarea/osm_landuse_extraction.sql | 2 +- src/egon/data/datasets/loadarea/osm_landuse_melt.sql | 2 +- 6 files changed, 6 insertions(+), 6 deletions(-) diff --git a/src/egon/data/datasets/loadarea/census_cells_melt.sql b/src/egon/data/datasets/loadarea/census_cells_melt.sql index 752d657fdc..6c7214bb9a 100644 --- a/src/egon/data/datasets/loadarea/census_cells_melt.sql +++ b/src/egon/data/datasets/loadarea/census_cells_melt.sql @@ -6,7 +6,7 @@ Include Census cells with CTS demand. __copyright__ = "Reiner Lemoine Institut" __license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" -__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__url__ = "https://github.com/openego/eGon-data/blob/main/LICENSE" __author__ = "Ludee, nesnoj" */ diff --git a/src/egon/data/datasets/loadarea/loadareas_add_demand.sql b/src/egon/data/datasets/loadarea/loadareas_add_demand.sql index 92cb883abf..608885b948 100644 --- a/src/egon/data/datasets/loadarea/loadareas_add_demand.sql +++ b/src/egon/data/datasets/loadarea/loadareas_add_demand.sql @@ -3,7 +3,7 @@ Add consumption and peak loads to load areas __copyright__ = "Reiner Lemoine Institut" __license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" -__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__url__ = "https://github.com/openego/eGon-data/blob/main/LICENSE" __author__ = "nesnoj" */ diff --git a/src/egon/data/datasets/loadarea/loadareas_create.sql b/src/egon/data/datasets/loadarea/loadareas_create.sql index 697a6d348d..8bffc86c22 100644 --- a/src/egon/data/datasets/loadarea/loadareas_create.sql +++ b/src/egon/data/datasets/loadarea/loadareas_create.sql @@ -9,7 +9,7 @@ Check for Loadareas without AGS code. __copyright__ = "Reiner Lemoine Institut" __license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" -__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__url__ = "https://github.com/openego/eGon-data/blob/main/LICENSE" __author__ = "Ludee, nesnoj" */ diff --git a/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql b/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql index d5a59ed5d9..ea7c2a80c5 100644 --- a/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql +++ b/src/egon/data/datasets/loadarea/osm_landuse_census_cells_melt.sql @@ -9,7 +9,7 @@ Check again for errors. __copyright__ = "Reiner Lemoine Institut" __license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" -__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__url__ = "https://github.com/openego/eGon-data/blob/main/LICENSE" __author__ = "Ludee, nesnoj" */ diff --git a/src/egon/data/datasets/loadarea/osm_landuse_extraction.sql b/src/egon/data/datasets/loadarea/osm_landuse_extraction.sql index f62863e78c..9d1765e6b0 100644 --- a/src/egon/data/datasets/loadarea/osm_landuse_extraction.sql +++ b/src/egon/data/datasets/loadarea/osm_landuse_extraction.sql @@ -9,7 +9,7 @@ Divide into 4 landuse sectors: 4. Agricultural __copyright__ = "Reiner Lemoine Institut" __license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" -__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__url__ = "https://github.com/openego/eGon-data/blob/main/LICENSE" __author__ = "Ludee, IlkaCu, nesnoj" */ diff --git a/src/egon/data/datasets/loadarea/osm_landuse_melt.sql b/src/egon/data/datasets/loadarea/osm_landuse_melt.sql index bc28753021..d8c179e708 100644 --- a/src/egon/data/datasets/loadarea/osm_landuse_melt.sql +++ b/src/egon/data/datasets/loadarea/osm_landuse_melt.sql @@ -6,7 +6,7 @@ Unbuffer buffer with -100m __copyright__ = "Reiner Lemoine Institut" __license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" -__url__ = "https://github.com/openego/data_processing/blob/master/LICENSE" +__url__ = "https://github.com/openego/eGon-data/blob/main/LICENSE" __author__ = "Ludee, nesnoj" */ From 37fbb0d3c4648521a04d403e0ea58b9b00502b7f Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 8 Nov 2022 10:24:49 +0100 Subject: [PATCH 19/20] Add header to drop script --- src/egon/data/datasets/loadarea/drop_temp_tables.sql | 9 ++++++++- 1 file changed, 8 insertions(+), 1 deletion(-) diff --git a/src/egon/data/datasets/loadarea/drop_temp_tables.sql b/src/egon/data/datasets/loadarea/drop_temp_tables.sql index 1824359996..e62aee3217 100644 --- a/src/egon/data/datasets/loadarea/drop_temp_tables.sql +++ b/src/egon/data/datasets/loadarea/drop_temp_tables.sql @@ -1,4 +1,11 @@ --- Drop temp tables, views and sequences +/* +Drop temp tables, views and sequences + +__copyright__ = "Reiner Lemoine Institut" +__license__ = "GNU Affero General Public License Version 3 (AGPL-3.0)" +__url__ = "https://github.com/openego/eGon-data/blob/main/LICENSE" +__author__ = "nesnoj" +*/ -- From script: osm_landuse_melt.sql DROP SEQUENCE IF EXISTS openstreetmap.osm_landuse_buffer100_mview_id CASCADE; From 55507fd85f0f14d96731bc31804ec1462c21fff7 Mon Sep 17 00:00:00 2001 From: nesnoj Date: Tue, 8 Nov 2022 11:14:27 +0100 Subject: [PATCH 20/20] Set pipeline dependencies for load areas dataset --- src/egon/data/airflow/dags/pipeline.py | 17 +++++++++++++---- 1 file changed, 13 insertions(+), 4 deletions(-) diff --git a/src/egon/data/airflow/dags/pipeline.py b/src/egon/data/airflow/dags/pipeline.py index 826cf3c865..48e1a8e04f 100644 --- a/src/egon/data/airflow/dags/pipeline.py +++ b/src/egon/data/airflow/dags/pipeline.py @@ -242,9 +242,6 @@ dependencies=[mv_grid_districts, vg250] ) - # Create load areas - load_areas = LoadArea(dependencies=[osm_landuse]) - # Create household demand profiles on zensus level hh_demand_profiles_setup = hh_profiles.HouseholdDemands( dependencies=[ @@ -422,7 +419,7 @@ run_pypsaeursec, foreign_lines, insert_hydrogen_buses, - create_gas_polygons_egon100RE + create_gas_polygons_egon100RE, ] ) @@ -594,6 +591,18 @@ ] ) + # Create load areas + load_areas = LoadArea( + dependencies=[ + osm_landuse, + zensus_vg250, + household_electricity_demand_annual, + tasks["hh_buildings.get-building-peak-loads"], + cts_demand_buildings, + demand_curves_industry, + ] + ) + # ########## Keep this dataset at the end # Sanity Checks sanity_checks = SanityChecks(