Re: WHERE column = X AND column = Y will always be zero matching rows - Mailing list pgsql-bugs

From Tom Lane
Subject Re: WHERE column = X AND column = Y will always be zero matching rows
Date
Msg-id 3497515.1691085559@sss.pgh.pa.us
Whole thread Raw
In response to WHERE column = X AND column = Y will always be zero matching rows  ("[Quipsy] Markus Karg" <karg@quipsy.de>)
Responses AW: WHERE column = X AND column = Y will always be zero matching rows  ("[Quipsy] Markus Karg" <karg@quipsy.de>)
List pgsql-bugs
"[Quipsy] Markus Karg" <karg@quipsy.de> writes:
> (In the following X and Y are literals; X <> Y)
> I noticed is that...
> EXPLAIN SELECT column FROM Table WHERE column = X AND column = Y
> ...says that PostgreSQL actually wants to perform a Scan!

You should learn to read plans before complaining about them.

What you actually get is something like

regression=# explain analyze select * from tenk1 where hundred = 42 and hundred = 99;
                                             QUERY PLAN
-----------------------------------------------------------------------------------------------------
 Result  (cost=5.04..224.95 rows=1 width=244) (actual time=0.001..0.002 rows=0 loops=1)
   One-Time Filter: false
   ->  Bitmap Heap Scan on tenk1  (cost=5.04..224.95 rows=1 width=244) (never executed)
         Recheck Cond: (hundred = 42)
         ->  Bitmap Index Scan on tenk1_hundred  (cost=0.00..5.04 rows=100 width=0) (never executed)
               Index Cond: (hundred = 42)
 Planning Time: 0.148 ms
 Execution Time: 0.046 ms
(8 rows)

See the "never executed" markings?  The one-time filter prevents
anything below the Result from actually doing anything.

From memory, the reason it's like this is that it's the most
straightforward extension of cases involving pseudoconstant
conditions, that is parameters not known at plan time.
If you had something like "WHERE var = param1 AND var = const1"
then you might get something involving a "param1 = const1"
one-time filter, and below that a plan to retrieve rows with
"var = const1", which would only be run when the run-time-supplied
parameter happens to match the constant.

David's statement that we don't want to write code for such cases
isn't completely true, but it is true that we don't want to expend
code on producing a pretty-looking plan for them.

> BTW the same happens for column IS NULL AND column = Y.

That indeed is a case we haven't bothered with, and probably
never will.  The multiple-constants-equated-to-the-same-thing
situation is dealt with by the equivalence class machinery,
which has many other purposes but happens to be able to detect
that situation cheaply.  But IS NULL is not an equivalence
condition (as we define those, anyway).  Likewise, we won't
reduce something like "var > C1 AND var < C1" to constant-false;
there's just not enough win probability to justify spending
planner cycles looking for such cases.

            regards, tom lane



pgsql-bugs by date:

Previous
From: Jaime Casanova
Date:
Subject: Re: WHERE column = X AND column = Y will always be zero matching rows
Next
From: Nathan Bossart
Date:
Subject: Re: search_path not recomputed when role name changes