SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Calculate EndDate From Subsequent StartDate


Calculate EndDate From Subsequent StartDate

Author
Message
Nilssond
Nilssond
Right there with Babe
Right there with Babe (797 reputation)Right there with Babe (797 reputation)Right there with Babe (797 reputation)Right there with Babe (797 reputation)Right there with Babe (797 reputation)Right there with Babe (797 reputation)Right there with Babe (797 reputation)Right there with Babe (797 reputation)

Group: General Forum Members
Points: 797 Visits: 556
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



Evil Kraig F
Evil Kraig F
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8599 Visits: 7660
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
LinksUp
LinksUp
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1024 Visits: 4446
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/
Luis Cazares
Luis Cazares
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16573 Visits: 19098
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.
General Disclaimer:
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?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search