Start and End Dates for Historical Data - SQL 2008R2 version of Lead/Lag?

  • I'm guessing that this is some sort of mashup of islands and running total code. I have historical data about phone numbers and I need to summarize the daily data into interval records to load into a historical dimension. On every change of phone location or type, I need to add a new record with the effective start and end dates. Here's some sample data

    Create table #A

    (PhoneNum varchar(10),

    PhoneType char(1),

    PhoneLocation char(1),

    FileDate date)

    INSERT INTO #A

    VALUES ('0000000000','A','B','01/01/2013'),

    ('0000000000','A','B','01/05/2013'),

    ('0000000000','A','B','01/10/2013'),

    ('0000000000','G','B','01/12/2013'),

    ('0000000000','G','B','01/13/2013'),

    ('0000000000','G','B','01/14/2013'),

    ('0000000000','A','B','01/18/2013'),

    ('0000000000','A','B','01/19/2013'),

    ('0000000001','A','V','01/01/2013'),

    ('0000000001','A','V','01/07/2013'),

    ('0000000001','X','Y','01/17/2013'),

    ('0000000001','G','B','01/18/2013'),

    ('0000000001','G','B','01/19/2013'),

    ('0000000001','A','B','01/21/2013')

    SELECT PhoneNum,

    PhoneType,

    PhoneLocation,

    MIN(FileDate) as StartDate,

    MAX(FileDate) as EndDate

    FROM #A

    GROUP BY PhoneNum,

    PhoneType,

    PhoneLocation

    ORDER BY PhoneNum,

    MIN(FileDate)

    The results from the select statement work fine for phone number '0000000001', but not for '0000000000'. The results I want are:

    PhoneNumPhoneTypePhoneLocationStartDateEndDate

    0000000000AB2013-01-012013-01-10

    0000000000GB2013-01-122013-01-14

    0000000000AB2013-01-182013-01-19

    0000000001AV2013-01-012013-01-07

    0000000001XY2013-01-172013-01-17

    0000000001GB2013-01-182013-01-19

    0000000001AB2013-01-212013-01-21

    I need to somehow set a grouping id if the previous values of PhoneType and PhoneLocation of a PhoneNumber change based on the order of the FileDate. If I had 2012, I could use LEAD/LAG right? Once I have the grouping, I should be able to pull the MIN/MAX FileDate to get my Start and End Dates. Any help would be much appreciated.

    Thanks,

    MWise

  • Hi

    This should do the trick for you

    with cte as (

    select PhoneNum, PhoneType, PhoneLocation, FileDate

    ,ROW_NUMBER() OVER (PARTITION BY PhoneNum ORDER BY PhoneType, PhoneLocation, FileDate) -

    ROW_NUMBER() OVER (PARTITION BY PhoneNum ORDER BY FileDate) R

    FROM #A

    )

    SELECT PhoneNum, PhoneType, PhoneLocation, Min(FileDate), max(FileDate)

    FROM cte

    GROUP BY PhoneNum, PhoneType, PhoneLocation, R

    ORDER BY PhoneNum, Min(fileDate);

  • MWise (10/16/2013)


    I need to somehow set a grouping id if the previous values of PhoneType and PhoneLocation of a PhoneNumber change based on the order of the FileDate. If I had 2012, I could use LEAD/LAG right? Once I have the grouping, I should be able to pull the MIN/MAX FileDate to get my Start and End Dates. Any help would be much appreciated.

    Thanks,

    MWise

    MickyT's solution (which earns him a +1 BTW) is probably the best you're going to do for solving this (an islands) problem.

    I've found the SQL 2012 LAG/LEAD functions very good at coming up with Gaps, which can be converted into Islands (The SQL of Gaps and Islands in Sequences[/url]), using CROSS APPLY VALUES. I'm just not sure how that would compare to the straight up islands approach MickyT did with respect to performance.

    Perhaps there is a direct solution to using LAG/LEAD to give you Islands, I just haven't hit upon it yet (nor have I tried to search for it).


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply