Re: What does "merge-joinable join conditions" mean ????

Lists: pgsql-sql
From: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>
To: pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: What does "merge-joinable join conditions" mean ????
Date: 2006-01-15 20:25:10
Message-ID: 43CAAFA6.6050001@ultimeth.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

I have a FULL JOIN between two simple tables, and am getting the message
" Query failed: ERROR: FULL JOIN is only supported with merge-joinable
join conditions"

I'd be glad to fix this in my query if I knew what the #(at)!! it meant.
Using 8.0.4 on FC1; willing to upgrade (PostgreSQL, not FC1) IF it
would fix the problem.

-- Dean


From: Michael Fuhr <mike(at)fuhr(dot)org>
To: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>
Cc: pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: What does "merge-joinable join conditions" mean ????
Date: 2006-01-15 21:54:48
Message-ID: 20060115215448.GA30809@winnie.fuhr.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

On Sun, Jan 15, 2006 at 12:25:10PM -0800, Dean Gibson (DB Administrator) wrote:
> I have a FULL JOIN between two simple tables, and am getting the message
> " Query failed: ERROR: FULL JOIN is only supported with merge-joinable
> join conditions"
>
> I'd be glad to fix this in my query if I knew what the #(at)!! it meant.

What's the query?

> Using 8.0.4 on FC1; willing to upgrade (PostgreSQL, not FC1) IF it
> would fix the problem.

The 8.0.5 Release Notes have the following item, but without seeing
your query it's hard to know whether this fix is relevant to your
problem (the fix mentions RIGHT JOIN; your error says FULL JOIN):

* Fix longstanding planning error for outer joins

This bug sometimes caused a bogus error "RIGHT JOIN is only
supported with merge-joinable join conditions".

Consider upgrading in any case. 8.0.6 is the latest in the 8.0
branch; see the Release Notes for a summary of fixes since 8.0.4:

http://www.postgresql.org/docs/8.0/interactive/release.html#RELEASE-8-0-6
http://www.postgresql.org/docs/8.0/interactive/release-8-0-5.html

--
Michael Fuhr


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>
Cc: pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: What does "merge-joinable join conditions" mean ????
Date: 2006-01-15 21:58:28
Message-ID: 17050.1137362308@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

"Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com> writes:
> I have a FULL JOIN between two simple tables, and am getting the message
> " Query failed: ERROR: FULL JOIN is only supported with merge-joinable
> join conditions"

> I'd be glad to fix this in my query if I knew what the #(at)!! it meant.

The join condition(s) of a FULL JOIN have to be mergejoinable, which
basically means an equality relation between sortable (btree-indexable)
data types. You can see exactly which operators are mergejoinable with
a query like

select oid::regoperator from pg_operator where oprlsortop != 0;

regards, tom lane


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Michael Fuhr <mike(at)fuhr(dot)org>
Cc: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>, pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: What does "merge-joinable join conditions" mean ????
Date: 2006-01-15 22:19:56
Message-ID: 17223.1137363596@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Michael Fuhr <mike(at)fuhr(dot)org> writes:
> The 8.0.5 Release Notes have the following item, but without seeing
> your query it's hard to know whether this fix is relevant to your
> problem (the fix mentions RIGHT JOIN; your error says FULL JOIN):

Good catch, but that bug was specific to left/right joins (basically,
the code failed to force the join to be flipped around when needed).
With a FULL JOIN you're stuck ... flipping it doesn't help.

The reason it's an issue is that for a FULL JOIN, the executor has to
keep track of whether rows on *both* sides of the join have been matched
to any rows of the other side. If there are join conditions that are
outside the mergejoin list then this requires an indefinitely large
amount of state.

It'd be possible to teach hash join to implement FULL JOIN (basically,
you'd have to add an I've-been-joined flag to each entry in the hash
table, and then re-scan the hash table at the end of the join to see
which inner-side rows remain unjoined). With this you'd only need one
hashable join condition to make it work, whereas the FULL JOIN mergejoin
code requires *all* the join conditions to be mergejoinable. The issue
hasn't come up often enough to make it seem like a high-priority
problem, however. I can only recall one or two people complaining about
it in all the time we've had outer-join support.

regards, tom lane


From: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>
To: pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: What does "merge-joinable join conditions" mean ????
Date: 2006-01-15 22:28:08
Message-ID: 43CACC78.7090107@ultimeth.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

On 2006-01-15 13:54, Michael Fuhr wrote:
> What's the query?
>

