~jomco/straatnaam

19b85af995d4bf13b7c219c172b8efa17b74923d — Remco van 't Veer 9 months ago 4c9fd4e
Ignore bad object geometries

Some objects contain geometry values outside of the Netherlands.  They
are wrong, but rare and normally get corrected in the next update but
they do mess up the visualization.
M doc/plot.sh => doc/plot.sh +3 -4
@@ 4,10 4,9 @@

trap "rm -f /tmp/plot-bag-$$.dat" exit

echo "SELECT x || ' ' || y FROM bag" \
echo "SELECT x || ' ' || y FROM bag WHERE x IS NOT NULL AND y IS NOT NULL" \
| psql -At straatnaam \
| grep '^[0-9]' \
> tmp/plot-bag-$$.dat
> /tmp/plot-bag-$$.dat

date=$(
  echo "SELECT TO_CHAR(updated, 'YYYY-MM-DD') FROM bag_syncs ORDER BY updated DESC LIMIT 1" \


@@ 17,5 16,5 @@ date=$(
gnuplot <<-EOF
set terminal png nocrop enhanced size 5000,5000 font "arial,12.0"
set output "plot.png"
plot "tmp/plot-bag-$$.dat" with points pt 1 lt rgb "#000993" title "BAG ${date}"
plot "/tmp/plot-bag-$$.dat" with points pt 1 lt rgb "#000993" title "BAG ${date}"
EOF

A resources/migrations/20230219121751-normalize-geometrie.down.sql => resources/migrations/20230219121751-normalize-geometrie.down.sql +1 -0
@@ 0,0 1,1 @@
DROP FUNCTION public.normalize_geometrie;

A resources/migrations/20230219121751-normalize-geometrie.up.sql => resources/migrations/20230219121751-normalize-geometrie.up.sql +23 -0
@@ 0,0 1,23 @@
--
-- Function returns NULL when object geometry is outside of a bounding
-- box roughly containing Netherlands.
--
-- From the 2022-12 dataset:
--
--  min(x)    | max(x)     | min(y)     | max(y)
-- -----------+------------+------------+------------
--  13611.555 | 277670.742 | 306922.077 | 613137.876

CREATE FUNCTION public.normalize_geometrie(gis.GEOMETRY)
RETURNS gis.GEOMETRY
RETURNS NULL ON NULL INPUT
LANGUAGE SQL
AS '
  SELECT CASE
    WHEN gis.ST_X($1) >  10000 AND gis.ST_X($1) < 290000 AND
         gis.ST_Y($1) > 290000 AND gis.ST_Y($1) < 620000
    THEN $1
    ELSE NULL
  END
'
IMMUTABLE;

M src/straatnaam/lvbag/bag.sql => src/straatnaam/lvbag/bag.sql +37 -25
@@ 6,18 6,22 @@ SELECT DISTINCT ON (num.id)
  num.huisnummertoevoeging                                                  AS huisnummertoevoeging,
  num.postcode                                                              AS postcode,
  COALESCE(wpl.naam, wpl2.naam)                                             AS woonplaats,
  COALESCE(gis.ST_X(vbo.geometrie),
           gis.ST_X(vbo2.geometrie),
           gis.ST_X(gis.ST_CENTROID(lig.geometrie)),
           gis.ST_X(gis.ST_CENTROID(lig2.geometrie)),
           gis.ST_X(gis.ST_CENTROID(sta.geometrie)),
           gis.ST_X(gis.ST_CENTROID(sta2.geometrie)))                       AS x,
  COALESCE(gis.ST_Y(vbo.geometrie),
           gis.ST_Y(vbo2.geometrie),
           gis.ST_Y(gis.ST_CENTROID(lig.geometrie)),
           gis.ST_Y(gis.ST_CENTROID(lig2.geometrie)),
           gis.ST_Y(gis.ST_CENTROID(sta.geometrie)),
           gis.ST_Y(gis.ST_CENTROID(sta2.geometrie)))                       AS y,
  gis.ST_X(
    public.normalize_geometrie(
      COALESCE(vbo.geometrie,
               vbo2.geometrie,
               gis.ST_CENTROID(lig.geometrie),
               gis.ST_CENTROID(lig2.geometrie),
               gis.ST_CENTROID(sta.geometrie),
               gis.ST_CENTROID(sta2.geometrie))))                           AS x,
  gis.ST_Y(
    public.normalize_geometrie(
      COALESCE(vbo.geometrie,
               vbo2.geometrie,
               gis.ST_CENTROID(lig.geometrie),
               gis.ST_CENTROID(lig2.geometrie),
               gis.ST_CENTROID(sta.geometrie),
               gis.ST_CENTROID(sta2.geometrie))))                           AS x,
  vbo2.id IS NOT NULL OR lig2.id IS NOT NULL OR sta2.id IS NOT NULL         AS nevenadres,
  CASE
    WHEN vbo.id IS NOT NULL OR vbo2.id IS NOT NULL THEN 'verblijfsobject'


@@ 28,24 32,32 @@ SELECT DISTINCT ON (num.id)

  COALESCE(vbo.id, vbo2.id, lig.id, lig2.id, sta.id, sta2.id)               AS object_id,

  COALESCE(gis.ST_X(gis.ST_TRANSFORM(vbo.geometrie, 4326)),
           gis.ST_X(gis.ST_TRANSFORM(vbo2.geometrie, 4326)),
           gis.ST_X(gis.ST_TRANSFORM(gis.ST_CENTROID(lig.geometrie), 4326)),
           gis.ST_X(gis.ST_TRANSFORM(gis.ST_CENTROID(lig2.geometrie), 4326)),
           gis.ST_X(gis.ST_TRANSFORM(gis.ST_CENTROID(sta.geometrie), 4326)),
           gis.ST_X(gis.ST_TRANSFORM(gis.ST_CENTROID(sta2.geometrie), 4326)))  AS lengtegraad,
  COALESCE(gis.ST_Y(gis.ST_TRANSFORM(vbo.geometrie, 4326)),
           gis.ST_Y(gis.ST_TRANSFORM(vbo2.geometrie, 4326)),
           gis.ST_Y(gis.ST_TRANSFORM(gis.ST_CENTROID(lig.geometrie), 4326)),
           gis.ST_Y(gis.ST_TRANSFORM(gis.ST_CENTROID(lig2.geometrie), 4326)),
           gis.ST_Y(gis.ST_TRANSFORM(gis.ST_CENTROID(sta.geometrie), 4326)),
           gis.ST_Y(gis.ST_TRANSFORM(gis.ST_CENTROID(sta2.geometrie), 4326)))  AS breedtegraad,
  gis.ST_X(
    gis.ST_TRANSFORM(
      public.normalize_geometrie(
        COALESCE(vbo.geometrie,
                 vbo2.geometrie,
                 gis.ST_CENTROID(lig.geometrie),
                 gis.ST_CENTROID(lig2.geometrie),
                 gis.ST_CENTROID(sta.geometrie),
                 gis.ST_CENTROID(sta2.geometrie))
      ), 4326))                                                             AS lengtegraad,
  gis.ST_Y(
    gis.ST_TRANSFORM(
      public.normalize_geometrie(
        COALESCE(vbo.geometrie,
                 vbo2.geometrie,
                 gis.ST_CENTROID(lig.geometrie),
                 gis.ST_CENTROID(lig2.geometrie),
                 gis.ST_CENTROID(sta.geometrie),
                 gis.ST_CENTROID(sta2.geometrie))
      ), 4326))                                                             AS breedtegraad,
  CASE
    WHEN vbo.id IS NOT NULL OR vbo2.id IS NOT NULL THEN COALESCE(vbo.gebruiksdoelen, vbo2.gebruiksdoelen)
    WHEN lig.id IS NOT NULL OR lig2.id IS NOT NULL THEN '{"ligplaats"}'
    WHEN sta.id IS NOT NULL OR sta2.id IS NOT NULL THEN '{"standplaats"}'
    ELSE NULL
  END                                                                          AS gebruiksdoelen
  END                                                                       AS gebruiksdoelen
FROM
  nummeraanduiding num
LEFT JOIN openbareruimte opr