Skip to content

Commit 2bf2ecf

Browse files
pyhalovdanolivo
authored andcommitted
[SHRDM-762] add tests for partitioned tables with foreign partitions
1 parent fd5a274 commit 2bf2ecf

File tree

2 files changed

+128
-1
lines changed

2 files changed

+128
-1
lines changed

expected/aqo_fdw.out

Lines changed: 85 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -160,6 +160,91 @@ WHERE a.aid = b.aid AND b.bval like 'val%';
160160
JOINS: 0
161161
(6 rows)
162162

163+
-- Partitioned join over foreign tables
164+
set enable_partitionwise_join = on;
165+
ALTER SERVER loopback OPTIONS (ADD fdw_tuple_cost '1.0');
166+
CREATE TABLE local_main_p0(aid int, aval text);
167+
CREATE TABLE local_main_p1(aid int, aval text);
168+
CREATE TABLE main (aid int, aval text) PARTITION BY HASH(aid);
169+
CREATE FOREIGN TABLE main_p0 PARTITION OF main FOR VALUES WITH (MODULUS 3, REMAINDER 0)
170+
SERVER loopback OPTIONS (table_name 'local_main_p0');
171+
CREATE FOREIGN TABLE main_p1 PARTITION OF main FOR VALUES WITH (MODULUS 3, REMAINDER 1)
172+
SERVER loopback OPTIONS (table_name 'local_main_p1');
173+
CREATE TABLE main_p2 PARTITION OF main FOR VALUES WITH (MODULUS 3, REMAINDER 2);
174+
CREATE TABLE local_ref_p0(bid int, aid int, bval text);
175+
CREATE TABLE local_ref_p1(bid int, aid int, bval text);
176+
CREATE TABLE ref (bid int, aid int, bval text) PARTITION BY HASH(aid);
177+
CREATE FOREIGN TABLE ref_p0 PARTITION OF ref FOR VALUES WITH (MODULUS 3, REMAINDER 0)
178+
SERVER loopback OPTIONS (table_name 'local_ref_p0');
179+
CREATE FOREIGN TABLE ref_p1 PARTITION OF ref FOR VALUES WITH (MODULUS 3, REMAINDER 1)
180+
SERVER loopback OPTIONS (table_name 'local_ref_p1');
181+
CREATE TABLE ref_p2 PARTITION OF ref FOR VALUES WITH (MODULUS 3, REMAINDER 2);
182+
INSERT INTO main SELECT i, 'val_' || i FROM generate_series(1,100) i;
183+
INSERT INTO ref SELECT i, mod(i, 10) + 1, 'val_' || i FROM generate_series(1,1000) i;
184+
ANALYZE local_main_p0, local_main_p1, main_p2;
185+
ANALYZE local_ref_p0, local_ref_p1, ref_p2;
186+
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
187+
SELECT * from main AS a, ref AS b
188+
WHERE a.aid = b.aid AND b.bval like 'val%';
189+
QUERY PLAN
190+
--------------------------------------------------------------------
191+
Append (actual rows=1000 loops=1)
192+
AQO not used
193+
-> Foreign Scan (actual rows=400 loops=1)
194+
AQO not used
195+
Relations: (main_p0 a_1) INNER JOIN (ref_p0 b_1)
196+
-> Foreign Scan (actual rows=300 loops=1)
197+
AQO not used
198+
Relations: (main_p1 a_2) INNER JOIN (ref_p1 b_2)
199+
-> Hash Join (actual rows=300 loops=1)
200+
AQO not used
201+
Hash Cond: (b_3.aid = a_3.aid)
202+
-> Seq Scan on ref_p2 b_3 (actual rows=300 loops=1)
203+
AQO not used
204+
Filter: (bval ~~ 'val%'::text)
205+
-> Hash (actual rows=38 loops=1)
206+
AQO not used
207+
Buckets: 1024 Batches: 1 Memory Usage: 10kB
208+
-> Seq Scan on main_p2 a_3 (actual rows=38 loops=1)
209+
AQO not used
210+
Using aqo: true
211+
AQO mode: LEARN
212+
JOINS: 1
213+
(22 rows)
214+
215+
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
216+
SELECT * from main AS a, ref AS b
217+
WHERE a.aid = b.aid AND b.bval like 'val%';
218+
QUERY PLAN
219+
--------------------------------------------------------------------
220+
Append (actual rows=1000 loops=1)
221+
AQO not used
222+
-> Foreign Scan (actual rows=400 loops=1)
223+
AQO: rows=400, error=0%
224+
Relations: (main_p0 a_1) INNER JOIN (ref_p0 b_1)
225+
-> Foreign Scan (actual rows=300 loops=1)
226+
AQO: rows=300, error=0%
227+
Relations: (main_p1 a_2) INNER JOIN (ref_p1 b_2)
228+
-> Hash Join (actual rows=300 loops=1)
229+
AQO: rows=300, error=0%
230+
Hash Cond: (b_3.aid = a_3.aid)
231+
-> Seq Scan on ref_p2 b_3 (actual rows=300 loops=1)
232+
AQO: rows=300, error=0%
233+
Filter: (bval ~~ 'val%'::text)
234+
-> Hash (actual rows=38 loops=1)
235+
AQO not used
236+
Buckets: 1024 Batches: 1 Memory Usage: 10kB
237+
-> Seq Scan on main_p2 a_3 (actual rows=38 loops=1)
238+
AQO: rows=38, error=0%
239+
Using aqo: true
240+
AQO mode: LEARN
241+
JOINS: 1
242+
(22 rows)
243+
244+
DROP TABLE main, local_main_p0, local_main_p1;
245+
DROP TABLE ref, local_ref_p0, local_ref_p1;
246+
ALTER SERVER loopback OPTIONS (DROP fdw_tuple_cost);
247+
reset enable_partitionwise_join;
163248
-- TODO: Non-mergejoinable join condition.
164249
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
165250
SELECT * FROM frgn AS a, frgn AS b WHERE a.x<b.x;

sql/aqo_fdw.sql

Lines changed: 43 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -85,6 +85,49 @@ EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
8585
SELECT * from frgn_a AS a, frgn_b AS b
8686
WHERE a.aid = b.aid AND b.bval like 'val%';
8787

88+
-- Partitioned join over foreign tables
89+
set enable_partitionwise_join = on;
90+
ALTER SERVER loopback OPTIONS (ADD fdw_tuple_cost '1.0');
91+
92+
CREATE TABLE local_main_p0(aid int, aval text);
93+
CREATE TABLE local_main_p1(aid int, aval text);
94+
CREATE TABLE main (aid int, aval text) PARTITION BY HASH(aid);
95+
96+
CREATE FOREIGN TABLE main_p0 PARTITION OF main FOR VALUES WITH (MODULUS 3, REMAINDER 0)
97+
SERVER loopback OPTIONS (table_name 'local_main_p0');
98+
CREATE FOREIGN TABLE main_p1 PARTITION OF main FOR VALUES WITH (MODULUS 3, REMAINDER 1)
99+
SERVER loopback OPTIONS (table_name 'local_main_p1');
100+
CREATE TABLE main_p2 PARTITION OF main FOR VALUES WITH (MODULUS 3, REMAINDER 2);
101+
102+
CREATE TABLE local_ref_p0(bid int, aid int, bval text);
103+
CREATE TABLE local_ref_p1(bid int, aid int, bval text);
104+
CREATE TABLE ref (bid int, aid int, bval text) PARTITION BY HASH(aid);
105+
106+
CREATE FOREIGN TABLE ref_p0 PARTITION OF ref FOR VALUES WITH (MODULUS 3, REMAINDER 0)
107+
SERVER loopback OPTIONS (table_name 'local_ref_p0');
108+
CREATE FOREIGN TABLE ref_p1 PARTITION OF ref FOR VALUES WITH (MODULUS 3, REMAINDER 1)
109+
SERVER loopback OPTIONS (table_name 'local_ref_p1');
110+
CREATE TABLE ref_p2 PARTITION OF ref FOR VALUES WITH (MODULUS 3, REMAINDER 2);
111+
112+
INSERT INTO main SELECT i, 'val_' || i FROM generate_series(1,100) i;
113+
INSERT INTO ref SELECT i, mod(i, 10) + 1, 'val_' || i FROM generate_series(1,1000) i;
114+
115+
ANALYZE local_main_p0, local_main_p1, main_p2;
116+
ANALYZE local_ref_p0, local_ref_p1, ref_p2;
117+
118+
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
119+
SELECT * from main AS a, ref AS b
120+
WHERE a.aid = b.aid AND b.bval like 'val%';
121+
122+
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
123+
SELECT * from main AS a, ref AS b
124+
WHERE a.aid = b.aid AND b.bval like 'val%';
125+
126+
DROP TABLE main, local_main_p0, local_main_p1;
127+
DROP TABLE ref, local_ref_p0, local_ref_p1;
128+
ALTER SERVER loopback OPTIONS (DROP fdw_tuple_cost);
129+
reset enable_partitionwise_join;
130+
88131
-- TODO: Non-mergejoinable join condition.
89132
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
90133
SELECT * FROM frgn AS a, frgn AS b WHERE a.x<b.x;
@@ -98,4 +141,3 @@ DROP EXTENSION postgres_fdw CASCADE;
98141
DROP TABLE local;
99142
DROP TABLE local_b;
100143
DROP TABLE local_a;
101-

0 commit comments

Comments
 (0)