SELECT count(*) FROM "GenAppExtra" FULL JOIN "GeoRestrict" ON callsign
~ pattern WHERE region_id = 4 OR geo_region = 4;

If either of the "region_id = 4" (a field in the right-hand table) or
"geo_region = 4" (a field in the left-hand table) are removed, the
SELECT functions (does not give an error message), as does the case
where the "callsign ~ pattern" (one field is from each table) is
replaced by "callsign = pattern".

What's frustrating is that both tables are small, and "GeoRestrict" is
only about 15 rows.

At this point, I'm considering a UNION; alternate suggestions welcome!

-- Dean


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>
Cc: pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: What does "merge-joinable join conditions" mean ????
Date: 2006-01-15 23:21:53
Message-ID: 24299.1137367313@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

"Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com> writes:
> SELECT count(*) FROM "GenAppExtra" FULL JOIN "GeoRestrict" ON callsign
> ~ pattern WHERE region_id = 4 OR geo_region = 4;

> If either of the "region_id = 4" (a field in the right-hand table) or
> "geo_region = 4" (a field in the left-hand table) are removed, the
> SELECT functions (does not give an error message),

Really? The FULL JOIN condition using ~ is the source of the failure,
and I'd be quite surprised if changing WHERE makes it work.

regards, tom lane


From: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>
To: pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: What does "merge-joinable join conditions" mean ????
Date: 2006-01-15 23:31:40
Message-ID: 43CADB5C.3020302@ultimeth.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

On 2006-01-15 15:21, Tom Lane wrote:
> Really? The FULL JOIN condition using ~ is the source of the failure, and I'd be quite surprised if changing WHERE makes it work.
>

Works fine:

EXPLAIN SELECT count(*) FROM "Extra" FULL JOIN "GeoRestrict" ON
callsign ~ pattern WHERE geo_region =
4;
QUERY
PLAN
---------------------------------------------------------------------------------
Aggregate (cost=1934.02..1934.02 rows=1 width=0)
-> Nested Loop Left Join (cost=1.18..1926.66 rows=2943 width=0)
Join Filter: ("outer".callsign ~ ("inner".pattern)::text)
-> Seq Scan on "Extra" (cost=0.00..866.00 rows=2943 width=10)
Filter: (geo_region = 4)
-> Materialize (cost=1.18..1.34 rows=16 width=7)
-> Seq Scan on "GeoRestrict" (cost=0.00..1.16 rows=16
width=7)

Note that this used to be just a LEFT JOIN (which also worked), but
today I wanted to include rows from "GeoRestrict" that had nulls for the
left-hand-side of the query, so I changed the LEFT JOIN to a FULL JOIN
(that worked), and then attempted to add a condition to restrict which
rows were included from "GeoRestrict", and that gave the error.

-- Dean


From: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>
To: pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: What does "merge-joinable join conditions" mean ????
Date: 2006-01-15 23:47:56
Message-ID: 43CADF2C.7010100@ultimeth.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

On 2006-01-15 15:42, Tom Lane wrote:
>
>> EXPLAIN SELECT count(*) FROM "Extra" FULL JOIN "GeoRestrict" ON
>> callsign ~ pattern WHERE geo_region =
>> 4;
>>
>
> Oh, but that reduces it to a left join, as you can see in the EXPLAIN
> output ---
Yes, I previously noticed that in the EXPLAIN output too.

> any null-extension rows from the right side are going to fail
> the WHERE condition anyway, so the planner simplifies the FULL JOIN to a
> LEFT JOIN. If you'd eliminate the WHERE altogether then the failure
> will come back.
>
>
Tried that, and you are right there as well.

So, given the fact that the right-hand-table is only about 15 rows, do
you think changing the SELECT back to a LEFT JOIN, and then using a
UNION to get the extra right-hand-rows in, is the best work-around?

-- Dean


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: "Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com>
Cc: pgsql-sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: What does "merge-joinable join conditions" mean ????
Date: 2006-01-16 00:10:18
Message-ID: 24607.1137370218@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

"Dean Gibson (DB Administrator)" <postgresql4(at)ultimeth(dot)com> writes:
> So, given the fact that the right-hand-table is only about 15 rows, do
> you think changing the SELECT back to a LEFT JOIN, and then using a
> UNION to get the extra right-hand-rows in, is the best work-around?

Yeah, a UNION of left and right joins seems the only very reasonable
solution. As long as you're sure there are no duplicate rows you
need to keep, it'll work well enough.

regards, tom lane