INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

return 0

return 0

(OP)

I am trying to return all portfolios, even if they don not have any that have NEWBIZ (return 0 with portfolio). I tried IFNULL. Not sure how to go about it. Any advice?
[code]
select ifnull(count(*),0) ,d.portfolio from dbase d, portfolios pf where statusname='NEWBIZ'
and pf.portfolio=d.portfolio
group by pf.portfolio order by pf.placementdate;
[code]

RE: return 0

Try

select d.portfolio,
sum(case when pf.portfolio is null then 1 else 0 end) PFCount
from dbase d
left outer join portfolios pf
on d.portfolio=pf.portfolio
and pf.statusname='NEWBIZ'
group by d.portfolio
order by pf.placementdate;

Ian

RE: return 0

COUNT() will return 0 if there weren't any matches in a LEFT OUTER JOIN (provided you count a column from the right table)

also, in a GROUP BY query, in order to sort on a column, that column must be in the SELECT list -- yes mysql will execute it regardless, but it might give the wrong data

CODE

SELECT d.portfolio
     , MAX(pf.placementdate) AS maxdate
     , COUNT(pf.portfolio) AS PFCount
 FROM dbase AS d
LEFT OUTER 
  JOIN portfolios AS pf 
    ON pf.portfolio = d.portfolio 
   AND pf.statusname = 'NEWBIZ'
GROUP 
    BY d.portfolio 
ORDER 
    BY maxdate; 

note also that dbases which are missing portfolios will have NULL as their placement date, so these will sort first

r937.com | rudy.ca
Buy my new book Simply SQL from Amazon

RE: return 0

(OP)
Thanks! Works perfect

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members!

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close