Compute Location from known Lat/Long point using delta easting and northing in miles

Over on the Oracle Spatial Forum at the Technology Network, Wojciech asked the following question:

My problem looks that way:
lets say we have a point:

 8307, -- SDO_SRID
 SDO_ORDINATE_ARRAY
 (
 -77, -- Longitude
 39 -- Latitude
 )

I want to get a location of a point 50 miles east and 30 miles north from the point presented here.

Do you know how to achieve this?

There is a function in the SDO_UTIL package – SDO_UTIL.POINT_AT_BEARING -that allows you to create a new point at a bearing and distance from a known point, but there is no function that allows one to compute a new point from an existing point using a delta distance in x and y.

Obviously for projected data one can do this via Pythagoras on the X and Y ordinates but for geographic/geodetic there is no method available to do this accurately. You have to write it yourself.

Which is what this blog article is all about.

Approach

Now, the function presented will only generate an approximate location for the new point but it may suffice for some.

The approach requires us to convert miles into decimal degrees in both longitude and latitude at the actual location of the known point. Why? Because the length subtended by a degree of longitude changes as you move from the Equator to the Pole. And at any one point on the globe that length in longitude is different from that in latitude.

So, how can I compute this value. The following method takes the starting point and creates two points a whole number of degrees of longitude and latitude away from it (in the case below 0.1 degrees). Then, Oracle’s sdo_geom.sdo_distance method is used to find out how many miles each of these decimal degree values subtends.

 WITH longLat AS (
   SELECT sdo_geometry(2001,8307,sdo_point_type(-77.0     ,39.0,NULL),NULL,NULL) AS pt1,
          sdo_geometry(2001,8307,sdo_point_type(-77.0+unit,39.0,NULL),NULL,NULL) AS pt2,
          sdo_geometry(2001,8307,sdo_point_type(-77.0     ,39.0+unit,NULL),NULL,NULL) AS pt3
     FROM (SELECT 0.1 AS unit FROM dual)
 )
 SELECT sdo_geom.sdo_distance(l.pt1,l.pt2,0.005,'unit=MILE') AS unitLongMiles,
        sdo_geom.sdo_distance(l.pt1,l.pt3,0.005,'unit=MILE') AS unitLatMiles
   FROM longLat l;
 -- Results
 UNITLONGMILES    UNITLATMILES
 ---------------- ----------------
 5.38271491729028 6.89824146515357

OK, now that we know the distances in miles we can compute the number of degrees of longitude and latitude covered by the required delta of 50 miles east and 30 miles north from that point.

 WITH longLat AS (
   SELECT sdo_geometry(2001,8307,sdo_point_type(-77.0     ,39.0,NULL),NULL,NULL) AS pt1,
          sdo_geometry(2001,8307,sdo_point_type(-77.0+unit,39.0,NULL),NULL,NULL) AS pt2,
          sdo_geometry(2001,8307,sdo_point_type(-77.0     ,39.0+unit,NULL),NULL,NULL) AS pt3,
          50.0 AS eastMile,
          30.0 AS northMile,
          unit
     FROM (SELECT 0.1 AS unit FROM dual)
 )
 SELECT round(sdo_geom.sdo_distance(l.pt1,l.pt2,0.005,'unit=MILE'),9) AS unitLongMiles,
        round(sdo_geom.sdo_distance(l.pt1,l.pt3,0.005,'unit=MILE'),9) AS unitLatMiles,
        round(l.eastMile /sdo_geom.sdo_distance(l.pt1,l.pt2,0.005,'unit=MILE') * l.unit,9) AS eastDeltaInDegrees,
        round(l.northMile/sdo_geom.sdo_distance(l.pt1,l.pt3,0.005,'unit=MILE') * l.unit,9) AS northDeltaInDegrees
   FROM longLat l;
 -- Results
 UNITLONGMILES UNITLATMILES EASTDELTAINDEGREES NORTHDELTAINDEGREES
 ------------- ------------ ------------------ -------------------
 5.382714917   6.898241465  0.928899278        0.434893446

