Deshalb wollen wir hier ein paar Hilfestellungen geben.
select * from dba_feature_usage_statistics where lower(name) like '%locator%' or lower(name) like '%spatial%';
Tipps, Tricks, Best Practices und Aktuelles zu Oracle Spatial Technologies
select * from dba_feature_usage_statistics where lower(name) like '%locator%' or lower(name) like '%spatial%';
SDO_UTIL.RECTIFY_GEOMETRY( geom IN SDO_GEOMETRY, tolerance IN NUMBER ) RETURN SDO_GEOMETRY;
drop table geometry_errors purge; -- Fehlertabelle anlegen create table geometry_errors ( table_name varchar2(30), column_name varchar2(30), obj_rowid rowid, geometry sdo_geometry, tolerance number, error_code char(5), error_message varchar2(256), error_context varchar2(256), is_fixed number(1) default 0 );
-- Prozedur zum Prüfen auf invalide Geometrien im gesamten Schema -- Achtung: Kann einige Zeit in Anspruch nehmen! declare DEFAULT_TOLERANCE number := 0.0000005; COMMIT_FREQUENCY number := 100; geom_cursor sys_refcursor; v_diminfo sdo_dim_array; v_srid number; v_tolerance number; v_rowid rowid; v_geometry sdo_geometry; v_num_rows number; v_num_errors number; v_error_code char(5); v_error_message varchar2(256); v_error_context varchar2(256); v_status varchar2(256); begin -- Alle Tabellen mit SDO_GEOMETRY Spalten prozessieren for t in ( select table_name, column_name from user_tab_columns where data_type = 'SDO_GEOMETRY' order by table_name, column_name ) loop -- Lies Toleranz aus den Metadaten begin select diminfo, srid into v_diminfo, v_srid from user_sdo_geom_metadata where table_name = t.table_name and column_name = t.column_name; exception when no_data_found then v_diminfo := null; v_srid := null; end; -- Bei fehlenden Metadaten, Default-Toleranz annehmen if v_diminfo is null then v_tolerance := DEFAULT_TOLERANCE; else v_tolerance := v_diminfo(1).sdo_tolerance; end if; -- Geometrien prozessieren v_num_rows := 0; v_num_errors := 0; open geom_cursor for 'select rowid,' || t.column_name || ' from ' || t.table_name; loop v_status := NULL; -- Hole Geometrie fetch geom_cursor into v_rowid, v_geometry; exit when geom_cursor%notfound; v_num_rows := v_num_rows + 1; -- Validiere Geometry v_status := sdo_geom.validate_geometry_with_context (v_geometry, v_tolerance); -- Wenn Fehler, dann protokollieren if v_status <> 'TRUE' then -- Fehler hochzählen v_num_errors := v_num_errors + 1; -- Format the error message if length(v_status) >= 5 then v_error_code := substr(v_status, 1, 5); v_error_message := sqlerrm(-v_error_code); v_error_context := substr(v_status,7); else v_error_code := v_status; v_error_message := null; v_error_context := null; end if; -- Fehler wegschreiben insert into geometry_errors ( table_name, column_name, obj_rowid, geometry, tolerance, error_code, error_message, error_context ) values ( t.table_name, t.column_name, v_rowid, v_geometry, v_tolerance, v_error_code, v_error_message, v_error_context ); end if; -- Commit entsprechend COMMIT_FREQUENCY if mod(v_num_rows,COMMIT_FREQUENCY) = 0 then commit; end if; end loop; end loop; -- Finales Commit commit; end; /
-- Fehler pro Tabelle, Error Code select table_name, error_code, error_message, count(*) from geometry_errors group by table_name, error_code, error_message order by table_name, error_code; -- Fehler pro Error Code, Tabelle select error_code, error_message, table_name, count(*) from geometry_errors group by error_code, error_message, table_name order by error_code, table_name; -- Fehlerdetails select table_name, obj_rowid, is_fixed, error_message, error_context from geometry_errors where is_fixed = 0 order by table_name, obj_rowid;
-- Prozedur zum Korrigieren der Geometrien declare -- Fehlerbehandlung für nicht korrigierbare Geometrien -- "ORA-13199: the given geometry cannot be rectified" cannot_rectify exception; pragma exception_init(cannot_rectify, -13199); v_geometry_fixed sdo_geometry; begin -- Invalide Geometrien prozessieren for e in ( select rowid, table_name, column_name, obj_rowid, tolerance, geometry from geometry_errors where is_fixed = 0 order by table_name, column_name ) loop -- Wenn möglich, Geometrie korrigieren mit SDO_UTIL.RECTIFY_GEOMETRY. -- Andernfalls: -- In 11.1.0.6: Funktion gibt NULL zurück -- In 11.1.0.7 und 11.2: Funktion wirft ORA-13199 Fehler begin v_geometry_fixed := sdo_util.rectify_geometry (e.geometry, e.tolerance); exception when cannot_rectify then v_geometry_fixed := null; end; if v_geometry_fixed is not null then -- Korrigiere Geometrie execute immediate 'update ' || e.table_name || ' set '|| e.column_name || ' = :g where rowid = :r' using v_geometry_fixed, e.obj_rowid; -- Kennzeichne korrigierte Geometrien in Fehlertabelle mit is_fixed = 1 update geometry_errors set is_fixed = 1 where rowid = e.rowid; -- Alternativ ist auch DELETE möglich -- delete from geometry_error where rowid = e.rowid; end if; end loop; end; /
-- Fehler nach Tabelle, Korrekturstatus und Error Code select table_name, is_fixed, error_code, error_message, count(*) from geometry_errors group by table_name, is_fixed, error_code, error_message order by table_name, is_fixed, error_code; -- Fehler nach Korrekturstatus und Error Code select is_fixed, error_code, error_message, count(*) from geometry_errors group by is_fixed, error_code, error_message order by is_fixed, error_code; -- Details select table_name, obj_rowid, is_fixed, error_message, error_context from geometry_errors order by is_fixed, table_name, obj_rowid;
drop table geometry_errors purge;
<gpx xmlns="http://www.topografix.com/GPX/1/1" tc2=" ... <trk> <name>2010-11-16T03:46:55Z</name> <trkseg> <trkpt lat="51.4799802" lon="7.9678522"> <ele>270.7484131</ele> <time>2010-11-16T03:46:55Z</time> </trkpt> <trkpt lat="51.4799436" lon="7.9678679"> <ele>264.0192871</ele> <time>2010-11-16T03:47:06Z</time> </trkpt> <trkpt lat="51.4797696" lon="7.9681059"> <ele>264.4998779</ele> <time>2010-11-16T03:47:12Z</time> </trkpt> <trkpt lat="51.4797497" lon="7.9681919"> <ele>264.9805908</ele> <time>2010-11-16T03:47:14Z</time> </trkpt>
create or replace function convert_gpx_to_sdo( p_gpxfile in xmltype, p_lrs in number default 0 ) return sdo_geometry is v_ordinates sdo_ordinate_array := sdo_ordinate_array(); v_gtype number; v_cnt pls_integer := 1; v_startts timestamp; v_interval interval day(9) to second; c_gpxns varchar2(200) := 'xmlns="http://www.topografix.com/GPX/1/1"'; begin if p_lrs = 1 then v_gtype := 3302; else v_gtype := 2002; end if; for tp in ( select extractvalue(value(tp), '/trkpt/@lon', c_gpxns) x, extractvalue(value(tp), '/trkpt/@lat', c_gpxns) y, extractvalue(value(tp), '/trkpt/time', c_gpxns) m from table(xmlsequence(extract(p_gpxfile, '//trkpt', c_gpxns))) tp ) loop if v_cnt = 1 then v_startts := to_timestamp(tp.m, 'YYYY-MM-DD"T"HH24:MI:SS"Z"'); end if; if p_lrs = 1 then v_ordinates.extend(3); else v_ordinates.extend(2); end if; v_ordinates(v_cnt) := tp.x; v_cnt := v_cnt + 1; v_ordinates(v_cnt) := tp.y; v_cnt := v_cnt + 1; if p_lrs = 1 then v_interval := to_timestamp(tp.m, 'YYYY-MM-DD"T"HH24:MI:SS"Z"') - v_startts; v_ordinates(v_cnt) := extract(MINUTE from v_interval) + extract(HOUR from v_interval) * 60 + extract(SECOND from v_interval) / 60; v_cnt := v_cnt + 1; end if; end loop; return sdo_geometry(v_gtype, 8307, null, sdo_elem_info_array(1,2,1), v_ordinates); end convert_gpx_to_sdo; / sho err
insert into user_sdo_geom_metadata values ( '{TABLE/VIEW NAME}', '{GEOM_COL_NAME}', sdo_dim_array( sdo_dim_element('X', {xmin}, {xmax}, {tolerance}), sdo_dim_element('Y', {ymin}, {ymax}, {tolerance}) ), {SRID} ) /
select c2.feature_name, sdo_geom.relate( c2.geometry, 'determine', -- Maskierungsparameter c1.geometry, 0.05 ) topo_rel from m_admin_area1 c1, m_admin_area1 c2 where c1.feature_name = 'GERMANY';
SQL> insert into user_sdo_geom_metadata (
table_name,
column_name,
diminfo,
srid)
values (
'GEOTAB',
'geometry',
sdo_dim_array(sdo_dim_element('X',-180,180,0.005),
sdo_dim_element('Y',-90,90,0.005)),
8307);
SQL> select * from user_sdo_geom_metadata where table_name = 'GEOTAB';bringt kein Ergebnis zurück.
SQL> select * from mdsys.sdo_geom_metadata_table;
Wie kann das jetzt bereinigt werden?
Bitten Sie Ihren DBA, Ihrem Nutzer UPDATE-Rechte für die MDSYS-Tabelle SDO_GEOM_METADATA_TABLE zuzuweisen.
SQL> grant update on mdsys.sdo_geom_metadata_table;
SQL> update MDSYS.SDO_GEOM_METADATA_TABLE
set sdo_owner='SPATIAL'
where sdo_table_name = 'GEOTAB' and sdo_owner = 'ANONYMOUS';
SQL> select srid,cs_name from cs_srs where srid in (31467, 82027) SRID CS_NAME ---------- ---------------------------------------- 31467 DHDN / Gauss-Kruger zone 3 82027 GK Zone 3 (DHDN)
select sdo_cs.transform( sdo_geometry(2001, 8307, sdo_point_type(11.536734, 48.1800773, null), null, null), 31467 ) transformed from dual; TRANSFORMED ------------------------------------------------------------------------------------ SDO_GEOMETRY(2001, 31467, SDO_POINT_TYPE(3688714,69, 5341125,2, NULL), NULL, NULL)
select sdo_cs.transform( SDO_GEOMETRY(2001, 31467, SDO_POINT_TYPE(3688714.69, 5341125.2, NULL), NULL, NULL ), 8307 ) transformed from dual; TRANSFORMED ------------------------------------------------------------------------------------ SDO_GEOMETRY(2001, 8307, SDO_POINT_TYPE(11,5367341, 48,1800773, NULL), NULL, NULL) select sdo_cs.transform( SDO_GEOMETRY(2001, 82027, SDO_POINT_TYPE(3688714.69, 5341125.2, NULL), NULL, NULL ), 8307 ) from dual; TRANSFORMED ------------------------------------------------------------------------------------ SDO_GEOMETRY(2001, 8307, SDO_POINT_TYPE(11,5391267, 48,180154, NULL), NULL, NULL)
select sdo_geom.sdo_distance( sdo_cs.transform( SDO_GEOMETRY(2001, 31467, SDO_POINT_TYPE(3688714.69, 5341125.2, NULL), NULL, NULL ), 8307 ), sdo_cs.transform( SDO_GEOMETRY(2001, 82027, SDO_POINT_TYPE(3688714.69, 5341125.2, NULL), NULL, NULL ), 8307 ), 1 ) distanz from dual; DISTANZ ------------- 178,128988
SQL> select sdo_cs.transform( 2 SDO_GEOMETRY(2001, 82027, SDO_POINT_TYPE(3688714.69, 5341125.2, NULL), NULL, NULL ), 3 31467 4 ) TRANSFORMED from dual; TRANSFORMED ----------------------------------------------------------------------------------- SDO_GEOMETRY(2001, 31467, SDO_POINT_TYPE(3688892,31, 5341139,61, NULL), NULL, NULL)
SQL> select srid,cs_name from cs_srs where srid in (31466, 82015); SRID CS_NAME ---------- ---------------------------------------- 31466 DHDN / Gauss-Kruger zone 2 82015 GK Zone 2 (DHDN) SQL> select srid,cs_name from cs_srs where srid in (31468, 82032); SRID CS_NAME ---------- ---------------------------------------- 31468 DHDN / Gauss-Kruger zone 4 82032 GK Zone 4 (DHDN)
Aus einer zusammengesetzten Geometrie (Multipolygon, welches mehrere Elemente, optional auch Subelemente/Ringe enthält) können mit Hilfe der Funktion EXTRACT einzelne Elemente herausgezogen werden.
Diese Funktion für 2D-Vektordaten, sowie analog EXTRACT3D für 3D-Vektordaten, steht im PL/SQL Package SDO_UTIL zur Verfügung. Letztere Funktion gibt es allerdings erst seit der DB Version 11.1 im Package.
Das Format ist wie folgt kurz beschrieben:
Und wie geht´s konkret?
Gegeben sei das Multipolgyon "Brandenburg" (SDO_GTYPE = 2007) aus dem World Sample NAVTEQ Data Bundle.
-- Extraction von Element 1, Ring 1
-- Extraction von Element 1, Ring 2
-- Extraction von Element 2, Ring 2
Weitere Infos finden sich natürlich in der Online-Doku auf OTN (http://download.oracle.com/docs/cd/B19306_01/appdev.102/b14255/sdo_util.htm#sthref1955).
sdo_util.extract (
geometry IN SDO_GEOMETRY,
element IN NUMBER,
ring IN NUMBER default 0
) return sdo_geometry; -- 2D
SQL> select sdo_util.extract(geometry, 1, 1) from m_admin_area2 where feature_name = 'Brandenburg';
-- Ergebnis ist der äußere Ring von Brandenburg
SQL> select sdo_util.extract(geometry, 1, 2) from m_admin_area2 where feature_name = 'Brandenburg';
-- Ergebnis ist der innere Ring von Brandenburg, gleichzeitig die administrative Grenze des Bundeslandes Berlin
SQL> select sdo_util.extract(geometry, 2, 1) from m_admin_area2 where feature_name = 'Brandenburg';
-- Ergebnis hier ist eine kleine Brandenburgische Exklave in Sachsen-Anhalt