Topological Relationships for Temporal Points

The topological relationships such as ST_Intersects and ST_Relate can be generalized for temporal points. The arguments of these generalized functions are either a temporal point or a base type (that is, a geometry or a geography), but these functions do not allow a base type in both arguments. Furthermore, both arguments must be of the same base type, that is, these functions do not allow to have a temporal geometry point (or a geometry) and a temporal geography point (or a geography) as arguments.

There are two versions of the temporal topological relationships:

All spatial relationships in the two versions are defined for temporal geometry points, while only four of them are defined for temporal geography points, namely, covers, coveredby, intersects, and dwithin, and the corresponding temporal versions.

The semantics conveyed by the first version of the relationships varies depending on the relationship and the type of the arguments. For example, the following query

SELECT intersects(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
tgeompoint '[Point(0 1)@2012-01-01, Point(1 1)@2012-01-03)');
			

tests whether the temporal point ever intersected the geometry, since the query is conceptually equivalent to the following one.

SELECT ST_Intersects(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
geometry 'Linestring(0 1,1 1)');
			

where the second geometry is obtained by applying the trajectory function to the temporal point. On the other hand, the query

SELECT contains(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
tgeompoint '[Point(0 1)@2012-01-01, Point(1 1)@2012-01-03)');
			

tests whether the geometry always contains the temporal point. Finally, the following query

SELECT intersects(tgeompoint '[Point(0 1)@2012-01-01, Point(1 0)@2012-01-03)',
tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)');
			

tests whether the temporal points may intersect, since the query above is conceptually equivalent to the following one

SELECT ST_Intersects('Linestring(0 1,1 0)', 'Linestring(0 0,1 1)');
			

The first versions of the relationships are typically used in combination with a spatio-temporal index when computing the temporal relationships. For example, the following query

SELECT T.TripId, R.RegionId, tintersects(T.Trip, R.Geom)
FROM Trips T, Regions R
WHERE intersects(T.Trip, R.Geom)
			

which verifies whether a trip T (which is a temporal point) intersects a region R (which is a geometry), will benefit rom a spatio-temporal index on the column T.Trip since the intersects function will automatically perform the bounding box comparison T.Trip && R.Geom. This is further explained later in this document.

Three topological relationships available in PostGIS are not provided in the temporal version.

Similarly, only a few temporal topological relationships are meaningful when the two arguments are temporal points. Therefore, the relationships supported for two temporal geometry points are tdisjoint, tequals, tintersects, tdwithin, and trelate (with 2 and 3 arguments), while only tintersects and tdwithin are supported for two temporal geography points.

The relate and the trelate functions have two forms with either two or three arguments. The two-argument forms consider the spatial relationship between the interior, the boundary, and the exterior of the arguments and return a text or a ttext value representing the maximum intersection matrix pattern. This pattern is defined using the Dimensionally Extended 9 Intersection Model or DE-9IM (see the PostGIS documentation for more details). The three-argument forms determine whether the first two arguments satisfy the intersection matrix pattern given as third argument (a text value) and return a Boolean or a temporal Boolean.