We can compute the new point via the following SQL:

 WITH longLat AS (
   SELECT sdo_geometry(2001,8307,sdo_point_type(-77.0     ,39.0,NULL),NULL,NULL) AS pt1,
          sdo_geometry(2001,8307,sdo_point_type(-77.0+unit,39.0,NULL),NULL,NULL) AS pt2,
          sdo_geometry(2001,8307,sdo_point_type(-77.0     ,39.0+unit,NULL),NULL,NULL) AS pt3,
          50.0 AS eastMile,
          30.0 AS northMile,
          unit
     FROM (SELECT 0.1 AS unit FROM dual)
 )
 SELECT f.pt1,f.pt2,
        ROUND(sdo_geom.sdo_distance(f.pt1,f.pt2,0.005,'unit=MILE'),3) AS dist,
        ROUND(SQRT(50.0*50.0+30.0*30.0),3) AS roughDistCheck
   FROM (SELECT b.pt1,
                sdo_geometry(2001,8307,
                             sdo_point_type(ROUND(b.pt1.sdo_point.x+b.longDelta,8),
                                            ROUND(b.pt1.sdo_point.y+b.latDelta,8),NULL),
                             NULL,NULL) AS pt2
           FROM (SELECT round(l.eastMile/sdo_geom.sdo_distance(l.pt1, l.pt2,0.005,'unit=MILE')*l.unit,9) AS longDelta,
                        round(l.northMile/sdo_geom.sdo_distance(l.pt1,l.pt3,0.005,'unit=MILE')*l.unit,9) AS latDelta,
                        l.pt1
                   FROM longLat l
               ) b
       ) f;
 -- Results
 PT1                                                           PT2                                                                             DIST   ROUGHDISTCHECK
 ------------------------------------------------------------- ------------------------------------------------------------------------------- ------ --------------
 SDO_GEOMETRY(2001,8307,SDO_POINT_TYPE(-77,39,NULL),NULL,NULL) SDO_GEOMETRY(2001,8307,SDO_POINT_TYPE(-76.07110072,39.43489345,NULL),NULL,NULL) 58.178 58.31

Now, let’s put this all together into a function.

 CREATE OR REPLACE
 FUNCTION pointFromDelta(p_geometry IN mdsys.sdo_geometry,
                         p_delta_x  IN NUMBER,
                         p_delta_y  IN NUMBER,
                         p_unit_deg IN NUMBER,
                         p_units    IN varchar2 := NULL,
                         p_tolerance IN NUMBER  := 0.05,
                         p_round_factor IN pls_integer := 9)
 RETURN sdo_geometry deterministic
 AS
   v_pt           mdsys.sdo_geometry := p_geometry;
   v_ptX          mdsys.sdo_geometry;
   v_ptY          mdsys.sdo_geometry;
   v_round_factor NUMBER :=  NVL(p_round_factor,9);
   v_units        varchar2(100) := CASE WHEN p_units IS NOT NULL
                                        THEN CASE WHEN INSTR(UPPER(p_units),'UNIT=')=0
                                                  THEN 'UNIT=' || UPPER(p_units)
                                                  ELSE p_units
                                              END
                                    END;
 BEGIN
    IF (p_geometry IS NULL OR p_geometry.sdo_point IS NULL OR p_unit_deg IS NULL) THEN
       RETURN p_geometry;
    END IF;
   v_pt  := NEW mdsys.sdo_geometry(p_geometry.sdo_gtype,
                                   p_geometry.sdo_srid,
                                   sdo_point_type(p_geometry.sdo_point.x,
                                                  p_geometry.sdo_point.y,
                                                  NULL),
                                   NULL,NULL);
   v_ptX := NEW mdsys.sdo_geometry(p_geometry.sdo_gtype,
                                   p_geometry.sdo_srid,
                                   sdo_point_type(p_geometry.sdo_point.x+p_unit_deg,
                                                  p_geometry.sdo_point.y,
                                                  NULL),
                                   NULL,NULL);
   v_ptY := NEW mdsys.sdo_geometry(p_geometry.sdo_gtype,
                                   p_geometry.sdo_srid,
                                   sdo_point_type(p_geometry.sdo_point.x,
                                                  p_geometry.sdo_point.y+p_unit_deg,
                                                  NULL),
                                   NULL,NULL);
    RETURN CASE WHEN v_units IS NULL
                THEN sdo_geometry(2001,
                        p_geometry.sdo_srid,
                        sdo_point_type(ROUND(v_pt.sdo_point.x+(p_delta_x/sdo_geom.sdo_distance(v_pt,v_ptX,p_tolerance)*p_unit_deg),v_round_factor),
                                       ROUND(v_pt.sdo_point.y+(p_delta_y/sdo_geom.sdo_distance(v_pt,v_ptY,p_tolerance)*p_unit_deg),v_round_factor),
                                       NULL),
                        NULL,NULL) 
                ELSE sdo_geometry(2001,
                        p_geometry.sdo_srid,
                        sdo_point_type(ROUND(v_pt.sdo_point.x+(p_delta_x/sdo_geom.sdo_distance(v_pt,v_ptX,p_tolerance,v_units)*p_unit_deg),v_round_factor),
                                       ROUND(v_pt.sdo_point.y+(p_delta_y/sdo_geom.sdo_distance(v_pt,v_ptY,p_tolerance,v_units)*p_unit_deg),v_round_factor),
                                       NULL),
                        NULL,NULL)
           END;
 END pointFromDelta;
 /
 FUNCTION pointFromDelta compiled
 SHOW errors
 No Errors.

