Top 5 Recent Articles
ARTICLES CATEGORIES
- Algorithms (22)
- All (399)
- Biography (1)
- Blog (44)
- Business Requirements (1)
- Commentary (1)
- Conversion (2)
- Customers (2)
- Data Models (1)
- Education (2)
- GeoRaptor (13)
- GPS (1)
- Image Processing (2)
- Import Export (8)
- Licensing (2)
- LiDAR (1)
- Linear Referencing (4)
- Manifold GIS (3)
- Mapping (1)
- MySQL Spatial (7)
- Networking and Routing (including Optimization) (5)
- Open Source (18)
- Oracle Spatial and Locator (194)
- Partitioning (1)
- PostGIS (36)
- Projections (1)
- Published Articles (1)
- qGIS (1)
- Recommendations (1)
- Services (1)
- Software Change Log (1)
- Source Code (37)
- Space Curves (9)
- Spatial Database Functions (109)
- Spatial DB comparison (1)
- Spatial XML Processing (11)
- SQL Server Spatial (92)
- Standards (3)
- Stored Procedure (17)
- Tessellation or Gridding (10)
- Tools (2)
- Topological Relationships (1)
- Training (2)
- Triangulation (2)
Implementing a Translate/ST_Translate/Move function for Oracle Spatial
Many years ago I wrote a PL/SQL function to move any sdo_geometry when supplied a “delta” in terms of deltaX, deltaY and optionally deltaZ. This function also allowed a user to supply an envelope, box or minimum bounding rectangle (MBR) to the function so that only those vertices that lie within an sdo_geometry object would be moved.
I often play with PostGIS and have found the writings on Regina Obe very enlightening. PostGIS contains a function called ST_Translate (not part of the SQL/MM standard) which is identical to my original Move function.
So, recently, I decided to re-visit my Move function to improve its implementation, and provide ST_Translate wrappers for it.
This article summarises this recent work.
PostGIS’s ST_Translate function is described, neatly, by its documentation so I will duplicate the examples it for my Oracle implementation.
/* Move a point 1 degree longitude */ /* PostGIS */ SELECT ST_AsText(ST_Translate(ST_GeomFromText('POINT(-71.01 42.37)',4326),1,0)) As wgs_transgeomtxt; wgs_transgeomtxt --------------------- POINT(-70.01 42.37) /* Oracle */ SELECT Geom.ST_Translate(mdsys.ST_Geometry.From_WKT('POINT(-71.01 42.37)',4326),1,0).Get_WKT() As wgs_transgeomtxt from dual; WGS_TRANSGEOMTXT --------------------------- (CLOB) POINT (-70.01 42.37) 1 rows selected /* Move a linestring 1 degree longitude and 1/2 degree latitude*/ /* PostGIS */ SELECT ST_AsText(ST_Translate(ST_GeomFromText('LINESTRING(-71.01 42.37,-71.11 42.38)',4326),1,0.5)) As wgs_transgeomtxt; wgs_transgeomtxt --------------------------------------- LINESTRING(-70.01 42.87,-70.11 42.88) /* Oracle */ SELECT Geom.ST_Translate(mdsys.ST_Geometry.From_WKT('LINESTRING(-71.01 42.37,-71.11 42.38)',4326),1,0.5).Get_WKT() As wgs_transgeomtxt from dual; WGS_TRANSGEOMTXT ---------------------------------------------- (CLOB) LINESTRING (-70.01 42.87, -70.11 42.88) 1 rows selected /* Move a 3d point */ /* PostGIS */ SELECT ST_AsEWKT(ST_Translate(CAST('POINT(0 0 0)' As geometry), 5, 12,3)); st_asewkt --------- POINT(5 12 3) /* Oracle */ SELECT Geom.AsEWKT(Geom.ST_Translate(mdsys.SDO_Geometry(3001,Null,sdo_point_type(0,0,0),null,null),5,12,3)) as st_asewkt FROM DUAL; ST_ASEWKT --------------------------- (CLOB) POINT XYZ (5 12 3) ) 1 rows selected /* Move a curve and a point */ /* PostGIS */ SELECT ST_AsText(ST_Translate(ST_Collect('CURVEPOLYGON(CIRCULARSTRING(4 3,3.12 0.878,1 0,-1.121 5.1213,6 7, 8 9,4 3))','POINT(1 3)'),1,2)); st_astext ------------------------------------------------------------------------------------------------------------ GEOMETRYCOLLECTION(CURVEPOLYGON(CIRCULARSTRING(5 5,4.12 2.878,2 2,-0.121 7.1213,7 9,9 11,5 5)),POINT(2 5)) /* Oracle */ SELECT GEOM.AsEWKT(Geom.ST_Translate(MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1005,1,1,2,2),MDSYS.SDO_ORDINATE_ARRAY(4,3,7,4,6,7,-1.121,5.1213,1,0,3.12,0.878,4,3)),1,2)) as st_asText from dual; ST_ASTEXT ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- (CLOB) POLYGON XY ( MULTICURVEPOLYGON( CURVESTRING(5.0 5.0, 8.0 6.0, 7.0 9.0, -0.121 7.1213 2.0 2.0, 4.12 2.878, 5.0 5.0)) ) 1 rows selected
OK, so my functions pass the “PostGIS” test.
That is all well and good with the standard parameters, but is that all?
What I have found is that, sometimes, you want to move only part of a geometry object. For example, at Forestry Tasmania, when I was GIS Manager, we had a situation, before my time, where King Island (see image below) had been artificially moved from its geographic position to an artificial position for the purposes of map production (it was also related to single precision vs double precision ArcInfo coverages but that is another story). When implementing a change from the Australian Map Grid (AMG, based on the Australian Geodetic Datum 1966) to the Map Grid of Australia (based on the Australian Geodetic Datum 1994), we had to first move King Island back to its normal AMG position before projecting it to MGA.
!http://www.spatialdbadvisor.com/images/21.png (King Island Original)!
In this situation, I found that the Move function needed to be enhanced to allow for the provision of a minimum bounding rectangle (MBR) which the function tested against each vertex in an sdo_geometry object such that it moved only those which the INSIDE topological relationship.
In summary, the ST_Translate PostGIS function needs enhancing to allow for this possibility. I will now present the Move and ST_Translate functions which are implemented in the GEOM package which is a part of my free PL/SQL functions. I will only present the relevant package specifications:
/* ---------------------------------------------------------------------------------------- * @function : MOVE * @precis : Function which updates all coordinates in a shape by applying x/y shift. * @version : 2.0 * @description: In order to be able to apply the King Island move to the shapes stored * in an Oracle Spatial shape, a function is needed that iterates though * all the coordinates of a shape and applys a deltaX and deltaY to them. * If p_envelope is provided, only those coordinate that fall within it are moved: * otherwise all are moved. * @usage : Function move ( p_geometry IN MDSYS.SDO_GEOMETRY, * p_deltaX IN number, * p_deltaY IN number, * p_envelope IN MDSYS.SDO_GEOMETRY ) RETURN MDSYS.SDO_GEOMETRY DETERMINISTIC; * eg fixedShape := CODESYS.geom.tolerance(shape,diminfo); * param : p_geometry : The shape to move. * paramtype : p_geomery : MDSYS.SDO_GEOMETRY * param : p_deltaX : Shift to be applied to the X coordinate. * paramtype : p_deltaX : number * param : p_deltaY : Shift to be applied to the Y coordinate. * paramtype : p_deltaY : number * param : p_deltaZ : Shift to be applied to the Z coordinate. * paramtype : p_deltaZ : number * param : p_mbr : minimum bounding rectangle/envelope in which p_geometry's coordinates have to be within to be able to be moved. * paramtype : p_mbr : MBR object * param : p_filter_geom : A shape defining a sub-area in which p_geometry's coordinates have to be within for move. * paramtype : p_filter_geom : MDSYS.SDO_GEOMETRY * param : p_filter_mask : A mask for use with SDO_GEOM.RELATE() * paramtype : p_filer_mask : varchar * param : p_tolerance : Tolerance used when processing vertices with SDO_GEOM.RELATE * param : p_tolerance : Number * @requires : CODESYS.GF package. * return : newShape : Shape whose coordinates are 'moved'. * rtnType : newShape : MDSYS.SDO_GEOMETRY * history : Simon Greener - Mar 2003 - Original coding. * history : Simon Greener - Jul 2006 - Migrated to GF package and made 3D aware. * history : Simon Greener - Sep 2007 - Removed need for SDO_GEOM.RELATE via use of MBR type. * history : Simon Greener - Jun 2008 - Removed modification of ordinates to precision of diminfo/tolerance as duplicates Tolerance() function. * @copyright : Free for public use **/ FUNCTION Move( p_geometry IN MDSYS.SDO_GEOMETRY, p_deltaX IN NUMBER, p_deltaY IN NUMBER, p_deltaZ IN NUMBER := NULL, p_mbr IN CODESYS.MBR := NULL, p_filter_geom IN MDSYS.SDO_GEOMETRY := NULL, p_filter_mask IN VARCHAR2 := 'INSIDE', p_tolerance IN NUMBER := NULL ) Return MDSYS.SDO_GEOMETRY Deterministic; /* Wrapper functions using OGC Syntax */ FUNCTION ST_Translate( p_geometry IN MDSYS.ST_GEOMETRY, p_deltaX IN NUMBER, p_deltaY IN NUMBER, p_deltaZ IN NUMBER := NULL ) Return MDSYS.ST_GEOMETRY DETERMINISTIC; FUNCTION ST_Translate( p_geometry IN MDSYS.SDO_GEOMETRY, p_deltaX IN NUMBER, p_deltaY IN NUMBER, p_deltaZ IN NUMBER := NULL, p_mbr IN CODESYS.MBR := NULL ) Return MDSYS.SDO_GEOMETRY Deterministic; FUNCTION ST_Translate( p_geometry IN MDSYS.SDO_GEOMETRY, p_deltaX IN NUMBER, p_deltaY IN NUMBER, p_deltaZ IN NUMBER, p_filter_geom IN MDSYS.SDO_GEOMETRY, p_filter_mask IN VARCHAR2 := 'INSIDE', p_tolerance IN NUMBER := 0.05 ) Return MDSYS.SDO_GEOMETRY Deterministic;
So, first, let’s move “King Island”: to a new location.
update King_Island a set a.geometry = Geom.St_Translate(a.geometry,40000,-9000,NULL,Codesys.MBR(225000,5548000,257000,5616000)) where a.name = 'King Island'; commit;
Notice how King Island has been moved to a new location in the following image.
!http://www.spatialdbadvisor.com/images/22.png (King Island New Location)!
Now, let’s move it back:
update King_Island a set a.geometry = Geom.St_Translate(a.geometry,-40000,9000,NULL,Codesys.MBR(265000,5539000,297000,5607000)) where a.name = 'King Island'; commit;
Here it is moved back to its original position:
!http://www.spatialdbadvisor.com/images/21.png (King Island Original)!
Now, above we used an MBR parameter to constrain the move. But what if we wanted to move vertices that won’t neatly fit into an MBR object? The Move/ST_Translate functions need parameters to enable a move from any input SDO_GEOMETRY and topological mask. If the following we use a polygon to move King Island and Hunter Island (in blue in the following image).
!http://www.spatialdbadvisor.com/images/23.png (All back to where they started)!
update King_Island a set a.geometry = Geom.St_Translate(a.geometry,40000,10000,NULL,NULL,mdsys.sdo_geometry('POLYGON((225647 5617686, 227451 5503583, 316749 5500877, 308180 5624902, 225647 5617686))',28355),'INSIDE',0.05); commit;
This image shows the two islands only being moved.
!http://www.spatialdbadvisor.com/images/24.png (King and Hunter Islandsl)!
Finally, Now, move King Island and Hunter Island back to their original position.
update King_Island a set a.geometry = Geom.St_Translate(a.geometry,-40000,-10000,NULL,NULL) where a.name in ('King Island','Hunter Island'); commit;
!http://www.spatialdbadvisor.com/images/21.png (All back to where they started)!
The implementation of the Move and ST_Translate functions are in the GEOM package of my free PL/SQL utilities.
I hope this is useful to someone.
Documentation
- MySQL Spatial General Functions
- Oracle LRS Objects
- Oracle Spatial Exporter (Java + pl/SQL)
- Oracle Spatial Object Functions
- Oracle Spatial Object Functions (Multi Page)
- PostGIS pl/pgSQL Functions
- SC4O Oracle Java Topology Suite (Java + pl/SQL)
- SQL Server Spatial General TSQL Functions
- SQL Server Spatial LRS TSQL Functions