Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    The Frontage Problem: Creating references from land parcel street frontage boundary to point in street
    Scheduling the Export of Spatial Data in Oracle to a Shapefile each night
    Oracle CENTROID package update
    Book: "Applying And Extending Oracle Spatial"
    Create Polygons and Linestrings From Bearings And Distances (COGO)
    Implementation Of Travelling Salesman Problem
    ST_Densify for Object PLSQL
    PLSQL ST_AsEWKT and ST_FromWKT Functions For Oracle (any version)
    Useful Package of Wrapper Functions for Sdo_Util.AffineTransforms
    GeoRaptor 4.x Update 2 (Project has Stalled)
    Tip: Drop that Spatial Index!
    Convert Single Geometry to Multi-part Geometry in Oracle Spatial
    Optimized Rectangle to 5 Point Polygon
    Centroid Package now supports Y ordinate seeding
    Convert GeoJSON document to Sdo_Geometry objects
    Function That Returns a Compass Point From a Whole Circle Bearing
    Playing around with Centroids by using different seed values
    Simple Oracle C Sprintf or Java String.format
    Some Oriented Point Functions
    Extracting Inner Rings Changed Ordinate Ordering: A Trap For Players Who Don't Read Documentation!
    PLS-00306: wrong number or types of arguments in call to 'SDO_GEOMETRY'
    Converting Google Earth Formatted Longitude/Latitude points to decimal degrees
    Oracle Business Intelligence Warehousing and Analytics - Spatial Summit
    How far inside, is inside? Measuring actual distance.
    Noding and building a polygon from single, overlapping linestrings
    Analyzing Spatial Query Performance Improvements in Oracle Spatial and Graph 12c Through Cross-Vendor Comparison
    ST_VertexN / ST_PointN - Extracting a specific point from any geometry
    Convert Single Point stored in SDO_ORDINATES to SDO_POINT_TYPE
    Aggregate APPEND Islands and XOR polygons
    Circular Arcs in Geodetic Polygons
    Some SDO_GEOMETRY/DIMINFO handling functions
    Changing all DIMINFO sdo_tolerance values for all metadata records in one go.
    Building Polygons from Incomplete Linestrings using ST_PolygonBuilder
    Computing Cardinal Directions to nearby geometries
    Intersecting two aggregated polygon layers with SC4O
    Spatial and Oracle 12c
    Update Triggers and SDO_GEOMETRY Equality
    Duplicate Geometry data and Data Models
    CENTROID package update
    How to calculate cumulative length of a linestring
    Compute Location from known Lat/Long point using delta easting and northing in miles
    SDO_AGGR_SET_UNION
    Sorting SDO_GEOMETRY data using the ORDER BY clause of a SELECT statement
    Creating linestrings from points
    Rounding Coordinates or Ordinates in SDO_GEOMETRY
    Effects of Sdo_Geometry Ordinate Precision on Performance
    Effects of Sdo_Geometry Ordinate Precision on Storage
    The Spatial filtering of geometries: The effect of tolerances on relationships
    Application of Delaunay Triangulation and Inverse Distance Weighting (IDW) in Oracle for Soils Interpolation
    Selecting all SDO_GTYPE values for all tables/sdo_geometry columns in a schema
    CENTROID package - Tips for Use
    Announcing the Spatial Companion For Oracle (SC4O)
    Filtering Rings (Oracle Spatial)
    Splitting a polygon using one or more linestrings
    isValid, isSimple, Dimension and CoordDim methods for SDO_Geometry
    Line Merging or Collecting lines together: ST_LineMerger
    ST_DeleteVertex for Oracle SDO_Geometry based on Jaspa/JTS
    3D/4D and SRID aware Conversion functions for SDO_Geometry: WKT and EWKT
    Topological vs Non-Topological Simplification/Generalization of Aggregated Area Geometies in Oracle
    Filtering very short linestrings via bitmap function index
    CENTROID For Oracle
    Gridding a sdo_geometry line/polygon object (Oracle)
    Finding centre and radius of a circular geometry
    Constraining geometry type for sdo_geometry column in a table.
    CASE Statements and SDO_GEOMETRY
    The Power of Constraints and Indexes for Spatial Constraints: stopping duplicate points
    Replacement for SDO_GEOM.RELATE - ST_Relate based on JTS
    Changing Oracle Spatial Index Parameters on existing index
    Writing Excel Spreadsheets files from within the Oracle database using Java and PL/SQL
    Writing xSV (eg csv) files from within the Oracle database using Java and PL/SQL
    A simple spike finder for Spatial/Locator
    JTS Java class compilation for 11g and above
    Random Spatial Search Procedure
    Geometry Snapping using JTS in Oracle
    Exposing JTS's MinimumBoundingCircle functionality
    Exposing JTS's Densifier functionality
    Using JTS's Comparison Functions - HausdorffSimilarityMeasure & AreaSimilarityMeasure with SDO_GEOMETRY
    Free JTS-based Area/Length Functions
    Handy way of systematically fixing polygon geometries with 13349 and other errors
    Standalone CENTROID package now available for download
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 4 Processing Geodetic data
    Configurable Buffer: JTS and Oracle
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 3
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 2
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 1
    Building Lines into Polygons in Oracle Locator / Spatial
    Finding Intersection Points between Line and Polygon
    SDO2GeoJSON
    Free version of sdo_length
    Alternative to my SQL based GetNumRings function
    External Tables and SDO_Geometry data.
    layer_gtype keyword issue when indexing linear data on 11g
    String Tokenizer for Oracle
    Free Aggregate Method for Concatenating 2D Lines in Oracle Locator 10g
    Reducing 5 Vertex Polygon to Optimized Rectangle
    Square Buffer
    Converting decimal seconds to string
    SDO_GEOM.VALIDATE_GEOMETRY_WITH_CONTEXT - 13356 Issues
    Valid conversion unit values for Oracle sdo_geom.sdo_length()
    Removing Steps in Gridded Vector Data - SmoothGrid for Oracle
    Oracle Spatial DISJOINT search/filtering
    Creating SDO_Geometry from geometric data recorded in the columns of a table
    Concave Hull Geometries in Oracle 11gR2
    Projecting SDO_GEOM_METADATA DIMINFO XY ordinates
    Instantiating MDSYS.VERTEX_TYPE
    New PL/SQL Packages - Rotate oriented point
    GeoRaptor Development Team
    Fast Refreshing Materialized View Containing SDO_GEOMETRY and SDO_GEOM.SDO_AREA function
    Performance of PL/SQL Functions using SQL vs Pure Code
    Implementing the BEST VicGrid Projection in Oracle 10gR2
    Making Sdo Geometry Metadata Update Generic Code
    ORA-13011 errors when using SDO_GEOM.VALIDATE_LAYER_WITH_CONTEXT()
    Extract Polygons from Compound Polygon
    Detecting sdo_geometries with compound (3-point Arcs) segments
    GEOMETRY_COLUMNS for Oracle Spatial
    Convert GML to SDO_Geometry in Oracle 10gR2
    Spatial Sorting of Data via Morton Key
    Swapping Ordinates in an SDO_GEOMETRY object
    New To_3D Function
    Extend (Reduce/Contract/Skrink) Function for Oracle
    Loading and Processing GPX 1.1 files using Oracle XMLDB
    Loading Spatial Data from an external CSV file in Oracle
    Calling the Oracle Spatial shapefile loader from within the Oracle database itself
    Implementing SDO_VertexUpdate/ST_VertexUpdate for Oracle
    Implementing SDO_RemovePoint/ST_RemovePoint for Oracle
    Implementing SDO_AddPoint/ST_AddPoint for Oracle
    ESRI ArcSDE Exverted and Inverted Polygons and Oracle Spatial
    Funky Fix Ordinates By Formula
    Implementing a SetPoint/ST_SetPoint function in Oracle
    Implementing an ST_SnapToGrid (PostGIS) function for Oracle Spatial
    Generating random point data
    Implementing an Affine/ST_Affine function for Oracle Spatial
    Implementing a Scale/ST_Scale function for Oracle Spatial
    Implementing a Parallel/ST_Parallel function for linestring data for Oracle Spatial
    Implementing a Rotate/ST_Rotate function for Oracle Spatial
    Limiting table list returned when connecting to Oracle Database using ODBC
    ST_Azimuth for Oracle: AKA Cogo.Bearing
    Implementing a Translate/ST_Translate/Move function for Oracle Spatial
    Elem_Info_Array Processing: An alternative to SDO_UTIL.GetNumRings and querying SDO_ELEM_INFO itself
    Minumum Bounding Rectangle (MBR) Object Type for Oracle
    How to extract elements from the result of an sdo_intersection of two polygons.
    How to restart a database after failed parameter change
    Fixing failed spatial indexes after import using data pump
    generate_series: an Oracle implementation in light of SQL Design Patterns
    Multi-Centroid Shootout
    Oracle Spatial Centroid Shootout
    On the use of ROLLUP in Oracle SELECT statements
    Surrounding Parcels
    Spatial Pipelining
    Using Oracle's SDO_NN Operator - Some examples
    Converting distances and units of measure in Oracle Locator
    Split Sdo_Geometry Linestring at a known point
    Forcing an Sdo_Geometry object to contain only points, lines or areas
    Unpacking USER_SDO_GEOM_METADATA's DIMINFO structure using SQL
    Generating multi-points from single point records in Oracle Spatial
    Object Tables of Sdo_Geometry
    Oracle Locator vs Oracle Spatial: A Reflection on Oracle Licensing of the SDO_GEOM Package
    FAST REFRESHing of Oracle Materialized Views containing Sdo_Geometry columns
    Australian MGA/AMG Zone Calculation from geographic (longitude/latitude) data
    Loading Shapefiles (SHP) into Oracle Spatial
    Oracle Spatial Mapping and Map Rendering Performance Tips
    The significance of sdo_lb/sdo_ub in USER_SDO_GEOM_METDATA: Do I need it?
    Oracle Spatial Forum - Melbourne April 2007
    Layer_GTypes for spatial indexes
    Oracle's SQL/MM Compliant Types
    Tips and Tricks

