[postgis-users] ST_Union (8.4) and TopologyException
Paragon Corporation
lr at pcorp.us
Sat Aug 8 22:51:25 PDT 2009
Simon,
Did you try separating out the timings between the Union and the
differencing. I'm wondering if the time is being lost in unioning or the
differencing part or combination of both. Something also very stupid may be
going on if postgresql choosed not to materialize that subselect for some
reason. Thats why for this type of thing, I like using CTEs instead since a
CTE will force a temp table creation (materialization of the subselect)
where
as a subselect is not guaranteed to and is finicky based on costing
parameters (which as we have discovered are kind of poor for PostGIS because
we haven't put in any costs).
The downside of CTE (well at least in PostgreSQL 8.4) is that it always
seems to force a temp table creation of some sort so for large numbers of
rows in result subselect you don't want materialized, may perform slower
than subselect way.
So I would write your below as
create table simon.si_result
as
WITH i AS
(select si_grouping_f_id, ST_Union(a.geom) as geom
from simon.si_grouping_f_store_f a
where geom is not null
group by si_grouping_f_id
)
select i.si_grouping_f_id, ST_Difference(s.geom,i.geom) as geom
from simon.si_grouping_f s
inner join i
on (s.id = i.si_grouping_f_id);
I probably made a typo but you get the idea.
Thanks,
Regina
-----Original Message-----
From: postgis-users-bounces at postgis.refractions.net
[mailto:postgis-users-bounces at postgis.refractions.net] On Behalf Of Simon
Greener
Sent: Saturday, August 08, 2009 7:11 PM
To: PostGIS Users Discussion
Subject: Re: [postgis-users] ST_Union (8.4) and TopologyException
Folks,
Sorry, yes, I was creating a table. I have visualised the result QGIS and
the result looks right.
create table simon.si_result
as
select i.si_grouping_f_id, ST_Difference(s.geom,i.geom) as geom
from simon.si_grouping_f s
inner join
(select si_grouping_f_id, ST_Union(a.geom) as geom
from simon.si_grouping_f_store_f a
where geom is not null
group by si_grouping_f_id
) as i
on (s.id = i.si_grouping_f_id);
S
On Sun, 09 Aug 2009 00:47:30 +1000, Paragon Corporation <lr at pcorp.us> wrote:
> Paul,
>> It's odd for union to return no result.
>
> I think he may have been dumping into a new table thus no results message
> though I thought inserts stated the number of records created, but can't
> recall if a select .. into bulk load does or not.
>
>> I can confirm that my data is now successfully processed by PostGIS's
> ST_Union though it isn't all that fast:
>>
>> "Query returned successfully with no result in 5011922 ms." = 1hr 23min
> which is pretty slow.
>
> Simon is that correct that you were dumping into a new table?
> I assumed you got something if you said it works correctly now.
>
> Thanks,
> Regina
>
>
> _______________________________________________
> postgis-users mailing list
> postgis-users at postgis.refractions.net
> http://postgis.refractions.net/mailman/listinfo/postgis-users
>
--
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
_______________________________________________
postgis-users mailing list
postgis-users at postgis.refractions.net
http://postgis.refractions.net/mailman/listinfo/postgis-users
More information about the postgis-users
mailing list