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

    Twitter: @AnyWayDBA