Skip to content

Commit 745b8ab

Browse files
committed
Fixing CustomScan pruning whenever the subplan is NOT of a Scan type. This bug manifested in LATERAL joins that have a time restriction and a constraint referencing the upper-level plan. As an optimization, also added a special case when the subplan is of type T_Result, which enables chunk pruning in this special case.
1 parent 472bf6a commit 745b8ab

File tree

4 files changed

+192
-15
lines changed

4 files changed

+192
-15
lines changed

src/constraint_aware_append.c

Lines changed: 43 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -67,6 +67,36 @@ excluded_by_constraint(RangeTblEntry *rte, AppendRelInfo *appinfo, List *restric
6767
return relation_excluded_by_constraints(&root, &rel, rte);
6868
}
6969

70+
static Plan *
71+
get_plans_for_exclusion(Plan *plan)
72+
{
73+
/* Optimization: If we want to be able to prune */
74+
/* when the node is a T_Result, then we need to peek */
75+
/* into the subplans of this Result node. */
76+
if (IsA(plan, Result))
77+
{
78+
Result *res = (Result *) plan;
79+
80+
if (res->plan.lefttree != NULL && res->plan.righttree == NULL)
81+
return res->plan.lefttree;
82+
if (res->plan.righttree != NULL && res->plan.lefttree == NULL)
83+
return res->plan.righttree;
84+
}
85+
return plan;
86+
}
87+
88+
static bool
89+
can_exclude_chunk(Scan *scan, AppendRelInfo *appinfo, EState *estate,
90+
List *restrictinfos)
91+
{
92+
RangeTblEntry *rte = rt_fetch(scan->scanrelid, estate->es_range_table);
93+
94+
return rte->rtekind == RTE_RELATION &&
95+
rte->relkind == RELKIND_RELATION &&
96+
!rte->inh &&
97+
excluded_by_constraint(rte, appinfo, restrictinfos);
98+
}
99+
70100
/*
71101
* Convert restriction clauses to constants expressions (i.e., if there are
72102
* mutable functions, they need to be evaluated to constants). For instance,
@@ -160,11 +190,10 @@ ca_append_begin(CustomScanState *node, EState *estate, int eflags)
160190

161191
forboth(lc_plan, old_appendplans, lc_info, append_rel_info)
162192
{
163-
Scan *scan = lfirst(lc_plan);
164-
AppendRelInfo *appinfo = lfirst(lc_info);
165-
RangeTblEntry *rte = rt_fetch(scan->scanrelid, estate->es_range_table);
193+
Plan *plan = get_plans_for_exclusion(lfirst(lc_plan));
194+
166195

167-
switch (nodeTag(scan))
196+
switch (nodeTag(plan))
168197
{
169198
case T_SeqScan:
170199
case T_SampleScan:
@@ -180,18 +209,17 @@ ca_append_begin(CustomScanState *node, EState *estate, int eflags)
180209
case T_WorkTableScan:
181210
case T_ForeignScan:
182211
case T_CustomScan:
183-
184-
/*
185-
* If this is a base rel (chunk), check if it can be excluded
186-
* from the scan. Otherwise, fall through.
187-
*/
188-
if (rte->rtekind == RTE_RELATION &&
189-
rte->relkind == RELKIND_RELATION &&
190-
!rte->inh &&
191-
excluded_by_constraint(rte, appinfo, restrictinfos))
192-
break;
212+
{
213+
/*
214+
* If this is a base rel (chunk), check if it can be
215+
* excluded from the scan. Otherwise, fall through.
216+
*/
217+
if (can_exclude_chunk((Scan *) plan, lfirst(lc_info), estate,
218+
restrictinfos))
219+
break;
220+
}
193221
default:
194-
*appendplans = lappend(*appendplans, scan);
222+
*appendplans = lappend(*appendplans, plan);
195223
}
196224
}
197225

test/expected/lateral.out

