Rename table to subdivided and remove split SQL

pull/367/head
lukasmartinelli 2016-06-28 08:38:03 +02:00
rodzic a76b5e9331
commit b0e7fdf0cb
7 zmienionych plików z 88 dodań i 136 usunięć

Wyświetl plik

@ -135,7 +135,7 @@ import-sql:
- postgis:db
environment:
SQL_CREATE_INDIZES: 'false'
SQL_SPLIT_POLYGON: 'false'
SQL_SUBDIVIDE_POLYGON: 'true'
mapbox-studio:
image: "osm2vectortiles/mapbox-studio"
volumes:

Wyświetl plik

@ -1,43 +0,0 @@
CREATE OR REPLACE FUNCTION zoom_level_grid(
zoom_level INTEGER
) RETURNS TABLE (
tile_z INTEGER,
tile_x INTEGER,
tile_y INTEGER,
tile_geometry GEOMETRY
) AS $$
BEGIN
RETURN QUERY
WITH RECURSIVE tiles(x, y, z, e) AS (
SELECT 0, 0, 0, XYZ_Extent(0, 0, 0, 0)
UNION ALL
SELECT x*2 + xx, y*2 + yy, z+1,
XYZ_Extent(x*2 + xx, y*2 + yy, z+1, 0)
FROM tiles,
(VALUES (0, 0), (0, 1), (1, 1), (1, 0)) as c(xx, yy)
WHERE z < zoom_level
)
SELECT DISTINCT z, x, y, e FROM tiles WHERE z = zoom_level;
END;
$$ LANGUAGE plpgsql IMMUTABLE;
DROP TABLE IF EXISTS grid_z9 CASCADE;
CREATE TABLE grid_z9 AS
SELECT tile_x AS x, tile_y AS y, tile_z AS z, tile_geometry AS geometry
FROM zoom_level_grid(9);
CREATE INDEX ON grid_z9 USING gist (geometry);
DROP TABLE IF EXISTS osm_landuse_split_polygon CASCADE;
CREATE TABLE osm_landuse_split_polygon AS
SELECT id, type, timestamp,
ST_Intersection(p.geometry, grid.geometry) AS geometry
FROM osm_landuse_polygon AS p
LEFT OUTER JOIN grid_z9 AS grid ON (p.geometry && grid.geometry)
WHERE ST_Area(p.geometry) > 1000000000;
CREATE INDEX ON osm_landuse_split_polygon USING gist (geometry);
CREATE INDEX ON osm_landuse_split_polygon
USING btree (st_geohash(st_transform(st_setsrid(box2d(geometry)::geometry, 3857), 4326)));
SELECT UpdateGeometrySRID('osm_landuse_split_polygon','geometry', 3857);

Wyświetl plik

