Re: What does LIKE %% actually do in a WHERE clause?

From: Randolf Geist <info_at_www.sqltools-plusplus.org>
Date: Thu, 06 Oct 2011 08:55:05 +0200
Message-ID: <4E8D50C9.nailNON11T3ME_at_sqltools-plusplus.org>



Hi Norman,

I don't have a 9.2 database at hand but could reproduce the basic issue of not using the indexes with optimizer features set to 9.2 in 11.2.

The point seems to be that in this ancient version the FIRST_ROWS_n mode of the optimizer doesn't get activated although the ROWNUM predicate is specified. It looks like the automatic activation of the FIRST_ROWS_n mode was introduced in 10g. In those versions this is controlled via the "_optimizer_rownum_pred_based_fkr" parameter, set to default to "true" from then on. You could try if this parameter is already available in your version but set to "false" by default - of course not without negotiating with Oracle Support before doing so in production.

If this is not feasible / available, then in principle what your developers are looking for is adding the FIRST_ROWS(100) hint to the statement or setting the "optimizer_mode" to FIRST_ROWS_100 if this is what the majority of your statements is supposed to do anyway.

This way the optimizer ought to use an index driven plan if available and applicable.

I can't reproduce by the way the massive reduction in cardinality / difference in plan by adding these like predicates, but that might again be a problem of my version not matching. The point seems to be that this construct lowers the cardinality estimates in such a way in your version so that the index access plan gets favoured by the CBO.

As I said, what your developers should actually be looking for is the FIRST_ROWS_n mode.

Hope this helps,
Randolf

> Afternoon all,
>
> a developer is asking me what the exact function of "LIKE '%%'" in a WHERE clause is. I'm stumped, and cannot find anything on Google or in the Oracle docs.
>
> The puzzler is this:
>
> There is a SELECT on 4 tables using a cartesian join of all 4 and returning only the first 100 rows:
>
> SELECT A.*, B.*, C.*, D.*
> FROM A, B, C, D
> WHERE ...
> AND ROWNUM < 101;
>
> The WHERE clause simply joins the 4 tables, there is no actual record selection.
>
> As expected, this takes a wee while and results in a plan that hash joins the full table scan results for all tables.
>
> Now, the developer has added to the where clause something like the following:
>
> AND a.id like '%%'
> AND b.id like '%%'
> AND c.id like '%%'
> AND d.id like '%%'
>
> This time, the query runs in seconds and uses indexes on the ID columns of all the tables.
>
> The cardinality comes down to 1 for each table in the plan, as opposed to the previous 3 million or greater, but the results are exactly the same.
>
> If '%%' is replaced by '%' it goes back to the original plan of hash joining the 4 full table spaces.
>
> Google seems to ignore the %% in a search as does Oracle, whether in single or double quotes.
>
> It's puzzling me (and a colleague) and we don't like being puzzled. All the developer knows is that he heard about this "trick" somewhere, but he can't remember where and he wants to know how it works and what it is doing!

--
http://www.freelists.org/webpage/oracle-l
Received on Thu Oct 06 2011 - 01:55:05 CDT

Original text of this message