Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Calculate EndDate From Subsequent StartDate Expand / Collapse
Author
Message
Posted Monday, July 28, 2014 3:44 PM
Say Hey Kid

Say Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey Kid

Group: General Forum Members
Last Login: Friday, October 17, 2014 3:59 PM
Points: 700, Visits: 441
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:


CATEGORYID EFFECTIVEDATE TERMDATE CATEGORYVALUE

1000 2014-01-01 2014-01-31 A
1000 2014-02-01 2014-03-21 B
1000 2014-04-01 2014-06-30 C
1000 2014-07-01 NULL A



Post #1597096
Posted Monday, July 28, 2014 3:54 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Saturday, October 18, 2014 4:43 AM
Points: 5,401, Visits: 7,512
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




- Craig Farrell

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 | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1597102
Posted Monday, July 28, 2014 4:14 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Yesterday @ 9:30 PM
Points: 361, Visits: 1,532
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/
Post #1597108
Posted Monday, July 28, 2014 4:24 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 8:12 AM
Points: 3,761, Visits: 8,441
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




Luis C.
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1597112
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse