1
0
mirror of https://github.com/postgres/postgres.git synced 2025-06-11 20:28:21 +03:00

postgres_fdw: Consider requesting sorted data so we can do a merge join.

When use_remote_estimate is enabled, consider adding ORDER BY to the
query we sending to the remote server so that we can use that ordered
data for a merge join.  Commit f18c944b61
arranges to push down the query pathkeys, which seems like the case
mostly likely to be a win, but testing shows this can sometimes win,
too.

For a regular table, we know which indexes are present and therefore
test whether the ordering provided by each such index is useful.  Here,
we take the opposite approach: guess what orderings would be useful if
they could be generated cheaply, and then ask the remote side what those
will cost.

Ashutosh Bapat, with very substantial cosmetic revisions by me.  Also
reviewed by Rushabh Lathia.
This commit is contained in:
Robert Haas
2015-12-22 13:46:40 -05:00
parent f5a4370aea
commit ccd8f97922
5 changed files with 410 additions and 41 deletions

View File

@ -343,6 +343,76 @@ SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
fixed |
(1 row)
-- Test forcing the remote server to produce sorted data for a merge join.
SET enable_hashjoin TO false;
SET enable_nestloop TO false;
-- inner join; expressions in the clauses appear in the equivalence class list
EXPLAIN (VERBOSE, COSTS false)
SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
QUERY PLAN
----------------------------------------------------------------------------
Limit
Output: t1.c1, t2."C 1"
-> Merge Join
Output: t1.c1, t2."C 1"
Merge Cond: (t1.c1 = t2."C 1")
-> Foreign Scan on public.ft2 t1
Output: t1.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC
-> Index Only Scan using t1_pkey on "S 1"."T 1" t2
Output: t2."C 1"
(10 rows)
SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
c1 | C 1
-----+-----
101 | 101
102 | 102
103 | 103
104 | 104
105 | 105
106 | 106
107 | 107
108 | 108
109 | 109
110 | 110
(10 rows)
-- outer join; expressions in the clauses do not appear in equivalence class
-- list but no output change as compared to the previous query
EXPLAIN (VERBOSE, COSTS false)
SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
QUERY PLAN
----------------------------------------------------------------------------
Limit
Output: t1.c1, t2."C 1"
-> Merge Left Join
Output: t1.c1, t2."C 1"
Merge Cond: (t1.c1 = t2."C 1")
-> Foreign Scan on public.ft2 t1
Output: t1.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC
-> Index Only Scan using t1_pkey on "S 1"."T 1" t2
Output: t2."C 1"
(10 rows)
SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
c1 | C 1
-----+-----
101 | 101
102 | 102
103 | 103
104 | 104
105 | 105
106 | 106
107 | 107
108 | 108
109 | 109
110 | 110
(10 rows)
RESET enable_hashjoin;
RESET enable_nestloop;
-- ===================================================================
-- WHERE with remotely-executable conditions
-- ===================================================================
@ -3538,6 +3608,101 @@ select tableoid::regclass, * from bar order by 1,2;
bar2 | 7 | 177
(6 rows)
-- Test forcing the remote server to produce sorted data for a merge join,
-- but the foreign table is an inheritance child.
truncate table loct1;
truncate table only foo;
\set num_rows_foo 2000
insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
SET enable_hashjoin to false;
SET enable_nestloop to false;
alter foreign table foo2 options (use_remote_estimate 'true');
create index i_loct1_f1 on loct1(f1);
create index i_foo_f1 on foo(f1);
analyze foo;
analyze loct1;
-- inner join; expressions in the clauses appear in the equivalence class list
explain (verbose, costs off)
select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
QUERY PLAN
---------------------------------------------------------------------------------------
Limit
Output: foo.f1, loct1.f1, foo.f2
-> Sort
Output: foo.f1, loct1.f1, foo.f2
Sort Key: foo.f2
-> Merge Join
Output: foo.f1, loct1.f1, foo.f2
Merge Cond: (foo.f1 = loct1.f1)
-> Merge Append
Sort Key: foo.f1
-> Index Scan using i_foo_f1 on public.foo
Output: foo.f1, foo.f2
-> Foreign Scan on public.foo2
Output: foo2.f1, foo2.f2
Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC
-> Index Only Scan using i_loct1_f1 on public.loct1
Output: loct1.f1
(17 rows)
select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
f1 | f1
----+----
20 | 20
22 | 22
24 | 24
26 | 26
28 | 28
30 | 30
32 | 32
34 | 34
36 | 36
38 | 38
(10 rows)
-- outer join; expressions in the clauses do not appear in equivalence class
-- list but no output change as compared to the previous query
explain (verbose, costs off)
select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
QUERY PLAN
---------------------------------------------------------------------------------------
Limit
Output: foo.f1, loct1.f1, foo.f2
-> Sort
Output: foo.f1, loct1.f1, foo.f2
Sort Key: foo.f2
-> Merge Left Join
Output: foo.f1, loct1.f1, foo.f2
Merge Cond: (foo.f1 = loct1.f1)
-> Merge Append
Sort Key: foo.f1
-> Index Scan using i_foo_f1 on public.foo
Output: foo.f1, foo.f2
-> Foreign Scan on public.foo2
Output: foo2.f1, foo2.f2
Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC
-> Index Only Scan using i_loct1_f1 on public.loct1
Output: loct1.f1
(17 rows)
select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
f1 | f1
----+----
10 | 10
11 |
12 | 12
13 |
14 | 14
15 |
16 | 16
17 |
18 | 18
19 |
(10 rows)
RESET enable_hashjoin;
RESET enable_nestloop;
-- Test that WHERE CURRENT OF is not supported
begin;
declare c cursor for select * from bar where f1 = 7;