Search

    Browse

RSS / Atom

Email me

textpattern

Creative Commons License
All Blog Articles, Data Models and Free Source Code by Simon Greener, The SpatialDB Advisor is licensed under a Creative Commons Attribution-ShareAlike 3.0 Unported License.

Scheduling the Export of Spatial Data in Oracle to a Shapefile each night

Wednesday September 05 2018 at 15:18

KeywordsIntegration process spatial data export shapefile scheduled task oracle
Summary

Business Software Process Integration using Oracle Scheduled Tasks to export spatial data to external file formats like shapefiles, MapInfo Tab files, GeoJson etc.

While there is always a need for software like Safe Software’s Awesome FME to automate import and export tasks from your database, the ability to do so just using Oracle can also be enormously useful.

I have implemented the approach described below many times over the years, in different customer sites.

At one customer site, there was a requirement for the engineers to be able to access the latest version of the corporate spatial data stored in Oracle within their own dedicated desktop software. Some of that software could access Oracle directly, but some couldn’t. Additionally, the engineers needed to be able to take the data into the field where no connection to the database was possible.

Luckily their software could access shapefiles or MapInfo TAB files (even those which wrap a shapefile).

Additionally, spatial data within databases is often undergoing such editing that makes it difficult to enable direct access at any time of the day.