Possible Spatial Relationships

  • May contain

    contains({geo, tgeompoint}, {geo, tgeompoint}): boolean

    SELECT contains(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)');
    -- true
    					
  • May contain properly

    containsproperly({geo, tgeompoint}, {geo, tgeompoint}): boolean

    SELECT containsproperly(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)');
    -- false
    					
  • May cover

    covers({geo, tpoint}, {geo, tpoint}): boolean

    SELECT covers(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)');
    -- true
    					
  • May be covered by

    coveredby({geo, tpoint}, {geo, tpoint}): boolean

    SELECT coveredby(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)');
    -- false
    					
  • May cross

    crosses({geo, tgeompoint}, {geo, tgeompoint}): boolean

    SELECT crosses(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(2 2)@2012-01-03)');
    -- true
    					
  • May be disjoint

    disjoint({geo, tgeompoint}, {geo, tgeompoint}): boolean

    SELECT disjoint(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)');
    -- false
    					
  • May be equal

    equals({geo, tgeompoint}, {geo, tgeompoint}): boolean

    SELECT equals(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)');
    -- false
    					
  • May intersect

    intersects({geo, tpoint}, {geo, tpoint}): boolean

    SELECT intersects(geometry 'Polygon((0 0 0,0 1 0,1 1 0,1 0 0,0 0 0))',
    tgeompoint '[Point(0 0 1)@2012-01-01, Point(1 1 1)@2012-01-03)');
    -- false
    SELECT intersects(geometry 'Polygon((0 0 0,0 1 1,1 1 1,1 0 0,0 0 0))',
    tgeompoint '[Point(0 0 1)@2012-01-01, Point(1 1 1)@2012-01-03)');
    -- true
    					
  • May overlap

    overlaps({geo, tgeompoint}, {geo, tgeompoint}): boolean

    SELECT overlaps(geometry 'Linestring(1 1,3 3)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(2 2)@2012-01-03)');
    -- true
    					
  • May touch

    touches({geo, tgeompoint}, {geo, tgeompoint}): boolean

    SELECT touches(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(0 1)@2012-01-03)');
    -- true
    					
  • May be within

    within({geo, tgeompoint}, {geo, tgeompoint}): boolean

    SELECT within(geometry 'LineString(1 1,2 2)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-03)');
    -- true
    					
  • May be at distance within

    dwithin({geo, tpoint}, {geo, tpoint}, double): boolean

    SELECT dwithin(geometry 'Polygon((0 0 0,0 1 1,1 1 1,1 0 0,0 0 0))',
    tgeompoint 'Point(0 2 1)@2000-01-01,Point(2 2 1)@2000-01-02', 1)
    -- true
    SELECT dwithin(geometry 'Polygon((0 0 0,0 1 1,1 1 1,1 0 0,0 0 0))',
    tgeompoint 'Point(0 2 2)@2000-01-01,Point(2 2 2)@2000-01-02', 1)
    --	false
    					
  • May relate

    relate({geo, tgeompoint}, {geo, tgeompoint}): text

    relate({geo, tgeompoint}, {geo, tgeompoint}, text): boolean

    SELECT relate(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)');
    -- "1F2F01FF2"
    SELECT relate(geometry 'Polygon((0 0,0 1,1 1,1 0,0 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(1 1)@2012-01-03)','1F2F01FF2');
    -- true
    					

