Joe,
I believe this is actually in the memo to users for 6.1, and has caused some confusion for me as well.
As I understand it, the fields within the using clause are no longer associated with any correlated table. In order to get the desired results with the USING your SQL has to look like this:
with t1 as (select key1, data1 from myfile)
select key1, t1.* from t1 join myfile using (key1)
It is actually very useful when trying to join multiple table with USING. Prior to 6.1 I would always have to use the ON criteria because the second JOIN would have ambiguous fields.
Hope this helps.
-Tom Stieger
California Fine Wire
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Joe Pluta
Sent: Monday, March 14, 2011 8:28 AM
To: midrange-l@xxxxxxxxxxxx
Subject: Ugly problem with USING vs ON in JOIN
Here's a real beauty. Try this with any file:
with t1 as (select key1, data1 from myfile)
select t1.* from t1 join myfile using (key1)
Then try this:
with t1 as (select key1, data1 from myfile)
select t1.* from t1 join myfile on t1.key1 = myfile.key1
myfile is any file with a single unique key field. key1 is that key field. data1 is any other field in the file. Actually, it doesn't HAVE to be that way; you can use any two fields. But if you don't use a unique field you may end up with a REALLY big result set.
The first select will return only data1 in the result set, while the second will return both key1 and data1. I'm one behind on DB2 group PTFs, but this is a pretty big one and it just bit me badly.
Please note that this is a completely stripped down query and I realize that it effectively does "select key1, data1 from myfile". The actual query is much more involved. But this reproduces the problem in the fewest steps.
Now I have to start looking for USING in all my queries.
Joe
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe, or change list options,
visit:
http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a moment to review the archives at
http://archive.midrange.com/midrange-l.
As an Amazon Associate we earn from qualifying purchases.