<html 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" xmlns="http://www.w3.org/TR/REC-html40">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=utf-8">
<meta name="Generator" content="Microsoft Word 14 (filtered medium)">
<style><!--
/* Font Definitions */
@font-face
{font-family:"Cambria Math";
panose-1:2 4 5 3 5 4 6 3 2 4;}
@font-face
{font-family:Calibri;
panose-1:2 15 5 2 2 2 4 3 2 4;}
@font-face
{font-family:Tahoma;
panose-1:2 11 6 4 3 5 4 4 2 4;}
/* Style Definitions */
p.MsoNormal, li.MsoNormal, div.MsoNormal
{margin:0cm;
margin-bottom:.0001pt;
font-size:12.0pt;
font-family:"Times New Roman","serif";}
a:link, span.MsoHyperlink
{mso-style-priority:99;
color:blue;
text-decoration:underline;}
a:visited, span.MsoHyperlinkFollowed
{mso-style-priority:99;
color:purple;
text-decoration:underline;}
tt
{mso-style-priority:99;
font-family:"Courier New";}
span.im
{mso-style-name:im;}
span.EmailStyle19
{mso-style-type:personal-reply;
font-family:"Calibri","sans-serif";
color:#1F497D;}
.MsoChpDefault
{mso-style-type:export-only;
font-family:"Calibri","sans-serif";
mso-fareast-language:EN-US;}
@page WordSection1
{size:612.0pt 792.0pt;
margin:3.0cm 2.0cm 3.0cm 2.0cm;}
div.WordSection1
{page:WordSection1;}
--></style><!--[if gte mso 9]><xml>
<o:shapedefaults v:ext="edit" spidmax="1026" />
</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="DA" link="blue" vlink="purple">
<div class="WordSection1">
<p class="MsoNormal"><span style="font-size:11.0pt;font-family:"Calibri","sans-serif";color:#1F497D">Hi Rémi and Andy.<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-size:11.0pt;font-family:"Calibri","sans-serif";color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span lang="EN-US" style="font-size:11.0pt;font-family:"Calibri","sans-serif";color:#1F497D">Thanks for your quick and simple but specific answer. It definitely helped me along the way toward a final solution.
<o:p></o:p></span></p>
<p class="MsoNormal"><span lang="EN-US" style="font-size:11.0pt;font-family:"Calibri","sans-serif";color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span lang="EN-US" style="font-size:11.0pt;font-family:"Calibri","sans-serif";color:#1F497D">Regards, Casper<o:p></o:p></span></p>
<p class="MsoNormal"><span lang="EN-US" style="font-size:11.0pt;font-family:"Calibri","sans-serif";color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span lang="EN-US" style="font-size:11.0pt;font-family:"Calibri","sans-serif";color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><b><span lang="EN-US" style="font-size:10.0pt;font-family:"Tahoma","sans-serif"">From:</span></b><span lang="EN-US" style="font-size:10.0pt;font-family:"Tahoma","sans-serif""> postgis-users-bounces@lists.osgeo.org [mailto:postgis-users-bounces@lists.osgeo.org]
<b>On Behalf Of </b>Rémi Cura<br>
<b>Sent:</b> 16. december 2014 17:50<br>
<b>To:</b> PostGIS Users Discussion<br>
<b>Subject:</b> Re: [postgis-users] Why won’t my SELECT query use the INDEX?<o:p></o:p></span></p>
<p class="MsoNormal"><span lang="EN-US"><o:p> </o:p></span></p>
<div>
<div>
<div>
<div>
<div>
<div>
<p class="MsoNormal">For this particular case,<br>
using st_srid(geom) means that the planner have to compute this value for each line .<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal">(the planner has no way to know that srid is the same for every geometry in the column, this might not be the case)<o:p></o:p></p>
</div>
<p class="MsoNormal">You can't use it .<br>
for instance, you could simply use plpgsql to get the srid, and create your querry directly with the number<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal">(your querry looks like it is fabricated programmatically anyway)<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal" style="margin-bottom:12.0pt">You could also look for this srid value in the geometry_columns view, but it would be less safe.
<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal" style="margin-bottom:12.0pt">lastly you coudl had an index on your geom table casted to srid 0, this way you could systematically cast your wkt to srid 0. I would call it a pretty bad idea unless you have lot's of differnt srid and you
will have to translate for other usages anyway<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal" style="margin-bottom:12.0pt">Example : <br>
CREATE INDEX ON my_table USING GIST( st_translate(geom,0) )<br>
<span class="im">SELECT "id",encode(ST_AsEWKB("geom"),'base64') as "geometry"</span><br>
<span class="im">FROM my_table</span><br>
<span class="im">WHERE st_translate(geom,0) &&</span><br>
ST_GeomFromText('POLYGON ((892267.1937422 6148208.34251139, 892500.497129949 6148208.34251139, 892500.497129949 6148009.40012468, 892267.1937422 6148009.40012468, 892267.1937422 6148208.34251139))',0)<o:p></o:p></p>
</div>
</div>
</div>
<p class="MsoNormal">Cheers,<o:p></o:p></p>
</div>
<p class="MsoNormal">Rémi-C<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal"><o:p> </o:p></p>
<div>
<p class="MsoNormal">2014-12-16 17:43 GMT+01:00 Rémi Cura <<a href="mailto:remi.cura@gmail.com" target="_blank">remi.cura@gmail.com</a>>:<o:p></o:p></p>
<div>
<div>
<div>
<div>
<div>
<div>
<div>
<p class="MsoNormal">Hey,<o:p></o:p></p>
</div>
<p class="MsoNormal">no index can come from 2 problems :<o:p></o:p></p>
</div>
<p class="MsoNormal"> - your querry can't use the index<o:p></o:p></p>
</div>
<p class="MsoNormal" style="margin-bottom:12.0pt"> - your querry could use the index but the planner thinks it's faster to do sequential scan.<o:p></o:p></p>
</div>
<p class="MsoNormal">You can discriminate between the 2 avoiding explicitly sequential scan :<br>
`SET enable_seqscan TO FALSE`<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal">(don't forget to turn it back one afterward)<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal">if you are still not using index, your querry can't use it at all, thus there is a problem of definition.<o:p></o:p></p>
</div>
<div>
<p class="MsoNormal">Cheers,<br>
Rémi-C<o:p></o:p></p>
</div>
</div>
</div>
<div>
<div>
<div>
<p class="MsoNormal"><o:p> </o:p></p>
<div>
<p class="MsoNormal">2014-12-16 17:23 GMT+01:00 Andy Colson <<a href="mailto:andy@squeakycode.net" target="_blank">andy@squeakycode.net</a>>:<o:p></o:p></p>
<div>
<div>
<p class="MsoNormal">On 12/16/2014 9:18 AM, Casper Børgesen (CABO) wrote:<o:p></o:p></p>
</div>
</div>
<blockquote style="border:none;border-left:solid #CCCCCC 1.0pt;padding:0cm 0cm 0cm 6.0pt;margin-left:4.8pt;margin-right:0cm">
<div>
<div>
<p class="MsoNormal" style="margin-bottom:12.0pt">This seems like one of the most asked questions in the PostgreSQL world,<br>
but I guess I haven’t understood all the answers yet:<br>
<br>
Why won’t my SELECT query use the INDEX I have created for it?<br>
<br>
I have a table with about 18mio rows.<br>
<br>
My SELECT statement looks like this:<br>
<br>
SELECT "id",encode(ST_AsEWKB("geom"),'base64') as "geometry"<br>
<br>
FROM my_table<br>
<br>
WHERE geom &&<br>
<br>
ST_GeomFromText('POLYGON ((892267.1937422 6148208.34251139,<br>
892500.497129949 6148208.34251139, 892500.497129949 6148009.40012468,<br>
892267.1937422 6148009.40012468, 892267.1937422 6148208.34251139))',<br>
ST_SRID("geom"))<br>
<br>
The EXPLAIN ANALYZE of the above statement returned this:<br>
<br>
"Seq Scan on my_table (cost=0.00..4329124.83 rows=1731 width=1700)<br>
(actual time=194785.745..1553525.244 rows=138 loops=1)"<br>
<br>
" Filter: (geom && st_geomfromtext('POLYGON ((892267.1937422<br>
6148208.34251139, 892500.497129949 6148208.34251139, 892500.497129949<br>
6148009.40012468, 892267.1937422 6148009.40012468, 892267.1937422<br>
6148208.34251139))'::text, st_srid(geom)))"<br>
<br>
" Rows Removed by Filter: 17311187"<br>
<br>
"Total runtime: 1553525.352 ms"<br>
<br>
The POLYGON described above is located at the outer edge of the 17mio<br>
geometries and the extent is pretty small.<br>
<br>
I have executed a VACUUM ANALYZE to clean up the statistics, which<br>
didn’t seem to improve the results.<br>
<br>
My INDEX has been created like this:<br>
<br>
CREATE INDEX my_table_geom_idx<br>
<br>
ON my_table<br>
<br>
USING gist<br>
<br>
(geom);<br>
<br>
Upon reading up on this issue I have changed the following in my<br>
postgresql.conf:<br>
<br>
random_page_cost = 2.0<br>
<br>
shared_buffers = 512MB<br>
<br>
work_mem = 8MB<br>
<br>
maintenance_work_mem = 256MB<br>
<br>
effective_cache_size = 8GB<br>
<br>
The HARDWARE is a Windows 2012R2 with 12GB ram and SAS HDDs. PostgreSQL<br>
9.3 x64 and PostGIS 2.1.1.<br>
<br>
Can any ask me the right questions so I can solve my INDEX problem?<br>
<br>
<br>
<o:p></o:p></p>
</div>
</div>
<p class="MsoNormal" style="margin-bottom:12.0pt">_______________________________________________<br>
postgis-users mailing list<br>
<a href="mailto:postgis-users@lists.osgeo.org" target="_blank">postgis-users@lists.osgeo.org</a><br>
<a href="http://lists.osgeo.org/cgi-bin/mailman/listinfo/postgis-users" target="_blank">http://lists.osgeo.org/cgi-bin/mailman/listinfo/postgis-users</a><o:p></o:p></p>
</blockquote>
<p class="MsoNormal"><br>
<br>
I doubt changing postgresql.conf options will have any affect.<br>
<br>
Its the st_srid(geom) call that's a problem.<br>
<br>
Remove it, or specify the integer value. The function call messes it up.<br>
<br>
This should work:<br>
<br>
<br>
explain analyze<br>
SELECT "id",encode(ST_AsEWKB("geom"),'base64') as "geometry"<br>
FROM my_table<br>
WHERE geom &&<br>
ST_GeomFromText('POLYGON ((892267.1937422 6148208.34251139, 892500.497129949 6148208.34251139, 892500.497129949 6148009.40012468, 892267.1937422 6148009.40012468, 892267.1937422 6148208.34251139))')<br>
<br>
<br>
-Andy<br>
<br>
<br>
<br>
_______________________________________________<br>
postgis-users mailing list<br>
<a href="mailto:postgis-users@lists.osgeo.org" target="_blank">postgis-users@lists.osgeo.org</a><br>
<a href="http://lists.osgeo.org/cgi-bin/mailman/listinfo/postgis-users" target="_blank">http://lists.osgeo.org/cgi-bin/mailman/listinfo/postgis-users</a><o:p></o:p></p>
</div>
</div>
</div>
</div>
</div>
</div>
</div>
</body>
</html>