Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 123»»»

LEFT JOIN without predicate , still works but what is that?<!-- 864 --><!-- 864 --> Expand / Collapse
Author
Message
Posted Thursday, August 21, 2014 10:41 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 11:24 AM
Points: 181, Visits: 440
Hi,
Dealing with some sp code where I have left join without predicate and it still works !!!!! Comments says : Optimization (?).
I surely thing it should not be the case, but maybe I'm wrong ?? Appreciate you comments, is it possible, sane?

Select C1, C2, C3
FROM TableA p
LEFT JOIN main.TableC c c.CustID = p.CustID
LEFT JOIN ( supr.Stats gs -- <@>>< nothing here but check next line
INNER JOIN supr.Abbr ab on ab.LogID = gs.LogID )
on gs.LogID = p.LogID.

LEFT JOIN dbo.TableLog l l.LogID = c.LogID


Best
Mario
Post #1605922
Posted Thursday, August 21, 2014 12:06 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Yesterday @ 6:24 AM
Points: 418, Visits: 2,451
I was unable to left join without a predicate, even if the predicate was a dummy (1=1).

What version of SQL are you using?
Post #1605953
Posted Thursday, August 21, 2014 12:15 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 11:24 AM
Points: 181, Visits: 440
Microsoft SQL Server 2012 - 11.0.5058.0 (X64)
Developer Edition (64-bit) on Windows NT 6.1 <X64> (Build 7601: Service Pack 1)

I heard something about default predicates by same column name, but in my case same columns names exists in multiple table which take part in this query, also you can see that gs predicated is on next line, so from a side it looks like "sub JOIN". I just want to break the code...
This piece came also from very reputable person, and after his tuning the whole piece running faster...

I'll try to compose test code with AdventrureWorks and see how it works.

Thanks
M
Post #1605956
Posted Thursday, August 21, 2014 1:02 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 12:10 PM
Points: 11,322, Visits: 13,115
I can't get the code to parse as it either. Something must be missing.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Post #1605973
Posted Thursday, August 21, 2014 1:07 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 11:24 AM
Points: 181, Visits: 440
<<What it's saying is that IF the Left join row exists , INNER join to that other table.
Otherwise, treat it like a regular LEFT join and put NULL in the JOINED columns.>>

Just got feedback from one top notch pro like above on that, so it's OK. It's definetely works and works very fast.

Sorry Jack, didn't get what good or worse in this case?

Thanks
M
Post #1605975
Posted Thursday, August 21, 2014 1:18 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 12:10 PM
Points: 11,322, Visits: 13,115
mario17 (8/21/2014)
<<What it's saying is that IF the Left join row exists , INNER join to that other table.
Otherwise, treat it like a regular LEFT join and put NULL in the JOINED columns.>>

Just got feedback from one top notch pro like above on that, so it's OK. It's definetely works and works very fast.

Sorry Jack, didn't get what good or worse in this case?

Thanks
M


The example you posted doesn't compile. I get:

Msg 102, Level 15, State 1, Line 11
Incorrect syntax near 'LogID'.


When trying to parse the query. I've also tried this:

 SELECT 
*
FROM
sys.tables AS T
LEFT JOIN sys.columns AS C
JOIN sys.index_columns AS IC
ON C.column_id = IC.column_id

To make sure the issue wasn't related to non-existent objects and I still get the same error. So I'm not sure how the code as presented could work.




Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Post #1605979
Posted Thursday, August 21, 2014 1:37 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 11:24 AM
Points: 181, Visits: 440
Thanks all, it's fact that this code works.
I'll try to do homework on demo db to break it completely down.

Mario
Post #1605985
Posted Thursday, August 21, 2014 2:44 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Yesterday @ 6:24 AM
Points: 418, Visits: 2,451
mario17 (8/21/2014)
Thanks all, it's fact that this code works.
I'll try to do homework on demo db to break it completely down.

Mario


Would be interesting to see if you can recreate a working left join that looks like that unless its actually quoted and sent to a linked server that I'm not interested in

LOL just kidding, send that too!
Post #1606012
Posted Thursday, August 21, 2014 4:02 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 11:24 AM
Points: 181, Visits: 440
Bingo !!
Yes it works, I didn't put one extra ON in my very first post, now it edited. and below is handy sample I made for all to try.
It claimed to be ANSI standard. I also put extra parentheses for readability. Plans are different, but Time is pretty much is the same..




WITH TestData AS
( SELECT 1 As testID
UNION ALL
SELECT td.testID + 1
FROM TestData td
WHERE td.testID < 32767 )