The obvious solution was to use Oracle Scheduled Tasks to export that critical engineering asset data each night to a shared drive. This approach provides security to end-users that they are working with the latest “published” version of the data (as different from the current version in the database that may still be undergoing editing). It also implements a level of robustness and reliability that is not possible when one is forced to use software external to the database and probably running on a completely different server.

Certainly the engineers and foresters that have benefited from these scheduled exports were happy with the idea!

But how do so it?

Well the Oracle Scheduler is easy enough to learn, but how can Oracle write formats that it does not directly support within the database?

(GeoJSON can be exported because most databases today support JSON and the ability to write/load data from disk.)

But Spatial to a Shapefile?

As I have said above one can use FME for this but not as a completely native Oracle process.

The solution I created uses my EXPORTER package which uses Java code (based on Java Topology Suite, GeoTools etc) to create the solution. The Java code is created, compiled and then loaded into the Oracle database JVM. The EXPORTER PL/SQL Package creates an interface which PL/SQL based processes can use. The EXPORTER Package supports ESRI Shapefiles, Wrapped TAB files, Excel Spreadsheets, Delimited Text Files (eg CSV) and soon GeoJSON.

Since I have been tidying up, improving, testing, and adding the GeoJSON functionality to the Java on which is based my EXPORTER code, I thought I would create an fully worked article on the exporting of sdo_geometry data to a shapefile via DBMS_SCHEDULER.

The EXPORTER package is available on my website. The new improved and expanded code will be re-leased soon as part of a whole package of tested software that will be bundled for purchase.

