SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Outer Join Mystery


Outer Join Mystery

Author
Message
David in .AU
David in .AU
SSChasing Mays
SSChasing Mays (600 reputation)SSChasing Mays (600 reputation)SSChasing Mays (600 reputation)SSChasing Mays (600 reputation)SSChasing Mays (600 reputation)SSChasing Mays (600 reputation)SSChasing Mays (600 reputation)SSChasing Mays (600 reputation)

Group: General Forum Members
Points: 600 Visits: 561

True and correct. I just put in the example code for the old style. I had actually noticed the execution plans were pretty much identical.

How people can still write in that scares me


Grant Fritchey
Grant Fritchey
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39725 Visits: 32639

A lot of it, unfortunately not all of it, comes from Oracle people. But even Oracle is starting down the path of eliminating the old style syntax. If you go out & search on the Oracle blogs & newsgroups, it's a big deal that lots of them are very unhappy about.



----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
amit gurjar
amit gurjar
Grasshopper
Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)

Group: General Forum Members
Points: 23 Visits: 1

Hi,

This article & discussion is very interesting and it helped me a lot in understanding the Outer Join Query plus the old vs. new syntax.

Thanks once again

Regards

Amit Gurjar


Mark_Horton
Mark_Horton
SSC Rookie
SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)

Group: General Forum Members
Points: 30 Visits: 29

To get the Execution plans to match between the old and new syntax, the "old style" join query needs to look something like this:

SELECT
S.IIATransactionId
,substring(rats_filename,1+patindex('%{________-____-____-____-____________}%',rats_filename),36) AS OracleTransactionId
FROM iiafeedtransaction S,
ratsiiafeedtransaction o
WHERE S.IIATransactionId *= substring(rats_filename,1+patindex('%{________-____-____-____-____________}%',rats_filename),36)
GROUP BY
S.IIATransactionId,substring(rats_filename,1+patindex('%{________-____-____-____-____________}%',rats_filename),36)
HAVING substring(rats_filename,1+patindex('%{________-____-____-____-____________}%',rats_filename),36) IS NULL
ORDER BY S.IIATransactionId

Using the GROUP BY and the HAVING clauses puts the filter back into the execution plan and the correct results are seen.

Far easier to just use the new style of joins

Regards,

Mark Horton.


R Tierney
R Tierney
SSC Rookie
SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)

Group: General Forum Members
Points: 42 Visits: 2

Because you dont have control over the order of WHERE clause execution, the WHERE condition can occur before the JOIN condition, meaning that the WHERE occurs on the *Cartesian Product* of the two tables, and therefore doesnt filter rows properly.

If you think about this closely enough, it makes sense.


Scott Strickland
Scott Strickland
Forum Newbie
Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)

Group: General Forum Members
Points: 7 Visits: 1
So, how does Oracle return the "right" results?
Scott Coleman
Scott Coleman
Hall of Fame
Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)

Group: General Forum Members
Points: 3794 Visits: 1464

The use of the old-style syntax promoted the entire WHERE clause to the ON clause. You get the same results as the "wrong" query if you used "LEFT JOIN ... ON S. = O. AND o.rats_filename IS NOT NULL". The IS NOT NULL condition is being used as a a join condition instead of a filter condition and, since none of the fields are null, has no effect.

The only mystery to me is how Oracle differentiates join conditions and filter conditions. Maybe only logical comparisons involving both tables are considered join conditions?





Grant Fritchey
Grant Fritchey
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39725 Visits: 32639

It simply returns the anticipated results, which is only those rows that don't match. Precisely how... you need to ask someone that understands Oracle. I think Scott Coleman's answers have been more precise than anything I'm going to offer up.



----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
Grant Fritchey
Grant Fritchey
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39725 Visits: 32639
Thanks. That makes more sense than any other explanation I've been able to come up with.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
Jeff B.
Jeff B.
Valued Member
Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)

Group: General Forum Members
Points: 59 Visits: 223

Itzik Ben-Gan wrote an article that explains this very clearly in SQL Magazine in the October 2004 issue. The InstantDoc ID is #43681.

The problem is that in Old Style Joins, you can't separate the join clause and the Where Clause so the result may include extraneous NULL values in your result set.

Here are two simple queries you can run in PUBS to see this:

-- Old Style Join
-- 13 Valid Entries, 6 Invalid Entries
select o.name, i.name,i.indid
from sysobjects o, sysindexes i
where o.id *= i.id and
o.type = 'S' and
i.indid = 1

-- New Style Join
-- 13 Valid Entries, 0 Invalid Entries
select o.name, i.name,i.indid
from sysobjects o
left outer join sysindexes i
on o.id = i.id
where o.type = 'S' and
i.indid = 1


Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search