Обсуждение: FULL JOIN and mergjoinable conditions...

Поиск
Список
Период
Сортировка

FULL JOIN and mergjoinable conditions...

От
Martijn van Oosterhout
Дата:
Today I got the error:

ERROR:  FULL JOIN is only supported with mergejoinable join conditions

Which is really annoying since a full join is exactly what I wanted. I
guess the alternative is to do a left join and a right join and merge
them? Is it just that no-one has come up with a way to code this
efficiently?

Maybe someone has a better way to express this. The problem is I have
two tables with ranges and I wanted to generate a result with the
overlaps and blanks where there are things missed. For example:

Table A                             Table B
Tag   Start    End                  Tag   Start    End
A       1       2                    A     2        7
B       6       9                    B     9        9
C      10      12                    C    13       15

So the query looks like:

SELECT * from A full outer join B on (a.end >= b.start and b.end >= a.start)

The result would be something like:

A       1      2      A      2      7
B       6      9      A      2      7
B       6      9      B      9      9
C      10     12      \N     \N    \N
\N     \N     \N      C      13    15

Any ideas?
--
Martijn van Oosterhout   <kleptog@svana.org>   http://svana.org/kleptog/
> Patent. n. Genius is 5% inspiration and 95% perspiration. A patent is a
> tool for doing 5% of the work and then sitting around waiting for someone
> else to do the other 95% so you can sue them.

Вложения

Re: FULL JOIN and mergjoinable conditions...

От
Tom Lane
Дата:
Martijn van Oosterhout <kleptog@svana.org> writes:
> Today I got the error:
> ERROR:  FULL JOIN is only supported with mergejoinable join conditions
> Which is really annoying since a full join is exactly what I wanted. I
> guess the alternative is to do a left join and a right join and merge
> them? Is it just that no-one has come up with a way to code this
> efficiently?

How would you do it?  It seems fairly impractical with an underlying
nestloop join --- you'd need persistent state for *every* row of the
inner relation to show whether any outer row had matched it.

You could imagine doing it with a hash join (mark every hash table entry
when it gets visited by an outer-row hash probe, then traverse the hash
table at the end to emit unvisited rows).  But a quick look into
pg_operator convinces me that this would be pointless to implement,
because we have no interesting datatypes that support hash join but not
mergejoin.  And hashjoins are only practical with relatively-small inner
relations anyway.  Not to mention that hashjoin isn't any more amenable
to inequality join conditions than mergejoin is...

            regards, tom lane