Here is an example of exporting data in a table called SEWER_PIT to a shapefile.

  1. DROP   TABLE Sewer_Pit  PURGE;
  2. TABLE SEWER_PIT dropped.
  3. .
  4. CREATE TABLE Sewer_Pit (
  5.   AssetId          INTEGER,
  6.   Pit_Label        varchar2(20),
  7.   Pit_Lid_Material varchar2(10),
  8.   Pit_Diameter     NUMBER,
  9.   Pit_Depth        NUMBER,
  10.   geom             mdsys.sdo_geometry
  11. );
  12. TABLE SEWER_PIT created.
  13. .
  14. SET FEEDBACK OFF
  15. INSERT INTO Sewer_Pit (AssetId, Pit_Label, Pit_Lid_Material, Pit_Diameter, Pit_Depth, geom)
  16.       SELECT rownum AS AssetId,
  17.              CHR(dbms_random.VALUE(65,90)) || to_char(round(dbms_random.VALUE(0,1000),0),'FM9999') AS Pit_Label,
  18.              CASE WHEN round(dbms_random.VALUE(0,1),0) = 0 THEN 'Concrete' ELSE 'Plastic' END AS Pit_Lid_Material,
  19.              CASE WHEN round(dbms_random.VALUE(0,1),0) = 0 THEN 900 ELSE 1200 END AS Pit_Diameter,
  20.              ROUND(dbms_random.VALUE(0.5,15.0),1) AS Pit_Depth,
  21.              mdsys.sdo_geometry(3001,
  22.                                 28355,
  23.                                 MDSYS.SDO_POINT_TYPE(
  24.                                    ROUND(DBMS_RANDOM.VALUE( 300000, 500000),3),
  25.                                    ROUND(DBMS_RANDOM.VALUE(5000000,5500000),3),
  26.                                    ROUND(DBMS_RANDOM.VALUE(    -50,   1500),2)),
  27.                                 NULL,NULL)
  28.        FROM DUAL
  29.      CONNECT BY LEVEL <= 500
  30. COMMIT
  31. SET FEEDBACK ON
  32. SET HEADING OFF
  33. .
  34. SELECT 'Inserted '||COUNT(*)||' records into Sewer_Pit' FROM Sewer_Pit
  35. Inserted 500 records INTO Sewer_Pit
  36. .
  37.  1 ROWS selected
  38. .
  39. SET HEADING ON
  40. DELETE FROM USER_SDO_GEOM_METADATA WHERE TABLE_NAME = UPPER('Sewer_Pit');
  41. 1 ROWS deleted.
  42. .
  43. COMMIT;
  44. committed.
  45. .
  46. DECLARE
  47.   v_shape mdsys.sdo_geometry;
  48. BEGIN
  49.   SELECT SDO_AGGR_MBR(geom)
  50.     INTO v_shape
  51.     FROM Sewer_Pit;
  52.   INSERT INTO USER_SDO_GEOM_METADATA(TABLE_NAME,COLUMN_NAME,DIMINFO,SRID)
  53.     VALUES (UPPER('Sewer_Pit'),
  54.             'GEOM',
  55.             MDSYS.SDO_DIM_ARRAY(
  56.                   MDSYS.SDO_DIM_ELEMENT('X',V_SHAPE.SDO_ORDINATES(1),V_SHAPE.SDO_ORDINATES(4),0.05),
  57.                   MDSYS.SDO_DIM_ELEMENT('Y',V_SHAPE.SDO_ORDINATES(2),V_SHAPE.SDO_ORDINATES(5),0.05),
  58.                   MDSYS.SDO_DIM_ELEMENT('Z',V_SHAPE.SDO_ORDINATES(3),V_SHAPE.SDO_ORDINATES(6),0.05)),
  59.             28355);
  60. END;
  61. /
  62. SHOW ERRORS
  63. anonymous block completed
  64. No Errors.
  65. .
  66. COMMIT;
  67. committed.
  68. .
  69. CREATE INDEX Sewer_Pit_GEOM ON Sewer_Pit(geom)
  70.        INDEXTYPE IS mdsys.spatial_index
  71.        parameters('sdo_indx_dims=2, layer_gtype=point');
  72. INDEX SEWER_PIT_GEOM created.
  73. .
  74. BEGIN
  75.  -- Note use of Aliases to make column names > 10 characters Dbase compliant
  76.  DBMS_SCHEDULER.CREATE_JOB (
  77.    job_name         ='ASSET_DATA_EXPORT',
  78.    job_type         ='PLSQL_BLOCK',
  79.    job_action       ='
  80. DECLARE
  81. BEGIN
  82.  EXPORTER.writeshapefile(
  83.   p_sql             =''SELECT ASSETID,PIT_LABEL,PIT_LID_MATERIAL as Lid_Mtrl,PIT_DIAMETER as diameter,PIT_DEPTH,GEOM FROM PROJPOINT2D'',
  84.   p_output_dir      =''C:\temp'',
  85.   p_file_name       =''points_night_extract'',
  86.   p_shape_type      =EXPORTER.c_Point,
  87.   p_geometry_index  =6,
  88.   p_precision       =3,
  89.   p_commit_interval =100,
  90.   p_prj_string      =''PROJCS["GDA94 / MGA zone 56",GEOGCS["GDA94",DATUM["D_GDA_1994",SPHEROID["GRS_1980",6378137,298.257222101]],PRIMEM["Greenwich",0],UNIT["Degree",0.017453292519943295]],PROJECTION["Transverse_Mercator"],PARAMETER["latitude_of_origin",0],PARAMETER["central_meridian",153],PARAMETER["scale_factor",0.9996],PARAMETER["false_easting",500000],PARAMETER["false_northing",10000000],UNIT["Meter",1]]'',
  91.   p_geomFormat      =EXPORTER.c_WKT_Format,
  92.   p_recordIdentifier=''GID''
  93.  );
  94. END;',
  95.  start_date      =to_timestamp(trunc(sysdate+1))+5/24,
  96.  repeat_interval ='freq=weekly; byday=mon,tue,wed,thu,fri; byhour=5; byminute=0; bysecond=0',
  97.  comments        ='Job to export sewer_pits for use with Civil Software every working day at 5am.'
  98. );
  99. END;
  100. /
  101. SHOW ERRORS
  102. anonymous block completed
  103. No Errors.
  104. .
  105. -- Enable the job
  106. EXEC DBMS_SCHEDULER.ENABLE('ASSET_DATA_EXPORT');
  107. anonymous block completed
  108. .
  109. -- Show the job
  110. SELECT job_name, job_type, schedule_type, start_date, Repeat_interval, Enabled, Run_Count, job_action FROM USER_SCHEDULER_JOBS;
  111. .
  112. -- Results edited and split across two lines...
  113. --
  114. JOB_NAME           JOB_TYPE         SCHEDULE_TYPE START_DATE                             REPEAT_INTERVAL                                                         ENABLED  RUN_COUNT
  115. ------------------------------- ------------- -------------------------------------- ---------------------------------------------------------------------------- ------- ---------
  116. ASSET_DATA_EXPORT  PLSQL_BLOCK      CALENDAR      06-SEP-18 05.00.00.000000000 AM AUSTRA freq=weekly; byday=mon,tue,wed,thu,fri; byhour=5; byminute=0; bysecond=0 TRUE            0
  117. .
  118. JOB_ACTION
  119. -------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  120. DECLARE
  121. BEGIN
  122.   EXPORTER.writeshapefile(
  123.    p_sql             ='SELECT ASSETID,PIT_LABEL,PIT_LID_MATERIAL,PIT_DIAMETER,PIT_DEPTH,GEOM FROM PROJPOINT2D',
  124.    p_output_dir      ='C:\temp',
  125.    p_file_name       ='points_night_extract',
  126.    p_shape_type      =EXPORTER.c_Point,
  127.    p_geometry_index  =6,
  128.    p_precision       =3,
  129.    p_commit_interval =100,
  130.    p_prj_string      ='PROJCS["GDA94 / MGA zone 56",GEOGCS["GDA94",DATUM["D_GDA_1994",SPHEROID["GRS_1980",6378137,298.257222101]],PRIMEM["Greenwich",0],UNIT["Degree",0.017453292519943295]],PROJECTION["Transverse_Mercator"],PARAMETER["latitude_of_origin",0],PARAMETER["central_meridian",153],PARAMETER["scale_factor",0.9996],PARAMETER["false_easting",500000],PARAMETER["false_northing",10000000],UNIT["Meter",1]]',
  131.    p_geomFormat      =EXPORTER.c_WKT_Format,
  132.    p_recordIdentifier='GID'
  133.    );
  134. END;
  135. .
  136.  1 ROWS selected
  137. .
  138. -- Drop the job
  139. EXECUTE DBMS_SCHEDULER.DROP_JOB (job_name => 'ASSET_DATA_EXPORT');
  140. anonymous block completed
  141. .
  142. -- Confirm job is gone.
  143. SELECT * FROM USER_SCHEDULER_JOBS
  144. no ROWS selected

Now this is of use to everybody working in a similar situation to that which caused this work to be done!

Creative Commons License

post this at del.icio.uspost this at Diggpost this at Technoratipost this at Redditpost this at Farkpost this at Yahoo! my webpost this at Windows Livepost this at Google Bookmarkspost this to Twitter

Comment

Article Navigation:   Previous   Next