Temporal Spatial Relationships

  • Temporal contains

    tcontains({geo, tgeompoint}, {geo, tgeompoint}): tbool

    SELECT tcontains(geometry 'Polygon((1 1,1 2,2 2,2 1,1 1))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-04)');
    -- "{[f@2012-01-01, f@2012-01-02], (t@2012-01-02, f@2012-01-03, f@2012-01-04)}"
    					
  • Temporal covers

    tcovers({geo, tpoint}, {geo, tpoint}): tbool

    SELECT tcovers(geometry 'Polygon((1 1,1 2,2 2,2 1,1 1))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-04)');
    -- "{[f@2012-01-01, t@2012-01-02, t@2012-01-03], (f@2012-01-03, f@2012-01-04]}"
    					
  • Temporal covered by

    tcoveredby({geo, tpoint}, {geo, tpoint}): tbool

    SELECT tcoveredby(geometry 'Point(1 1)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-04)');
    -- "{[f@2012-01-01, t@2012-01-02], (f@2012-01-02, f@2012-01-04)}"
    					
  • Temporal disjoint

    tdisjoint({geo, tgeompoint}, {geo, tgeompoint}): tbool

    SELECT tdisjoint(geometry 'Polygon((1 1,1 2,2 2,2 1,1 1))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-04)');
    -- "{[t@2012-01-01, f@2012-01-02, f@2012-01-03], (t@2012-01-03, t@2012-01-04]}"
    SELECT tdisjoint(tgeompoint '[Point(0 3)@2012-01-01, Point(3 0)@2012-01-05)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-05)');
    -- "{[t@2012-01-01, f@2012-01-03], (t@2012-01-03, t@2012-01-05)}"
    					
  • Temporal equals

    tequals({point, tgeompoint}, {point, tgeompoint}): tbool

    SELECT tequals(geometry 'Point(1 1)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-04)');
    -- "{[f@2012-01-01, t@2012-01-02], (f@2012-01-02, f@2012-01-04]}"
    SELECT tequals(tgeompoint '[Point(0 3)@2012-01-01, Point(3 0)@2012-01-05)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-05)');
    -- "{[f@2012-01-01, t@2012-01-03], (f@2012-01-03, f@2012-01-05)}"
    					
  • Temporal intersects

    tintersects({geo, tpoint}, {geo, tpoint}): tbool

    SELECT tintersects(geometry 'MultiPoint(1 1,2 2)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-04)');
    -- "{[f@2012-01-01, t@2012-01-02], (f@2012-01-02, t@2012-01-03],
    (f@2012-01-03, f@2012-01-04]}"
    SELECT tintersects(tgeompoint '[Point(0 3)@2012-01-01, Point(3 0)@2012-01-05)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 3)@2012-01-05)');
    -- "{[f@2012-01-01, t@2012-01-03], (f@2012-01-03, f@2012-01-05)}"
    					
  • Temporal touches

    ttouches({geo, tgeompoint}, {geo, tgeompoint}): tbool

    SELECT ttouches(geometry 'Polygon((1 0,1 2,2 2,2 0,1 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 0)@2012-01-04)');
    -- "{[f@2012-01-01, t@2012-01-02, t@2012-01-03], (f@2012-01-03, f@2012-01-04]}"
    					
  • Temporal within

    twithin({geo, tgeompoint}, {geo, tgeompoint}): tbool

    SELECT twithin(geometry 'Point(1 1)',
    tgeompoint '[Point(0 0)@2012-01-01, Point(2 2)@2012-01-03)');
    -- "{[f@2012-01-01, t@2012-01-02], (f@2012-01-02, f@2012-01-03]}"
    					
  • Temporal distance within

    tdwithin({geo, tpoint}, {geo, tpoint}, double): tbool

    SELECT tdwithin(geometry 'Polygon((1 1,1 2,2 2,2 1,1 1))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 0)@2012-01-04)', 1);
    -- "{[f@2012-01-01, t@2012-01-02, t@2012-01-03], (f@2012-01-03, f@2012-01-04)}"
    SELECT tdwithin(tgeompoint '[Point(1 0)@2000-01-01, Point(1 4)@2000-01-05]',
    tgeompoint 'Interp=Stepwise;[Point(1 2)@2000-01-01, Point(1 3)@2000-01-05]', 1);
    -- "{[f@2000-01-01, t@2000-01-02, t@2000-01-04], (f@2000-01-04, t@2000-01-05]}"
    					
  • Temporal relate

    trelate({geo, tgeompoint}, {geo, tgeompoint}, text): tbool

    trelate({geo, tgeompoint}, {geo, tgeompoint}): ttext

    SELECT trelate(geometry 'Polygon((1 0,1 2,2 2,2 0,1 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 0)@2012-01-04)');
    -- "{[FF2FF10F2@2012-01-01, FF20F1FF2@2012-01-02, FF20F1FF2@2012-01-03],
    (FF2FF10F2@2012-01-03, FF2FF10F2@2012-01-04]}"
    SELECT trelate(geometry 'Polygon((1 0,1 2,2 2,2 0,1 0))',
    tgeompoint '[Point(0 0)@2012-01-01, Point(3 0)@2012-01-04)', 'FF20F1FF2');
    -- "{[f@2012-01-01, t@2012-01-02, t@2012-01-03], (f@2012-01-03, f@2012-01-04]}"
    2012-01-04)}"