From c7520f7e7d5f32694de42d4025cbc70e9c9d9f52 Mon Sep 17 00:00:00 2001 From: lukasmartinelli Date: Sat, 8 Oct 2016 18:04:29 +0200 Subject: [PATCH] Add state from Natural Earth --- data.yml | 28 ++++++++++++++++++++++++++ schema/layers/state.sql | 44 +++++++++++++++++++++++++++++++++++++++++ 2 files changed, 72 insertions(+) create mode 100644 schema/layers/state.sql diff --git a/data.yml b/data.yml index 968620b..bbb4a43 100644 --- a/data.yml +++ b/data.yml @@ -191,6 +191,34 @@ Layer: abbrev: String labelrank: Number name: String + postal: String + scalerank: Number + properties: + "buffer-size": 64 + srs: +proj=merc +a=6378137 +b=6378137 +lat_ts=0.0 +lon_0=0.0 +x_0=0.0 +y_0=0.0 +k=1.0 +units=m +nadgrids=@null +wktext +no_defs +over + - id: state + Datasource: + dbname: osm + extent: -20037508.34,-20037508.34,20037508.34,20037508.34 + geometry_field: geom + geometry_table: '' + host: db + key_field: '' + key_field_as_attribute: '' + max_size: 512 + password: osm + port: 5432 + srid: 900913 + table: (SELECT * FROM layer_state(!bbox!, z(!scale_denominator!))) AS t + type: postgis + user: osm + description: Buildings + fields: + abbrev: String + labelrank: Number + name: String + name_en: String + postal: String scalerank: Number properties: "buffer-size": 64 diff --git a/schema/layers/state.sql b/schema/layers/state.sql new file mode 100644 index 0000000..6cad81a --- /dev/null +++ b/schema/layers/state.sql @@ -0,0 +1,44 @@ +CREATE TABLE IF NOT EXISTS state_label AS ( + SELECT topoint(geom) AS geom, + name_local, fix_win1252_shp_encoding(name) AS name_en, + abbrev, postal, + scalerank, labelrank, + shape_area, datarank, type + FROM ne_10m_admin_1_states_provinces_shp + WHERE type IN ('State', 'Avtonomnyy Okrug', 'Sheng', 'Estado') + AND scalerank <= 3 AND labelrank <= 2 +); +CREATE INDEX IF NOT EXISTS state_label_geom_idx ON state_label USING gist(geom); + +CREATE OR REPLACE FUNCTION fix_win1252_shp_encoding(str TEXT) RETURNS TEXT +AS $$ +BEGIN + RETURN convert_from(convert_to(str, 'WIN1252'), 'UTF-8'); + EXCEPTION WHEN others THEN RETURN str; +END; +$$ LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE VIEW state_z3 AS ( + SELECT * FROM state_label + WHERE (scalerank <= 2 AND labelrank <= 1) OR type = 'Avtonomnyy Okrug' +); + +CREATE OR REPLACE VIEW state_z4 AS ( + SELECT * FROM state_label +); + +CREATE OR REPLACE FUNCTION layer_state(bbox geometry, zoom_level int) +RETURNS TABLE(geom geometry, name text, name_en text, abbrev text, postal text, scalerank int, labelrank int) AS $$ + WITH zoom_levels AS ( + SELECT * FROM state_z3 + WHERE zoom_level = 3 + UNION ALL + SELECT * FROM state_z4 + WHERE zoom_level >= 4 + ) + SELECT geom, + COALESCE(name_local, name_en) AS name_local, name_en, + abbrev, postal, scalerank::int, labelrank::int FROM zoom_levels + WHERE geom && bbox + ORDER BY scalerank ASC, labelrank ASC, shape_area DESC; +$$ LANGUAGE SQL IMMUTABLE;