Lines changed: 96 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,96 @@
1+
CREATE TABLE regular_table(name text, junk text);
2+
CREATE TABLE ht(time timestamptz NOT NULL, location text);
3+
SELECT create_hypertable('ht', 'time');
4+
create_hypertable
5+
-------------------
6+
7+
(1 row)
8+
9+
INSERT INTO ht(time) select timestamp 'epoch' + (i * interval '1 second') from generate_series(1, 100) as T(i);
10+
INSERT INTO regular_table values('name', 'junk');
11+
SELECT * FROM regular_table ik LEFT JOIN LATERAL (select max(time::timestamptz) from ht s where ik.name='name' and s.time < now()) s on true;
12+
name | junk | max
13+
------+------+------------------------------
14+
name | junk | Thu Jan 01 00:01:40 1970 PST
15+
(1 row)
16+
17+
select * from regular_table ik LEFT JOIN LATERAL (select max(time::timestamptz) from ht s where ik.name='name' and s.time > now()) s on true;
18+
name | junk | max
19+
------+------+-----
20+
name | junk |
21+
(1 row)
22+
23+
DROP TABLE regular_table;
24+
DROP TABLE ht;
25+
CREATE TABLE orders(id int, user_id int, time TIMESTAMPTZ NOT NULL);
26+
SELECT create_hypertable('orders', 'time');
27+
create_hypertable
28+
-------------------
29+
30+
(1 row)
31+
32+
INSERT INTO orders values(1,1,timestamp 'epoch' + '1 second');
33+
INSERT INTO orders values(2,1,timestamp 'epoch' + '2 second');
34+
INSERT INTO orders values(3,1,timestamp 'epoch' + '3 second');
35+
INSERT INTO orders values(4,2,timestamp 'epoch' + '4 second');
36+
INSERT INTO orders values(5,1,timestamp 'epoch' + '5 second');
37+
INSERT INTO orders values(6,3,timestamp 'epoch' + '6 second');
38+
INSERT INTO orders values(7,1,timestamp 'epoch' + '7 second');
39+
INSERT INTO orders values(8,4,timestamp 'epoch' + '8 second');
40+
INSERT INTO orders values(9,2,timestamp 'epoch' + '9 second');
41+
-- Need a LATERAL query with a reference to the upper-level table and
42+
-- with a restriction on time
43+
-- Upper-level table constraint should be a constant in order to trigger
44+
-- creation of a one-time filter in the planner
45+
SELECT user_id, first_order_time, max_time FROM
46+
(SELECT user_id, min(time) AS first_order_time FROM orders GROUP BY user_id) o1
47+
LEFT JOIN LATERAL
48+
(SELECT max(time) AS max_time FROM orders WHERE o1.user_id = '2' AND time > now()) o2 ON true
49+
ORDER BY user_id, first_order_time, max_time;
50+
user_id | first_order_time | max_time
51+
---------+------------------------------+----------
52+
1 | Thu Jan 01 00:00:01 1970 PST |
53+
2 | Thu Jan 01 00:00:04 1970 PST |
54+
3 | Thu Jan 01 00:00:06 1970 PST |
55+
4 | Thu Jan 01 00:00:08 1970 PST |
56+
(4 rows)
57+
58+
SELECT user_id, first_order_time, max_time FROM
59+
(SELECT user_id, min(time) AS first_order_time FROM orders GROUP BY user_id) o1
60+
LEFT JOIN LATERAL
61+
(SELECT max(time) AS max_time FROM orders WHERE o1.user_id = '2' AND time < now()) o2 ON true
62+
ORDER BY user_id, first_order_time, max_time;
63+
user_id | first_order_time | max_time
64+
---------+------------------------------+------------------------------
65+
1 | Thu Jan 01 00:00:01 1970 PST |
66+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:09 1970 PST
67+
3 | Thu Jan 01 00:00:06 1970 PST |
68+
4 | Thu Jan 01 00:00:08 1970 PST |
69+
(4 rows)
70+
71+
-- Nested LATERALs
72+
SELECT user_id, first_order_time, time1, min_time FROM
73+
(SELECT user_id, min(time) AS first_order_time FROM orders GROUP BY user_id) o1
74+
LEFT JOIN LATERAL
75+
(SELECT user_id as o2user_id, time AS time1 FROM orders WHERE o1.user_id = '2' AND time < now()) o2 ON true
76+
LEFT JOIN LATERAL
77+
(SELECT min(time) as min_time FROM orders WHERE o2.o2user_id = '1' AND time < now()) o3 ON true
78+
ORDER BY user_id, first_order_time, time1, min_time;
79+
user_id | first_order_time | time1 | min_time
80+
---------+------------------------------+------------------------------+------------------------------
81+
1 | Thu Jan 01 00:00:01 1970 PST | |
82+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:01 1970 PST | Thu Jan 01 00:00:01 1970 PST
83+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:02 1970 PST | Thu Jan 01 00:00:01 1970 PST
84+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:03 1970 PST | Thu Jan 01 00:00:01 1970 PST
85+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:04 1970 PST |
86+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:05 1970 PST | Thu Jan 01 00:00:01 1970 PST
87+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:06 1970 PST |
88+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:07 1970 PST | Thu Jan 01 00:00:01 1970 PST
89+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:08 1970 PST |
90+
2 | Thu Jan 01 00:00:04 1970 PST | Thu Jan 01 00:00:09 1970 PST |
91+
3 | Thu Jan 01 00:00:06 1970 PST | |
92+
4 | Thu Jan 01 00:00:08 1970 PST | |
93+
(12 rows)
94+
95+
-- Cleanup
96+
DROP TABLE orders;

