diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..b750ca5 --- /dev/null +++ b/.gitignore @@ -0,0 +1,8 @@ + +*.pyc + +*.pbf + +*.qgs + +*.csv diff --git a/code/build_up_db.sql b/code/build_up_db.sql index 68e0f85..f9677d6 100755 --- a/code/build_up_db.sql +++ b/code/build_up_db.sql @@ -167,6 +167,17 @@ CREATE TABLE IF NOT EXISTS results.nuts3_subst( ALTER TABLE results.nuts3_subst DROP CONSTRAINT IF EXISTS result_fk; ALTER TABLE results.nuts3_subst ADD CONSTRAINT result_fk foreign key (result_id) references results.results_metadata (id) ON DELETE CASCADE; + +CREATE TABLE IF NOT EXISTS results.nuts3_subst_110kv( + result_id INT, + nuts_id Character Varying (14), + substation_id BIGINT, + percentage NUMERIC, + distance NUMERIC); + +ALTER TABLE results.nuts3_subst_110kv DROP CONSTRAINT IF EXISTS result_fk; +ALTER TABLE results.nuts3_subst_110kv + ADD CONSTRAINT result_fk foreign key (result_id) references results.results_metadata (id) ON DELETE CASCADE; CREATE TABLE IF NOT EXISTS results.plz_subst( result_id INT, @@ -179,6 +190,16 @@ ALTER TABLE results.plz_subst DROP CONSTRAINT IF EXISTS result_fk; ALTER TABLE results.plz_subst ADD CONSTRAINT result_fk foreign key (result_id) references results.results_metadata (id) ON DELETE CASCADE; +CREATE TABLE IF NOT EXISTS results.plz_subst_110kv( + result_id INT, + plz INTEGER, + substation_id BIGINT, + percentage NUMERIC, + distance NUMERIC); + +ALTER TABLE results.plz_subst_110kv DROP CONSTRAINT IF EXISTS result_fk; +ALTER TABLE results.plz_subst_110kv + ADD CONSTRAINT result_fk foreign key (result_id) references results.results_metadata (id) ON DELETE CASCADE; CREATE TABLE IF NOT EXISTS results.substations( result_id INT, diff --git a/code/functions.sql b/code/functions.sql index a3a3240..acace89 100755 --- a/code/functions.sql +++ b/code/functions.sql @@ -1151,6 +1151,113 @@ LANGUAGE plpgsql; -- TOPOLOGIE-BERECHNUNG + +-- OTG_split_table () Teilt eine Tabelle v_table in 10 Einzeltabellen auf. Dabei ist die in v_parameter spezifizierte Spalte das Unterscheidungsmerkmal. Die Ursprüngliche Tabelle wird nach der Aufteilung gelöscht. + +CREATE OR REPLACE FUNCTION otg_split_table (v_table TEXT, v_parameter TEXT) RETURNS void +AS $$ + +DECLARE +number_of_rows INT; +part_end_1 INT; +part_end_2 INT; +part_end_3 INT; +part_end_4 INT; +part_end_5 INT; +part_end_6 INT; +part_end_7 INT; +part_end_8 INT; +part_end_9 INT; + +BEGIN + +-- Eine Hilfstabelle, in welcher die Rheinfolge der 10 Einzeltabellen bestimmt wird wird erstellt. +EXECUTE 'CREATE TABLE table_order AS +SELECT DISTINCT ' || v_parameter || ' FROM ' || v_table ||' +ORDER BY ' || v_parameter; +ALTER TABLE table_order ADD COLUMN indx serial NOT NULL PRIMARY KEY; + +number_of_rows := (SELECT COUNT (*) +FROM table_order); + +part_end_1 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_1 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_1 ||') +ORDER BY '|| v_parameter; + +part_end_2 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (2*number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_2 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_1 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_2 ||') +ORDER BY '|| v_parameter; + +part_end_3 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (3*number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_3 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_2 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_3 ||') +ORDER BY '|| v_parameter; + +part_end_4 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (4*number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_4 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_3 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_4 ||') +ORDER BY '|| v_parameter; + +part_end_5 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (5*number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_5 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_4 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_5 ||') +ORDER BY '|| v_parameter; + +part_end_6 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (6*number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_6 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_5 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_6 ||') +ORDER BY '|| v_parameter; + +part_end_7 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (7*number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_7 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_6 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_7 ||') +ORDER BY '|| v_parameter; + +part_end_8 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (8*number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_8 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_7 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_8 ||') +ORDER BY '|| v_parameter; + +part_end_9 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (9*number_of_rows/10)) = indx); +EXECUTE 'CREATE TABLE split_table_9 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_8 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_9 ||') +ORDER BY '|| v_parameter; + +EXECUTE 'CREATE TABLE split_table_10 AS +SELECT * +FROM '|| v_table ||' +WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_9 ||') +ORDER BY '|| v_parameter; + +DROP TABLE table_order; +-- Löschung der Ursprünglichen Tabelle um Doppelungen zu vermeiden. +EXECUTE 'DROP TABLE '|| v_table; + +END +$$ +LANGUAGE plpgsql; + + -- CREATE_GRID_TOPOLOGY -- Hier werden die Topologien der Spannungsebenen / Stromkreise berechnet. @@ -1205,9 +1312,9 @@ LOOP AND main.voltage = '|| v_params.voltage ||' AND main.frequency = '|| v_params.frequency; - -- pgr_createTopology should not be used. + -- pgr_createTopology should not be used. Which alternatives do we have? PERFORM pgr_createTopology ( 'branch_data_topo', --source und target werden immer wieder auf NULL gesetzt und Topologie neu berechnet. - 0.0005, -- Is this a good buffer? + 0.0001, -- Is this a good buffer? 0.0005 was not good, some lines have been deleted which should not have been. 'way', 'line_id'); @@ -1296,13 +1403,29 @@ UPDATE bus_data SET substation_id = (SELECT power_substation.id AS substation_id FROM power_substation, bus_data bus - WHERE ST_Intersects (ST_Buffer(bus.the_geom, 0.004), power_substation.poly) AND -- 0.004° (breite) = 443m Buffer + WHERE ST_Intersects (ST_Buffer(bus.the_geom, 0.003), power_substation.poly) AND -- 0.004° (breite) = 443m Buffer bus.id = bus_data.id LIMIT 1), -- verbessern: wenn Buffer mehrer findet soll er nähere nehmen! buffered = true WHERE cnt = 1 AND substation_id IS NULL AND origin = 'rel'; -- Das obere Update wird immer durchgeführt, auch wenn keine Überschneidung stattfindet UPDATE bus_data SET buffered = false WHERE buffered = true AND substation_id IS NULL AND origin = 'rel'; -- Also alle nicht erfolgreichen Buffer +-- Try the buffer in non german Substations as well +UPDATE bus_data +SET substation_id = + (SELECT power_substation.id AS substation_id + FROM power_substation, bus_data bus + WHERE ST_Intersects (ST_Buffer(bus.the_geom, 0.003), power_substation.poly) AND -- 0.004° (breite) = 443m Buffer + bus.id = bus_data.id LIMIT 1), -- verbessern: wenn Buffer mehrer findet soll er nähere nehmen! + buffered = true + WHERE cnt = 1 AND substation_id = 0 AND origin = 'rel' AND cntr_id != 'DE'; +-- Das obere Update wird immer durchgeführt, auch wenn keine Überschneidung stattfindet +UPDATE bus_data + SET buffered = false WHERE buffered = true AND substation_id IS NULL AND origin = 'rel' AND cntr_id != 'DE'; -- Also alle nicht erfolgreichen Buffer + +UPDATE bus_data + SET substation_id = 0 WHERE cnt = 1 AND substation_id IS NULL AND origin = 'rel' AND cntr_id != 'DE'; -- Also alle nicht erfolgreichen Buffer auf id = 0 zurücksetzten + END $$ LANGUAGE plpgsql; @@ -1601,7 +1724,7 @@ BEGIN END IF; -- Falls v_lev mehr als einen Eintrag hat werden die Einträge neu geordnet... - --... und zwar so, dass in v_freq auftrtende Level zuerst im Array stehen. + --... und zwar so, dass in v_freq auftretende Level zuerst im Array stehen. -- Dadurch werden zunächst die am besten passenden Levels ausgewählt IF array_length (v_lev, 1) > 1 THEN v_lev := otg_array_reorder_by_match (v_lev, v_freq); END IF; @@ -2251,7 +2374,78 @@ RETURN NULL; END; $$ LANGUAGE plpgsql; +-- OTG_plz_substation_110kV () + +-- Function to assign substations to plz +CREATE OR REPLACE FUNCTION otg_plz_substation_110kV () RETURNS void +AS $$ + +DECLARE +v_plz_area RECORD; +v_numb_subst INT; +v_total_plz_power NUMERIC; + +BEGIN +-- Creates new table for assignment of substations to plz +DROP TABLE IF EXISTS plz_substation_110kV; +IF (SELECT val_int + FROM abstr_values + WHERE val_description = 'min_voltage') > 110000 -- Only if min Voltage is higher than 110kV + THEN + CREATE TABLE plz_substation_110kV ( + plz INT, + substation_id INT, + percentage NUMERIC, + distance NUMERIC + ); + + + FOR v_plz_area IN SELECT plz::INT as plz, geom FROM plz_poly + LOOP + INSERT INTO plz_substation_110kV (plz, substation_id) + SELECT v_plz_area.plz, id + FROM power_substation + WHERE ST_Within(center_geom, v_plz_area.geom) + AND connection_110kV = 'TRUE' + AND NOT power = 'plant'; + + v_numb_subst := (SELECT count(*) FROM plz_substation_110kV WHERE plz = v_plz_area.plz); + + IF v_numb_subst = 0 + THEN + INSERT INTO plz_substation_110kV ( plz, + substation_id, + distance) + SELECT v_plz_area.plz, + id, + ST_Distance(ST_Centroid(v_plz_area.geom), center_geom) as dist + FROM power_substation + WHERE connection_110kV = 'TRUE' AND NOT power = 'plant' + ORDER BY dist ASC + LIMIT 1; + RAISE NOTICE 'remote added'; + END IF; + v_total_plz_power := (SELECT sum(s_long) + FROM power_substation + WHERE connection_110kV = 'TRUE' AND NOT power = 'plant' + AND id = ANY (SELECT substation_id + FROM plz_substation_110kV + WHERE plz = v_plz_area.plz)); + + UPDATE plz_substation_110kV + SET percentage = (((SELECT s_long + FROM power_substation + WHERE connection_110kV = 'TRUE' AND NOT power = 'plant' + AND id = substation_id) / v_total_plz_power) * 100) + WHERE plz = v_plz_area.plz; + + RAISE NOTICE 'done'; + END LOOP; +END IF; +END; +$$ LANGUAGE plpgsql; + -- OTG_PLZ_SUBSTATION () @@ -2320,7 +2514,7 @@ $$ LANGUAGE plpgsql; -- OTG_NUTS3_SUBSTATION () --- Function to assign substations to plz +-- Function to assign substations to nuts3 CREATE OR REPLACE FUNCTION otg_nuts3_substation () RETURNS void AS $$ @@ -2330,7 +2524,7 @@ v_numb_subst INT; v_total_nuts3_power NUMERIC; BEGIN --- Creates new table for assignment of substations to plz +-- Creates new table for assignment of substations to nuts3 DROP TABLE IF EXISTS nuts3_substation; CREATE TABLE nuts3_substation ( nuts_id CHARACTER VARYING (14), @@ -2384,6 +2578,80 @@ END LOOP; END; $$ LANGUAGE plpgsql; +-- OTG_NUTS3_SUBSTATION_110kV () + +-- Function to assign substations to nuts3 +CREATE OR REPLACE FUNCTION otg_nuts3_substation_110kV () RETURNS void +AS $$ + +DECLARE +v_nuts3_area RECORD; +v_numb_subst INT; +v_total_nuts3_power NUMERIC; + +BEGIN +-- Creates new table for assignment of substations to nuts3 +DROP TABLE IF EXISTS nuts3_substation_110kV; +IF (SELECT val_int + FROM abstr_values + WHERE val_description = 'min_voltage') > 110000 -- Only if min Voltage is higher than 110kV + THEN + + CREATE TABLE nuts3_substation_110kV ( + nuts_id CHARACTER VARYING (14), + substation_id INT, + percentage NUMERIC, + distance NUMERIC + ); + + + FOR v_nuts3_area IN SELECT nuts_id, geom + FROM nuts_poly + WHERE nuts_id ILIKE '%DE%' AND -- Only Germany + stat_levl_ = 3 -- Only Nuts3 + LOOP + INSERT INTO nuts3_substation_110kV (nuts_id, substation_id) + SELECT v_nuts3_area.nuts_id, id + FROM power_substation + WHERE connection_110kV = 'TRUE' AND NOT power = 'plant' + AND ST_Within(center_geom, v_nuts3_area.geom); + + v_numb_subst := (SELECT count(*) FROM nuts3_substation_110kV WHERE nuts_id = v_nuts3_area.nuts_id); + + IF v_numb_subst = 0 + THEN + INSERT INTO nuts3_substation_110kV ( nuts_id, + substation_id, + distance) + SELECT v_nuts3_area.nuts_id, + id, + ST_Distance(ST_Centroid(v_nuts3_area.geom), center_geom) as dist + FROM power_substation + WHERE connection_110kV = 'TRUE' AND NOT power = 'plant' + ORDER BY dist ASC + LIMIT 1; + RAISE NOTICE 'remote added'; + END IF; + + v_total_nuts3_power := (SELECT sum(s_long) + FROM power_substation + WHERE connection_110kV = 'TRUE' AND NOT power = 'plant' + AND id = ANY (SELECT substation_id + FROM nuts3_substation_110kV + WHERE nuts_id = v_nuts3_area.nuts_id)); + + UPDATE nuts3_substation_110kV + SET percentage = (((SELECT s_long + FROM power_substation + WHERE connection_110kV = 'TRUE' AND NOT power = 'plant' + AND id = substation_id) / v_total_nuts3_power) * 100) + WHERE nuts_id = v_nuts3_area.nuts_id; + + RAISE NOTICE 'done'; + END LOOP; +END IF; +END; +$$ LANGUAGE plpgsql; ----------------------------------------------------------------------------- @@ -3336,6 +3604,23 @@ INSERT INTO results.nuts3_subst ( FROM nuts3_substation; DROP TABLE nuts3_substation; +IF (SELECT to_regclass('nuts3_substation_110kV') IS NOT NULL) = TRUE +THEN + INSERT INTO results.nuts3_subst_110kv ( + result_id, + nuts_id, + substation_id, + percentage, + distance) + + SELECT v_new_id, + nuts_id, + substation_id, + percentage, + distance + FROM nuts3_substation_110kv; + DROP TABLE nuts3_substation_110kV; +END IF; INSERT INTO results.plz_subst ( result_id, @@ -3351,6 +3636,24 @@ INSERT INTO results.plz_subst ( distance FROM plz_substation; DROP TABLE plz_substation; + +IF (SELECT to_regclass('plz_substation_110kV') IS NOT NULL) = TRUE +THEN + INSERT INTO results.plz_subst_110kv ( + result_id, + plz, + substation_id, + percentage, + distance) + + SELECT v_new_id, + plz, + substation_id, + percentage, + distance + FROM plz_substation_110kv; + DROP TABLE plz_substation_110kV; +END IF; INSERT INTO results.substations( result_id , @@ -3399,108 +3702,3 @@ DROP TABLE problem_log; END; $$ LANGUAGE plpgsql; - --- OTG_split_table () Teilt eine Tabelle v_table in 10 Einzeltabellen auf. Dabei ist die in v_parameter spezifizierte Spalte das Unterscheidungsmerkmal. Die Ursprüngliche Tabelle wird nach der Aufteilung gelöscht. - -CREATE OR REPLACE FUNCTION otg_split_table (v_table TEXT, v_parameter TEXT) RETURNS void -AS $$ - -DECLARE -number_of_rows INT; -part_end_1 INT; -part_end_2 INT; -part_end_3 INT; -part_end_4 INT; -part_end_5 INT; -part_end_6 INT; -part_end_7 INT; -part_end_8 INT; -part_end_9 INT; - -BEGIN - --- Eine Hilfstabelle, in welcher die Rheinfolge der 10 Einzeltabellen bestimmt wird wird erstellt. -EXECUTE 'CREATE TABLE table_order AS -SELECT DISTINCT ' || v_parameter || ' FROM ' || v_table ||' -ORDER BY ' || v_parameter; -ALTER TABLE table_order ADD COLUMN indx serial NOT NULL PRIMARY KEY; - -number_of_rows := (SELECT COUNT (*) -FROM table_order); - -part_end_1 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_1 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_1 ||') -ORDER BY '|| v_parameter; - -part_end_2 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (2*number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_2 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_1 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_2 ||') -ORDER BY '|| v_parameter; - -part_end_3 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (3*number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_3 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_2 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_3 ||') -ORDER BY '|| v_parameter; - -part_end_4 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (4*number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_4 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_3 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_4 ||') -ORDER BY '|| v_parameter; - -part_end_5 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (5*number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_5 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_4 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_5 ||') -ORDER BY '|| v_parameter; - -part_end_6 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (6*number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_6 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_5 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_6 ||') -ORDER BY '|| v_parameter; - -part_end_7 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (7*number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_7 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_6 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_7 ||') -ORDER BY '|| v_parameter; - -part_end_8 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (8*number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_8 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_7 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_8 ||') -ORDER BY '|| v_parameter; - -part_end_9 := (SELECT indx FROM table_order WHERE (SELECT FLOOR (9*number_of_rows/10)) = indx); -EXECUTE 'CREATE TABLE split_table_9 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_8 ||') AND '|| v_parameter ||' <= (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_9 ||') -ORDER BY '|| v_parameter; - -EXECUTE 'CREATE TABLE split_table_10 AS -SELECT * -FROM '|| v_table ||' -WHERE '|| v_parameter ||' > (SELECT '|| v_parameter ||' FROM table_order WHERE indx = '|| part_end_9 ||') -ORDER BY '|| v_parameter; - -DROP TABLE table_order; --- Löschung der Ursprünglichen Tabelle um Doppelungen zu vermeiden. -EXECUTE 'DROP TABLE '|| v_table; - -END -$$ -LANGUAGE plpgsql; diff --git a/code/osmTGmod.py b/code/osmTGmod.py index f15ec24..9943fd8 100755 --- a/code/osmTGmod.py +++ b/code/osmTGmod.py @@ -408,7 +408,6 @@ def execute_abstraction(self, min_voltage, main_station, graph_dfs, - conn_subgraphs, comment = None): # None is 'translated' to NULL in Postgres (See: Adaptation of Python values to SQL types in Docu!) """ Executes the abstraction. @@ -444,12 +443,12 @@ def execute_abstraction(self, WHERE val_description = 'graph_dfs'""", (graph_dfs,)) self.conn.commit() - print ("Sets conn_subgraphs...") - self.cur.execute(""" - UPDATE abstr_values - SET val_bool = %s - WHERE val_description = 'conn_subgraphs'""", (conn_subgraphs,)) - self.conn.commit() +# print ("Sets conn_subgraphs...") +# self.cur.execute(""" +# UPDATE abstr_values +# SET val_bool = %s +# WHERE val_description = 'conn_subgraphs'""", (conn_subgraphs,)) +# self.conn.commit() @@ -467,7 +466,7 @@ def execute_abstraction(self, def write_to_csv (self, result_id, path): - tables = ['bus_data', 'branch_data', 'dcline_data', 'substations', 'problem_log', 'plz_subst', 'nuts3_subst'] + tables = ['bus_data', 'branch_data', 'dcline_data', 'substations', 'problem_log', 'plz_subst', 'nuts3_subst', 'plz_subst_110kV', 'nuts3_subst_110kV'] for table in tables: print ('writing %s...' % table) @@ -650,7 +649,6 @@ def information (self): min_voltage, main_station, graph_dfs, - conn_subgraphs, user_comment) except: # Get the most recent exception diff --git a/code/power_script.sql b/code/power_script.sql index b607505..147b818 100755 --- a/code/power_script.sql +++ b/code/power_script.sql @@ -125,7 +125,7 @@ CREATE INDEX power_line_way_gix ON power_line USING GIST (way); SELECT * INTO power_substation FROM power_ways_applied_changes - WHERE power = ANY (ARRAY ['substation','sub_station','station']); -- "todo" Hier noch power = plant oder power = generator einfügen und extra kennzeichnen + WHERE power = ANY (ARRAY ['substation','sub_station','station', 'plant']); -- Erstellt einen normalen Index auf ID CREATE INDEX substation_id_idx ON power_substation(id); @@ -163,18 +163,47 @@ UPDATE power_line startpoint = st_startpoint(way), endpoint = st_endpoint(way); --- "todo" Alle relation und relation members löschen, die ausschließlich im Ausland liegen + +-- Determine which power_lines are outside the border and which ones are part of relations crossing the border + +SELECT id INTO power_line_not_ger FROM power_line WHERE + id IN (SELECT member_id FROM relation_members + WHERE member_id NOT IN + (SELECT line.id + FROM power_line line, nuts_poly + WHERE ST_Within(line.startpoint, nuts_poly.geom) AND + nuts_poly.nuts_id = 'DE')) AND + + id IN (SELECT member_id FROM relation_members + WHERE member_id NOT IN + (SELECT line.id + FROM power_line line, nuts_poly + WHERE ST_Within(line.endpoint, nuts_poly.geom) AND + nuts_poly.nuts_id = 'DE') ); + +ALTER TABLE power_line_not_ger ADD COLUMN rel_id INT; +UPDATE power_line_not_ger + SET rel_id = relation_id FROM relation_members WHERE power_line_not_ger.id = relation_members.member_id; + +SELECT DISTINCT relation_id INTO power_relations_crossing_border FROM relation_members WHERE +member_id IN (SELECT id FROM power_line) AND +NOT member_id IN (SELECT id FROM power_line_not_ger) AND +relation_id IN (SELECT rel_id FROM power_line_not_ger) +ORDER BY relation_id; + +DROP TABLE power_line_not_ger; -- Es werden alle Leitungen gelöscht, die Anfang und Ende außerhalb Deutschlands haben. --- Leitungen, die Teil einer Relation sind werden allerdings behalten (disabled for now) +-- power_lines, which are part of a relation crossing the border are not deleted. CREATE TRIGGER problem_log_trigger AFTER DELETE ON power_line FOR EACH ROW EXECUTE PROCEDURE otg_power_line_problem_tg ('Not_in_Ger'); - DELETE FROM power_line WHERE NOT id IN (SELECT line.id + DELETE FROM power_line WHERE + NOT id IN (SELECT line.id FROM power_line line, nuts_poly WHERE ST_Within(line.startpoint, nuts_poly.geom) AND nuts_poly.nuts_id = 'DE') AND @@ -182,11 +211,14 @@ CREATE TRIGGER problem_log_trigger NOT id IN (SELECT line.id FROM power_line line, nuts_poly WHERE ST_Within(line.endpoint, nuts_poly.geom) AND - nuts_poly.nuts_id = 'DE');-- AND + nuts_poly.nuts_id = 'DE') AND --- NOT id IN (SELECT member_id FROM relation_members); + NOT id IN (SELECT member_id + FROM relation_members + WHERE relation_id IN (SELECT relation_id FROM power_relations_crossing_border)); DROP TRIGGER problem_log_trigger ON power_line; + DROP TABLE power_relations_crossing_border; -- BEZIEHUNG POWER_LINE/POWER SUBSTATION @@ -285,7 +317,56 @@ UPDATE power_line WHERE numb_volt_lev - 1 = otg_numb_of_cert_char (cables, ';'); -- Dort, wo die Cables pro Spannungsebene genau identifizierbar sind (Anzahl ';' übereinsimmen) +-- Mark all substations (not plants), which have 110kV connection. Thus they connect lower voltage grids. + +ALTER TABLE power_substation ADD COLUMN connection_110kv BOOLEAN; + +ALTER TABLE power_substation ADD COLUMN numb_volt_lev INT; + +UPDATE power_substation + SET numb_volt_lev = otg_numb_of_cert_char (voltage, ';') + 1; +-- Jede Zeile des ARRAYs (neue Spalte voltage_array) enthält die Spannung der jeweiligen Leitungs-Ebene +-- (Es werden die 4 oberen Leitungsebenen einer Substation betrachtet) +ALTER TABLE power_substation ADD COLUMN voltage_array INT [4]; +CREATE INDEX sub_volt_idx ON power_substation(voltage_array); +UPDATE power_substation + SET + voltage_array [1] = otg_get_int_from_semic_string (voltage, 1), + voltage_array [2] = otg_get_int_from_semic_string (voltage, 2), + voltage_array [3] = otg_get_int_from_semic_string (voltage, 3), + voltage_array [4] = otg_get_int_from_semic_string (voltage, 4); + + +-- ASSUMPTION +-- It is assumed that all 60kV voltages can be considered 110kV +UPDATE power_substation + SET + voltage_array [1] = 110000 WHERE voltage_array[1] = 60000; +UPDATE power_substation + SET + voltage_array [2] = 110000 WHERE voltage_array[2] = 60000; +UPDATE power_substation + SET + voltage_array [3] = 110000 WHERE voltage_array[3] = 60000; +UPDATE power_substation + SET + voltage_array [4] = 110000 WHERE voltage_array[4] = 60000; +-- Pass information from voltage tag of substation into connection_110kv +UPDATE power_substation + SET connection_110kv = TRUE WHERE voltage_array[1] = 110000 OR voltage_array[2] = 110000 OR voltage_array[3] = 110000 OR voltage_array[4] = 110000; + +ALTER TABLE power_substation DROP COLUMN voltage_array; +ALTER TABLE power_substation DROP COLUMN numb_volt_lev; + +-- Consider all substations which have power lines with 110kV and end or start in a substation also connected to 110kV +UPDATE power_substation + SET connection_110kv = TRUE WHERE id IN (SELECT point_substation_id [1] FROM power_line WHERE voltage_array[1] = 110000 OR voltage_array[2] = 110000 OR voltage_array[3] = 110000 OR voltage_array[4] = 110000); +UPDATE power_substation + SET connection_110kv = TRUE WHERE id IN (SELECT point_substation_id [2] FROM power_line WHERE voltage_array[1] = 110000 OR voltage_array[2] = 110000 OR voltage_array[3] = 110000 OR voltage_array[4] = 110000); + + + -- UNTERSUCHUNG WIRES @@ -659,9 +740,9 @@ SELECT otg_set_count ('power_circ_members', 'rel'); FOR EACH ROW EXECUTE PROCEDURE otg_power_circuits_problem_tg ('branch_off_(cables_>_3)'); -- Die in das Log eingetragenen Werte für z.B. cables sind die aus der Datenbanke erhaltenen Werte (und nicht die über Annahmen veränderten) - -- auch bei cables = 3 führt branch off oft zu fehlern!!!! + -- bei cables = 3 führt branch off (fast) nicht mehr zu Fehlern! DELETE FROM power_circuits - WHERE --cables > 3 AND + WHERE cables > 3 AND id IN (SELECT relation_id FROM power_circ_members WHERE f_bus IN (SELECT id FROM bus_data WHERE cnt > 2 AND origin = 'rel') OR t_bus IN (SELECT id FROM bus_data WHERE cnt > 2 AND origin = 'rel') @@ -677,8 +758,10 @@ ALTER TABLE bus_data ADD COLUMN cntr_id character varying (2); --(setzt Länderkennung, substation_id und Offene Enden im Ausland bekommen Substation_id = 0) SELECT otg_bus_analysis ('rel'); - --- Heuristik: Funktion otg_connect_dead_ends_with_substation () versucht offene Stromkreisendenin der Nähe von Umspannwerken über Puffer zu schließen +-- Deletes all lines, which are to small to be taken into account for by pgr_create_topology. They are close to substations and the relation will be taken care of within the function otg_connect_dead_ends_with_substation +DELETE FROM power_circ_members WHERE f_bus = t_bus; + +-- Heuristik: Funktion otg_connect_dead_ends_with_substation () versucht offene Stromkreisendenin der Nähe von Umspannwerken über Puffer zu schließen, auch im Ausland SELECT otg_connect_dead_ends_with_substation (); -- Löscht alle circuit_members, die (nun aufgrund des Puffers) Anfang und Ende innerhalb derselben Substation haben @@ -714,12 +797,13 @@ DELETE FROM power_circ_members WHERE f_bus = t_bus; substation_id IS NULL))); DROP TRIGGER problem_log_trigger ON power_circuits; +-- Important: delete circuit_members whos circuits have already been deleted +DELETE FROM power_circ_members WHERE relation_id NOT IN (SELECT id FROM power_circuits); -- Anschließend werden alle Knoten gelöscht, an die aufgrund der Sromkreis-Löschung keine Leitungen mehr angeschlossen sind SELECT otg_set_count ('power_circ_members', 'rel'); DELETE FROM bus_data WHERE origin = 'rel' AND cnt = 0; - -- SUBTRAKTION DER STROMKREISE (power_circ_members) VON DEN LEITUNGEN (POWER_LINES) -- Die in den power_circ_members enthaltenen Informationen werden genutzt und quasi über die Leitungen "gelegt" -- ... bzw. von diesen subtrahiert @@ -1149,8 +1233,10 @@ UPDATE power_substation SET s_long = (SELECT sum(s_long_sum) --sum instead of ma SELECT AddGeometryColumn('power_substation', 'center_geom', 4326, 'Point', 2); UPDATE power_substation SET center_geom = ST_Centroid(poly); --- Executes functions to create assignment-tables for plz and nut3 to substations +-- Executes functions to create assignment-tables for plz and nuts3 to substations +SELECT otg_plz_substation_110kV (); SELECT otg_plz_substation (); +SELECT otg_nuts3_substation_110kV (); SELECT otg_nuts3_substation (); @@ -1173,6 +1259,7 @@ UPDATE bus_data SET va = 0; ALTER TABLE bus_data ADD COLUMN pd REAL; ALTER TABLE bus_data ADD COLUMN qd REAL; + -- Zu Beachten: -- Slack Bus benötigt Generator -- pd und qd der Buses von außerhalb vorgeben.