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)
Extend (Reduce/Contract/Skrink) Function for Oracle
Recently I was looking at some cadastral data with a view to working out how to polygonize the linestrings. The data contains this sort of boundary understood anomaly.
To be able to able to form intersections between the cadastral boundaries and the road frontage I need to be “extend” the linestrings along the direction of the line.
To do this I found that to implement this in Oracle, because there is no function to do this, I needed to write a PL/SQL function.
Before I present the function, I decided that I would make the one function capable of being able to lengthen or extend a linestring and also shorten (reduce, contract or shrink) it. Skrinking is easy: specify the extension length as a negative number (as against a positive number for extension).
I have noted that other solutions such as FME’s ExtensionFactory which allows the user to specify that the direction for extension can be computed by 1 more more vectors or segments:
The optional SEGMENTS_TO_AVERAGE clause indicates the number of segments that should be considered when computing the orientation angle for the extension feature. By default, this is set to 1, which means the orientation of the extension feature matches the orientation of just one segment in the original feature. It can be set to any number of segments, in which case the orientation will be set to the average orientation of those segments. If the number of segments is larger than the number of segments available on the feature, then the entire feature orientation is averaged and used.
However, because I allow for shrinkage of the linestring I decided not to implement a similar feature to FME (though it would not be all that difficult to do – it’s just maths).
Another restriction for the function is that I decided to only handle single linestrings (gtype of 2 and not 6). If you need such a function then simply use the Explode function in my GEOM package and concatenate the results back together when finished.
The function allows the user to extend a linestring from the beginning (START), END or BOTH ends of the linestring.
And, finally, I don’t stop you from pumping geodetic data in to the function but the result will be, technically, incorrect. I will look to modify the function at some stage so that it handles geodetic data more correctly than the averaging that occurs now.
This is also the case for linestrings with 3-point circular curve elements: neither reduction (3-point circular curve anythere in the linestring) nor extension (where the 3-point circular curve is at either end of the linestring) respect a 3-point circular curve: it treats them as simple vertex-connected elements.
Now, like most functions, the following Extend function is dependent on other functions. The first is a function that can return a vertex in a geometry given the vertex’s position as a positive (starting at the beginning of the sdo_geometry) or negative (-1 is the last vertex, -2 second last etc). This function is in my NETWORK package but here is is:
/** ------------------------------------------------------------------------------------- * @function : get_point * @precis : Returns vertex of linestring/polygon as sdo_geometry. * @version : 1.0 * @description: Can nominate vertex either as positive number starting * at 1 up to max vertices, or specify vertex from the * last vertex down by specifying -1 down to -max vertices * @usage : FUNCTION get_point( p_geom IN SDO_GEOMETRY, * p_point_number IN NUMBER DEFAULT 1 ) * RETURN SDO_GEOMETRY DETERMINISTIC; * @param : p_geom : Geometry * @paramtype : p_geom : MDSY.SDO_GEOMETRY * @param : p_point_number : Vertex number between 1..(max vertices) OR * -1 .. -(max vertices) * @paramtype : p_point_number : Integer * @history : Simon Greener - June 2008 - Original coding. * @copyright : Free for public use **/ CREATE FUNCTION get_point ( p_geom SDO_GEOMETRY, p_point_number NUMBER DEFAULT 1 ) RETURN SDO_GEOMETRY IS v_d NUMBER; -- Number of dimensions in geometry v_gtype NUMBER; -- SDO_GTYPE of returned geometry v_p NUMBER; -- Index into ordinates array v_px NUMBER; -- X of extracted point v_py NUMBER; -- Y of extracted point v_pz NUMBER; -- Z of extracted point BEGIN -- Get the number of dimensions from the gtype v_d := SUBSTR (p_geom.SDO_GTYPE, 1, 1); -- Verify that the point exists -- and set index in ordinates array IF p_point_number = 0 OR ABS(p_point_number) > p_geom.SDO_ORDINATES.COUNT()/v_d THEN RETURN NULL; ELSIF p_point_number <= -1 THEN v_p := ( (p_geom.SDO_ORDINATES.COUNT() / v_d) + p_point_number ) * v_d + 1 ; ELSE v_p := (p_point_number - 1) * v_d + 1; END IF; -- Extract the X and Y coordinates of the desired point v_gtype := 2001; v_px := p_geom.SDO_ORDINATES(v_p); v_py := p_geom.SDO_ORDINATES(v_p+1); IF v_d > 2 THEN v_gtype := 3001; v_pz := p_geom.SDO_ORDINATES(v_p+2); END IF; -- Construct and return the point RETURN SDO_GEOMETRY ( v_gtype, p_geom.SDO_SRID, SDO_POINT_TYPE (v_px, v_py, v_pz), NULL, NULL); END Get_Point;
Here is how to use it:
SELECT get_point(a.geom,1) AS start_geom, get_point(a.geom,-1) AS end_geom FROM (SELECT sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)) AS geom FROM dual) a; -- Results START_GEOM END_GEOM ---------------------------------------------------------- ---------------------------------------------------------- SDO_GEOMETRY(2001,NULL,SDO_POINT_TYPE(1,1,NULL),NULL,NULL) SDO_GEOMETRY(2001,NULL,SDO_POINT_TYPE(4,3,NULL),NULL,NULL) . 1 ROWS selected
I also use my SDO_SetPoint and SDO_RemovePoint functions that I are described by the referenced blog articles.
The function uses two internal PL/SQL functions, Extension and Reduction to effect its processing. Reduction is selected when a negative “extension” distance is supplied. If a negative distance is supplied and that distance is greater than the segment being processed, the function will “prune” segments off the end of line that is being processed. Fairly obviously an reduction distance that is greater than the length of the line will be rejected.
Here is the function.
/** ---------------------------------------------------------------------------------------- * @function : Extend * @precis : Shortens or increases length of single linestring by desired amount. * @description : To extend a linestring provide a positive number. The line string * will be extended by taking the bearing of the first/last vector in the linestring * and extending it by the desired amount. Providing START for the p_end parameter * will cause the linestring to be ended at its beginning only; END ensures the * extension occurs from the end of the linestring; BOTH ensures extension occurs at * both ends. Providing a negative extension value will cause the linestring to shrink * from either START, END or BOTH ends. If vertices are met when shrink the linestring * within the distance to be shrunk the vertices will be removed. * @version : 1.0 * @usage : FUNCTION get_point( p_geom in sdo_geometry, * p_extension in number, * p_tolerance in number, * p_end in varchar2 default 'START' ) * RETURN SDO_GEOMETRY DETERMINISTIC; * @param : p_geom : Geometry * @paramtype : p_geom : MDSY.SDO_GEOMETRY * @param : p_extension : The value to extend or shrink (-ve) the linestring * @paramtype : p_extension : number * @param : p_tolerance : Standard Oracle diminfo tolerance. * @paramType : p_tolerance : Number * @param : p_end : START, END or BOTH * @paramType : p_end : VARCHAR * @history : Simon Greener - July 2009 - Original coding. * @copyright : Licensed under a Creative Commons Attribution-Share Alike 2.5 Australia License. * (http://creativecommons.org/licenses/by-sa/2.5/au/) **/ CREATE OR REPLACE FUNCTION extend( p_geom IN sdo_geometry, p_extension IN NUMBER, p_tolerance IN NUMBER, p_end IN varchar2 DEFAULT 'START' ) RETURN sdo_geometry AS v_geom sdo_geometry := p_geom; v_geom_length NUMBER := 0; v_x_round_factor NUMBER; v_y_round_factor NUMBER; v_end varchar2(5) := UPPER(SUBSTR(p_end,1,5)); INVALID_END EXCEPTION; BAD_EXTENSION EXCEPTION; NULL_EXTENSION EXCEPTION; NULL_TOLERANCE EXCEPTION; NULL_GEOMETRY EXCEPTION; NOT_LINEAR EXCEPTION; -- PROCEDURE Extension( p_end_pt_id IN NUMBER, p_internal_pt_id IN NUMBER, p_extension IN NUMBER) IS v_extend NUMBER := p_extension; v_end_pt sdo_geometry; v_internal_pt sdo_geometry; v_deltaX NUMBER; v_deltaY NUMBER; v_length NUMBER; v_new_point Vertex_Type; BEGIN v_end_pt := Get_Point(v_geom,p_end_pt_id ); v_internal_pt := Get_Point(v_geom,p_internal_pt_id); v_deltaX := v_end_pt.sdo_point.x - v_internal_pt.sdo_point.x; v_deltaY := v_end_pt.sdo_point.y - v_internal_pt.sdo_point.y; v_length := SDO_GEOM.SDO_DISTANCE( v_end_pt, v_internal_pt, p_tolerance ); v_new_point := vertex_type(NULL,NULL,NULL,NULL,NULL); v_new_point.x := ROUND(v_internal_pt.sdo_point.x + v_deltaX * ( (v_Length + p_extension) / v_Length ), v_x_round_factor); v_new_point.y := ROUND(v_internal_pt.sdo_point.y + v_deltaY * ( (v_Length + p_extension) / v_Length ), v_y_round_factor); v_geom := CODESYS.GEOM.SDO_SetPoint(v_geom, v_new_point, CASE SIGN(p_end_pt_id) WHEN -1 THEN NULL ELSE 1 END ); END Extension; -- PROCEDURE Reduction( p_end_pt_id IN NUMBER, p_internal_pt_id IN NUMBER, p_extension IN NUMBER) IS v_extend NUMBER := p_extension; v_sign NUMBER := SIGN(p_end_pt_id); v_pt_id NUMBER := 0; v_end_pt sdo_geometry; v_internal_pt sdo_geometry; v_deltaX NUMBER; v_deltaY NUMBER; v_length NUMBER; v_new_point Vertex_Type; -- FUNCTION EndPoint( p_geom IN SDO_GEOMETRY ) RETURN NUMBER IS BEGIN RETURN (p_geom.SDO_ORDINATES.COUNT() / TO_NUMBER(SUBSTR(p_geom.SDO_GTYPE,1,1)) ); END EndPoint; -- BEGIN LOOP v_pt_id := v_pt_id + v_sign; v_end_pt := Get_Point(v_geom,v_pt_id ); v_internal_pt := Get_Point(v_geom,v_pt_id + v_sign); v_deltaX := v_end_pt.sdo_point.x - v_internal_pt.sdo_point.x; v_deltaY := v_end_pt.sdo_point.y - v_internal_pt.sdo_point.y; v_length := sdo_geom.sdo_distance( v_end_pt, v_internal_pt, p_tolerance ); IF ( ABS(ROUND(v_extend, v_x_round_factor + 1)) >= ROUND(v_length, v_x_round_factor + 1) ) THEN v_geom := CODESYS.GEOM.SDO_RemovePoint(v_geom,v_pt_id); v_extend := v_length + v_extend; v_pt_id := v_pt_id - v_sign; ELSE v_new_point := vertex_type(NULL,NULL,NULL,NULL,NULL); v_new_point.x := ROUND(v_internal_pt.sdo_point.x + v_deltaX * ( (v_Length + v_extend) / v_Length ), v_x_round_factor); v_new_point.y := ROUND(v_internal_pt.sdo_point.y + v_deltaY * ( (v_Length + v_extend) / v_Length ), v_y_round_factor); v_geom := CODESYS.GEOM.SDO_SetPoint(v_geom, v_new_point, CASE v_sign WHEN -1 THEN EndPoint(v_geom) ELSE v_pt_id END ); EXIT; END IF; END LOOP; END Reduction; -- BEGIN IF ( p_tolerance IS NULL ) THEN RAISE NULL_TOLERANCE; END IF; v_x_round_factor := round(log(10,(1/p_tolerance)/2)); v_y_round_factor := round(log(10,(1/p_tolerance)/2)); IF ( v_geom IS NULL ) THEN RAISE NULL_GEOMETRY; END IF; -- Only support simple linestrings IF ( MOD(v_geom.sdo_gtype,10) <> 2 ) THEN RAISE NOT_LINEAR; END IF; IF ( NOT v_end IN ('START','BOTH','END') ) THEN RAISE INVALID_END; END IF; IF ( p_extension IS NULL OR p_extension = 0 ) THEN RAISE NULL_EXTENSION; END IF; IF ( SIGN(p_extension) = -1 ) THEN -- Is reduction distance (when BOTH) greater than actual length of string? v_geom_length := SDO_GEOM.SDO_LENGTH(v_geom,p_tolerance); IF ( ABS(p_extension) >= ( v_geom_length / CASE v_end WHEN 'BOTH' THEN 2.0 ELSE 1 END ) ) THEN RAISE BAD_EXTENSION; END IF; END IF; IF v_end IN ('START','BOTH') THEN IF ( SIGN(p_extension) = 1 ) THEN Extension(1,2,p_extension); ELSE Reduction(1,2,p_extension); END IF; END IF; IF v_end IN ('BOTH','END') THEN IF ( SIGN(p_extension) = 1 ) THEN Extension(-1,-2,p_extension); ELSE Reduction(-1,-2, p_extension); END IF; END IF; RETURN v_geom; EXCEPTION WHEN NULL_GEOMETRY THEN raise_application_error(-20001,'p_geom may not be NULL.'); WHEN NULL_TOLERANCE THEN raise_application_error(-20001,'p_tolerance may not be NULL.'); WHEN NULL_EXTENSION THEN raise_application_error(-20001,'p_extension value must not be 0 or NULL.'); WHEN NOT_LINEAR THEN raise_application_error(-20001,'p_geom must be a single linestring.'); WHEN INVALID_END THEN raise_application_error(-20001,'p_end value (' || v_end || ') must be START, BOTH or END'); WHEN BAD_EXTENSION THEN raise_application_error(-20001,'Reduction of geometry of length (' || v_geom_length || ') of each end by (' || ABS(p_extension) || ') would result in zero length geometry.'); END extend;
Testing
Right, now let’s throw some test data at this function to show how it performs.
Reduction/Shrinkage
-- Test Shape SELECT sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)) AS geom FROM dual; -- Results GEOM ------------------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(1,1,2,2,3,2,4,3)) . 1 ROWS selected -- -- Shrink from end by 1.414 meters ... SELECT extend(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)),-1.414,0.005,'END') AS sGeom FROM dual; -- Results SGEOM --------------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(1,1,2,2,3,2)) . 1 ROWS selected
Let’s visualise this. The green background line is the original test line. The red dotted line is the result of its reduction.
-- Shrink from start by 1.414 meters ... SELECT extend(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)),-1.414,0.05,'START') AS sGeom FROM dual; -- Results SGEOM --------------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(2,2,3,2,4,3)) . 1 ROWS selected
Let’s visualise this. The green background line is the original test line. The red dotted line is the result of its reduction.
-- Shrink from both ends by 1.414 meters ... SELECT extend(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)),-1.414,0.05,'BOTH') AS sGeom FROM dual; -- Results SGEOM ----------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(2,2,3,2)) . 1 ROWS selected
Let’s visualise this. The green background line is the original test line. The red dotted line is the result of its reduction.
-- Shrink from both ends by 1.5 meters ... SELECT extend(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)),-1.5,0.05,'BOTH') AS sGeom FROM dual; -- Results SGEOM --------------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(2.1,2,2.9,2)) . 1 ROWS selected
Let’s visualise this. The green background line is the original test line. The red dotted line is the result of its reduction.
-- Shrink from both ends by 2.0 meters each ... SELECT extend(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)),-2.0,0.05,'BOTH') AS sGeom FROM dual; -- Results Error report: SQL Error: ORA-20001: Reduction OF geometry OF LENGTH (3.82842712474619) OF each END BY (2) would RESULT IN zero LENGTH geometry. ORA-06512: at "CODESYS.EXTEND", line 191 ORA-06512: at line 1 -- -- Shrink both ends by half actual length to generate 0 length linestring... SELECT extend(a.geom,-1 * sdo_geom.sdo_length(a.geom,0.05)/2,0.05,'BOTH') AS sGeom FROM (SELECT sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)) AS geom FROM dual ) a; -- Results Error report: SQL Error: ORA-20001: Reduction OF geometry OF LENGTH (3.82842712474619) OF each END BY (1.914213562373095) would RESULT IN zero LENGTH geometry. ORA-06512: at "CODESYS.EXTEND", line 191 ORA-06512: at line 1 -- -- Shrink from end by 0.2 meters less than actual length of original linestring ... SELECT extend(a.geom,-1 * (sdo_geom.sdo_length(a.geom,0.05) - 0.2),0.05,'END') AS sGeom FROM (SELECT sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)) AS geom FROM dual ) a; -- Results SGEOM --------------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(1,1,1.1,1.1)) . 1 ROWS selected
Let’s visualise this. The green background line is the original test line. The red dotted line is the result of its reduction.
Extension Tests
Now let’s conduct some tests showing how to extend a linestring from one, or both, ends.
-- Extend from end 1.414 meters ... SELECT extend(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)),1.414,0.05,'END') AS eGeom FROM dual; -- Results EGEOM ------------------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(1,1,2,2,3,2,5,4)) . 1 ROWS selected
Let’s visualise this. The green background line is the original test line. The red dotted line is the result of its extension.
-- Extend from starting end 1.414 meters ... SELECT extend(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)),1.414,0.05,'START') AS egeom FROM dual; -- Results EGEOM ------------------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(0,0,2,2,3,2,4,3)) . 1 ROWS selected
Let’s visualise this. The green background line is the original test line. The red dotted line is the result of its extension.
-- Extend from both ends 1.414 meters ... SELECT extend(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)),1.414,0.05,'BOTH') AS eGeom FROM dual; -- Results EGEOM ------------------------------------------------------------------------------------------- SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(0,0,2,2,3,2,5,4)) . 1 ROWS selected
Let’s visualise this. The green background line is the original test line. The red dotted line is the result of its extension.
Uses
Other than extending the side boundaries of the cadastral polygon in the first image, the extend function can be used for all sorts of things. One particularly useful example is its use in extending a road centreline so that it touches the boundary of a buffer generated around the same road centreline. Here is an example based on our linestring pretending to be a road centreline!
CREATE TABLE rd_centreline_extended AS SELECT 1 AS id,sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)) AS geom FROM dual UNION ALL SELECT 2 AS id,extend(a.geom,1.0,0.005,'BOTH') AS geom FROM (SELECT sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)) AS geom FROM dual) a UNION ALL SELECT 3 AS id,sdo_geom.sdo_buffer(b.geom,1.0,0.005) AS geom FROM (SELECT sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(1,1,2,2,3,2,4,3)) AS geom FROM dual) b; -- Result CREATE TABLE succeeded.
Which, when visualised, looks like this:
I hope someone finds this useful.
I will consider looking at handling geodetic data is anyone shows any interest. Similarly, if anyone wants the function to behave in a similar manner to the FME ExtensionFactory drop me a line. Or, if anyone makes these changes themselves, I would appreciate a copy!
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