├── util ├── __init__.py ├── check-topology.sql ├── invalid-polygons.sql ├── which.py ├── load_polyfile.py ├── hstore.py ├── polyfile.py ├── geojson-to-postgis.py ├── postgres.py ├── geometry.py └── network.py ├── doc ├── .gitignore └── log.org ├── entsoe ├── .gitignore ├── import.sh ├── entsoe.conf ├── download.sh ├── export.sh ├── detile.sql ├── run.sh ├── fixup-hvdc.sql ├── fixup-merge.sql ├── gridkit-start.sql ├── README.md ├── electric-properties.sql └── abstraction.sql ├── TODO ├── src ├── defaults.conf ├── node-1-find-shared.sql ├── abstraction-2-network.sql ├── prepare-functions.sql ├── abstraction-1-high-voltage-network.sql ├── spatial-1-merge-stations.sql ├── node-2-merge-lines.sql ├── spatial-4-terminal-intersections.sql ├── spatial-2-eliminate-line-overlap.sql ├── spatial-5-terminal-joints.sql ├── topology-2-dangling-joints.sql ├── topology-3-redundant-splits.sql ├── abstraction-2-export.sql ├── node-3-line-joints.sql ├── electric-4-station.sql ├── spatial-6-merge-lines.sql ├── topology-1-connections.sql ├── electric-1-tags.sql ├── electric-5-flood.sql ├── electric-2-patch.sql ├── topology-4-redundant-joints.sql ├── spatial-3-attachment-joints.sql ├── prepare-tables.sql └── electric-3-line.sql ├── .gitignore ├── analysis ├── export-line-structure.sql └── line-length-plot.R ├── requirements.txt ├── reset.sh ├── import-dataset.sh ├── LICENSE ├── run.sh ├── power.style ├── README.md └── gridkit.py /util/__init__.py: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- /doc/.gitignore: -------------------------------------------------------------------------------- 1 | *.html -------------------------------------------------------------------------------- /entsoe/.gitignore: -------------------------------------------------------------------------------- 1 | /node_modules 2 | *.geojson 3 | -------------------------------------------------------------------------------- /entsoe/import.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | python ../util/geojson-to-postgis.py *.geojson 4 | -------------------------------------------------------------------------------- /TODO: -------------------------------------------------------------------------------- 1 | * Factor out functions 2 | * Investigate medium-voltage query failure 3 | * Use integer-sequence-ids -------------------------------------------------------------------------------- /entsoe/entsoe.conf: -------------------------------------------------------------------------------- 1 | GRIDKIT_TERMINAL_RADIUS=750 2 | GRIDKIT_STATION_BUFFER=50 3 | GRIDKIT_MERGE_DISTORTION=2500 4 | GRIDKIT_HVDC_DISTANCE=20000 5 | -------------------------------------------------------------------------------- /src/defaults.conf: -------------------------------------------------------------------------------- 1 | GRIDKIT_TERMINAL_RADIUS=50 2 | GRIDKIT_STATION_BUFFER=100 3 | GRIDKIT_HIGH_VOLTAGE=220000 4 | GRIDKIT_MERGE_DISTORTION=300 5 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *~ 2 | *# 3 | .#* 4 | *.png 5 | *.dot 6 | *.pdf 7 | *.pyc 8 | __pycache__/ 9 | *.csv 10 | *.zip 11 | *.osm 12 | *.o5m 13 | *.osm.pbf 14 | .R* -------------------------------------------------------------------------------- /analysis/export-line-structure.sql: -------------------------------------------------------------------------------- 1 | COPY ( 2 | SELECT l.*, st_length(st_transform(e.line_extent, 4326)::geography) as line_length, e.station_id 3 | FROM line_structure l JOIN topology_edges e ON l.line_id = e.line_id 4 | ) TO STDOUT WITH CSV HEADER 5 | -------------------------------------------------------------------------------- /requirements.txt: -------------------------------------------------------------------------------- 1 | PYPOWER==git+https://github.com/rwl/pypower.git 2 | argparse==1.2.1 3 | cycler==0.9.0 4 | matplotlib==1.5.0 5 | numpy==1.10.2 6 | pyparsing==2.0.6 7 | python-dateutil==2.4.2 8 | pytz==2015.7 9 | recordclass==0.4 10 | scipy==0.16.1 11 | six==1.10.0 12 | wsgiref==0.1.2 13 | -------------------------------------------------------------------------------- /entsoe/download.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | npm install vt-geojson 4 | export MapboxAccessToken=pk.eyJ1IjoicnVzdHkiLCJhIjoib0FjUkJybyJ9.V9QoXck_1Z18MhpwyIE2Og 5 | ./node_modules/vt-geojson/cli.js rusty.cm0b8gzp -z 3 > rusty.cm0b8gzp-z3.geojson 6 | ./node_modules/vt-geojson/cli.js rusty.02rit83j -z 3 > rusty.02rit83j-z3.geojson 7 | -------------------------------------------------------------------------------- /reset.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | source src/defaults.conf 4 | if [ -f ./gridkit.conf ] 5 | then 6 | source ./gridkit.conf 7 | fi 8 | 9 | psql -f ./src/prepare-functions.sql 10 | psql -v terminal_radius=$GRIDKIT_TERMINAL_RADIUS \ 11 | -v station_buffer=$GRIDKIT_STATION_BUFFER \ 12 | -f ./src/prepare-tables.sql 13 | -------------------------------------------------------------------------------- /util/check-topology.sql: -------------------------------------------------------------------------------- 1 | select count(*) from ( 2 | select distinct unnest(line_id) from topology_nodes 3 | ) f (line_id) where line_id not in (select line_id from topology_edges); 4 | select count(*) from ( 5 | select distinct unnest(station_id) from topology_edges 6 | ) f (station_id) where station_id not in (select station_id from topology_nodes); -------------------------------------------------------------------------------- /entsoe/export.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | psql -c "COPY network_bus TO STDOUT WITH CSV HEADER QUOTE ''''" > buses.csv 3 | psql -c "COPY network_link TO STDOUT WITH CSV HEADER QUOTE ''''" > links.csv 4 | psql -c "COPY network_generator TO STDOUT WITH CSV HEADER QUOTE ''''" > generators.csv 5 | psql -c "COPY network_transformer TO STDOUT WITH CSV HEADER QUOTE ''''" > transformers.csv 6 | 7 | zip entsoe.zip README.md buses.csv links.csv generators.csv transformers.csv 8 | -------------------------------------------------------------------------------- /entsoe/detile.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists tile_split_lines; 3 | create table tile_split_lines ( 4 | short_id integer, 5 | long_id integer, 6 | short_line geometry(linestring,4326), 7 | long_line geometry(linestring,4326) 8 | ); 9 | 10 | insert into tile_split_lines (short_id, long_id, short_line, long_line) 11 | select a.import_id, b.import_id, a.line, b.line 12 | from feature_lines a, feature_lines b 13 | where a.properties->'objectid' != '0' 14 | and a.properties->'objectid' = b.properties->'objectid' 15 | and st_length(a.line) < st_length(b.line); 16 | commit; 17 | -------------------------------------------------------------------------------- /analysis/line-length-plot.R: -------------------------------------------------------------------------------- 1 | line.structure <- read.csv("line-structure.csv") 2 | attach(line.structure) 3 | line.length.log <- log(line_length) 4 | hist(line.length.log, freq=F, breaks=50, main="Normal distribution of logarithmic line lengths", 5 | xlab="ln(length)", ylab="Density") 6 | line.length.range <- range(line.length.log) 7 | line.length.x <- seq(line.length.range[1], line.length.range[2], length.out=100) 8 | lll.mu = mean(line.length.log) 9 | lll.sigma = sd(line.length.log) 10 | lines(line.length.x, dnorm(line.length.x, mean=lll.mu, sd=lll.sigma), lty=2) 11 | legend("topleft", legend=c("Observed distribution",paste("µ = ", format(lll.mu, digits=3), "/ σ = ", format(lll.sigma, digits=3))), 12 | fill=c("white",NA), border=c("black", NA), lty=c(NA,2)) 13 | dev.copy(png, "logarithm-of-all-line-length.png") 14 | dev.off() 15 | detach(line.structure) 16 | -------------------------------------------------------------------------------- /src/node-1-find-shared.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists shared_nodes; 3 | create table shared_nodes ( 4 | node_id bigint, 5 | way_id bigint array, 6 | power_type char(1) array, 7 | path_idx float array, 8 | primary key (node_id) 9 | ); 10 | 11 | insert into shared_nodes (node_id, way_id, power_type, path_idx) 12 | select node_id, array_agg(way_id order by way_id), 13 | array_agg(power_type order by way_id), 14 | array_agg(path_idx order by way_id) from ( 15 | select id, unnest(nodes), power_type, 16 | (generate_subscripts(nodes, 1)::float - 1.0)/(array_length(nodes, 1)-1) 17 | from planet_osm_ways 18 | join power_type_names on power_name = hstore(tags)->'power' 19 | where array_length(nodes, 1) > 1 20 | ) f(way_id, node_id, power_type, path_idx) 21 | group by node_id having count(*) > 1; 22 | 23 | commit; 24 | -------------------------------------------------------------------------------- /import-dataset.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | 4 | if [ -z "$1" ] || [ ! -f "$1" ] 5 | then 6 | echo Please pass OSM datafile as argument 7 | exit 1 8 | fi 9 | OSM_DATAFILE=$1 10 | 11 | if [ -z "$PGDATABASE" ] 12 | then 13 | if [ -z "$2" ] 14 | then 15 | echo Please pass database name as second argument 16 | exit 1 17 | else 18 | export PGDATABASE=$2 19 | fi 20 | fi 21 | 22 | if [ -n "$PGPORT" ] 23 | then 24 | # osm2pgsql needs an explicit --port parameter 25 | OSM2PGSQL_FLAGS=--port=$PGPORT 26 | fi 27 | 28 | dropdb --if-exists $PGDATABASE || exit 1 29 | createdb $PGDATABASE || exit 1 30 | psql -c 'CREATE EXTENSION postgis;' || exit 1 31 | psql -c 'CREATE EXTENSION hstore;' || exit 1 32 | osm2pgsql -d $PGDATABASE -c -k -s \ 33 | -S ./power.style \ 34 | --number-processes 1 \ 35 | $OSM2PGSQL_FLAGS \ 36 | $OSM_DATAFILE || exit 1 37 | 38 | source ./reset.sh 39 | -------------------------------------------------------------------------------- /util/invalid-polygons.sql: -------------------------------------------------------------------------------- 1 | drop table if exists invalid_polygons; 2 | create table invalid_polygons as 3 | select station_id, osm_id, polygon 4 | from ( 5 | select o.power_id, o.osm_id, 6 | case when st_isclosed(wg.line) and st_numpoints(wg.line) > 3 then st_makepolygon(wg.line) 7 | when st_numpoints(wg.line) >= 3 8 | -- looks like an unclosed polygon based on endpoints distance 9 | and st_distance(st_startpoint(wg.line), st_endpoint(wg.line)) < (st_length(wg.line) / 2) 10 | then st_makepolygon(st_addpoint(wg.line, st_startpoint(wg.line))) 11 | else null end 12 | from source_objects o 13 | join way_geometry wg on o.osm_id = wg.way_id 14 | where o.power_type = 's' and o.osm_type = 'w' 15 | ) _g(station_id, osm_id, polygon) 16 | -- even so not all polygons will be valid 17 | where polygon is not null and not st_isvalid(polygon); 18 | -------------------------------------------------------------------------------- /entsoe/run.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | source entsoe.conf 4 | 5 | psql -f ../src/prepare-functions.sql 6 | psql -v terminal_radius=$GRIDKIT_TERMINAL_RADIUS \ 7 | -v station_buffer=$GRIDKIT_STATION_BUFFER \ 8 | -f gridkit-start.sql 9 | psql -f ../src/spatial-1-merge-stations.sql 10 | psql -f ../src/spatial-2-eliminate-line-overlap.sql 11 | psql -f ../src/spatial-3-attachment-joints.sql 12 | psql -f ../src/spatial-4-terminal-intersections.sql 13 | psql -f ../src/spatial-5-terminal-joints.sql 14 | psql -f ../src/spatial-6-merge-lines.sql 15 | psql -f ../src/topology-1-connections.sql 16 | psql -f ../src/topology-2-dangling-joints.sql 17 | 18 | psql -v merge_distortion=$GRIDKIT_MERGE_DISTORTION \ 19 | -f ../src/topology-3-redundant-splits.sql 20 | psql -f ../src/topology-4-redundant-joints.sql 21 | 22 | psql -f electric-properties.sql 23 | # Fix edges which should not have been merged 24 | psql -f fixup-merge.sql 25 | 26 | psql -f abstraction.sql 27 | # Add transformers between DC terminals and stations 28 | psql -v hvdc_distance=$GRIDKIT_HVDC_DISTANCE \ 29 | -f fixup-hvdc.sql 30 | 31 | bash ./export.sh 32 | echo "All done" 33 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2016 Bart Wiegmans 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /util/which.py: -------------------------------------------------------------------------------- 1 | import os 2 | 3 | def which(program): 4 | '''Find executable for a given name by PATH, or None if no executable could be found''' 5 | if os.name == 'nt': 6 | return _nt_which(program) 7 | elif os.name == 'posix': 8 | return _posix_which(program) 9 | raise NotImplementedError(os.platform) 10 | 11 | def _nt_which(program): 12 | PATH = os.environ['PATH'].split(os.pathsep) 13 | EXT = os.environ['PATHEXT'].split(os.pathsep) 14 | name, ext = os.path.splitext(program) 15 | if ext in EXT: 16 | # program is specified as foo.exe, for example, in which case 17 | # we don't go looking for foo.exe.exe or foo.exe.bat 18 | for p in PATH: 19 | n = os.path.join(p, program) 20 | if os.path.isfile(n): 21 | return n 22 | else: 23 | for p in PATH: 24 | for e in EXT: 25 | n = os.path.join(p, program + e) 26 | if os.path.isfile(n): 27 | return n 28 | return None 29 | 30 | def _posix_which(program): 31 | PATH = os.environ['PATH'].split(os.pathsep) 32 | for p in PATH: 33 | n = os.path.join(p, program) 34 | if os.path.isfile(n) and os.access(n, os.X_OK): 35 | return n 36 | return None 37 | -------------------------------------------------------------------------------- /util/load_polyfile.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env python 2 | from __future__ import print_function, unicode_literals, division 3 | import argparse 4 | import sys 5 | import os 6 | import io 7 | from polyfile import PolyfileParser 8 | from geometry import Polygon 9 | 10 | ap = argparse.ArgumentParser() 11 | ap.add_argument('file', nargs='+', type=str) 12 | ap.add_argument('--table', type=str, default='polygons') 13 | args = ap.parse_args() 14 | 15 | polygons = dict() 16 | parser = PolyfileParser() 17 | for file_name in args.file: 18 | if not os.path.isfile(file_name): 19 | print("Usage: {0} ".format(sys.argv[0])) 20 | name, ext = os.path.splitext(os.path.basename(file_name)) 21 | try: 22 | pr = parser.parse(io.open(file_name, 'r').read()) 23 | pl = Polygon(pr[1]['1']) 24 | polygons[name] = pl.to_wkt() 25 | except Exception as e: 26 | print("Could not process {0} because {1}".format(file_name, e), file=sys.stderr) 27 | quit(1) 28 | 29 | values = ','.join("('{0}', ST_SetSRID(ST_GeomFromText('{1}'), 4326))".format(n, p) 30 | for (n, p) in polygons.items()) 31 | 32 | print(''' 33 | BEGIN; 34 | DROP TABLE IF EXISTS {0}; 35 | CREATE TABLE {0} ( 36 | name varchar(64) primary key, 37 | polygon geometry(polygon, 4326) 38 | ); 39 | INSERT INTO {0} (name, polygon) VALUES {1}; 40 | COMMIT; 41 | '''.format(args.table, values)) 42 | # of course you can abuse this. don't do that, then 43 | -------------------------------------------------------------------------------- /src/abstraction-2-network.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists network_links; 3 | drop table if exists network_buses; 4 | drop table if exists network_generators; 5 | drop table if exists network_transformers; 6 | drop sequence if exists link_id; 7 | drop sequence if exists bus_id; 8 | create sequence link_id; 9 | create sequence bus_id; 10 | 11 | 12 | 13 | create table network_bus ( 14 | bus_id integer primary key, 15 | station_id integer not null, 16 | voltage integer, 17 | frequency numeric, 18 | station_name text, 19 | station_operator text, 20 | substation text, 21 | geometry text 22 | ); 23 | 24 | create table network_link ( 25 | link_id integer primary key, 26 | line_id integer not null, 27 | part_nr integer not null, 28 | voltage integer, 29 | frequency numeric, 30 | cables integer, 31 | wires integer, 32 | geometry text 33 | ); 34 | 35 | -- a trasnforer is a link, but not like the others 36 | create table network_transformer ( 37 | transformer_id integer primary key, 38 | station_id integer, 39 | src_bus_id integer references network_bus (bus_id), 40 | dst_bus_id integer references network_bus (bus_id), 41 | src_voltage integer, 42 | dst_voltage integer, 43 | src_frequency numeric, 44 | dst_frequency numeric, 45 | geometry text 46 | ); 47 | 48 | create table network_generator ( 49 | generator_id integer primary key, 50 | tags hstore, 51 | geometry text 52 | ) 53 | 54 | commit; 55 | -------------------------------------------------------------------------------- /run.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | source src/defaults.conf 4 | if [ -f ./gridkit.conf ] 5 | then 6 | source ./gridkit.conf 7 | fi 8 | 9 | # run postgresql with 'safe mode' 10 | shopt -s expand_aliases 11 | alias psql='psql -v ON_ERROR_STOP=1' 12 | # shared node algorithms before any others 13 | psql -f src/node-1-find-shared.sql || exit 1 14 | psql -v terminal_radius=$GRIDKIT_TERMINAL_RADIUS \ 15 | -f src/node-2-merge-lines.sql || exit 1 16 | psql -f src/node-3-line-joints.sql || exit 1 17 | 18 | # spatial algorithms benefit from reduction of work from shared node 19 | # algorithms 20 | psql -f src/spatial-1-merge-stations.sql || exit 1 21 | psql -f src/spatial-2-eliminate-line-overlap.sql || exit 1 22 | psql -f src/spatial-3-attachment-joints.sql || exit 1 23 | psql -f src/spatial-4-terminal-intersections.sql || exit 1 24 | psql -f src/spatial-5-terminal-joints.sql || exit 1 25 | psql -f src/spatial-6-merge-lines.sql || exit 1 26 | 27 | # topological algorithms 28 | psql -f src/topology-1-connections.sql || exit 1 29 | psql -f src/topology-2-dangling-joints.sql || exit 1 30 | psql -v merge_distortion=$GRIDKIT_MERGE_DISTORTION \ 31 | -f src/topology-3-redundant-splits.sql || exit 1 32 | psql -f src/topology-4-redundant-joints.sql || exit 1 33 | 34 | # process electrical tags 35 | psql -f src/electric-1-tags.sql || exit 1 36 | psql -f src/electric-2-patch.sql || exit 1 37 | psql -f src/electric-3-line.sql || exit 1 38 | psql -f src/electric-4-station.sql || exit 1 39 | # abstract network 40 | psql -f src/abstraction-1-high-voltage-network.sql || exit 1 41 | psql -f src/abstraction-2-export.sql || exit 1 42 | -------------------------------------------------------------------------------- /util/hstore.py: -------------------------------------------------------------------------------- 1 | import re 2 | 3 | class hstore(dict): 4 | class parser(object): 5 | word = re.compile(r'"([^"]+)"') 6 | arrow = re.compile(r'\s*=>\s*') 7 | comma = re.compile(r',\s*') 8 | 9 | def __init__(self, text): 10 | self.position = 0 11 | self.text = text 12 | 13 | def __iter__(self): 14 | while self.peek(self.word): 15 | key = self.read(self.word, 1) 16 | self.read(self.arrow) 17 | value = self.read(self.word, 1) 18 | yield key, value 19 | if self.peek(self.comma): 20 | self.read(self.comma) 21 | else: 22 | break 23 | 24 | def read(self, expect, group=0): 25 | match = expect.match(self.text, self.position) 26 | if match is None: 27 | raise Exception('parse error at ' + position) 28 | self.position = match.end() 29 | return match.group(group) 30 | 31 | def peek(self, expect): 32 | return expect.match(self.text, self.position) is not None 33 | 34 | def __init__(self, text): 35 | super(hstore,self).__init__(self.parser(text)) 36 | 37 | def __str__(self): 38 | return ', '.join('"{0}"=>"{1}"'.format(k,v) for k,v in self.items()) 39 | 40 | def _main(): 41 | hstore_str = '"foo" => "bar"' 42 | hstore_dct = hstore(hstore_str) 43 | assert hstore_dct['foo'] == 'bar' 44 | assert str(hstore_dct) == '"foo"=>"bar"' 45 | assert repr(hstore_dct) == "{'foo': 'bar'}" 46 | 47 | if __name__ == '__main__': 48 | _main() 49 | -------------------------------------------------------------------------------- /util/polyfile.py: -------------------------------------------------------------------------------- 1 | import re 2 | 3 | # syntax of poly files; 4 | # name 5 | # number 6 | # indented list of longitude, latitude 7 | # end 8 | # possibly another number 9 | # another end 10 | 11 | class PolyfileParser(object): 12 | newline = re.compile(r'\s*\n') 13 | whitespace = re.compile(r'\s+') 14 | end = re.compile(r'END') 15 | word = re.compile(r'\w+') 16 | number = re.compile(r'-?\d\.\d+E[+-]\d+') 17 | identifier = re.compile(r'!?\d+') 18 | 19 | class Error(Exception): 20 | pass 21 | 22 | def parse(self, buf): 23 | self.buf = buf 24 | self.position = 0 25 | name = self.read(self.word) 26 | sections = {} 27 | self.read(self.newline) 28 | while not self.peek(self.end): 29 | # read section 30 | identifier = self.read(self.identifier) 31 | sequence = [] 32 | self.read(self.newline) 33 | while not self.peek(self.end): 34 | # read sequence 35 | self.read(self.whitespace) 36 | longitude = float(self.read(self.number)) 37 | self.read(self.whitespace) 38 | latitude = float(self.read(self.number)) 39 | coordinates = (longitude, latitude) 40 | sequence.append(coordinates) 41 | self.read(self.newline) 42 | self.read(self.end) 43 | self.read(self.newline) 44 | sections[identifier] = sequence 45 | self.read(self.end) 46 | if self.peek(self.newline): 47 | self.read(self.newline) 48 | return name, sections 49 | 50 | def peek(self, expect): 51 | return expect.match(self.buf, self.position) is not None 52 | 53 | def read(self, expect): 54 | match = expect.match(self.buf, self.position) 55 | if match is None: 56 | raise self.Error("%s was not matched (got %s...)" % (expect.pattern, self.buf[self.position:self.position+10])) 57 | self.position = match.end() 58 | return match.group() 59 | -------------------------------------------------------------------------------- /src/prepare-functions.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | /* functions */ 3 | drop function if exists array_remove(anyarray, anyarray); 4 | drop function if exists array_replace(anyarray, anyarray, anyarray); 5 | drop function if exists array_sym_diff(anyarray, anyarray); 6 | drop function if exists array_merge(anyarray, anyarray); 7 | 8 | drop function if exists connect_lines(a geometry(linestring), b geometry(linestring)); 9 | drop function if exists minimal_radius(geometry, geometry, int array); 10 | 11 | 12 | create function array_remove(a anyarray, b anyarray) returns anyarray as $$ 13 | begin 14 | return array((select unnest(a) except select unnest(b))); 15 | end; 16 | $$ language plpgsql; 17 | 18 | create function array_replace(a anyarray, b anyarray, n anyarray) returns anyarray as $$ 19 | begin 20 | return array((select unnest(a) except select unnest(b) union select unnest(n))); 21 | end; 22 | $$ language plpgsql; 23 | 24 | create function array_sym_diff(a anyarray, b anyarray) returns anyarray as $$ 25 | begin 26 | return array(((select unnest(a) union select unnest(b)) 27 | except 28 | (select unnest(a) intersect select unnest(b)))); 29 | end; 30 | $$ language plpgsql; 31 | 32 | create function array_merge(a anyarray, b anyarray) returns anyarray as $$ 33 | begin 34 | return array(select unnest(a) union select unnest(b)); 35 | end; 36 | $$ language plpgsql; 37 | 38 | 39 | create function connect_lines (a geometry(linestring), b geometry(linestring)) returns geometry(linestring) as $$ 40 | begin 41 | -- select the shortest line that comes from joining the lines 42 | -- in all possible directions 43 | return (select e from ( 44 | select unnest( 45 | array[st_makeline(a, b), 46 | st_makeline(a, st_reverse(b)), 47 | st_makeline(st_reverse(a), b), 48 | st_makeline(st_reverse(a), st_reverse(b))]) e) f 49 | order by st_length(e) limit 1); 50 | end; 51 | $$ language plpgsql; 52 | 53 | create function minimal_radius(line geometry, area geometry, radius int array) returns int array as $$ 54 | begin 55 | return array[case when st_dwithin(st_startpoint(line), area, 1) then 1 else radius[1] end, 56 | case when st_dwithin(st_endpoint(line), area, 1) then 1 else radius[2] end]; 57 | end; 58 | $$ language plpgsql; 59 | 60 | commit; 61 | -------------------------------------------------------------------------------- /src/abstraction-1-high-voltage-network.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists high_voltage_lines; 3 | drop table if exists high_voltage_stations; 4 | create table high_voltage_lines ( 5 | line_id integer primary key, 6 | line_extent geometry(linestring,3857) -- for visualization 7 | ); 8 | create table high_voltage_stations ( 9 | station_id integer primary key, 10 | station_location geometry(point, 3857) 11 | ); 12 | 13 | -- because we've added the line voltage to the station structure in 14 | -- the previous step, we don't need to check lines to find nodes anymore 15 | insert into high_voltage_stations (station_id, station_location) 16 | select n.station_id, n.station_location 17 | from topology_nodes n 18 | join station_structure s on n.station_id = s.station_id 19 | where 220000 <= any(s.voltage) 20 | and (not 16.7 = all(s.frequency) or array_length(s.frequency,1) is null); 21 | 22 | 23 | -- we do need to repeat the station check, otherwise it isn't 24 | -- sensitive enough (NULLs are ok, exclusion values are not) 25 | insert into high_voltage_lines (line_id, line_extent) 26 | select e.line_id, line_extent 27 | from topology_edges e 28 | join line_structure l on l.line_id = e.line_id 29 | where l.voltage >= 220000 and (l.frequency != 16.7 or l.frequency is null) 30 | 31 | union 32 | 33 | select e.line_id, line_extent 34 | from topology_edges e 35 | join station_structure a on a.station_id = e.station_id[1] 36 | join station_structure b on b.station_id = e.station_id[2] 37 | where (not 220000 >= all(a.voltage) or array_length(a.voltage, 1) is null) 38 | and (not 220000 >= all(b.voltage) or array_length(b.voltage, 1) is null) 39 | and (not 16.7 = all(a.frequency) or array_length(a.frequency, 1) is null) 40 | and (not 16.7 = all(b.frequency) or array_length(b.frequency, 1) is null) 41 | and ( 220000 <= any(a.voltage) or 220000 <= any(b.voltage) ); 42 | 43 | -- but we can have added lines to stations not in the high-voltage 44 | -- set, and that is not good 45 | insert into high_voltage_stations (station_id, station_location) 46 | select station_id, station_location 47 | from topology_nodes n 48 | where exists ( 49 | select 1 from high_voltage_lines h 50 | where h.line_id = any(n.line_id) 51 | ) 52 | and not exists ( 53 | select 1 from high_voltage_stations h 54 | where h.station_id = n.station_id 55 | ); 56 | commit; 57 | -------------------------------------------------------------------------------- /entsoe/fixup-hvdc.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists isolated_hvdc_terminal; 3 | create table isolated_hvdc_terminal ( 4 | terminal_id integer primary key, 5 | terminal_location geometry(point,3857), 6 | station_id integer not null, 7 | connection_line geometry(linestring,3857) 8 | ); 9 | 10 | insert into isolated_hvdc_terminal (terminal_id, terminal_location, 11 | station_id, connection_line) 12 | select t.station_id, t.station_location, f.station_id, 13 | st_makeline(f.station_location, t.station_location) 14 | from topology_nodes t 15 | join lateral ( 16 | select s.station_id, n.station_location from power_station s 17 | join topology_nodes n on n.station_id = s.station_id 18 | where t.station_id != n.station_id 19 | -- not to another HVDC station, or to a joint 20 | and n.topology_name not in ( 21 | 'joint', 22 | 'Wind farm', 23 | 'Converter Station', 24 | 'Converter Station Back-to-back', 25 | 'Converter Station, under construction' 26 | ) 27 | -- indexed k-nearest neighbor 28 | order by t.station_location <-> s.area limit 1 29 | -- TODO, this distorts lengths due to projection; maybe 30 | -- better results with geography measurements 31 | ) f on st_distance(t.station_location, f.station_location) < :hvdc_distance 32 | where t.topology_name in ( 33 | 'Converter Station', 34 | 'Converter Station Back-to-back', 35 | 'Converter Station, under construction' 36 | ) 37 | -- all lines are hvdc lines 38 | and not exists ( 39 | select 1 from line_structure l 40 | where l.line_id = any(t.line_id) and not l.dc_line 41 | ); 42 | 43 | insert into network_transformer (transformer_id, symbol, src_bus_id, dst_bus_id, 44 | src_voltage, dst_voltage, src_dc, dst_dc, geometry) 45 | select nextval('line_id'), 'ac/dc', c.bus_id, s.bus_id, 46 | c.voltage, s.voltage, c.dc, s.dc, 47 | st_astext(st_transform(i.connection_line, 4326)) 48 | from isolated_hvdc_terminal i 49 | join network_bus c on c.station_id = i.terminal_id 50 | join network_bus s on s.station_id = i.station_id; 51 | -- TODO, maybe join lateral to find only the highest voltage / best matching bus 52 | 53 | commit; 54 | -------------------------------------------------------------------------------- /src/spatial-1-merge-stations.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists overlapping_stations; 3 | drop table if exists station_set; 4 | drop table if exists merged_stations; 5 | 6 | create table overlapping_stations ( 7 | a_id integer not null, 8 | b_id integer not null, 9 | primary key (a_id, b_id) 10 | ); 11 | 12 | create table station_set ( 13 | station_id integer primary key, 14 | set_key integer not null 15 | ); 16 | 17 | create index station_set_key on station_set (set_key); 18 | 19 | create table merged_stations ( 20 | new_id integer primary key, 21 | old_id integer array, 22 | area geometry(polygon, 3857) 23 | ); 24 | 25 | 26 | insert into overlapping_stations (a_id, b_id) 27 | select a.station_id, b.station_id 28 | from power_station a, power_station b 29 | where a.station_id < b.station_id 30 | and st_dwithin(a.area, b.area, 0); 31 | 32 | insert into station_set (station_id, set_key) 33 | select station_id, station_id from ( 34 | select a_id from overlapping_stations union select b_id from overlapping_stations 35 | ) f (station_id); 36 | 37 | do $$ 38 | declare 39 | pair overlapping_stations; 40 | src_key integer; 41 | dst_key integer; 42 | begin 43 | for pair in select * from overlapping_stations loop 44 | src_key = set_key from station_set where station_id = pair.a_id; 45 | dst_key = set_key from station_set where station_id = pair.b_id; 46 | if src_key != dst_key then 47 | update station_set set set_key = src_key where set_key = dst_key; 48 | end if; 49 | end loop; 50 | end; 51 | $$ language plpgsql; 52 | 53 | insert into merged_stations (new_id, old_id, area) 54 | select nextval('station_id'), old_id, area from ( 55 | select array_agg(z.station_id), st_union(s.area) 56 | from station_set z 57 | join power_station s on s.station_id = z.station_id 58 | group by set_key 59 | ) f(old_id, area); 60 | 61 | -- TODO ; somehow during the union of ares, we're getting multipolygons 62 | insert into power_station (station_id, power_name, area) 63 | select new_id, 64 | (select power_name from power_station 65 | where station_id = any(old_id) 66 | order by st_area(area) desc limit 1), 67 | area 68 | from merged_stations; 69 | 70 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 71 | select new_id, 's', 'merge', old_id, 's' 72 | from merged_stations; 73 | 74 | delete from power_station s where station_id in ( 75 | select unnest(old_id) from merged_stations 76 | ); 77 | 78 | commit; 79 | -------------------------------------------------------------------------------- /src/node-2-merge-lines.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists node_line_pair; 3 | drop table if exists node_line_set; 4 | drop table if exists node_merged_lines; 5 | 6 | create table node_line_pair ( 7 | src bigint not null, 8 | dst bigint not null 9 | ); 10 | 11 | -- todo, find a way to abstract beyond this 12 | create table node_line_set ( 13 | v bigint, 14 | k bigint not null, 15 | e geometry(linestring, 3857), 16 | primary key (v) 17 | ); 18 | 19 | create table node_merged_lines ( 20 | line_id integer not null, 21 | way_id bigint array, 22 | extent geometry(linestring, 3857) 23 | ); 24 | 25 | create index node_line_set_k on node_line_set (k); 26 | 27 | insert into node_line_pair (src, dst) 28 | select way_id[1], way_id[2] from shared_nodes 29 | where 'l' = all(power_type) 30 | and array_length(way_id, 1) = 2 31 | and path_idx[1] in (0, 1) and path_idx[2] in (0,1); 32 | 33 | insert into node_line_set (v, k, e) 34 | select way_id, way_id, line from way_geometry 35 | where way_id in (select src from node_line_pair union all select dst from node_line_pair); 36 | 37 | do $$ 38 | declare 39 | p node_line_pair; 40 | s node_line_set; 41 | d node_line_set; 42 | e geometry(linestring); 43 | begin 44 | for p in select * from node_line_pair 45 | loop 46 | select * into s from node_line_set where v = p.src; 47 | select * into d from node_line_set where v = p.dst; 48 | if s.k != d.k 49 | then 50 | update node_line_set set k = s.k where k = d.k; 51 | update node_line_set set e = connect_lines(s.e, d.e) where k = s.k; 52 | end if; 53 | end loop; 54 | end 55 | $$ language plpgsql; 56 | 57 | insert into node_merged_lines (line_id, way_id, extent) 58 | select nextval('line_id'), array_agg(v), e 59 | from node_line_set group by k, e; 60 | 61 | insert into power_line (line_id, power_name, extent, radius) 62 | select line_id, 'line', extent, 63 | array_fill(least(:terminal_radius, st_length(extent)/3), array[2]) 64 | from node_merged_lines; 65 | 66 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 67 | select line_id, 'l', 'join', 68 | array(select power_id 69 | from source_objects o 70 | where o.osm_id = any(m.way_id) 71 | and o.osm_type = 'w'), 'l' 72 | from node_merged_lines m; 73 | 74 | delete from power_line l where exists ( 75 | select 1 from source_objects 76 | where osm_type = 'w' and osm_id in ( 77 | select src from node_line_pair union select dst from node_line_pair 78 | ) 79 | and power_type = 'l' and power_id = line_id 80 | ); 81 | 82 | commit; 83 | -------------------------------------------------------------------------------- /src/spatial-4-terminal-intersections.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists intersecting_terminals; 3 | drop table if exists terminal_sets; 4 | drop sequence if exists terminal_set_keys; 5 | create sequence terminal_set_keys; 6 | 7 | create table intersecting_terminals ( 8 | src_id integer not null, 9 | src_pt integer not null, 10 | dst_id integer not null, 11 | dst_pt integer not null 12 | ); 13 | 14 | -- sets of mutually intersecting terminals 15 | create table terminal_sets ( 16 | line_id integer not null, 17 | line_pt integer not null, 18 | set_key integer not null, 19 | primary key (line_id, line_pt) 20 | ); 21 | 22 | create index terminal_sets_key on terminal_sets (set_key); 23 | 24 | insert into intersecting_terminals (src_id, src_pt, dst_id, dst_pt) 25 | select a.line_id, 1, b.line_id, 1 from power_line a, power_line b 26 | where a.line_id != b.line_id and st_dwithin(st_startpoint(a.extent), st_startpoint(b.extent), a.radius[1]) 27 | and not exists (select 1 from power_station s where st_dwithin(s.area, st_startpoint(a.extent), a.radius[1])); 28 | 29 | insert into intersecting_terminals (src_id, src_pt, dst_id, dst_pt) 30 | select a.line_id, st_numpoints(a.extent), b.line_id, 1 from power_line a, power_line b 31 | where a.line_id != b.line_id and st_dwithin(st_endpoint(a.extent), st_startpoint(b.extent), a.radius[2]) 32 | and not exists (select 1 from power_station s where st_dwithin(s.area, st_endpoint(a.extent), a.radius[2])); 33 | 34 | insert into intersecting_terminals (src_id, src_pt, dst_id, dst_pt) 35 | select a.line_id, st_numpoints(a.extent), b.line_id, st_numpoints(b.extent) from power_line a, power_line b 36 | where a.line_id != b.line_id and st_dwithin(st_endpoint(a.extent), st_endpoint(b.extent), a.radius[2]) 37 | and not exists (select 1 from power_station s where st_dwithin(s.area, st_endpoint(a.extent), a.radius[2])); 38 | 39 | insert into terminal_sets (line_id, line_pt, set_key) 40 | select line_id, line_pt, nextval('terminal_set_keys') 41 | from ( 42 | select src_id, src_pt from intersecting_terminals 43 | union 44 | select dst_id, dst_pt from intersecting_terminals 45 | ) f (line_id, line_pt); 46 | 47 | do $$ 48 | declare 49 | i intersecting_terminals; 50 | s int; 51 | d int; 52 | begin 53 | for i in select * from intersecting_terminals loop 54 | s = set_key from terminal_sets where line_id = i.src_id and line_pt = i.src_pt; 55 | d = set_key from terminal_sets where line_id = i.dst_id and line_pt = i.dst_pt; 56 | if s != d then 57 | update terminal_sets set set_key = least(s,d) where set_key = greatest(s,d); 58 | end if; 59 | end loop; 60 | end 61 | $$ language plpgsql; 62 | 63 | commit; 64 | -------------------------------------------------------------------------------- /src/spatial-2-eliminate-line-overlap.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists line_intersections; 3 | drop table if exists internal_lines; 4 | drop table if exists split_lines; 5 | drop table if exists cropped_lines; 6 | 7 | create table line_intersections ( 8 | line_id integer primary key, 9 | station_id integer array, 10 | extent geometry(linestring, 3857), 11 | areas geometry(multipolygon, 3857) 12 | ); 13 | 14 | create table internal_lines ( 15 | line_id integer primary key, 16 | station_id integer, 17 | extent geometry(linestring, 3857) 18 | ); 19 | 20 | create table split_lines ( 21 | new_id integer, 22 | old_id integer, 23 | segment geometry(linestring, 3857) 24 | ); 25 | 26 | create table cropped_lines ( 27 | line_id integer primary key, 28 | old_extent geometry(linestring, 3857), 29 | new_extent geometry(linestring, 3857), 30 | areas geometry(multipolygon, 3857) 31 | ); 32 | 33 | insert into line_intersections (line_id, station_id, extent, areas) 34 | select l.line_id, array_agg(s.station_id), l.extent, st_multi(st_union(s.area)) 35 | from power_line l 36 | join power_station s on st_intersects(l.extent, s.area) 37 | group by l.line_id, l.extent; 38 | 39 | insert into split_lines (new_id, old_id, segment) 40 | select nextval('line_id'), line_id, (st_dump(st_difference(extent, areas))).geom 41 | from line_intersections 42 | where st_numgeometries(st_difference(extent,areas)) > 1; 43 | 44 | insert into cropped_lines(line_id, old_extent, new_extent, areas) 45 | select line_id, extent, st_difference(extent, areas), areas 46 | from line_intersections 47 | where st_numgeometries(st_difference(extent, areas)) = 1; 48 | 49 | insert into internal_lines (line_id, station_id, extent) 50 | select line_id, station_id[1], extent from line_intersections 51 | where st_isempty(st_difference(extent, areas)); 52 | 53 | insert into power_line (line_id, power_name, extent, radius) 54 | select s.new_id, l.power_name, s.segment, 55 | minimal_radius(s.segment, i.areas, l.radius) 56 | from split_lines s 57 | join line_intersections i on i.line_id = s.old_id 58 | join power_line l on l.line_id = s.old_id; 59 | 60 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 61 | select new_id, 'l', 'split', array[old_id], 'l' 62 | from split_lines; 63 | 64 | update power_line l 65 | set extent = c.new_extent, 66 | radius = minimal_radius(c.new_extent, c.areas, l.radius) 67 | from cropped_lines c where c.line_id = l.line_id; 68 | 69 | delete from power_line l where exists ( 70 | select 1 from split_lines s where s.old_id = l.line_id 71 | ) or exists ( 72 | select 1 from internal_lines i where i.line_id = l.line_id 73 | ); 74 | 75 | 76 | commit; 77 | -------------------------------------------------------------------------------- /src/spatial-5-terminal-joints.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists terminal_joints; 3 | drop table if exists extended_lines; 4 | 5 | create table terminal_joints ( 6 | station_id integer primary key, 7 | line_id integer array, 8 | line_pt integer array, 9 | location geometry(point, 3857) 10 | ); 11 | 12 | create table extended_lines ( 13 | line_id integer primary key, 14 | line_pt integer array, 15 | old_extent geometry(linestring, 3857), 16 | new_extent geometry(linestring, 3857), 17 | locations geometry(multipoint, 3857) 18 | ); 19 | 20 | with joint_groups (line_id, line_pt, locations) as ( 21 | select array_agg(s.line_id), array_agg(s.line_pt), st_union(st_pointn(l.extent, s.line_pt)) 22 | from terminal_sets s join power_line l on l.line_id = s.line_id 23 | group by set_key having count(*) > 2 24 | ) insert into terminal_joints (station_id, line_id, line_pt, location) 25 | select nextval('station_id'), line_id, line_pt, st_centroid(locations) from joint_groups; 26 | 27 | insert into extended_lines (line_id, line_pt, old_extent, new_extent, locations) 28 | select j.line_id, array_agg(j.line_pt), l.extent, l.extent, st_multi(st_union(j.location)) from ( 29 | select unnest(line_id), unnest(line_pt), location from terminal_joints 30 | ) j (line_id, line_pt, location) 31 | join power_line l on l.line_id = j.line_id 32 | where not st_dwithin(j.location, st_pointn(l.extent, j.line_pt), 1) 33 | group by j.line_id, l.extent; 34 | 35 | update extended_lines 36 | set new_extent = case when line_pt[1] = 1 then st_addpoint(new_extent, st_closestpoint(locations, st_startpoint(new_extent)), 0) 37 | else st_addpoint(new_extent, st_closestpoint(locations, st_endpoint(new_extent)), -1) end; 38 | 39 | update extended_lines 40 | set new_extent = case when line_pt[2] = 1 then st_addpoint(new_extent, st_closestpoint(locations, st_startpoint(new_extent)), 0) 41 | else st_addpoint(new_extent, st_closestpoint(locations, st_endpoint(new_extent)), -1) end 42 | where array_length(line_pt, 1) = 2; 43 | 44 | insert into power_station (station_id, power_name, area) 45 | select station_id, 'joint', st_buffer(location, 1) 46 | from terminal_joints; 47 | 48 | update power_line l 49 | set extent = j.new_extent 50 | from extended_lines j 51 | where j.line_id = l.line_id; 52 | 53 | update power_line l 54 | set radius = minimal_radius(l.extent, t.locations, l.radius) from ( 55 | select line_id, st_union(location) from ( 56 | select unnest(line_id), location from terminal_joints 57 | ) f (line_id, location) group by line_id 58 | ) t (line_id, locations) where t.line_id = l.line_id; 59 | 60 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 61 | select station_id, 's', 'merge', line_id, 'l' 62 | from terminal_joints; 63 | 64 | commit; 65 | -------------------------------------------------------------------------------- /src/topology-2-dangling-joints.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists removed_nodes; 3 | drop table if exists removed_edges; 4 | 5 | create table removed_nodes ( 6 | station_id integer primary key, 7 | location geometry(point, 3857) 8 | ); 9 | 10 | create table removed_edges ( 11 | line_id integer primary key, 12 | extent geometry(linestring, 3857) 13 | ); 14 | 15 | 16 | 17 | -- iteratively prune 'dangling' joints, a joint should attach at least two stations 18 | do $$ 19 | declare 20 | last_count integer; 21 | new_count integer; 22 | begin 23 | last_count = 0; 24 | loop 25 | insert into removed_nodes (station_id, location) 26 | select n.station_id, n.station_location 27 | from topology_nodes n 28 | join topology_edges e on e.line_id = any(n.line_id) 29 | join topology_nodes c on c.station_id = any(e.station_id) 30 | where c.station_id != n.station_id 31 | and n.topology_name = 'joint' 32 | group by n.station_id having count(distinct c.station_id) < 2; 33 | new_count = count(*) from removed_nodes; 34 | raise notice 'found %', new_count - last_count; 35 | if new_count = last_count 36 | then 37 | raise notice 'total %', last_count; 38 | exit; 39 | end if; 40 | last_count = new_count; 41 | delete from topology_nodes 42 | where station_id in (select station_id from removed_nodes); 43 | end loop; 44 | end; 45 | $$ language plpgsql; 46 | 47 | 48 | -- we're going to remove edges, and finally nodes 49 | insert into removed_edges (line_id, extent) 50 | select line_id, line_extent from topology_edges where line_id in ( 51 | select line_id from ( 52 | select line_id, unnest(station_id) 53 | ) f(line_id, station_id) where station_id not in ( 54 | select station_id from topology_nodes 55 | ) 56 | ); 57 | 58 | delete from topology_edges where line_id in (select line_id from removed_edges); 59 | 60 | update topology_nodes n set line_id = array_remove(n.line_id, r.line_id) 61 | from ( 62 | select station_id, array_agg(line_id) from ( 63 | select station_id, unnest(line_id) from topology_nodes 64 | ) f(station_id, line_id) where line_id not in ( 65 | select line_id from topology_edges 66 | ) group by station_id 67 | ) r (station_id, line_id) where r.station_id = n.station_id; 68 | 69 | insert into removed_nodes (station_id, location) 70 | select station_id, station_location 71 | from topology_nodes where array_length(line_id, 1) is null; 72 | delete from topology_nodes where station_id in (select station_id from removed_nodes); 73 | 74 | -- this cannot result into newly 'dangling edges', because if those 75 | -- nodes were connected to anything, they wouldn't have been removed. 76 | 77 | commit; 78 | 79 | -------------------------------------------------------------------------------- /power.style: -------------------------------------------------------------------------------- 1 | # This is the adjusted and shortened default osm2pgsql .style file that comes 2 | # with osm2pgsql where all lines are deleted that are not necessary for SciGRID. 3 | # Further there are power related lines are added such that osm2pgsql creates 4 | # columns for the power entries. 5 | # 6 | # A .style file has 4 columns that define how OSM objects end up in tables in 7 | # the database and what columns are created. It interacts with the command-line 8 | # hstore options. 9 | # 10 | # Columns 11 | # ======= 12 | # 13 | # OsmType: This is either "node", "way" or "node,way" and indicates if this tag 14 | # applies to nodes, ways, or both. 15 | # 16 | # Tag: The tag 17 | # 18 | # DataType: The type of the column to be created. Normally "text" 19 | # 20 | # Flags: Flags that indicate what table the OSM object is moved into. 21 | # 22 | # There are 5 possible flags. These flags are used both to indicate if a column 23 | # should be created, and if ways with the tag are assumed to be areas. The area 24 | # assumptions can be overridden with an area=yes/no tag 25 | # 26 | # polygon - Create a column for this tag, and objects the tag with are areas 27 | # 28 | # linear - Create a column for this tag 29 | # 30 | # phstore - Don't create a column for this tag, but objects with the tag are areas 31 | # 32 | # delete - Drop this tag completely and don't create a column for it. This also 33 | # prevents the tag from being added to hstore columns 34 | # 35 | # nocache - Deprecated and does nothing 36 | # 37 | # If an object has a tag that indicates it is an area or has area=yes/1, 38 | # osm2pgsql will try to turn it into an area. If it succeeds, it places it in 39 | # the polygon table. If it fails (e.g. not a closed way) it places it in the 40 | # line table. 41 | # 42 | # Nodes are never placed into the polygon or line table and are always placed in 43 | # the point table. 44 | # 45 | # Hstore 46 | # ====== 47 | # 48 | # The option --hstore interacts with the .style file. 49 | # 50 | # With --hstore any tags without a column will be added to the hstore column. 51 | # This will also cause all objects to be kept. 52 | # 53 | # 54 | # Special database columns 55 | # ======================== 56 | # 57 | # There are some special database columns that if present in the .style file 58 | # will be populated by osm2pgsql. 59 | # 60 | # These are 61 | # 62 | # z_order - datatype int4 63 | # 64 | # way_area - datatype real. The area of the way, in the units of the projection 65 | # (e.g. square mercator meters). Only applies to areas 66 | # 67 | # osm_user, osm_uid, osm_version, osm_timestamp - datatype text. Used with the 68 | # --extra-attributes option to include metadata in the database. If importing 69 | # with both --hstore and --extra-attributes the meta-data will end up in the 70 | # tags hstore column regardless of the style file. 71 | 72 | # OsmType Tag DataType Flags 73 | node,way power text polygon 74 | node,way cables text linear 75 | node,way voltage text linear 76 | node,way wires text linear 77 | 78 | -------------------------------------------------------------------------------- /src/topology-3-redundant-splits.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists redundant_splits; 3 | drop table if exists simplified_splits; 4 | create table redundant_splits ( 5 | line_id integer array, 6 | station_id integer array 7 | ); 8 | 9 | create table simplified_splits ( 10 | new_id integer primary key, 11 | station_id integer array[2], 12 | old_id integer array, 13 | simple_extent geometry(linestring, 3857), 14 | original_extents geometry(multilinestring, 3857), 15 | distortion float 16 | ); 17 | 18 | 19 | -- select distinct stations so that we don't add double simplified lines on beads-on-a-string 20 | insert into redundant_splits (station_id, line_id) 21 | select distinct array[least(j.station_id, c.station_id), greatest(j.station_id, c.station_id)], 22 | array_agg(e.line_id order by e.line_id) 23 | from topology_nodes j 24 | join topology_edges e on e.line_id = any(j.line_id) 25 | join topology_nodes c on c.station_id = any(e.station_id) 26 | where j.topology_name = 'joint' and c.station_id != j.station_id 27 | group by j.station_id, c.station_id having count(distinct e.line_id) > 1; 28 | 29 | with split_simplify_candidates (line_id, station_id, simple_extent, original_length, original_extents) as ( 30 | select line_id, r.station_id, st_shortestline(a.area, b.area), 31 | (select avg(st_length(line_extent)) from topology_edges e where e.line_id = any(r.line_id)), 32 | (select st_multi(st_union(line_extent)) from topology_edges e where e.line_id = any(r.line_id)) 33 | from redundant_splits r 34 | join power_station a on a.station_id = r.station_id[1] 35 | join power_station b on b.station_id = r.station_id[2] 36 | ) 37 | insert into simplified_splits (new_id, station_id, old_id, simple_extent, original_extents, distortion) 38 | select nextval('line_id'), station_id, line_id, 39 | simple_extent, original_extents, 40 | abs(original_length - st_length(simple_extent)) 41 | from split_simplify_candidates 42 | where abs(original_length - st_length(simple_extent)) < :merge_distortion; 43 | 44 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 45 | select new_id, 'l', 'merge', old_id, 'l' 46 | from simplified_splits; 47 | 48 | -- edges are only ever replaced, never removed, so we don't need to do a pruning step 49 | 50 | insert into topology_edges (line_id, station_id, line_extent) 51 | select new_id, s.station_id, simple_extent 52 | from simplified_splits s; 53 | 54 | update topology_nodes n set line_id = array_replace(n.line_id, r.old_id, r.new_id) 55 | from ( 56 | select station_id, array_agg(distinct old_id), array_agg(distinct new_id) from ( 57 | select station_id[1], unnest(old_id), new_id from simplified_splits 58 | union 59 | select station_id[2], unnest(old_id), new_id from simplified_splits 60 | ) f (station_id, old_id, new_id) group by station_id 61 | ) r(station_id, old_id, new_id) where n.station_id = r.station_id; 62 | 63 | delete from topology_edges where line_id in (select unnest(old_id) from simplified_splits); 64 | commit; 65 | -------------------------------------------------------------------------------- /entsoe/fixup-merge.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists invalid_merge; 3 | drop table if exists invalid_join; 4 | create table invalid_merge ( 5 | merged_id integer primary key, 6 | line_id integer array, 7 | station_id integer array[2] 8 | ); 9 | 10 | create table invalid_join ( 11 | joined_id integer primary key, 12 | line_id integer array, 13 | joint_id integer array 14 | ); 15 | 16 | 17 | insert into invalid_merge (merged_id, line_id, station_id) 18 | select derived_id, s.line_id, s.station_id 19 | from redundant_splits s 20 | join derived_objects o on s.line_id = o.source_id 21 | join line_structure_conflicts c on c.line_id = o.derived_id 22 | where o.derived_type = 'l' and o.operation = 'merge'; 23 | 24 | insert into invalid_join (joined_id, line_id, joint_id) 25 | select derived_id, source_id, 26 | array(select joint_id from joint_edge_pair 27 | where left_id = any(source_id) or right_id = any(source_id)) 28 | from derived_objects 29 | join invalid_merge i on i.merged_id = any(source_id); 30 | 31 | -- delete prior to insert 32 | delete from topology_edges where line_id in (select unnest(line_id) from invalid_merge union select unnest(line_id) from invalid_join); 33 | delete from topology_nodes where station_id in (select unnest(joint_id) from invalid_join); 34 | 35 | -- restore edges and nodes 36 | insert into topology_edges (line_id, station_id, line_extent, topology_name) 37 | select l.line_id, array(select c.station_id from topology_connections c where c.line_id = l.line_id), 38 | extent, power_name 39 | from power_line l 40 | where exists (select 1 from invalid_join j where l.line_id = any(j.line_id)) 41 | or exists (select 1 from invalid_merge m where l.line_id = any(m.line_id)); 42 | 43 | insert into topology_nodes (station_id, line_id, station_location, topology_name) 44 | select s.station_id, array(select c.line_id from topology_connections c where c.station_id = s.station_id), 45 | st_centroid(area), power_name 46 | from power_station s 47 | where exists (select 1 from invalid_join j where s.station_id = any(j.joint_id)); 48 | 49 | -- remove invalidly merged /joined lines 50 | delete from topology_edges e 51 | where exists(select 1 from invalid_join where e.line_id = joined_id) 52 | or exists(select 1 from invalid_merge where e.line_id = merged_id); 53 | 54 | -- i reconstructed the edges from 'pristine' connections; now restore the nodes as well 55 | with restored_edges(line_id) as ( 56 | select unnest(line_id) from invalid_join 57 | union 58 | select unnest(line_id) from invalid_merge 59 | ), affected_stations(station_id) as ( 60 | select unnest(station_id) from topology_edges e 61 | join restored_edges r on e.line_id = r.line_id 62 | ), current_edges (station_id, line_id) as ( 63 | select station_id, 64 | array(select line_id 65 | from topology_edges e 66 | where a.station_id = any(e.station_id) 67 | order by line_id) 68 | from affected_stations a 69 | ) 70 | update topology_nodes n 71 | set line_id = c.line_id 72 | from current_edges c 73 | where c.station_id = n.station_id; 74 | 75 | commit; 76 | -------------------------------------------------------------------------------- /entsoe/gridkit-start.sql: -------------------------------------------------------------------------------- 1 | -- script to transfer features to gridkit power stations and lines 2 | begin; 3 | drop table if exists power_station; 4 | drop table if exists power_line; 5 | drop table if exists power_generator; 6 | drop table if exists source_objects; 7 | drop table if exists derived_objects; 8 | 9 | drop sequence if exists station_id; 10 | drop sequence if exists line_id; 11 | drop sequence if exists generator_id; 12 | 13 | create table power_station ( 14 | station_id integer primary key, 15 | power_name varchar(64) not null, 16 | area geometry(polygon, 3857) 17 | ); 18 | 19 | create index power_station_area on power_station using gist (area); 20 | 21 | create table power_line ( 22 | line_id integer primary key, 23 | power_name varchar(64) not null, 24 | extent geometry(linestring, 3857), 25 | radius integer array[2] 26 | ); 27 | 28 | create index power_line_extent_idx on power_line using gist(extent); 29 | create index power_line_startpoint_idx on power_line using gist(st_startpoint(extent)); 30 | create index power_line_endpoint_idx on power_line using gist(st_endpoint(extent)); 31 | 32 | create table power_generator ( 33 | generator_id integer primary key, 34 | location geometry(point, 3857), 35 | tags hstore 36 | ); 37 | 38 | create index power_generator_location_idx on power_generator using gist(location); 39 | 40 | create sequence line_id; 41 | create sequence station_id; 42 | create sequence generator_id; 43 | 44 | create table source_objects ( 45 | power_id integer not null, 46 | power_type char(1) not null, 47 | import_id integer not null, 48 | primary key (power_id, power_type) 49 | ); 50 | 51 | create table derived_objects ( 52 | derived_id integer not null, 53 | derived_type char(1) not null, 54 | operation varchar(16), 55 | source_id integer array, 56 | source_type char(1), 57 | primary key (derived_id, derived_type) 58 | ); 59 | 60 | insert into source_objects (power_id, power_type, import_id) 61 | select nextval('station_id'), 's', import_id 62 | from feature_points; 63 | 64 | insert into source_objects (power_id, power_type, import_id) 65 | select nextval('line_id'), 'l', import_id 66 | from feature_lines; 67 | 68 | insert into power_station (station_id, power_name, area) 69 | select o.power_id, properties->'symbol', 70 | st_buffer(st_transform(point, 3857), :station_buffer) 71 | from feature_points f 72 | join source_objects o 73 | on o.import_id = f.import_id 74 | where o.power_type = 's'; 75 | 76 | insert into power_line (line_id, power_name, extent, radius) 77 | select o.power_id, 'line', st_transform(line, 3857), 78 | array[:terminal_radius,:terminal_radius] 79 | from feature_lines f 80 | join source_objects o on o.import_id = f.import_id 81 | where o.power_type = 'l'; 82 | 83 | insert into power_generator (generator_id, location, tags) 84 | select nextval('generator_id'), st_transform(point, 3857), properties 85 | from feature_points 86 | where properties->'symbol' not in ( 87 | 'Substation', 88 | 'Substation, under construction', 89 | 'Converter Station', 90 | 'Converter Station, under construction', 91 | 'Converter Station Back-to-Back' 92 | ); 93 | 94 | commit; 95 | -------------------------------------------------------------------------------- /src/abstraction-2-export.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists heuristic_links cascade; 3 | drop table if exists heuristic_vertices cascade; 4 | drop table if exists heuristic_vertices_highvoltage; 5 | drop table if exists heuristic_links_highvoltage; 6 | 7 | -- simplify to format of scigrid export 8 | -- v_id,lon,lat,typ,voltage,frequency,name,operator,ref,wkt_srid_4326 9 | create table heuristic_vertices ( 10 | v_id integer primary key, 11 | lon float, 12 | lat float, 13 | typ text, 14 | voltage text, 15 | frequency text, 16 | name text, 17 | operator text, 18 | ref text, 19 | wkt_srid_4326 text 20 | ); 21 | 22 | -- l_id,v_id_1,v_id_2,voltage,cables,wires,frequency,name,operator,ref,length_m,r_ohmkm,x_ohmkm,c_nfkm,i_th_max_a,from_relation,wkt_srid_4326 23 | create table heuristic_links ( 24 | l_id integer primary key, 25 | v_id_1 integer references heuristic_vertices (v_id), 26 | v_id_2 integer references heuristic_vertices (v_id), 27 | voltage text, 28 | cables text, 29 | wires text, 30 | frequency text, 31 | name text, 32 | operator text, 33 | ref text, 34 | length_m float, 35 | r_ohmkm float, 36 | x_ohmkm float, 37 | c_nfkm float, 38 | i_th_max_a float, 39 | from_relation text, 40 | wkt_srid_4326 text 41 | ); 42 | 43 | insert into heuristic_vertices (v_id, lon, lat, typ, voltage, frequency, name, operator, ref, wkt_srid_4326) 44 | select n.station_id, 45 | ST_X(ST_Transform(station_location, 4326)), 46 | ST_Y(ST_Transform(station_location, 4326)), 47 | n.topology_name, 48 | array_to_string(e.voltage, ';'), 49 | array_to_string(e.frequency, ';'), 50 | e.name, 51 | e.operator, 52 | t.tags->'ref', 53 | ST_AsEWKT(ST_Transform(station_location, 4326)) 54 | from topology_nodes n 55 | join electrical_properties e on e.power_id = n.station_id and e.power_type = 's' 56 | join osm_tags t on t.power_id = n.station_id and t.power_type = 's'; 57 | 58 | 59 | insert into heuristic_links (l_id, v_id_1, v_id_2, length_m, voltage, cables, wires, frequency, name, operator, ref, from_relation, wkt_srid_4326) 60 | select l.line_id, 61 | l.station_id[1], 62 | l.station_id[2], 63 | st_length(st_transform(l.line_extent, 4326)::geography), 64 | array_to_string(e.voltage, ';'), 65 | array_to_string(e.conductor_bundles, ';'), 66 | array_to_string(e.subconductors, ';'), 67 | array_to_string(e.frequency, ';'), 68 | e.name, 69 | e.operator, 70 | t.tags->'ref', '', 71 | ST_AsEWKT(ST_Transform(direct_line, 4326)) 72 | from topology_edges l 73 | join electrical_properties e on e.power_id = l.line_id and e.power_type = 'l' 74 | join osm_tags t on t.power_id = l.line_id and t.power_type = 'l'; 75 | 76 | create table heuristic_vertices_highvoltage as 77 | select * from heuristic_vertices where v_id in (select station_id from high_voltage_nodes); 78 | 79 | create table heuristic_links_highvoltage as 80 | select * from heuristic_links where l_id in (select line_id from high_voltage_edges); 81 | 82 | 83 | 84 | commit; 85 | -------------------------------------------------------------------------------- /src/node-3-line-joints.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists shared_nodes_joint; 3 | drop table if exists node_joint_lines; 4 | drop table if exists node_split_lines; 5 | 6 | create table shared_nodes_joint ( 7 | node_id bigint primary key, 8 | line_id integer array, 9 | location geometry(point, 3857) 10 | ); 11 | 12 | create table node_joint_lines ( 13 | line_id integer primary key, 14 | extent geometry(linestring, 3857), 15 | points geometry(multipolygon, 3857) 16 | ); 17 | 18 | create table node_split_lines ( 19 | new_id integer not null, 20 | old_id integer not null, 21 | segment geometry(linestring, 3857), 22 | points geometry(multipolygon, 3857) 23 | ); 24 | 25 | 26 | insert into shared_nodes_joint (node_id, location, line_id) 27 | select s.node_id, n.point, array( 28 | select power_id from source_objects o 29 | where o.osm_type = 'w' and o.osm_id = any(s.way_id) 30 | ) 31 | from shared_nodes s 32 | join node_geometry n on n.node_id = s.node_id 33 | where 'l' = all(power_type) and ( 34 | array_length(way_id, 1) > 2 or ( 35 | path_idx[1] not in (0, 1) or 36 | path_idx[2] not in (0, 1) 37 | ) 38 | ) and not exists ( 39 | select 1 from power_station s where st_intersects(s.area, n.point) 40 | ); 41 | 42 | insert into node_joint_lines (line_id, extent, points) 43 | select g.line_id, l.extent, g.points from ( 44 | select line_id, st_multi(st_union(st_buffer(location, 1))) from ( 45 | select unnest(line_id), location from shared_nodes_joint 46 | ) f(line_id, location) group by line_id 47 | ) g (line_id, points) 48 | join power_line l on g.line_id = l.line_id; 49 | 50 | insert into node_split_lines (new_id, old_id, segment, points) 51 | select nextval('line_id'), line_id, 52 | (st_dump(st_difference(extent, points))).geom, points 53 | from node_joint_lines; 54 | 55 | -- create joints power stations, start with ids for osm id 56 | insert into source_objects (osm_type, osm_id, power_type, power_id) 57 | select 'n', node_id, 's', nextval('station_id') 58 | from shared_nodes_joint; 59 | 60 | insert into power_station (station_id, power_name, area) 61 | select o.power_id, 'joint', st_buffer(j.location, 1) 62 | from shared_nodes_joint j 63 | join source_objects o on o.osm_type = 'n' and o.osm_id = j.node_id; 64 | 65 | -- source objects are combination of lines and the node itself - we'll need to register the node 66 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 67 | select o.power_id, 's', 'merge', line_id, 'l' 68 | from shared_nodes_joint j 69 | join source_objects o on o.osm_type = 'n' and o.osm_id = j.node_id; 70 | 71 | -- replacement power lines 72 | insert into power_line (line_id, power_name, extent, radius) 73 | select s.new_id, l.power_name, s.segment, 74 | minimal_radius(s.segment, s.points, l.radius) 75 | from node_split_lines s 76 | join power_line l on l.line_id = s.old_id; 77 | 78 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 79 | select new_id, 'l', 'split', array[old_id], 'l' 80 | from node_split_lines; 81 | 82 | delete from power_line l where exists ( 83 | select 1 from node_joint_lines j where j.line_id = l.line_id 84 | ); 85 | 86 | commit; 87 | -------------------------------------------------------------------------------- /src/electric-4-station.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists station_structure; 3 | drop table if exists station_terminals; 4 | drop table if exists merged_station_tags; 5 | 6 | create table station_structure ( 7 | station_id integer primary key, 8 | voltage integer array, 9 | frequency float array, 10 | station_name text, 11 | station_operator text, 12 | substation text 13 | ); 14 | 15 | create table station_terminals ( 16 | station_id integer primary key, 17 | voltage integer array, 18 | frequency float array 19 | ); 20 | 21 | create table merged_station_tags ( 22 | like station_tags 23 | ); 24 | 25 | 26 | -- step one, the set of connected lines 27 | insert into station_terminals (station_id, voltage, frequency) 28 | select n.station_id, 29 | array(select distinct l.voltage from line_structure l 30 | where l.line_id = any(n.line_id) and l.voltage is not null), 31 | array(select distinct l.frequency from line_structure l 32 | where l.line_id = any(n.line_id) and l.voltage is not null) 33 | from topology_nodes n; 34 | 35 | 36 | -- step two, merge station tags 37 | insert into merged_station_tags (station_id, power_name, voltage, frequency, station_name, station_operator, substation) 38 | select derived_id, 39 | array_to_string(array(select distinct power_name from station_tags where station_id = any(source_id)), ';'), 40 | array(select distinct unnest(voltage) from station_tags where station_id = any(source_id)), 41 | array(select distinct unnest(frequency) from station_tags where station_id = any(source_id)), 42 | array_to_string(array(select distinct station_name from station_tags where station_id = any(source_id)), ';'), 43 | array_to_string(array(select distinct station_operator from station_tags where station_id = any(source_id)), ';'), 44 | array_to_string(array(select distinct substation from station_tags where station_id = any(source_id)), ';') 45 | from derived_objects 46 | where derived_type = 's' and operation = 'merge' and source_type = 's' 47 | and exists (select 1 from topology_nodes where station_id = derived_id and topology_name != 'joint'); 48 | 49 | -- step three, merge connected-line information with tag information 50 | insert into station_structure (station_id, voltage, frequency, station_name, station_operator, substation) 51 | select t.station_id, 52 | array(select unnest(t.voltage) union select unnest(s.voltage)), 53 | array(select unnest(t.frequency) union select unnest(s.frequency)), station_name, station_operator, substation 54 | from station_tags t 55 | join station_terminals s on s.station_id = t.station_id; 56 | 57 | insert into station_structure (station_id, voltage, frequency, station_name, station_operator, substation) 58 | select t.station_id, 59 | array(select unnest(t.voltage) union select unnest(s.voltage)), 60 | array(select unnest(t.frequency) union select unnest(s.frequency)), station_name, station_operator, substation 61 | from merged_station_tags t 62 | join station_terminals s on s.station_id = t.station_id; 63 | 64 | -- step four, synthesize structure information for joints 65 | insert into station_structure (station_id, voltage, frequency) 66 | select a.station_id, a.voltage, a.frequency 67 | from station_terminals a 68 | join topology_nodes n on n.station_id = a.station_id 69 | where n.topology_name = 'joint'; 70 | 71 | commit; 72 | -------------------------------------------------------------------------------- /src/spatial-6-merge-lines.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists line_pairs; 3 | drop table if exists line_sets; 4 | drop table if exists merged_lines; 5 | 6 | -- outer radius of merged line 7 | drop function if exists outer_radius(geometry, int array, geometry, int array, geometry); 8 | create function outer_radius (a_e geometry, a_r int array, b_e geometry, b_r int array, c_e geometry) returns int array as $$ 9 | begin 10 | return array[case when st_startpoint(a_e) = st_startpoint(c_e) then a_r[1] 11 | when st_endpoint(a_e) = st_startpoint(c_e) then a_r[2] 12 | when st_startpoint(b_e) = st_startpoint(c_e) then b_r[1] 13 | when st_endpoint(b_e) = st_startpoint(c_e) then b_r[2] end, 14 | case when st_startpoint(a_e) = st_endpoint(c_e) then a_r[1] 15 | when st_endpoint(a_e) = st_endpoint(c_e) then a_r[2] 16 | when st_startpoint(b_e) = st_endpoint(c_e) then b_r[1] 17 | when st_endpoint(b_e) = st_endpoint(c_e) then b_r[2] end]; 18 | end; 19 | $$ language plpgsql; 20 | 21 | create table line_pairs ( 22 | src_id integer, 23 | dst_id integer, 24 | primary key (src_id, dst_id) 25 | ); 26 | 27 | create table line_sets ( 28 | set_key integer not null, 29 | line_id integer primary key, 30 | extent geometry(linestring, 3857), 31 | radius integer array[2] 32 | ); 33 | 34 | 35 | create table merged_lines ( 36 | new_id integer primary key, 37 | old_id integer array, 38 | extent geometry(linestring, 3857), 39 | radius integer array[2] 40 | ); 41 | 42 | insert into line_pairs (src_id, dst_id) 43 | select distinct min(line_id), max(line_id) 44 | from terminal_sets 45 | group by set_key having count(*) = 2; 46 | 47 | insert into line_sets (set_key, line_id, extent, radius) 48 | select line_id, line_id, extent, radius from power_line 49 | where line_id in ( 50 | select src_id from line_pairs union select dst_id from line_pairs 51 | ); 52 | 53 | 54 | create index line_sets_k on line_sets (set_key); 55 | -- union-find algorithm again. 56 | 57 | do $$ 58 | declare 59 | src line_sets; 60 | dst line_sets; 61 | pair line_pairs; 62 | ext geometry(linestring,3857); 63 | rad int array[2]; 64 | begin 65 | for pair in select * from line_pairs loop 66 | select * into src from line_sets where line_id = pair.src_id; 67 | select * into dst from line_sets where line_id = pair.dst_id; 68 | if src.set_key != dst.set_key then 69 | update line_sets set set_key = src.set_key where set_key = dst.set_key; 70 | ext = connect_lines(src.extent, dst.extent); 71 | rad = outer_radius(src.extent, src.radius, dst.extent, dst.radius, ext); 72 | update line_sets set extent = ext, radius = rad where set_key = src.set_key; 73 | end if; 74 | end loop; 75 | end 76 | $$ language plpgsql; 77 | 78 | insert into merged_lines (new_id, extent, radius, old_id) 79 | select nextval('line_id'), extent, radius, array(select z.line_id from line_sets z where z.set_key = s.set_key) 80 | from line_sets s where line_id = set_key; 81 | 82 | insert into power_line (line_id, power_name, extent, radius) 83 | select new_id, 'merge', extent, radius from merged_lines; 84 | 85 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 86 | select new_id, 'l', 'join', old_id, 'l' 87 | from merged_lines; 88 | 89 | 90 | delete from power_line l where line_id in ( 91 | select unnest(old_id) from merged_lines m 92 | ); 93 | 94 | commit; 95 | -------------------------------------------------------------------------------- /src/topology-1-connections.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists topology_connections; 3 | drop table if exists problem_lines; 4 | drop table if exists topology_edges; 5 | drop table if exists topology_nodes; 6 | drop table if exists topology_generators; 7 | drop table if exists dangling_lines; 8 | 9 | 10 | create table topology_connections ( 11 | line_id integer, 12 | station_id integer 13 | ); 14 | 15 | create table problem_lines ( 16 | line_id integer, 17 | station_id integer array, 18 | line_extent geometry(linestring, 3857), 19 | line_terminals geometry(geometry, 3857), 20 | station_area geometry(geometry, 3857) 21 | ); 22 | 23 | create table dangling_lines ( 24 | line_id integer, 25 | extent geometry(linestring, 3857) 26 | ); 27 | 28 | create table topology_edges ( 29 | line_id integer primary key, 30 | station_id integer array, 31 | line_extent geometry(linestring, 3857), 32 | topology_name varchar(64) 33 | ); 34 | 35 | create table topology_nodes ( 36 | station_id integer primary key, 37 | line_id integer array, 38 | station_location geometry(point, 3857), 39 | topology_name varchar(64) 40 | ); 41 | 42 | create table topology_generators ( 43 | station_id integer not null, 44 | generator_id integer not null, 45 | primary key (station_id, generator_id) 46 | ); 47 | 48 | create index topology_edges_station_id on topology_edges using gin(station_id); 49 | create index topology_nodes_line_id on topology_nodes using gin(line_id); 50 | 51 | insert into topology_connections (line_id, station_id) 52 | select line_id, station_id 53 | from power_line 54 | join power_station 55 | on st_dwithin(st_startpoint(extent), area, radius[1]) or 56 | st_dwithin(st_endpoint(extent), area, radius[2]); 57 | 58 | insert into topology_edges (line_id, station_id, line_extent, topology_name) 59 | select c.line_id, c.station_id, l.extent, l.power_name from ( 60 | select line_id, array_agg(station_id) from topology_connections group by line_id having count(*) = 2 61 | ) c (line_id, station_id) 62 | join power_line l on c.line_id = l.line_id; 63 | 64 | insert into topology_nodes (station_id, line_id, station_location, topology_name) 65 | select s.station_id, array_agg(e.line_id), st_centroid(s.area), s.power_name 66 | from power_station s 67 | join topology_edges e on s.station_id = any(e.station_id) 68 | group by s.station_id; 69 | 70 | 71 | insert into problem_lines (line_id, station_id, line_extent, line_terminals, station_area) 72 | select c.line_id, c.station_id, extent, 73 | st_multi(st_union(st_buffer(st_startpoint(extent), radius[1]), st_buffer(st_endpoint(extent), radius[2]))), 74 | (select st_union(area) from power_station s where station_id = any(c.station_id)) from ( 75 | select line_id, array_agg(station_id) from topology_connections group by line_id having count(*) > 2 76 | ) c (line_id, station_id) 77 | join power_line l on l.line_id = c.line_id; 78 | 79 | insert into dangling_lines (line_id, extent) 80 | select line_id, extent from power_line where line_id not in ( 81 | select line_id from topology_edges 82 | union all 83 | select line_id from problem_lines 84 | ); 85 | 86 | insert into topology_generators (generator_id, station_id) 87 | select generator_id, 88 | (select n.station_id from power_station s 89 | join topology_nodes n on n.station_id = s.station_id 90 | where n.topology_name != 'joint' 91 | order by g.location <-> s.area limit 1) 92 | from power_generator g; 93 | commit; 94 | -------------------------------------------------------------------------------- /util/geojson-to-postgis.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env python 2 | from __future__ import print_function, unicode_literals 3 | import operator 4 | import psycopg2 5 | import psycopg2.extras 6 | import io 7 | import json 8 | import sys 9 | import logging 10 | 11 | 12 | CREATE_TABLES = ''' 13 | CREATE EXTENSION IF NOT EXISTS hstore; 14 | CREATE EXTENSION IF NOT EXISTS postgis; 15 | DROP TABLE IF EXISTS feature_points; 16 | DROP TABLE IF EXISTS feature_lines; 17 | DROP TABLE IF EXISTS feature_multilines; 18 | CREATE TABLE feature_points ( 19 | import_id serial primary key, 20 | point geometry(point, 4326), 21 | properties hstore 22 | ); 23 | CREATE TABLE feature_lines ( 24 | import_id serial primary key, 25 | line geometry(linestring, 4326), 26 | properties hstore 27 | ); 28 | CREATE TABLE feature_multilines ( 29 | import_id serial primary key, 30 | multiline geometry(multilinestring, 4326), 31 | properties hstore 32 | ) 33 | ''' 34 | 35 | INSERT_STATEMENT = { 36 | 'Point': 'INSERT INTO feature_points (point, properties) VALUES (ST_SetSRID(ST_GeomFromText(%s), 4326), %s);', 37 | 'LineString': 'INSERT INTO feature_lines (line, properties) VALUES (ST_SetSRID(ST_GeomFromText(%s), 4326), %s);', 38 | 'MultiLineString': 'INSERT INTO feature_multilines (multiline, properties) VALUES (ST_SetSRID(ST_GeomFromText(%s), 4326), %s);', 39 | } 40 | 41 | REMOVE_DUPLICATES = ''' 42 | DELETE FROM feature_lines WHERE import_id IN ( 43 | SELECT b.import_id 44 | FROM feature_lines a, feature_lines b 45 | WHERE a.import_id < b.import_id 46 | AND a.properties = b.properties 47 | AND a.line = b.line 48 | ); 49 | ''' 50 | 51 | SPLIT_MULTILINES = ''' 52 | INSERT INTO feature_lines (line, properties) 53 | SELECT (ST_Dump(multiline)).geom, properties 54 | FROM feature_multilines; 55 | ''' 56 | 57 | def hstore(d): 58 | return dict((unicode(k), unicode(v)) for k, v, in d.items()) 59 | 60 | def wkt(g): 61 | def coords(c): 62 | if isinstance(c[0], list): 63 | if isinstance(c[0][0], list): 64 | f = '({0})' 65 | else: 66 | f = '{0}' 67 | t = ', '.join(f.format(a) for a in map(coords, c)) 68 | else: 69 | t = '{0:f} {1:f}'.format(*c) 70 | return t 71 | return '{0:s} ({1:s})'.format(g['type'].upper(), coords(g['coordinates'])) 72 | 73 | 74 | def import_feature(cur,feature_data): 75 | if feature_data.get('type') == 'FeatureCollection': 76 | for feature in feature_data['features']: 77 | import_feature(cur, feature) 78 | elif feature_data.get('type') == 'Feature': 79 | cur.execute(INSERT_STATEMENT[feature_data['geometry']['type']], 80 | (wkt(feature_data['geometry']), 81 | hstore(feature_data['properties']))) 82 | 83 | if __name__ == '__main__': 84 | logging.basicConfig(level=logging.DEBUG) 85 | con = psycopg2.connect('') 86 | # create table 87 | with con: 88 | with con.cursor() as cur: 89 | cur.execute(CREATE_TABLES) 90 | 91 | # use hstore to store attributes 92 | psycopg2.extras.register_hstore(con) 93 | 94 | 95 | if len(sys.argv) == 1: 96 | handles = [sys.stdin] 97 | else: 98 | handles = [io.open(a,'r') for a in sys.argv[1:]] 99 | for handle in handles: 100 | with handle: 101 | feature_data = json.load(handle) 102 | with con: 103 | with con.cursor() as cur: 104 | import_feature(cur, feature_data) 105 | cur.execute(SPLIT_MULTILINES) 106 | cur.execute(REMOVE_DUPLICATES) 107 | con.commit() 108 | -------------------------------------------------------------------------------- /src/electric-1-tags.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists line_tags; 3 | drop table if exists station_tags; 4 | drop table if exists wires_to_numbers; 5 | drop function if exists string_to_integer_array(text,text); 6 | drop function if exists string_to_float_array(text,text); 7 | drop function if exists number_of_wires(text); 8 | 9 | 10 | -- table of parsed line tags 11 | create table line_tags ( 12 | line_id integer primary key, 13 | power_name varchar(64) not null, 14 | voltage integer array, 15 | frequency float array, 16 | cables integer array, 17 | wires integer array, 18 | circuits integer array, 19 | num_classes integer 20 | ); 21 | 22 | create table station_tags ( 23 | station_id integer primary key, 24 | power_name varchar(64) not null, 25 | -- we don't /really/ care about those, since they can be derived 26 | -- from connected lines 27 | voltage integer array, 28 | frequency float array, 29 | station_name text, 30 | station_operator text, 31 | substation text 32 | ); 33 | 34 | 35 | create function string_to_integer_array(a text, b text) returns integer array as $$ 36 | declare 37 | r integer array; 38 | t text; 39 | begin 40 | for t in select unnest(string_to_array(a, b)) loop 41 | begin 42 | r = r || t::int; 43 | exception when others then 44 | r = r || null; 45 | end; 46 | end loop; 47 | return r; 48 | end; 49 | $$ language plpgsql; 50 | 51 | create function string_to_float_array(a text, b text) returns float array as $$ 52 | declare 53 | r float array; 54 | t text; 55 | begin 56 | for t in select unnest(string_to_array(a, b)) loop 57 | begin 58 | r = r || t::float; 59 | exception when others then 60 | r = r || null; 61 | end; 62 | end loop; 63 | return r; 64 | end; 65 | $$ language plpgsql; 66 | 67 | 68 | create table wires_to_numbers ( 69 | name varchar(16), 70 | nr integer 71 | ); 72 | 73 | insert into wires_to_numbers(name, nr) 74 | values ('single', 1), 75 | ('double', 2), 76 | ('triple', 3), 77 | ('quad', 4); 78 | 79 | 80 | create function number_of_wires(a text) returns integer array as $$ 81 | declare 82 | r integer array; 83 | t text; 84 | w wires_to_numbers; 85 | begin 86 | for t in select unnest(string_to_array(a, ';')) loop 87 | select * into w from wires_to_numbers where name = t; 88 | if w is not null 89 | then 90 | r = r || w.nr; 91 | else 92 | begin 93 | r = r || t::integer; 94 | exception when others then 95 | r = r || null; 96 | end; 97 | end if; 98 | end loop; 99 | return r; 100 | end; 101 | $$ language plpgsql; 102 | 103 | 104 | insert into line_tags (line_id, power_name, voltage, frequency, cables, wires, circuits) 105 | select power_id, tags->'power', 106 | string_to_integer_array(tags->'voltage',';'), 107 | string_to_float_array(tags->'frequency',';'), 108 | string_to_integer_array(tags->'cables',';'), 109 | number_of_wires(tags->'wires'), 110 | string_to_integer_array(tags->'circuits',';') 111 | from source_tags 112 | where power_type = 'l'; 113 | 114 | -- compute num_classes 115 | update line_tags 116 | set num_classes = greatest(array_length(voltage, 1), array_length(frequency, 1), 117 | array_length(cables, 1), array_length(wires, 1), 118 | array_length(circuits, 1), 1); 119 | 120 | insert into station_tags (station_id, power_name, voltage, frequency, station_name, station_operator, substation) 121 | select power_id, tags->'power', 122 | string_to_integer_array(tags->'voltage', ';'), 123 | string_to_float_array(tags->'frequency',';'), 124 | tags->'name', tags->'operator', tags->'substation' 125 | from source_tags 126 | where power_type = 's'; 127 | 128 | commit; 129 | -------------------------------------------------------------------------------- /src/electric-5-flood.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists line_neighbor_voltage_pairs; 3 | drop table if exists base_probability; 4 | drop table if exists conditional_probability; 5 | 6 | create table line_voltage_distribution ( 7 | voltage integer not null, 8 | line_count integer not null, 9 | primary key (voltage) 10 | ); 11 | 12 | create table line_neighbor_voltage_pairs ( 13 | line_voltage integer not null, 14 | neighbor_voltage integer not null, 15 | pair_count integer not null, 16 | primary key (line_voltage, neighbor_voltage) 17 | ); 18 | 19 | create table base_probability ( 20 | quantity varchar(64) not null, 21 | prediction integer not null, 22 | probability float not null, 23 | primary key (quantity, prediction) 24 | ); 25 | 26 | create table conditional_probability ( 27 | quantity varchar(64) not null, 28 | conditional integer not null, 29 | prediction integer not null, 30 | probability float not null, 31 | primary key (quantity, conditional, prediction) 32 | ); 33 | 34 | -- compute all probabilities for line-neighbor voltage pairs 35 | with voltage_pair (low_v, high_v, cnt) as ( 36 | select least(a.voltage, b.voltage), greatest(a.voltage, b.voltage), count(*) 37 | from topology_nodes n 38 | join line_structure a on a.line_id = any(n.line_id) 39 | join line_structure b on b.line_id = any(n.line_id) 40 | where a.line_id < b.line_id 41 | and a.voltage is not null and b.voltage is not null 42 | group by least(a.voltage, b.voltage), greatest(a.voltage, b.voltage) 43 | having count(*) >= 10 44 | ) 45 | insert into line_neighbor_voltage_pairs (line_voltage, neighbor_voltage, pair_count) 46 | select low_v, high_v, cnt from voltage_pair 47 | union 48 | select high_v, low_v, cnt from voltage_pair; 49 | 50 | /* compute probabilities, recompute some values, but who cares */ 51 | 52 | insert into base_probability (quantity, prediction, probability) 53 | select 'line_voltage', line_voltage, (line_count * 1.0) / total_count 54 | from ( 55 | select line_voltage, sum(pair_count) 56 | from line_neighbor_voltage_pairs 57 | group by line_voltage 58 | ) line_total (line_voltage, line_count), 59 | ( 60 | select sum(pair_count) from line_neighbor_voltage_pairs 61 | ) pair_total (total_count); 62 | 63 | insert into base_probability (quantity, prediction, probability) 64 | select 'neighbor_voltage', neighbor_voltage, (neighbor_count * 1.0) / total_count 65 | from ( 66 | select neighbor_voltage, sum(pair_count) 67 | from line_neighbor_voltage_pairs 68 | group by neighbor_voltage 69 | ) neighbor_total (neighbor_voltage, neighbor_count), 70 | ( 71 | select sum(pair_count) from line_neighbor_voltage_pairs 72 | ) pair_total (total_count); 73 | 74 | insert into conditional_probability (quantity, conditional, prediction, probability) 75 | select 'neighbor_voltage_given_line_voltage', line_voltage, neighbor_voltage, 76 | (pair_count * 1.0)/line_total 77 | from line_neighbor_voltage_pairs 78 | join ( 79 | select line_voltage, sum(pair_count) 80 | from line_neighbor_voltage_pairs 81 | group by line_voltage 82 | ) line_total (group_voltage, line_total) 83 | on group_voltage = line_voltage; 84 | 85 | 86 | /* 87 | something is going very wrong, here! 88 | select line_id, neighbor_voltage, f.prediction, "p(n|l)/p(n)"*probability from ( 89 | select l.line_id, ncp.conditional as prediction, array_agg(nl.line_id) as neighbor_id, array_agg(nl.voltage) as neighbor_voltage, 90 | exp(sum(log(nbp.probability)) - sum(log(ncp.probability))) as "p(n|l)/p(n)" 91 | from line_structure l 92 | join topology_nodes tn on l.line_id = any(tn.line_id) 93 | join line_structure nl on nl.line_id = any(tn.line_id) 94 | join conditional_probability ncp on ncp.quantity = 'neighbor_voltage_given_line_voltage' and ncp.prediction = nl.voltage 95 | join base_probability nbp on nbp.quantity = 'neighbor_voltage' and nbp.prediction = nl.voltage 96 | 97 | where l.voltage is null and nl.voltage is not null and l.line_id in (524, 1017) 98 | group by l.line_id, ncp.conditional 99 | ) f join base_probability b on f.prediction = b.prediction and quantity = 'line_voltage' 100 | order by line_id, "p(n|l)/p(n)"*probability desc; 101 | 102 | */ 103 | commit; 104 | -------------------------------------------------------------------------------- /util/postgres.py: -------------------------------------------------------------------------------- 1 | from which import which 2 | try: 3 | import psycopg2 4 | import psycopg2.extensions 5 | except ImportError: 6 | psycopg2 = False 7 | 8 | PSQL = which('psql') 9 | 10 | class QueryError(Exception): 11 | def __init__(self, error, query): 12 | super(QueryError, self).__init__(error) 13 | self.query = query 14 | 15 | def make_copy_query(subquery_or_table): 16 | if subquery_or_table.lower().startswith('select'): 17 | query = 'COPY ({0}) TO STDOUT WITH CSV HEADER' 18 | else: 19 | query = 'COPY {0} TO STDOUT WITH CSV HEADER' 20 | return query.format(subquery_or_table) 21 | 22 | 23 | class PsqlWrapper(object): 24 | "Wrap psql client executable under subprocess" 25 | def check_connection(self): 26 | try: 27 | self.do_query('SELECT 1') 28 | except QueryError as e: 29 | return False 30 | else: 31 | return True 32 | 33 | def update_params(self, params): 34 | for n,v in params.items(): 35 | k = 'PG' + n.upper() 36 | os.environ[k] = str(v) 37 | 38 | def do_createdb(self, database_name): 39 | self.do_query('CREATE DATABASE {0}'.format(database_name)) 40 | 41 | def do_query(self, query): 42 | try: 43 | subprocess.check_call([PSQL, '-v', 'ON_ERROR_STOP=1', '-c', query]) 44 | except subprocess.CalledProcessError as e: 45 | raise QueryError(e, query) 46 | except OSError as e: 47 | raise Exception(e) 48 | 49 | def do_queryfile(self, queryfile): 50 | try: 51 | subprocess.check_call([PSQL, '-v', 'ON_ERROR_STOP=1', '-f', queryfile]) 52 | except subprocess.CalledProcessError as e: 53 | raise QueryError(e, queryfile) 54 | except OSError as e: 55 | raise Exception(e) 56 | 57 | def do_getcsv(self, subquery_or_table, io_handle): 58 | query = make_copy_query(subquery_or_table) 59 | try: 60 | command = [PSQL, '-v', 'ON_ERROR_STOP=1', '-c', query] 61 | try: 62 | subprocess.check_call(command, stdout=io_handle) 63 | except io.UnsupportedOperation as e: 64 | io_handle.write(subprocess.check_output(command).decode('utf-8')) 65 | except subprocess.CalledProcessError as e: 66 | raise QueryError(e, subquery_or_table) 67 | except OSError as e: 68 | raise Exception(e) 69 | 70 | 71 | class Psycopg2Wrapper(object): 72 | "Wrap psycopg2 for consistency with psql-wrapper" 73 | def __init__(self): 74 | self._connection = None 75 | self._params = dict() 76 | 77 | def update_params(self, params): 78 | if self._connection is not None: 79 | # close existing connection 80 | if not self._connection.closed: 81 | self._connection.close() 82 | self._connection = None 83 | self._params.update(**params) 84 | 85 | def check_connection(self): 86 | try: 87 | if self._connection is None: 88 | self._connection = psycopg2.connect(**self._params) 89 | except (TypeError, psycopg2.Error) as e: 90 | return False 91 | else: 92 | return True 93 | 94 | def do_createdb(self, database_name): 95 | self._connection.set_isolation_level(psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT) 96 | self.do_query('CREATE DATABASE {0};'.format(database_name)) 97 | 98 | def do_query(self, query): 99 | try: 100 | with self._connection as con: 101 | with con.cursor() as cursor: 102 | cursor.execute(query) 103 | except psycopg2.Error as e: 104 | raise QueryError(e, query) 105 | 106 | def do_queryfile(self, queryfile): 107 | with io.open(queryfile, 'r', encoding='utf-8') as handle: 108 | query = handle.read() 109 | self.do_query(query) 110 | 111 | def do_getcsv(self, subquery_or_table, io_handle): 112 | query = make_copy_query(subquery_or_table) 113 | try: 114 | with self._connection.cursor() as cursor: 115 | cursor.copy_expert(query, io_handle) 116 | except psycopg2.Error as e: 117 | raise QueryError(e, query) 118 | 119 | 120 | 121 | class PgWrapper(Psycopg2Wrapper if psycopg2 else PsqlWrapper): 122 | ''' 123 | Wrap interfaces of either psycopg2 or psql-under-subprocess 124 | Which of these is actually implemented depends on the runtime 125 | environment; psycopg2 is given preference, but psql is a fallback. 126 | ''' 127 | pass 128 | -------------------------------------------------------------------------------- /src/electric-2-patch.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop function if exists fair_division(n int, d int); 3 | drop function if exists array_mult(n int array, int); 4 | 5 | create function fair_division (n int, d int) returns int array as $$ 6 | begin 7 | return array_cat(array_fill( n / d + 1, array[n % d]), array_fill( n / d, array[d - n % d])); 8 | end; 9 | $$ language plpgsql; 10 | 11 | create function array_mult(n int array, x int) returns int array as $$ 12 | begin 13 | return array(select v*x from unnest(n) v); 14 | end; 15 | $$ language plpgsql; 16 | 17 | -- use the 'circuits' tag to compute the cables if this is not set 18 | update line_tags set cables = array_mult(circuits, 3) 19 | where cables is null and circuits is not null; 20 | 21 | drop table if exists divisible_cables; 22 | create table divisible_cables ( 23 | line_id integer primary key, 24 | num_lines integer, 25 | total_cables integer, 26 | cables integer array 27 | ); 28 | 29 | insert into divisible_cables (line_id, num_lines, total_cables) 30 | select line_id, case when array_length(voltage, 1) > 1 then array_length(voltage, 1) 31 | else array_length(frequency, 1) end, cables[1] 32 | from line_tags l 33 | where (array_length(voltage, 1) > 1 or array_length(frequency, 1) > 1) and array_length(cables, 1) = 1 34 | and cables[1] > 4; 35 | 36 | 37 | update divisible_cables 38 | set cables = case when total_cables >= num_lines * 3 and total_cables % 3 = 0 then array_mult(fair_division(total_cables / 3, num_lines), 3) 39 | when total_cables >= num_lines * 4 and total_cables % 4 = 0 then array_mult(fair_division(total_cables / 4, num_lines), 4) 40 | when total_cables >= 7 and (total_cables - 4) % 3 = 0 then array_cat(array[4], array_mult(fair_division((total_cables - 4) / 3, num_lines - 1), 3)) 41 | when total_cables >= 11 and (total_cables - 8) % 3 = 0 then array_cat(array[8], array_mult(fair_division((total_cables - 8) / 3, num_lines-1), 3)) 42 | else array[total_cables] end; 43 | 44 | -- can't seem to solve this one analytically... 45 | update divisible_cables set cables = array[4,4,3] where total_cables = 11 and num_lines = 3; 46 | 47 | update line_tags t set cables = d.cables from divisible_cables d where d.line_id = t.line_id; 48 | 49 | -- fix 16.67 Hz to 16.7 frequency for consistency. 50 | update line_tags 51 | set frequency = array_replace(frequency::numeric[],16.67,16.7) 52 | where 16.67 = any(frequency); 53 | 54 | -- fix inconsistently striped lines 55 | 56 | drop table if exists inconsistent_line_tags; 57 | create table inconsistent_line_tags ( 58 | line_id integer primary key, 59 | voltage integer array, 60 | frequency float array, 61 | cables integer array, 62 | wires integer array 63 | ); 64 | 65 | -- this affects surprisingly few lines, actually 66 | insert into inconsistent_line_tags (line_id, voltage, frequency, cables, wires) 67 | select line_id, voltage, frequency, cables, wires 68 | from line_tags t 69 | where num_classes > 2 and 70 | array_length(voltage, 1) between 2 and num_classes - 1 or 71 | array_length(frequency, 1) between 2 and num_classes - 1 or 72 | array_length(cables, 1) between 2 and num_classes - 1 or 73 | array_length(wires, 1) between 2 and num_classes - 1; 74 | 75 | -- patch cables and wires 76 | -- default cables is 3, default wires is 1 77 | update inconsistent_line_tags set cables = array_cat(cables, array_fill(null::int, array[array_length(voltage, 1) - array_length(cables, 1)])) 78 | where array_length(voltage, 1) > array_length(cables, 1) and array_length(cables, 1) > 1; 79 | 80 | update inconsistent_line_tags set wires = array_cat(wires, array_fill(null::int, array[array_length(voltage,1) - array_length(wires, 1)])) 81 | where array_length(voltage, 1) > array_length(wires, 1) and array_length(wires, 1) > 1; 82 | 83 | update inconsistent_line_tags set frequency = array_cat(frequency, array_fill(null::float, array[array_length(voltage, 1) - array_length(frequency, 1)])) 84 | where array_length(voltage, 1) > array_length(frequency, 1) and array_length(frequency, 1) > 1; 85 | 86 | -- peel of excess wires 87 | update inconsistent_line_tags set wires = wires[1:(array_length(voltage,1))] 88 | where array_length(wires, 1) > array_length(voltage, 1) and array_length(voltage, 1) > 1; 89 | 90 | -- that's enough! for now at least 91 | update line_tags l 92 | set frequency = i.frequency, cables = i.cables, wires = i.wires, 93 | num_classes = greatest(array_length(i.voltage, 1), array_length(i.frequency, 1), 94 | array_length(i.cables, 1), array_length(i.wires, 1)) 95 | from inconsistent_line_tags i 96 | where l.line_id = i.line_id; 97 | 98 | commit; 99 | -------------------------------------------------------------------------------- /entsoe/README.md: -------------------------------------------------------------------------------- 1 | # Unofficial ENTSO-E dataset processed by GridKit 2 | 3 | This dataset was generated based on a map extract from May 11, 2016. 4 | This is an _unofficial_ extract of the 5 | [ENTSO-E interactive map](https://www.entsoe.eu/map/Pages/default.aspx) 6 | of the European power system (including to a limited extent North 7 | Africa and the Middle East). The dataset has been processed by GridKit 8 | to form complete topological connections. This dataset is neither 9 | approved nor endorsed by ENTSO-E. 10 | 11 | This dataset may be inaccurate in several ways, notably: 12 | 13 | + Geographical coordinates are transfered from the ENTSO-E map, which 14 | is known to choose topological clarity over geographical 15 | accuracy. Hence coordinates will not correspond exactly to reality. 16 | + Voltage levels are typically provided as ranges by ENTSO-E, of which 17 | the lower bound has been reported in this dataset. Not all lines - 18 | especially DC lines - contain voltage information. 19 | + Line structure conflicts are resolved by picking the first structure 20 | in the set 21 | + Transformers are _not present_ in the original ENTSO-E dataset, 22 | there presence has been derived from the different voltages from 23 | connected lines. 24 | + The connection between generators and busses is derived as the 25 | geographically nearest station at the lowest voltage level. This 26 | information is again not present in the ENTSO-E dataset. 27 | 28 | All users are advised to exercise caution in the use of this 29 | dataset. No liability is taken for inaccuracies. 30 | 31 | 32 | 33 | ## Contents of dataset 34 | 35 | This dataset is provided as set of CSV files that describe the ENTSO-E 36 | network. These files use the comma (`,`) as field separator, single 37 | newlines (`\n`) as record separator, and single quotes (`'`) as string 38 | quote characters. The CSV files have headers. 39 | 40 | Example code for reading the files: 41 | 42 | # R 43 | buses <- read.csv("buses.csv", header=TRUE, quote="'") 44 | # python 45 | import io, csv 46 | class dialect(csv.excel): 47 | quotechar = "'" 48 | with io.open('buses.csv', 'rb') as handle: 49 | buses = list(csv.DictReader(handle, dialect)) 50 | 51 | ### buses.csv: 52 | 53 | Describes terminals, vertices, or 'nodes' of the system 54 | 55 | + `bus_id`: the unique identifier for the bus 56 | + `station_id`: the substation or plant of this; a station may have 57 | multiple buses, which are typically connected by transformers 58 | + `voltage`: the operating voltage of this bus 59 | + `dc`: boolean ('t' or 'f'), describes whether the bus is a HVDC 60 | terminal (t) or a regular AC terminal (f) 61 | + `symbol`: type of station of this bus. 62 | + `tags`: _hstore_ encoded dictionary of 'extra' properties for this bus 63 | + `under_construction`: boolean ('t' if station is currently under 64 | construction, 'f' otherwise) 65 | + `geometry`: location of the station in well-known-text format (WGS84) 66 | 67 | **NOTA BENE**: During the processing of the network, so called 68 | 'synthetic' stations may be inserted on locations where lines are 69 | apparantly connected. Such synthetic stations can be recognised 70 | because their symbol is always `joint`. 71 | 72 | ### links.csv: 73 | 74 | Connections between buses: 75 | 76 | + `link_id`: unique identifier for the link 77 | + `src_bus_id`: first of the two connected buses 78 | + `dst_bus_id`: second of two connected buses 79 | + `voltage`: operating voltage of the link (_must_ be identical to 80 | operating voltage of the buses) 81 | + `circuits`: number of (independent) circuits in this link, each of 82 | which typically has 3 cables (for AC lines). 83 | + `dc`: boolean, `t` if this is a HVDC line 84 | + `underground`: boolean, `t` if this is an underground cable, `f` for 85 | an overhead line 86 | + `under_construction`: boolean, `t` for lines that are currently 87 | under construction 88 | + `length_m`: length of line in meters 89 | + `tags`: _hstore_ encoded dictionary of extra properties for this link 90 | + `geometry`: extent of this line in well-known-text format (WGS84) 91 | 92 | ### generators.csv 93 | 94 | Generators attached to the network. 95 | 96 | + `generator_id`: unique identifier for the generator 97 | + `bus_id`: the bus to which this generator is connected 98 | + `symbol`: type of generator 99 | + `capacity`: capacity of this generator (in megawatt) 100 | + `tags`: _hstore_ encoded dictionary of extra attributes 101 | + `geometry`: location of generator in well-known text format (WGS84) 102 | 103 | ### transformers.csv 104 | 105 | A transformer forms a link between buses which operate at distinct 106 | voltages. **NOTA BENE**: Transformers _never_ originate from the 107 | original dataset, and transformers are _only_ infered in 'real' 108 | stations, never in synthetic ('joint') stations. 109 | 110 | + `transformer_id`: unique identifier 111 | + `symbol`: either `transformer` for AC-to-AC voltage transformers, or 112 | `ac/dc` for AC-to-DC converters. 113 | + `src_bus_id`: first of the connected buses 114 | + `dst_bus_id`: second of connected buses 115 | + `src_voltage`: voltage of first bus 116 | + `dst_voltage`: voltage of second bus 117 | + `src_dc`: boolean, `t` if first bus is a DC terminal 118 | + `dst_dc`: boolean, `f` if second bus is a DC terminal 119 | + `geometry`: location of station of this transformer in well-known 120 | text format (WGS84) 121 | -------------------------------------------------------------------------------- /src/topology-4-redundant-joints.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop table if exists redundant_joints; 3 | drop table if exists joint_edge_pair; 4 | drop table if exists joint_edge_set; 5 | drop table if exists joint_merged_edges; 6 | drop table if exists joint_cyclic_edges; 7 | 8 | create table redundant_joints ( 9 | joint_id integer, 10 | line_id integer array, 11 | station_id integer array, 12 | primary key (joint_id) 13 | ); 14 | 15 | create table joint_edge_pair ( 16 | joint_id integer, 17 | left_id integer, 18 | right_id integer 19 | ); 20 | 21 | create table joint_edge_set ( 22 | v integer primary key, 23 | k integer not null, 24 | s integer array[2], -- stations 25 | e geometry(linestring, 3857) 26 | ); 27 | create index joint_edge_set_k on joint_edge_set (k); 28 | 29 | create table joint_merged_edges ( 30 | new_id integer, 31 | extent geometry(linestring, 3857), 32 | -- exterior stations, not internal joints 33 | station_id integer array[2], 34 | old_id integer array 35 | ); 36 | 37 | create table joint_cyclic_edges ( 38 | extent geometry(linestring, 3857), 39 | line_id integer array 40 | ); 41 | 42 | create index joint_merged_edges_old_id on joint_merged_edges using gin(old_id); 43 | 44 | insert into redundant_joints (joint_id, line_id, station_id) 45 | select joint_id, array_agg(line_id), array_agg(distinct station_id) from ( 46 | select n.station_id, e.line_id, unnest(e.station_id) 47 | from topology_nodes n 48 | join topology_edges e on e.line_id = any(n.line_id) 49 | where n.topology_name = 'joint' 50 | ) f (joint_id, line_id, station_id) 51 | where joint_id != station_id 52 | group by joint_id having count(distinct station_id) <= 2; 53 | 54 | -- create pairs out of simple joints 55 | insert into joint_edge_pair (joint_id, left_id, right_id) 56 | select joint_id, least(line_id[1], line_id[2]), greatest(line_id[1], line_id[2]) 57 | from redundant_joints 58 | where array_length(station_id, 1) = 2 and array_length(line_id, 1) = 2; 59 | 60 | insert into joint_edge_set (k, v, e, s) 61 | select line_id, line_id, line_extent, station_id from topology_edges e 62 | where line_id in ( 63 | select left_id from joint_edge_pair 64 | union all 65 | select right_id from joint_edge_pair 66 | ); 67 | 68 | 69 | do $$ 70 | declare 71 | p joint_edge_pair; 72 | l joint_edge_set; 73 | r joint_edge_set; 74 | begin 75 | for p in select * from joint_edge_pair loop 76 | select * into l from joint_edge_set where v = p.left_id; 77 | select * into r from joint_edge_set where v = p.right_id; 78 | if l.k != r.k then 79 | update joint_edge_set set k = l.k where k = r.k; 80 | update joint_edge_set 81 | set e = connect_lines(l.e, r.e), 82 | s = array_sym_diff(l.s, r.s) 83 | where k = l.k; 84 | end if; 85 | end loop; 86 | end; 87 | $$ language plpgsql; 88 | 89 | insert into joint_merged_edges (new_id, extent, station_id, old_id) 90 | select nextval('line_id'), e, s, g.v 91 | from joint_edge_set s join ( 92 | select k, array_agg(v) from joint_edge_set group by k having count(*) > 1 93 | ) g(k,v) on s.v = g.k where array_length(s,1) is not null; 94 | 95 | insert into joint_cyclic_edges (extent, line_id) 96 | select e, array_agg(v) 97 | from joint_edge_set e 98 | where array_length(s,1) is null 99 | group by k,e; 100 | 101 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 102 | select new_id, 'l', 'join', old_id, 'l' 103 | from joint_merged_edges; 104 | 105 | insert into topology_edges (line_id, station_id, line_extent) 106 | select new_id, e.station_id, extent 107 | from joint_merged_edges e 108 | join topology_nodes a on a.station_id = e.station_id[1] 109 | join topology_nodes b on b.station_id = e.station_id[2]; 110 | 111 | 112 | update topology_nodes n set line_id = array_replace(n.line_id, r.old_id, r.new_id) 113 | from ( 114 | select station_id, array_agg(distinct old_id), array_agg(distinct new_id) from ( 115 | select station_id[1], unnest(old_id), new_id from joint_merged_edges 116 | union 117 | select station_id[2], unnest(old_id), new_id from joint_merged_edges 118 | ) f (station_id, old_id, new_id) group by station_id 119 | ) r (station_id, old_id, new_id) where n.station_id = r.station_id; 120 | 121 | 122 | with removed_cyclic_edges(station_id, line_id) as ( 123 | select station_id, array_agg(line_id) from ( 124 | select line_id, unnest(station_id) from topology_edges e where line_id in ( 125 | select unnest(line_id) from joint_cyclic_edges 126 | ) 127 | ) e (line_id, station_id) 128 | where not exists ( 129 | select 1 from joint_edge_pair p where p.joint_id = e.station_id 130 | ) 131 | group by station_id 132 | ) update topology_nodes n set line_id = array_remove(n.line_id, c.line_id) 133 | from removed_cyclic_edges c where c.station_id = n.station_id; 134 | 135 | delete from topology_nodes where station_id in ( 136 | select joint_id from joint_edge_pair 137 | ); 138 | 139 | delete from topology_nodes where array_length(line_id, 1) is null; 140 | 141 | delete from topology_edges where line_id in ( 142 | select unnest(old_id) from joint_merged_edges 143 | union all 144 | select unnest(line_id) from joint_cyclic_edges 145 | ); 146 | 147 | commit; 148 | -------------------------------------------------------------------------------- /entsoe/electric-properties.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | -- this replaces the 'electric' series in the OSM directory, primarily 3 | -- because the situation for ENTSO-E is drastically simpler 4 | drop function if exists derive_line_structure(integer); 5 | drop function if exists join_line_structure(integer, integer array); 6 | drop function if exists merge_line_structure(integer, integer array); 7 | drop function if exists derive_station_properties(integer); 8 | drop function if exists merge_station_properties(integer, integer array); 9 | drop table if exists station_properties; 10 | drop table if exists line_structure_conflicts; 11 | drop table if exists line_structure; 12 | 13 | 14 | create table station_properties ( 15 | station_id integer primary key, 16 | symbol text, 17 | name text, 18 | under_construction boolean, 19 | tags hstore 20 | ); 21 | 22 | create table line_structure ( 23 | line_id integer primary key, 24 | voltage integer, 25 | circuits integer, 26 | dc_line boolean, 27 | underground boolean, 28 | under_construction boolean, 29 | tags hstore 30 | ); 31 | 32 | create table line_structure_conflicts ( 33 | line_id integer not null, 34 | conflicts line_structure array 35 | ); 36 | 37 | insert into station_properties (station_id, symbol, name, under_construction, tags) 38 | select power_id, properties->'symbol', properties->'name_all', (properties->'under_construction')::boolean, 39 | properties - array['symbol','name_all','under_construction'] 40 | from feature_points f 41 | join source_objects o on o.import_id = f.import_id and o.power_type = 's'; 42 | 43 | insert into line_structure (line_id, voltage, circuits, under_construction, underground, dc_line, tags) 44 | select power_id, 45 | substring(properties->'voltagelevel' from '^[0-9]+')::int, 46 | (properties->'numberofcircuits')::int, 47 | (properties->'underconstruction')::boolean, 48 | (properties->'underground')::boolean, 49 | (properties->'current' = 'DC'), 50 | properties - array['voltagelevel','numberofcircuits','shape_length','underconstruction','underground','current'] 51 | from feature_lines f 52 | join source_objects o on o.import_id = f.import_id and o.power_type = 'l'; 53 | 54 | create function derive_line_structure (i integer) returns line_structure as $$ 55 | declare 56 | s line_structure; 57 | d derived_objects; 58 | begin 59 | select * into s from line_structure where line_id = i; 60 | if (s).line_id is not null 61 | then 62 | return s; 63 | end if; 64 | 65 | select * into d from derived_objects where derived_id = i and derived_type = 'l'; 66 | if d is null 67 | then 68 | raise exception 'Cannot find derived objects for line_id %', i; 69 | elsif d.operation = 'split' then 70 | s = derive_line_structure(d.source_id[1]); 71 | elsif d.operation = 'join' then 72 | s = join_line_structure(d.derived_id, d.source_id); 73 | elsif d.operation = 'merge' then 74 | s = merge_line_structure(d.derived_id, d.source_id); 75 | end if; 76 | 77 | -- memoize the computed line structure 78 | insert into line_structure (line_id, voltage, circuits, dc_line, underground, under_construction) 79 | select i, (s).voltage, (s).circuits, (s).dc_line, (s).underground, (s).under_construction; 80 | return s; 81 | end; 82 | $$ language plpgsql; 83 | 84 | create function join_line_structure (i integer, j integer array) returns line_structure as $$ 85 | declare 86 | s line_structure array; 87 | c integer; 88 | begin 89 | s = array(select derive_line_structure(l_id) from unnest(j) f(l_id)); 90 | c = greatest(count(distinct (e).voltage), count(distinct (e).circuits), count(distinct (e).dc_line), count(distinct (e).underground)) 91 | from unnest(s) e; 92 | if c > 1 93 | then 94 | insert into line_structure_conflicts (line_id, conflicts) values (i, s); 95 | end if; 96 | return row(i, (s[1]).voltage, (s[1]).circuits, (s[1]).dc_line, 97 | (s[1]).underground, (s[1]).under_construction, 98 | (s[1]).tags); -- TODO merge tags 99 | end 100 | $$ language plpgsql; 101 | 102 | create function merge_line_structure (i integer, j integer array) returns line_structure as $$ 103 | begin 104 | -- this causes some problems, may want to reconsider the spatial-first strategy 105 | return join_line_structure(i, j); 106 | end; 107 | $$ language plpgsql; 108 | 109 | create function derive_station_properties(i integer) returns station_properties as $$ 110 | declare 111 | p station_properties; 112 | d derived_objects; 113 | begin 114 | select * into p from station_properties where station_id = i; 115 | if (p).station_id is not null 116 | then 117 | return p; 118 | end if; 119 | select * into d from derived_objects where derived_id = i and derived_type = 's'; 120 | if d is null 121 | then 122 | raise exception 'Cannot find derived objects for station_id %', i; 123 | elsif (d).operation = 'merge' 124 | then 125 | p = merge_station_properties(i, d.source_id); 126 | end if; 127 | insert into station_properties (station_id, symbol, name, under_construction, tags) 128 | select i, (p).symbol, (p).name, (p).under_construction, (p).tags; 129 | return p; 130 | end; 131 | $$ language plpgsql; 132 | 133 | create function merge_station_properties(i integer, m integer array) returns station_properties as $$ 134 | begin 135 | -- very noppy implementation 136 | return derive_station_properties(s_id) from unnest(m) s_id limit 1; 137 | end 138 | $$ language plpgsql; 139 | 140 | do $$ 141 | begin 142 | perform derive_line_structure(line_id) from topology_edges e 143 | where not exists (select 1 from line_structure l where l.line_id = e.line_id); 144 | perform derive_station_properties(station_id) from topology_nodes n 145 | where topology_name != 'joint' 146 | and not exists (select 1 from station_properties s where s.station_id = n.station_id); 147 | end 148 | $$ language plpgsql; 149 | commit; 150 | -------------------------------------------------------------------------------- /entsoe/abstraction.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop sequence if exists network_bus_id; 3 | drop table if exists station_transformer; 4 | drop table if exists station_terminal; 5 | 6 | drop table if exists network_link; 7 | drop table if exists network_transformer; 8 | drop table if exists network_generator; 9 | drop table if exists network_bus; 10 | 11 | -- split stations into busses 12 | -- insert transformers 13 | -- export to text format 14 | create table station_terminal ( 15 | station_id integer not null, 16 | voltage integer null, 17 | dc boolean not null, 18 | network_bus_id integer primary key 19 | ); 20 | 21 | create index station_terminal_idx on station_terminal (station_id, voltage, dc); 22 | 23 | create table station_transformer ( 24 | transformer_id integer primary key, 25 | station_id integer, 26 | src_bus_id integer references station_terminal (network_bus_id), 27 | dst_bus_id integer references station_terminal (network_bus_id), 28 | src_voltage integer, 29 | dst_voltage integer, 30 | src_dc boolean, 31 | dst_dc boolean 32 | ); 33 | 34 | create sequence network_bus_id; 35 | 36 | with connected_line_structures as ( 37 | select distinct station_id, voltage, dc_line 38 | from topology_nodes n 39 | join line_structure l on l.line_id = any(n.line_id) 40 | order by station_id, voltage 41 | ) 42 | insert into station_terminal (station_id, voltage, dc, network_bus_id) 43 | select station_id, voltage, dc_line, nextval('network_bus_id') 44 | from connected_line_structures; 45 | 46 | with terminal_bridges (station_id, src_bus_id, dst_bus_id, src_voltage, dst_voltage, src_dc, dst_dc) as ( 47 | select distinct s.station_id, s.network_bus_id, d.network_bus_id, s.voltage, d.voltage, s.dc, d.dc 48 | from station_terminal s 49 | join station_terminal d on s.station_id = d.station_id and s.network_bus_id < d.network_bus_id 50 | join topology_nodes n on s.station_id = n.station_id 51 | where n.topology_name != 'joint' 52 | ) 53 | insert into station_transformer (transformer_id, station_id, src_bus_id, dst_bus_id, src_voltage, dst_voltage, src_dc, dst_dc) 54 | select nextval('line_id'), station_id, 55 | src_bus_id, dst_bus_id, 56 | src_voltage, dst_voltage, 57 | src_dc, dst_dc 58 | from terminal_bridges b; 59 | 60 | 61 | -- exported entities 62 | create table network_bus ( 63 | bus_id integer primary key, 64 | station_id integer, 65 | voltage integer, 66 | dc boolean, 67 | symbol text, 68 | under_construction boolean, 69 | tags hstore, 70 | geometry text 71 | ); 72 | 73 | create table network_link ( 74 | link_id integer primary key, 75 | src_bus_id integer references network_bus (bus_id), 76 | dst_bus_id integer references network_bus (bus_id), 77 | voltage integer, 78 | circuits integer not null, 79 | dc boolean not null, 80 | underground boolean not null, 81 | under_construction boolean not null, 82 | length_m numeric, 83 | tags hstore, 84 | geometry text 85 | ); 86 | 87 | create table network_generator ( 88 | generator_id integer primary key, 89 | bus_id integer not null references network_bus(bus_id), 90 | symbol text, 91 | capacity numeric, 92 | tags hstore, 93 | geometry text 94 | ); 95 | 96 | create table network_transformer ( 97 | transformer_id integer primary key, 98 | symbol text, 99 | src_bus_id integer references network_bus(bus_id), 100 | dst_bus_id integer references network_bus(bus_id), 101 | src_voltage integer, 102 | dst_voltage integer, 103 | src_dc boolean, 104 | dst_dc boolean, 105 | geometry text 106 | ); 107 | 108 | insert into network_bus (bus_id, station_id, voltage, dc, symbol, under_construction, tags, geometry) 109 | select t.network_bus_id, t.station_id, t.voltage, t.dc, n.topology_name, p.under_construction, 110 | p.tags, st_astext(st_transform(n.station_location, 4326)) 111 | from topology_nodes n 112 | join station_terminal t on t.station_id = n.station_id 113 | left join station_properties p on p.station_id = n.station_id; 114 | 115 | insert into network_link (link_id, src_bus_id, dst_bus_id, voltage, circuits, dc, underground, under_construction, length_m, tags, geometry) 116 | select e.line_id, s.network_bus_id, d.network_bus_id, 117 | l.voltage, l.circuits, l.dc_line, l.underground, l.under_construction, 118 | st_length(st_transform(e.line_extent, 4326)::geography), l.tags, 119 | st_astext(st_transform(e.line_extent, 4326)) 120 | from topology_edges e 121 | join line_structure l on l.line_id = e.line_id 122 | join station_terminal s on s.station_id = e.station_id[1] 123 | and (s.voltage = l.voltage or s.voltage is null and l.voltage is null) 124 | and s.dc = l.dc_line 125 | join station_terminal d on d.station_id = e.station_id[2] 126 | and (d.voltage = l.voltage or s.voltage is null 127 | and l.voltage is null) and d.dc = l.dc_line; 128 | 129 | insert into network_generator (generator_id, bus_id, symbol, capacity, tags, geometry) 130 | select g.generator_id, 131 | (select network_bus_id from station_terminal t 132 | where g.station_id = t.station_id order by voltage asc limit 1), 133 | p.tags->'symbol', (p.tags->'mw')::numeric, p.tags - array['symbol','mw'], 134 | st_astext(st_transform(p.location, 4326)) 135 | from topology_generators g 136 | join power_generator p on p.generator_id = g.generator_id; 137 | 138 | insert into network_transformer (transformer_id, symbol, src_bus_id, dst_bus_id, src_voltage, dst_voltage, src_dc, dst_dc, geometry) 139 | select t.transformer_id, 140 | case when t.src_dc = t.dst_dc then 'transformer' else 'ac/dc' end, 141 | t.src_bus_id, t.dst_bus_id, t.src_voltage, t.dst_voltage, t.src_dc, t.dst_dc, 142 | st_astext(st_transform(n.station_location, 4326)) 143 | from station_transformer t 144 | join topology_nodes n 145 | on t.station_id = n.station_id; 146 | 147 | commit; 148 | -------------------------------------------------------------------------------- /src/spatial-3-attachment-joints.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | -- Get attachment points, split lines, insert stations for attachment points 3 | drop table if exists line_attachments; 4 | drop table if exists attachment_joints; 5 | drop table if exists attachment_split_lines; 6 | drop table if exists attached_lines; 7 | 8 | create table line_attachments ( 9 | extent_id integer not null, 10 | attach_id integer not null, 11 | extent geometry(linestring, 3857), 12 | terminal geometry(point, 3857), 13 | attachment geometry(point, 3857) 14 | ); 15 | 16 | create table attachment_joints ( 17 | station_id integer not null, 18 | line_id integer array, 19 | location geometry(point, 3857) 20 | ); 21 | 22 | create table attachment_split_lines ( 23 | new_id integer primary key, 24 | old_id integer not null, 25 | extent geometry(linestring, 3857), 26 | attachments geometry(multipolygon, 3857) 27 | ); 28 | 29 | create table attached_lines ( 30 | line_id integer primary key, 31 | old_extent geometry(linestring, 3857), 32 | new_extent geometry(linestring, 3857), 33 | terminals geometry(multipoint, 3857), 34 | attachments geometry(multipoint, 3857) 35 | ); 36 | 37 | create index attachment_joints_location on attachment_joints using gist (location); 38 | 39 | -- startpoint attachments 40 | insert into line_attachments (extent_id, attach_id, extent, terminal, attachment) 41 | select distinct on (b.line_id) a.line_id, b.line_id, a.extent, st_startpoint(b.extent), st_closestpoint(a.extent, st_startpoint(b.extent)) 42 | from power_line a 43 | join power_line b on st_dwithin(a.extent, st_startpoint(b.extent), b.radius[1]) 44 | and not (st_dwithin(st_startpoint(a.extent), st_startpoint(b.extent), b.radius[1]) 45 | or st_dwithin(st_endpoint(a.extent), st_startpoint(b.extent), b.radius[1])) 46 | and not exists (select 1 from power_station s where st_dwithin(s.area, st_startpoint(b.extent), b.radius[1])) 47 | order by b.line_id, st_distance(a.extent, st_startpoint(b.extent)) asc; 48 | 49 | -- endpoint attachments 50 | insert into line_attachments (extent_id, attach_id, extent, terminal, attachment) 51 | select distinct on (b.line_id) a.line_id, b.line_id, a.extent, st_endpoint(b.extent), st_closestpoint(a.extent, st_endpoint(b.extent)) 52 | from power_line a 53 | join power_line b on st_dwithin(a.extent, st_endpoint(b.extent), b.radius[2]) 54 | and not (st_dwithin(st_startpoint(a.extent), st_endpoint(b.extent), b.radius[2]) 55 | or st_dwithin(st_endpoint(a.extent), st_endpoint(b.extent), b.radius[2])) 56 | and not exists (select 1 from power_station s where st_dwithin(s.area, st_endpoint(b.extent), b.radius[2])) 57 | order by b.line_id, st_distance(a.extent, st_endpoint(b.extent)) asc; 58 | 59 | -- Create segments for the split line 60 | insert into attachment_split_lines (new_id, old_id, extent, attachments) 61 | select nextval('line_id'), extent_id, (st_dump(st_difference(extent, attachments))).geom, attachments from ( 62 | select extent_id, extent, st_multi(st_buffer(st_union(attachment), 1)) 63 | from line_attachments group by extent_id, extent 64 | ) f (extent_id, extent, attachments) 65 | where st_numgeometries(st_difference(extent, attachments)) > 1; 66 | 67 | 68 | -- Create a station for each attachment point 69 | insert into attachment_joints (station_id, line_id, location) 70 | select nextval('station_id'), array[extent_id, attach_id], attachment 71 | from line_attachments; 72 | 73 | -- Remove duplicates 74 | delete from attachment_joints where station_id in ( 75 | select greatest(a.station_id, b.station_id) from attachment_joints a, attachment_joints b 76 | where a.station_id != b.station_id and st_dwithin(a.location, b.location, 1) 77 | ); 78 | 79 | -- Compute which lines to extend to attach to the power lines 80 | insert into attached_lines (line_id, old_extent, new_extent, terminals, attachments) 81 | select a.attach_id, l.extent, l.extent, a.terminals, a.attachments 82 | from ( 83 | select attach_id, st_multi(st_union(terminal)), st_multi(st_union(attachment)) 84 | from line_attachments group by attach_id 85 | ) a (attach_id, terminals, attachments) 86 | join power_line l on a.attach_id = l.line_id; 87 | 88 | -- Extend the attached lines to connect cleanly with the attachment station. 89 | update attached_lines 90 | set new_extent = st_addpoint(new_extent, st_closestpoint(attachments, st_startpoint(new_extent)), 0) 91 | where st_contains(terminals, st_startpoint(old_extent)) 92 | and not st_dwithin(attachments, st_startpoint(old_extent), 1); 93 | 94 | update attached_lines 95 | set new_extent = st_addpoint(new_extent, st_closestpoint(attachments, st_endpoint(new_extent)), -1) 96 | where st_contains(terminals, st_endpoint(old_extent)) 97 | and not st_dwithin(attachments, st_endpoint(old_extent), 1); 98 | 99 | 100 | -- insert joints 101 | insert into power_station (station_id, power_name, area) 102 | select station_id, 'joint', st_buffer(location, 1) 103 | from attachment_joints; 104 | 105 | 106 | 107 | -- replace power lines 108 | insert into power_line (line_id, power_name, extent, radius) 109 | select s.new_id, l.power_name, s.extent, 110 | minimal_radius(s.extent, s.attachments, l.radius) 111 | from attachment_split_lines s 112 | join power_line l on l.line_id = s.old_id; 113 | 114 | 115 | delete from power_line l where exists ( 116 | select 1 from attachment_split_lines s where l.line_id = s.old_id 117 | ); 118 | 119 | -- update extended lengths 120 | update power_line l 121 | set extent = a.new_extent, radius = minimal_radius(a.new_extent, a.attachments, l.radius) 122 | from attached_lines a 123 | where a.line_id = l.line_id; 124 | 125 | 126 | -- track new lines 127 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 128 | select new_id, 'l', 'split', array[old_id], 'l' 129 | from attachment_split_lines; 130 | 131 | -- and stations 132 | insert into derived_objects (derived_id, derived_type, operation, source_id, source_type) 133 | select station_id, 's', 'merge', line_id, 'l' 134 | from attachment_joints; 135 | 136 | commit; 137 | -------------------------------------------------------------------------------- /util/geometry.py: -------------------------------------------------------------------------------- 1 | from __future__ import print_function, division 2 | import collections 3 | 4 | 5 | def cross_vertical(line_d, line_v): 6 | pt_d1, pt_d2 = line_d 7 | pt_v1, pt_v2 = line_v 8 | x_d1, y_d1 = pt_d1 9 | x_d2, y_d2 = pt_d2 10 | 11 | dy_d = y_d2 - y_d1 12 | dx_d = x_d2 - x_d1 13 | if dx_d == 0: 14 | # parallel (vertical) line 15 | return None 16 | slope_d = dy_d / dx_d 17 | intercept_d = y_d1 - slope_d * x_d1 18 | 19 | x_v, y_v1 = pt_v1 20 | x_v, y_v2 = pt_v2 21 | if x_v < min(x_d1, x_d2) or x_v > max(x_d1, x_d2): 22 | return None 23 | 24 | y_meet = slope_d * x_v + intercept_d 25 | if min(y_v1, y_v2) <= y_meet <= max(y_v1, y_v2): 26 | return x_v, y_meet 27 | return None 28 | 29 | def cross_line(line_a, line_b): 30 | pt_a1, pt_a2 = line_a 31 | pt_b1, pt_b2 = line_b 32 | x_a1, y_a1 = pt_a1 33 | x_a2, y_a2 = pt_a2 34 | x_b1, y_b1 = pt_b1 35 | x_b2, y_b2 = pt_b2 36 | 37 | dy_a = y_a2 - y_a1 38 | dx_a = x_a2 - x_a1 39 | dy_b = y_b2 - y_b1 40 | dx_b = x_b2 - x_b1 41 | 42 | if dx_a == 0: 43 | return cross_vertical(line_b, line_a) 44 | if dx_b == 0: 45 | return cross_vertical(line_a, line_b) 46 | 47 | slope_a = dy_a / dx_a 48 | slope_b = dy_b / dx_b 49 | intercept_a = y_a1 - slope_a * x_a1 50 | intercept_b = y_b1 - slope_b * x_b1 51 | if slope_a == slope_b: 52 | # parallel lines, never meet 53 | return None 54 | x_meet = (intercept_b - intercept_a) / (slope_a - slope_b) 55 | y_meet = slope_a * x_meet + intercept_a 56 | if max(min(x_a1, x_a2), min(x_b1, x_b2)) <= x_meet <= min(max(x_a1, x_a2), max(x_b1, x_b2)): 57 | return x_meet, y_meet 58 | return None 59 | 60 | def edges(polygon): 61 | for i in range(1, len(polygon)): 62 | yield polygon[i-1], polygon[i] 63 | if polygon[0] != polygon[-1]: 64 | yield polygon[-1], polygon[0] 65 | 66 | 67 | 68 | def polygon_includes(polygon, point): 69 | x, y = zip(*polygon) 70 | line_left = ((min(x), point[1]), (point[0], point[1])) 71 | line_right = ((point[0], point[1]), (max(x), point[1])) 72 | # The set is necessary to eliminate duplicate points, which happens 73 | # when a node is crossed exactly, in which case the line crosses 74 | # two edges rather than one 75 | cross_left = set(cross_line(line_left, edge) 76 | for edge in edges(polygon)) - {None} 77 | cross_right = set(cross_line(line_right, edge) 78 | 79 | for edge in edges(polygon)) - {None} 80 | return (len(cross_left) & 1) == 1 and (len(cross_right) & 1) == 1 81 | 82 | 83 | class Edges(object): 84 | def __init__(self, points): 85 | self.points = points 86 | 87 | def __getitem__(self, idx): 88 | if 0 <= idx < len(self.points) - 1: 89 | return self.points[idx], self.points[idx+1] 90 | elif idx == len(self.points) - 1: 91 | return self.points[idx], self.points[0] 92 | elif -len(self.points) < idx < 0: 93 | return self[idx+len(self.points)] 94 | else: 95 | raise IndexError("%s not in %s" % (idx, len(self.points))) 96 | 97 | def __iter__(self): 98 | for i in range(len(self.points)): 99 | yield self[i] 100 | 101 | 102 | class IntervalTree(object): 103 | Node = collections.namedtuple('Node', ['left','right','interval','value']) 104 | 105 | def __init__(self, intervals): 106 | # first, transform of a,b into min(a,b),max(a,b), i sorted 107 | prepared = sorted((min(x1,x2),max(x1,x2), i) for (i, (x1, x2)) in enumerate(intervals)) 108 | # then recursively build a tree 109 | self.root = self._build_tree(prepared, 0, len(prepared)) 110 | 111 | def _build_tree(self, sorted_intervals, left, right): 112 | if left == right or left + 1 == right: 113 | # leaf node 114 | return self.Node(None, None, sorted_intervals[left][0:2], sorted_intervals[left][2]) 115 | else: 116 | mid = (left + right) // 2 117 | left_node = self._build_tree(sorted_intervals, left, mid) 118 | right_node = self._build_tree(sorted_intervals, mid, right) 119 | interval = left_node.interval[0], max(left_node.interval[1], right_node.interval[1]) 120 | # interior node 121 | return self.Node(left_node, right_node, interval, None) 122 | 123 | def _query_tree(self, node, x): 124 | min_x, max_x = node.interval 125 | results = [] 126 | if min_x > x or max_x < x: 127 | return results 128 | if node.left is not None: 129 | results.extend(self._query_tree(node.left, x)) 130 | if node.right is not None: 131 | results.extend(self._query_tree(node.right, x)) 132 | if node.value is not None: 133 | results.append(node.value) 134 | return results 135 | 136 | def __getitem__(self, x): 137 | return self._query_tree(self.root, x) 138 | 139 | 140 | class Polygon(object): 141 | def __init__(self, points): 142 | self.points = points 143 | self.edges = Edges(points) 144 | # build vertical extent tree for efficient point-in-polygon query 145 | verticals = ((y1, y2) for ((x1,y1), (x2, y2)) in self.edges) 146 | self.vertical_intervals = IntervalTree(verticals) 147 | 148 | def __len__(self): 149 | return len(self.points) 150 | 151 | def __iter__(self): 152 | return iter(self.points) 153 | 154 | def __contains__(self, point): 155 | x, y = point 156 | left, right = 0, 0 157 | # don't have min/max handy, so this will have to do 158 | horizontal = ((-180, y), (180, y)) 159 | # a horizontal line at y crosses the edges given by the idxs 160 | cross_pts = set() 161 | cross_left, cross_right = 0, 0 162 | # check if they cross an odd number of times on right and left sides 163 | for i in self.vertical_intervals[y]: 164 | cross_x, cross_y = cross_line(horizontal, self.edges[i]) 165 | if cross_x in cross_pts: 166 | continue 167 | cross_pts.add(cross_x) 168 | if cross_x < x: 169 | cross_left += 1 170 | else: 171 | cross_right += 1 172 | if cross_left & 1 == 1 and cross_right & 1 == 1: 173 | return True 174 | return False 175 | 176 | def to_wkt(self): 177 | return 'POLYGON(({0}))'.format(','.join('{0} {1}'.format(x, y) for (x,y) in self.points)) 178 | 179 | 180 | if __name__ == '__main__': 181 | line_a = ((1,1), (3,4)) 182 | line_b = ((1,3), (3,2)) 183 | line_c = ((1,6), (3,5)) 184 | line_v = ((2, 0), (2, 4)) 185 | 186 | assert cross_line(line_a, line_b) == (2.0, 2.5) 187 | assert cross_line(reversed(line_a), line_b) == (2.0, 2.5) 188 | assert cross_line(line_v, line_b) == (2.0, 2.5) 189 | assert cross_line(line_b, line_c) is None 190 | 191 | square = ((0,0), (0,5), 192 | (5,5), (5,0)) 193 | point = (2,2) 194 | assert polygon_includes(square, point) 195 | assert not polygon_includes(square, (7, 2)) 196 | 197 | pentagon = ((1,0), (0, 2), (2, 3), (4,2), (3,0)) 198 | assert polygon_includes(pentagon, (2, 2)) 199 | assert not polygon_includes(pentagon, (1,3)) 200 | print("done") 201 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Code (v1.0): [![DOI](https://zenodo.org/badge/20808/bdw/GridKit.svg)](https://zenodo.org/badge/latestdoi/20808/bdw/GridKit) 2 | 3 | ENTSO-E extract: [![DOI](https://zenodo.org/badge/doi/10.5281/zenodo.55853.svg)](http://dx.doi.org/10.5281/zenodo.55853) 4 | 5 | 6 | # GridKit is a power grid extraction toolkit 7 | 8 | GridKit uses spatial and topological analysis to transform map objects 9 | from OpenStreetMap into a network model of the electric power 10 | system. It has been developed in the context of the 11 | [SciGRID](http://scigrid.de) project at the 12 | [Next Energy](http://www.next-energy.de/) research institute, to 13 | investigate the possibility of 'heuristic' analysis to augment the 14 | route-based analysis used in SciGRID. This has been implemented as a 15 | series of scripts for the PostgreSQL database using the PostGIS 16 | spatial extensions. 17 | 18 | The network model is intended to be used in power systems analysis 19 | applications, for example using the 20 | [PYPOWER](https://rwl.github.io/PYPOWER) system, or the 21 | [PyPSA](https://github.com/FRESNA/PyPSA) toolkit. In general this will 22 | require the following: 23 | 24 | * Careful interpretation of results (e.g. power lines and stations may 25 | have multiple voltages). 26 | * Realistic information on generation and load in the system 27 | (electrical supply and demand). 28 | * Reasonable, possibly location specific assumptions on the impedance 29 | of lines, depending on their internal structure. Unlike SciGRID, 30 | *such assumptions have not yet been applied*. 31 | 32 | Of note, PyPSA implements several methods of network simplification, 33 | which is in many cases essential for ensuring that the power flow 34 | computations remain managable. 35 | 36 | ## Data exports 37 | 38 | Data exports created at March 14, 2016 for North America and Europe 39 | can be downloaded from 40 | [zenodo](https://zenodo.org/record/47317). These exports are licensed 41 | under the Open Database License because they derive from OpenStreetMap 42 | data. They follow the same file structure as [SciGRID](http://scigrid.de/). 43 | The file `util/network.py` contains a parser for these files. 44 | 45 | ## Requirements 46 | 47 | * Python (2.7 or higher) 48 | * PostgreSQL (9.4 or higher) 49 | * PostGIS (2.1 or higher) 50 | * osm2pgsql (0.88.1 or higher) 51 | * Optionally psycopg2 (2.6 or higher) 52 | * Optionally [osm-c-tools](https://gitlab.com/osm-c-tools/osmctools) 53 | 54 | 55 | ## How to Use (the simple way) 56 | 57 | Download a power extract from enipedia: 58 | 59 | wget http://enipedia.tudelft.nl/OpenStreetMap/EuropePower.zip 60 | unzip EuropePower.zip 61 | 62 | Ensure you have a user for postgresql with permissions to create 63 | databases and modify schemas. For example: 64 | 65 | createuser -d gridkit 66 | 67 | Run `gridkit.py`: 68 | 69 | python gridkit.py EuropePower.osm 70 | 71 | The `--pg` option takes a series of key=value pairs, which are parsed 72 | into database connection options. For example to connect to a host on 73 | `10.0.0.160` listening on port 9000: 74 | 75 | python gridkit.py --pg host=10.0.0.160 port=9000 EuropePower.osm 76 | 77 | The files `gridkit-highvoltage-vertices.csv` contains a CSV file with 78 | all high-voltage stations, and `gridkit-highvoltage-edges.csv` 79 | contains a CSV file with all high-voltage lines. You may use 80 | `--full-export` to export all other lines, too. 81 | 82 | ## How to Use (the hard way) 83 | 84 | Download a full-planet dump from 85 | [planet.openstreetmap.org](http://planet.openstreetmap.org/pbf/) or a 86 | geographically-bounded extract from 87 | [geofabrik](http://download.geofabrik.de/). 88 | 89 | Extract the power information 90 | 91 | osmconvert my_area.osm.pbf -o=my_area.o5m 92 | osmfilter my_area.o5m --keep='power=*' -o=my_area_power.o5m 93 | 94 | Alternatively for extracting a specific region from the planet file 95 | (my\_area.poly should a 96 | [polygon filter file](http://wiki.openstreetmap.org/wiki/Osmosis/Polygon_Filter_File_Format), 97 | which you can acquire from 98 | [polygons.openstreetmap.fr](http://polygons.openstreetmap.fr)): 99 | 100 | osmconvert planet-latest.osm.pbf -B=my_area.poly -o=my_area.o5m 101 | 102 | ### PostgreSQL configuration 103 | 104 | GridKit assumes that you have the `psql` and `osm2pgsql` binaries 105 | available. Configuring access to the postgresql server is implemented 106 | using standard 107 | [environment variables](http://www.postgresql.org/docs/9.4/static/libpq-envars.html). Thus, 108 | prior to importing the openstreetmap source data, you should use something like: 109 | 110 | export PGUSER=my_username PGDATABASE=my_database PGPASSWORD=my_password 111 | 112 | Optionally also: 113 | 114 | export PGHOST=server_hostname PGPORT=server_port 115 | 116 | For more information, check out the linked documentation. 117 | 118 | ### Extraction process 119 | 120 | Import data using the script: 121 | 122 | ./import-data.sh /path/to/data.o5m database_name 123 | 124 | The `database_name` parameter is optional if the `PGDATABASE` 125 | environment variable has been set. Running the extraction process is just: 126 | 127 | ./run.sh 128 | 129 | You should expect this, depending on your machine and the size of your 130 | dataset, to take anywhere from 5 minutes to a few hours. Afterwards, 131 | you can extract a copy of the network using: 132 | 133 | psql -f export-topology.sql 134 | 135 | Which will copy the network to a set of CSV files in `/tmp`: 136 | 137 | * `/tmp/heuristic_vertices.csv` and `/tmp/heuristic_links.csv` contain 138 | the complete network at all voltage and frequency levels. 139 | 140 | * `/tmp/heuristic_vertices_highvoltage` and 141 | `/tmp/heuristic_links_highvoltage` contain the high-voltage network 142 | (>220kV) at any frequency which is not 16.7Hz. 143 | 144 | 145 | ### Some things to watch out for 146 | 147 | This process requires a lot of memory and significant amounts of CPU 148 | time. It also makes *a lot of copies* of the same data. This is very 149 | useful for investigating issues and tracking changes by the system. It 150 | also means that you should probably not use this on 151 | resource-constrained systems, such as docker containers in constrained 152 | virtual machines or raspberry pi's. 153 | 154 | Queries have been typically optimized to make the best possible use of 155 | indices, but whether they are actually used is sensitive to query 156 | planner specifics. Depending on the specifics, 157 | [PostgreSQL tuning](https://wiki.postgresql.org/wiki/Performance_Optimization) 158 | may be necessary to run the extraction process efficiently. 159 | 160 | The resultant network will in almost all cases be considerably more 161 | complex than equivalent networks (e.g. from SciGRID or the 162 | [Bialek model](http://www.powerworld.com/knowledge-base/updated-and-validated-power-flow-model-of-the-main-continental-european-transmission-network). For 163 | practical applications, it is highly advisable to use simplification. 164 | 165 | 166 | ## Analysis Utilities 167 | 168 | Aside from the main codebase, some utilities have been implemented to 169 | enable analysis of the results. Notably: 170 | 171 | * `util/network.py` allows for some simple analysis of the network, 172 | transformation into a **PYPOWER** powercase dictionary, and 173 | 'patching' of the network to propagate voltage and frequency 174 | information from neighbors. 175 | * `util/load_polyfile.py` transforms a set of `poly` files into import 176 | statements for PostgreSQL, to allow data statistics per area, among 177 | other things. 178 | 179 | 180 | 181 | -------------------------------------------------------------------------------- /doc/log.org: -------------------------------------------------------------------------------- 1 | #+TITLE: GridKit Log 2 | #+OPTIONS: num:nil toc:nil 3 | 4 | * Date: <2016-11-30 Wed> 5 | 6 | I think I have fixed the issue with the broken polygons by making a 7 | separate polygons table and filtering them on validity. I've also made 8 | a separate script to test on invalidity, which now lives in 9 | util/invalid-polygons.sql. 10 | 11 | To distinguish polygon-like open linestrings from linelike open 12 | linestrings, I'm using the heuristic that the distance between the 13 | start and enpoint of the line should be less than (or equal to) the 14 | length of the line divided by two, which is actually quite liberal 15 | since it includes two legs of equidistant triangles as polygons. 16 | 17 | In all of EuropePower.osm, 11 polygons are invalid, and of those, just 18 | 1 actually creates a multipolygon when buffered. In other words, the 19 | underlying data issue is probably common enough, but it rarely 20 | generates an error. And in each of those cases, buffering the line 21 | rather than the created polygon will create a proper polygon. 22 | 23 | * Date: <2016-11-29 Tue> 24 | 25 | I can repeat the issue with the broken multipolygons. 26 | I results from self-intersecting polygons. 27 | Some of these, apparently, are actually... lines. 28 | 29 | Which is of course because I originally hadn't specified that the damn 30 | thing had to be stations. I've modified the query so it returns only stations. 31 | 32 | And now, I just get two stations, which is just enough to fail :-). 33 | 34 | 35 | 36 | 37 | * Date: <2016-11-28 Mon> 38 | 39 | Start of a new logfile to document GridKit development. 40 | 41 | Applying GridKit's export to a network model, missing properties are a 42 | large problem. Without knowing the line voltage and/or frequency, it 43 | is impossible to determine the line impedance, and it is impossible to 44 | determine if a station should need a transformer. Without knowning 45 | that, results will be highly distorted. 46 | 47 | It is my goal to produce a *consistent* and *complete* model of the 48 | electricity network from OpenStreetMap data, given that 'perfect' 49 | information will never be forthcoming. (Such is not in the nature of 50 | 'open' data systems). Thus, GridKit tries to *interpret* the given 51 | data in the most *reasonable* way possible. 52 | 53 | Part of that is developing and testing heuristics for discovering 54 | topological relatiosn from spatial relations. Part of that is 55 | resolving conflicts using a consensus heuristic. And I think the last 56 | part that is statistical inference of missing values. 57 | 58 | For stations, that is not very interesting, because a station must 59 | carry at least those voltages of the lines it is attached 60 | to. Typically these should be the same, but I can't check that! There 61 | might be a transformer inbetween or the voltage may be 62 | misattributed. For a line, however, it directly affects the 63 | performance of the network. So it is on lines that I focus. 64 | 65 | A line always has a few features that provide some information on it: 66 | 67 | + length 68 | + connected stations 69 | + neighboring lines 70 | 71 | Furthermore, we are not actually very interested in the exact voltage 72 | and frequency (at least not as reported by the user), but rather in 73 | the 'classification' of the line, as a guide to its impedance 74 | characteristics. A preliminary classification (based on observation of 75 | data from Germany/Europe) might be as follows: 76 | 77 | | Voltage \ Frequency | DC | 16.7/16.67Hz | 50/60Hz | 78 | |---------------------+---------------------+-----------------------------+-------------------------------| 79 | | <10kV | Trams/Trolleys etc. | Minor railroads | Endpoint Distribution | 80 | | 10-60kV | - | Main Railroads | Local distribution | 81 | | 60-120kV | - | Railroad power Transmission | Low-voltage transmission | 82 | | 120-250kV | HVDC | - | Medium-voltage transmission | 83 | | 250-400kV | HVDC | - | High-voltage transmission | 84 | | >400kV | HVDC | - | Very-high-voltage transmision | 85 | 86 | Traditionally, most interest has been in transmission and HVDC lines, 87 | but there is no reason to focus on those exclusively. 88 | 89 | I expect that lines in these different categories differ on the tree 90 | features noted above, and that those features can be used to determine 91 | the probability that a line belongs to a particular class. Once the 92 | class is known, the values of frequency and voltage can be derived 93 | from the modal values in the category. 94 | 95 | That probably means that the 50Hz values should be in a different 96 | category from 60Hz, lest we start mixing 50Hz and 60Hz lines if we 97 | ever cover an area that has both. Which is interesting. 98 | 99 | The basic theory so far is that I want to use Bayes rule for computing 100 | the probability that a line is in a given category given it has 101 | certain features, by determining the probablity that a line would have 102 | those features if it were in that category. Or to put it mathematically: 103 | 104 | \begin{equation} 105 | P(C|F) = \frac{P(F|C) * P(C)}{P(F)} 106 | \end{equation} 107 | 108 | A crucial assumption is that all features $F_i$ in $F$ are 109 | independent, and that the combined probability of $P(F) = 110 | \prod{F_i}$. Since that is not true for each of the separate neighbors 111 | (neighborship is symmetrical), the calculation of $P(N)$ must be 112 | somewhat different, and I haven't fully worked that out yet. 113 | 114 | The line length feature, well, that depends a bit on the distribution 115 | of the line lengths. Now I have some reason to believe that the 116 | /logarithm/ of the line length is normally distributed, and I hope to 117 | find that the mean of the logaritmic line length differs sufficiently 118 | between groups. And if it does, we can use [[https://en.wikipedia.org/wiki/Gaussian_function][Gauss' formula]] to compute 119 | the probability of finding a line with that length per category: 120 | 121 | \begin{equation} 122 | f(x) = \frac{e^{-(x-\mu)/2\sigma^2}}{\sigma \sqrt{2 \pi}} 123 | \end{equation} 124 | 125 | Both attached stations are probably sufficiently independent features 126 | to be treated as such. 127 | 128 | 129 | ** MultiPolygon Bugs. 130 | 131 | But first, a bugfix. Apparently on some inputs and on some versions of 132 | PostgreSQL, the following query: 133 | 134 | #+BEGIN_SRC sql 135 | select power_id, hstore(w.tags)->'power', 136 | st_buffer(case when st_isclosed(wg.line) and st_numpoints(wg.line) > 3 then st_makepolygon(wg.line) 137 | when st_numpoints(wg.line) = 3 and st_isclosed(wg.line) or st_numpoints(wg.line) = 2 then st_buffer(wg.line, 1) 138 | else st_makepolygon(st_addpoint(wg.line, st_startpoint(wg.line))) end, :station_buffer) 139 | from source_objects o 140 | join planet_osm_ways w on w.id = o.osm_id 141 | join way_geometry wg on wg.way_id = o.osm_id 142 | where o.osm_type = 'w' and o.power_type = 's';​ 143 | #+END_SRC 144 | 145 | Will sometimes result in the third variable being a multipolygon! 146 | 147 | What I need to do is figure out when this happens: 148 | 149 | #+BEGIN_SRC sql 150 | SELECT * FROM ( 151 | SELECT way_id, line, st_buffer(st_makepolygon(st_addpoint(line, st_startpoint(line))), 100) 152 | FROM way_geometry 153 | JOIN source_objects on osm_id = way_id and osm_type = 'w' 154 | WHERE power_type = 's' AND NOT ST_IsClosed(line) AND ST_NumPoints(line) > 3 155 | ) line_buffers (osm_id, line_geom, buffer_geom) 156 | WHERE ST_GeometryType(buffer_geom) = 'ST_MultiPolygon'; 157 | #+END_SRC 158 | 159 | I've been unable to replicate this issue, unfortunately, but I will, 160 | and I will fix it. 161 | -------------------------------------------------------------------------------- /src/prepare-tables.sql: -------------------------------------------------------------------------------- 1 | /* assume we use the osm2pgsql 'accidental' tables */ 2 | begin transaction; 3 | drop table if exists node_geometry; 4 | drop table if exists way_geometry; 5 | drop table if exists station_polygon; 6 | 7 | drop table if exists power_type_names; 8 | drop table if exists power_station; 9 | drop table if exists power_line; 10 | drop table if exists power_generator; 11 | 12 | drop table if exists source_tags; 13 | drop table if exists source_objects; 14 | drop table if exists derived_objects; 15 | 16 | drop sequence if exists line_id; 17 | drop sequence if exists station_id; 18 | drop sequence if exists generator_id; 19 | 20 | create sequence station_id; 21 | create sequence line_id; 22 | create sequence generator_id; 23 | 24 | create table node_geometry ( 25 | node_id bigint primary key, 26 | point geometry(point, 3857) not null 27 | ); 28 | 29 | create table way_geometry ( 30 | way_id bigint primary key, 31 | line geometry(linestring, 3857) not null 32 | ); 33 | 34 | create table station_polygon ( 35 | station_id integer primary key, 36 | polygon geometry(polygon, 3857) not null 37 | ); 38 | 39 | -- implementation of source_ids and source_tags table will depend on the data source used 40 | create table source_objects ( 41 | osm_id bigint not null, 42 | osm_type char(1) not null, 43 | power_id integer not null, 44 | power_type char(1) not null, 45 | primary key (osm_id, osm_type) 46 | ); 47 | 48 | -- both ways lookups 49 | create index source_objects_power_idx on source_objects (power_type, power_id); 50 | 51 | create table source_tags ( 52 | power_id integer not null, 53 | power_type char(1) not null, 54 | tags hstore, 55 | primary key (power_id, power_type) 56 | ); 57 | 58 | -- NB the arrays are convenient but not necessary 59 | create table derived_objects ( 60 | derived_id integer not null, 61 | derived_type char(1) not null, 62 | operation varchar(16) not null, 63 | source_id integer array, 64 | source_type char(1) 65 | ); 66 | 67 | /* lookup table for power types */ 68 | create table power_type_names ( 69 | power_name varchar(64) primary key, 70 | power_type char(1) not null, 71 | check (power_type in ('s','l','g', 'v')) 72 | ); 73 | 74 | create table power_station ( 75 | station_id integer primary key, 76 | power_name varchar(64) not null, 77 | area geometry(polygon, 3857) 78 | ); 79 | 80 | create index power_station_area_idx on power_station using gist (area); 81 | 82 | create table power_line ( 83 | line_id integer primary key, 84 | power_name varchar(64) not null, 85 | extent geometry(linestring, 3857), 86 | radius integer array[2] 87 | ); 88 | 89 | create index power_line_extent_idx on power_line using gist(extent); 90 | create index power_line_startpoint_idx on power_line using gist(st_startpoint(extent)); 91 | create index power_line_endpoint_idx on power_line using gist(st_endpoint(extent)); 92 | 93 | 94 | create table power_generator ( 95 | generator_id integer primary key, 96 | osm_id bigint, 97 | osm_type char(1), 98 | geometry geometry(geometry, 3857), 99 | location geometry(point, 3857), 100 | tags hstore 101 | ); 102 | 103 | create index power_generator_location_idx on power_generator using gist(location); 104 | 105 | -- all things recognised as power objects 106 | insert into power_type_names (power_name, power_type) 107 | values ('station', 's'), 108 | ('substation', 's'), 109 | ('sub_station', 's'), 110 | ('plant', 's'), 111 | ('cable', 'l'), 112 | ('line', 'l'), 113 | ('minor_cable', 'l'), 114 | ('minor_line', 'l'), 115 | ('minor_undeground_cable', 'l'), 116 | ('generator', 'g'), 117 | ('gas generator', 'g'), 118 | ('wind generator', 'g'), 119 | ('hydro', 'g'), 120 | ('hydroelectric', 'g'), 121 | ('heliostat', 'g'), 122 | -- virtual elements 123 | ('merge', 'v'), 124 | ('joint', 'v'); 125 | 126 | 127 | 128 | -- we could read this out of the planet_osm_point table, but i'd 129 | -- prefer calculating under my own control. 130 | insert into node_geometry (node_id, point) 131 | select id, st_setsrid(st_makepoint(lon/100.0, lat/100.0), 3857) 132 | from planet_osm_nodes; 133 | 134 | insert into way_geometry (way_id, line) 135 | select way_id, ST_MakeLine(n.point order by order_nr) 136 | from ( 137 | select id as way_id, 138 | unnest(nodes) as node_id, 139 | generate_subscripts(nodes, 1) as order_nr 140 | from planet_osm_ways 141 | ) as wn 142 | join node_geometry n on n.node_id = wn.node_id 143 | group by way_id; 144 | 145 | 146 | -- identify objects as lines or stations 147 | insert into source_objects (osm_id, osm_type, power_id, power_type) 148 | select id, 'n', nextval('station_id'), 's' 149 | from planet_osm_nodes n 150 | join power_type_names t on hstore(n.tags)->'power' = t.power_name 151 | and t.power_type = 's'; 152 | 153 | insert into source_objects (osm_id, osm_type, power_id, power_type) 154 | select id, 'w', nextval('station_id'), 's' 155 | from planet_osm_ways w 156 | join power_type_names t on hstore(w.tags)->'power' = t.power_name 157 | and t.power_type = 's'; 158 | 159 | insert into source_objects (osm_id, osm_type, power_id, power_type) 160 | select id, 'w', nextval('line_id'), 'l' 161 | from planet_osm_ways w 162 | join power_type_names t on hstore(w.tags)->'power' = t.power_name 163 | and t.power_type = 'l'; 164 | 165 | 166 | 167 | insert into power_generator (generator_id, osm_id, osm_type, geometry, location, tags) 168 | select nextval('generator_id'), id, 'n', ng.point, ng.point, hstore(n.tags) 169 | from planet_osm_nodes n 170 | join node_geometry ng on ng.node_id = n.id 171 | join power_type_names t on hstore(tags)->'power' = t.power_name 172 | and t.power_type = 'g'; 173 | 174 | insert into power_generator (generator_id, osm_id, osm_type, geometry, location, tags) 175 | select nextval('generator_id'), id, 'w', 176 | case when st_isclosed(wg.line) then st_makepolygon(wg.line) 177 | else wg.line end, 178 | st_centroid(wg.line), hstore(w.tags) 179 | from planet_osm_ways w 180 | join way_geometry wg on wg.way_id = w.id 181 | join power_type_names t on hstore(tags)->'power' = t.power_name 182 | and t.power_type = 'g'; 183 | 184 | insert into station_polygon (station_id, polygon) 185 | select station_id, polygon 186 | from ( 187 | select o.power_id, 188 | case when st_isclosed(wg.line) and st_numpoints(wg.line) > 3 then st_makepolygon(wg.line) 189 | when st_numpoints(wg.line) >= 3 190 | -- looks like an unclosed polygon based on endpoints distance 191 | and st_distance(st_startpoint(wg.line), st_endpoint(wg.line)) < (st_length(wg.line) / 2) 192 | then st_makepolygon(st_addpoint(wg.line, st_startpoint(wg.line))) 193 | else null end 194 | from source_objects o 195 | join way_geometry wg on o.osm_id = wg.way_id 196 | where o.power_type = 's' and o.osm_type = 'w' 197 | ) _g(station_id, polygon) 198 | -- even so not all polygons will be valid 199 | where polygon is not null and st_isvalid(polygon); 200 | 201 | 202 | insert into power_station (station_id, power_name, area) 203 | select o.power_id, hstore(n.tags)->'power', st_buffer(ng.point, :station_buffer/2) 204 | from source_objects o 205 | join planet_osm_nodes n on n.id = o.osm_id 206 | join node_geometry ng on ng.node_id = o.osm_id 207 | where o.power_type = 's' and o.osm_type = 'n'; 208 | 209 | insert into power_station (station_id, power_name, area) 210 | select power_id, hstore(w.tags)->'power', 211 | case when sp.polygon is not null 212 | then st_buffer(sp.polygon, least(:station_buffer, sqrt(st_area(sp.polygon)))) 213 | else st_buffer(wg.line, least(:station_buffer, st_length(wg.line)/2)) end 214 | -- not sure if that is the right way to deal with line-geometry stations 215 | from source_objects o 216 | join planet_osm_ways w on w.id = o.osm_id 217 | join way_geometry wg on wg.way_id = o.osm_id 218 | left join station_polygon sp on sp.station_id = o.power_id 219 | where o.osm_type = 'w' and o.power_type = 's'; 220 | 221 | insert into power_line (line_id, power_name, extent, radius) 222 | select o.power_id, hstore(w.tags)->'power', wg.line, 223 | array_fill(least(:terminal_radius, st_length(wg.line)/3), array[2]) -- default radius 224 | from source_objects o 225 | join planet_osm_ways w on w.id = o.osm_id 226 | join way_geometry wg on wg.way_id = o.osm_id 227 | where o.power_type = 'l'; 228 | 229 | 230 | insert into source_tags (power_id, power_type, tags) 231 | select o.power_id, o.power_type, hstore(n.tags) 232 | from planet_osm_nodes n 233 | join source_objects o on o.osm_id = n.id and o.osm_type = 'n'; 234 | 235 | insert into source_tags (power_id, power_type, tags) 236 | select o.power_id, o.power_type, hstore(w.tags) 237 | from planet_osm_ways w 238 | join source_objects o on o.osm_id = w.id and o.osm_type = 'w'; 239 | 240 | commit; 241 | -------------------------------------------------------------------------------- /src/electric-3-line.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | /* temporarily create the table so that the line structure type exists */ 3 | create table if not exists line_structure ( line_id integer ); 4 | drop function if exists derive_line_structure(integer); 5 | drop function if exists join_line_structure(integer, integer array); 6 | drop function if exists merge_line_structure(integer, integer array); 7 | drop function if exists line_structure_majority(integer, line_structure array, boolean); 8 | drop function if exists line_structure_distance(line_structure, line_structure); 9 | drop function if exists line_structure_classify(integer, line_structure array, integer); 10 | drop function if exists line_structure_set(integer, line_structure array); 11 | drop table if exists line_structure; 12 | 13 | create table line_structure ( 14 | line_id integer, 15 | part_nr integer, 16 | -- properties 17 | voltage integer, 18 | frequency float, 19 | cables integer, 20 | wires integer, 21 | -- counts 22 | num_objects integer, 23 | num_conflicts integer array[4], 24 | num_classes integer, 25 | primary key (line_id, part_nr) 26 | ); 27 | 28 | 29 | create function derive_line_structure (i integer) returns line_structure array as $$ 30 | declare 31 | r line_structure array; 32 | d derived_objects; 33 | begin 34 | r = array(select row(l.*) from line_structure l where line_id = i); 35 | if array_length(r, 1) is not null then 36 | return r; 37 | end if; 38 | select * into d from derived_objects where derived_id = i and derived_type = 'l'; 39 | if d.derived_id is null then 40 | raise exception 'No derived object for line_id %', i; 41 | elsif d.operation = 'join' then 42 | r = join_line_structure(i, d.source_id); 43 | elsif d.operation = 'merge' then 44 | r = merge_line_structure(i, d.source_id); 45 | elsif d.operation = 'split' then 46 | r = derive_line_structure(d.source_id[1]); 47 | end if; 48 | if array_length(r, 1) is null then 49 | raise exception 'Could not derive line_structure for %', i; 50 | end if; 51 | -- store and return 52 | insert into line_structure (line_id, part_nr, voltage, frequency, cables, wires, num_objects, num_conflicts, num_classes) 53 | select * from line_structure_set(i, r); 54 | return array(select row(l.*) from line_structure_set(i, r) l); 55 | end; 56 | $$ language plpgsql; 57 | 58 | create function line_structure_set(i integer, r line_structure array) returns setof line_structure as $$ 59 | begin 60 | return query select i, s, (l).voltage, (l).frequency, (l).cables, (l).wires, (l).num_objects, (l).num_conflicts, (l).num_classes 61 | from (select unnest(r), generate_subscripts(r, 1)) f(l, s); 62 | end; 63 | $$ language plpgsql; 64 | 65 | create function join_line_structure(i integer, j integer array) returns line_structure array as $$ 66 | declare 67 | r line_structure array; 68 | n integer; 69 | begin 70 | r = array(select unnest(derive_line_structure(line_id)) from unnest(j) line_id); 71 | n = max((e).num_classes) from unnest(r) as e; 72 | if n > 1 then 73 | return array(select line_structure_majority(i, array_agg(l), false) 74 | from line_structure_classify(i, r, n) c 75 | join unnest(r) l on (l).line_id = c.source_id and (l).part_nr = c.part_nr 76 | group by c.class_key); 77 | else 78 | return array[line_structure_majority(i, r, false)]; 79 | end if; 80 | end; 81 | $$ language plpgsql; 82 | 83 | 84 | create function merge_line_structure(i integer, j integer array) returns line_structure array as $$ 85 | declare 86 | r line_structure array; 87 | n integer; 88 | begin 89 | r = array(select unnest(derive_line_structure(line_id)) from unnest(j) line_id); 90 | -- if we have multiple classes, multiple voltages, or frequencies, choose to treat them as s 91 | n = greatest(max((e).num_classes::bigint), count(distinct (e).voltage), count(distinct (e).frequency)) from unnest(r) as e; 92 | if n > 1 then 93 | -- divide over c classes 94 | return array(select line_structure_majority(i, array_agg(l), true) 95 | from line_structure_classify(i, r, n) c 96 | join unnest(r) l on (l).line_id = c.source_id and (l).part_nr = c.part_nr 97 | group by c.class_key); 98 | else 99 | return array[line_structure_majority(i, r, true)]; 100 | end if; 101 | end; 102 | $$ language plpgsql; 103 | 104 | create function line_structure_majority(i integer, d line_structure array, sum_cables boolean) returns line_structure as $$ 105 | declare 106 | r line_structure; 107 | begin 108 | with raw_data (line_id, part_nr, voltage, frequency, cables, wires, num_objects, num_conflicts, num_classes) as ( 109 | select (e).* from unnest(d) e 110 | ), 111 | cnt_t (n) as ( select sum(num_objects) from raw_data ), 112 | cnt_v (n) as ( select sum(num_objects) from raw_data where voltage is not null ), 113 | cnt_f (n) as ( select sum(num_objects) from raw_data where frequency is not null ), 114 | cnt_c (n) as ( select sum(num_objects) from raw_data where cables is not null ), 115 | cnt_w (n) as ( select sum(num_objects) from raw_data where wires is not null ), 116 | num_c (n) as ( select max(num_classes) from raw_data ), 117 | vlt(voltage, conflicts) as ( 118 | select voltage, coalesce(n - score, 0) from ( 119 | select voltage, sum(num_objects) - sum(num_conflicts[1]) 120 | from raw_data 121 | group by voltage 122 | ) _t (voltage, score), cnt_v 123 | order by voltage is not null desc, score desc, voltage asc limit 1 124 | ), 125 | frq(frequency, conflicts) as ( 126 | select frequency, coalesce(n - score, 0) from ( 127 | select frequency, sum(num_objects) - sum(num_conflicts[2]) 128 | from raw_data 129 | group by frequency 130 | ) _t (frequency, score), cnt_f 131 | order by frequency is not null desc, score desc, frequency asc limit 1 132 | ), 133 | cbl(cables, conflicts) as ( 134 | select cables, coalesce(n - score, 0) from ( 135 | select cables, sum(num_objects) - sum(num_conflicts[3]) 136 | from raw_data 137 | group by cables 138 | ) _t (cables, score), cnt_c 139 | order by cables is not null desc, score desc, cables asc limit 1 140 | ), 141 | wrs(wires, conflicts) as ( 142 | select wires, coalesce(n - score, 0) from ( 143 | select wires, sum(num_objects) - sum(num_conflicts[4]) 144 | from raw_data 145 | group by wires 146 | ) _t (wires, score), cnt_w 147 | order by wires is not null desc, score desc, wires asc limit 1 148 | ), 149 | _sum (cables) as ( 150 | select sum(cables) from raw_data where cables is not null 151 | ) 152 | select null, null, vlt.voltage, frq.frequency, 153 | case when sum_cables then _sum.cables else cbl.cables end, 154 | wrs.wires, cnt_t.n, 155 | array[vlt.conflicts, frq.conflicts, cbl.conflicts, wrs.conflicts], 156 | num_c.n 157 | into r 158 | from vlt, frq, cbl, wrs, cnt_t, num_c, _sum; 159 | return r; 160 | end; 161 | $$ language plpgsql; 162 | 163 | 164 | create function line_structure_distance(a line_structure, b line_structure) returns numeric as $$ 165 | begin 166 | return case when a.voltage is null or b.voltage is null then 1 167 | when a.voltage = b.voltage then 0 168 | when least(a.voltage, b.voltage) = 0 then 4 169 | else 2*greatest(a.voltage, b.voltage)::float / least(a.voltage, b.voltage)::float end 170 | + 171 | case when a.frequency is null or b.frequency is null then 1 172 | when a.frequency = b.frequency then 0 173 | when least(a.frequency, b.frequency) = 0 then 4 174 | else 2*greatest(a.frequency, b.frequency) / least(a.frequency, b.frequency) end 175 | + 176 | case when a.cables is null or b.cables is null then 1 177 | when a.cables = b.cables then 0 178 | when least(a.cables, b.cables) = 0 then 2 179 | else 0.7*greatest(a.cables, b.cables)::float / least(a.cables, b.cables)::float end 180 | + 181 | case when a.wires is null or b.wires is null then 1 182 | when a.wires = b.wires then 0 183 | when least(a.wires, b.wires) = 0 then 2 184 | else 0.7*greatest(a.wires, b.wires)::float / least(a.wires, b.wires)::float end; 185 | end; 186 | $$ language plpgsql; 187 | 188 | 189 | 190 | -- TODO this needs a structure_id of sorts... (OR we can introduce link_id here, but that means we need two tables) 191 | drop table if exists line_structure_class; 192 | create table line_structure_class ( 193 | line_id integer, 194 | source_id integer, 195 | part_nr integer, 196 | class_key integer, 197 | primary key (line_id, source_id, part_nr) 198 | ); 199 | 200 | create index line_structure_class_key_idx 201 | on line_structure_class (line_id, class_key); 202 | 203 | create function line_structure_classify (i integer, r line_structure array, n integer) returns setof line_structure_class as $$ 204 | declare 205 | edge record; 206 | src_key integer; 207 | dst_key integer; 208 | num_edges integer; 209 | begin 210 | num_edges = 0; 211 | insert into line_structure_class (line_id, source_id, part_nr, class_key) 212 | select i, (unnest(r)).line_id, (unnest(r)).part_nr, generate_subscripts(r, 1); 213 | 214 | for edge in with pairs (src_id, src_pt, dst_id, dst_pt, cost) as ( 215 | select a_id, a_pt, b_id, b_pt, line_structure_distance(_s, _t) 216 | from unnest(r) _s(a_id, a_pt), 217 | unnest(r) _t(b_id, b_pt) -- line id is the first column 218 | where a_id < b_id 219 | order by line_structure_distance(_s, _t) asc 220 | ) select * from pairs loop 221 | src_key := class_key from line_structure_class 222 | where line_id = i 223 | and source_id = edge.src_id 224 | and part_nr = edge.src_pt; 225 | dst_key := class_key from line_structure_class 226 | where line_id = i 227 | and source_id = edge.dst_id 228 | and part_nr = edge.dst_pt; 229 | if src_key = dst_key then 230 | continue; 231 | elsif num_edges + n = array_length(r, 1) then 232 | exit; 233 | else 234 | update line_structure_class 235 | set class_key = least(src_key, dst_key) 236 | where line_id = i 237 | and class_key = greatest(src_key, dst_key); 238 | num_edges = num_edges + 1; 239 | end if; 240 | end loop; 241 | return query select line_id, source_id, part_nr, class_key 242 | from line_structure_class 243 | where line_id = i; 244 | end; 245 | $$ language plpgsql; 246 | 247 | 248 | insert into line_structure (line_id, part_nr, voltage, frequency, cables, wires, num_objects, num_conflicts, num_classes) 249 | select line_id, generate_series(1, num_classes), 250 | case when voltage is not null then unnest(voltage) end, 251 | case when frequency is not null then unnest(frequency) end, 252 | case when cables is not null then unnest(cables) end, 253 | case when wires is not null then unnest(wires) end, 254 | 1, array[0,0,0,0], num_classes 255 | from line_tags; 256 | 257 | 258 | do $$ 259 | declare 260 | i integer; 261 | c integer; 262 | begin 263 | -- todo, we may want to split this into partial queries, because 264 | -- a single run takes a /very/ long time... 265 | i = 0; 266 | loop 267 | c = count(*) from topology_edges e where not exists ( 268 | select 1 from line_structure l where l.line_id = e.line_id 269 | ); 270 | i := i + 1; 271 | exit when c = 0; 272 | raise notice 'Iteration %, % left', i, c; 273 | 274 | perform derive_line_structure(derived_id) 275 | from derived_objects j 276 | join topology_edges e on e.line_id = j.derived_id 277 | where derived_type = 'l' 278 | and not exists (select 1 from line_structure l where l.line_id = e.line_id) 279 | order by line_id asc 280 | limit 1000; 281 | end loop; 282 | end; 283 | $$ language plpgsql; 284 | 285 | commit; 286 | -------------------------------------------------------------------------------- /gridkit.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env python 2 | """GridKit is a power grid extraction toolkit. 3 | 4 | Usage: 5 | python gridkit.py path/to/data-file.osm --filter \\ 6 | --poly path/to/area.poly \\ 7 | --pg user=gridkit database=gridkit 8 | 9 | GridKit will create a database, import the power data, run the 10 | extraction procedures, and write CSV's with the high-voltage network 11 | extract. 12 | """ 13 | from __future__ import print_function, unicode_literals, division 14 | import os, sys, io, re, csv, argparse, logging, subprocess, functools, getpass, operator 15 | from util.postgres import PgWrapper as PgClient, PSQL 16 | from util.which import which 17 | 18 | __author__ = 'Bart Wiegmans' 19 | 20 | if sys.version_info >= (3,0): 21 | raw_input = input 22 | 23 | 24 | 25 | 26 | def ask(question, default=None, type=str): 27 | if default is not None: 28 | question = "{0} [{1}]".format(question, default) 29 | try: 30 | value = raw_input(question + ' ') 31 | except KeyboardInterrupt: 32 | print('') 33 | quit(1) 34 | if not value: 35 | return default 36 | try: 37 | return type(value) 38 | except ValueError: 39 | return None 40 | 41 | def ask_db_params(pg_client, database_params): 42 | while not pg_client.check_connection(): 43 | print("Please provide the PostgreSQL connection parameters (press Ctrl+C to exit)") 44 | user = ask("PostgreSQL user name:", default=(database_params.get('user') or getpass.getuser())) 45 | host = ask("PostgreSQL hostname:", default=(database_params.get('host') or 'localhost')) 46 | port = ask("PostgreSQL port number:", type=int, default=(database_params.get('port') or 5432)) 47 | dbnm = ask("PostgreSQL database:", type=str, default=(database_params.get('database') or user)) 48 | new_params = database_params.copy() 49 | new_params.update(user=user, host=host, port=port, database=dbnm) 50 | pg_client.update_params(new_params) 51 | print("Connection succesful") 52 | database_params.update(**new_params) 53 | 54 | def setup_database(pg_client, database_name, interactive): 55 | io_handle = io.StringIO() 56 | pg_client.do_getcsv('SELECT datname FROM pg_database', io_handle) 57 | io_handle.seek(0,0) 58 | databases = list(map(operator.itemgetter(0), csv.reader(io_handle))) 59 | 60 | while interactive and database_name in databases: 61 | overwrite = ask("Database {0} exists. Overwrite [y/N]?".format(database_name), 62 | type=lambda s: s.lower().startswith('y')) 63 | if overwrite: 64 | break 65 | database_name = ask("Database name:", default='gridkit') 66 | if not database_name in databases: 67 | pg_client.do_createdb(database_name) 68 | pg_client.update_params({'database': database_name}) 69 | pg_client.check_connection() 70 | pg_client.do_query('CREATE EXTENSION IF NOT EXISTS hstore;') 71 | pg_client.do_query('CREATE EXTENSION IF NOT EXISTS postgis;') 72 | print("Database", database_name, "set up") 73 | return database_name 74 | 75 | def do_import(osm_data_file, database_name, database_params): 76 | if 'password' in database_params: 77 | os.environ['PGPASS'] = database_params['password'] 78 | command_line = [OSM2PGSQL, '-d', database_name, 79 | '-c', '-k', '-s', '-S', POWERSTYLE] 80 | if 'port' in database_params: 81 | command_line.extend(['-P', str(database_params['port'])]) 82 | if 'user' in database_params: 83 | command_line.extend(['-U', database_params['user']]) 84 | if 'host' in database_params: 85 | command_line.extend(['-H', database_params['host']]) 86 | command_line.append(osm_data_file) 87 | logging.info("Calling %s", ' '.join(command_line)) 88 | subprocess.check_call(command_line) 89 | 90 | def do_conversion(pg_client, voltage_cutoff=220000): 91 | f = functools.partial(os.path.join, BASE_DIR, 'src') 92 | # preparing tables 93 | logging.info("Preparing tables") 94 | pg_client.do_queryfile(f('prepare-functions.sql')) 95 | pg_client.do_queryfile(f('prepare-tables.sql')) 96 | 97 | # shared node algorithms 98 | logging.info("Shared-node algorithms started") 99 | pg_client.do_queryfile(f('node-1-find-shared.sql')) 100 | pg_client.do_queryfile(f('node-2-merge-lines.sql')) 101 | pg_client.do_queryfile(f('node-3-line-joints.sql')) 102 | logging.info("Shared-node algorithms finished") 103 | 104 | # spatial algorithms 105 | logging.info("Spatial algorithms started") 106 | pg_client.do_queryfile(f('spatial-1-merge-stations.sql')) 107 | pg_client.do_queryfile(f('spatial-2-eliminate-line-overlap.sql')) 108 | pg_client.do_queryfile(f('spatial-3-attachment-joints.sql')) 109 | pg_client.do_queryfile(f('spatial-4-terminal-intersections.sql')) 110 | pg_client.do_queryfile(f('spatial-5-terminal-joints.sql')) 111 | pg_client.do_queryfile(f('spatial-6-merge-lines.sql')) 112 | logging.info("Spatial algorithms finished") 113 | 114 | # topological algoritms 115 | logging.info("Topological algorithms started") 116 | pg_client.do_queryfile(f('topology-1-connections.sql')) 117 | pg_client.do_queryfile(f('topology-2-dangling-joints.sql')) 118 | pg_client.do_queryfile(f('topology-3-redundant-splits.sql')) 119 | pg_client.do_queryfile(f('topology-4-redundant-joints.sql')) 120 | logging.info("Topological algorithms finished") 121 | 122 | logging.info("Electric algorithms started") 123 | pg_client.do_queryfile(f('electric-1-tags.sql')) 124 | pg_client.do_queryfile(f('electric-2-patch.sql')) 125 | pg_client.do_queryfile(f('electric-3-compute.sql')) 126 | 127 | pg_client.do_queryfile(f('electric-4-reference.sql')) 128 | logging.info("Electric algorithms finished") 129 | 130 | 131 | pg_client.do_queryfile(f('topology-3a-assign-tags.sql')) 132 | pg_client.do_queryfile(f('topology-3b-electrical-properties.sql')) 133 | 134 | with io.open(f('topology-4-high-voltage-network.sql'), 'r') as handle: 135 | query_text = handle.read().replace('220000', str(voltage_cutoff)) 136 | pg_client.do_query(query_text) 137 | 138 | pg_client.do_queryfile(f('topology-5-abstraction.sql')) 139 | logging.info("Topological algorithms done") 140 | 141 | def export_network_csv(pg_client, full_export=False, base_name='gridkit'): 142 | logging.info("Running export") 143 | if full_export: 144 | with io.open(base_name + '-all-vertices.csv', 'w') as handle: 145 | pg_client.do_getcsv('heuristic_vertices', handle) 146 | with io.open(base_name + '-all-links.csv', 'w') as handle: 147 | pg_client.do_getcsv('heuristic_links', handle) 148 | 149 | with io.open(base_name + '-highvoltage-vertices.csv', 'w') as handle: 150 | pg_client.do_getcsv('heuristic_vertices_highvoltage', handle) 151 | 152 | with io.open(base_name + '-highvoltage-links.csv', 'w') as handle: 153 | pg_client.do_getcsv('heuristic_links_highvoltage', handle) 154 | 155 | logging.info("Export done") 156 | 157 | 158 | def file_age_cmp(a, b): 159 | # negative if a is younger than b, positive if a is older than b 160 | return os.path.getmtime(b) - os.path.getmtime(a) 161 | 162 | 163 | if __name__ == '__main__': 164 | logging.basicConfig(format='%(levelname)s [%(asctime)s] / %(message)s', level=logging.INFO) 165 | 166 | 167 | OSM2PGSQL = which('osm2pgsql') 168 | OSMCONVERT = which('osmconvert') 169 | OSMFILTER = which('osmfilter') 170 | OSMOSIS = which('osmosis') 171 | BASE_DIR = os.path.realpath(os.path.dirname(__file__)) 172 | POWERSTYLE = os.path.join(BASE_DIR, 'power.style') 173 | 174 | parse_pair = lambda s: tuple(s.split('=', 1)) 175 | ap = argparse.ArgumentParser() 176 | # polygon filter files 177 | ap.add_argument('--filter', action='store_true', help='Filter input file for power data (requires osmfilter)') 178 | ap.add_argument('--poly',type=str,nargs='+', help='Polygon file(s) to limit the areas of the input file (requires osmconvert)') 179 | ap.add_argument('--no-interactive', action='store_false', dest='interactive', help='Proceed automatically without asking questions') 180 | ap.add_argument('--no-import', action='store_false', dest='_import', help='Skip import step') 181 | ap.add_argument('--no-conversion', action='store_false', dest='convert', help='Skip conversion step') 182 | ap.add_argument('--no-export', action='store_false', dest='export', help='Skip export step') 183 | ap.add_argument('--pg', type=parse_pair, default=[], nargs='+', help='Connection arguments to PostgreSQL, eg. --pg user=gridkit database=europe') 184 | ap.add_argument('--psql', type=str, help='Location of psql binary', default=PSQL) 185 | ap.add_argument('--osm2pgsql', type=str, help='Location of osm2pgsql binary', default=OSM2PGSQL) 186 | ap.add_argument('--voltage', type=int, help='High-voltage cutoff level', default=220000) 187 | ap.add_argument('--full-export', action='store_true', dest='full_export') 188 | ap.add_argument('osmfile', nargs='?') 189 | args = ap.parse_args() 190 | 191 | # i've added this for the scigrid folks 192 | PSQL = args.psql 193 | OSM2PGSQL = args.osm2pgsql 194 | osmfile = args.osmfile 195 | interactive = args.interactive and os.isatty(sys.stdin.fileno()) 196 | if args._import and args.osmfile is None: 197 | ap.error("OSM source file required") 198 | 199 | if args.filter: 200 | if not OSMFILTER: 201 | logging.error("Cannot find osmfilter executable, necessary for --filter") 202 | quit(1) 203 | name, ext = os.path.splitext(osmfile) 204 | new_name = name + '-power.o5m' 205 | logging.info("Filtering %s to make %s", osmfile, new_name) 206 | subprocess.check_call([OSMFILTER, osmfile, '--keep="power=*"', '-o=' + new_name]) 207 | osmfile = new_name 208 | 209 | # get effective database parameters 210 | db_params = dict((k[2:].lower(), v) for k, v in os.environ.items() if k.startswith('PG')) 211 | db_params.update(**dict(args.pg)) 212 | 213 | # need 'root' database for polyfile based extraction 214 | if args.poly: 215 | db_params.update(database=db_params.get('user') or 'postgres') 216 | 217 | pg_client = PgClient() 218 | pg_client.update_params(db_params) 219 | 220 | if pg_client.check_connection(): 221 | logging.info("Connection OK") 222 | elif interactive and not args.poly: 223 | logging.warn("Cannot connect to database") 224 | ask_db_params(pg_client, db_params) 225 | else: 226 | logging.error("Cannot connect to database") 227 | quit(1) 228 | 229 | 230 | if OSM2PGSQL is None or not (os.path.isfile(OSM2PGSQL) and os.access(OSM2PGSQL, os.X_OK)): 231 | logging.error("Cannot find osm2pgsql executable") 232 | quit(1) 233 | 234 | 235 | if args.poly: 236 | osmfiles = dict() 237 | for polyfile in args.poly: 238 | if not os.path.isfile(polyfile): 239 | logging.warn("%s is not a file", polyfile) 240 | continue 241 | polygon_name, ext = os.path.splitext(os.path.basename(polyfile)) 242 | osmfile_name, ext = os.path.splitext(osmfile) 243 | osmfile_for_area = '{0}-{1}.o5m'.format(osmfile_name, polygon_name) 244 | if os.path.isfile(osmfile_for_area) and file_age_cmp(osmfile_for_area, osmfile) < 0: 245 | logging.info("File %s already exists and is newer than %s", osmfile_for_area, osmfile) 246 | else: 247 | logging.info("Extracting area %s from %s to make %s", polygon_name, osmfile, osmfile_for_area) 248 | subprocess.check_call([OSMCONVERT, osmfile, '--complete-ways', '-B='+polyfile, '-o='+osmfile_for_area]) 249 | osmfiles[polygon_name] = osmfile_for_area 250 | 251 | for area_name, area_osmfile in osmfiles.items(): 252 | # cleanup the name for use as a database name 253 | database_name = 'gridkit_' + re.sub('[^A-Z0-9]+', '_', area_name, 0, re.I) 254 | # select 'postgres' database for creating other databases 255 | pg_client.update_params({'database':'postgres'}) 256 | pg_client.check_connection() 257 | setup_database(pg_client, database_name, False) 258 | # setup-database automatically uses the right connection 259 | do_import(area_osmfile, database_name, db_params) 260 | do_conversion(pg_client, args.voltage) 261 | export_network_csv(pg_client, args.full_export, database_name) 262 | 263 | else: 264 | database_name = db_params.get('database') or db_params.get('postgres') 265 | if database_name is None: 266 | # last case fallback 267 | osmfile_name, ext = os.path.splitext(os.path.basename(osmfile)) 268 | database_name = re.sub(r'[^A-Z0-9_]+', '_', osmfile_name.lower(), 0, re.I) 269 | if args._import: 270 | database_name = setup_database(pg_client, database_name, interactive) 271 | do_import(osmfile, database_name, db_params) 272 | if args.convert: 273 | try: 274 | do_conversion(pg_client, args.voltage) 275 | except KeyboardInterrupt: 276 | logging.warn("Execution interrupted - process is not finished") 277 | quit(1) 278 | if args.export: 279 | export_network_csv(pg_client, args.full_export, database_name or 'gridkit') 280 | -------------------------------------------------------------------------------- /util/network.py: -------------------------------------------------------------------------------- 1 | from __future__ import unicode_literals, division, print_function 2 | import io 3 | import csv 4 | import random 5 | import itertools 6 | import heapq 7 | import math 8 | import warnings 9 | try: 10 | from recordclass import recordclass 11 | except ImportError: 12 | from collections import namedtuple as recordclass 13 | warnings.warn("recordclass is necessary for Network.patch() to work") 14 | 15 | try: 16 | from numpy import array 17 | from matplotlib import pyplot 18 | except ImportError as e: 19 | warnings.warn(str(e)) 20 | 21 | 22 | 23 | 24 | class Station(recordclass('Station', str('station_id lat lon name operator voltages frequencies lines'))): 25 | def __hash__(self): 26 | return hash(self.station_id) 27 | 28 | @property 29 | def coordinates(self): 30 | return self.lon, self.lat 31 | 32 | def distance(self, other): 33 | # See https://www.math.ksu.edu/~dbski/writings/haversine.pdf 34 | # earths radius will be 6.371 km 35 | R = 6372.8 36 | delta_lat = math.radians(other.lat - self.lat) 37 | delta_lon = math.radians(other.lon - self.lon) 38 | a = math.sin(delta_lat/2)**2 + math.cos(math.radians(self.lat))*math.cos(math.radians(other.lat))*math.sin(delta_lon/2)**2 39 | c = 2*math.asin(math.sqrt(a)) 40 | return R*c 41 | 42 | 43 | def to_ewkt(self): 44 | return 'SRID=4326;POINT({0} {1})'.format(self.lon, self.lat) 45 | 46 | 47 | class Line(recordclass('Line', str('line_id operator left right length frequencies voltages resistance reactance capacitance max_current'))): 48 | def __hash__(self): 49 | return hash(self.line_id) 50 | 51 | def __repr__(self): 52 | return "{0}: {1} -> {2}".format(self.line_id, self.left.name, self.right.name).encode('utf-8') 53 | 54 | @property 55 | def susceptance(self): 56 | if self.capacitance is None or not self.frequencies: 57 | return None 58 | return self.capacitance * max(self.frequencies) 59 | 60 | class Path(object): 61 | def __init__(self, stations): 62 | self.stations = stations 63 | # make list of lines 64 | self.lines = list() 65 | for i in range(1, len(stations)): 66 | f = stations[i-1] 67 | t = stations[i] 68 | for l in f.lines: 69 | if f is l.left: 70 | if t is l.right: 71 | break 72 | elif t is l.left: 73 | break 74 | self.lines.append(l) 75 | 76 | def plot(self, figure=None, color='yellow'): 77 | if figure is None: 78 | figure = pyplot.figure() 79 | axs = figure.add_subplot(1,1,1) 80 | lat = [s.lat for s in self.stations] 81 | lon = [s.lon for s in self.stations] 82 | axs.plot(lon,lat, color=color) 83 | return figure 84 | 85 | @property 86 | def length(self): 87 | return sum(l.length for l in self.lines) 88 | 89 | def __iter__(self): 90 | return iter(self.stations) 91 | 92 | def __repr__(self): 93 | return 'Path of length {0} over [{1}]'.format( 94 | self.length, ', '.join(s.name for s in self.stations) 95 | ).encode('utf-8') 96 | 97 | def to_ewkt(self): 98 | return 'SRID=4326;LINESTRING({0})'.format( 99 | ','.join('{0} {1}'.format(s.lon, s.lat) for s in self.stations) 100 | ) 101 | 102 | 103 | 104 | class Network(object): 105 | def __init__(self): 106 | self.stations = dict() 107 | self.lines = dict() 108 | self._areas = dict() 109 | 110 | def connected_sets(self): 111 | # bfs algorithm to find connected sets in the network 112 | unseen = set(self.stations.values()) 113 | connected = [] 114 | while unseen: 115 | current = [] 116 | root = unseen.pop() 117 | queue = [root] 118 | while queue: 119 | node = queue.pop() 120 | if node in unseen: 121 | unseen.remove(node) 122 | current.append(node) 123 | for line in node.lines: 124 | if line.left in unseen: 125 | queue.append(line.left) 126 | if line.right in unseen: 127 | queue.append(line.right) 128 | connected.append(current) 129 | return connected 130 | 131 | def patch(self): 132 | # flood algorithm to patch all lines and stations with values from neighbours 133 | totals = list() 134 | while True: 135 | changes = 0 136 | for station in self.stations.itervalues(): 137 | line_voltages = set(v for line in station.lines for v in line.voltages) 138 | line_frequencies = set(f for line in station.lines for f in line.frequencies) 139 | if line_voltages - station.voltages: 140 | station.voltages |= line_voltages 141 | changes += 1 142 | if line_frequencies - station.frequencies: 143 | station.frequencies |= line_frequencies 144 | changes += 1 145 | 146 | 147 | for line in self.lines.itervalues(): 148 | shared_frequencies = line.left.frequencies & line.right.frequencies 149 | if shared_frequencies and not line.frequencies & shared_frequencies: 150 | line.frequencies |= shared_frequencies 151 | changes += 1 152 | elif not line.frequencies: 153 | if line.left.frequencies: 154 | line.frequencies = set(line.left.frequencies) 155 | changes += 1 156 | elif line.right.frequencies: 157 | line.frequencies = set(line.right.frequencies) 158 | changes += 1 159 | 160 | shared_voltages = line.left.voltages & line.right.voltages 161 | if shared_voltages and not line.voltages & shared_voltages: 162 | line.voltages |= shared_voltages 163 | changes += 1 164 | elif not line.voltages: 165 | if line.left.voltages: 166 | line.voltages = set(line.left.voltages) 167 | changes += 1 168 | elif line.right.voltages: 169 | line.voltages = set(line.right.voltages) 170 | changes += 1 171 | 172 | if changes == 0: 173 | break 174 | totals.append(changes) 175 | if len(totals) > 1000: 176 | raise Exception('dont think ill be stopping soon') 177 | return totals 178 | 179 | def report(self): 180 | # calculate missing values statically 181 | broken_stations = 0 182 | broken_lines = 0 183 | mismatches = 0 184 | for station in self.stations.itervalues(): 185 | if not station.voltages or not station.frequencies: 186 | broken_stations += 1 187 | for line in station.lines: 188 | if station.frequencies: 189 | if line.frequencies - station.frequencies: 190 | mismatches += 1 191 | continue 192 | elif line.frequencies: 193 | mismatches += 1 194 | continue 195 | if station.voltages: 196 | if line.voltages - station.voltages: 197 | mismatches += 1 198 | continue 199 | elif line.voltages: 200 | mismatches += 1 201 | continue 202 | 203 | for line in self.lines.itervalues(): 204 | if not line.voltages or not line.frequencies: 205 | broken_lines += 1 206 | return broken_stations, broken_lines, mismatches 207 | 208 | def find(self, from_id, to_id): 209 | # A* algorithm to find shortest path 210 | scores = dict() 211 | come_from = dict() 212 | seen = set() 213 | path = list() 214 | try: 215 | start = self.stations[from_id] 216 | goal = self.stations[to_id] 217 | except KeyError: 218 | return None 219 | queue = [(0,start)] 220 | while queue: 221 | score, station = heapq.heappop(queue) 222 | if station is goal: 223 | break 224 | seen.add(station) 225 | for line in station.lines: 226 | neighbor = line.left if line.right is station else line.right 227 | if neighbor in seen: 228 | continue 229 | g_score = score + line.length 230 | if scores.get(neighbor, g_score+1) < g_score: 231 | continue 232 | h_score = goal.distance(neighbor) 233 | heapq.heappush(queue, (g_score + h_score, neighbor)) 234 | come_from[neighbor] = station 235 | if station is not goal: 236 | return None 237 | while station is not start: 238 | path.append(station) 239 | station = come_from[station] 240 | path.append(start) 241 | path.reverse() 242 | return Path(path) 243 | 244 | 245 | def plot(self, figure=None, node_color='blue', edge_color='red'): 246 | if figure is None: 247 | figure = pyplot.figure() 248 | axis = figure.add_subplot(1,1,1) 249 | for line in self.lines.values(): 250 | axis.plot([line.left.lon, line.right.lon], 251 | [line.left.lat, line.right.lat], color=edge_color) 252 | coordinates = [s.coordinates for s in self.stations.values()] 253 | axis.plot(*zip(*coordinates), marker='o', color=node_color, lineStyle='None') 254 | return figure 255 | 256 | def _area_number(self, area_name): 257 | if area_name not in self._areas: 258 | # assign next area number 259 | self._areas[area_name] = len(self._areas) + 1 260 | return self._areas[area_name] 261 | 262 | def powercase(self, loads=None): 263 | # loads is a map of station id -> load, either positive or 264 | # negative; a negative load is represented by a generator. 265 | 266 | # if no loads map is passed, generate an 'electrified pair' of 267 | # two random nodes, one of which delivers power, the other 268 | # consumes it 269 | if loads is None: 270 | loads = self._electrified_pair() 271 | ppc = { 272 | "version": 2, 273 | "baseMVA": 100.0 274 | } 275 | nodes = list() 276 | edges = list() 277 | generators = list() 278 | 279 | station_to_bus = dict() 280 | bus_id_gen = itertools.count() 281 | 282 | for station in self.stations.itervalues(): 283 | # because we do a DC PF, we ignore frequencies completely 284 | minv, maxv = min(station.voltages), max(station.voltages) 285 | for voltage in station.voltages: 286 | if station.station_id in loads and voltage == minv: 287 | bus_load = loads[station.station_id] 288 | else: 289 | bus_load = 0 290 | bus_id = next(bus_id_gen) 291 | station_to_bus[station.station_id, voltage] = bus_id 292 | if bus_load < 0: 293 | # it is a generator instead of a load, insert it 294 | generators.append(self._make_generator(bus_id, -bus_load)) 295 | bus_load = 0 296 | nodes.append(self._make_bus(station, voltage, bus_load, bus_id)) 297 | 298 | for voltage in station.voltages: 299 | if voltage != maxv: 300 | # create a transformer branch from max voltage to this voltage 301 | from_bus = station_to_bus[station.station_id, maxv] 302 | to_bus = station_to_bus[station.station_id, voltage] 303 | edges.append(self._make_transformer(from_bus, to_bus)) 304 | 305 | for line in self.lines.itervalues(): 306 | # create branches between stations 307 | for voltage in line.voltages: 308 | from_bus = station_to_bus[line.left.station_id, voltage] 309 | to_bus = station_to_bus[line.right.station_id, voltage] 310 | edges.append(self._make_line(line, from_bus, to_bus)) 311 | 312 | ppc['bus'] = array(nodes) 313 | ppc['gen'] = array(generators) 314 | ppc['branch'] = array(edges) 315 | return ppc 316 | 317 | def _electrified_pair(self): 318 | src, dst = random.sample(self.stations, 2) 319 | return { 320 | src: -100, # MW 321 | dst: 50, # MW 322 | } 323 | 324 | def _make_bus(self, station, voltage, load, bus_id): 325 | # see pypower.caseformat for documentation on how this works 326 | area_nr = self._area_number(station.operator) 327 | base_kv = voltage // 1000 328 | return [ 329 | bus_id, 330 | 3, # slack bus 331 | load, # real load in MW 332 | 0, # reactive load MVAr, zero because DC 333 | 0, # shunt conductance 334 | 0, # shunt susceptance 335 | area_nr, # area number 336 | 1.0, # voltage magnitude per unit 337 | 0, # voltage angle 338 | base_kv, # base voltage (per unit base) 339 | area_nr, # loss zone nr 340 | 1.1, # max voltage per unit 341 | 0.9, # min voltage per unit 342 | ] 343 | 344 | def _make_transformer(self, from_bus, to_bus): 345 | return [ 346 | from_bus, 347 | to_bus, 348 | 0.01, # resistance 349 | 0.01, # reactance 350 | 0.01, # line charging susceptance 351 | 200, # long term rating (MW) 352 | 200, # short term rating (MW) 353 | 200, # emergency rating (MW) 354 | 1, # off-nominal (correction) taps ratio, 1 for no correction 355 | 0, # transformer phase shift angle, 356 | 1, # status (1 = on) 357 | -360, # minimum angle 358 | 360, # maximum angle 359 | ] 360 | 361 | def _make_line(self, line, from_bus, to_bus): 362 | return [ 363 | from_bus, 364 | to_bus, 365 | line.resistance or 0.01, # default value if None 366 | line.reactance or 0.01, 367 | line.susceptance or 0.01, 368 | 200, 369 | 200, 370 | 200, 371 | 0, # not a transformer 372 | 0, # not a transformer 373 | 1, # status 374 | -360, 375 | 360 376 | ] 377 | 378 | def _make_generator(self, bus_id, power_output): 379 | return [ 380 | bus_id, 381 | power_output, 382 | 0, # reactive power output 383 | 0, # maximum reactive power output 384 | 0, # minimum reactive power output 385 | 1.0, # per-unit voltage magnitude setpoint 386 | 100, # base MVA 387 | 1, # status (on) 388 | power_output, # maximum real power output 389 | 0, # minimum real power output 390 | 0, # Pc1, irrelevant 391 | 0, # Pc2 392 | 0, # Qc1min 393 | 0, # Qc1max 394 | 0, # Qc2min 395 | 0, # Qc2max 396 | 5, # ramp rate load-following (MW/min) 397 | 5, # ramp rate 10-min reserve (MW/min) 398 | 5, # ramp rate 30-min reserve (MW/min) 399 | 0, # ramp rate reactive power 400 | 0, # area participation factor 401 | ] 402 | pass 403 | 404 | 405 | def dot(self): 406 | buf = io.StringIO() 407 | buf.write("graph {\n") 408 | buf.write("rankdir LR\n") 409 | for station in self.stations.itervalues(): 410 | buf.write('s_{0} [label="{1}"]\n'.format(station.station_id, station.name.replace('"', "'"))) 411 | for line in self.lines.itervalues(): 412 | buf.write('s_{0} -- s_{1}\n'.format(line.left.station_id, line.right.station_id)) 413 | buf.write("}\n") 414 | return buf.getvalue() 415 | 416 | def __repr__(self): 417 | return "Network of {0} stations, {1} lines".format(len(self.stations), len(self.lines)).encode('utf-8') 418 | 419 | 420 | class ScigridNetwork(Network): 421 | class _csv_dialect(csv.excel): 422 | quotechar = b"'" 423 | 424 | def read(self, vertices_csv, links_csv): 425 | with io.open(vertices_csv, 'rb') as handle: 426 | for row in csv.DictReader(handle, dialect=self._csv_dialect): 427 | station_id = int(row['v_id']) 428 | lat = float(row['lat']) 429 | lon = float(row['lon']) 430 | name = row['name'].decode('utf-8') 431 | operator = row['operator'].decode('utf-8') 432 | voltages = set(map(int, row['voltage'].split(';')) if row['voltage'] else []) 433 | frequencies = set(map(float, row['frequency'].split(';')) if row['frequency'] else []) 434 | self.stations[station_id] = Station(station_id=station_id, lat=lat, lon=lon, name=name, operator=operator, 435 | voltages=voltages, frequencies=frequencies, lines=list()) 436 | 437 | with io.open(links_csv, 'rb') as handle: 438 | for i, row in enumerate(csv.DictReader(handle, dialect=self._csv_dialect)): 439 | line_id = int(row['l_id']) 440 | operator = row['operator'].decode('utf-8') 441 | left = self.stations[int(row['v_id_1'])] 442 | right = self.stations[int(row['v_id_2'])] 443 | length = float(row['length_m']) 444 | resistance = float(row['r_ohmkm']) * int(row['length_m']) / 1000 if row['r_ohmkm'] else None 445 | reactance = float(row['x_ohmkm']) * int(row['length_m']) / 1000 if row['x_ohmkm'] else None 446 | capacitance = float(row['c_nfkm']) * int(row['length_m']) / 1000 if row['c_nfkm'] else None 447 | max_current = float(row['i_th_max_a']) if row['i_th_max_a'] else None 448 | # use complex voltages for lines 449 | frequencies = set(map(float, row['frequency'].split(';')) if row['frequency'] else []) 450 | voltages = set(map(int, row['voltage'].split(';')) if row['voltage'] else []) 451 | line = Line(line_id=line_id, operator=operator, left=left, right=right, length=length, 452 | voltages=voltages, frequencies=frequencies, 453 | resistance=resistance, reactance=reactance, capacitance=capacitance, 454 | max_current=max_current) 455 | self.lines[line_id] = line 456 | left.lines.append(line) 457 | right.lines.append(line) 458 | 459 | --------------------------------------------------------------------------------