st_contains.sql 2.4 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576
  1. -- The city engineer needs to find out that a lot is
  2. -- within the footprint of the buiding. There are two tables
  3. -- created here to get the building footprints and the lots.
  4. -- The building footprints are stored in the buildingfootprints
  5. -- table created with the following CREATE TABLE statement.
  6. CREATE TABLE buildingfootprints (building_id integer,
  7. lot_id integer,
  8. footprint ST_MultiPolygon);
  9. -- Here is the creation of the lots
  10. CREATE TABLE lots (lot_id integer,
  11. lot ST_MultiPolygon);
  12. INSERT INTO buildingfootprints VALUES(
  13. 506, 1010,
  14. 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)
  15. );
  16. INSERT INTO buildingfootprints VALUES(
  17. 543, 2930,
  18. 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)
  19. );
  20. INSERT INTO buildingfootprints VALUES(
  21. 1208, 203,
  22. 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)
  23. );
  24. INSERT INTO buildingfootprints VALUES(
  25. 178, 5192,
  26. 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)
  27. );
  28. INSERT INTO lots VALUES(
  29. 1010,
  30. ST_MPolyFromText('multipolygon (((2 57,21.5 57,21.5 38,2 38,2 57)))',1000)
  31. );
  32. INSERT INTO lots VALUES(
  33. 2930,
  34. ST_MPolyFromText('multipolygon (((21.5 57,40 57,40 38,21.5 38,21.5 57)))',1000)
  35. );
  36. INSERT INTO lots VALUES(
  37. 203,
  38. ST_MPolyFromText('multipolygon (((21.5 38,40 38,40 20,21.5 20,21.5 38)))',1000)
  39. );
  40. INSERT INTO lots VALUES(
  41. 5192,
  42. ST_MPolyFromText('multipolygon (((2 20,2 38,21.5 38,21.5 20,2 20)))',1000)
  43. );
  44. -- The city engineer first selects the buildings that are not completely
  45. -- contained within one lot.
  46. SELECT building_id
  47. FROM buildingfootprints, lots
  48. WHERE NOT ST_Contains(lot,footprint);
  49. -- The city engineer realizes that although the first query will provide
  50. -- her with a list of all building IDs that have footprints outside of a
  51. -- lot polygon, it won't tell her if the rest have the correct lot_id
  52. -- assigned to them. This second query performs a data integrity check
  53. -- on the lot_id column of the buildingfootprints table.
  54. SELECT bf.building_id, bf.lot_id, lots.lot_id
  55. FROM buildingfootprints bf, lots
  56. WHERE NOT ST_Contains(lot,footprint)
  57. AND lots.lot_id <> bf.lot_id;