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


Left outer join and subquery.


Left outer join and subquery.

Author
Message
todinhkhoi
todinhkhoi
SSC Rookie
SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)

Group: General Forum Members
Points: 41 Visits: 73
I have a question on left outer join and subquery as follows:

Below is the code that gave me what I wanted:
---------------------------------
Code 1:

select distinct stpidm
, styear
, stterm
, stcyt
, MIN(dadate)
, shrtgpa_term_code
, sum(shrtgpa_hours_earned)
from oiradm.student
, saturn.shrtgpa
, oiradm.degrees_awarded
where st1sttime = 'F'
and stlevel = 'UG'
and ststsch = 'AS'
and styear >= '2003'
and styear <= '2008'
and stterm = '40'
and stpidm = dapidm(+)
and dalevel(+) = 'U'
and daschool(+) = 'AS'
and stpidm = shrtgpa_pidm(+)
and shrtgpa_levl_code(+) = 'UG'
group by stpidm, styear, stterm, stcyt, shrtgpa_term_code
---------------------------------

Now, instead of using MIN function for "dadate" as above, I want to use a subquery:
---------------------------------
Code 2:

select distinct stpidm
, styear
, stterm
, stcyt
, dadate
, shrtgpa_term_code
, sum(shrtgpa_hours_earned)
from oiradm.student
, saturn.shrtgpa
, oiradm.degrees_awarded A
where st1sttime = 'F'
and stlevel = 'UG'
and ststsch = 'AS'
and styear >= '2003'
and styear <= '2008'
and stterm = '40'
and stpidm = dapidm(+)
and dalevel(+) = 'U'
and daschool(+) = 'AS'
and dadate IN
(
select min(B.dadate)
from oiradm.degrees_awarded B
where A.dapidm = B.dapidm
and A.dalevel = B.dalevel
and A.daschool = B.daschool
and A.dalevel = 'U'
and A.daschool = 'AS'
and B.dalevel = 'U'
and B.daschool = 'AS'
group by B.dapidm, B.dalevel, B.daschool
)
and stpidm = shrtgpa_pidm(+)
and shrtgpa_levl_code(+) = 'UG'
group by stpidm, styear, stterm, stcyt, dadate, shrtgpa_term_code
---------------------------------

However, Code 2 only gives me records that exist in both tables "oiradm.student" and "oiradm.degrees_awarded". So I think I need to put (+) next to the variable "dadate" above (in bold) to complete a left outer join. I tried it, got an error message, and still do not know how to fix it. Do you have any ideas on how to make Code 2 work?

Any of your suggestions are much appreciated.
Grant Fritchey
Grant Fritchey
SSC Guru
SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)

Group: General Forum Members
Points: 98425 Visits: 33014
You're performing either ANSI 89 style joins. Instead, you should use the ANSI 92 style

SELECT ...
FROM TABLEA AS a
JOIN TABLEB AS b
ON a.ID = b.ID
LEFT JOIN TABLEC AS c
ON b.NewID = c.NewID
LEFT JOIN ...
WHERE...


This way you separate JOIN criteria from the filtering operations of the WHERE clause.

----------------------------------------------------
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
todinhkhoi
todinhkhoi
SSC Rookie
SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)

Group: General Forum Members
Points: 41 Visits: 73
Dear Grant

Thank you very much for your help.

I tried to rerun the codes as you instructed (please see Code 3 below). However, it still gave me only records that existed in both "oiradm.degrees_awarded" and "oiradm.student" tables although I had specified a right join. What I needed was all records from "oiradm.student" table (with filter conditions). Do you have any ideas on how I should modify the codes? Thank you very much.

-----------------------------
Code 3

