st_distance.sql 2.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566
  1. -- The city engineer needs a list of all buildings within one foot of
  2. -- any lot line. The building_id column of the buildingfootprints table
  3. -- uniquely identifies each building. The lot_id column identifies
  4. -- the lot each building belongs to. The footprints multipolygon
  5. -- stores the geometry of each building's footprint.
  6. CREATE TABLE buildingfootprints (building_id integer,
  7. lot_id integer,
  8. footprint ST_Multipolygon);
  9. -- The lots table stores the lot_id, which uniquely identifies each lot,
  10. -- and the lot ST_MultiPolygon that contains the lot geometry.
  11. CREATE TABLE lots (lot_id integer,
  12. lot ST_Multipolygon);
  13. INSERT INTO buildingfootprints VALUES(
  14. 506, 1010,
  15. ST_MPolyFromText('multipolygon (((7.0 45.0,15.0 45.0,15.0 51.0,18.0 51.0,18.0 54.0,8.0 54.0,8.0 51.0,7.0 51.0,7.0 45.0)))',1000)
  16. );
  17. INSERT INTO buildingfootprints VALUES(
  18. 543, 2930,
  19. ST_MPolyFromText('multipolygon (((26.0 55.0,38.0 55.0,38.0 48.0,34.0 48.0,34.0 50.0,26.0 50.0,26.0 55.0)))',1000)
  20. );
  21. INSERT INTO buildingfootprints VALUES(
  22. 1208, 203,
  23. ST_MPolyFromText('multipolygon (((8.0 39.0,12.0 39.0,12.0 33.0,17.0 33.0,17.0 22.0,8.0 22.0,8.0 39.0)))',1000)
  24. );
  25. INSERT INTO buildingfootprints VALUES(
  26. 178, 5192,
  27. ST_MPolyFromText('multipolygon (((26.0 33.0,38.0 33.0,38.0 24.0,33.0 24.0,33.0 27.0,26.0 27.0,26.0 33.0)))',1000)
  28. );
  29. INSERT INTO lots VALUES(
  30. 1010,
  31. ST_MPolyFromText('multipolygon (((2 57,21.5 57,21.5 38,2 38,2 57)))',1000)
  32. );
  33. INSERT INTO lots VALUES(
  34. 2930,
  35. ST_MPolyFromText('multipolygon (((21.5 57,40 57,40 38,21.5 38,21.5 57)))',1000)
  36. );
  37. INSERT INTO lots VALUES(
  38. 203,
  39. ST_MPolyFromText('multipolygon (((21.5 38,40 38,40 20,21.5 20,21.5 38)))',1000)
  40. );
  41. INSERT INTO lots VALUES(
  42. 5192,
  43. ST_MPolyFromText('multipolygon (((2 20,2 38,21.5 38,21.5 20,2 20)))',1000)
  44. );
  45. -- The query returns a list of building IDs that are within one foot of
  46. -- their lot lines. The ST_Distance function performs a spatial join on the
  47. -- footprints and lot ST_MultiPolygons. However, the equijoin between
  48. -- bf.lot_id and lots.lot_id ensures that only the ST_MultiPolygons
  49. -- belonging to the same lot are compared by the ST_Distance function.
  50. SELECT bf.building_id
  51. FROM buildingfootprints bf, lots
  52. WHERE bf.lot_id = lots.lot_id
  53. AND ST_Distance(footprint,lot) <= 1.0;