Thread: Query ending up with hitting all the partition with sub-query in the projection list
Query ending up with hitting all the partition with sub-query in the projection list
From
Rushabh Lathia
Date:
Hi All,
Query with the sub-query in the projection list ending up with hitting all the
partition table even though having proper partition key condition.
Example:
CREATE TABLE measurement (
city_id int not null,
logdate date not null,
peaktemp int,
unitsales int
);
CREATE TABLE measurement_y2006m02 (
CHECK ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' )
) INHERITS (measurement);
CREATE TABLE measurement_y2006m03 (
CHECK ( logdate >= DATE '2006-03-01' AND logdate < DATE '2006-04-01' )
) INHERITS (measurement);
CREATE TABLE test (
a int,
b date);
-- Hitting all the partition table
postgres=# explain select a , ( select city_id from measurement where logdate = test.b and logdate = '2006-02-02') xyz from test;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Seq Scan on test (cost=0.00..206289.95 rows=2140 width=8)
SubPlan 1
-> Result (cost=0.00..96.38 rows=27 width=4)
-> Append (cost=0.00..96.38 rows=27 width=4)
-> Result (cost=0.00..32.13 rows=9 width=4)
One-Time Filter: ('2006-02-02'::date = test.b)
-> Seq Scan on measurement (cost=0.00..32.13 rows=9 width=4)
Filter: (logdate = test.b)
-> Result (cost=0.00..32.13 rows=9 width=4)
One-Time Filter: ('2006-02-02'::date = test.b)
-> Seq Scan on measurement_y2006m02 measurement (cost=0.00..32.13 rows=9 width=4)
Filter: (logdate = test.b)
-> Result (cost=0.00..32.13 rows=9 width=4)
One-Time Filter: ('2006-02-02'::date = test.b)
-> Seq Scan on measurement_y2006m03 measurement (cost=0.00..32.13 rows=9 width=4)
Filter: (logdate = test.b)
(16 rows)
-- With swapping the condition hitting only one partition
postgres=# explain select a , ( select city_id from measurement where logdate = '2006-02-02' and logdate = test.b ) xyz from test;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Seq Scan on test (cost=0.00..137537.10 rows=2140 width=8)
SubPlan 1
-> Result (cost=0.00..64.25 rows=18 width=4)
-> Append (cost=0.00..64.25 rows=18 width=4)
-> Result (cost=0.00..32.13 rows=9 width=4)
One-Time Filter: (test.b = '2006-02-02'::date)
-> Seq Scan on measurement (cost=0.00..32.13 rows=9 width=4)
Filter: (logdate = '2006-02-02'::date)
-> Result (cost=0.00..32.13 rows=9 width=4)
One-Time Filter: (test.b = '2006-02-02'::date)
-> Seq Scan on measurement_y2006m02 measurement (cost=0.00..32.13 rows=9 width=4)
Filter: (logdate = '2006-02-02'::date)
(12 rows)
Here if with the swap of sub-query WHERE clause logdate = test.b and logdate = '2006-02-02' to
logdate = '2006-02-02' and logdate = test.b query hitting proper partition.
Any input/comments ?
Regards,
Rushabh LathiaRe: Query ending up with hitting all the partition with sub-query in the projection list
From
Tom Lane
Date:
Rushabh Lathia <rushabh.lathia@gmail.com> writes: > *-- Hitting all the partition table* > postgres=# explain select a , ( select city_id from measurement where *logdate > = test.b and logdate = '2006-02-02')* xyz from test; Hm. What's happening here is that you get an equivalence class containing logdate, test.b, and '2006-02-02', where test.b is actually a Param supplied from the outer query level. So the equivclass.c machinery considers that both test.b and '2006-02-02' are constants, and it just picks the first one to construct derived equalities from. So what comes out is "test.b = logdate and test.b = '2006-02-02'", and neither of those can be used by the constraint-exclusion machinery to prove that some partitions of "measurement" can be skipped. What we need is to teach generate_base_implied_equalities_const() to prefer an actual constant to pseudo-constants. Will fix, thanks for the example! regards, tom lane
Re: Query ending up with hitting all the partition with sub-query in the projection list
From
Rushabh Lathia
Date:
On Fri, Oct 26, 2012 at 10:39 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Rushabh Lathia <rushabh.lathia@gmail.com> writes:
> *-- Hitting all the partition table*
> postgres=# explain select a , ( select city_id from measurement where *logdate
> = test.b and logdate = '2006-02-02')* xyz from test;
Hm. What's happening here is that you get an equivalence class
containing logdate, test.b, and '2006-02-02', where test.b is actually
a Param supplied from the outer query level. So the equivclass.c
machinery considers that both test.b and '2006-02-02' are constants,
and it just picks the first one to construct derived equalities from.
So what comes out is "test.b = logdate and test.b = '2006-02-02'", and
neither of those can be used by the constraint-exclusion machinery to
prove that some partitions of "measurement" can be skipped.
What we need is to teach generate_base_implied_equalities_const() to
prefer an actual constant to pseudo-constants. Will fix, thanks for the
example!
Thanks for nice explanation.
regards, tom lane
Rushabh Lathia