test/sql/CMakeLists.txt

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -30,6 +30,7 @@ set(TEST_FILES
3030
index.sql
3131
insert_single.sql
3232
insert.sql
33+
lateral.sql
3334
partitioning.sql
3435
pg_dump.sql
3536
plain.sql

test/sql/lateral.sql

Lines changed: 52 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,52 @@
1+
CREATE TABLE regular_table(name text, junk text);
2+
CREATE TABLE ht(time timestamptz NOT NULL, location text);
3+
SELECT create_hypertable('ht', 'time');
4+
5+
INSERT INTO ht(time) select timestamp 'epoch' + (i * interval '1 second') from generate_series(1, 100) as T(i);
6+
INSERT INTO regular_table values('name', 'junk');
7+
8+
SELECT * FROM regular_table ik LEFT JOIN LATERAL (select max(time::timestamptz) from ht s where ik.name='name' and s.time < now()) s on true;
9+
select * from regular_table ik LEFT JOIN LATERAL (select max(time::timestamptz) from ht s where ik.name='name' and s.time > now()) s on true;
10+
11+
DROP TABLE regular_table;
12+
DROP TABLE ht;
13+
14+
CREATE TABLE orders(id int, user_id int, time TIMESTAMPTZ NOT NULL);
15+
SELECT create_hypertable('orders', 'time');
16+
INSERT INTO orders values(1,1,timestamp 'epoch' + '1 second');
17+
INSERT INTO orders values(2,1,timestamp 'epoch' + '2 second');
18+
INSERT INTO orders values(3,1,timestamp 'epoch' + '3 second');
19+
INSERT INTO orders values(4,2,timestamp 'epoch' + '4 second');
20+
INSERT INTO orders values(5,1,timestamp 'epoch' + '5 second');
21+
INSERT INTO orders values(6,3,timestamp 'epoch' + '6 second');
22+
INSERT INTO orders values(7,1,timestamp 'epoch' + '7 second');
23+
INSERT INTO orders values(8,4,timestamp 'epoch' + '8 second');
24+
INSERT INTO orders values(9,2,timestamp 'epoch' + '9 second');
25+
26+
-- Need a LATERAL query with a reference to the upper-level table and
27+
-- with a restriction on time
28+
-- Upper-level table constraint should be a constant in order to trigger
29+
-- creation of a one-time filter in the planner
30+
SELECT user_id, first_order_time, max_time FROM
31+
(SELECT user_id, min(time) AS first_order_time FROM orders GROUP BY user_id) o1
32+
LEFT JOIN LATERAL
33+
(SELECT max(time) AS max_time FROM orders WHERE o1.user_id = '2' AND time > now()) o2 ON true
34+
ORDER BY user_id, first_order_time, max_time;
35+
36+
SELECT user_id, first_order_time, max_time FROM
37+
(SELECT user_id, min(time) AS first_order_time FROM orders GROUP BY user_id) o1
38+
LEFT JOIN LATERAL
39+
(SELECT max(time) AS max_time FROM orders WHERE o1.user_id = '2' AND time < now()) o2 ON true
40+
ORDER BY user_id, first_order_time, max_time;
41+
42+
-- Nested LATERALs
43+
SELECT user_id, first_order_time, time1, min_time FROM
44+
(SELECT user_id, min(time) AS first_order_time FROM orders GROUP BY user_id) o1
45+
LEFT JOIN LATERAL
46+
(SELECT user_id as o2user_id, time AS time1 FROM orders WHERE o1.user_id = '2' AND time < now()) o2 ON true
47+
LEFT JOIN LATERAL
48+
(SELECT min(time) as min_time FROM orders WHERE o2.o2user_id = '1' AND time < now()) o3 ON true
49+
ORDER BY user_id, first_order_time, time1, min_time;
50+
51+
-- Cleanup
52+
DROP TABLE orders;

0 commit comments

Comments
 (0)