st_geometryn.sql 2.1 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263
  1. -- The city engineer wants to know which building footprints are all inside
  2. -- the first polygon of the lots ST_MultiPolygon.
  3. -- The building_id column uniquely identifies each row of the
  4. -- buildingfootprints table. The lot_id column identifies the building's lot.
  5. -- The footprints column stores the buildings' geometries.
  6. CREATE TABLE buildingfootprints (building_id integer,
  7. lot_id integer,
  8. footprint ST_MultiPolygon);
  9. CREATE TABLE lots (lot_id integer,
  10. lot ST_MultiPolygon);
  11. INSERT INTO buildingfootprints VALUES(
  12. 506, 1010,
  13. 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)
  14. );
  15. INSERT INTO buildingfootprints VALUES(
  16. 543, 2930,
  17. 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)
  18. );
  19. INSERT INTO buildingfootprints VALUES(
  20. 1208, 203,
  21. 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)
  22. );
  23. INSERT INTO buildingfootprints VALUES(
  24. 178, 5192,
  25. 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)
  26. );
  27. INSERT INTO lots VALUES(
  28. 1010,
  29. ST_MPolyFromText('multipolygon (((2 57,21.5 57,21.5 38,2 38,2 57)))',1000)
  30. );
  31. INSERT INTO lots VALUES(
  32. 2930,
  33. ST_MPolyFromText('multipolygon (((21.5 57,40 57,40 38,21.5 38,21.5 57)))',1000)
  34. );
  35. INSERT INTO lots VALUES(
  36. 203,
  37. ST_MPolyFromText('multipolygon (((21.5 38,40 38,40 20,21.5 20,21.5 38)))',1000)
  38. );
  39. INSERT INTO lots VALUES(
  40. 5192,
  41. ST_MPolyFromText('multipolygon (((2 20,2 38,21.5 38,21.5 20,2 20)))',1000)
  42. );
  43. -- The query lists the buildingfootprints' building_id and lot_id
  44. -- for all building footprints that are all within the first lot polygon.
  45. -- The ST_GeometryN function returns a first lot polygon element in the
  46. -- ST_MultiPolygon.
  47. SELECT bf.building_id,bf.lot_id
  48. FROM buildingfootprints bf,lots
  49. WHERE ST_Within(footprint,ST_GeometryN(lot,1))
  50. AND bf.lot_id = lots.lot_id;