How to write a Query to get related result

  • I need help to write a query like below oupt put.

    create table #table (id int, cid int , startdate datetime)

    insert #table

    select 1, 100, '02/23/2014'

    union select 1, 100, '06/25/2013'

    union select 1, 100, '06/04/2013'

    union select 1, 100, '06/17/2013'

    union select 2, 200, '08/9/2013'

    union select 2, 200, '08/3/2013'

    First date 02/23/2014...So heere I need only the 2013 Current End dates Based On Start Date...

    I need oupt put like below table based on above table.

    id cid start_date end_date

    1 100 02/23/2014 --

    1 100 06/25/2013 12/31/2013

    1 100 06/04/2013 06/24/2013

    1 100 06/17/2013 06/03/2013

    2 200 08/9/2013 12/31/2013

    2 200 08/03/2013 08/08/2013

    Thanks,

  • I think there is a problem with your sample data.

    There is at least one end date that occurs prior to the start date for the associated record.

    Additionally, since the end dates are inconsistent in duration from the start, the query would be to write a query with those dates as static values.

    Otherwise, you should be recording the end dates in a table along with the start date.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • Thanks for your reply,

    But there is no end date....I need to calculate the End date based on Start Date.

    Example I am calculating the 2013 year Data.

    If Start date date 2014 year , but we need to calculate only 2013 date..so there is no end date for 2014 Year.

    I taken Start Date is Order By Desc.....for Highest Date it needs to calculate the Year End Date (12/31/2013).

    Below is The Sample Out Put Based On Start Date..need to Calculate The End Date

    id cid start_date end_date

    1 100 02/23/2014 --

    1 100 06/25/2013 12/31/2013

    1 100 06/04/2013 06/24/2013

    1 100 06/17/2013 06/03/2013

    2 200 08/9/2013 12/31/2013

    2 200 08/03/2013 08/08/2013

  • suresh0534 (2/5/2014)


    Thanks for your reply,

    But there is no end date....I need to calculate the End date based on Start Date.

    Example I am calculating the 2013 year Data.

    If Start date date 2014 year , but we need to calculate only 2013 date..so there is no end date for 2014 Year.

    I taken Start Date is Order By Desc.....for Highest Date it needs to calculate the Year End Date (12/31/2013).

    Below is The Sample Out Put Based On Start Date..need to Calculate The End Date

    id cid start_date end_date

    1 100 02/23/2014 --

    1 100 06/25/2013 12/31/2013

    1 100 06/04/2013 06/24/2013

    1 100 06/17/2013 06/03/2013

    2 200 08/9/2013 12/31/2013

    2 200 08/03/2013 08/08/2013

    Your end dates make no common sense.

    You have multiple End dates that are end of year. Based on your statement that the highest start date should be the end of the year for the end date, we have a conflict there.

    Then you have the bolded start and end date where the end date is prior to your start date.

    Then you have some end dates that are 20 days from start date and some that are just 5 days from the start date.

    Are you trying to say that an end date just goes to the next start date in sequence? Well if so, then we still have a conflict in your sample data in that that sequence is still not consistent.

    We still need to have a more precise and clear set of rules to follow. We need to have a better set of data.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • I agree that your expected results are wrong because you have an enddate greater than the startdate and that will generate a problem in the next row (rows 3 & 4).

    This might give you an idea of what you need to solve your problem, even if I don't understand your "First Date" parameter.

    WITH CTE AS(

    SELECT *,

    ROW_NUMBER() OVER( PARTITION BY id, YEAR(StartDate) ORDER BY startdate) rn,

    YEAR(StartDate) DateYear

    FROM #table

    )

    SELECT c1.id,

    c1.cid,

    c1.startdate,

    ISNULL( c2.startdate - 1, CASE WHEN DATEADD(YEAR, DATEDIFF(YEAR, 0, c1.startdate) + 1, 0) < GETDATE()

    THEN DATEADD(YEAR, DATEDIFF(YEAR, 0, c1.startdate) + 1, 0) END)

    FROM CTE c1

    LEFT

    JOIN CTE c2 ON c1.DateYear = c2.DateYear

    AND c1.id = c2.id

    AND c1.rn = c2.rn - 1

    ORDER BY c1.id, c1.startdate DESC

    EDIT: Code Formatting.

    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
  • Luis Cazares (2/5/2014)


    I agree that your expected results are wrong because you have an enddate greater than the startdate and that will generate a problem in the next row (rows 3 & 4).

    This might give you an idea of what you need to solve your problem, even if I don't understand your "First Date" parameter.

    WITH CTE AS(

    SELECT *,

    ROW_NUMBER() OVER( PARTITION BY id, YEAR(StartDate) ORDER BY startdate) rn,

    YEAR(StartDate) DateYear

    FROM #table

    )

    SELECT c1.id,

    c1.cid,

    c1.startdate,

    ISNULL( c2.startdate - 1, CASE WHEN DATEADD(YEAR, DATEDIFF(YEAR, 0, c1.startdate) + 1, 0) < GETDATE()

    THEN DATEADD(YEAR, DATEDIFF(YEAR, 0, c1.startdate) + 1, 0) END)

    FROM CTE c1

    LEFT

    JOIN CTE c2 ON c1.DateYear = c2.DateYear

    AND c1.id = c2.id

    AND c1.rn = c2.rn - 1

    ORDER BY c1.id, c1.startdate DESC

    EDIT: Code Formatting.

    Slight tweak to this solution by Louis (good job)

    WITH CTE AS(

    SELECT *,

    ROW_NUMBER() OVER( PARTITION BY id, YEAR(StartDate) ORDER BY startdate) rn,

    YEAR(StartDate) DateYear

    FROM #table

    )

    SELECT c1.id,

    c1.cid,

    c1.startdate,

    ISNULL( c2.startdate - 1, CASE WHEN DATEADD(YEAR, DATEDIFF(YEAR, 0, c1.startdate) + 1, -1) < GETDATE()

    THEN DATEADD(YEAR, DATEDIFF(YEAR, 0, c1.startdate) + 1, -1) END) AS ENDDate

    FROM CTE c1

    LEFT OUTER JOIN CTE c2

    ON c1.DateYear = c2.DateYear

    AND c1.id = c2.id

    AND c1.rn = c2.rn - 1

    ORDER BY c1.id, c1.startdate DESC

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • I agree that your expected results don't match your sample data. But I think you're looking for something like this:

    SELECT id, cid, startdate=MIN(d)

    , enddate=CASE

    WHEN DATEPART(year, MIN(d)) = DATEPART(year, GETDATE()) THEN NULL

    WHEN DATEPART(year, MAX(d)) = DATEPART(year, MIN(d)) AND MAX(d) <> MIN(d) THEN MAX(d)

    ELSE DATEADD(year, 1, DATEADD(year, DATEDIFF(year, 0, MIN(d)), 0))-1 END

    FROM

    (

    SELECT id, cid, startdate, d

    ,rn=ROW_NUMBER() OVER (PARTITION BY id, cid ORDER BY d)/2

    FROM #table

    CROSS APPLY

    (

    VALUES (startdate),(startdate-1)

    ) b (d)

    ) a

    WHERE rn > 0

    GROUP BY id, cid, rn;

    Output from your sample data:

    id cid startdate enddate

    1 100 2013-06-04 00:00:00.000 2013-06-16 00:00:00.000

    1 100 2013-06-17 00:00:00.000 2013-06-24 00:00:00.000

    1 100 2013-06-25 00:00:00.000 2013-12-31 00:00:00.000

    1 100 2014-02-23 00:00:00.000 NULL

    2 200 2013-08-03 00:00:00.000 2013-08-08 00:00:00.000

    2 200 2013-08-09 00:00:00.000 2013-12-31 00:00:00.000


    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

  • dwain.c (2/5/2014)


    I agree that your expected results don't match your sample data. But I think you're looking for something like this:

    SELECT id, cid, startdate=MIN(d)

    , enddate=CASE

    WHEN DATEPART(year, MIN(d)) = DATEPART(year, GETDATE()) THEN NULL

    WHEN DATEPART(year, MAX(d)) = DATEPART(year, MIN(d)) AND MAX(d) <> MIN(d) THEN MAX(d)

    ELSE DATEADD(year, 1, DATEADD(year, DATEDIFF(year, 0, MIN(d)), 0))-1 END

    FROM

    (

    SELECT id, cid, startdate, d

    ,rn=ROW_NUMBER() OVER (PARTITION BY id, cid ORDER BY d)/2

    FROM #table

    CROSS APPLY

    (

    VALUES (startdate),(startdate-1)

    ) b (d)

    ) a

    WHERE rn > 0

    GROUP BY id, cid, rn;

    Output from your sample data:

    id cid startdate enddate

    1 100 2013-06-04 00:00:00.000 2013-06-16 00:00:00.000

    1 100 2013-06-17 00:00:00.000 2013-06-24 00:00:00.000

    1 100 2013-06-25 00:00:00.000 2013-12-31 00:00:00.000

    1 100 2014-02-23 00:00:00.000 NULL

    2 200 2013-08-03 00:00:00.000 2013-08-08 00:00:00.000

    2 200 2013-08-09 00:00:00.000 2013-12-31 00:00:00.000

    Nice solution. I saw the results before the edit to fix the end dates - way to get that fixed quickly 😉

    IMHO, I don't see why the start date of 6/25 would not have an end date of 8/2 instead of 12/31. That just makes more sense to me.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • SQLRNNR (2/5/2014)


    IMHO, I don't see why the start date of 6/25 would not have an end date of 8/2 instead of 12/31. That just makes more sense to me.

    Agreed that was a pretty weird requirement. My code makes the assumption that the end date has to be in the same year as the start date. No telling if that is true or not but the sample data seemed to suggest 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

  • SQLRNNR (2/5/2014)


    Nice solution.

    Actually, I am not too proud to admit that solution stunk up the house! Not sure what I was thinking there.

    This will be much faster, assuming a PRIMARY KEY consisting of id, cid and startdate of course.

    SELECT id, cid, StartDate

    ,EndDate=CASE

    WHEN DATEPART(year, StartDate) = DATEPART(year, GETDATE()) THEN NULL

    WHEN DATEPART(year, EndDate) = DATEPART(year, StartDate) AND EndDate <> StartDate THEN EndDate

    ELSE DATEADD(year, 1, DATEADD(year, DATEDIFF(year, 0, StartDate), 0))-1

    END

    FROM #table a

    OUTER APPLY

    (

    SELECT TOP 1 StartDate-1

    FROM #table b

    WHERE a.id = b.id AND a.cid = b.cid AND a.startdate < b.startdate

    ORDER BY b.startdate

    ) b(EndDate)

    ORDER BY id, cid, StartDate;


    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

  • dwain.c (2/5/2014)


    SQLRNNR (2/5/2014)


    Nice solution.

    Actually, I am not too proud to admit that solution stunk up the house! Not sure what I was thinking there.

    Well, it worked with limited information. Besides, tuning the query could have been a good exercise for the OP.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • Thank you so much...it help me lot....

    Big thankful to all the members....

    Thanks,

  • Good to hear. Glad there was some great stuff that worked for you on this thread.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • suresh0534 (2/6/2014)


    Thank you so much...it help me lot....

    Big thankful to all the members....

    Thanks,

    I'm glad to hear it helped too. It got me to thinking that this is sort of a common problem and what kinds of business cases need the support of this kind of query.

    Too bad you're not using SQL 2012. The LEAD function there is your ticket to the fastest possible solution.


    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

  • One More Small Issue can you help...

    create table #table (id int, cid int , startdate datetime)

    insert #table

    select 1, 100, '02/23/2014'

    union select 1, 100, '06/25/2013'

    union select 1, 100, '06/04/2013'

    union select 1, 100, '06/17/2013'

    union select 2, 200, '08/9/2013'

    union select 2, 200, '08/3/2013'

    union select 4, 600, '06/11/2013'

    union select 4, 600, '06/18/2013'

    union select 4, 600, '06/17/2013'

    union select 4, 600, '09/17/2013'

    union select 4, 600, '01/20/2014'

    union select 4, 600, '01/24/2014'

    SELECT id, cid, StartDate

    ,EndDate=CASE

    WHEN DATEPART(year, StartDate) = DATEPART(year, GETDATE()) THEN NULL

    WHEN DATEPART(year, EndDate) = DATEPART(year, StartDate) AND EndDate <> StartDate THEN EndDate

    ELSE DATEADD(year, 1, DATEADD(year, DATEDIFF(year, 0, StartDate), 0))-1

    END

    FROM #table a

    OUTER APPLY

    (

    SELECT TOP 1 StartDate-1

    FROM #table b

    WHERE a.id = b.id AND a.cid = b.cid AND a.startdate < b.startdate

    ORDER BY b.startdate

    ) b(EndDate)

    ORDER BY id, cid, StartDate;

    idcidStartDateEndDate

    11002013-06-04 00:00:00.0002013-06-16 00:00:00.000

    11002013-06-17 00:00:00.0002013-06-24 00:00:00.000

    11002013-06-25 00:00:00.0002013-12-31 00:00:00.000

    11002014-02-23 00:00:00.000NULL

    22002013-08-03 00:00:00.0002013-08-08 00:00:00.000

    22002013-08-09 00:00:00.0002013-12-31 00:00:00.000

    46002013-06-11 00:00:00.0002013-06-16 00:00:00.000

    46002013-06-17 00:00:00.0002013-12-31 00:00:00.000 --This End Date should Come 2013-06-17 But it showing 2013 12-31

    46002013-06-18 00:00:00.0002013-09-16 00:00:00.000

    46002013-09-17 00:00:00.0002013-12-31 00:00:00.000

    46002014-01-20 00:00:00.000NULL

    46002014-01-24 00:00:00.000NULL

    Remaining Data Every Thing Perfect...only that one has Issue...

    Thanks,

Viewing 15 posts - 1 through 15 (of 16 total)

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