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


Inner join returning all rows.


Inner join returning all rows.

Author
Message
TryingToLearn
TryingToLearn
SSC Veteran
SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)

Group: General Forum Members
Points: 205 Visits: 456
I figured it out....Thank you,

I would like to return all the data for a single empnum, but this query is returnng data for ALL empnum's. any suggestion would be greatly appreciated.

select E.empnum, rtrim(C.lname) + ', ' + rtrim(C.fname) as Name,
rtrim(substring(C.dept,1,3)) as Office,
C.dept,
calldate,
duration_in_decimal,
io
from CALLS C INNER JOIN EMP E on C.empnum = E.empnum and C.empnum = 6396 where
(month(calldate) = case month('2012/11/30') when '1' then '12' else month('2012/11/30') - 1 end and
year(calldate) = case month('2012/11/30') when '1' then year('2012/11/30') - 1 else year('2012/11/30') end and duration_in_decimal > .0055555
and (len(phonenum) IN (7,10,11))) or (month(calldate) = case month('2012/11/30') when '1' then '12' else month('2012/11/30') - 1 end and
year(calldate) = case month('2012/11/30') when '1' then year('2012/11/30') - 1 else year('2012/11/30') end and io = 'I')
ORDER BY C.empnum;
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26307 Visits: 17553
TryingToLearn (5/3/2013)
I figured it out....Thank you,

I would like to return all the data for a single empnum, but this query is returnng data for ALL empnum's. any suggestion would be greatly appreciated.

select E.empnum, rtrim(C.lname) + ', ' + rtrim(C.fname) as Name,
rtrim(substring(C.dept,1,3)) as Office,
C.dept,
calldate,
duration_in_decimal,
io
from CALLS C INNER JOIN EMP E on C.empnum = E.empnum and C.empnum = 6396 where
(month(calldate) = case month('2012/11/30') when '1' then '12' else month('2012/11/30') - 1 end and
year(calldate) = case month('2012/11/30') when '1' then year('2012/11/30') - 1 else year('2012/11/30') end and duration_in_decimal > .0055555
and (len(phonenum) IN (7,10,11))) or (month(calldate) = case month('2012/11/30') when '1' then '12' else month('2012/11/30') - 1 end and
year(calldate) = case month('2012/11/30') when '1' then year('2012/11/30') - 1 else year('2012/11/30') end and io = 'I')
ORDER BY C.empnum;


You should move that to the where clause.

So let's look at your where clause a little bit here...

If you have anything resembling a lot of data this is going to crawl like a snail in frozen molasses. You have all sorts of nonSARGable predicates and tons of implicit conversions.

I suspect that what you are doing is creating a big long sql string in your application and then executing it? This code could be greatly improved from a performance standpoint.

Try moving your empnum check to the where clause and see if that helps. Then if you want some help to make this run faster we can take a look.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Sergiy
Sergiy
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10494 Visits: 11963
SELECT E.empnum, RTRIM(C.lname) + ', ' + RTRIM(C.fname) AS Name,
RTRIM(SUBSTRING(C.dept,1,3)) AS Office,
C.dept,
calldate,
duration_in_decimal,
io
FROM CALLS C
INNER JOIN ( -- subquery returnig beginning of the curent(?) month. This approach allows us to do the conversion and month calculations just once
SELECT DATEADD(mm, DATEDIFF(mm, 0, CONVERT(DATETIME, '20121130', 112)), 0) MonthStart ) CM
-- selecting the range of dates for calldate - the way allowing to use an index
ON calldate >= DATEADD(mm, -1, MonthStart) AND calldate < MonthStart
INNER JOIN EMP E ON C.empnum = E.empnum
WHERE C.empnum = 6396 -- following Sean's sound advice
AND (
-- now the conditions look pretty straight forward. Please correct it if I made a mistake somewhere.
-- it was not so easy to find the ends in the original version :-)
(duration_in_decimal > .0055555 AND LEN(phonenum) IN (7,10,11))
OR io = 'I'
)
ORDER BY C.empnum;



And one last comment.
I'm pretty sure the table CALLS has a clustered index with 1st column "calldate". Right?
Well, why am I asking? It just cannot be any other way.
Silly me.Hehe
TryingToLearn
TryingToLearn
SSC Veteran
SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)

Group: General Forum Members
Points: 205 Visits: 456
Thank you...
TryingToLearn
TryingToLearn
SSC Veteran
SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)

Group: General Forum Members
Points: 205 Visits: 456
Thank you..
TryingToLearn
TryingToLearn
SSC Veteran
SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)SSC Veteran (205 reputation)

Group: General Forum Members
Points: 205 Visits: 456
really appreciate your help. This code was written 10 years ago....and i am a little new to coding.

SELECT DATEADD(mm, DATEDIFF(mm, 0, CONVERT(DATETIME, '20121130', 112)), 0) MonthStart ) CM
ON calldate >= DATEADD(mm, -1, MonthStart) AND calldate < MonthStart



Could you pseudo code explain what is happening in this block of code? what i thought it was doing was getting all data for this employee for the month i pass in(20121130). what the CM relates to is confusing me..
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26307 Visits: 17553
TryingToLearn (5/7/2013)
really appreciate your help. This code was written 10 years ago....and i am a little new to coding.

SELECT DATEADD(mm, DATEDIFF(mm, 0, CONVERT(DATETIME, '20121130', 112)), 0) MonthStart ) CM
ON calldate >= DATEADD(mm, -1, MonthStart) AND calldate < MonthStart



Could you pseudo code explain what is happening in this block of code? what i thought it was doing was getting all data for this employee for the month i pass in(20121130). what the CM relates to is confusing me..


You are missing the very critical piece of that which is the line above it.


INNER JOIN ( -- subquery returnig beginning of the curent(?) month. This approach allows us to do the conversion and month calculations just once


This is joining to the subselect inside the parenthesis. The CM is the alias for the subselect.

I tried to reformat this a little bit so it might be easier to see what is going on here.


INNER JOIN
( -- subquery returnig beginning of the curent(?) month. This approach allows us to do the conversion and month calculations just once
SELECT DATEADD(mm, DATEDIFF(mm, 0, CONVERT(DATETIME, '20121130', 112)), 0) MonthStart
) CM ON calldate >= DATEADD(mm, -1, MonthStart) AND calldate < MonthStart
-- selecting the range of dates for calldate - the way allowing to use an index



Does this help?

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
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