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 |
|
Clas
Starting Member
33 Posts |
Posted - 2012-08-25 : 05:27:59
|
| Create and fill gap in dateperiodcreate table #source(individual int,movingIN date,movingOut date,household int)Insert INTO #sourceSELECT '3','1858-06-27', '1873-10-31','100'UNION ALL SELECT '3','1877-11-01', '1884-09-05','100'UNION ALL SELECT '4','1861-04-26', '1875-10-31','100'UNION ALL SELECT '4','1875-10-31', '1881-11-09','300'UNION ALL SELECT '4','1881-11-09', '1882-07-01','100'UNION ALL SELECT '4','1882-11-02', '1883-11-22','400'UNION ALL SELECT '4','1884-11-22', '1885-05-20','100'Gap (household -1):3 1873-10-31 1877-11-01 -14 1882-07-01 1882-11-02 -14 1883-11-22 1884-11-22 -1RESULT: individual movingIN movingOut household3 1858-06-27 1873-10-31 1003 1873-10-31 1877-11-01 -13 1877-11-01 1884-09-05 1004 1861-04-26 1875-10-31 1004 1875-10-31 1881-11-09 3004 1881-11-09 1882-07-01 1004 1882-07-01 1882-11-02 -14 1882-11-02 1883-11-22 4004 1883-11-22 1884-11-22 -14 1884-11-22 1885-05-20 100THANKS ! |
|
|
khtan
In (Som, Ni, Yak)
17689 Posts |
Posted - 2012-08-25 : 10:03:53
|
[code]; with cte as( select *, rn = row_number() over (partition by individual order by movingIN) from #source)select c1.individual, movingIN = c1.movingOut, movingOut = c2.movingIN, household = -1from cte c1 inner join cte c2 on c1.individual = c2.individual and c1.rn = c2.rn - 1where c1.movingOut <> c2.movingINunion allselect individual, movingIN, movingOut, householdfrom cte[/code] KH[spoiler]Time is always against us[/spoiler] |
 |
|
|
|
|
|
|
|