st_intersection.sql 2.5 KB

1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162
  1. -- The fire marshal must obtain the areas of the hospitals,
  2. -- schools, and nursing homes intersected by the radius of
  3. -- a possible hazardous waste contamination.
  4. -- The sensitive areas are stored in the sensitive_areas table
  5. -- that is created with the CREATE TABLE statement that follows.
  6. -- The zone column defined as a polygon stores the outline of each
  7. -- of the sensitive areas.
  8. CREATE TABLE sensitive_areas (id integer,
  9. name varchar(128),
  10. size float,
  11. type varchar(10),
  12. zone ST_Polygon);
  13. INSERT INTO sensitive_areas VALUES(
  14. 1, 'Johnson County Hospital', 102281.91, 'hospital',
  15. ST_PolyFromText('polygon ((22000 45000,22000 58000,28000 58000,28000 42000,25000 42000,25000 45000,22000 45000))',1000)
  16. );
  17. INSERT INTO sensitive_areas VALUES(
  18. 2, 'Rydale Nursing Home', 53926.54, 'nursing hm',
  19. ST_PolyFromText('polygon ((22000 18000,28000 18000,28000 12000,22000 12000,22000 18000))',1000)
  20. );
  21. INSERT INTO sensitive_areas VALUES(
  22. 3, 'Summerhill Elementary School', 67920.64, 'school',
  23. ST_PolyFromText('polygon ((42000 18000,48000 18000,48000 13000,42000 13000,42000 18000))',1000)
  24. );
  25. -- The hazardous sites are stored in the hazardous_sites table created
  26. -- with the CREATE TABLE statement that follows. The location column,
  27. -- defined as a point, stores a location that is the geographic center
  28. -- of each hazardous site.
  29. CREATE TABLE hazardous_sites (site_id integer,
  30. name varchar(128),
  31. location ST_Point);
  32. INSERT INTO hazardous_sites VALUES(
  33. 102,
  34. 'W. H. Kleenare Chemical Repository',
  35. ST_PointFromText('point (7000 47000)',1000)
  36. );
  37. INSERT INTO hazardous_sites VALUES(
  38. 59,
  39. 'Landmark Industrial',
  40. ST_PointFromText('point (48000 39000)',1000)
  41. );
  42. -- The ST_Buffer function generates a five-mile buffer surrounding
  43. -- the hazardous waste site locations. The ST_Intersection function
  44. -- generates polygons from the intersection of the buffered hazardous
  45. -- waste sites and the sensitive areas. The ST_Area function returns
  46. -- the intersection polygons' area, which is summarized for all hazardous
  47. -- sites by the sum function. The group by clause directs the query to
  48. -- aggregate the intersection areas by hazardous waste site ID.
  49. SELECT hs.site_id, SUM(ST_Area(ST_Intersection(sa.zone,
  50. ST_Buffer(hs.location,(5 * 5280)))::ST_MultiPolygon))
  51. FROM sensitive_areas sa, hazardous_sites hs
  52. GROUP BY hs.site_id;