st_overlaps.sql 2.1 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455
  1. -- The county supervisor needs a list of hazardous waste sites
  2. -- whose five-mile radius overlaps sensitive areas.
  3. -- The sensitive_areas table contains several columns that
  4. -- describe the threatened institutions in addition to the
  5. -- zone column, which stores the institutions' ST_Polygon geometries.
  6. CREATE TABLE sensitive_areas (id integer,
  7. name varchar(128),
  8. size float,
  9. type varchar(10),
  10. zone ST_Polygon);
  11. -- The hazardous_sites table stores the identity of the sites
  12. -- in the site_id and name columns, while the actual geographic
  13. -- location of each site is stored in the location point column.
  14. CREATE TABLE hazardous_sites (site_id integer,
  15. name varchar(128),
  16. location ST_Point);
  17. INSERT INTO sensitive_areas VALUES(
  18. 1, 'Johnson County Hospital', 102281.91, 'hospital',
  19. ST_PolyFromText('polygon ((22000 45000,22000 58000,28000 58000,28000 42000,25000 42000,25000 45000,22000 45000))',1000)
  20. );
  21. INSERT INTO sensitive_areas VALUES(
  22. 2, 'Rydale Nursing Home', 53926.54, 'nursing hm',
  23. ST_PolyFromText('polygon ((22000 18000,28000 18000,28000 12000,22000 12000,22000 18000))',1000)
  24. );
  25. INSERT INTO sensitive_areas VALUES(
  26. 3, 'Summerhill Elementary School', 67920.64, 'school',
  27. ST_PolyFromText('polygon ((42000 18000,48000 18000,48000 13000,42000 13000,42000 18000))',1000)
  28. );
  29. INSERT INTO hazardous_sites VALUES(
  30. 102,
  31. 'W. H. Kleenare Chemical Repository',
  32. ST_PointFromText('point (7000 47000)',1000)
  33. );
  34. INSERT INTO hazardous_sites VALUES(
  35. 59,
  36. 'Landmark Industrial',
  37. ST_PointFromText('point (48000 39000)',1000)
  38. );
  39. -- The sensitive_areas and hazardous_sites tables are joined by the
  40. -- ST_Overlaps function, which returns t (TRUE) for all sensitive_areas
  41. -- rows whose zone polygons overlap the buffered five-mile radius of
  42. -- the hazardous_sites location points.
  43. SELECT hs.name hazardous_site, sa.name sensitive_area
  44. FROM hazardous_sites hs, sensitive_areas sa
  45. WHERE ST_Overlaps(ST_Buffer(hs.location,(26400)),sa.zone);