Thread: left outer join and values()

left outer join and values()

From
Tom Allison
Date:
I did something like this with a single VALUES statment [eg:  VALUES
((2),(3))]
and thought I could extend this to two columns....
But I'm not having any luck.

BTW - history_idx is an integer and token_idx is a bigint.

select v.history.idx, v.token_idx
from (
values ((3,1),(3,2))) as v(history_idx, token_idx)
left outer join history_token ht on v.history_idx = ht.history_idx
and v.token_idx = ht.token_idx
where ht.history_idx is null;
ERROR:  operator does not exist: record = integer
LINE 4: left outer join history_token ht on v.history_idx = ht.histo...
                                                           ^
HINT:  No operator matches the given name and argument type(s). You
may need to add explicit type casts.

NOTE: the '^' is pointing to the '=' on Line 4

Re: left outer join and values()

From
Tom Lane
Date:
Tom Allison <tom@tacocat.net> writes:
> select v.history.idx, v.token_idx
> from (
> values ((3,1),(3,2))) as v(history_idx, token_idx)
> left outer join history_token ht on v.history_idx = ht.history_idx
> and v.token_idx = ht.token_idx
> where ht.history_idx is null;
> ERROR:  operator does not exist: record = integer
> LINE 4: left outer join history_token ht on v.history_idx = ht.histo...
>                                                            ^

You've got too many parentheses --- the system thinks that "values"
specification is a single row containing two fields that are each
two-column records.  I think you want

select v.history_idx, v.token_idx
from (
values (3,1),(3,2)) as v(history_idx, token_idx)
left outer join history_token ht on v.history_idx = ht.history_idx
and v.token_idx = ht.token_idx
where ht.history_idx is null;

Note the "history.idx" typo as well.

            regards, tom lane

Re: left outer join and values()

From
Tom Allison
Date:
Thank you for the response.
I did figure this out a few minutes after I sent this post.
Apologies for jumping the gun.

I must say, I am absolutely impressed with what pgsql's
implimentation of VALUES allows me to do.
It's kind of ridiculous how much "work" goes away in my code.
Too bad I can't do this at work (Oracle 8/9).

On May 31, 2007, at 11:48 PM, Tom Lane wrote:

>
> Tom Allison <tom@tacocat.net> writes:
>> select v.history.idx, v.token_idx
>> from (
>> values ((3,1),(3,2))) as v(history_idx, token_idx)
>> left outer join history_token ht on v.history_idx = ht.history_idx
>> and v.token_idx = ht.token_idx
>> where ht.history_idx is null;
>> ERROR:  operator does not exist: record = integer
>> LINE 4: left outer join history_token ht on v.history_idx =
>> ht.histo...
>>                                                            ^
>
> You've got too many parentheses --- the system thinks that "values"
> specification is a single row containing two fields that are each
> two-column records.  I think you want
>
> select v.history_idx, v.token_idx
> from (
> values (3,1),(3,2)) as v(history_idx, token_idx)
> left outer join history_token ht on v.history_idx = ht.history_idx
> and v.token_idx = ht.token_idx
> where ht.history_idx is null;
>
> Note the "history.idx" typo as well.
>
>             regards, tom lane
>
> ---------------------------(end of
> broadcast)---------------------------
> TIP 2: Don't 'kill -9' the postmaster