SELECT testID, 'This is #t1' AS C1 INTO #t1 FROM testData OPTION (MAXRECURSION 32767) -- drop table #t1, #t22, #T333
SELECT testID, 'This is #t22' AS C1 INTO #t22 FROM #t1 ; DELETE FROM #t22 WHERE testID IN (3,4,5);
SELECT testID, 'This is #t333' AS C1 INTO #t333 FROM #t1 -- select top 10 * from #t122
--------------------------------------------------

select
#t1.testID, #t1.C1 , #t22.C1, #t333.C1
FROM #t1
LEFT JOIN (#t22
INNER JOIN #t333 ON #t333.testID = #t22.testID)
ON #t1.testID = #t22.testID
-- SET STATISTICS TIME ON
/* vs. traditional
select
#t1.testID, #t1.C1 , #t22.C1, #t333.C1
FROM #t1
LEFT JOIN #t22 ON #t22.testID = #t1.testID
left JOIN #t333 ON #t333.testID = #t22.testID */


Post #1606063
Posted Friday, August 22, 2014 1:52 AM This worked for the OP Answer marked as solution


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Friday, September 12, 2014 9:43 AM
Points: 7,284, Visits: 13,824
Here's something I wrote some time ago (inspired by something Jack Corbett wrote years ago) which explains why you have two joins followed by two ON clauses:

The order of tables in the FROM clause is usually irrelevant because SQL Server will join the tables in whatever order results in the lowest-cost plan. However, the order of ON clauses matters...and can be manipulated to do some funky stuff.
“You have a query which joins two tables, say Customers and Orders. It’s an outer join because you want all customers whether or not they’ve ever placed an order – but the order can’t be empty, it must actually have some lines.”

Create a customer table with three customers, Peter, Simon and Chris
CREATE TABLE #Customers (CustomerID INT IDENTITY(1,1), CustomerName VARCHAR(20))
INSERT INTO #Customers (CustomerName) VALUES ('Peter'), ('Simon'), ('Chris')

Three orders for Peter, two orders for Simon and none for Chris (boo hoo)
CREATE TABLE #Orders (OrderID INT IDENTITY(1,1), CustomerID INT)
INSERT INTO #Orders (CustomerID) VALUES (1),(1),(1),(2),(2)

Only one of those orders has any items on it – Peter’s first order
CREATE TABLE #Orderlines (OrderlineID INT IDENTITY(1,1), OrderID INT, PartName VARCHAR(20))
INSERT INTO #Orderlines (OrderID, PartName) VALUES (1, 'Peter01'), (1, 'Peter02')


Then you write the obvious query:

-- Query 1
SELECT c.*, o.*, ol.*
FROM #Customers c
LEFT JOIN #Orders o ON o.CustomerID = c.CustomerID
INNER JOIN #Orderlines ol ON ol.OrderID = o.OrderID

The result set isn’t what you might expect – there are only two rows, corresponding to Peter’s two items. The result set looks as if SQL Server has changed the outer join to an inner join and the execution plan confirms it. Most TSQL coders know this and will usually begin testing a query where both child tables are outer joined:

-- Query 2
SELECT c.*, o.*, ol.*
FROM #Customers c
LEFT JOIN #Orders o ON o.CustomerID = c.CustomerID
LEFT JOIN #Orderlines ol ON ol.OrderID = o.OrderID

- Which returns too many rows and is tricky to filter. So they switch to this:

-- Query 3
SELECT c.*, o.*
FROM #Customers c
LEFT JOIN (
SELECT o.*, ol.OrderlineID, ol.PartName
FROM #Orders o
INNER JOIN #Orderlines ol ON ol.OrderID = o.OrderID
) o
ON o.CustomerID = c.CustomerID

- Which generates the correct result set as you would expect, and the execution plan confirms an inner join and an outer join.
You could also bracket your joins, but it’s so counterintuitive and tricky to maintain that I’m not even going to provide an example. If you must have a look, use Google – then forget what you’ve seen. There is another way, and that is to change the order of the ON clauses, so that Orders and Orderlines are inner joined before the product is joined to the Customer table:

-- Query 4
SELECT c.*, o.*, ol.*
FROM #Customers c
LEFT JOIN #Orders o
INNER JOIN #Orderlines ol
ON ol.OrderID = o.OrderID
ON o.CustomerID = c.CustomerID

This also generates the correct result set, confirmed by the execution plan. It’s easy to see what’s going on and the plan is only trivially different from query 3 – it’s slightly cheaper.



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1606135
« Prev Topic | Next Topic »

Add to briefcase 123»»»

Permissions Expand / Collapse