[postgis-users] [From Oracle Spatial to PostGIS] How to store rectangles?
Simon Greener
simon at spatialdbadvisor.com
Sun Apr 26 16:56:27 PDT 2009
Mulone,
These scripts work and, perhaps, gives you an idea how to go about what you want to do.
1. Generate Test Data in Oracle
--optimized_oracle.sql
=============================================
DROP TABLE Conversion PURGE;
CREATE TABLE Conversion ( gid integer, geom mdsys.sdo_geometry );
SET FEEDBACK OFF
INSERT INTO COnversion
SELECT rownum,
mdsys.sdo_geometry(2003,4326,NULL,
MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,3),
MDSYS.SDO_ORDINATE_ARRAY(
ROUND(lon,2),
ROUND(lat,2),
ROUND(lon+dbms_random.value(0.1,1.0),2),
ROUND(lat+dbms_random.value(0.1,1.0),2)
))
FROM (SELECT dbms_random.value(147,149) as lon,
dbms_random.value(-44,-42) as lat
FROM DUAL)
CONNECT BY LEVEL <= 500;
commit;
select distinct sdo_geom.validate_geometry(geom,0.005) from conversion;
-- Write CSV header and data
SET ECHO OFF
@write_csv
===========================================================
2. Dump CSV file
--write_csv.sql
===========================================================
SET NEWPAGE 0
SET SPACE 0
SET LINESIZE 9999
SET PAGESIZE 0
SET FEEDBACK OFF
SET VERIFY OFF
SET HEADING OFF
SET MARKUP HTML OFF
SET TRIMSPOOL ON
SET LONG 4000
SET LONGCHUNKSIZE 500
SET TERMOUT OFF
SET SQLPROMPT OFF
spool c:\temp\conversion.csv
select 'gid,bottomleftlon,bottomleftlat,toprightlon,toprightlat' from dual;
select gid || ',' || bottomleftlon || ',' || bottomleftlat || ',' || toprightlon || ',' || toprightlat
from (select a.gid,
sum(case when MOD(rownum,2) = 1 then v.x else null end) as bottomleftlon,
sum(case when MOD(rownum,2) = 1 then v.y else null end) as bottomleftlat,
sum(case when MOD(rownum,2) = 0 then v.x else null end) as toprightlon,
sum(case when MOD(rownum,2) = 0 then v.y else null end) as toprightlat
from conversion a,
table(sdo_util.getvertices(a.geom)) v
group by a.gid
order by 1
);
spool off
SET SQLPROMPT 'SQL> '
===========================================================
3. Load into PostGIS
--optimized_postgis.sql
===========================================================
DROP TABLE Conversion;
CREATE TABLE Conversion (
GID integer,
bottomLeftLon double precision,
bottomLeftLat double precision,
topRightLon double precision,
topRightLat double precision);
COPY Conversion ( gid,bottomLeftLon,bottomLeftLat,topRightLon, topRightLat )
FROM 'c:/temp/conversion.csv'
WITH
DELIMITER AS ','
CSV HEADER ;
/*
insert into Conversion (bottomLeftLon,bottomLeftLat,topRightLon, topRightLat)
VALUES (147,-43,148,-42),
(148,-44,149,-43);
*/
SELECT addGeometryColumn('postgis','conversion','bbox','4326','POLYGON','2');
UPDATE Conversion set bbox = ST_SetSRID(ST_MakeBox2D(ST_MakePoint(bottomLeftLon,bottomLeftLat), ST_MakePoint(topRightLon, topRightLat)),4326);
SELECT gid, ST_AsText(bbox)
FROM Conversion
LIMIT 10;
-- Create a spatial index for faster querying
CREATE INDEX conversion_bbox ON conversion USING GIST ( bbox );
-- Now, use the newly indexed spatial column in the spatial equivalent of the above query
SELECT count(*)
FROM conversion
WHERE bbox && SetSRID('BOX3D(148.5 -43.1, 148.9 -42.4)'::box3d,4326) ;
===========================================================
regards
Simon
--
SpatialDB Advice and Design, Solutions Architecture and Programming,
Oracle Database 10g Administrator Certified Associate; Oracle Database 10g SQL Certified Professional
Oracle Spatial, SQL Server, PostGIS, MySQL, ArcSDE, Manifold GIS, FME, Radius Topology and Studio Specialist.
39 Cliff View Drive, Allens Rivulet, 7150, Tasmania, Australia.
Website: www.spatialdbadvisor.com
Email: simon at spatialdbadvisor.com
Voice: +61 362 396397
Mobile: +61 418 396391
Skype: sggreener
Longitude: 147.20515 (147° 12' 18" E)
Latitude: -43.01530 (43° 00' 55" S)
NAC:W80CK 7SWP3
More information about the postgis-users
mailing list