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 12»»

How to write a Query to get related result Expand / Collapse
Author
Message
Posted Wednesday, February 5, 2014 4:55 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 27, 2014 9:28 AM
Points: 48, Visits: 273
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,
Post #1538410
Posted Wednesday, February 5, 2014 5:02 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 1:51 PM
Points: 21,644, Visits: 15,317
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


SQL RNNR

Posting Performance Based Questions - Gail Shaw
Posting Data Etiquette - Jeff Moden
Hidden RBAR - Jeff Moden
VLFs and the Tran Log - Kimberly Tripp
Post #1538413
Posted Wednesday, February 5, 2014 5:09 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 27, 2014 9:28 AM
Points: 48, Visits: 273
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
Post #1538416
Posted Wednesday, February 5, 2014 5:15 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 1:51 PM
Points: 21,644, Visits: 15,317
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


SQL RNNR

Posting Performance Based Questions - Gail Shaw
Posting Data Etiquette - Jeff Moden
Hidden RBAR - Jeff Moden
VLFs and the Tran Log - Kimberly Tripp
Post #1538418
Posted Wednesday, February 5, 2014 5:19 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: Yesterday @ 7:20 PM
Points: 3,545, Visits: 7,653
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.
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 #1538420
Posted Wednesday, February 5, 2014 5:36 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 1:51 PM
Points: 21,644, Visits: 15,317
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


SQL RNNR

Posting Performance Based Questions - Gail Shaw
Posting Data Etiquette - Jeff Moden
Hidden RBAR - Jeff Moden
VLFs and the Tran Log - Kimberly Tripp
Post #1538427
Posted Wednesday, February 5, 2014 5:48 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: 2 days ago @ 8:30 PM
Points: 3,627, Visits: 5,273
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!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1538432
Posted Wednesday, February 5, 2014 5:55 PM This worked for the OP Answer marked as solution


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 1:51 PM
Points: 21,644, Visits: 15,317
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


SQL RNNR

Posting Performance Based Questions - Gail Shaw
Posting Data Etiquette - Jeff Moden
Hidden RBAR - Jeff Moden
VLFs and the Tran Log - Kimberly Tripp
Post #1538434
Posted Wednesday, February 5, 2014 6:02 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: 2 days ago @ 8:30 PM
Points: 3,627, Visits: 5,273
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!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1538437
Posted Wednesday, February 5, 2014 8:12 PM This worked for the OP Answer marked as solution


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: 2 days ago @ 8:30 PM
Points: 3,627, Visits: 5,273
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!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1538451
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse