July 28, 2014 at 3:44 pm
Here is sample data I am working with:
Create table cattimelines (categoryID int, EffectiveDate datetime, CategoryValue varchar(11))
INSERT INTO cattimelines(categoryID, EffectiveDate, CategoryValue) VALUES(1000, '2014-01-01', 'A')
INSERT INTO cattimelines(categoryID, EffectiveDate, CategoryValue) VALUES(1000, '2014-02-01', 'B')
INSERT INTO cattimelines(categoryID, EffectiveDate, CategoryValue) VALUES(1000, '2014-04-01', 'C')
INSERT INTO cattimelines(categoryID, EffectiveDate, CategoryValue) VALUES(1000, '2014-07-01', 'A')
I need to calculates a term date for each record which will be 1 day before the effective date of any new record, thus:
CATEGORYIDEFFECTIVEDATETERMDATECATEGORYVALUE
10002014-01-012014-01-31A
10002014-02-012014-03-21B
10002014-04-012014-06-30C
10002014-07-01NULLA
July 28, 2014 at 3:54 pm
Does this data only work with dates, and never times (such as what GETDATE() would return?). The reason I ask is that it basically skips a day worth of minutes between, say, 6/30/14 00:00:00.003 and 6/30/14 23:59:59.957.
However, if you're simply doing this for reporting purposes and not detection logic, the easiest way is to dual query the information (you have to do this), and find the minimum date for your key greater than the current row's value. This is most easily done with Outer Apply:
IF OBJECT_ID ('tempdb..#cattimelines') IS NOT NULL
DROP TABLE #cattimelines
Create table #cattimelines (categoryID int, EffectiveDate datetime, CategoryValue varchar(11))
INSERT INTO #cattimelines(categoryID, EffectiveDate, CategoryValue) VALUES(1000, '2014-01-01', 'A')
INSERT INTO #cattimelines(categoryID, EffectiveDate, CategoryValue) VALUES(1000, '2014-02-01', 'B')
INSERT INTO #cattimelines(categoryID, EffectiveDate, CategoryValue) VALUES(1000, '2014-04-01', 'C')
INSERT INTO #cattimelines(categoryID, EffectiveDate, CategoryValue) VALUES(1000, '2014-07-01', 'A')
SELECT
ct.CategoryID,
EffectiveDate AS StartDate,
DATEADD( dd, -1, drv.MinED) AS EndDate,
CategoryValue
FROM
#cattimelines AS ct
OUTER APPLY
(SELECT
ct2.CategoryID,
MIN( ct2.EffectiveDate) AS MinED
FROM
#cattimelines AS ct2
WHERE
ct.EffectiveDate < ct2.EffectiveDate
AND ct.CategoryID = ct2.CategoryID
GROUP BY
ct2.CategoryID
) AS drv
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[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
July 28, 2014 at 4:14 pm
Since you posted in an SQL 2012 forum, you could look at LAG & LEAD.
A non 2012 solution to this would be something like this:
;with cte as
(
Select categoryID, effectivedate, categoryvalue,
ROW_NUMBER() over(order by categoryID, effectiveDate) as RowNum
from cattimelines
)
select c.categoryID, c.effectivedate, DATEADD(dd, -1, n.effectivedate) termDate
from cte as c
left outer join cte as n
on c.categoryID = n.categoryID
and c.RowNum = N.RowNum-1
__________________________________________________________________________________________________________
How to Post to get the most: http://www.sqlservercentral.com/articles/Best+Practices/61537/
July 28, 2014 at 4:24 pm
To give the example of LEAD() as proposed by LinksUp.
SELECT categoryID,
EffectiveDate AS StartDate,
DATEADD( dd, -1, LEAD(EffectiveDate) OVER( PARTITION BY categoryID ORDER BY EffectiveDate) ) AS EndDate,
CategoryValue
FROM cattimelines
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply