Ask the Expert

Returning data when requested time period has no data, part 2

Here is the continuation of Jason's response. See part 1.

    Requires Free Membership to View

You might write the SQL like this:

select convert(varchar,Day,107) Day, 
       count(Passed) TotalCars
  from Days left join TollCars
    on TollCars.Passed >= Days.Day and 
       TollCars.Passed < Days.Day + 1
  where Color = 'RED'
  group by Day;
Here are the resulting rows:
Day          TotalCars
------------ ---------
Mar 01, 2002         1
Mar 04, 2002         1
Mar 07, 2002         2
But, you find that you have gaps in your days even though you've used an outer join. We need to remember that in an outer join situation, when no rows exist for the join condition in the non-preserved table, the columns are padded with nulls. So if the Color column is NULL, then the condition Color = ?RED' will not resolve to TRUE, and so the whole resulting row, including the preserved table's columns, is thrown out. The solution is to move the condition into the ON clause, making it part of the join condition. This has the same affect as filtering the TollCars table before performing the join. The following SQL statement will provide us with the results we want:
select convert(varchar,Day,107) Day, 
       count(Passed) TotalCars
  from Days left join TollCars
    on TollCars.Passed >= Days.Day and 
       TollCars.Passed < Days.Day + 1 and 
       Color = 'RED'
  group by Day;

Day          TotalCars
------------ ---------
Mar 01, 2002         1
Mar 02, 2002         0
Mar 03, 2002         0
Mar 04, 2002         1
Mar 05, 2002         0
Mar 06, 2002         0
Mar 07, 2002         2

For More Information

  • What do you think about this answer? E-mail the edtiors at editor@searchDatabase.com with your feedback.
  • The Best SQL Web Links: tips, tutorials, scripts, and more.
  • Have an SQL tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize. Submit your tip today!
  • Ask your technical SQL questions -- or help out your peers by answering them -- in our live discussion forums.
  • Ask the Experts yourself: Our SQL, database design, Oracle, SQL Server, DB2, metadata, object-oriented and data warehousing gurus are waiting to answer your toughest questions.

This was first published in March 2002

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to: