Yep, that's my understanding of Oracle as well. Postgresql is not as dumb though, planning happens when the actual parameters are provided, even with prepared statements: http://www.postgresql.org/docs/9.3/static/sql-prepare.html
This is however a recent improvement, for example the 9.1 documentation reports the same behavior as Oracle: http://www.postgresql.org/docs/9.1/static/sql-prepare.html Checked, this improvement is indeed part of the 9.2 release notes: http://www.postgresql.org/docs/9.2/static/release-9-2.html Cheers Andrea On Thu, Oct 1, 2015 at 8:54 AM, Patrick Valsecchi < [email protected]> wrote: > I'm a bit rusty in Oracle, but if I remember well, oracle parses and > builds a plan only once. Then, when the same query comes again, it uses the > cached plan. So the optimization of ignoring the second expression of the > OR is made impossible because of the variable bindings. > > Also, that maybe explains why the same query (with OR and two equivalent > expressions) without bound variables uses the index. > > On Wed, Sep 30, 2015 at 5:49 PM, Andrea Aime <[email protected] > > wrote: > >> On Wed, Sep 30, 2015 at 5:07 PM, Ron Lindhoudt <[email protected]> >> wrote: >> >>> Not sure if this helps: >>> - If you really need the OR you can maybe rewrite the query and use a >>> UNION >>> - As far as I know Oracle cannot use an index if OR is used. Are there >>> any databases that do this? >>> >> >> Peter's issue should be solved by his fix. >> >> As for the more general case of dateline crossing, yes, in theory we >> could use a UNION. But that would >> mean, we have to maintain a separate codebase for Oracle, which we tried >> in the past, and resulted >> in the Oracle store being abandoned while the others were marching on. >> Currently we have a shared set of classes for all spatial databases, and >> a dialect for each one, to >> sort out the differences in syntax and the like, it makes it much easier >> to keep most databases >> on par, but deviations like this one are hard to manage. >> >> About databases using indexes in case of OR over selective clauses, yes, >> it's somewhat >> simple for a good designed optimizer, you do two index scans and pick the >> union of the >> tuple ids, it's well worth it if the index is deemed to be selective. >> I've been told Oracle can do it, but only in the enterprise version. >> Postgresql will do it in >> the one and only free version instead ;-) >> >> Here is an example with two bboxes, and the explain showing the two index >> scans being merged >> >> > explain select count(*) from osm_roads where geometry && >> ST_MakeEnvelope(12000000,4000000,12100000,4100000,3857) or geometry && >> ST_MakeEnvelope(13000000,4000000,13100000,4100000,3857); >> >> Aggregate (cost=18629.08..18629.09 rows=1 width=0) >> -> Bitmap Heap Scan on osm_roads (cost=278.66..18612.20 rows=6755 >> width=0) >> Recheck Cond: ((geometry && >> '0103000020110F000001000000050000000000000060E366410000000080844E410000000060E3664100000000D0474F41000000003414674100000000D0474F4100000000341467410000000080844E410000000060E366410000000080844E41'::geometry) >> OR (geometry && >> '0103000020110F0000010000000500000000000000A8CB68410000000080844E4100000000A8CB684100000000D0474F41000000007CFC684100000000D0474F41000000007CFC68410000000080844E4100000000A8CB68410000000080844E41'::geometry)) >> -> BitmapOr (cost=278.66..278.66 rows=6762 width=0) >> -> Bitmap Index Scan on osm_roads_geom >> (cost=0.00..211.44 rows=5220 width=0) >> Index Cond: (geometry && >> '0103000020110F000001000000050000000000000060E366410000000080844E410000000060E3664100000000D0474F41000000003414674100000000D0474F4100000000341467410000000080844E410000000060E366410000000080844E41'::geometry) >> -> Bitmap Index Scan on osm_roads_geom (cost=0.00..63.85 >> rows=1542 width=0) >> Index Cond: (geometry && >> '0103000020110F0000010000000500000000000000A8CB68410000000080844E4100000000A8CB684100000000D0474F41000000007CFC684100000000D0474F41000000007CFC68410000000080844E4100000000A8CB68410000000080844E41'::geometry) >> (8 rows) >> >> >> and here is the case of the same bbox, showing the planner is smart >> enough to even avoid doing the merge, it recognizes the bbox is the same >> and does a single scan: >> >> > explain select count(*) from osm_roads where geometry && >> ST_MakeEnvelope(12000000,4000000,12100000,4100000,3857) or geometry && >> ST_MakeEnvelope(12000000,4000000,12100000,4100000,3857); >> >> QUERY PLAN >> >> >> >> -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- >> Aggregate (cost=15214.68..15214.69 rows=1 width=0) >> -> Bitmap Heap Scan on osm_roads (cost=212.74..15201.63 rows=5220 >> width=0) >> Recheck Cond: (geometry && >> '0103000020110F000001000000050000000000000060E366410000000080844E410000000060E3664100000000D0474F41000000003414674100000000D0474F4100000000341467410000000080844E410000000060E366410000000080844E41'::geometry) >> -> Bitmap Index Scan on osm_roads_geom (cost=0.00..211.44 >> rows=5220 width=0) >> Index Cond: (geometry && >> '0103000020110F000001000000050000000000000060E366410000000080844E410000000060E3664100000000D0474F41000000003414674100000000D0474F4100000000341467410000000080844E410000000060E366410000000080844E41'::geometry) >> >> >> I believe Oracle cannot do this last type of evaluation because we are >> using prepared statements, and it's not able to re-evaluate the plan that >> was setup when parsing the version of the stataments with the ? >> (placeholders) inside >> >> >> Cheers >> Andrea >> >> >> >> -- >> == >> GeoServer Professional Services from the experts! Visit >> http://goo.gl/it488V for more information. >> == >> >> Ing. Andrea Aime >> @geowolf >> Technical Lead >> >> GeoSolutions S.A.S. >> Via Poggio alle Viti 1187 >> 55054 Massarosa (LU) >> Italy >> phone: +39 0584 962313 >> fax: +39 0584 1660272 >> mob: +39 339 8844549 >> >> http://www.geo-solutions.it >> http://twitter.com/geosolutions_it >> >> *AVVERTENZE AI SENSI DEL D.Lgs. 196/2003* >> >> Le informazioni contenute in questo messaggio di posta elettronica e/o >> nel/i file/s allegato/i sono da considerarsi strettamente riservate. Il >> loro utilizzo è consentito esclusivamente al destinatario del messaggio, >> per le finalità indicate nel messaggio stesso. Qualora riceviate questo >> messaggio senza esserne il destinatario, Vi preghiamo cortesemente di >> darcene notizia via e-mail e di procedere alla distruzione del messaggio >> stesso, cancellandolo dal Vostro sistema. Conservare il messaggio stesso, >> divulgarlo anche in parte, distribuirlo ad altri soggetti, copiarlo, od >> utilizzarlo per finalità diverse, costituisce comportamento contrario ai >> principi dettati dal D.Lgs. 196/2003. >> >> >> >> The information in this message and/or attachments, is intended solely >> for the attention and use of the named addressee(s) and may be confidential >> or proprietary in nature or covered by the provisions of privacy act >> (Legislative Decree June, 30 2003, no.196 - Italy's New Data Protection >> Code).Any use not in accord with its purpose, any disclosure, reproduction, >> copying, distribution, or either dissemination, either whole or partial, is >> strictly forbidden except previous formal approval of the named >> addressee(s). If you are not the intended recipient, please contact >> immediately the sender by telephone, fax or e-mail and delete the >> information in this message that has been received in error. The sender >> does not give any warranty or accept liability as the content, accuracy or >> completeness of sent messages and accepts no responsibility for changes >> made after they were sent or for other risks which arise as a result of >> e-mail transmission, viruses, etc. >> >> ------------------------------------------------------- >> > > -- == GeoServer Professional Services from the experts! Visit http://goo.gl/it488V for more information. == Ing. Andrea Aime @geowolf Technical Lead GeoSolutions S.A.S. Via Poggio alle Viti 1187 55054 Massarosa (LU) Italy phone: +39 0584 962313 fax: +39 0584 1660272 mob: +39 339 8844549 http://www.geo-solutions.it http://twitter.com/geosolutions_it *AVVERTENZE AI SENSI DEL D.Lgs. 196/2003* Le informazioni contenute in questo messaggio di posta elettronica e/o nel/i file/s allegato/i sono da considerarsi strettamente riservate. Il loro utilizzo è consentito esclusivamente al destinatario del messaggio, per le finalità indicate nel messaggio stesso. Qualora riceviate questo messaggio senza esserne il destinatario, Vi preghiamo cortesemente di darcene notizia via e-mail e di procedere alla distruzione del messaggio stesso, cancellandolo dal Vostro sistema. Conservare il messaggio stesso, divulgarlo anche in parte, distribuirlo ad altri soggetti, copiarlo, od utilizzarlo per finalità diverse, costituisce comportamento contrario ai principi dettati dal D.Lgs. 196/2003. The information in this message and/or attachments, is intended solely for the attention and use of the named addressee(s) and may be confidential or proprietary in nature or covered by the provisions of privacy act (Legislative Decree June, 30 2003, no.196 - Italy's New Data Protection Code).Any use not in accord with its purpose, any disclosure, reproduction, copying, distribution, or either dissemination, either whole or partial, is strictly forbidden except previous formal approval of the named addressee(s). If you are not the intended recipient, please contact immediately the sender by telephone, fax or e-mail and delete the information in this message that has been received in error. The sender does not give any warranty or accept liability as the content, accuracy or completeness of sent messages and accepts no responsibility for changes made after they were sent or for other risks which arise as a result of e-mail transmission, viruses, etc. -------------------------------------------------------
------------------------------------------------------------------------------
_______________________________________________ GeoTools-Devel mailing list [email protected] https://lists.sourceforge.net/lists/listinfo/geotools-devel