select distinct stpidm
, styear
, stterm
, stcyt
, dadate
, shrtgpa_term_code
, sum(shrtgpa_hours_earned)
from oiradm.degrees_awarded A RIGHT JOIN oiradm.student ON dapidm = stpidm
LEFT JOIN saturn.shrtgpa ON stpidm = shrtgpa_pidm
where st1sttime = 'F'
and stlevel = 'UG'
and ststsch = 'AS'
and styear >= '2003'
and styear <= '2008'
and stterm = '40'
and dalevel = 'U'
and daschool = 'AS'
and dadate IN
(select min(B.dadate)
from oiradm.degrees_awarded B
where A.dapidm = B.dapidm
and A.dalevel = B.dalevel
and A.daschool = B.daschool
and A.dalevel = 'U'
and A.daschool = 'AS'
and B.dalevel = 'U'
and B.daschool = 'AS'
group by B.dapidm, B.dalevel, B.daschool
)
and shrtgpa_levl_code = 'UG'
group by stpidm, styear, stterm, stcyt, dadate, shrtgpa_term_code
-----------------------------
dan-404057
dan-404057
SSC-Enthusiastic
SSC-Enthusiastic (165 reputation)SSC-Enthusiastic (165 reputation)SSC-Enthusiastic (165 reputation)SSC-Enthusiastic (165 reputation)SSC-Enthusiastic (165 reputation)SSC-Enthusiastic (165 reputation)SSC-Enthusiastic (165 reputation)SSC-Enthusiastic (165 reputation)

Group: General Forum Members
Points: 165 Visits: 334
You need to filter on the join if selecting only specific records in the left join.

I.e.

Select a.*, b.*
From a
left join b on a.id = b.id
and b.date >= '06-01-2011'
where a.name = 'smith'

Another option is to use a CTE to filter the data first for the saturn.shrtgpa table and then left join to the CTE instead.
Grant Fritchey
Grant Fritchey
SSC Guru
SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)

Group: General Forum Members
Points: 98425 Visits: 33014
Yeah, Dan has it right. If you filter on columns from the OUTER table in the WHERE clause you will get an INNER JOIN. The trick is to move those criteria from the WHERE to the JOIN to fix that issue.

----------------------------------------------------
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
todinhkhoi
todinhkhoi
SSC Rookie
SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)

Group: General Forum Members
Points: 41 Visits: 73
Dear DAN and GRANT

Thank you for the instructions. I followed them, and finally I was successful in retrieving the data I wanted. I have another 2 questions as follows:

1. Can you tell me why I would get an INNER JOIN if I filtered on columns from the OUTER table in the WHERE clause?

2. I am reading the book "Mastering Oracle SQL" (by Sanjay Mishra and Alan Beaulieu), but it does not mention the above issue. Can you suggest me a book that discusses in much detail different issues related to joins?

Thank you
Evil Kraig F
Evil Kraig F
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20613 Visits: 7660
I can answer one of these. What I officially know about Oracle you can fit in a thimble and still pour a shot into.

todinhkhoi (6/13/2011)

1. Can you tell me why I would get an INNER JOIN if I filtered on columns from the OUTER table in the WHERE clause?


It's the operational order.

First, think about the join itself: (tbl1: 1/2/3/4, tbl2: 1/2)

1 1
2 2
3 NULL
4 NULL

Now, if you where clause BEFORE you join (thus, in the on clause) and remove line 2 via some tbl2.attribute = 'x':

1 1
2 NULL
3 NULL
4 NULL

If you do it in the WHERE clause:
1 1

The where clause happens (logically, not necessarily physically) after the joins complete. The ON clause is a direct descriptor as to what to take from a table during the join mechanic. The OUTER JOIN needed to have the NULL side restricted without restricting the full query result.


- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Grant Fritchey
Grant Fritchey
SSC Guru
SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)SSC Guru (98K reputation)

Group: General Forum Members
Points: 98425 Visits: 33014
todinhkhoi (6/13/2011)
Dear DAN and GRANT

Thank you for the instructions. I followed them, and finally I was successful in retrieving the data I wanted. I have another 2 questions as follows:

1. Can you tell me why I would get an INNER JOIN if I filtered on columns from the OUTER table in the WHERE clause?

2. I am reading the book "Mastering Oracle SQL" (by Sanjay Mishra and Alan Beaulieu), but it does not mention the above issue. Can you suggest me a book that discusses in much detail different issues related to joins?

Thank you


You're posting in a SQL Server forum, so I would assume you're learning TSQL, not PLSQL. That Oracle book will steer you wrong. Itzik Ben-Gan has a book called, I think, Introducing TSQL-Querying. I'd get that.

----------------------------------------------------
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
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