<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.0 Transitional//EN">
<HTML xmlns="http://www.w3.org/TR/REC-html40" xmlns:v =
"urn:schemas-microsoft-com:vml" xmlns:o =
"urn:schemas-microsoft-com:office:office" xmlns:w =
"urn:schemas-microsoft-com:office:word" xmlns:m =
"http://schemas.microsoft.com/office/2004/12/omml"><HEAD>
<META content="text/html; charset=us-ascii" http-equiv=Content-Type>
<META name=GENERATOR content="MSHTML 9.00.8112.16437"><!--[if !mso]>
<STYLE>v\:* {
BEHAVIOR: url(#default#VML)
}
o\:* {
BEHAVIOR: url(#default#VML)
}
w\:* {
BEHAVIOR: url(#default#VML)
}
.shape {
BEHAVIOR: url(#default#VML)
}
</STYLE>
<![endif]-->
<STYLE>@font-face {
font-family: Calibri;
}
@page Section1 {size: 8.5in 11.0in; margin: 1.0in 1.0in 1.0in 1.0in; }
P.MsoNormal {
MARGIN: 0in 0in 0pt; FONT-FAMILY: "Calibri","sans-serif"; FONT-SIZE: 11pt
}
LI.MsoNormal {
MARGIN: 0in 0in 0pt; FONT-FAMILY: "Calibri","sans-serif"; FONT-SIZE: 11pt
}
DIV.MsoNormal {
MARGIN: 0in 0in 0pt; FONT-FAMILY: "Calibri","sans-serif"; FONT-SIZE: 11pt
}
A:link {
COLOR: blue; TEXT-DECORATION: underline; mso-style-priority: 99
}
SPAN.MsoHyperlink {
COLOR: blue; TEXT-DECORATION: underline; mso-style-priority: 99
}
A:visited {
COLOR: purple; TEXT-DECORATION: underline; mso-style-priority: 99
}
SPAN.MsoHyperlinkFollowed {
COLOR: purple; TEXT-DECORATION: underline; mso-style-priority: 99
}
SPAN.EmailStyle17 {
FONT-FAMILY: "Calibri","sans-serif"; COLOR: windowtext; mso-style-type: personal-compose
}
.MsoChpDefault {
mso-style-type: export-only
}
DIV.Section1 {
page: Section1
}
</STYLE>
<!--[if gte mso 9]><xml>
<o:shapedefaults v:ext="edit" spidmax="2050" />
</xml><![endif]--><!--[if gte mso 9]><xml>
<o:shapelayout v:ext="edit">
<o:idmap v:ext="edit" data="1" />
</o:shapelayout></xml><![endif]--></HEAD>
<BODY lang=EN-US vLink=purple link=blue>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial>Stephen, </FONT></SPAN></DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial></FONT></SPAN> </DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial>It takes a brave man to admit he is using antiquated
technology. I applaud you :).</FONT></SPAN></DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial></FONT></SPAN> </DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial>I see one major issue here. You are doing a cartesian
product before unioning / collecting.</FONT></SPAN></DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial></FONT></SPAN> </DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial>That means for every new.the_geom you have you are creating n
copies of it where n is the number of boundary_old records you have and then
unioning that permutation. You'll get the right answer, but it will be
really slow the more geometries you have. </FONT></SPAN></DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial></FONT></SPAN> </DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial>Try this:</FONT></SPAN></DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT color=#0000ff
size=2 face=Arial></FONT></SPAN> </DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT
face="Courier New"> SELECT ST_SymDifference(new.geom,
oldd.geom)</FONT></SPAN></DIV>
<DIV dir=ltr align=left><SPAN class=203172201-18102011><FONT
face="Courier New">FROM </FONT><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN
class=203172201-18102011> </SPAN></SPAN></DIV>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN class=203172201-18102011>(SELECT
ST_Union(the_geom) As geom FROM </SPAN>boundary<SPAN
class=203172201-18102011>) AS</SPAN> neww</SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN class=203172201-18102011> CROSS
JOIN (SELECT ST_Union(the_geom) As geom FROM </SPAN>boundary_old<SPAN
class=203172201-18102011>) AS</SPAN> oldd;</SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"></SPAN> </P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN class=203172201-18102011>The above
should be faster, but depending on how many geometries you have could still be
slow.</SPAN></SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN class=203172201-18102011>In 1.4 and
above, aggregation speed and ST_Unionspeed got wicked faster than 1.3
especially when you are talking about a lot of geometries.</SPAN></SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN
class=203172201-18102011></SPAN></SPAN> </P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN class=203172201-18102011>That would be
one reason to upgrade.</SPAN></SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN
class=203172201-18102011></SPAN></SPAN> </P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN class=203172201-18102011>As far as
using ST_Collect vs. ST_Union. If you are dealing with polygons you are
much safer using ST_Union since ST_Collect will create invalid multipolygons if
any of your geometries intersect.</SPAN></SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN
class=203172201-18102011></SPAN></SPAN> </P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN class=203172201-18102011>Hope that
helps,</SPAN></SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN
class=203172201-18102011>Regina</SPAN></SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN class=203172201-18102011><A
href="http://www.postgis.us">http://www.postgis.us</A></SPAN></SPAN></P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><SPAN
class=203172201-18102011></SPAN></SPAN> </P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"></SPAN> </P>
<P dir=ltr class=MsoNormal align=left><SPAN
style="FONT-FAMILY: 'Courier New'"><o:p></o:p></SPAN> </P>
<P dir=ltr class=MsoNormal align=left><o:p><FONT color=#0000ff size=2
face=Arial></FONT></o:p></P></SPAN><BR>
<BLOCKQUOTE
style="BORDER-LEFT: #0000ff 2px solid; PADDING-LEFT: 5px; MARGIN-LEFT: 5px; MARGIN-RIGHT: 0px"
dir=ltr>
<DIV dir=ltr lang=en-us class=OutlookMessageHeader align=left>
<HR tabIndex=-1>
<FONT size=2 face=Tahoma><B>From:</B>
postgis-users-bounces@postgis.refractions.net
[mailto:postgis-users-bounces@postgis.refractions.net] <B>On Behalf Of
</B>Stephen V. Mather<BR><B>Sent:</B> Monday, October 17, 2011 5:03
PM<BR><B>To:</B> postgis-users@postgis.refractions.net<BR><B>Subject:</B>
[postgis-users] ST_SymDifference<BR></FONT><BR></DIV>
<DIV></DIV>
<DIV class=Section1>
<P class=MsoNormal>Hi All,<o:p></o:p></P>
<P
class=MsoNormal>
True confession, I’m running PostGIS 1.3.5, so throw the tomatoes gently if A)
I’m doing a bad query, or B) I’m dredging up old news on (in)efficiency, and I
really should upgrade to 1.5.x, thank you very much… . Admittedly, it is
time for that, but hopefully that’s a separate issue.<o:p></o:p></P>
<P
class=MsoNormal>
I’m trying to calculate the symmetrical difference on a pair of geometries,
and my query runs slowly:<o:p></o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'"> SELECT
ST_SymDifference(<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'">
ST_Collect(neww.the_geom),<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'">
ST_Collect(oldd.the_geom) <o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'">
) AS the_geom<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'">
FROM boundary neww, boundary_old oldd;<o:p></o:p></SPAN></P>
<P class=MsoNormal><o:p> </o:p></P>
<P style="TEXT-INDENT: 0.5in" class=MsoNormal>Now, if I were to be entirely
honest, I’d confess that this was my cludge of an original
query:<o:p></o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'"> SELECT
ST_SymDifference(<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'">
ST_Union(ST_Buffer(neww.the_geom, 0)),<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'">
ST_Union(ST_Buffer(oldd.the_geom, 0)) <o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'">
) AS the_geom<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Courier New'">
FROM boundary neww, boundary_old oldd;<o:p></o:p></SPAN></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal>but who would admit to running a query like that, should
they know better. Not I.<o:p></o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal>So, why is my query sooooo slooooow? Is it A), B), or
some yet to be known to me C). BTW, (now I’m just to being provocative,)
when I run a symmetrical difference in ArcGIS, it runs very quickly…
:).<o:p></o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal>Best,<o:p></o:p></P>
<P class=MsoNormal>Thanks,<o:p></o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal><!--[if gte vml 1]><v:shapetype id="_x0000_t75" coordsize="21600,21600"
o:spt="75" o:preferrelative="t" path="m@4@5l@4@11@9@11@9@5xe" filled="f"
stroked="f">
<v:stroke joinstyle="miter" />
<v:formulas>
<v:f eqn="if lineDrawn pixelLineWidth 0" />
<v:f eqn="sum @0 1 0" />
<v:f eqn="sum 0 0 @1" />
<v:f eqn="prod @2 1 2" />
<v:f eqn="prod @3 21600 pixelWidth" />
<v:f eqn="prod @3 21600 pixelHeight" />
<v:f eqn="sum @0 0 1" />
<v:f eqn="prod @6 1 2" />
<v:f eqn="prod @7 21600 pixelWidth" />
<v:f eqn="sum @8 21600 0" />
<v:f eqn="prod @7 21600 pixelHeight" />
<v:f eqn="sum @10 21600 0" />
</v:formulas>
<v:path o:extrusionok="f" gradientshapeok="t" o:connecttype="rect" />
<o:lock v:ext="edit" aspectratio="t" />
</v:shapetype><v:shape id="cmp-ms-90x122.png" o:spid="_x0000_s1026" type="#_x0000_t75"
alt="http://www.clemetparks.com/images/esig/cmp-ms-90x122.png" style='position:absolute;
margin-left:1.5pt;margin-top:0;width:67.5pt;height:91.5pt;z-index:1;
visibility:visible;mso-wrap-style:square;mso-wrap-distance-left:9pt;
mso-wrap-distance-top:0;mso-wrap-distance-right:9pt;
mso-wrap-distance-bottom:0;mso-position-horizontal:absolute;
mso-position-horizontal-relative:text;mso-position-vertical:absolute;
mso-position-vertical-relative:text'>
<v:imagedata src="cid:image001.png@01CC8CEE.9BCADC50" o:href="http://www.clemetparks.com/images/esig/cmp-ms-90x122.png" />
<w:wrap type="square"/>
</v:shape><![endif]--><![if !vml]><IMG hspace=12
alt=http://www.clemetparks.com/images/esig/cmp-ms-90x122.png align=left
src="cid:203172201@18102011-3062" width=90 height=122
v:shapes="cmp-ms-90x122.png"><![endif]><SPAN
style="FONT-FAMILY: 'Arial','sans-serif'; COLOR: #006c56; FONT-SIZE: 14pt">Stephen
Mather<BR></SPAN><SPAN
style="FONT-FAMILY: 'Arial','sans-serif'; COLOR: #006c56">Geographic
Information Systems (GIS) Manager<BR></SPAN><SPAN
style="FONT-FAMILY: 'Arial','sans-serif'; COLOR: #006c56; FONT-SIZE: 9pt">(216)
635-3243<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN
style="FONT-FAMILY: 'Arial','sans-serif'; COLOR: #006c56; FONT-SIZE: 9pt">svm@clevelandmetroparks.com<BR></SPAN><A
href="http://www.clemetparks.com/"><SPAN
style="FONT-FAMILY: 'Arial','sans-serif'; FONT-SIZE: 9pt">clevelandmetroparks.com</SPAN></A><o:p></o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal><o:p> </o:p></P></DIV></BLOCKQUOTE></BODY></HTML>