Query ending up with hitting all the partition with sub-query in the projection list - Mailing list pgsql-hackers
From | Rushabh Lathia |
---|---|
Subject | Query ending up with hitting all the partition with sub-query in the projection list |
Date | |
Msg-id | CAGPqQf1pgXnEbzVnuKkW4=h2AJ9UNUWS1HdN7EK3sM2Dh0QTwA@mail.gmail.com Whole thread Raw |
Responses |
Re: Query ending up with hitting all the partition with sub-query in the projection list
|
List | pgsql-hackers |
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 Lathiapgsql-hackers by date: