Refactor schema, one _gen_z view per zoom. (#1045)
* Refactor layer aeroway. * Refactor layer boundary. * Refactor layer landcover. * Refactor layer landuse. * Refactor layer park. * Refactor layer transportation. * Refactor layer water. * Refactor layer waterway. * Re-generate water* layers etl_diagrams. * Regenerate etl_diagrams for waterway. * Cast NULL to text.
This commit is contained in:
@@ -18,220 +18,401 @@ $$ LANGUAGE SQL IMMUTABLE
|
||||
STRICT
|
||||
PARALLEL SAFE;
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW water_z0 AS
|
||||
-- ne_10m_ocean
|
||||
-- etldoc: ne_10m_ocean -> ne_10m_ocean_gen_z5
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_10m_ocean_gen_z5 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_10m_ocean_gen_z5 AS
|
||||
(
|
||||
-- etldoc: ne_110m_ocean -> water_z0
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_110m_ocean
|
||||
UNION ALL
|
||||
-- etldoc: ne_110m_lakes -> water_z0
|
||||
SELECT geometry,
|
||||
'lake'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_110m_lakes
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z1 AS
|
||||
(
|
||||
-- etldoc: ne_110m_ocean -> water_z1
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_110m_ocean
|
||||
UNION ALL
|
||||
-- etldoc: ne_110m_lakes -> water_z1
|
||||
SELECT geometry,
|
||||
'lake'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_110m_lakes
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z2 AS
|
||||
(
|
||||
-- etldoc: ne_50m_ocean -> water_z2
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_50m_ocean
|
||||
UNION ALL
|
||||
-- etldoc: ne_50m_lakes -> water_z2
|
||||
SELECT geometry,
|
||||
'lake'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_50m_lakes
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z4 AS
|
||||
(
|
||||
-- etldoc: ne_50m_ocean -> water_z4
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_50m_ocean
|
||||
UNION ALL
|
||||
-- etldoc: ne_10m_lakes -> water_z4
|
||||
SELECT geometry,
|
||||
'lake'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_10m_lakes
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z5 AS
|
||||
(
|
||||
-- etldoc: ne_10m_ocean -> water_z5
|
||||
SELECT geometry,
|
||||
SELECT ST_Simplify(geometry, ZRes(7)) AS geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_10m_ocean
|
||||
UNION ALL
|
||||
-- etldoc: ne_10m_lakes -> water_z5
|
||||
SELECT geometry,
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_10m_ocean_gen_z5_idx ON ne_10m_ocean_gen_z5 USING gist (geometry);
|
||||
|
||||
-- ne_10m_lakes
|
||||
-- etldoc: ne_10m_lakes -> ne_10m_lakes_gen_z5
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_10m_lakes_gen_z5 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_10m_lakes_gen_z5 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(7)) AS geometry,
|
||||
'lake'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_10m_lakes
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_10m_lakes_gen_z5_idx ON ne_10m_lakes_gen_z5 USING gist (geometry);
|
||||
|
||||
-- etldoc: ne_10m_lakes -> ne_10m_lakes_gen_z4
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_10m_lakes_gen_z4 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_10m_lakes_gen_z4 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(6)) AS geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_10m_lakes_gen_z5
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_10m_lakes_gen_z4_idx ON ne_10m_lakes_gen_z4 USING gist (geometry);
|
||||
|
||||
-- ne_50m_ocean
|
||||
-- etldoc: ne_50m_ocean -> ne_50m_ocean_gen_z4
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z4 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z4 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(6)) AS geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_50m_ocean
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z4_idx ON ne_50m_ocean_gen_z4 USING gist (geometry);
|
||||
|
||||
-- etldoc: ne_50m_ocean_gen_z4 -> ne_50m_ocean_gen_z3
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z3 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z3 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(5)) AS geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_50m_ocean_gen_z4
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z3_idx ON ne_50m_ocean_gen_z3 USING gist (geometry);
|
||||
|
||||
-- etldoc: ne_50m_ocean_gen_z3 -> ne_50m_ocean_gen_z2
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z2 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z2 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(4)) AS geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_50m_ocean_gen_z3
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z2_idx ON ne_50m_ocean_gen_z2 USING gist (geometry);
|
||||
|
||||
-- ne_50m_lakes
|
||||
-- etldoc: ne_50m_lakes -> ne_50m_lakes_gen_z3
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_50m_lakes_gen_z3 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_50m_lakes_gen_z3 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(5)) AS geometry,
|
||||
'lakes'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_50m_lakes
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_50m_lakes_gen_z3_idx ON ne_50m_lakes_gen_z3 USING gist (geometry);
|
||||
|
||||
-- etldoc: ne_50m_lakes_gen_z3 -> ne_50m_lakes_gen_z2
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_50m_lakes_gen_z2 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_50m_lakes_gen_z2 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(4)) AS geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_50m_lakes_gen_z3
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_50m_lakes_gen_z2_idx ON ne_50m_lakes_gen_z2 USING gist (geometry);
|
||||
|
||||
--ne_110m_ocean
|
||||
-- etldoc: ne_110m_ocean -> ne_110m_ocean_gen_z1
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_110m_ocean_gen_z1 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_110m_ocean_gen_z1 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(3)) AS geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_110m_ocean
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_110m_ocean_gen_z1_idx ON ne_110m_ocean_gen_z1 USING gist (geometry);
|
||||
|
||||
-- etldoc: ne_110m_ocean_gen_z1 -> ne_110m_ocean_gen_z0
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_110m_ocean_gen_z0 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_110m_ocean_gen_z0 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(2)) AS geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_110m_ocean_gen_z1
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_110m_ocean_gen_z0_idx ON ne_110m_ocean_gen_z0 USING gist (geometry);
|
||||
|
||||
|
||||
-- ne_110m_lakes
|
||||
-- etldoc: ne_110m_lakes -> ne_110m_lakes_gen_z1
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_110m_lakes_gen_z1 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_110m_lakes_gen_z1 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(3)) AS geometry,
|
||||
'lakes'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM ne_110m_lakes
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z1_idx ON ne_110m_lakes_gen_z1 USING gist (geometry);
|
||||
|
||||
-- etldoc: ne_110m_lakes_gen_z1 -> ne_110m_lakes_gen_z0
|
||||
DROP MATERIALIZED VIEW IF EXISTS ne_110m_lakes_gen_z0 CASCADE;
|
||||
CREATE MATERIALIZED VIEW ne_110m_lakes_gen_z0 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, ZRes(2)) AS geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_110m_lakes_gen_z1
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
||||
CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z0_idx ON ne_110m_lakes_gen_z0 USING gist (geometry);
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW water_z0 AS
|
||||
(
|
||||
-- etldoc: ne_110m_ocean_gen_z0 -> water_z0
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_110m_ocean_gen_z0
|
||||
UNION ALL
|
||||
-- etldoc: ne_110m_lakes_gen_z0 -> water_z0
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_110m_lakes_gen_z0
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z1 AS
|
||||
(
|
||||
-- etldoc: ne_110m_ocean_gen_z1 -> water_z1
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_110m_ocean_gen_z1
|
||||
UNION ALL
|
||||
-- etldoc: ne_110m_lakes_gen_z1 -> water_z1
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_110m_lakes_gen_z1
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z2 AS
|
||||
(
|
||||
-- etldoc: ne_50m_ocean_gen_z2 -> water_z2
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_50m_ocean_gen_z2
|
||||
UNION ALL
|
||||
-- etldoc: ne_50m_lakes_gen_z2 -> water_z2
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_50m_lakes_gen_z2
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z3 AS
|
||||
(
|
||||
-- etldoc: ne_50m_ocean_gen_z3 -> water_z3
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_50m_ocean_gen_z3
|
||||
UNION ALL
|
||||
-- etldoc: ne_50m_lakes_gen_z3 -> water_z3
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_50m_lakes_gen_z3
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z4 AS
|
||||
(
|
||||
-- etldoc: ne_50m_ocean_gen_z4 -> water_z4
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_50m_ocean_gen_z4
|
||||
UNION ALL
|
||||
-- etldoc: ne_10m_lakes_gen_z4 -> water_z4
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_10m_lakes_gen_z4
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z5 AS
|
||||
(
|
||||
-- etldoc: ne_10m_ocean_gen_z5 -> water_z5
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_10m_ocean_gen_z5
|
||||
UNION ALL
|
||||
-- etldoc: ne_10m_lakes_gen_z5 -> water_z5
|
||||
SELECT geometry,
|
||||
class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM ne_10m_lakes_gen_z5
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z6 AS
|
||||
(
|
||||
-- etldoc: osm_ocean_polygon_gen4 -> water_z6
|
||||
-- etldoc: osm_ocean_polygon_gen_z6 -> water_z6
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_ocean_polygon_gen4
|
||||
FROM osm_ocean_polygon_gen_z6
|
||||
UNION ALL
|
||||
-- etldoc: osm_water_polygon_gen6 -> water_z6
|
||||
-- etldoc: osm_water_polygon_gen_z6 -> water_z6
|
||||
SELECT geometry,
|
||||
water_class(waterway) AS class,
|
||||
is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_water_polygon_gen6
|
||||
FROM osm_water_polygon_gen_z6
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z7 AS
|
||||
(
|
||||
-- etldoc: osm_ocean_polygon_gen4 -> water_z7
|
||||
-- etldoc: osm_ocean_polygon_gen_z7 -> water_z7
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_ocean_polygon_gen4
|
||||
FROM osm_ocean_polygon_gen_z7
|
||||
UNION ALL
|
||||
-- etldoc: osm_water_polygon_gen5 -> water_z7
|
||||
-- etldoc: osm_water_polygon_gen_z7 -> water_z7
|
||||
SELECT geometry,
|
||||
water_class(waterway) AS class,
|
||||
is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_water_polygon_gen5
|
||||
FROM osm_water_polygon_gen_z7
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z8 AS
|
||||
(
|
||||
-- etldoc: osm_ocean_polygon_gen4 -> water_z8
|
||||
-- etldoc: osm_ocean_polygon_gen_z8 -> water_z8
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_ocean_polygon_gen4
|
||||
FROM osm_ocean_polygon_gen_z8
|
||||
UNION ALL
|
||||
-- etldoc: osm_water_polygon_gen4 -> water_z8
|
||||
-- etldoc: osm_water_polygon_gen_z8 -> water_z8
|
||||
SELECT geometry,
|
||||
water_class(waterway) AS class,
|
||||
is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_water_polygon_gen4
|
||||
FROM osm_water_polygon_gen_z8
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z9 AS
|
||||
(
|
||||
-- etldoc: osm_ocean_polygon_gen3 -> water_z9
|
||||
-- etldoc: osm_ocean_polygon_gen_z9 -> water_z9
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_ocean_polygon_gen3
|
||||
FROM osm_ocean_polygon_gen_z9
|
||||
UNION ALL
|
||||
-- etldoc: osm_water_polygon_gen3 -> water_z9
|
||||
-- etldoc: osm_water_polygon_gen_z9 -> water_z9
|
||||
SELECT geometry,
|
||||
water_class(waterway) AS class,
|
||||
is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_water_polygon_gen3
|
||||
FROM osm_water_polygon_gen_z9
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z10 AS
|
||||
(
|
||||
-- etldoc: osm_ocean_polygon_gen2 -> water_z10
|
||||
-- etldoc: osm_ocean_polygon_gen_z10 -> water_z10
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_ocean_polygon_gen2
|
||||
FROM osm_ocean_polygon_gen_z10
|
||||
UNION ALL
|
||||
-- etldoc: osm_water_polygon_gen2 -> water_z10
|
||||
-- etldoc: osm_water_polygon_gen_z10 -> water_z10
|
||||
SELECT geometry,
|
||||
water_class(waterway) AS class,
|
||||
is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_water_polygon_gen2
|
||||
FROM osm_water_polygon_gen_z10
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z11 AS
|
||||
(
|
||||
-- etldoc: osm_ocean_polygon_gen1 -> water_z11
|
||||
-- etldoc: osm_ocean_polygon_gen_z11 -> water_z11
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_ocean_polygon_gen1
|
||||
FROM osm_ocean_polygon_gen_z11
|
||||
UNION ALL
|
||||
-- etldoc: osm_water_polygon_gen1 -> water_z11
|
||||
-- etldoc: osm_water_polygon_gen_z11 -> water_z11
|
||||
SELECT geometry,
|
||||
water_class(waterway) AS class,
|
||||
is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_water_polygon_gen1
|
||||
FROM osm_water_polygon_gen_z11
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
@@ -255,48 +436,8 @@ FROM osm_water_polygon
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z13 AS
|
||||
(
|
||||
-- etldoc: osm_ocean_polygon_union -> water_z13
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_ocean_polygon_union
|
||||
UNION ALL
|
||||
-- etldoc: osm_water_polygon -> water_z13
|
||||
SELECT geometry,
|
||||
water_class(waterway) AS class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM osm_water_polygon
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE VIEW water_z14 AS
|
||||
(
|
||||
-- etldoc: osm_ocean_polygon_union -> water_z14
|
||||
SELECT geometry,
|
||||
'ocean'::text AS class,
|
||||
NULL::boolean AS is_intermittent,
|
||||
NULL::boolean AS is_bridge,
|
||||
NULL::boolean AS is_tunnel
|
||||
FROM osm_ocean_polygon_union
|
||||
UNION ALL
|
||||
-- etldoc: osm_water_polygon -> water_z14
|
||||
SELECT geometry,
|
||||
water_class(waterway) AS class,
|
||||
is_intermittent,
|
||||
is_bridge,
|
||||
is_tunnel
|
||||
FROM osm_water_polygon
|
||||
WHERE "natural" != 'bay'
|
||||
);
|
||||
|
||||
-- etldoc: layer_water [shape=record fillcolor=lightpink, style="rounded,filled",
|
||||
-- etldoc: label="layer_water |<z0> z0|<z1>z1|<z2>z2|<z3>z3 |<z4> z4|<z5>z5|<z6>z6|<z7>z7| <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14_> z14+" ] ;
|
||||
-- etldoc: label="layer_water |<z0> z0|<z1>z1|<z2>z2|<z3>z3 |<z4> z4|<z5>z5|<z6>z6|<z7>z7| <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12+" ] ;
|
||||
|
||||
CREATE OR REPLACE FUNCTION layer_water(bbox geometry, zoom_level int)
|
||||
RETURNS TABLE
|
||||
@@ -324,10 +465,14 @@ FROM (
|
||||
WHERE zoom_level = 1
|
||||
UNION ALL
|
||||
-- etldoc: water_z2 -> layer_water:z2
|
||||
-- etldoc: water_z2 -> layer_water:z3
|
||||
SELECT *
|
||||
FROM water_z2
|
||||
WHERE zoom_level BETWEEN 2 AND 3
|
||||
WHERE zoom_level = 2
|
||||
UNION ALL
|
||||
-- etldoc: water_z3 -> layer_water:z3
|
||||
SELECT *
|
||||
FROM water_z3
|
||||
WHERE zoom_level = 3
|
||||
UNION ALL
|
||||
-- etldoc: water_z4 -> layer_water:z4
|
||||
SELECT *
|
||||
@@ -372,17 +517,7 @@ FROM (
|
||||
-- etldoc: water_z12 -> layer_water:z12
|
||||
SELECT *
|
||||
FROM water_z12
|
||||
WHERE zoom_level = 12
|
||||
UNION ALL
|
||||
-- etldoc: water_z13 -> layer_water:z13
|
||||
SELECT *
|
||||
FROM water_z13
|
||||
WHERE zoom_level = 13
|
||||
UNION ALL
|
||||
-- etldoc: water_z14 -> layer_water:z14_
|
||||
SELECT *
|
||||
FROM water_z14
|
||||
WHERE zoom_level >= 14
|
||||
WHERE zoom_level >= 12
|
||||
) AS zoom_levels
|
||||
WHERE geometry && bbox;
|
||||
$$ LANGUAGE SQL STABLE
|
||||
|
||||
Reference in New Issue
Block a user