Skip to content

Instantly share code, notes, and snippets.

@pramsey
Last active January 15, 2016 15:13
Show Gist options
  • Star 2 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save pramsey/eb996055c85d7908d0e3 to your computer and use it in GitHub Desktop.
Save pramsey/eb996055c85d7908d0e3 to your computer and use it in GitHub Desktop.
Parcel Distance to Hydrant
-- An example of a lateral join driving a nearest-neighbor
-- distance calculation
SELECT
parcels.*,
-- keep the hydrant id around, might be useful later
hydrants.cartodb_id as hydrant_cartodb_id,
-- calculate distance over the spheroid using geography distance
ST_Distance(geography(hydrants.the_geom), geography(parcels.the_geom)) as distance
FROM
-- for this data, removing the duplicate parcel geometries and
-- null attributed parcels cuts the size by 2/3 so a good
-- performance improvement to filter records here
(SELECT DISTINCT ON (the_geom) *
FROM parcelsshp
WHERE pid IS NOT NULL) AS parcels
-- cross join takes every combination of join records
-- without restriction, which is fine since we're limiting
-- the hydrants side of the join to just one return record
-- per parcel
CROSS JOIN LATERAL
-- the guts of the query, actually do a KNN query for each
-- candidate parcel on the other side of the join
(SELECT cartodb_id, the_geom
FROM hydrantsshp
ORDER BY parcels.the_geom_webmercator <-> the_geom_webmercator
LIMIT 1) AS hydrants
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment