Please start any new threads on our new
site at https://forums.sqlteam.com. We've got lots of great SQL Server
experts to answer whatever question you can come up with.
| Author |
Topic |
|
slimt_slimt
Aged Yak Warrior
746 Posts |
Posted - 2012-06-04 : 16:00:56
|
| hi,i have a insurance data, where i need to calculate prolonging dates. Prolonging dates are calculated based on overlapping. if date overlaps previous insurance date, recalulate it and prolonge it, else just add to starting day 1 year (1 year is a length of insurance premium).here is a sample of data (wit DDL) and desired output which I want to query it.DDL:create table insurance (id int identity(1,1),customerID int,InsuranceID int,InsuranceDate datetime,CancelInsurance tinyint default(0) --(0 - No, 1 - Yes),CalculatedValidFrom datetime,CalculatedValidTo datetime)insert into insurance (customerID, InsuranceID, InsuranceDate, CancelInsurance)select 52,22312,'2010/10/19',0 union allselect 52,22313,'2011/10/21',1 union allselect 52,52369,'2012/02/14',0 union allselect 52,52353,'2012/02/16',0 union allselect 52,52380,'2012/02/17',0 union allselect 79,65322,'2012/05/05',0 union allselect 79,65323,'2012/05/06',0 union allselect 42,23523,'2012/05/05',0 union all select 49,23532,'2010/02/25',0 union allselect 49,23533,'2012/02/26',0 union allselect 49,23534,'2012/02/27',0 -- desired output:CustomerID | InsuranceID | InsuranceDate | CalculaterValidFrom | CalculatedValidTo----------------------------------------------------------------------------------52 | 22312 | 2010/10/19 | 2010/10/19 | 2011/10/1952 | 52369 | 2012/02/14 | 2012/02/14 | 2013/02/1452 | 52353 | 2012/02/16 | 2013/02/14 | 2014/02/1452 | 52380 | 2012/02/17 | 2014/02/14 | 2015/02/1479 | 65322 | 2012/05/05 | 2012/05/05 | 2013/05/0579 | 65323 | 2012/05/06 | 2013/05/05 | 2014/05/0542 | 23523 | 2012/05/05 | 2012/05/05 | 2013/05/0549 | 23532 | 2010/02/25 | 2010/02/25 | 2011/02/25 49 | 23533 | 2012/02/26 | 2012/02/26 | 2013/02/2649 | 23534 | 2012/02/27 | 2013/02/26 | 2014/02/26cheers! |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-06-04 : 16:36:35
|
| [code];With TempAS(SELECT CustomerID , InsuranceID , InsuranceDate ,InsuranceDate AS CalculaterValidFrom,DATEADD(yy,1,InsuranceDate) AS CalculatedValidTo,ROW_NUMBER() OVER (PARTITION BY CustomerID ORDER BY InsuranceID ) AS RnFROM table)SELECT t.CustomerID,t.InsuranceID,t.InsuranceDate,CASE WHEN t1.Cnt > 0 THEN MaxTo ELSE CalculaterValidFrom END AS CalculaterValidFrom,CASE WHEN t1.Cnt > 0 THEN DATEADD(yy,1,MaxTo) ELSE CalculaterValidTo END AS CalculaterValidToFROM Temp tOUTER APPLY (SELECT COUNT(1) AS Cnt,MAX(CalculatedValidTo) AS MaxTo FROM Temp WHERE CustomerID =t.CustomerID AND InsuranceID < t.InsuranceID AND t.InsuranceDate BETWEEN CalculaterValidFrom AND CalculatedValidTo )t1[/code]------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
slimt_slimt
Aged Yak Warrior
746 Posts |
Posted - 2012-06-04 : 16:54:38
|
| Visakhm,big thanks for solution.runnint the query, it returns a false premium dates for: CustomerID: 52 on InsuranceID: 52380 it should be as (i hope i'm clear enough):[Code]CustomerID | InsuranceID | InsuranceDate | CalculaterValidFrom | CalculatedValidTo----------------------------------------------------------------------------------52 | 22312 | 2010/10/19 | 2010/10/19 | 2011/10/1952 | 52369 | 2012/02/14 | 2012/02/14 | 2013/02/1452 | 52353 | 2012/02/16 | 2013/02/14 | 2014/02/1452 | 52380 | 2012/02/17 | 2014/02/14 | 2015/02/14[/code]and i've added a where clause in CTE part (i forgot to mention it, cancellation are excluded):[Code];With TempAS(SELECT CustomerID , InsuranceID , InsuranceDate ,InsuranceDate AS CalculaterValidFrom,DATEADD(yy,1,InsuranceDate) AS CalculatedValidTo,ROW_NUMBER() OVER (PARTITION BY CustomerID ORDER BY InsuranceID ) AS RnFROM tableWHERE CancelInsurance = 0[/code] |
 |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-06-04 : 21:39:58
|
this?;With TempAS(SELECT CustomerID , InsuranceID , InsuranceDate ,InsuranceDate AS CalculaterValidFrom,DATEADD(yy,1,InsuranceDate) AS CalculatedValidTo,ROW_NUMBER() OVER (PARTITION BY CustomerID ORDER BY InsuranceID ) AS RnFROM tableWHERE CancelInsurance = 0)SELECT t.CustomerID,t.InsuranceID,t.InsuranceDate,CASE WHEN t.InsuranceDate BETWEEN t1.CalculaterValidFrom AND t1.CalculatedValidTo THEN t1.CalculatedValidTo ELSE t.CalculaterValidFrom END AS CalculaterValidFrom,CASE WHEN t.InsuranceDate BETWEEN t1.CalculaterValidFrom AND t1.CalculatedValidTo THEN DATEADD(yy,1,t1.CalculatedValidTo) ELSE t.CalculaterValidTo END AS CalculaterValidToFROM Temp tOUTER APPLY (SELECT TOP 1 CalculatedValidFrom,CalculatedValidTo FROM Temp WHERE CustomerID =t.CustomerID AND InsuranceID < t.InsuranceID ORDER BY InsuranceID DESC )t1 ------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
slimt_slimt
Aged Yak Warrior
746 Posts |
Posted - 2012-06-05 : 04:18:25
|
| Visakh,still query does not return result as expected. for customerID 52, all insurance premium should be calculated cumulatively as shown in desired output. |
 |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-06-05 : 10:01:21
|
| Where have you shown insurance premium in output? I can see only insurance details and valid from and To dates------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
slimt_slimt
Aged Yak Warrior
746 Posts |
Posted - 2012-06-05 : 14:29:48
|
| Visakh,sorry for any misunderstanding. only fields CalculaterValidFrom and CalculatedValidTo are being calculated. And these dates are being calculated in sense of prolongation of Insurance premium. If you buy three premiums in one week, i want to have for each premium calculated ValidFrom-ValidTo time frames. In case of CustomerID = 52 only one date is coming out wrong in query.instead of: CustomerID InsuranceID CalculatedValidFrom CalculatedValidTo 52 52369 2012-02-14 2013-02-14 52 52353 2012-02-16 2013-02-16 52 52380 2013-02-14 2014-02-14 one should get:CustomerID | InsuranceID |CalculatedValidFrom | CalculatedValidTo ------------------------------------------------------------------- 52 | 52369 | 2012/02/14 | 2013/02/14 52 | 52353 | 2013/02/14 | 2014/02/14 52 | 52380 | 2014/02/14 | 2015/02/14i hope i made my self somehow more clear :)thanks again. |
 |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-06-05 : 14:42:43
|
| sorry but doesnt my suggestion on 06/04/2012 : 16:36:35 give you that?------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
slimt_slimt
Aged Yak Warrior
746 Posts |
Posted - 2012-06-05 : 18:10:32
|
| hi,no it doesn't. it returns:CustomerID InsuranceID InsuranceDate CalculatedValidFrom CalculatedValidTo52 52369 2012-02-14 2012-02-14 2013-02-14 52 52353 2012-02-16 2012-02-16 2013-02-16 52 52380 2012-02-17 2013-02-16 2014-02-16 where you can see that two InsuranceID (52353,52380) are overlapping but they should be calculated in the future. so you have all the way to year 2015 not only to 2014. both insuranceID are for same Car, it's just that special offer was created and customer bought two one-year insurance premium in two days. :) |
 |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-06-05 : 18:55:48
|
| [code]create table insurance (id int identity(1,1),customerID int,InsuranceID int,InsuranceDate datetime,CancelInsurance tinyint default(0) --(0 - No, 1 - Yes),CalculatedValidFrom datetime,CalculatedValidTo datetime)insert into insurance (customerID, InsuranceID, InsuranceDate, CancelInsurance)select 52,22312,'2010/10/19',0 union allselect 52,22313,'2011/10/21',1 union allselect 52,52369,'2012/02/14',0 union allselect 52,52353,'2012/02/16',0 union allselect 52,52380,'2012/02/17',0 union allselect 79,65322,'2012/05/05',0 union allselect 79,65323,'2012/05/06',0 union allselect 42,23523,'2012/05/05',0 union all select 49,23532,'2010/02/25',0 union allselect 49,23533,'2012/02/26',0 union allselect 49,23534,'2012/02/27',0 ;With TempAS(SELECT CustomerID , InsuranceID , InsuranceDate ,InsuranceDate AS CalculatedValidFrom,DATEADD(yy,1,InsuranceDate) AS CalculatedValidTo,ROW_NUMBER() OVER (PARTITION BY CustomerID ORDER BY InsuranceDate ) AS RnFROM insuranceWHERE CancelInsurance = 0),RecurAS(SELECT CustomerID , InsuranceID , InsuranceDate ,CalculatedValidFrom,CalculatedValidTo,RnFROM TempWHERE Rn=1UNION ALLSELECT t.CustomerID , t.InsuranceID , t.InsuranceDate ,CASE WHEN t.CalculatedValidFrom < r.CalculatedValidTo THEN r.CalculatedValidTo ELSE t.CalculatedValidFrom END,CASE WHEN t.CalculatedValidFrom < r.CalculatedValidTo THEN DATEADD(yy,1,r.CalculatedValidTo) ELSE t.CalculatedValidTo END,t.RnFROM Recur rINNER JOIN Temp tON t.CustomerID = r.CustomerIDAND t.Rn = r.Rn + 1)SELECT CustomerID , InsuranceID , InsuranceDate ,CalculatedValidFrom,CalculatedValidToFROM Recur ORDER BY CustomerID,RnCustomerID InsuranceID InsuranceDate CalculatedValidFrom CalculatedValidTo42 23523 2012-05-05 00:00:00.000 2012-05-05 00:00:00.000 2013-05-05 00:00:00.00049 23532 2010-02-25 00:00:00.000 2010-02-25 00:00:00.000 2011-02-25 00:00:00.00049 23533 2012-02-26 00:00:00.000 2012-02-26 00:00:00.000 2013-02-26 00:00:00.00049 23534 2012-02-27 00:00:00.000 2013-02-26 00:00:00.000 2014-02-26 00:00:00.00052 22312 2010-10-19 00:00:00.000 2010-10-19 00:00:00.000 2011-10-19 00:00:00.00052 52369 2012-02-14 00:00:00.000 2012-02-14 00:00:00.000 2013-02-14 00:00:00.00052 52353 2012-02-16 00:00:00.000 2013-02-14 00:00:00.000 2014-02-14 00:00:00.00052 52380 2012-02-17 00:00:00.000 2014-02-14 00:00:00.000 2015-02-14 00:00:00.00079 65322 2012-05-05 00:00:00.000 2012-05-05 00:00:00.000 2013-05-05 00:00:00.00079 65323 2012-05-06 00:00:00.000 2013-05-05 00:00:00.000 2014-05-05 00:00:00.000[/code]------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
slimt_slimt
Aged Yak Warrior
746 Posts |
Posted - 2012-06-06 : 04:11:12
|
| Visakh,yes. this is it. it calculates now okey.thank oyu very much |
 |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2012-06-07 : 22:30:31
|
| welcome------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
|
|
|
|
|