Lists: | pgsql-hackers |
---|
From: | Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> |
---|---|
To: | PostgreSQL-development <pgsql-hackers(at)postgresql(dot)org> |
Subject: | ERROR: left and right pathkeys do not match in mergejoin |
Date: | 2018-02-21 21:04:45 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-hackers |
Hi hackers,
I found a bug related to the planning of merge joins. The steps to
reproduce are as follows:
```
CREATE TABLE J1_TBL (
i integer,
j integer,
t text
);
CREATE TABLE J2_TBL (
i integer,
k integer
);
set enable_hashjoin to off;
explain select * from j1_tbl full join (select * from j2_tbl order by
j2_tbl.i desc, j2_tbl.k) j2_tbl on j1_tbl.i = j2_tbl.i and j1_tbl.i =
j2_tbl.k;
ERROR: left and right pathkeys do not match in mergejoin
```
It can be reproduced on the latest 9.6, 10 and devel versions.
Basically, j2_tbl is used as the outer relation in merge join. We try to
use the existing order of j2_tbl, that is, 'i2 desc' and 'k asc'. As a
result, there is no order for i1 that would allow it to be merge-joined
to both i2 and k. The corresponding code path begins in
`generate_mergejoin_pathkeys()`, when it is first called by
`match_unsorted_outer()`. `find_mergeclauses_for_pathkeys()` selects
both mergeclauses for the given outer pathkeys, and then
`make_inner_pathkeys_for_merge()` generates inner pathkey for the first
mergeclause. Inner pathkey for the second mergeclause is skipped as
redundant. It looks suspicious already, because this new pathkey has
different direction and is more like conflicting than redundant.
Finally, `create_mergejoin_plan()` detects that the inner pathkey
doesn't match the second mergeclause and throws the error.
I found this while working on the inequality merge join patch. I don't
know yet how to fix this, so any help is welcome.
--
Alexander Kuzmenkov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> |
Cc: | PostgreSQL-development <pgsql-hackers(at)postgresql(dot)org> |
Subject: | Re: ERROR: left and right pathkeys do not match in mergejoin |
Date: | 2018-02-22 18:03:13 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-hackers |
Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> writes:
> explain select * from j1_tbl full join (select * from j2_tbl order by
> j2_tbl.i desc, j2_tbl.k) j2_tbl on j1_tbl.i = j2_tbl.i and j1_tbl.i =
> j2_tbl.k;
> ERROR: left and right pathkeys do not match in mergejoin
Nice example. There are several places that we could consider trying
to fix this:
The first possibility is to teach find_mergeclauses_for_pathkeys that
it should not select both of the join clauses in a case like this,
perhaps based on noting that the associated pathkeys have the same
eclass but different sort orders. However, that seems like a loser
for the reason specified in the comment in that function: we need to
select a maximal list of mergeclauses, not a minimal list, because
if it's a full join and we aren't able to include all the clauses as
mergeclauses then we won't have a valid plan. (At the time this code
was written, that could have resulted in failure to produce a plan
at all. Now we could fall back to a hash full join ... but that might
be inefficient, or we might not have hashable operators.)
The next possibility is to fix it in make_inner_pathkeys_for_merge,
by having it not suppress lower-order pathkeys unless they match earlier
ones in all details (not just eclass). In an example like this, that
means emitting a redundant inner pathkey list, equivalent to "ORDER BY
j1_tbl.i DESC, j1_tbl.i ASC". That's kind of annoying. It seems to
work in a simple test, but it implies doing useless comparisons during
the sort (since we'd only reach comparing the second sort column if
the first sort column compares equal, whereupon the second must too).
And it means representing the inner sort order by a noncanonical
pathkey list, which is not nice. For example, even if we have an inner
path available that delivers rows ordered by "j1_tbl.i DESC", we'd
still think we have to physically sort it to add the extra sort key.
(And no, I don't want to change pathkey comparison rules to avoid that.)
The third possibility is to decide that create_mergejoin_plan is being
overly paranoid and it's okay to extract merge details from a "redundant"
path key even though it specifies the opposite sort order from what the
current merge clause seems to need. This is scary at first glance, but
it seems like it should work. We'd essentially be lying to the executor
about the sort ordering of the lower-order merge column, and trusting that
it won't take any wrong actions as a result because it should never reach
comparison of that lower-order column except when the higher column(s)
are equal. I can't see a reason for that to go wrong; it's basically a
restatement of the argument why the lower-order sort key can be considered
redundant in the first place. But it doesn't leave a warm feeling in the
pit of the stomach, especially for a bug fix that needs to be back-patched
a long way.
On balance, though, this last choice seems like the thing to do. There
are clear downsides to the first two, in terms of failing to construct a
plan or constructing a needlessly inefficient plan.
regards, tom lane
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> |
Cc: | PostgreSQL-development <pgsql-hackers(at)postgresql(dot)org> |
Subject: | Re: ERROR: left and right pathkeys do not match in mergejoin |
Date: | 2018-02-22 19:52:04 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-hackers |
I wrote:
> The third possibility is to decide that create_mergejoin_plan is being
> overly paranoid and it's okay to extract merge details from a "redundant"
> path key even though it specifies the opposite sort order from what the
> current merge clause seems to need. This is scary at first glance, but
> it seems like it should work.
BTW, while working through this, I realized that there's an additional
problem in the same area, which can be demonstrated thus in the
regression database:
explain select * from
(select * from tenk1 a order by a.unique2) a
right join
(select * from tenk1 b order by b.thousand, b.twothousand, b.fivethous) b
on a.unique2 = b.thousand and a.hundred = b.twothousand and a.unique2 = b.fivethous;
ERROR: outer pathkeys do not match mergeclauses
The problem here is that find_mergeclauses_for_pathkeys has an API
designed on the assumption that the outer and inner pathkeys have
identical relationships to the mergeclauses, ie, if you want to find
the mergeclauses to use given a particular available sort ordering,
it works basically the same way for outer or inner pathkeys. But per
this discussion, tain't so. What really happens is that initially
we choose a list of mergeclauses that line up with the outer pathkeys,
and then we identify inner pathkeys that make sense given that list
of mergeclauses; but, in the presence of redundancy, those inner pathkeys
are not necessarily one-for-one with the mergeclauses. All fine so
far. But then, generate_mergejoin_paths looks at inner paths that have
available sort keys that are truncations of the original inner pathkey
list, and it uses find_mergeclauses_for_pathkeys to decide which
mergeclauses still make sense for that truncated pathkey list. That
doesn't work. In my example, we consider the pre-ordered sub-select
output for B as the outer side, and we choose all three mergeclauses
in the order the example has them, and we arrive at the initial inner
pathkey list of ({a.unique2}, {a.hundred}), dropping the redundant
second appearance of {a.unique2}. We can successfully make a plan
from that. But then we consider the truncated inner pathkey list
({a.unique2}), which this example is set up to ensure will win since
it avoids an extra sort step. As the code stands, the mergeclause list
that's extracted to use with that pair of input paths is
a.unique2 = b.thousand and a.unique2 = b.fivethous
(from the find_mergeclauses_for_pathkeys call with outer_keys = false).
That's just wrong, because it doesn't match the already-determined
outer path order, and create_mergejoin_plan is quite right to whine.
So it seems like find_mergeclauses_for_pathkeys should be renamed to
find_mergeclauses_for_outer_pathkeys, and then we need a second
function for the task of truncating the outer mergeclauses --- not
selecting them from scratch --- given a truncated inner pathkey list.
In this example, we could keep a.unique2 = b.thousand, but we'd have
to drop a.hundred = b.twothousand and then everything after it, since
the inner path doesn't have the sort order needed for that mergeclause.
regards, tom lane
From: | Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> |
---|---|
To: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
Cc: | PostgreSQL-development <pgsql-hackers(at)postgresql(dot)org> |
Subject: | Re: ERROR: left and right pathkeys do not match in mergejoin |
Date: | 2018-02-22 23:05:10 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-hackers |
El 22/02/18 a las 21:03, Tom Lane escribió:
> The third possibility is to decide that create_mergejoin_plan is being
> overly paranoid and it's okay to extract merge details from a "redundant"
> path key even though it specifies the opposite sort order from what the
> current merge clause seems to need.
This check looks necessary to me, because merge join can't work with
such a combination of outer pathkeys and merge clauses. The order of
outer and inner column must be the same. Here, two outer columns with
different orders are compared to the same inner column, so there will be
mismatch one way or another. Consider the original query with some
sample data:
outer inner
desc asc desc
i2 k2 i1
------------------
-> 1 0 1 <-
1 1 0
1 2
0
The merge join starts at tuples marked with arrows. It finds that the
outer tuple is less than the inner, so it advances the inner pointer,
and loses the tuple with i1 = 1.
So, if we can't do a merge join on these clauses with these pathkeys
anyway, it is OK to discard some of them in
find_mergeclauses_for_pathkey. This helps the case when we use the
existing order of outer relation. Also, we should take care not to
create such combinations in select_outer_pathkeys_for_merge, when it
tries to match root->query_pathkeys.
--
Alexander Kuzmenkov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> |
Cc: | PostgreSQL-development <pgsql-hackers(at)postgresql(dot)org> |
Subject: | Re: ERROR: left and right pathkeys do not match in mergejoin |
Date: | 2018-02-22 23:59:58 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-hackers |
Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> writes:
>> The third possibility is to decide that create_mergejoin_plan is being
>> overly paranoid and it's okay to extract merge details from a "redundant"
>> path key even though it specifies the opposite sort order from what the
>> current merge clause seems to need.
> This check looks necessary to me, because merge join can't work with
> such a combination of outer pathkeys and merge clauses.
No, I think it's okay, for exactly the same reason that the pathkey got
thrown away as redundant in the first place. That is, imagine that we
are mergejoining on "o.a = i.x AND o.b = i.x", and we know that the sort
ordering of the outer relation is "a ASC, b DESC". It would appear that
this means the inner relation needs to be ordered like "x ASC, x DESC",
and certainly if we were to play dumb and sort it that way, you'd expect
everything to work. The reason that we're having trouble is that the
pathkey machinery knows that "x ASC, x DESC" is stupid, and it throws
away the second column. It would not matter whether we considered the
sort ordering of the inner relation to be "x ASC, x DESC", or just
"x ASC", or indeed "x ASC, x ASC": all of those describe exactly the same
row ordering, because we only get to comparing the second sort column for
rows having equal values in the first sort column, and then our conclusion
must still be that the rows' values are equal.
This logic still goes through if the sort column contents are not simply
duplicate variables but distinct variables that have gotten put into the
same eclass, that is "SELECT ... WHERE x = y ORDER BY x ASC, y DESC".
Equal is equal. (We go to some pains to be sure this is true, ie that
the equality operator's semantics agree with the ordering operator's.)
So essentially, we can lie to the executor and say that we sorted the
inner rel as "x ASC, x DESC", even though we really did no such thing,
because there will be no difference in the actual input row order from
what it would be if we had done that.
Attached is a completed patch that fixes this and also deals with the
overall topic that the inner and outer pathkeys aren't so interchangeable
as some parts of the code thought. Maybe the comments could use further
improvement but I think it's OK otherwise. I haven't started on
back-porting this, but the bugs are demonstrable back to 8.3, so that
needs to be done.
regards, tom lane
Attachment | Content-Type | Size |
---|---|---|
fix-mergejoin-redundant-pathkey-issues.patch | text/x-diff | 27.5 KB |
From: | Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> |
---|---|
To: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
Cc: | PostgreSQL-development <pgsql-hackers(at)postgresql(dot)org> |
Subject: | Re: ERROR: left and right pathkeys do not match in mergejoin |
Date: | 2018-02-23 11:16:30 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-hackers |
Ah, I understand now. We can lie to the executor about the order,
because when we are moving based on the second outer column, we have a
stretch of equal values in the inner column, so we can consider them to
be sorted whatever way we need.
The patch applies cleanly, make check-world passes.
In create_mergejoin_plan:
* implied inner ordering is then "ORDER BY x, y, x", but the pathkey
* drops the second sort by x as redundant, and this code must cope.
-- should this read "the pathkey machinery drops"?
--
Alexander Kuzmenkov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> |
Cc: | PostgreSQL-development <pgsql-hackers(at)postgresql(dot)org> |
Subject: | Re: ERROR: left and right pathkeys do not match in mergejoin |
Date: | 2018-02-23 18:48:47 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-hackers |
Alexander Kuzmenkov <a(dot)kuzmenkov(at)postgrespro(dot)ru> writes:
> In create_mergejoin_plan:
> * implied inner ordering is then "ORDER BY x, y, x", but the pathkey
> * drops the second sort by x as redundant, and this code must cope.
> -- should this read "the pathkey machinery drops"?
I changed that and improved some other comments, and pushed it.
Thanks for reviewing!
regards, tom lane