Testing this we get:

 WITH pt AS (
   SELECT sdo_geometry(2001,8307,sdo_point_type(-77,39,NULL),NULL,NULL) AS pt,
          0.1 AS unit
     FROM dual
 )
 SELECT p.pt,
        pointFromDelta(p.pt,50.0,30.0,p.unit,'UNIT=MILE',0.05,9),
        ROUND(sdo_geom.sdo_distance(p.pt,
                                    pointFromDelta(p.pt,50.0,30.0,p.unit,'UNIT=MILE',0.05,9),
                                    0.005,'unit=MILE'),4) AS dist,
        ROUND(SQRT(50.0*50.0+30.0*30.0),4) AS roughDistCheck
   FROM pt p;
 -- Results
 PT                                                            POINTFROMDELTA(P.PT,50.0,30.0,0.1,'UNIT=MILE',0.05,9)                             DIST   ROUGHDISTCHECK
 ------------------------------------------------------------- --------------------------------------------------------------------------------- ------ --------------
 SDO_GEOMETRY(2001,8307,SDO_POINT_TYPE(-77,39,NULL),NULL,NULL) SDO_GEOMETRY(2001,8307,SDO_POINT_TYPE(-76.071100722,39.434893446,NULL),NULL,NULL) 58.178 58.3095

Don’t forget that the ROUGHDISTCHECK is just a Pythagoras of the delta east and north on a flat plane. This approach isn’t all that accurate.

Alternate method using SDO_UTIL POINT_AT_BEARING

There is an alternate approach that writing this article reminded me was possible. And that is to use the SDO_UTIL.POINT_AT_BEARING function as follows:

 WITH longLat AS (
   SELECT sdo_geometry(2001,8307,sdo_point_type(-77.0,39.0,NULL),NULL,NULL) AS pt1,
          50.0 AS eastMile,
          30.0 AS northMile,
          unit
     FROM (SELECT 0.1 AS unit FROM dual)
 )
 SELECT f.pt2,
        ROUND(sdo_geom.sdo_distance(f.pt1,f.pt2,0.005,'unit=MILE'),3) AS dist
   FROM (SELECT l.pt1,
                SDO_UTIL.POINT_AT_BEARING(
                         SDO_UTIL.POINT_AT_BEARING(l.pt1,
                                                   DECODE(SIGN(l.eastMile),1.570796326794895,0,-1.570796326794895),
                                                   codesys.geom.Convert_Unit( 'MILE',l.eastMile, 'Meter')),
                                          DECODE(SIGN(l.northMile),3.14159265358979,0,-3.14159265358979),
                                          codesys.geom.Convert_Unit('MILE',l.northMile, 'Meter')) AS pt2
          FROM longLat l
       ) f;
 -- Results
 PT2                                                                                                            DIST
 -------------------------------------------------------------------------------------------------------------- ------
 SDO_GEOMETRY(2001,8307,NULL,SDO_ELEM_INFO_ARRAY(1,1,1),SDO_ORDINATE_ARRAY(-77.9288670026001,38.5613888205277)) 58.571

That is, go either 90 degrees to the East for +Eastings and 0 degrees to the North for +northings (or -90/270 for -Eastings and 180 degrees south for -northings).

Note that the distance difference between the two methods is 58.178 for my method and 58.571 for the method using the Oracle function. Knowing that a distance in longitude changes by latitude this may be affecting the second method as the conversion routine from Miles to Meters (SDO_UTIL.POINT_AT_BEARING requires distances in Meters) will not take this into account.

Something could be done using spherical or spheroidal math, but you would have to approach me directly to see if I would be interested coding something.

Anyway, I hope this is of help to someone.