ArcGIS Server Banner

ST_Intersects

ST_Intersects

Release 9.3 E-mail This TopicPrintable VersionGive Us feedback

Definition

ST_Intersects returns 1 (Oracle) or t (PostgreSQL) if the intersection of two geometries doesn't result in an empty set; otherwise, it returns 0 (Oracle) or f (PostgreSQL).

Syntax

Oracle

sde.st_intersects (g1 sde.st_geometry, g2 sde.st_geometry)

PostgreSQL

st_intersects (g1 st_geometry, g2 st_geometry)

Return type

Boolean

Example

The fire marshal wants a list of sensitive areas within a radius of a hazardous waste site.

The sensitive areas are stored in the sensitive_areas table that is created with the CREATE TABLE statement that follows. The zone column, defined as a polygon, stores the outline of each of the sensitive areas.

The hazardous sites are stored in the hazardous_sites table created with the CREATE TABLE statement that follows. The location column, defined as a point, stores a location that is the geographic center of each hazardous site.

Oracle

CREATE TABLE sensitive_areas (id integer, 
                               zone sde.st_geometry); 

CREATE TABLE hazardous_sites (id integer, 
                              location sde.st_geometry); 

INSERT INTO sensitive_areas VALUES (
1,
sde.st_polygon ('polygon ((20 30, 30 30, 30 40, 20 40, 20 30))', 0)
);

INSERT INTO sensitive_areas VALUES (
2,
sde.st_polygon ('polygon ((30 30, 30 50, 50 50, 50 30, 30 30))', 0)
);

INSERT INTO sensitive_areas VALUES (
3,
sde.st_polygon ('polygon ((40 40, 40 60, 60 60, 60 40, 40 40))', 0)
);

INSERT INTO hazardous_sites VALUES (
4,
sde.st_point ('point (60 60)', 0)
);

INSERT INTO hazardous_sites VALUES (
5,
sde.st_point ('point (30 30)', 0)
);

PostgreSQL

CREATE TABLE sensitive_areas (id integer, 
                               zone st_geometry); 

CREATE TABLE hazardous_sites (id integer, 
                              location st_geometry); 

INSERT INTO sensitive_areas VALUES (
1,
st_polygon ('polygon ((20 30, 30 30, 30 40, 20 40, 20 30))', 0)
);

INSERT INTO sensitive_areas VALUES (
2,
st_polygon ('polygon ((30 30, 30 50, 50 50, 50 30, 30 30))', 0)
);

INSERT INTO sensitive_areas VALUES (
3,
st_polygon ('polygon ((40 40, 40 60, 60 60, 60 40, 40 40))', 0)
);

INSERT INTO hazardous_sites VALUES (
4,
st_point ('point (60 60)', 0)
);

INSERT INTO hazardous_sites VALUES (
5,
st_point ('point (30 30)', 0)
);

The query returns a list of sensitive areas and hazardous sites for sensitive areas that intersect the buffer radius of the hazardous sites.

Oracle

SELECT sa.id SA_ID, hs.id HS_ID
FROM sensitive_areas sa, hazardous_sites hs
WHERE sde.st_intersects (sde.st_buffer (hs.location, .1), sa.zone) = 1
ORDER BY sa.id;

SA_ID      HS_ID

    1          5
    2          5
    3          4

PostgreSQL

SELECT sa.id AS SA_ID, hs.id AS HS_ID
FROM sensitive_areas sa, hazardous_sites hs
WHERE st_intersects (st_buffer (hs.location, .1), sa.zone) = 't'
ORDER BY sa.id;

sa_id     hs_id

    1          5
    2          5
    3          4

See Also

  • An overview of SQL functions used with ST_Geometry types
  • Spatial relationships