Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2005 Forums
 Transact-SQL (2005)
 This query works, but should it?

Author  Topic 

theboyholty
Posting Yak Master

226 Posts

Posted - 2013-06-05 : 06:34:27
I've just been debugging my predecessors code and I came across this query. I don't understand how it works, but it does.

It uses a right join but then instead of going straight to the ON clause, it uses an inner join, and then does TWO ON clauses.

Is this the work of an evil genius, or an idiot? Well the query runs like a dog (this is part of a complex embedded query within a select clause) so I'm thinking idiot.

Either way, i'd appreciate your comments because if I don't understand this its going to give me nightmares.

SELECT DISTINCT s1.CAPEX
FROM dbo.v_product_family_capx AS s1
RIGHT OUTER JOIN dbo.part_usage AS s2
INNER JOIN dbo.part AS s3 ON s2.part_id = s3.part_id ON s1.product_family = s3.product_family




---------------------------------------------------------------------------------
http://www.mannyroadend.co.uk A Bury FC supporters website and forum

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-06-05 : 06:45:10
it looks though ON got misplaced but it wont have any issues in running as optimizer will be able to match and join the tables based on columns referred so far as they all exist.

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

Ifor
Aged Yak Warrior

700 Posts

Posted - 2013-06-05 : 12:32:05
This is a nested join. Most shops insist on brackets when doing this:

SELECT DISTINCT s1.CAPEX
FROM dbo.v_product_family_capx AS s1
RIGHT OUTER JOIN
(
dbo.part_usage AS s2
INNER JOIN dbo.part AS s3
ON s2.part_id = s3.part_id
)
ON s1.product_family = s3.product_family


As all the outer join can do is possibly add a NULL, I would be inclined to re-write as:
		
SELECT DISTINCT --??
CAPEX
FROM dbo.v_product_family_capx
UNION ALL
SELECT TOP 1 NULL
FROM dbo.v_product_family_capx S1
WHERE NOT EXISTS
(
SELECT 1
FROM dbo.part AS s3
WHERE s3.product_family = s1.product_family
AND EXISTS
(
SELECT 1
FROM dbo.part_usage AS s2
WHERE s2.part_id = s3.part_id
)
)
Go to Top of Page
   

- Advertisement -