<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=iso-8859-1"><meta name=Generator content="Microsoft Word 15 (filtered medium)"><!--[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 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;}
/* Style Definitions */
p.MsoNormal, li.MsoNormal, div.MsoNormal
{margin:0in;
margin-bottom:.0001pt;
font-size:12.0pt;
font-family:"Times New Roman",serif;}
a:link, span.MsoHyperlink
{mso-style-priority:99;
color:#0563C1;
text-decoration:underline;}
a:visited, span.MsoHyperlinkFollowed
{mso-style-priority:99;
color:#954F72;
text-decoration:underline;}
p
{mso-style-priority:99;
margin:0in;
margin-bottom:.0001pt;
font-size:12.0pt;
font-family:"Times New Roman",serif;}
span.EmailStyle18
{mso-style-type:personal-reply;
font-family:"Calibri",sans-serif;
color:#1F497D;}
.MsoChpDefault
{mso-style-type:export-only;
font-size:10.0pt;}
@page WordSection1
{size:8.5in 11.0in;
margin:1.0in 1.0in 1.0in 1.0in;}
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=EN-US link="#0563C1" vlink="#954F72"><div class=WordSection1><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>Lars,<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>Looking at the definition of pc_intersects, it is piggy backing on PostGIS ST_Intersects, which I can tell you right off the bat CAN NOT use an ND index, thus no surprise you aren't seeing index usage. On top of that ST_Intersects only looks at 2D part. To consider the Z you'd need ST_3DIntersects.<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>PostGIS team had discussed putting &&& in the ST_3DIntersects to use the 3D spatial operator &&& but we were worried about performance as we'd still need the && since most folks just have 2 d indexes so haven't settled on that yet. So it too ironically only uses && (the 2d spatial operator)<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>I'm not really sure why pc_patch opted for ST_Intersects since that doesn't care about the 3<sup>rd</sup> dimension at all and will only use X and Y.<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>ST_3DIntersects would have seemed like a better choice. <o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>Try creating functions like the below and see if you do better – note I put a U in front to distinguish it from pc patched shipped functions<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>CREATE OR REPLACE FUNCTION upc_3dintersects(<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> pcpatch,<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> geometry)<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> RETURNS boolean AS<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> SELECT $2 &&& PC_EnvelopeGeometry($1)) AND ST_3DIntersects($2, PC_EnvelopeGeometry($1))<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> LANGUAGE sql VOLATILE<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> COST 100;<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>CREATE OR REPLACE FUNCTION upc_3dintersects(<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> geometry,<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> pcpatch)<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> RETURNS boolean AS<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>$BODY$<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> SELECT UPC_Intersects($2, $1)<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> $BODY$<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> LANGUAGE sql VOLATILE<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'> COST 100;<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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>Then run<o:p></o:p></span></p><p class=MsoNormal><span style='font-family:"Calibri",sans-serif;color:black'>explain analyze select id from import where UPC_3DIntersects(pa, st_geomfromtext('POLYGON ((6.9821 25.2525......))', 4326));<o:p></o:p></span></p><p class=MsoNormal><span style='font-family:"Calibri",sans-serif;color:black'><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 style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'><o:p> </o:p></span></p><div><div style='border:none;border-top:solid #E1E1E1 1.0pt;padding:3.0pt 0in 0in 0in'><p class=MsoNormal style='margin-left:.5in'><b><span style='font-size:11.0pt;font-family:"Calibri",sans-serif'>From:</span></b><span style='font-size:11.0pt;font-family:"Calibri",sans-serif'> pgpointcloud [mailto:pgpointcloud-bounces@lists.osgeo.org] <b>On Behalf Of </b>Lars<br><b>Sent:</b> Wednesday, May 02, 2018 9:06 AM<br><b>To:</b> pgpointcloud@lists.osgeo.org<br><b>Subject:</b> Re: [pgpointcloud] PC_Intersects and indexing<o:p></o:p></span></p></div></div><p class=MsoNormal style='margin-left:.5in'><o:p> </o:p></p><div><p class=MsoNormal style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>Forgot to mention that we did run vacuum analyze without seeing much improvement.<o:p></o:p></span></p></div><div><p class=MsoNormal style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p></div><div><p class=MsoNormal style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>Using PostgresSQL 10.3 and Postgis 2.4.4 on Windows 7.<o:p></o:p></span></p></div><div class=MsoNormal align=center style='margin-left:.5in;text-align:center'><hr size=3 width="98%" align=center></div><div id=divRplyFwdMsg><p class=MsoNormal style='margin-left:.5in'><b><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:black'>Fra:</span></b><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:black'> pgpointcloud <<a href="mailto:pgpointcloud-bounces@lists.osgeo.org">pgpointcloud-bounces@lists.osgeo.org</a>> pć vegne av Lars <<a href="mailto:laasunde@hotmail.com">laasunde@hotmail.com</a>><br><b>Sendt:</b> 2. mai 2018 14:01<br><b>Til:</b> <a href="mailto:pgpointcloud@lists.osgeo.org">pgpointcloud@lists.osgeo.org</a><br><b>Emne:</b> [pgpointcloud] PC_Intersects and indexing</span> <o:p></o:p></p><div><p class=MsoNormal style='margin-left:.5in'> <o:p></o:p></p></div></div><div><div><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>Hello,<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>Used PDAL (1.7.1) to import xyz data into a PostgresSQL "pointcloud" table called "import" with chipper capacity set to 4000. The table has about 50,000 rows with more than 2GB of data.<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>The "import" table contains column id and pa which are of type integer and pcpatch respectively. The table is configured with btree indexing on the id column.<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>Running the following query takes 776,952 ms and returns two records.<br>select id from import where PC_Intersects(pa, st_geomfromtext('POLYGON ((6.9821 25.2525......))', 4326));<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>The documentation at <a href="https://github.com/pgpointcloud/pointcloud">https://github.com/pgpointcloud/pointcloud</a> mention using GIST as indexing;<br>CREATE INDEX ON import USING GIST(PC_BoundingDiagonalGeometry(pa) gist_geometry_ops_nd);<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>So we drop btree and add gist indexing, run the same query takes 796,384 ms and return the two same records.<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>We expected btree on a integer to be relative slow but gist on a spatial type to be relative quick but the actual performance appears to be quiet similar.<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>How does PC_Intersects function work? Does it need to decode the WellKnownBinary data inside pcpatch in order to determine the boundary? How does it use index?<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>Running "explain analyze select id from import where PC_Intersects(pa, st_geomfromtext('POLYGON ((6.9821 25.2525......))', 4326));"<br>QUERY_PLAN | Seq Scan on "import" (cost=10000000000..10000014803 rows=3539 width=4)<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>It was interesting to see that the query used sequential scan of the table. We expected the query to use indexing and wanted to understand more about why this is happening. <o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>Maybe the structure of our SQL query is suboptimal or we have configured PostgresSQL poorly or the planner takes into account number of rows or amount of data.<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>Appreciate any input<o:p></o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p><p style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'>kind regards, Lars<o:p></o:p></span></p><p class=MsoNormal style='margin-left:.5in'><span style='font-family:"Calibri",sans-serif;color:black'><o:p> </o:p></span></p></div></div></div></body></html>