@ -1,41 +1,41 @@
CREATE OR REPLACE VIEW landuse_z5toz6 AS
SELECT id AS osm_id, geometry, type
FROM osm_landuse_polygon_gen0
FROM osm_landuse_polygon_subdivided_gen0
WHERE landuse_class(type) = 'wood';
CREATE OR REPLACE VIEW landuse_z7toz8 AS
SELECT id AS osm_id, geometry, type
FROM osm_landuse_polygon_gen0
FROM osm_landuse_polygon_subdivided_gen0
WHERE landuse_class(type) IN ('wood', 'residential')
AND area > 1000000;
CREATE OR REPLACE VIEW landuse_z9 AS
SELECT id AS osm_id, geometry, type
FROM osm_landuse_polygon_gen0
FROM osm_landuse_polygon_subdivided_gen0
WHERE landuse_class(type) IN ('wood', 'residential', 'grass', 'cemetery', 'park', 'school')
AND area > 500000;
CREATE OR REPLACE VIEW landuse_z10 AS
SELECT id AS osm_id, geometry, type
FROM osm_landuse_polygon_gen0
FROM osm_landuse_polygon_subdivided_gen0
WHERE landuse_class(type) IN ('wood', 'residential', 'commercial', 'retail', 'railway', 'industrial', 'grass', 'cemetery', 'park', 'school')
AND area > 99000;
CREATE OR REPLACE VIEW landuse_z11 AS
SELECT id AS osm_id, geometry, type
FROM osm_landuse_polygon_gen1
FROM osm_landuse_polygon_subdivided_gen1
WHERE landuse_class(type) IN ('wood', 'residential','commercial', 'retail', 'railway', 'industrial', 'military', 'grass', 'cemetery', 'park', 'school', 'hospital')
AND area > 50000;
CREATE OR REPLACE VIEW landuse_z12 AS
SELECT id AS osm_id, geometry, type
FROM osm_landuse_polygon
FROM osm_landuse_polygon_subdivided
WHERE landuse_class(type) IN ('wood', 'residential', 'grass','retail', 'railway', 'industrial', 'military', 'cemetery', 'park', 'school', 'hospital')
AND area > 10000;
CREATE OR REPLACE VIEW landuse_z13toz14 AS
SELECT id AS osm_id, geometry, type
FROM osm_landuse_polygon
FROM osm_landuse_polygon_subdivided
WHERE type NOT IN ('wetland', 'marsh', 'swamp', 'bog', 'mud', 'tidalflat', 'national_park', 'nature_reserve', 'protected_area');
CREATE OR REPLACE VIEW landuse_layer AS (

Wyświetl plik

@ -7,42 +7,42 @@ $$ LANGUAGE plpgsql;
CREATE OR REPLACE VIEW landuse_overlay_z5 AS
SELECT id AS osm_id, type, geometry
FROM osm_landuse_polygon_gen0
WHERE is_landuse_overlay(type) AND st_area(geometry) > 300000000;
FROM osm_landuse_polygon_subdivided_gen0
WHERE is_landuse_overlay(type) AND area > 300000000;
CREATE OR REPLACE VIEW landuse_overlay_z6 AS
SELECT id AS osm_id, type, geometry
FROM osm_landuse_polygon_gen0
WHERE is_landuse_overlay(type) AND st_area(geometry) > 100000000;
FROM osm_landuse_polygon_subdivided_gen0
WHERE is_landuse_overlay(type) AND area > 100000000;
CREATE OR REPLACE VIEW landuse_overlay_z7 AS
SELECT id AS osm_id, type, geometry
FROM osm_landuse_polygon_gen0
WHERE is_landuse_overlay(type) AND st_area(geometry) > 20000000;
FROM osm_landuse_polygon_subdivided_gen0
WHERE is_landuse_overlay(type) AND area > 20000000;
CREATE OR REPLACE VIEW landuse_overlay_z8 AS
SELECT id AS osm_id, type, geometry
FROM osm_landuse_polygon_gen0
WHERE is_landuse_overlay(type) AND st_area(geometry) > 6000000;
FROM osm_landuse_polygon_subdivided_gen0
WHERE is_landuse_overlay(type) AND area > 6000000;
CREATE OR REPLACE VIEW landuse_overlay_z9 AS
SELECT id AS osm_id, type, geometry
FROM osm_landuse_polygon_gen0
WHERE is_landuse_overlay(type) AND st_area(geometry) > 2000000;
FROM osm_landuse_polygon_subdivided_gen0
WHERE is_landuse_overlay(type) AND area > 2000000;
CREATE OR REPLACE VIEW landuse_overlay_z10 AS
SELECT id AS osm_id, type, geometry
FROM osm_landuse_polygon_gen0
WHERE is_landuse_overlay(type) AND st_area(geometry) > 500000;
FROM osm_landuse_polygon_subdivided_gen0
WHERE is_landuse_overlay(type) AND area > 500000;
CREATE OR REPLACE VIEW landuse_overlay_z11toz12 AS
SELECT id AS osm_id, type, geometry
FROM osm_landuse_polygon_gen1
FROM osm_landuse_polygon_subdivided_gen1
WHERE is_landuse_overlay(type);
CREATE OR REPLACE VIEW landuse_overlay_z13toz14 AS
SELECT id AS osm_id, type, geometry
FROM osm_landuse_polygon
FROM osm_landuse_polygon_subdivided
WHERE is_landuse_overlay(type);
CREATE OR REPLACE VIEW landuse_overlay_layer AS (

Wyświetl plik

@ -1,48 +1,48 @@
CREATE OR REPLACE VIEW water_z0 AS
SELECT 0 AS osm_id, geom AS geometry
FROM ne_110m_ocean
FROM ne_110m_ocean_subdivided
UNION ALL
SELECT 0 AS osm_id, geom AS geometry
FROM ne_110m_lakes;
CREATE OR REPLACE VIEW water_z1 AS
SELECT 0 AS osm_id, geom AS geometry
FROM ne_50m_ocean
FROM ne_50m_ocean_subdivided
UNION ALL
SELECT 0 AS osm_id, geom AS geometry
FROM ne_110m_lakes;
CREATE OR REPLACE VIEW water_z2toz3 AS
SELECT 0 AS osm_id, geom AS geometry
FROM ne_10m_ocean
FROM ne_10m_ocean_subdivided
UNION ALL
SELECT 0 AS osm_id, geom AS geometry
FROM ne_50m_lakes;
CREATE OR REPLACE VIEW water_z4 AS
SELECT 0 AS osm_id, geometry
FROM osm_ocean_polygon_gen0
FROM osm_ocean_polygon_subdivided_gen0
UNION ALL
SELECT 0 AS osm_id, geom AS geometry
FROM ne_10m_lakes;
CREATE OR REPLACE VIEW water_z5toz7 AS
SELECT 0 AS osm_id, geometry
FROM osm_ocean_polygon_gen0
FROM osm_ocean_polygon_subdivided_gen0
UNION ALL
SELECT id AS osm_id, geometry
FROM osm_water_polygon_gen1;
CREATE OR REPLACE VIEW water_z8toz10 AS
SELECT 0 AS osm_id, geometry
FROM osm_ocean_polygon
FROM osm_ocean_polygon_subdivided
UNION ALL
SELECT id AS osm_id, geometry
FROM osm_water_polygon_gen1;
CREATE OR REPLACE VIEW water_z11toz12 AS
SELECT 0 AS osm_id, geometry, 0 AS area
FROM osm_ocean_polygon
FROM osm_ocean_polygon_subdivided
UNION ALL
SELECT id AS osm_id, geometry, area
FROM osm_water_polygon
@ -50,7 +50,7 @@ CREATE OR REPLACE VIEW water_z11toz12 AS
CREATE OR REPLACE VIEW water_z13toz14 AS
SELECT 0 AS osm_id, geometry
FROM osm_ocean_polygon
FROM osm_ocean_polygon_subdivided
UNION ALL
SELECT id AS osm_id, geometry
FROM osm_water_polygon;

Wyświetl plik

@ -26,24 +26,19 @@ function exec_sql_file() {
}
function main() {
echo "Subdividing polygons in $OSM_DB"
exec_sql_file "$SQL_SUBDIVIDE_POLYGON_FILE"
if [ "$SQL_SUBDIVIDE_POLYGON" = true ] ; then
echo "Subdividing polygons in $OSM_DB"
exec_sql_file "$SQL_SUBDIVIDE_POLYGON_FILE"
else
echo "Omitting subdividing polygons for $OSM_DB"
fi
echo "Creating functions in $OSM_DB"
exec_sql_file "$SQL_FUNCTIONS_FILE"
exec_sql_file "$SQL_XYZ_EXTENT_FILE"
echo "Creating generated functions in $OSM_DB"
exec_sql_file "$SQL_GENERATED_FILE"
echo "Creating triggers in $OSM_DB"
if [ "$SQL_SPLIT_POLYGON" = true ] ; then
echo "Split polygons for $OSM_DB"
exec_sql_file "${SQL_SPLIT_POLYGON_FILE}"
else
echo "Omitting splitting polygon for $OSM_DB"
fi
exec_sql_file "$SQL_TRIGGERS_FILE"
echo "Creating layers in $OSM_DB"
exec_sql_file "${SQL_LAYERS_DIR}admin.sql"

Wyświetl plik

@ -1,78 +1,78 @@
/* OSM Landuse Polygons */
ALTER TABLE osm_landuse_polygon_gen0 RENAME TO osm_landuse_polygon_gen0_full;
ALTER TABLE osm_landuse_polygon_gen1 RENAME TO osm_landuse_polygon_gen1_full;
ALTER TABLE osm_landuse_polygon RENAME TO osm_landuse_polygon_full;
DROP TABLE IF EXISTS osm_landuse_polygon_subdivided_gen0 CASCADE;
DROP TABLE IF EXISTS osm_landuse_polygon_subdivided_gen1 CASCADE;
DROP TABLE IF EXISTS osm_landuse_polygon_subdivided CASCADE;
CREATE TABLE osm_landuse_polygon_gen0 AS SELECT id,timestamp,type,st_subdivide(geometry,1024) AS geometry FROM osm_landuse_polygon_gen0_full;
CREATE TABLE osm_landuse_polygon_gen1 AS SELECT id,timestamp,type,st_subdivide(geometry,1024) AS geometry FROM osm_landuse_polygon_gen1_full;
CREATE TABLE osm_landuse_polygon AS SELECT id,timestamp,type,st_subdivide(geometry,1024) AS geometry FROM osm_landuse_polygon_full;
CREATE TABLE osm_landuse_polygon_subdivided_gen0 AS SELECT id,timestamp,type,area,st_subdivide(geometry,1024) AS geometry FROM osm_landuse_polygon_gen0;
CREATE TABLE osm_landuse_polygon_subdivided_gen1 AS SELECT id,timestamp,type,area,st_subdivide(geometry,1024) AS geometry FROM osm_landuse_polygon_gen1;
CREATE TABLE osm_landuse_polygon_subdivided AS SELECT id,timestamp,type,area,st_subdivide(geometry,1024) AS geometry FROM osm_landuse_polygon;
SELECT UpdateGeometrySRID('osm_landuse_polygon_gen0','geometry',3857);
SELECT UpdateGeometrySRID('osm_landuse_polygon_gen1','geometry',3857);
SELECT UpdateGeometrySRID('osm_landuse_polygon','geometry',3857);
SELECT UpdateGeometrySRID('osm_landuse_polygon_subdivided_gen0','geometry',3857);
SELECT UpdateGeometrySRID('osm_landuse_polygon_subdivided_gen1','geometry',3857);
SELECT UpdateGeometrySRID('osm_landuse_polygon_subdivided','geometry',3857);
CREATE INDEX ON osm_landuse_polygon_gen0 USING btree(id);
CREATE INDEX ON osm_landuse_polygon_gen1 USING btree(id);
CREATE INDEX ON osm_landuse_polygon USING btree(id);
CREATE INDEX ON osm_landuse_polygon_subdivided_gen0 USING btree(id);
CREATE INDEX ON osm_landuse_polygon_subdivided_gen1 USING btree(id);
CREATE INDEX ON osm_landuse_polygon_subdivided USING btree(id);
CREATE INDEX ON osm_landuse_polygon_gen0 USING btree (st_geohash(st_transform(st_setsrid(box2d(geometry)::geometry, 3857), 4326)));
CREATE INDEX ON osm_landuse_polygon_gen1 USING btree (st_geohash(st_transform(st_setsrid(box2d(geometry)::geometry, 3857), 4326)));
CREATE INDEX ON osm_landuse_polygon USING btree (st_geohash(st_transform(st_setsrid(box2d(geometry)::geometry, 3857), 4326)));
CREATE INDEX ON osm_landuse_polygon_subdivided_gen0 USING btree (st_geohash(st_transform(st_setsrid(box2d(geometry)::geometry, 3857), 4326)));
CREATE INDEX ON osm_landuse_polygon_subdivided_gen1 USING btree (st_geohash(st_transform(st_setsrid(box2d(geometry)::geometry, 3857), 4326)));
CREATE INDEX ON osm_landuse_polygon_subdivided USING btree (st_geohash(st_transform(st_setsrid(box2d(geometry)::geometry, 3857), 4326)));
CREATE INDEX ON osm_landuse_polygon_gen0 USING gist (geometry);
CREATE INDEX ON osm_landuse_polygon_gen1 USING gist (geometry);
CREATE INDEX ON osm_landuse_polygon USING gist (geometry);
CREATE INDEX ON osm_landuse_polygon_subdivided_gen0 USING gist (geometry);
CREATE INDEX ON osm_landuse_polygon_subdivided_gen1 USING gist (geometry);
CREATE INDEX ON osm_landuse_polygon_subdivided USING gist (geometry);
ANALYZE osm_landuse_polygon_gen0;
ANALYZE osm_landuse_polygon_gen1;
ANALYZE osm_landuse_polygon;
ANALYZE osm_landuse_polygon_subdivided_gen0;
ANALYZE osm_landuse_polygon_subdivided_gen1;
ANALYZE osm_landuse_polygon_subdivided;
/* OSM Ocean Polygons */
ALTER TABLE osm_ocean_polygon RENAME TO osm_ocean_polygon_full;
ALTER TABLE osm_ocean_polygon_gen0 RENAME TO osm_ocean_polygon_gen0_full;
DROP TABLE IF EXISTS osm_ocean_polygon_subdivided CASCADE;
DROP TABLE IF EXISTS osm_ocean_polygon_subdivided_gen0 CASCADE;
CREATE TABLE osm_ocean_polygon AS SELECT gid,fid,st_subdivide(geometry,1024) AS geometry FROM osm_ocean_polygon_full;
CREATE TABLE osm_ocean_polygon_gen0 AS SELECT gid,fid,st_subdivide(geometry,1024) AS geometry FROM osm_ocean_polygon_gen0_full;
CREATE TABLE osm_ocean_polygon_subdivided AS SELECT gid,fid,st_subdivide(geometry,1024) AS geometry FROM osm_ocean_polygon;
CREATE TABLE osm_ocean_polygon_subdivided_gen0 AS SELECT gid,fid,st_subdivide(geometry,1024) AS geometry FROM osm_ocean_polygon_gen0;
SELECT UpdateGeometrySRID('osm_ocean_polygon_gen0','geometry',3857);
SELECT UpdateGeometrySRID('osm_ocean_polygon','geometry',3857);
SELECT UpdateGeometrySRID('osm_ocean_polygon_subdivided_gen0','geometry',3857);
SELECT UpdateGeometrySRID('osm_ocean_polygon_subdivided','geometry',3857);
CREATE INDEX ON osm_ocean_polygon USING btree (gid);
CREATE INDEX ON osm_ocean_polygon_gen0 USING btree (gid);
CREATE INDEX ON osm_ocean_polygon_subdivided USING btree (gid);
CREATE INDEX ON osm_ocean_polygon_subdivided_gen0 USING btree (gid);
CREATE INDEX ON osm_ocean_polygon USING gist (geometry);
CREATE INDEX ON osm_ocean_polygon_gen0 USING gist (geometry);
CREATE INDEX ON osm_ocean_polygon_subdivided USING gist (geometry);
CREATE INDEX ON osm_ocean_polygon_subdivided_gen0 USING gist (geometry);
ANALYZE osm_ocean_polygon;
ANALYZE osm_ocean_polygon_gen0;
ANALYZE osm_ocean_polygon_subdivided;
ANALYZE osm_ocean_polygon_subdivided_gen0;
/* Natural-Earth Ocean Polygons */
ALTER TABLE ne_110m_ocean RENAME TO ne_110m_ocean_full;
ALTER TABLE ne_50m_ocean RENAME TO ne_50m_ocean_full;
ALTER TABLE ne_10m_ocean RENAME TO ne_10m_ocean_full;
DROP TABLE IF EXISTS ne_110m_ocean_subdivided CASCADE;
DROP TABLE IF EXISTS ne_50m_ocean_subdivided CASCADE;
DROP TABLE IF EXISTS ne_10m_ocean_subdivided CASCADE;
CREATE TABLE ne_110m_ocean AS SELECT ogc_fid,st_subdivide(geom,1024) AS geom,scalerank,featurecla FROM ne_110m_ocean_full;
CREATE TABLE ne_50m_ocean AS SELECT ogc_fid,st_subdivide(geom,1024) AS geom,scalerank,featurecla FROM ne_50m_ocean_full;
CREATE TABLE ne_10m_ocean AS SELECT ogc_fid,st_subdivide(geom,1024) AS geom,featurecla,scalerank FROM ne_10m_ocean_full;
CREATE TABLE ne_110m_ocean_subdivided AS SELECT ogc_fid,st_subdivide(geom,1024) AS geom,scalerank,featurecla FROM ne_110m_ocean;
CREATE TABLE ne_50m_ocean_subdivided AS SELECT ogc_fid,st_subdivide(geom,1024) AS geom,scalerank,featurecla FROM ne_50m_ocean;
CREATE TABLE ne_10m_ocean_subdivided AS SELECT ogc_fid,st_subdivide(geom,1024) AS geom,featurecla,scalerank FROM ne_10m_ocean;
SELECT UpdateGeometrySRID('ne_110m_ocean','geom',3857);
SELECT UpdateGeometrySRID('ne_50m_ocean','geom',3857);
SELECT UpdateGeometrySRID('ne_10m_ocean','geom',3857);
SELECT UpdateGeometrySRID('ne_110m_ocean_subdivided','geom',3857);
SELECT UpdateGeometrySRID('ne_50m_ocean_subdivided','geom',3857);
SELECT UpdateGeometrySRID('ne_10m_ocean_subdivided','geom',3857);
CREATE INDEX ON ne_110m_ocean USING btree (ogc_fid);
CREATE INDEX ON ne_50m_ocean USING btree (ogc_fid);
CREATE INDEX ON ne_10m_ocean USING btree (ogc_fid);
CREATE INDEX ON ne_110m_ocean_subdivided USING btree (ogc_fid);
CREATE INDEX ON ne_50m_ocean_subdivided USING btree (ogc_fid);
CREATE INDEX ON ne_10m_ocean_subdivided USING btree (ogc_fid);
CREATE INDEX ON ne_110m_ocean USING gist (geom);
CREATE INDEX ON ne_50m_ocean USING gist (geom);
CREATE INDEX ON ne_10m_ocean USING gist (geom);
CREATE INDEX ON ne_110m_ocean_subdivided USING gist (geom);
CREATE INDEX ON ne_50m_ocean_subdivided USING gist (geom);
CREATE INDEX ON ne_10m_ocean_subdivided USING gist (geom);
ANALYZE ne_110m_ocean;
ANALYZE ne_50m_ocean;
ANALYZE ne_10m_ocean;
ANALYZE ne_110m_ocean_subdivided;
ANALYZE ne_50m_ocean_subdivided;
ANALYZE ne_10m_ocean_subdivided;
/* Update SRID for lakes and water polygons */