A View Inside My Head

Jason's Random Thoughts of Interest
posts - 48, comments - 110, trackbacks - 4

Filtering using Effective Dates in Queries

Nothing makes me want to pull my hair out more than writing SQL Queries that need to join two or more tables, with one of those tables containing an "Effective Date" column. Of course, the requirement is inevitably to filter out all records from this join such that the match condition is on some date value from one table and the latest "Effective Date" from the second table that pre-dates the first table's date value. /headdesk

For example, suppose that we have a table that maintains a "capacity" number that changes over time. To maintain historical accuracy, an "Effective Date" column tracks when the capacity changes:

EffDate Capacity
2007-01-01 50
2007-05-01 45
2008-01-01 52

And another table that contains a "quantity" value that changes over time.

Date Quantity
2007-01-01 45
2007-03-04 33
2007-08-11 65
2008-02-28 56

Now the challenge is to write a single SELECT statement that will join these two tables so that you can see Date, Quantity, and the effective Capacity for the given date all in the same row. Extraneous Capacities need to be filtered out. Inner queries are acceptable.

The result should be:

Date Quantity Capacity
2007-01-01 45 50
2007-03-04 33 50
2007-08-11 65 45
2008-02-28 56 52

I have written a few different solutions to this problem in the past, and I'll post my most recent attempt in comments here. But, I'm interested to see if anyone has a real head-slapper approach to writing this type of query that differs from my method.

Here's some setup code to generate the tables used in the sample above:

CREATE TABLE #EffCapacity
    (
      EffDate DATETIME,
      Capacity INT
    )
INSERT  INTO #EffCapacity
VALUES  ( '1/1/2007', 50 )
INSERT  INTO #EffCapacity
VALUES  ( '5/1/2007', 45 )
INSERT  INTO #EffCapacity
VALUES  ( '1/1/2008', 52 )
CREATE TABLE #MyQuantity
    (
      Date DATETIME,
      Quantity INT
    )
INSERT  INTO #MyQuantity
VALUES  ( '1/1/2007', 45 )
INSERT  INTO #MyQuantity
VALUES  ( '3/4/2007', 33 )
INSERT  INTO #MyQuantity
VALUES  ( '8/11/2007', 65 )
INSERT  INTO #MyQuantity
VALUES  ( '2/28/2008', 56 )

Print | posted on Thursday, December 27, 2007 11:58 AM | Filed Under [ SQL ]

Feedback

Gravatar

# re: Filtering using Effective Dates in Queries

And here's the query that I've come up with for this example:

SELECT Date,
Quantity,
Capacity
FROM #MyQuantity
JOIN #EffCapacity ON #MyQuantity.Date >= #EffCapacity.EffDate
WHERE #EffCapacity.EffDate IN ( SELECT MAX(effdate)
FROM #EffCapacity
WHERE effdate <= #MyQuantity.Date )
12/27/2007 12:24 PM | Jason
Gravatar

# re: Filtering using Effective Dates in Queries

After stepping back, I realized that the JOIN condition was not necessary because the MAX EffDate that is less than the Date is all that we're looking for. So, I can use a cross join with an appropriate predicate clause:

SELECT Date, Quantity, Capacity
FROM #MyQuantity, #EffCapacity
WHERE #EffCapacity.EffDate IN
(
SELECT MAX(effdate)
FROM #EffCapacity
WHERE effdate <= #MyQuantity.Date
)
12/27/2007 12:59 PM | Jason

# re: Filtering using Effective Dates in Queries

I can only think of three different ways to do this and the first two are really just variations of each other.

The first one is the simplest merely using a subquery to choose the capacity of the most recent applicable effective date.
1) SELECT Date, Quantity,
(SELECT TOP (1) Capacity
FROM EffCapacity
WHERE (EffDate <= MyQuantity.Date)
ORDER BY EffDate DESC) AS Capacity
FROM MyQuantity

The second on is the same thing just with the subquery in the where clause instead.
2)SELECT MyQuantity.Date, MyQuantity.Quantity, EffCapacity.Capacity, EffCapacity.EffDate
FROM EffCapacity INNER JOIN
MyQuantity ON EffCapacity.EffDate <= MyQuantity.Date
WHERE (EffCapacity.EffDate = (SELECT TOP (1) EffDate
FROM EffCapacity
WHERE (EffDate <= MyQuantity.Date)
ORDER BY EffDate DESC))

The third one is the complicated one as it uses a secondary join and a group/having by to remove the 'extra' capacities instead of a subquery. However it does seem to be fater than the previous two - altough I didn't try it on anything larger than the data used in your example.

3)SELECT MyQuantity.Date, MyQuantity.Quantity, EffCapacity.Capacity
FROM MyQuantity INNER JOIN
EffCapacity ON MyQuantity.Date >= EffCapacity.EffDate INNER JOIN
EffCapacity AS EffCapacity_1 ON EffCapacity.EffDate <= EffCapacity_1.EffDate AND MyQuantity.Date >= EffCapacity_1.EffDate
GROUP BY MyQuantity.Date, MyQuantity.Quantity, EffCapacity.Capacity, EffCapacity.EffDate
HAVING (COUNT(EffCapacity_1.EffDate) = 1)
12/27/2007 1:15 PM | Joshua Morgan

Post Comment

Title  
Name  
Email
Url
Comment   
Please add 7 and 6 and type the answer here:

Powered by: